Files
RBMESAPICore/Context/SQL/GetWPLAN_MN.sql
liangjunyu 001a03c747 1
2025-10-28 17:55:28 +08:00

90 lines
4.4 KiB
Transact-SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

USE [AIS20220929093310]
GO
/****** Object: UserDefinedFunction [dbo].[GetWPLAN_MN] Script Date: 2025-10-27 11:50:09 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author: <Author,,Name>
-- Create date: <Create Date,,>
-- Description: <Description,,>
-- =============================================
ALTER FUNCTION [dbo].[GetWPLAN_MN]
(
@ERP_MO varchar(255),
@orgid int
)
RETURNS TABLE
AS
RETURN
(
/*dialect*/
SELECT * FROM (
SELECT DISTINCT P1.FBILLNO WPLAN_MO,P1.FMOBILLNO ERP_MO_ID,P1.FMOENTRYSEQ MO_SEQ,M1.FNUMBER PROD_ID,P1.FQty P_QTY
,M2.FNUMBER MTRL_ID,CASE WHEN P3.FPARENTROWID='' THEN 'Y' ELSE 'N' END IS_MAIN
,CASE WHEN P3.FPARENTROWID='' THEN M2.FNUMBER ELSE (SELECT M.FNUMBER FROM T_PRD_PPBOMENTRY C1
INNER JOIN T_PRD_PPBOMENTRY_C C3 ON C3.FID=C1.FID AND C3.FENTRYID=C1.FENTRYID AND C3.FROWID=P3.FPARENTROWID
INNER JOIN T_BD_MATERIAL M ON M.FMATERIALID=C1.FMATERIALID
WHERE C1.FID=P2.FID) END MAIN_ID
,CASE WHEN P3.FISSUETYPE = '7' AND CHARINDEX('93',M2.FNUMBER) = 0 AND CHARINDEX('94',M2.FNUMBER) = 0 AND CHARINDEX('95',M2.FNUMBER) = 0 THEN 0
ELSE ISNULL(t2e.DOSAGE,
CASE P2.FMUSTQTY WHEN 0 THEN ISNULL(t3e.DOSAGE,ISNULL((
SELECT ROUND(SUM(t4e.FNUMERATOR) / AVG(t4e.FDENOMINATOR),6) DOSAGE FROM T_PRD_PPBOMENTRY t4e
WHERE 1 = 1 AND t4e.FID = P2.FID AND t4e.FREPLACEGROUP = P2.FREPLACEGROUP AND t4e.FDENOMINATOR != 1 AND t4e.FUSERATE > 0 AND t4e.FMUSTQTY > 0 GROUP BY t4e.FREPLACEGROUP
),0))
ELSE ROUND(P2.FNUMERATOR/P2.FDENOMINATOR,6) END
) END AS DOSAGE --2024/11/27
,CASE WHEN P3.FISSUETYPE = '7' AND CHARINDEX('93',M2.FNUMBER) = 0 AND CHARINDEX('94',M2.FNUMBER) = 0 AND CHARINDEX('95',M2.FNUMBER) = 0 THEN 0 ELSE (CASE WHEN P2.FMUSTQTY = 0 THEN 0 ELSE P2.FBASESTDQTY END) END NN_QTY
,CASE WHEN P3.FISSUETYPE = '7' AND CHARINDEX('93',M2.FNUMBER) = 0 AND CHARINDEX('94',M2.FNUMBER) = 0 AND CHARINDEX('95',M2.FNUMBER) = 0 THEN 0 ELSE P2.FMUSTQTY END TN_QTY
,P2.FSEQ SEQ,P3.FPOSITIONNO POINT_STR
,CASE P2.FMATERIALTYPE WHEN 2 THEN 'Y' ELSE 'N' END IS_BACK
--,P2.FNUMERATOR AS '<27><><EFBFBD><EFBFBD>',P2.FDENOMINATOR AS '<27><>ĸ',P2.FUSERATE AS 'ʹ<>ñ<EFBFBD><C3B1><EFBFBD>',P2.FREPLACEGROUP
FROM T_PRD_PPBOM P1
INNER JOIN T_PRD_PPBOMENTRY P2 ON P2.FID=P1.FID
OUTER APPLY (
SELECT ROUND(SUM(t2e.FNUMERATOR)/AVG(t2e.FDENOMINATOR),6) DOSAGE
FROM T_PRD_PPBOMENTRY t2e
WHERE 1 = 1
AND t2e.FID = P2.FID AND t2e.FREPLACEGROUP = P2.FREPLACEGROUP
AND t2e.FUSERATE > 0 AND t2e.FMUSTQTY > 0
AND t2e.FDENOMINATOR = P1.FQTY
GROUP BY t2e.FREPLACEGROUP
) t2e
OUTER APPLY (
SELECT ROUND(SUM(t3e.FNUMERATOR)/AVG(t3e.FDENOMINATOR),6) DOSAGE
FROM T_PRD_PPBOMENTRY t3e
WHERE 1 = 1
AND t3e.FID = P2.FID AND t3e.FREPLACEGROUP = P2.FREPLACEGROUP
AND t3e.FDENOMINATOR = 1
AND t3e.FUSERATE > 0 AND t3e.FMUSTQTY > 0
GROUP BY t3e.FREPLACEGROUP
) t3e
INNER JOIN T_PRD_PPBOMENTRY_C P3 ON P3.FID=P2.FID AND P3.FENTRYID=P2.FENTRYID
INNER JOIN T_BD_MATERIAL M1 ON M1.FMATERIALID=P1.FMATERIALID
INNER JOIN T_BD_MATERIAL M2 ON M2.FMATERIALID=P2.FMATERIALID
--INNER JOIN T_PRD_MOENTRY MO2 ON MO2.FID=P2.FMOID AND MO2.FENTRYID=P2.FMOENTRYID
WHERE P1.FMOBILLNO=@ERP_MO AND P1.FPrdOrgId=@orgid
UNION
SELECT DISTINCT P1.FBILLNO WPLAN_MO,P1.FSUBBILLNO ERP_MO_ID,P1.FSUBREQENTRYSEQ MO_SEQ,M1.FNUMBER PROD_ID,P1.FQty P_QTY
,M2.FNUMBER MTRL_ID,CASE WHEN P3.FPARENTROWID='' THEN 'Y' ELSE 'N' END IS_MAIN
,CASE WHEN P3.FPARENTROWID='' THEN M2.FNUMBER ELSE (SELECT M.FNUMBER FROM T_SUB_PPBOMENTRY C1
INNER JOIN T_SUB_PPBOMENTRY_C C3 ON C3.FID=C1.FID AND C3.FENTRYID=C1.FENTRYID AND C3.FROWID=P3.FPARENTROWID
INNER JOIN T_BD_MATERIAL M ON M.FMATERIALID=C1.FMATERIALID
WHERE C1.FID=P2.FID) END MAIN_ID
--,CASE P4.FNOPICKEDQTY WHEN 0 THEN 0 ELSE ROUND(P2.FNUMERATOR/P2.FDENOMINATOR,6) END DOSAGE
,ROUND(P2.FNUMERATOR/P2.FDENOMINATOR,6) DOSAGE
,P2.FSTDQTY NN_QTY,P4.FNOPICKEDQTY TN_QTY,P2.FSEQ SEQ,P3.FPOSITIONNO POINT_STR
,CASE P2.FMATERIALTYPE WHEN 2 THEN 'Y' ELSE 'N' END IS_BACK--,'' REMARK
FROM T_SUB_PPBOM P1
INNER JOIN T_SUB_PPBOMENTRY P2 ON P2.FID=P1.FID
INNER JOIN T_SUB_PPBOMENTRY_C P3 ON P3.FID=P2.FID AND P3.FENTRYID=P2.FENTRYID
INNER JOIN T_SUB_PPBOMENTRY_Q P4 ON P4.FID=P2.FID AND P4.FENTRYID=P2.FENTRYID
INNER JOIN T_BD_MATERIAL M1 ON M1.FMATERIALID=P1.FMATERIALID
INNER JOIN T_BD_MATERIAL M2 ON M2.FMATERIALID=P2.FMATERIALID
WHERE P1.FSUBBILLNO=@ERP_MO AND P1.FSubOrgId=@orgid
) A
)