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

266 lines
11 KiB
Transact-SQL

--WO2405090020
declare @Level int
;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
,t0e_a.FSTOCKINQUASELAUXQTY AS '入库数量'
,t0e_a.FSTATUS
,CHARINDEX(t0.FBILLNO,'SUB') AS 'oType'
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 = 'RO2405090020'
--AND t0.FBILLNO = 'TO2405210015'
--AND t0.FBILLNO = 'WO2405160002'
--AND t0.FBILLNO = 'WO2405080005'
--AND t0.FBILLNO = 'TO2404290033'
--AND t0.FBILLNO = 'TO2403250007'
)
,#生产领料单 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.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.oType
,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
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.oType,-1)
,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 #TABLE1 tt
CROSS APPLY (
SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
--,t0e_a.FSTOCKINQUASELAUXQTY AS '入库数量'
,CONVERT(decimal(23,10),0) AS '入库数量'
,0 AS 'FSTATUS'
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID,t1.oType
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
--LEFT JOIN T_PRD_MOENTRY_A t0e_a on t0e.FENTRYID = t0e_a.FENTRYID
WHERE t1.FMOENTRYID = tt.MoEntryId
AND tt.oType = t1.oType
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,t1.oType
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.oType = t1.oType
) t0
WHERE 1=1
AND tt.isTrue = 0
--AND tt.lv < 10
)
, #table2 AS (
SELECT FID AS 'MoId',FENTRYID AS 'MoEntryId',FBILLNO AS 'MoBillNo'
,0 AS 'PMoId'
,0 AS 'PMoEntryId'
,'' AS 'PMoBillNo'
,TopMaterialId,TopMaterialId AS 'MoMaterialId',FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT,入库数量,FSTATUS,aPATH,'' AS 'PPATH',lv,oType
--,CONCAT('/',aPATH,'/') RnPath
--,(CASE LEFT(FBILLNO,2) WHEN 'WO' THEN 1 WHEN 'RO' THEN 2 WHEN 'TO' THEN 3 WHEN 'RT' THEN 4 ELSE 0 END) AS 'MoType'
FROM #TopMo
UNION ALL
SELECT MoId,MoEntryId,MoBillNo,PMoId,PMoEntryId,PMoBillNo
,TopMaterialId,MoMaterialId,FMATERIALID,FLOT,FLOT_TEXT,FAMOUNT,入库数量,FSTATUS,aPATH,PPATH,lv,oType
--,CONCAT('/',REPLACE(aPATH,'.','/'),'/') RnPath
--,(CASE LEFT(MoBillNo,2) WHEN 'WO' THEN 1 WHEN 'RO' THEN 2 WHEN 'TO' THEN 3 WHEN 'RT' THEN 4 ELSE 0 END) AS 'MoType'
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
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
)
, #table3 AS (
SELECT MoBillNo,PMoBillNo
,MoId,MoEntryId,PMoId,PMoEntryId,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 AS '批号',aPATH,PPATH,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 '直接材料'
,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.oType WHEN 0 THEN ISNULL(t0e.FSTOCKINQUASELAUXQTY ,0) ELSE t0.入库数量 END AS '入库数量A'
,CASE t0.oType WHEN 0 THEN ISNULL(t0e.FSTATUS ,0) ELSE t0.FSTATUS END AS '业务状态'
FROM #table2 t0
LEFT JOIN T_PRD_MOENTRY_A t0e on t0.MoEntryId = t0e.FENTRYID
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.MoEntryId
)
, #table4 AS (
SELECT t0.MoBillNo
,t0.PMoBillNo
,t0.aPATH
,t0.PPATH
,t0.lv
,t0.批号
,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,PMoId,PMoEntryId,TopMaterialId,MoMaterialId,t0.FMATERIALID
FROM #table3 t0
)
,#统计 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'
,t0.aPATH
FROM #table4 t0
INNER JOIN #table4 t1 ON CHARINDEX(t0.aPATH,t1.aPATH) = 1
GROUP BY t0.aPATH
)
SELECT t0.MoBillNo
,t0.PMoBillNo
--,t0.FNUMBER,t0.FNAME,t0.物料属性
,t1.FNUMBER,t1_l.FNAME
,CASE t1b.FERPCLSID WHEN 1 THEN '外购' WHEN 2 THEN '自制' WHEN 3 THEN '委外' WHEN 5 THEN '虚拟' ELSE '' END AS '物料属性'
,t0.批号
,t0.业务状态
,t0.直接材料
,t0.入库数量A
,t0.单位工时B
,t2.C AS [普通C]
,t2.D [试制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=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=I+J+K+L+M]
,t0.aPATH
,t0.PPATH
,t0.lv
,MoId,MoEntryId,PMoId,PMoEntryId,TopMaterialId,MoMaterialId,t0.FMATERIALID
FROM #table4 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
--ORDER BY CAST(t0.RnPath AS HIERARCHYID)
ORDER BY CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID)