IF EXISTS (SELECT 1 WHERE object_id('tempdb..#生产订单') IS NOT NULL) BEGIN DROP TABLE #生产订单 END IF EXISTS (SELECT 1 WHERE object_id('tempdb..#关联项目费用临时表') IS NOT NULL) BEGIN DROP TABLE [dbo].[#关联项目费用临时表] END CREATE TABLE #生产订单( [FBILLNO] [nvarchar](80) NULL, [FID] [int] NOT NULL, [FENTRYID] [int] NOT NULL, [TopMaterialId] [int] NULL, [FMATERIALID] [int] NULL, [FFORMID] [varchar](36) NULL, [入库数量] [decimal](23, 10) NOT NULL, [FSTATUS] [char](1) NULL, [FCOSTDATE] [datetime] NULL, [FQTY] [decimal](23, 10) NOT NULL, [FPERIOD] [int] NULL ) ON [PRIMARY] declare @sqlL varchar(max) declare @billNo varchar(100),@materialNumber varchar(100) declare @dbName varchar(100) SET @sqlL = N' INSERT INTO #生产订单 SELECT t0.FBILLNO,t0.FID,t0e.FENTRYID,t0e.FMATERIALID AS TopMaterialId,t0e.FMATERIALID ,t0.FFORMID AS FFORMID,t0e_a.FSTOCKINQUASELAUXQTY AS 入库数量 ,t0e_a.FSTATUS,t0e_a.FCOSTDATE,t0e_a.FSTOCKINQUASELAUXQTY AS FQTY ,CONVERT(INT, CONVERT(VARCHAR(6),ISNULL(t0e_a.FCOSTDATE,GETDATE()),112)) AS FPERIOD FROM T_PRD_MO t0 INNER JOIN T_PRD_MOENTRY t0e on t0.FID = t0e.FID INNER JOIN T_PRD_MOENTRY_A t0e_a on t0e.FENTRYID = t0e_a.FENTRYID INNER JOIN T_BD_MATERIAL t1 on t1.FMATERIALID = t0e.FMATERIALID WHERE 1 = 1 ' select @dbName = db_name() if @dbName != 'AIS20231110222743' BEGIN SET @billNo = 'WO2403210039' --SET @billNo = 'WO2310240111' --SET @billNo = 'TO2310120003' SET @billNo = 'RO2403280019' SET @billNo = 'WO2304230023' END IF @billNo != '' OR @materialNumber = '' BEGIN SET @sqlL = @sqlL + N' AND t0.FBILLNO = ''' + @billNo + '''' END IF @materialNumber != '' BEGIN SET @sqlL = @sqlL + N' AND t1.FNUMBER = ''' + @materialNumber + '''' END EXEC(@sqlL) ;WITH #TopMo AS ( SELECT * FROM #生产订单 ) ,#生产领料单 AS ( SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'PRD_MO' AS 'FFORMID' ,SUM(t1e.FAMOUNT) AS 'FAMOUNT',t1e.FMOENTRYID,t1e.FMOBILLNO ,SUM(t1e.FBASEACTUALQTY) AS 'FBASEACTUALQTY' ,CONVERT(INT, CONVERT(VARCHAR(6),MAX(t1.FDATE),112)) AS 'FPERIOD' FROM T_PRD_PICKMTRL t1 INNER JOIN T_PRD_PICKMTRLDATA t1e on t1.FID = t1e.FID WHERE t1.FDOCUMENTSTATUS = 'C' AND t1e.FMOBILLNO != t1e.FLOT_TEXT GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,t1e.FMOENTRYID,t1e.FMOBILLNO ) ,#委外领料单 AS ( SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID' ,SUM(ISNULL(t1e_a.FAMOUNT,0)) FAMOUNT,t1e.FSUBREQENTRYID AS FMOENTRYID ,SUM(t1e.FBASEACTUALQTY) AS 'FBASEACTUALQTY' ,CONVERT(INT, CONVERT(VARCHAR(6),MAX(t1.FDATE),112)) AS 'FPERIOD' 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 t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID ,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID ,CONVERT(VARCHAR(36),t1.FFORMID) AS 'FFORMID' ,CONVERT(decimal(23,10),0) AS '入库数量' ,CONVERT(decimal(23,10),0) AS '生产数量' ,t1.FBASEACTUALQTY AS '领料数量' ,t1.FPERIOD FROM #生产领料单 t1 LEFT JOIN T_PRD_MO t0 on t0.FBILLNO = t1.FLOT_TEXT LEFT JOIN T_PRD_MOENTRY t0e on t0.FID = t0e.FID 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 ,CONVERT(VARCHAR(36),t1.FFORMID) AS 'FFORMID' ,t0e.FSTOCKINQTY ,t0e.FQTY AS '生产数量' ,t1.FBASEACTUALQTY AS '领料数量' ,t1.FPERIOD FROM #委外领料单 t1 LEFT JOIN T_SUB_REQORDER t0 on t0.FBILLNO = t1.FLOT_TEXT LEFT JOIN T_SUB_REQORDERENTRY t0e on t0.FID = t0e.FID ) , #整合数据 AS ( SELECT t0.FBILLNO AS 'MoBillNo' ,t0.FBILLNO AS 'PMoBillNo' ,CONVERT(varchar(1000),ROW_NUMBER() OVER (ORDER BY t0.FID,t0.FENTRYID,t0.FMATERIALID)) AS 'aPATH' ,CONVERT(varchar(1000),'0') AS 'PPATH',CONVERT(VARCHAR(8000),'') AS 'MPath',0 AS 'lv' ,t0.FID AS 'MoId' ,t0.FENTRYID AS 'MoEntryId' ,t0.FMATERIALID AS 'MoMaterialId' ,0 AS 'PMoId' ,0 AS 'PMoEntryId' ,0 AS 'PMoMaterialId' ,t0.TopMaterialId ,t0.FMATERIALID ,0 FLOT ,CONVERT(nvarchar(255),'') AS 'FLOT_TEXT' ,CONVERT(decimal(23,10),0) AS 'FAMOUNT' ,t0.FQTY AS '领料数量' ,t0.FPERIOD ,t0.入库数量 ,t0.FFORMID FROM #TopMo t0 UNION ALL SELECT ISNULL(t0.FBILLNO,'') AS 'MoBillNo' ,tt.MoBillNo ,CONVERT(varchar(1000),CONCAT(tt.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY tt.MoId,tt.MoEntryId ORDER BY t0.FMATERIALID))) AS 'aPATH' ,tt.aPATH,CONVERT(varchar(8000),CONCAT(tt.MPath,ISNULL(tt.MoBillNo,''),'>')),tt.lv + 1 lv ,ISNULL(t0.FID,0) AS 'MoId' ,ISNULL(t0.FENTRYID,0) AS 'MoEntryId' ,ISNULL(t0.MoMaterialId, 0) ,tt.MoId AS 'PMoId' ,tt.MoEntryId AS 'PMoEntryId' ,tt.MoMaterialId AS 'PMoMaterialId' ,tt.TopMaterialId ,t0.FMATERIALID ,t0.FLOT ,t0.FLOT_TEXT ,CONVERT(decimal(23,10),t0.FAMOUNT) ,CONVERT(decimal(23,10),t0.领料数量) --,t0.FPERIOD ,tt.FPERIOD ,ISNULL(t0.入库数量,0) AS '入库数量' ,ISNULL(t0.FFORMID,'') FROM #整合数据 tt CROSS APPLY ( SELECT * FROM #领料单 t0 WHERE t0.FFORMID = tt.FFORMID AND t0.FMOENTRYID = tt.MoEntryId ) t0 WHERE 1=1 AND CHARINDEX(tt.MoBillNo,tt.MPath) = 0 ) , #生产补料单 AS ( SELECT t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT','PRD_MO' AS 'FFORMID' ,SUM(t0e_q.FACTUALQTY) AS 'FQTY' FROM T_PRD_FEEDMTRL t0 INNER JOIN T_PRD_FEEDMTRLDATA t0e on t0.FID = t0e.FID INNER JOIN T_PRD_FEEDMTRLDATA_Q t0e_q on t0e_q.FENTRYID = t0e.FENTRYID 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','PRD_MO' AS 'FFORMID' ,SUM(t0e.FQTY) AS 'FQTY' 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 t0e.FSUBREQENTRYID AS FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT','SUB_SUBREQORDER' AS 'FFORMID' ,SUM(t0e_q.FACTUALQTY) AS 'FQTY' FROM T_SUB_FEEDMTRL t0 INNER JOIN T_SUB_FEEDMTRLENTRY t0e on t0.FID = t0e.FID INNER JOIN T_SUB_FEEDMTRLENTRY_Q t0e_q on t0e_q.FENTRYID = t0e.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','SUB_SUBREQORDER' AS 'FFORMID' ,SUM(t0e.FQTY) AS 'FQTY' 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 ) , #成本数据 AS ( SELECT MoBillNo,PMoBillNo ,(CASE LEFT(t0.MoBillNo,2) WHEN 'WO' THEN 1 WHEN 'TO' THEN 2 WHEN 'RO' THEN 3 WHEN 'RT' THEN 4 ELSE 0 END) AS 'MoType' ,MoId,MoEntryId,PMoId,PMoEntryId,PMoMaterialId,TopMaterialId,MoMaterialId,t0.FMATERIALID ,t0.FLOT,t0.FLOT_TEXT AS '批号',aPATH,PPATH,lv,t0.FFORMID ,CASE t0.MoId WHEN 0 THEN (t0.FAMOUNT + (ISNULL(t2.FAMOUNT,0) - ISNULL(t3.FAMOUNT,0) + ISNULL(t4.FAMOUNT,0) - ISNULL(t5.FAMOUNT,0))) ELSE 0 END AS '直接材料' ,(t0.FAMOUNT + (ISNULL(t2.FAMOUNT,0) - ISNULL(t3.FAMOUNT,0) + ISNULL(t4.FAMOUNT,0) - ISNULL(t5.FAMOUNT,0))) AS '领料成本' ,t0.FAMOUNT AS '领料',ISNULL(t2.FAMOUNT,0) AS '补料',ISNULL(t3.FAMOUNT,0) AS '退料',ISNULL(t4.FAMOUNT,0) AS '委外补料',ISNULL(t5.FAMOUNT,0) AS '委外退料' ,CASE t0.FFORMID WHEN 'PRD_MO' THEN ISNULL(t0e_a.FSTOCKINQUASELAUXQTY ,0) ELSE t0.入库数量 END AS '入库数量A' ,(t0.领料数量 + ISNULL(t2.FQTY,0) - ISNULL(t3.FQTY,0) + ISNULL(t4.FQTY,0) - ISNULL(t5.FQTY,0)) AS '实领数量' ,t0.领料数量,t0.FPERIOD FROM #整合数据 t0 LEFT JOIN T_PRD_MOENTRY_A t0e_a on t0.MoEntryId = t0e_a.FENTRYID LEFT JOIN #生产补料单 t2 on t2.FMOENTRYID = t0.PMoEntryId AND t2.FMATERIALID = t0.FMATERIALID AND t2.FLOT = t0.FLOT AND t2.FFORMID = t0.FFORMID LEFT JOIN #生产退料单 t3 on t3.FMOENTRYID = t0.PMoEntryId AND t3.FMATERIALID = t0.FMATERIALID AND t3.FLOT = t0.FLOT AND t3.FFORMID = t0.FFORMID LEFT JOIN #委外补料单 t4 on t4.FMOENTRYID = t0.PMoEntryId AND t4.FMATERIALID = t0.FMATERIALID AND t4.FLOT = t0.FLOT AND t4.FFORMID = t0.FFORMID LEFT JOIN #委外退料单 t5 on t5.FMOENTRYID = t0.PMoEntryId AND t5.FMATERIALID = t0.FMATERIALID AND t5.FLOT = t0.FLOT AND t5.FFORMID = t0.FFORMID ) ,#工单费用明细 AS ( SELECT t0.FBILLID ,t0.FBILLENTRYID ,t0.FBILLSEQ ,t1e.FCOSTITEMID ,t1e.FEXPENSESITEMID ,t1e.FQUALIFIEDINAMOUNT ,t1.FQUALIFIEDINQTY ,t1.FSUMQUALIFIEDINQTY ,tt.实领数量 FROM (SELECT MoEntryId,FPERIOD,实领数量 FROM #成本数据 WHERE MoId > 0) tt INNER JOIN T_CB_PROORDERDIME t0 on t0.FBILLENTRYID = tt.MoEntryId INNER JOIN V_CB_PROORDERINFO t0e ON t0e.FPRODUCTDIMEID = t0.FPRODUCTDIMEID INNER JOIN V_CB_COSTCALEXPENSE t1 ON t1.FID = t0e.FID AND t1.FQUALIFIEDINQTY != 0 INNER JOIN V_CB_COSTCALEXPENSEDETAIL t1e ON t1.FENTRYID = t1e.FENTRYID CROSS APPLY( SELECT TOP 1 1 AS 'val' FROM V_HS_OUTACCTG t5 WHERE t5.FID = t0e.FACCTGID AND (t5.FYEAR *100 + t5.FPERIOD <= tt.FPERIOD) ORDER BY t5.FYEAR *100 + t5.FPERIOD DESC ) t2 WHERE 1 = 1 AND t1.FQUALIFIEDINQTY > 0 ) , #费用项目 AS ( SELECT * FROM ( SELECT FBILLENTRYID AS 'EXP_BILLENTRYID',t1.fieldName AS '费用项目' ,SUM(FQUALIFIEDINAMOUNT) / MAX(FSUMQUALIFIEDINQTY) * MAX(t0.实领数量) AS 'FAMOUNT' ,MAX(t0.实领数量) / MAX(FSUMQUALIFIEDINQTY) AS 'NewQtyRation' ,MAX(FSUMQUALIFIEDINQTY) AS '入库数量' FROM #工单费用明细 t0 LEFT JOIN V_BD_COST_RESTORE_EXPENSE t1 on t0.FEXPENSESITEMID = t1.FEXPID WHERE NOT (t0.FCOSTITEMID = 20522 AND t0.FEXPENSESITEMID = 20045) GROUP BY t0.FBILLENTRYID,t1.fieldName ) t0 PIVOT ( SUM(t0.FAMOUNT) FOR t0.费用项目 IN (O1,O2,O3,O4,O5,O6,O7,O8,O9,O10,O11,O12,O13,O14,O15,O16) ) AS t1 ) , #成本项目 AS ( SELECT * FROM ( SELECT FBILLENTRYID AS 'COST_BILLENTRYID',t2_l.成本项目 ,SUM(FQUALIFIEDINAMOUNT) / MAX(FSUMQUALIFIEDINQTY) * MAX(t0.实领数量) AS 'FAMOUNT' ,MAX(t0.实领数量) / MAX(FSUMQUALIFIEDINQTY) AS 'NewQtyRation' FROM #工单费用明细 t0 LEFT JOIN ( SELECT FCOSTITEMID,CONCAT('P',ROW_NUMBER() OVER (ORDER BY t2_l.FCOSTITEMID)) 成本项目 FROM T_HS_COSTITEM_L t2_l WHERE t2_l.FLOCALEID = 2052 ) t2_l on t0.FCOSTITEMID = t2_l.FCOSTITEMID GROUP BY t0.FBILLENTRYID,t2_l.成本项目 ) t0 PIVOT ( SUM(t0.FAMOUNT) FOR t0.成本项目 IN (P1,P2,P3,P4,P5,P6,P7,P8,P9,P10,P11,P12) ) AS t1 ) , #关联项目费用 AS ( SELECT t0.MoBillNo ,t0.PMoBillNo ,t0.aPATH ,t0.PPATH --,t0.MPath ,t0.lv ,t0.批号 ,t0.直接材料 ,t0.领料成本,t0.领料,t0.补料,t0.退料,t0.委外补料,t0.委外退料 ,t0.领料数量,t0.实领数量,t7.入库数量 ,t0.入库数量A ,MoId,MoEntryId,MoMaterialId,PMoId,PMoEntryId,PMoMaterialId,TopMaterialId,t0.FMATERIALID ,ISNULL(t7.O1,0) AS 'FO1' ,ISNULL(t7.O2,0) AS 'FO2' ,ISNULL(t7.O3,0) AS 'FO3' ,ISNULL(t7.O4,0) AS 'FO4' ,ISNULL(t7.O5,0) AS 'FO5' ,ISNULL(t7.O6,0) AS 'FO6' ,ISNULL(t7.O7,0) AS 'FO7' ,ISNULL(t7.O8,0) AS 'FO8' ,ISNULL(t7.O9,0) AS 'FO9' ,ISNULL(t7.O10,0) AS 'FO10' ,ISNULL(t7.O11,0) AS 'FO11' ,ISNULL(t7.O12,0) AS 'FO12' ,ISNULL(t7.O13,0) AS 'FO13' ,ISNULL(t7.O14,0) AS 'FO14' ,ISNULL(t7.O15,0) AS 'FO15' ,ISNULL(t7.O16,0) AS 'FO16' ,ISNULL(t1.P1,0) AS 'P1' ,ISNULL(t1.P2,0) AS 'P2' ,ISNULL(t1.P3,0) AS 'P3' ,ISNULL(t1.P4,0) AS 'P4' ,ISNULL(t1.P5,0) AS 'P5' ,ISNULL(t1.P6,0) AS 'P6' ,ISNULL(t1.P7,0) AS 'P7' ,ISNULL(t1.P8,0) AS 'P8' ,ISNULL(t1.P9,0) AS 'P9' ,ISNULL(t1.P10,0) AS 'P10' ,ISNULL(t1.P11,0) AS 'P11' ,ISNULL(t1.P12,0) AS 'P12' ,CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID) PATH_ID ,CAST(CONCAT('/',REPLACE(t0.PPATH,'.','/'),'/') AS HIERARCHYID) PPATH_ID ,t1.NewQtyRation AS 'CostRation' ,t7.NewQtyRation AS 'ExpRation' FROM #成本数据 t0 LEFT JOIN #成本项目 t1 on t0.MoEntryId = t1.COST_BILLENTRYID LEFT JOIN #费用项目 t7 on t0.MoEntryId = t7.EXP_BILLENTRYID ) SELECT * INTO #关联项目费用临时表 FROM #关联项目费用 t0 ;WITH #统计 AS ( SELECT --SUM(t1.[普通C]) AS 'C' --,SUM(t1.[试制D]) AS 'D' --,SUM(t1.[返工E]) AS 'E' --,SUM(t1.[返工试制F]) AS 'F' --,SUM(t1.[其他G]) AS 'G' --,SUM(t1.[普通I=C*A]) AS 'I' --,SUM(t1.[试制J=D*A]) AS 'J' --,SUM(t1.[返工K=E*A]) AS 'K' --,SUM(t1.[返工试制L=F*A]) AS 'L' --,SUM(t1.[其他M=G*A]) AS 'M' SUM(t1.直接材料) AS '直接材料' ,SUM((t1.FO1 + t1.FO2 + t1.FO3 + t1.FO4 + t1.FO5 + t1.FO6 + t1.FO7 + t1.FO8 + t1.FO9 + t1.FO10 + t1.FO11 + t1.FO12 + t1.FO13 + t1.FO14 + t1.FO15 + t1.FO16)) AS 'O0' ,SUM((t1.P2 + t1.P3 + t1.P4 + t1.P5 + t1.P6 + t1.P7 + t1.P8 + t1.P9 + t1.P10 + t1.P11 + t1.P12)) AS 'P0' --,SUM(t1.领料成本) AS '领料成本' ,t0.aPATH FROM #关联项目费用临时表 t0 INNER JOIN #关联项目费用临时表 t1 ON t0.lv <= t1.lv AND t1.PATH_ID.IsDescendantOf(t0.PATH_ID) = 1 GROUP BY t0.aPATH ) , #计算成本 AS ( SELECT SUM(t0.直接材料) AS '直接材料' ,t1.aPATH FROM #关联项目费用临时表 t0 INNER JOIN #关联项目费用临时表 t1 ON t0.lv <= t1.lv AND t1.PATH_ID.IsDescendantOf(t0.PATH_ID) = 1 GROUP BY t1.aPATH ) , #物料属性 AS ( SELECT t0e.FENUMID,t0e.FSEQ,t0e.FVALUE,t0e_l.FCAPTION FROM T_META_FORMENUMITEM t0e INNER JOIN T_META_FORMENUMITEM_L t0e_l on t0e.FENUMID = t0e_l.FENUMID AND t0e_l.FLOCALEID = 2052 WHERE 1 = 1 AND t0e.FID = 'ac14913e-bd72-416d-a50b-2c7432bbff63' --ORDER BY t0e.FSEQ ) SELECT * FROM #关联项目费用临时表 t0 ORDER BY CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID)