Files
GateDge2023_ljy/07.珠海英搏尔/Enpower.Python/产品成本还原报表V9.2_20240819.sql
PastSaid 5472714e30 aa
2024-08-29 09:42:49 +08:00

366 lines
14 KiB
PL/PgSQL

IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#查询结果') IS NOT NULL)
BEGIN
DROP TABLE [dbo].[#]
END
DECLARE @period int
DECLARE @dbName varchar(100)
DECLARE @ACCTGORGID int
DECLARE @billNo varchar(100)
SET @ACCTGORGID = 100039
SET @period = 201801
SET @billNo = 'MO000019'
SELECT @dbName = DB_NAME()
IF @dbName != 'AIS20231110222743'
BEGIN
SET @period = 202407
--SET @period = 202308
SET @ACCTGORGID = 1
--SET @billNo = 'WO2403210039'
--SET @billNo = 'WO2403210048'
SET @billNo = 'WO2304230023'
--SET @billNo = 'WO2405290121'
--SET @billNo = 'WO2406220013'
--SET @billNo = 'TO2302060061'
--SET @billNo = 'WO2311020005'
--SET @billNo = 'WO2312050303'
--SET @billNo = 'WO2403270354'
--SET @billNo = 'WO2406050001'
--SET @billNo = 'WO2404170154'
END
CREATE TABLE #(
[FPRODUCTNO] nvarchar(255) COLLATE Chinese_PRC_CI_AS NOT NULL,
[FBILLID] int NOT NULL,
[FBILLENTRYID] int NOT NULL,
[FPRODUCTID] int NOT NULL,
[FPRODUCTDIMEID] int NOT NULL,
[FMATERIALID] int NOT NULL,
[FEXPTYPE] char(1) COLLATE Chinese_PRC_CI_AS NOT NULL,
[使] decimal(23,10) NOT NULL,
[S] decimal(23,10) NOT NULL,
--[间接人工S2] decimal(23,10) NOT NULL,
[Q] decimal(23,10) NOT NULL,
--[间接材料Q2] decimal(23,10) NOT NULL,
[_职工薪酬] decimal(23,10) NOT NULL,
[_股份支付] decimal(23,10) NOT NULL,
[_劳动保护费] decimal(23,10) NOT NULL,
[_差旅费] decimal(23,10) NOT NULL,
[_业务招待费] decimal(23,10) NOT NULL,
[_办公费] decimal(23,10) NOT NULL,
[_折旧与摊销] decimal(23,10) NOT NULL,
[_租赁费] decimal(23,10) NOT NULL,
[_水电费] decimal(23,10) NOT NULL,
[_物料消耗] decimal(23,10) NOT NULL,
[_加工_修理_检测费] decimal(23,10) NOT NULL,
[_车辆使用费] decimal(23,10) NOT NULL,
[_其他] decimal(23,10) NOT NULL,
[_委外加工费] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[] decimal(23,10) NOT NULL,
[FAMOUNT] decimal(23,10) NULL,
[FQTY] decimal(23,10) NULL,
[FLOT] int NULL,
[FPERIOD] int NULL,
[FNUMBER] nvarchar(255) COLLATE Chinese_PRC_CI_AS NULL,
[SubBillId] int NULL,
[SubBillEntryId] int NULL,
[SubPRODUCTDIMEID] int NULL,
[MPATH] nvarchar(MAX) COLLATE Chinese_PRC_CI_AS NOT NULL,
[FGOON] int NOT NULL,
[FLEVEL] int not null
)
CREATE INDEX idx_查询结果_fuhesuoyin ON #([SubBillEntryId]);
;WITH # AS (
SELECT t0.FPRODUCTNO
,t0.FBILLID
,t0.FBILLENTRYID
,t0.FPRODUCTID
,t0.FFORMID
,t3.FMATERIALID
,t1.FPRODUCTDIMEID
,t3.FEXPTYPE
,t3.FSUMCURRINPUTAMOUNT '物料投入成本'
,t3.FSUMQUALIFIEDINAMOUNT '物料完工成本'
,t4.FSUMCURRINPUTAMOUNT '产品投入成本'
,t4.FSUMQUALIFIEDINAMOUNT '产品完工成本'
,t3.FSUMCURRINPUTQTY '物料投入数量'
,CAST(t3.FSUMQUALIFIEDINQTY AS decimal(23,10)) '物料完工数量'
,t4.FSUMCURRINPUTQTY '产品投入数量'
,t4.FSUMQUALIFIEDINQTY '产品完工数量'
,CONCAT(t0.FPRODUCTNO,'_') AS 'MPATH'
,(t2.FYEAR * 100 + t2.FPERIOD) AS 'FPERIOD'
,RANK() OVER (ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN'
,t3d.FQUALIFIEDINAMOUNT AS '物料完工费用'
,t5.fieldName
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
INNER JOIN V_CB_COSTMATTERIAL t3 on t3.FID = t1.FID
LEFT JOIN V_CB_COSTMATTERIALDETAIL t3d on t3d.FENTRYID = t3.FENTRYID
INNER JOIN V_CB_COSTCALEXPENSE t4 on t4.FID = t3.FID
LEFT JOIN V_BD_COST_RESTORE_EXPENSE_V2 t5 on t3d.FEXPENSESITEMID = t5.FEXPID
WHERE 1 = 1
AND t0.FPRODUCTNO = @billNo
AND t2.FACCTGORGID = @ACCTGORGID
AND t2.FCOMPUTEID != ''
AND (t2.FYEAR * 100 + t2.FPERIOD) <= @period
AND t1.FENDINITKEY = 1
AND t4.FSUMQUALIFIEDINQTY != 0
)
, # AS (
SELECT *
FROM # t0
PIVOT (
SUM(t0.) FOR
t0.fieldName IN (O0,O1,O2,O3,O4,O5,O6,O7,O8,O9,O10,O11,O12,O13,O14,O15)
) t1
)
INSERT INTO #
SELECT t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID
,t0.FPRODUCTDIMEID
,t0.FMATERIALID
,t0.FEXPTYPE
,CASE WHEN (t0.FEXPTYPE = 0 AND ISNULL(t4.FLOT,0)!= 0) AND t0. != 0 THEN (ISNULL(t4.FAMOUNT, 0) / t0.) ELSE 1 END '使用比例'
--,CASE t0.FEXPTYPE WHEN 0 THEN ISNULL(t0.O1,0) ELSE 0 END AS '原材料'
--,CASE WHEN t0.FEXPTYPE != 0 THEN ISNULL(t0.O1,0) ELSE 0 END '间接材料'
--,CASE WHEN t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2 THEN ISNULL(t0.O0,0) ELSE 0 END '直接人工'
--,CASE WHEN NOT (t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2) THEN ISNULL(t0.O0,0) ELSE 0 END AS '间接人工'
,ISNULL(t0.O0,0),ISNULL(t0.O1,0),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)
,t0.
,t0.
,t0.[]
,t0.
,t0.[]
,t0.
,t0.[]
,t0.
,ISNULL(t4.FAMOUNT, 0) '领料成本'
,ISNULL(t4.FQTY,0) AS '领料数量'
,ISNULL(t4.FLOT,0) AS 'FLOT'
,ISNULL(t4.FPERIOD ,0) AS 'FPERIOD'
,ISNULL(t5.FNUMBER,'') AS 'FLOT_TEXT'
,t6.FBILLID SUBFBILLID
,t6.FBILLENTRYID SUBFBILLENTRYID
,t6.FPRODUCTDIMEID SUBFPRODUCTDIMEID
,t0.MPATH AS 'MPATH'
,CASE WHEN ISNULL(t6.FBILLENTRYID,0) = 0 THEN 0
WHEN t0.FPRODUCTNO = t5.FNUMBER THEN 0
WHEN t0. = 0 THEN 0
ELSE 1 END 'FGOON'
,0
FROM # t0
OUTER APPLY (
SELECT t5.FLOT
,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) AS 'FPERIOD'
,SUM(t4.FAMOUNT) AS 'FAMOUNT',CAST(SUM(t6.FQTY) AS decimal(23,10)) AS 'FQTY'
FROM V_CB_COSTALLORESULTSEND t4
INNER JOIN T_HS_INIVSTOCKDIMENSION t5 on t5.FENTRYID = t4.FDIMEENTRYID AND t5.FLOT != 0
INNER JOIN V_HS_OUTINSTOCKSEQ t6 on t6.FENTRYID = t4.FOUTINSTOCKID
WHERE t4.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t5.FMATERIALID = t0.FMATERIALID
AND CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) <= t0.FPERIOD
GROUP BY t5.FLOT
,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112))
) t4
LEFT JOIN T_BD_LOTMASTER t5 on t5.FLOTID = t4.FLOT
LEFT JOIN T_CB_PROORDERDIME t6 on t6.FPRODUCTNO = t5.FNUMBER AND t6.FPRODUCTID = t0.FMATERIALID
WHERE t0.RN = 1
ORDER BY t0.FPRODUCTDIMEID
,t0.FEXPTYPE DESC
,t0.FMATERIALID ASC
,t4.FLOT ASC
DECLARE @num INT,@level int,@LoopCount int
SET @num = 1
SET @level =1
SET @LoopCount = 0;
WHILE(@num!=0 AND @LoopCount < 30)
BEGIN
;WITH # AS (
SELECT t0.FPRODUCTNO
,t0.FBILLID
,t0.FBILLENTRYID
,t0.FPRODUCTID
,t0.FFORMID
,t3.FMATERIALID
,t1.FPRODUCTDIMEID
,t3.FEXPTYPE
,t3.FSUMCURRINPUTQTY '物料投入数量'
,t3.FSUMCURRINPUTAMOUNT '物料投入成本'
,t3.FSUMQUALIFIEDINQTY '物料完工数量'
,t3.FSUMQUALIFIEDINAMOUNT '物料完工成本'
,t4.FSUMCURRINPUTQTY '产品投入数量'
,t4.FSUMCURRINPUTAMOUNT '产品投入成本'
,t4.FSUMQUALIFIEDINQTY '产品完工数量'
,t4.FSUMQUALIFIEDINAMOUNT '产品完工成本'
,CONCAT(tt.MPATH,t0.FPRODUCTNO,'_') AS 'MPATH'
,(t2.FYEAR * 100 + t2.FPERIOD) AS 'FPERIOD'
,RANK() OVER (PARTITION BY t0.FBILLENTRYID ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN'
,tt.使
,tt. AS '上级物料完工成本'
,CAST(CASE WHEN t4.FSUMQUALIFIEDINAMOUNT = 0 THEN 1 ELSE tt. / t4.FSUMQUALIFIEDINAMOUNT END AS decimal(23,10)) AS '完工占比'
,t3d.FQUALIFIEDINAMOUNT AS '物料完工费用'
,t5.fieldName
FROM # tt
INNER JOIN T_CB_PROORDERDIME t0 on tt.SubBillId = t0.FBILLID AND tt.SubBillEntryId = t0.FBILLENTRYID
AND tt.SubPRODUCTDIMEID = t0.FPRODUCTDIMEID
INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID
INNER JOIN V_HS_OUTACCTG t2 on t1.FACCTGID = t2.FID
INNER JOIN V_CB_COSTMATTERIAL t3 on t3.FID = t1.FID
LEFT JOIN V_CB_COSTMATTERIALDETAIL t3d on t3d.FENTRYID = t3.FENTRYID
INNER JOIN V_CB_COSTCALEXPENSE t4 on t4.FID = t3.FID
LEFT JOIN V_BD_COST_RESTORE_EXPENSE_V2 t5 on t3d.FEXPENSESITEMID = t5.FEXPID
WHERE 1 = 1
AND tt.FGOON = 1
AND tt.FLEVEL = @level - 1
AND t2.FACCTGORGID = @ACCTGORGID
AND t2.FCOMPUTEID != ''
AND (t2.FYEAR * 100 + t2.FPERIOD) <= tt.FPERIOD
AND t1.FENDINITKEY = 1
--AND t4.FSUMQUALIFIEDINQTY != 0
--AND tt.FLEVEL < 2
)
, # AS (
SELECT *
FROM # t0
PIVOT (
SUM(t0.) FOR
t0.fieldName IN (O0,O1,O2,O3,O4,O5,O6,O7,O8,O9,O10,O11,O12,O13,O14,O15)
) t1
)
INSERT INTO #
SELECT t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID
,t0.FPRODUCTDIMEID
,t0.FMATERIALID
,t0.FEXPTYPE
,CAST(CASE WHEN (t0.FEXPTYPE = 0 AND ISNULL(t4.FLOT,0)!= 0) AND t0. != 0 THEN (ISNULL(t4.FAMOUNT, 0) / t0.) ELSE 1 END AS decimal(23,10)) * CAST(t0.使 * t0. AS decimal(23,10)) '使用比例'
--,CASE t0.FEXPTYPE WHEN 0 THEN ISNULL(t0.O1,0) ELSE 0 END AS '原材料'
--,CASE WHEN t0.FEXPTYPE != 0 THEN ISNULL(t0.O1,0) ELSE 0 END '间接材料'
--,CASE WHEN t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2 THEN ISNULL(t0.O0,0) ELSE 0 END '直接人工'
--,CASE WHEN NOT (t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2) THEN ISNULL(t0.O0,0) ELSE 0 END AS '间接人工'
,ISNULL(t0.O0,0),ISNULL(t0.O1,0),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)
,t0.
,t0.
,t0.[]
,t0.
,t0.[]
,t0.
,t0.[]
,t0.
,ISNULL(t4.FAMOUNT, 0) '领料成本'
,ISNULL(t4.FQTY,0) AS '领料数量'
,ISNULL(t4.FLOT,0) AS 'FLOT'
,ISNULL(t4.FPERIOD ,0) AS 'FPERIOD'
,ISNULL(t5.FNUMBER,'') AS 'FLOT_TEXT'
,t6.FBILLID SUBFBILLID
,t6.FBILLENTRYID SUBFBILLENTRYID
,t6.FPRODUCTDIMEID SUBFPRODUCTDIMEID
,t0.MPATH AS 'MPATH'
,CASE WHEN ISNULL(t6.FBILLENTRYID,0) = 0 THEN 0
WHEN CHARINDEX(CONCAT(t5.FNUMBER,'_'),t0.MPATH) > 0 THEN 0
WHEN t0. = 0 THEN 0
ELSE 1 END 'FGOON'
,@level AS 'Flevel'
FROM # t0
OUTER APPLY (
SELECT t5.FLOT
,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) AS 'FPERIOD'
,SUM(t4.FAMOUNT) AS 'FAMOUNT',CAST(SUM(t6.FQTY) AS decimal(23,10)) AS 'FQTY'
FROM V_CB_COSTALLORESULTSEND t4
INNER JOIN T_HS_INIVSTOCKDIMENSION t5 on t5.FENTRYID = t4.FDIMEENTRYID AND t5.FLOT != 0
INNER JOIN V_HS_OUTINSTOCKSEQ t6 on t6.FENTRYID = t4.FOUTINSTOCKID
WHERE t4.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t5.FMATERIALID = t0.FMATERIALID
AND CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) <= t0.FPERIOD
GROUP BY t5.FLOT
,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112))
) t4
LEFT JOIN T_BD_LOTMASTER t5 on t5.FLOTID = t4.FLOT
LEFT JOIN T_CB_PROORDERDIME t6 on t6.FPRODUCTNO = t5.FNUMBER AND t6.FPRODUCTID = t0.FMATERIALID
WHERE t0.RN = 1
ORDER BY t0.FPRODUCTDIMEID
,t0.FEXPTYPE DESC
,t0.FMATERIALID ASC
,t4.FLOT ASC
SET @num = @@ROWCOUNT
SET @level += 1
SET @LoopCount += 1
END
SELECT t0.FPRODUCTNO AS '工单编号'
,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID,t0.FPRODUCTDIMEID,t0.FMATERIALID
,t1.FNUMBER AS '物料编码'
,t1_l.FNAME AS '物料名称'
,CASE t0.FEXPTYPE WHEN 0 THEN '直接材料' WHEN 1 THEN '间接材料' WHEN 2 THEN '加工费' WHEN 9 THEN '工时' ELSE '其他' END AS '费用类别'
--,t0.使用比例
,CASE t0.FEXPTYPE WHEN 9 THEN t0. ELSE 0 END * t0.使 AS '总工时'
--,ROUND(t0.使用比例 * t0.物料完工成本,2) AS '料工费'
--,t0.使用比例 * t0.材料成本Q AS '原材料Q1'
--,t0.使用比例 * t0.间接材料Q2 AS '间接材料Q2'
--,t0.使用比例 * t0.直接人工S AS '直接人工S'
--,t0.使用比例 * t0.间接人工S2 AS '间接人工S2'
,ROUND(CASE t0.FEXPTYPE WHEN 0 THEN ISNULL(t0.Q,0) ELSE 0 END * t0.使,2) AS '原材料'
,ROUND(CASE WHEN t0.FEXPTYPE != 0 THEN ISNULL(t0.Q,0) ELSE 0 END * t0.使,2) '间接材料'
,ROUND(CASE WHEN t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2 THEN ISNULL(t0.S,0) ELSE 0 END * t0.使,2) '直接人工'
,ROUND(CASE WHEN NOT (t0.FEXPTYPE = 0 OR t0.FEXPTYPE = 2) THEN ISNULL(t0.S,0) ELSE 0 END * t0.使,2) AS '间接人工'
,ROUND(t0.使 * t0._职工薪酬 ,2) AS '制造费用_职工薪酬'
,ROUND(t0.使 * t0._股份支付 ,2) AS '制造费用_股份支付'
,ROUND(t0.使 * t0._劳动保护费 ,2) AS '制造费用_劳动保护费'
,ROUND(t0.使 * t0._差旅费 ,2) AS '制造费用_差旅费'
,ROUND(t0.使 * t0._业务招待费 ,2) AS '制造费用_业务招待费'
,ROUND(t0.使 * t0._办公费 ,2) AS '制造费用_办公费'
,ROUND(t0.使 * t0._折旧与摊销 ,2) AS '制造费用_折旧与摊销'
,ROUND(t0.使 * t0._租赁费 ,2) AS '制造费用_租赁费'
,ROUND(t0.使 * t0._水电费 ,2) AS '制造费用_水电费'
,ROUND(t0.使 * t0._物料消耗 ,2) AS '制造费用_物料消耗'
,ROUND(t0.使 * t0._加工_修理_检测费 ,2) AS '制造费用_加工_修理_检测费'
,ROUND(t0.使 * t0._车辆使用费 ,2) AS '制造费用_车辆使用费'
,ROUND(t0.使 * t0._其他 ,2) AS '制造费用_其他'
,ROUND(t0.使 * t0._委外加工费 ,2) AS '制造费用_委外加工费'
,t0.
,t0.
,t0.
,t0.
,t0.FNUMBER AS '批号'
,t0.FPERIOD AS '领料周期'
,t0.FGOON AS '执行分解'
,t0.FLEVEL AS '层级'
,t0.MPATH AS '分解路径'
,t0.
,t0.
,t0.
,t0.
,t0.FAMOUNT AS '领料成本'
,t0.FQTY AS '领料数量'
,t0.FLOT
,t0.SubBillId
,t0.SubBillEntryId
,t0.SubPRODUCTDIMEID
FROM # t0
LEFT JOIN T_BD_MATERIAL t1 on t0.FMATERIALID = t1.FMATERIALID
LEFT JOIN T_BD_MATERIAL_L t1_l on t1_l.FMATERIALID = t0.FMATERIALID AND t1_l.FLOCALEID = 2052
LEFT JOIN T_BD_MATERIAL t2 on t2.FMATERIALID = t0.FPRODUCTID
LEFT JOIN T_BD_MATERIAL_L t2_l on t2_l.FMATERIALID = t0.FPRODUCTID AND t2_l.FLOCALEID = 2052
WHERE 1=1
ORDER BY t0.FLEVEL
,t0.FPRODUCTID DESC
,t0.FEXPTYPE
,t0.FMATERIALID