--WO2405090020 ;WITH #TopMo AS ( SELECT t0.FBILLNO,t0e.FID,t0e.FENTRYID,t0e.FMATERIALID AS TopMaterialId,t0e.FMATERIALID ,0 FLOT,CAST('' AS nvarchar(255)) FLOT_TEXT,CONVERT(decimal(23,10), 0) FAMOUNT ,CONVERT(varchar(1000),ROW_NUMBER() OVER (ORDER BY t0.FID,t0e.FSEQ)) AS 'aPATH' ,0 lv ,CHARINDEX(t0.FBILLNO,'SUB') AS 'oType' FROM T_PRD_MO t0 INNER JOIN T_PRD_MOENTRY t0e on t0.FID = t0e.FID WHERE 1=1 --AND t0.FBILLNO = 'RO2405090020' --AND t0.FBILLNO = 'TO2405210015' --AND t0.FBILLNO = 'WO2405160002' --AND t0.FBILLNO = 'WO2405080005' ) ,#生产领料单 AS ( SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,0 AS 'oType' ,SUM(t1e.FAMOUNT) AS 'FAMOUNT',t1e.FMOENTRYID,t1e.FMOBILLNO FROM T_PRD_PICKMTRL t1 INNER JOIN T_PRD_PICKMTRLDATA t1e on t1.FID = t1e.FID WHERE t1.FDOCUMENTSTATUS = 'C' GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,t1e.FMOENTRYID,t1e.FMOBILLNO ) , #生产补料单 AS ( SELECT t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT',0 AS 'oType' FROM T_PRD_FEEDMTRL t0 INNER JOIN T_PRD_FEEDMTRLDATA t0e on t0.FID = t0e.FID WHERE t0.FDOCUMENTSTATUS = 'C' GROUP BY t0e.FMOID,t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT ) , #生产退料单 AS ( SELECT t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT',0 AS 'oType' FROM T_PRD_RETURNMTRL t0 INNER JOIN T_PRD_RETURNMTRLENTRY t0e on t0.FID = t0e.FID WHERE t0.FDOCUMENTSTATUS = 'C' GROUP BY t0e.FMOID,t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT ) ,#委外领料单 AS ( SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,1 AS 'oType' ,SUM(ISNULL(t1e_a.FAMOUNT,0)) FAMOUNT,t1e.FSUBREQENTRYID AS FMOENTRYID FROM T_SUB_PICKMTRL t1 INNER JOIN T_SUB_PICKMTRLDATA t1e on t1.FID = t1e.FID INNER JOIN T_SUB_PICKMTRLDATA_A t1e_a on t1e.FENTRYID = t1e_a.FENTRYID WHERE t1.FDOCUMENTSTATUS = 'C' GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,t1e.FSUBREQENTRYID ) , #委外补料单 AS ( SELECT t0e.FSUBREQENTRYID AS FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT',1 AS 'oType' FROM T_SUB_FEEDMTRL t0 INNER JOIN T_SUB_FEEDMTRLENTRY t0e on t0.FID = t0e.FID --INNER JOIN T_SUB_FEEDMTRLENTRY_A t0e_a on t0e.FENTRYID = t0e_a.FENTRYID WHERE t0.FDOCUMENTSTATUS = 'C' GROUP BY t0e.FLOT,t0e.FMATERIALID,t0e.FSUBREQENTRYID ) , #委外退料单 AS ( SELECT t0e_a.FSUBREQENTRYID AS FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT',1 AS 'oType' FROM T_SUB_RETURNMTRL t0 INNER JOIN T_SUB_RETURNMTRLENTRY t0e on t0.FID = t0e.FID INNER JOIN T_SUB_RETURNMTRLENTRY_A t0e_a on t0e.FENTRYID = t0e_a.FENTRYID WHERE t0.FDOCUMENTSTATUS = 'C' GROUP BY t0e.FLOT,t0e.FMATERIALID,t0e_a.FSUBREQENTRYID ) , #TABLE1 AS ( SELECT t0.FLOT_TEXT AS 'FBILLNO',t0.FID,t0.FENTRYID ,t0.FMATERIALID AS 'TopMaterialId' ,t0.FMATERIALID AS 'MoMaterialId' ,t1e.FMATERIALID ,t1e.FLOT,t1e.FLOT_TEXT,t1e.FAMOUNT ,CONVERT(varchar(1000),CONCAT(t0.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY t0.FID,t0.FENTRYID ORDER BY t1e.FMATERIALID))) AS 'aPATH' ,t0.lv + 1 lv ,t0.oType ,t0.FID AS 'MoId' ,t0.FENTRYID AS 'MoEntryId' ,0 AS 'isTrue' FROM #TopMo t0 CROSS APPLY ( SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID ,SUM(t1e.FAMOUNT) FAMOUNT FROM T_PRD_PICKMTRLDATA t1e WHERE t1e.FMOENTRYID = t0.FENTRYID GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID ) t1e UNION ALL SELECT tt.FLOT_TEXT AS 'FBILLNO',tt.FID,tt.FENTRYID ,tt.TopMaterialId ,t0.MoMaterialId ,t0.FMATERIALID ,t0.FLOT,t0.FLOT_TEXT,t0.FAMOUNT ,CONVERT(varchar(1000),CONCAT(tt.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY tt.FID,tt.FENTRYID ORDER BY t0.FMATERIALID))) AS 'aPATH' ,tt.lv + 1 lv ,CHARINDEX(t0.FBILLNO,'SUB') AS 'oType' ,t0.FID AS 'MoId' ,t0.FENTRYID AS 'MoEntryId' ,CASE WHEN t0.FBILLNO = tt.FBILLNO THEN 1 ELSE 0 END AS 'isTrue' FROM #TABLE1 tt CROSS APPLY ( SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID ,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID FROM T_PRD_MO t0 INNER JOIN T_PRD_MOENTRY t0e on t0.FID = t0e.FID INNER JOIN #生产领料单 t1 on t1.FMOENTRYID = t0e.FENTRYID WHERE t0.FBILLNO = tt.FLOT_TEXT AND tt.oType = 0 UNION ALL SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID ,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID FROM T_SUB_REQORDER t0 INNER JOIN T_SUB_REQORDERENTRY t0e on t0.FID = t0e.FID INNER JOIN #委外领料单 t1 on t1.FMOENTRYID = t0e.FENTRYID WHERE t0.FBILLNO = tt.FLOT_TEXT AND tt.oType = 1 ) t0 WHERE tt.isTrue = 0 ) ,#table2 AS ( SELECT FBILLNO,FID AS 'MoId',FENTRYID AS 'MoEntryId',FENTRYID,TopMaterialId,TopMaterialId AS 'MoMaterialId',FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT,aPATH,lv,oType ,CONCAT('/',aPATH,'/') RnPath FROM #TopMo UNION ALL SELECT FBILLNO,MoId,MoEntryId,FENTRYID,TopMaterialId,MoMaterialId,FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT,aPATH,lv,oType ,CONCAT('/',REPLACE(aPATH,'.','/'),'/') RnPath FROM #TABLE1 ) , #实际工时归集 AS ( SELECT t0e.FPROORDERNO,t0e.FPROORDERENTRYID,FCOSTCENTERID ,SUM(t0e.FHRWORKTIME) AS '人员实作工时',SUM(t0e.FRPTQTY) AS '汇报数量' ,SUM(t2e.FHRWORKTIME) FHRWORKTIME,SUM(t2e.FFINISHQTY) FFINISHQTY --,t2.FBILLNO,t2.FDOCUMENTSTATUS --,t0e.* FROM T_CB_WORKHOURSENTRY t0e --INNER JOINl T_PRD_MOENTRY t1e on t1e.FENTRYID = t0e.FPROORDERENTRYID INNER JOIN T_PRD_MORPTENTRY t2e on t2e.FENTRYID = t0e.FSRCENTRYID --INNER JOIN T_PRD_MORPT t2 on t2e.FID = t2.FID WHERE t0e.FSRCBILLFORMID = 'PRD_MORPT' GROUP BY t0e.FPROORDERNO,t0e.FPROORDERENTRYID,FCOSTCENTERID ) SELECT FBILLNO,MoId,MoEntryId,t0.FENTRYID,TopMaterialId,MoMaterialId,t0.FMATERIALID ,t1.FNUMBER,t1_l.FNAME,CASE t1b.FERPCLSID WHEN 1 THEN '外购' WHEN 2 THEN '自制' WHEN 3 THEN '委外' WHEN 5 THEN '虚拟' ELSE '' END AS '物料属性' ,t0.FLOT,t0.FLOT_TEXT,aPATH,lv,t0.oType --,t0.FAMOUNT AS '领料总成本', ISNULL(t2.FAMOUNT,0) AS '补料总成本',ISNULL(t3.FAMOUNT,0) AS '退料总成本' --, ISNULL(t4.FAMOUNT,0) AS '委外补料总成本',ISNULL(t5.FAMOUNT,0) AS '委外退料总成本' ,(t0.FAMOUNT + ISNULL(t2.FAMOUNT,0) -ISNULL(t3.FAMOUNT,0) + ISNULL(t4.FAMOUNT,0) - ISNULL(t5.FAMOUNT,0)) AS '直接材料' ,ISNULL(t6.汇报数量,0) AS '汇报数量',ISNULL(t6.人员实作工时,0) AS '人员实作工时' ,(CASE LEFT(t0.FBILLNO,2) WHEN 'WO' THEN 1 WHEN 'RO' THEN 2 WHEN 'TO' THEN 3 WHEN 'RT' THEN 4 ELSE 0 END) AS 'MoType' FROM #table2 t0 INNER JOIN T_BD_MATERIAL t1 on t0.FMATERIALID = t1.FMATERIALID INNER JOIN T_BD_MATERIALBASE t1b on t1b.FMATERIALID = t0.FMATERIALID INNER JOIN T_BD_MATERIAL_L t1_l on t0.FMATERIALID = t1_l.FMATERIALID AND t1_l.FLOCALEID = 2052 LEFT JOIN #生产补料单 t2 on t2.FMOENTRYID = t0.MoEntryId AND t2.FMATERIALID = t0.FMATERIALID AND t2.FLOT = t0.FLOT AND t2.oType = t0.oType LEFT JOIN #生产退料单 t3 on t3.FMOENTRYID = t0.MoEntryId AND t3.FMATERIALID = t0.FMATERIALID AND t3.FLOT = t0.FLOT AND t3.oType = t0.oType LEFT JOIN #委外补料单 t4 on t4.FMOENTRYID = t0.MoEntryId AND t4.FMATERIALID = t0.FMATERIALID AND t4.FLOT = t0.FLOT AND t4.oType = t0.oType LEFT JOIN #委外退料单 t5 on t5.FMOENTRYID = t0.MoEntryId AND t5.FMATERIALID = t0.FMATERIALID AND t5.FLOT = t0.FLOT AND t5.oType = t0.oType LEFT JOIN #实际工时归集 t6 on t6.FPROORDERENTRYID = t0.FENTRYID ORDER BY CAST(RnPath AS HIERARCHYID) --OPTION(MAXRECURSION 0)