declare @sqlL varchar(max) declare @billNo varchar(100),@materialNumber varchar(100) ,@sYear int,@sMonth int ,@eYear int,@eMonth int SELECT @sYear = 0,@eYear = 0,@sMonth = 0,@eMonth = 0 --SELECT @sYear = 2024,@eYear = 2024,@sMonth = 2,@eMonth = 2 SET @sqlL = N' 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.FBASEUNITQTY AS FQTY ,YEAR(t0e_a.FCOSTDATE) * 100 + MONTH(t0e_a.FCOSTDATE) AS FPERIOD INTO ##查找对应工单 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 ' SET @billNo = '' SET @materialNumber = '' --SET @billNo = 'RO2405090020' --SET @billNo = 'TO2405210015' --SET @billNo = 'WO2405160002' --SET @billNo = 'WO2405080005' --SET @billNo = 'TO2404290033' --SET @billNo = 'TO2403250007' --SET @billNo = 'WO2403210039' --SET @billNo = 'RO2403130015' SET @billNo = 'RO2403280019' --SET @billNo = 'TO2310120003' --SET @billNo = 'WO2310020141' --SET @billNo = 'WO2310240123' --SET @billNo = 'WO2310240112' --SET @billNo = 'WO2310240116' --SET @billNo = 'WO2310240111' --SET @materialNumber = '03.70.0143' IF @billNo != '' BEGIN SET @sqlL = @sqlL + N' AND t0.FBILLNO = ''' + @billNo + '''' END IF @materialNumber != '' BEGIN SET @sqlL = @sqlL + N' AND t1.FNUMBER = ''' + @materialNumber + '''' END IF @sYear != 0 OR @sYear != 0 OR @sMonth != 0 OR @eMonth != 0 BEGIN SET @sqlL=CONCAT(@sqlL, ' AND ISNULL(YEAR(FCOSTDATE),0) BETWEEN ',@sYear,' AND ', @eYear) SET @sqlL=CONCAT(@sqlL, ' AND ISNULL(MONTH(FCOSTDATE),0) BETWEEN ',@sMonth,' AND ', @eMonth) END --SELECT @sqlL 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 'FQTY' ,YEAR(MAX(t1.FDATE)) * 100 + MONTH(MAX(t1.FDATE)) 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 'FQTY' ,YEAR(MAX(t1.FDATE)) * 100 + MONTH(MAX(t1.FDATE)) 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 ,CONVERT(decimal(23,10),0) AS '入库数量' ,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID ,CONVERT(VARCHAR(36),t1.FFORMID) AS 'FFORMID' ,t0e.FBASEUNITQTY AS '生产数量',t1.FQTY AS '领料数量' ,t1.FPERIOD ,CASE WHEN t1.FQTY > ISNULL(t0e.FBASEUNITQTY,0) THEN 1 ELSE CONVERT(decimal(23,10),t1.FQTY / ISNULL(t0e.FBASEUNITQTY,t1.FQTY)) END AS 'QtyRatio' 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 ,t0e.FSTOCKINQTY ,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID ,CONVERT(VARCHAR(36),t1.FFORMID) AS 'FFORMID' ,t0e.FQTY AS '生产数量',t1.FQTY AS '领料数量' ,t1.FPERIOD ,CASE WHEN t1.FQTY > ISNULL(t0e.FQTY,0) THEN 1 ELSE CONVERT(decimal(23,10),t1.FQTY / ISNULL(t0e.FQTY,t1.FQTY)) END AS 'QtyRatio' 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' ,CONVERT(decimal(23,10),1) AS 'QtyRatio' ,t0.FQTY AS '领料数量' ,t0.FQTY AS '生产数量' ,t0.FPERIOD ,t0.入库数量 ,t0.FFORMID ,0 AS 'isTrue' 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 * tt.QtyRatio) ,CONVERT(decimal(23,10),tt.QtyRatio * t0.QtyRatio) ,CONVERT(decimal(23,10),t0.领料数量) ,ISNULL(t0.生产数量,t0.领料数量) ,t0.FPERIOD ,ISNULL(t0.入库数量,0) AS '入库数量' ,ISNULL(t0.FFORMID,'') ,CASE WHEN t0.FBILLNO = tt.MoBillNo THEN 1 ELSE 0 END AS 'isTrue' FROM #整合数据 tt CROSS APPLY ( SELECT * FROM #领料单 t0 WHERE t0.FFORMID = tt.FFORMID AND t0.FMOENTRYID = tt.MoEntryId --AND CHARINDEX(t0.FBILLNO,tt.MPath) = 0 ) t0 WHERE 1=1 AND tt.isTrue = 0 AND CHARINDEX(tt.MoBillNo,tt.MPath) = 0 --AND tt.lv < 5 ) ,#工单费用明细 AS ( SELECT t0.FBILLID ,t0.FBILLENTRYID ,t0.FBILLSEQ --,t2_l.FNAME AS '成本项目' ,t1e.FCOSTITEMID --,t3_l.FNAME AS '费用项目' ,t1e.FEXPENSESITEMID --,t1e.FQUALIFIEDINAMOUNT / t1.FQUALIFIEDINQTY * tt.生产数量 * tt.QtyRatio AS 'FAMOUNT' ,t1e.FQUALIFIEDINAMOUNT ,t1.FSUMQUALIFIEDINQTY ,生产数量 ,QtyRatio FROM (SELECT MoEntryId,QtyRatio,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 (tt.FPERIOD IS NULL OR t5.FYEAR *100 + t5.FPERIOD <= tt.FPERIOD) ORDER BY t5.FYEAR *100 + t5.FPERIOD DESC ) t2 --INNER JOIN V_HS_OUTACCTG t2 on t2.FID = t0e.FACCTGID AND (t2.FYEAR * 100 + t2.FPERIOD) <= tt.FPERIOD WHERE 1 = 1 --AND NOT (t1e.FCOSTITEMID = 20522 AND t1e.FEXPENSESITEMID = 20045) AND t1.FQUALIFIEDINQTY > 0 ) , #费用项目 AS ( SELECT * FROM ( SELECT FBILLENTRYID AS 'EXP_BILLENTRYID',t1.fieldName AS '费用项目' ,SUM(FQUALIFIEDINAMOUNT) / MAX(FSUMQUALIFIEDINQTY) * MAX(t0.生产数量) * MAX(t0.QtyRatio) AS 'FAMOUNT' ,MAX(t0.生产数量) / MAX(FSUMQUALIFIEDINQTY) AS 'NewQtyRation' 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.生产数量) * MAX(t0.QtyRatio) 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 t0e.FPROORDERNO,t0e.FPROORDERENTRYID,FCOSTCENTERID ,SUM(t0e.FHRWORKTIME) AS '人员实作工时',SUM(t0e.FRPTQTY) AS '汇报数量' ,SUM(t2e.FHRWORKTIME) FHRWORKTIME,SUM(t2e.FFINISHQTY) FFINISHQTY FROM T_CB_WORKHOURSENTRY t0e INNER JOIN T_PRD_MORPTENTRY t2e on t2e.FENTRYID = t0e.FSRCENTRYID WHERE t0e.FSRCBILLFORMID = 'PRD_MORPT' GROUP BY t0e.FPROORDERNO,t0e.FPROORDERENTRYID,FCOSTCENTERID ) , #生产补料单 AS ( SELECT t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,SUM(t0e.FAMOUNT) AS 'FAMOUNT','PRD_MO' AS 'FFORMID' 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','PRD_MO' AS 'FFORMID' 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' FROM T_SUB_FEEDMTRL t0 INNER JOIN T_SUB_FEEDMTRLENTRY t0e on t0.FID = t0e.FID 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' 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 ,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)) * ISNULL(t0.QtyRatio,1)) ELSE 0 END AS '直接材料' ,(t0.FAMOUNT + (ISNULL(t2.FAMOUNT,0) - ISNULL(t3.FAMOUNT,0) + ISNULL(t4.FAMOUNT,0) - ISNULL(t5.FAMOUNT,0)) * t0.QtyRatio ) 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 ISNULL(t6.汇报数量,0) WHEN 0 THEN 0 ELSE ISNULL(t6.人员实作工时,0)/ISNULL(t6.汇报数量,0) END AS '单位工时B' ,(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' ,CASE t0.FFORMID WHEN 'PRD_MO' THEN ISNULL(t0e.FSTOCKINQUASELAUXQTY ,0) ELSE t0.入库数量 END AS '入库数量A' ,t0.QtyRatio,t0.生产数量,t0.领料数量 FROM #整合数据 t0 LEFT JOIN T_PRD_MOENTRY_A t0e on t0.MoEntryId = t0e.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 LEFT JOIN #实际工时归集 t6 on t6.FPROORDERENTRYID = t0.MoEntryId ) , #关联项目费用 AS ( SELECT t0.MoBillNo ,t0.PMoBillNo ,t0.aPATH ,t0.PPATH --,t0.MPath ,t0.lv ,t0.批号 ,t0.直接材料 ,t0.领料成本,t0.领料,t0.补料,t0.退料,t0.委外补料,t0.委外退料 ,t0.QtyRatio ,t0.生产数量,t0.领料数量 ,t0.入库数量A ,t0.单位工时B ,CASE t0.MoType WHEN 1 THEN t0.单位工时B ELSE 0 END '普通C' ,CASE t0.MoType WHEN 2 THEN t0.单位工时B ELSE 0 END '试制D' ,CASE t0.MoType WHEN 3 THEN t0.单位工时B ELSE 0 END '返工E' ,CASE t0.MoType WHEN 4 THEN t0.单位工时B ELSE 0 END '返工试制F' ,CASE t0.MoType WHEN 0 THEN t0.单位工时B ELSE 0 END '其他G' ,CASE t0.MoType WHEN 1 THEN t0.单位工时B * t0.入库数量A ELSE 0 END '普通I=C*A' ,CASE t0.MoType WHEN 2 THEN t0.单位工时B * t0.入库数量A ELSE 0 END '试制J=D*A' ,CASE t0.MoType WHEN 3 THEN t0.单位工时B * t0.入库数量A ELSE 0 END '返工K=E*A' ,CASE t0.MoType WHEN 4 THEN t0.单位工时B * t0.入库数量A ELSE 0 END '返工试制L=F*A' ,CASE t0.MoType WHEN 0 THEN t0.单位工时B * t0.入库数量A ELSE 0 END '其他M=G*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 ,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 *--,t0.直接材料 +t0.FO1 + t0.FO2 + t0.FO3 + t0.FO4 + t0.FO5 + t0.FO6 + t0.FO7 + t0.FO8 + t0.FO9 + t0.FO10 + t0.FO11 + t0.FO12 + t0.FO13 + t0.FO14 + t0.FO15 + t0.FO16 AS '材料成本' 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 ) SELECT t0.MoBillNo ,t0.PMoBillNo ,t0.aPATH ,t0.PPATH --,t0.MPath ,t0.QtyRatio,t0.生产数量,t0.领料数量 ,t3.FNUMBER AS '产品编码',t3_l.FNAME AS '产品名称',t3_l.FSPECIFICATION AS '产品规格型号' ,t1.FNUMBER AS '物料编码',t1_l.FNAME AS '物料名称',t1_l.FSPECIFICATION AS '物料规格型号' ,CASE t1b.FERPCLSID WHEN 1 THEN '外购' WHEN 2 THEN '自制' WHEN 3 THEN '委外' WHEN 5 THEN '虚拟' ELSE '' END AS '物料属性' ,t0.批号 ,(CASE t0.直接材料 WHEN 0 THEN t0.P1 ELSE t0.直接材料 END) AS '领料成本' ,t2.直接材料 ,t2.O0 ,t0.FO1 + t0.FO2 + t0.FO3 + t0.FO4 + t0.FO5 + t0.FO6 + t0.FO7 + t0.FO8 + t0.FO9 + t0.FO10 + t0.FO11 + t0.FO12 + t0.FO13 + t0.FO14 + t0.FO15 + t0.FO16 AS O0 ,t0.FO1 + t0.FO2 + t0.FO3 + t0.FO4 + t0.FO5 + t0.FO6 + t0.FO7 + t0.FO8 + t0.FO9 + t0.FO10 + t0.FO11 + t0.FO12 + t0.FO13 + t0.FO14 + t0.FO15 AS O02 ,t2.O0 AS 'OO1' ,(t0.P1 + t0.P2 + t0.P3 + t0.P4 + t0.P5 + t0.P6 + t0.P7 + t0.P8 + t0.P9 + t0.P10 + t0.P11 + t0.P12) AS P0 ,(t0.P2 + t0.P3 + t0.P4 + t0.P5 + t0.P6 + t0.P7 + t0.P8 + t0.P9 + t0.P10 + t0.P11 + t0.P12) AS P01 ,(t0.FO1 + t0.FO2 + t0.FO3 + t0.FO4 + t0.FO5 + t0.FO6 + t0.FO7 + t0.FO8 + t0.FO9 + t0.FO10 + t0.FO11 + t0.FO12 + t0.FO13 + t0.FO14 + t0.FO15 + t0.FO16) AS O02 ,t0.P1,t0.P2,t0.P3,t0.P4,t0.P5,t0.P6,t0.P7,t0.P8,t0.P9,t0.P10,t0.P11,t0.P12 ,t0.FO1 AS 直接人工 --AS O1 ,t0.FO2 AS 职工薪酬 --AS O2 ,t0.FO3 AS 股份支付 --AS O3 ,t0.FO4 AS 劳动保护费 --AS O4 ,t0.FO5 AS 差旅费 --AS O5 ,t0.FO6 AS 业务招待费 --AS O6 ,t0.FO7 AS 办公费 --AS O7 ,t0.FO8 AS 折旧与摊销 --AS O8 ,t0.FO9 AS 租赁费 --AS O9 ,t0.FO10 AS 水电费 --AS O10 ,t0.FO11 AS 物料消耗费 --AS O11 ,t0.FO12 --AS [加工、修理、检测费] ,t0.FO13 AS 车辆使用费 --AS O13 ,t0.FO14 --AS [制造费用-其他] ,t0.FO15 AS '材料成本' ,t0.FO16 ,t0.入库数量A --AS A ,t0.单位工时B --AS B ,t2.C AS [普通C] ,t2.D AS [试制D] ,t2.E AS [返工E] ,t2.F AS [返工试制F] ,t2.G AS [其他G] ,t2.C + t2.D +t2.E + t2.F + t2.G AS H--[合计H=C+D+E+F+G] ,t2.I --AS [普通I=C*A] ,t2.J --AS [试制J=D*A] ,t2.K --AS [返工K=E*A] ,t2.L --AS [返工试制L=F*A] ,t2.M --AS [其他M=G*A] ,t2.I + t2.J + t2.K + t2.L + t2.M AS N--[合计N=I+J+K+L+M] ,t0.lv ,MoId,MoEntryId,PMoId,PMoEntryId,PMoMaterialId,TopMaterialId,MoMaterialId,t0.FMATERIALID FROM #关联项目费用临时表 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 INNER JOIN #统计 t2 on t0.aPATH = t2.aPATH INNER JOIN T_BD_MATERIAL t3 on t0.TopMaterialId = t3.FMATERIALID INNER JOIN T_BD_MATERIAL_L t3_l on t0.TopMaterialId = t3_l.FMATERIALID AND t3_l.FLOCALEID = 2052 OUTER APPLY ( SELECT SUM(t4.P1 + t4.P2 + t4.P3 + t4.P4 + t4.P5 + t4.P6 + t4.P7 + t4.P8 + t4.P9 + t4.P10 + t4.P11 + t4.P12) '成本' ,SUM(t4.P2) AS '间接材料' FROM #关联项目费用临时表 t4 WHERE t4.PPATH = t0.aPATH GROUP BY t4.PPATH ) t4 WHERE 1 = 1 ORDER BY CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID) DROP TABLE ##查找对应工单 DROP TABLE #关联项目费用临时表