Files
GateDge2023_ljy/07.珠海英搏尔/Enpower.Python/产品成本还原汇总表(不分解)V1.0_20240802.sql
PastSaid 5472714e30 aa
2024-08-29 09:42:49 +08:00

145 lines
6.2 KiB
Transact-SQL

DECLARE @period int
DECLARE @dbName varchar(100)
DECLARE @ACCTGORGID int
DECLARE @billNo varchar(100)
SET @ACCTGORGID = 1
;WITH #列表数据 AS (
SELECT t0.FPRODUCTNO
,t0.FBILLID
,t0.FBILLENTRYID
,t0.FPRODUCTID
,t0.FFORMID
,t1.FPRODUCTDIMEID
,t3.FQUALIFIEDINQTY AS '本期完工数量'
,t3.FCURRINPUTQTY AS '本期投入数量'
,t3.FSUMCURRINPUTQTY AS '累计投入数量'
,t3.FSUMQUALIFIEDINQTY AS '累计完工数量'
,RANK() OVER (PARTITION BY t0.FBILLID,t0.FBILLENTRYID ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN'
,(t2.FYEAR * 100 + t2.FPERIOD) AS 'FPERIOD'
FROM T_CB_PROORDERDIME t0
INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID
INNER JOIN V_HS_OUTACCTG t2 on t1.FACCTGID = t2.FID
LEFT JOIN V_CB_COSTCALEXPENSE t3 on t3.FID = t1.FID
WHERE 1 = 1
AND t2.FACCTGORGID = @ACCTGORGID
AND t2.FCOMPUTEID != ''
--{1}
AND t2.FYEAR = 2023
AND t1.FENDINITKEY = 1
AND t0.FFORMID = 'PRD_MO'
--{0}
)
,#初始数据 AS (
SELECT t0.FPRODUCTNO
,t0.FBILLID
,t0.FBILLENTRYID
,t0.FPRODUCTID
,t0.FFORMID
,t0.本期完工数量
,t0.本期投入数量
,t1.FPRODUCTDIMEID
,t3.FEXPTYPE
,t3.FCURRINPUTQTY
,t3.FQUALIFIEDINQTY
,t3d.FCURRINPUTAMOUNT
,t3d.FCOSTITEMID
,t3d.FEXPENSESITEMID
,t3d.FQUALIFIEDINAMOUNT
FROM #列表数据 t0
INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID
INNER JOIN V_HS_OUTACCTG t2 on t1.FACCTGID = t2.FID
AND (t2.FYEAR * 100 + t2.FPERIOD) <= t0.FPERIOD
LEFT JOIN V_CB_COSTMATTERIAL t3 on t3.FID = t1.FID
LEFT JOIN V_CB_COSTMATTERIALDETAIL t3d on t3d.FENTRYID = t3.FENTRYID
WHERE 1 = 1
AND t0.RN = 1
AND t2.FACCTGORGID = @ACCTGORGID
AND t2.FCOMPUTEID != ''
AND t1.FENDINITKEY = 1
AND t0.FFORMID = 'PRD_MO'
)
, #成本转换 AS (
SELECT t1.FPRODUCTNO,t1.FPRODUCTID,t1.FPRODUCTDIMEID,t1.FBILLID,t1.FBILLENTRYID--,t1.FMATERIALID
,t1.FEXPTYPE
,t1.FCURRINPUTAMOUNT,t1.本期完工数量,t1.本期投入数量,t1.FQUALIFIEDINQTY
,t1.O0,t1.O1,t1.O2,t1.O3,t1.O4,t1.O5,t1.O6,t1.O7,t1.O8,t1.O9,t1.O10,t1.O11,t1.O12,t1.O13,t1.O14,t1.O15
FROM (
SELECT t0.FPRODUCTNO,t0.FPRODUCTID,t0.FPRODUCTDIMEID,t0.FBILLID,t0.FBILLENTRYID
,t0.FQUALIFIEDINAMOUNT,t0.FCURRINPUTAMOUNT,t0.FEXPTYPE
,t0.FQUALIFIEDINQTY
,t0.本期完工数量,t0.本期投入数量
,t1.fieldName
FROM #初始数据 t0
LEFT JOIN V_BD_COST_RESTORE_EXPENSE_V2 t1 on t0.FEXPENSESITEMID = t1.FEXPID
) t0
PIVOT
(
SUM(t0.FQUALIFIEDINAMOUNT) FOR
t0.fieldName IN (O0,O1,O2,O3,O4,O5,O6,O7,O8,O9,O10,O11,O12,O13,O14,O15)
) AS t1
)
, #物料属性 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'
)
SELECT t0.FPRODUCTNO,t0.FPRODUCTID,t0.FPRODUCTDIMEID
,ROW_NUMBER() OVER (ORDER BY t0.FPRODUCTNO) FRN
,t0.FBILLID,t0.FBILLENTRYID
,t3_l.FNAME,t3.FNUMBER
,t1.本期投入数量
,t1.本期完工数量
,t1.累计投入数量
,t1.累计完工数量
,t0.累计投入成本
,t0.总工时
,t0.材料成本Q + t0.制造费用O + t0.直接人工S AS '料工费R'
,t0.原材料Q1
,t0.直接人工S AS '直接人工S'
,t0.直接人工S1
,t0.间接人工S2
,t0.制造费用O + t0.间接材料Q2 AS '制造费用O'
,t0.间接材料Q2
,t0.制造费用_职工薪酬,t0.制造费用_股份支付,t0.制造费用_劳动保护费,t0.制造费用_差旅费,t0.制造费用_业务招待费,t0.制造费用_办公费,t0.制造费用_折旧与摊销,t0.制造费用_租赁费,t0.制造费用_水电费,t0.制造费用_物料消耗,t0.制造费用_加工_修理_检测费,t0.制造费用_车辆使用费
,t0.制造费用_其他 AS '制造费用_其他'
,t0.制造费用_委外加工费
FROM ( SELECT t0.FPRODUCTNO,t0.FPRODUCTID,t0.FPRODUCTDIMEID
,t0.FBILLID,t0.FBILLENTRYID
--,AVG(t0.本期完工数量) AS '本期完工数量'
--,AVG(t0.本期投入数量) AS '本期投入数量'
,SUM(CASE t0.FEXPTYPE WHEN 9 THEN ISNULL(t0.FQUALIFIEDINQTY,0) ELSE 0 END) AS '总工时'
,SUM(ISNULL(t0.FCURRINPUTAMOUNT,0)) AS '累计投入成本'
,SUM(ISNULL(t0.O0,0)) AS '直接人工S'
,SUM(CASE t0.FEXPTYPE WHEN 0 THEN ISNULL(t0.O0,0) ELSE 0 END) AS '直接人工S1'
,SUM(CASE WHEN t0.FEXPTYPE != 0 THEN ISNULL(t0.O0,0) ELSE 0 END) AS '间接人工S2'
,SUM(ISNULL(t0.O1,0)) AS '材料成本Q'
,SUM(CASE t0.FEXPTYPE WHEN 0 THEN ISNULL(t0.O1,0) ELSE 0 END) AS '原材料Q1'
,SUM(CASE WHEN t0.FEXPTYPE != 0 THEN ISNULL(t0.O1,0) ELSE 0 END) AS '间接材料Q2'
,SUM(ISNULL(t0.O2,0) + ISNULL(t0.O3,0)+ISNULL(t0.O4,0)+ISNULL(t0.O5,0)+ISNULL(t0.O6,0)+ISNULL(t0.O7,0)+ISNULL(t0.O8,0)+ISNULL(t0.O9,0)+ISNULL(t0.O10,0)+ISNULL(t0.O11,0)+ISNULL(t0.O12,0)+ISNULL(t0.O13,0)+ISNULL(t0.O14,0)+ISNULL(t0.O15,0)) AS '制造费用O'
,SUM(ISNULL(t0.O2,0)) AS '制造费用_职工薪酬'
,SUM(ISNULL(t0.O3,0)) AS '制造费用_股份支付'
,SUM(ISNULL(t0.O4,0)) AS '制造费用_劳动保护费'
,SUM(ISNULL(t0.O5,0)) AS '制造费用_差旅费'
,SUM(ISNULL(t0.O6,0)) AS '制造费用_业务招待费'
,SUM(ISNULL(t0.O7,0)) AS '制造费用_办公费'
,SUM(ISNULL(t0.O8,0)) AS '制造费用_折旧与摊销'
,SUM(ISNULL(t0.O9,0)) AS '制造费用_租赁费'
,SUM(ISNULL(t0.O10,0)) AS '制造费用_水电费'
,SUM(ISNULL(t0.O11,0)) AS '制造费用_物料消耗'
,SUM(ISNULL(t0.O12,0)) AS '制造费用_加工_修理_检测费'
,SUM(ISNULL(t0.O13,0)) AS '制造费用_车辆使用费'
,SUM(ISNULL(t0.O14,0)) AS '制造费用_其他'
,SUM(ISNULL(t0.O15,0)) AS '制造费用_委外加工费'
FROM #成本转换 t0
GROUP BY t0.FPRODUCTNO,t0.FPRODUCTID
,t0.FPRODUCTDIMEID
,t0.FBILLID,t0.FBILLENTRYID
) t0
INNER JOIN #列表数据 t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t1.RN = 1
INNER JOIN T_BD_MATERIAL t3 on t0.FPRODUCTID = t3.FMATERIALID
INNER JOIN T_BD_MATERIAL_L t3_l on t3_l.FMATERIALID = t0.FPRODUCTID AND t3_l.FLOCALEID = 2052