Files
GateDge2023_ljy/07.珠海英搏尔/Enpower.Python/产品成本还原报表V4.0_存储过程.sql
PastSaid fa480006a8 1
2024-07-16 10:33:50 +08:00

385 lines
16 KiB
PL/PgSQL

--EXEC PROC_CB_PRODUCT_COST_SELECT '',''
ALTER PROCEDURE PROC_CB_PRODUCT_COST_SELECT
@billNo varchar(100)
,@materialNumber varchar(100)
AS
BEGIN
;WITH #SelectMo AS (
SELECT t0.FBILLNO,t0.FID,t0e.FENTRYID,t0e.FMATERIALID AS TopMaterialId,t0e.FMATERIALID
,t0.FFORMID AS 'FFORMID'
,t0e_a.FSTOCKINQUASELAUXQTY AS '入库数量',t0e_a.FSTATUS
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
WHERE 1 = 1
AND t0.FBILLNO = @billNo
UNION
SELECT t0.FBILLNO,t0.FID,t0e.FENTRYID,t0e.FMATERIALID AS TopMaterialId,t0e.FMATERIALID
,t0.FFORMID AS 'FFORMID',t0e_a.FSTOCKINQUASELAUXQTY AS '入库数量'
,t0e_a.FSTATUS
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
AND t1.FNUMBER = @materialNumber
)
,#TopMo AS (
SELECT t0.*
,CONVERT(varchar(1000),ROW_NUMBER() OVER (ORDER BY t0.FID,t0.FMATERIALID)) AS 'aPATH'
,0 AS 'FLOT',CAST('' AS nvarchar(255)) AS 'FLOT_TEXT',CONVERT(decimal(23,10), 0) AS 'FAMOUNT',0 'lv'
FROM #SelectMo t0
)
,# AS (
SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'PRD_MO' AS 'FFORMID'
,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','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 t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID'
,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','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 t0.FMATERIALID AS 'TopMaterialId'
,t0.FMATERIALID AS 'MoMaterialId'
,t1e.FMATERIALID
,t1e.FLOT
,t1e.FLOT_TEXT
,t1e.FAMOUNT
,CONVERT(decimal(23,10),0) AS '入库数量'
,0 AS 'FSTATUS'
,CONVERT(varchar(1000),CONCAT(t0.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY t0.FID,t0.FENTRYID ORDER BY t1e.FMATERIALID))) AS 'aPATH'
,t0.aPATH AS 'PPATH'
,t0.lv + 1 lv
,t0.FFORMID
,t1e.MoId AS 'MoId'
,t1e.MoEntryId AS 'MoEntryId'
,t1e.MoBillNo AS 'MoBillNo'
,t0.FID AS 'PMoId'
,t0.FENTRYID AS 'PMoEntryId'
,t0.FBILLNO AS 'PMoBillNo'
,0 AS 'isTrue'
FROM #TopMo t0
CROSS APPLY (
SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,SUM(t1e.FAMOUNT) AS 'FAMOUNT'
,ISNULL(t2.FID,0) AS 'MoId',ISNULL(t2e.FENTRYID,0) AS 'MoEntryId',ISNULL(t2.FBILLNO,'') AS 'MoBillNo'
FROM T_PRD_PICKMTRLDATA t1e
LEFT JOIN T_PRD_MO t2 on t2.FBILLNO = t1e.FLOT_TEXT AND t2.FDOCUMENTSTATUS = 'C'
LEFT JOIN T_PRD_MOENTRY t2e on t2e.FID = t2.FID
WHERE t1e.FMOENTRYID = t0.FENTRYID
GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,t2.FID,t2e.FENTRYID,t2.FBILLNO
) t1e
UNION ALL
SELECT tt.TopMaterialId
,ISNULL(t0.MoMaterialId,'')
,t0.FMATERIALID
,t0.FLOT
,t0.FLOT_TEXT
,t0.FAMOUNT
,ISNULL(t0.,0) AS '入库数量'
,t0.FSTATUS
,CONVERT(varchar(1000),CONCAT(tt.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY tt.MoId,tt.MoEntryId ORDER BY t0.FMATERIALID))) AS 'aPATH'
,tt.aPATH
,tt.lv + 1 lv
,ISNULL(t0.FFORMID,'')
,ISNULL(t0.FID,0) AS 'MoId'
,ISNULL(t0.FENTRYID,0) AS 'MoEntryId'
,ISNULL(t0.FBILLNO,'') AS 'MoBillNo'
,tt.MoId AS 'PMoId'
,tt.MoEntryId AS 'PMoEntryId'
,tt.MoBillNo AS 'PMoEntryId'
,CASE WHEN t0.FBILLNO = tt.MoBillNo THEN 1 ELSE 0 END AS 'isTrue'
FROM # tt
CROSS APPLY (
SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
,CONVERT(decimal(23,10),0) AS '入库数量'
,0 AS 'FSTATUS'
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID,CONVERT(varchar(36),t1.FFORMID) AS 'FFORMID'
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
WHERE t1.FMOENTRYID = tt.MoEntryId
AND tt.FFORMID = t1.FFORMID
UNION ALL
SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
,t0e.FSTOCKINQTY,t0e.FSTATUS
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID,CONVERT(varchar(36),t1.FFORMID) AS 'FFORMID'
FROM # t1
INNER JOIN T_SUB_REQORDER t0 on t0.FBILLNO = t1.FLOT_TEXT
INNER JOIN T_SUB_REQORDERENTRY t0e on t0.FID = t0e.FID
WHERE t1.FMOENTRYID = tt.MoEntryId
AND tt.FFORMID = t1.FFORMID
) t0
WHERE 1=1
AND tt.isTrue = 0
)
, # AS (
SELECT FID AS 'MoId',FENTRYID AS 'MoEntryId',FBILLNO AS 'MoBillNo'
,0 AS 'PMoId'
,0 AS 'PMoEntryId'
,FBILLNO AS 'PMoBillNo'
,TopMaterialId,TopMaterialId AS 'MoMaterialId',FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT
,,FSTATUS,aPATH,'' AS 'PPATH',lv,FFORMID
FROM #TopMo
UNION ALL
SELECT MoId,MoEntryId,MoBillNo,PMoId,PMoEntryId,PMoBillNo
,TopMaterialId,MoMaterialId,FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT,,FSTATUS,aPATH,PPATH,lv,FFORMID
FROM #
)
, # 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 t2.FNAME
--,t0_L.FNAME
,ISNULL(t0.FEXPID,0) AS 'FEXPID'
FROM T_BD_EXPENSE t0
INNER JOIN T_BD_EXPENSE_L t0_L on t0.FEXPID = t0_L.FEXPID AND t0_L.FLOCALEID = 2052
RIGHT JOIN (
SELECT '直接人工' AS 'FNAME'
UNION ALL SELECT '职工薪酬'
UNION ALL SELECT '股份支付'
UNION ALL SELECT '劳动保护费'
UNION ALL SELECT '差旅费'
UNION ALL SELECT '业务招待费'
UNION ALL SELECT '办公费'
UNION ALL SELECT '折旧与摊销'
UNION ALL SELECT '租赁费'
UNION ALL SELECT '水电费'
UNION ALL SELECT '物料消耗'
UNION ALL SELECT '加工、修理、检测费'
UNION ALL SELECT '车辆使用费'
UNION ALL SELECT '制造费用-其他'
) t2 on CHARINDEX(t2.FNAME ,t0_L.FNAME) > 0
)
, # AS (
SELECT
t0.aPATH
,SUM(t2.FAMOUNT) famount
,t4_l.FNAME AS '费用项目'
,' ' fsourcebilltypename
FROM # t0
INNER JOIN T_CB_PROORDERDIME t1 ON t1.FBILLID = t0.MoId
AND t1.FFORMID = t0.FFORMID AND t0.MoEntryId = t1.FBILLENTRYID
INNER JOIN V_CB_EXPALLORESULTREC t2 on t2.FPRODUCTDIMEID = t1.FPRODUCTDIMEID
INNER JOIN V_CB_EXPALLORESULTSEND t3 on t3.FSENDID = t2.FSENDID
INNER JOIN # t4_l on t4_l.FEXPID = t2.FEXPENSEITEMID
WHERE 1 = 1
AND t0.MoEntryId != 0
GROUP BY t1.FCOSTCENTERID
,t2.FCOSTCENTERID,t2.FCostItemId,t2.FEXPENSEITEMID
,t4_l.FNAME
,t0.aPATH
)
, # AS (
SELECT *
FROM # t0
PIVOT
(
SUM(t0.famount)
FOR
t0. IN ([],[],[],[],[],[],[],[],[],[],[],[],[使],[-])
) AS t1
)
, # AS (
SELECT MoBillNo,PMoBillNo
,MoId,MoEntryId,PMoId,PMoEntryId,TopMaterialId,MoMaterialId,t0.FMATERIALID
,t0.FLOT,t0.FLOT_TEXT AS '批号',aPATH,PPATH,lv,t0.FFORMID
--,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.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 '直接材料2'
,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'
,CASE t0.FFORMID WHEN 'PRD_MO' THEN ISNULL(t0e.FSTATUS ,0) ELSE t0.FSTATUS END AS '业务状态'
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.lv
,t0.
,t0.
,t0.2
,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,PMoId,PMoEntryId,TopMaterialId,MoMaterialId,t0.FMATERIALID
,ISNULL(t7.,0) AS '办公费'
,ISNULL(t7.,0) AS '差旅费'
,ISNULL(t7.使,0) AS '车辆使用费'
,ISNULL(t7.,0) AS '股份支付'
,ISNULL(t7.[],0) AS '加工、修理、检测费'
,ISNULL(t7.,0) AS '劳动保护费'
,ISNULL(t7.,0) AS '水电费'
,ISNULL(t7.,0) AS '物料消耗费'
,ISNULL(t7.,0) AS '业务招待费'
,ISNULL(t7.,0) AS '折旧与摊销'
,ISNULL(t7.,0) AS '直接人工'
,ISNULL(t7.,0) AS '职工薪酬'
,ISNULL(t7.,0) AS '租赁费'
,ISNULL(t7.[-],0) AS '制造费用-其他'
,ISNULL(t7.,0) +ISNULL(t7.,0) +ISNULL(t7.使,0) +ISNULL(t7.,0)
+ISNULL(t7.[],0)+ISNULL(t7.,0)+ISNULL(t7.,0) +ISNULL(t7.,0)
+ISNULL(t7.,0) +ISNULL(t7.,0) +ISNULL(t7.,0)+ISNULL(t7.,0)
+ISNULL(t7.,0) +ISNULL(t7.[-],0) AS '成本计算'
FROM # t0
LEFT JOIN # t7 on t7.aPATH = t0.aPATH
)
SELECT * INTO # FROM #
;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.) AS '办公费'
,SUM(t1.) AS '差旅费'
,SUM(t1.使) AS '车辆使用费'
,SUM(t1.) AS '股份支付'
,SUM(t1.[]) AS '加工、修理、检测费'
,SUM(t1.[-]) AS '制造费用-其他'
,SUM(t1.) AS '劳动保护费'
,SUM(t1.) AS '水电费'
,SUM(t1.) AS '物料消耗费'
,SUM(t1.) AS '业务招待费'
,SUM(t1.) AS '折旧与摊销'
,SUM(t1.) AS '直接人工'
,SUM(t1.) AS '职工薪酬'
,SUM(t1.) AS '租赁费'
,t0.aPATH
FROM # t0
INNER JOIN # t1 ON t0.lv <= t1.lv AND CHARINDEX(t0.aPATH,t1.aPATH) = 1
GROUP BY t0.aPATH
)
SELECT t0.MoBillNo
,t0.PMoBillNo
,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.
,t0.
--,t0.直接材料
,t2. + t2. +t2. +t2.+t2.+t2.+t2.+t2.+t2.+t2.+t2.+t2.+t2.[] + t2.使 +t2.[-] AS O0
--,t0.直接材料2 + t0.直接人工 +t0.职工薪酬 +t0.股份支付+t0.劳动保护费+t0.差旅费+t0.业务招待费+t0.办公费+t0.折旧与摊销+t0.租赁费+t0.水电费+t0.物料消耗费+t0.[加工、修理、检测费] + t0.车辆使用费 +t0.[制造费用-其他] AS O02
,t0. + t01.2 AS 'O02'
,t2.
,t0.2
,t2. --AS O1
,t2. --AS O2
,t2. --AS O3
,t2. --AS O4
,t2. --AS O5
,t2. --AS O6
,t2. --AS O7
,t2. --AS O8
,t2. --AS O9
,t2. --AS O10
,t2. --AS O11
,t2.[] AS O12
,t2.使 --AS O13
,t2.[-]
,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.aPATH
,t0.PPATH
,t0.lv
,MoId,MoEntryId,PMoId,PMoEntryId,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
LEFT JOIN (
SELECT tt.PPATH,SUM(tt.2) AS '直接材料2'
FROM # tt
GROUP BY tt.PPATH
) t01 on t01.PPATH = t0.aPATH
ORDER BY CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID)
DROP TABLE #
END