335 lines
10 KiB
PL/PgSQL
335 lines
10 KiB
PL/PgSQL
CREATE PROC [dbo].[CB_ActualTimeWorked_ALL]
|
|
@billNo varchar(100)
|
|
,@YEAR int
|
|
,@M int
|
|
,@ACCTGORGID int
|
|
AS
|
|
BEGIN
|
|
--设置超时时间
|
|
SET QUERY_GOVERNOR_COST_LIMIT 15000
|
|
|
|
--declare @billNo varchar(100)
|
|
-- ,@YEAR int
|
|
-- ,@M int
|
|
-- ,@ACCTGORGID int
|
|
--SET @billNo = 'WO2409180061'
|
|
--SET @YEAR = 2024
|
|
--SET @M = 10
|
|
--SET @ACCTGORGID = 1
|
|
IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#查询结果') IS NOT NULL)
|
|
BEGIN
|
|
DROP TABLE [dbo].[#查询结果]
|
|
END
|
|
|
|
DECLARE @period int
|
|
SET @period = (@YEAR * 100 + @M)
|
|
IF (@period = 0 OR @YEAR = 0)
|
|
BEGIN
|
|
--SET @period = 6
|
|
SELECT @period = t0.FVALUE * 100 + t1.FVALUE
|
|
FROM T_BAS_SYSTEMPROFILE t0
|
|
INNER JOIN T_BAS_SYSTEMPROFILE t1 ON t0.FORGID=t1.FORGID
|
|
AND t0.FACCTSYSTEMID = t1.FACCTSYSTEMID AND t0.FACCTPOLICYID = t1.FACCTPOLICYID
|
|
AND t1.FKEY IN ('CurrentPeriod')
|
|
WHERE 1=1
|
|
AND t0.FCATEGORY='HS'
|
|
AND t1.FCATEGORY='HS'
|
|
AND t0.FKEY IN ('CurrentYear')
|
|
AND t0.FORGID = @ACCTGORGID
|
|
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,
|
|
[物料完工成本] 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,
|
|
[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],[FGOON],[FLEVEL]);
|
|
|
|
;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.FSUMQUALIFIEDINAMOUNT 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
|
|
INNER 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
|
|
,t0.物料投入成本
|
|
,t0.物料完工成本
|
|
,t0.[产品投入成本]
|
|
,t0.产品完工成本
|
|
,t0.[物料投入数量]
|
|
,t0.物料完工数量
|
|
,t0.[产品投入数量]
|
|
,t0.产品完工数量
|
|
,0 '领用数量'
|
|
,ISNULL(t4.FAMOUNT, 0) '领料成本'
|
|
,ISNULL(t4.FQTY,0) AS '领料数量'
|
|
,ISNULL(t4.FLOT,0) AS 'FLOT'
|
|
,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
|
|
,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
|
|
GROUP BY t5.FLOT
|
|
) 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.FBILLID,t0.FBILLENTRYID ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN'
|
|
,tt.物料完工成本 AS '上级物料完工成本'
|
|
,CAST(CASE WHEN t4.FSUMQUALIFIEDINAMOUNT = 0 THEN 1 ELSE tt.物料完工成本 / t4.FSUMQUALIFIEDINAMOUNT END AS decimal(23,10)) AS '完工占比'
|
|
,t3d.FSUMQUALIFIEDINAMOUNT AS '物料完工费用'
|
|
,t5.fieldName
|
|
,tt.FQTY AS '领用数量'
|
|
FROM #查询结果 tt
|
|
INNER JOIN T_CB_PROORDERDIME t0 on tt.SubBillEntryId = t0.FBILLENTRYID
|
|
--AND tt.SubBillId = t0.FBILLID AND tt.SubPRODUCTDIMEID = t0.FPRODUCTDIMEID
|
|
INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t1.FENDINITKEY = 1
|
|
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 > 0
|
|
AND tt.FLEVEL > @level - 2
|
|
AND t2.FACCTGORGID = @ACCTGORGID
|
|
AND t2.FCOMPUTEID != ''
|
|
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
|
|
,t0.物料投入成本
|
|
,t0.物料完工成本
|
|
,t0.[产品投入成本]
|
|
,t0.产品完工成本
|
|
,t0.[物料投入数量]
|
|
,t0.物料完工数量
|
|
,t0.[产品投入数量]
|
|
,t0.产品完工数量
|
|
,t0.领用数量
|
|
,ISNULL(t4.FAMOUNT, 0) '领料成本'
|
|
,ISNULL(t4.FQTY,0) AS '领料数量'
|
|
,ISNULL(t4.FLOT,0) AS 'FLOT'
|
|
,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
|
|
,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
|
|
GROUP BY t5.FLOT
|
|
) 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
|
|
|
|
--IF(@num > 50000)
|
|
--BEGIN
|
|
-- SET @LoopCount = 30
|
|
--END
|
|
|
|
UPDATE STATISTICS #查询结果 idx_查询结果_fuhesuoyin
|
|
END
|
|
|
|
|
|
;WITH #数据整合 AS (
|
|
SELECT t0.FPRODUCTNO AS '工单编号'
|
|
,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID,t0.FPRODUCTDIMEID,t0.FMATERIALID
|
|
,t0.FEXPTYPE
|
|
,CASE t0.FEXPTYPE WHEN 0 THEN '直接费用' WHEN 1 THEN '间接费用' WHEN 2 THEN '加工费' WHEN 9 THEN '工时' ELSE '其他' END AS '费用类别'
|
|
,t0.物料投入成本
|
|
,t0.物料完工成本
|
|
,t0.产品投入成本
|
|
,t0.产品完工成本
|
|
,t0.FNUMBER AS '批号'
|
|
,t0.FGOON AS '执行分解'
|
|
,t0.FLEVEL AS '层级'
|
|
,t0.MPATH AS '分解路径'
|
|
,t0.物料投入数量
|
|
,t0.物料完工数量
|
|
,t0.产品投入数量
|
|
,t0.产品完工数量
|
|
,CASE t0.FEXPTYPE WHEN 9 THEN t0.领用数量 ELSE 0 END AS '领用数量'
|
|
,CASE t0.FEXPTYPE WHEN 9 THEN t0.物料完工数量 ELSE 0 END AS '工时U_汇报工时'
|
|
,t0.FAMOUNT AS '领料成本'
|
|
,t0.FQTY AS '领料数量'
|
|
,t0.FLOT
|
|
,t0.SubBillId
|
|
,t0.SubBillEntryId
|
|
,t0.SubPRODUCTDIMEID
|
|
FROM #查询结果 t0
|
|
WHERE 1=1
|
|
--AND t0.FGOON = 0
|
|
)
|
|
SELECT t0.工单编号
|
|
,t2.FNUMBER AS '产品编码'
|
|
,t2_l.FNAME AS '产品名称'
|
|
,t1.FNUMBER AS '物料编码'
|
|
,t1_l.FNAME AS '物料名称'
|
|
,t0.费用类别
|
|
,t0.产品完工成本
|
|
,t0.物料投入数量
|
|
,t0.物料完工数量
|
|
,t0.产品完工数量
|
|
,t0.工时U_汇报工时
|
|
,t0.工时U_汇报工时 / t0.产品完工数量 AS '工时U_单位工时'
|
|
,t0.领用数量 AS '工时U_领用数量'
|
|
,t0.领用数量 * (t0.工时U_汇报工时 / t0.产品完工数量) AS '工时U_总工时'
|
|
,t0.领料数量
|
|
,t0.执行分解
|
|
,t0.批号
|
|
,t0.分解路径
|
|
,t0.层级
|
|
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 t0.FEXPTYPE = 9
|
|
ORDER BY t0.层级
|
|
,t0.FPRODUCTID DESC
|
|
,t0.FEXPTYPE
|
|
,t0.FMATERIALID
|
|
end |