445 lines
17 KiB
Transact-SQL
445 lines
17 KiB
Transact-SQL
IF EXISTS (SELECT 1 WHERE object_id('tempdb..#生产订单') IS NOT NULL)
|
|
DROP TABLE [dbo].#生产订单
|
|
GO
|
|
IF EXISTS (SELECT 1 WHERE object_id('tempdb..#整合数据临时表') IS NOT NULL)
|
|
DROP TABLE [dbo].#整合数据临时表
|
|
GO
|
|
IF EXISTS (SELECT 1 WHERE object_id('tempdb..#计算使用成本_临时表') IS NOT NULL)
|
|
DROP TABLE [dbo].#计算使用成本_临时表
|
|
GO
|
|
|
|
CREATE TABLE #生产订单(
|
|
[FBILLNO] nvarchar(80) NULL,
|
|
[FID] int NOT NULL,
|
|
[FENTRYID] int NOT NULL,
|
|
[TopMaterialId] int NULL,
|
|
[FMATERIALID] int NULL,
|
|
[FFORMID] varchar(36) NULL,
|
|
[入库数量] decimal(23, 10) NOT NULL,
|
|
[FSTATUS] char(1) NULL,
|
|
[FCOSTDATE] datetime NULL,
|
|
[FQTY] decimal(23, 10) NOT NULL,
|
|
[FPERIOD] int NULL
|
|
) ON [PRIMARY]
|
|
|
|
|
|
declare @sqlL varchar(max)
|
|
declare @billNo varchar(100),@materialNumber varchar(100)
|
|
declare @dbName varchar(100)
|
|
|
|
SET @sqlL = N'
|
|
INSERT INTO #生产订单
|
|
SELECT t0.FBILLNO,t0.FID,t0e.FENTRYID,t0e.FMATERIALID AS TopMaterialId,t0e.FMATERIALID
|
|
,t0.FFORMID AS FFORMID,t0e_a.FSTOCKINQUASELAUXQTY AS 入库数量
|
|
,t0e_a.FSTATUS,t0e_a.FCOSTDATE,t0e_a.FSTOCKINQUASELAUXQTY AS FQTY
|
|
,CONVERT(INT, CONVERT(VARCHAR(6),ISNULL(t0e_a.FCOSTDATE,GETDATE()),112)) AS FPERIOD
|
|
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
|
|
'
|
|
select @dbName = db_name()
|
|
|
|
if @dbName != 'AIS20231110222743'
|
|
BEGIN
|
|
SET @billNo = 'WO2403210039'
|
|
--SET @billNo = 'WO2310240111'
|
|
--SET @billNo = 'TO2310120003'
|
|
SET @billNo = 'RO2403280019'
|
|
--SET @billNo = 'WO2304230023'
|
|
--SET @billNo = 'WO2310240112'
|
|
END
|
|
|
|
IF @billNo != '' OR @materialNumber = ''
|
|
BEGIN
|
|
SET @sqlL = @sqlL + N' AND t0.FBILLNO = ''' + @billNo + ''''
|
|
END
|
|
|
|
IF @materialNumber != ''
|
|
BEGIN
|
|
SET @sqlL = @sqlL + N' AND t1.FNUMBER = ''' + @materialNumber + ''''
|
|
END
|
|
|
|
EXEC(@sqlL)
|
|
|
|
|
|
;WITH #TopMo AS (
|
|
SELECT * FROM #生产订单
|
|
)
|
|
,#生产领料单 AS (
|
|
SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'PRD_MO' AS 'FFORMID'
|
|
,SUM(t1e.FAMOUNT) AS 'FAMOUNT',t1e.FMOENTRYID,t1e.FMOBILLNO
|
|
,SUM(t1e.FBASEACTUALQTY) AS 'FBASEACTUALQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t1.FDATE,112))) AS 'FPERIOD'
|
|
FROM T_PRD_PICKMTRL t1
|
|
INNER JOIN T_PRD_PICKMTRLDATA t1e on t1.FID = t1e.FID
|
|
WHERE t1.FDOCUMENTSTATUS = 'C' AND t1e.FMOBILLNO != t1e.FLOT_TEXT
|
|
GROUP BY t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,t1e.FMOENTRYID,t1e.FMOBILLNO
|
|
)
|
|
, #生产补料单 AS (
|
|
SELECT t0e.FLOT,t0e.FLOT_TEXT,t0e.FMATERIALID,'PRD_MO' AS 'FFORMID'
|
|
,SUM(t0e.FAMOUNT) AS 'FAMOUNT',t0e.FMOENTRYID,t0e.FMOBILLNO
|
|
,SUM(t0e_q.FACTUALQTY) AS 'FQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t0.FDATE,112))) AS 'FPERIOD'
|
|
FROM T_PRD_FEEDMTRL t0
|
|
INNER JOIN T_PRD_FEEDMTRLDATA t0e on t0.FID = t0e.FID
|
|
INNER JOIN T_PRD_FEEDMTRLDATA_Q t0e_q on t0e_q.FENTRYID = t0e.FENTRYID
|
|
WHERE t0.FDOCUMENTSTATUS = 'C'
|
|
GROUP BY t0e.FMOID,t0e.FMOENTRYID,t0e.FMATERIALID,t0e.FLOT,t0e.FLOT_TEXT,t0e.FMOBILLNO
|
|
)
|
|
, #生产退料单 AS (
|
|
SELECT t0e.FLOT,t0e.FLOT_TEXT,t0e.FMATERIALID,'PRD_MO' AS 'FFORMID'
|
|
,-SUM(t0e.FAMOUNT) AS 'FAMOUNT',t0e.FMOENTRYID,t0e.FMOBILLNO
|
|
,-SUM(t0e.FQTY) AS 'FQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t0.FDATE,112))) AS 'FPERIOD'
|
|
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,t0e.FLOT_TEXT,t0e.FMOBILLNO
|
|
)
|
|
, #生产订单领料成本 AS (
|
|
SELECT t0.FLOT,t0.FLOT_TEXT,t0.FMATERIALID,'PRD_MO' AS 'FFORMID'
|
|
,SUM(t0.FAMOUNT) AS 'FAMOUNT',t0.FMOENTRYID,t0.FMOBILLNO
|
|
,SUM(t0.FBASEACTUALQTY) AS 'FBASEACTUALQTY'
|
|
,MAX(t0.FPERIOD) AS 'FPERIOD'
|
|
FROM (
|
|
SELECT * FROM #生产领料单
|
|
UNION ALL
|
|
SELECT * FROM #生产补料单
|
|
UNION ALL
|
|
SELECT * FROM #生产退料单
|
|
) t0
|
|
GROUP BY t0.FMOENTRYID,t0.FMATERIALID,t0.FLOT,t0.FLOT_TEXT,t0.FMOBILLNO
|
|
)
|
|
,#委外领料单 AS (
|
|
SELECT t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID'
|
|
,SUM(ISNULL(t1e_a.FAMOUNT,0)) FAMOUNT,t1e.FSUBREQENTRYID AS 'FMOENTRYID',t1e.FSUBREQBILLNO AS 'FMOBILLNO'
|
|
,SUM(t1e.FBASEACTUALQTY) AS 'FBASEACTUALQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t1.FDATE,112))) AS 'FPERIOD'
|
|
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,t1e.FSUBREQBILLNO
|
|
)
|
|
, #委外补料单 AS (
|
|
SELECT t0e.FLOT,t0e.FLOT_TEXT,t0e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID'
|
|
,SUM(t0e.FAMOUNT) AS 'FAMOUNT',t0e.FSUBREQENTRYID AS 'FMOENTRYID',t0e.FSUBREQBILLNO AS 'FMOBILLNO'
|
|
,SUM(t0e_q.FACTUALQTY) AS 'FQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t0.FDATE,112))) AS 'FPERIOD'
|
|
FROM T_SUB_FEEDMTRL t0
|
|
INNER JOIN T_SUB_FEEDMTRLENTRY t0e on t0.FID = t0e.FID
|
|
INNER JOIN T_SUB_FEEDMTRLENTRY_Q t0e_q on t0e_q.FENTRYID = t0e.FENTRYID
|
|
WHERE t0.FDOCUMENTSTATUS = 'C'
|
|
GROUP BY t0e.FLOT,t0e.FLOT_TEXT,t0e.FMATERIALID,t0e.FSUBREQENTRYID,t0e.FSUBREQBILLNO
|
|
)
|
|
, #委外退料单 AS (
|
|
SELECT t0e.FLOT,t0e.FLOT_TEXT,t0e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID'
|
|
,-SUM(t0e.FAMOUNT) AS 'FAMOUNT',t0e_a.FSUBREQENTRYID AS 'FMOENTRYID',t0e_a.FSUBREQBILLNO AS 'FMOBILLNO'
|
|
,-SUM(t0e.FQTY) AS 'FQTY'
|
|
,MAX(CONVERT(int,CONVERT(varchar(6),t0.FDATE,112))) AS 'FPERIOD'
|
|
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.FLOT_TEXT,t0e.FMATERIALID,t0e_a.FSUBREQENTRYID,t0e_a.FSUBREQBILLNO
|
|
)
|
|
, #委外订单领料成本 AS (
|
|
SELECT t0.FLOT,t0.FLOT_TEXT,t0.FMATERIALID,'PRD_MO' AS 'FFORMID'
|
|
,SUM(t0.FAMOUNT) AS 'FAMOUNT',t0.FMOENTRYID,t0.FMOBILLNO
|
|
,SUM(t0.FBASEACTUALQTY) AS 'FBASEACTUALQTY'
|
|
,MAX(t0.FPERIOD) AS 'FPERIOD'
|
|
FROM (
|
|
SELECT * FROM #委外领料单
|
|
UNION ALL
|
|
SELECT * FROM #委外补料单
|
|
UNION ALL
|
|
SELECT * FROM #委外退料单
|
|
) t0
|
|
GROUP BY t0.FMOENTRYID,t0.FMATERIALID,t0.FLOT,t0.FLOT_TEXT,t0.FMOBILLNO
|
|
)
|
|
, #直接材料 AS (
|
|
SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
|
|
,CONVERT(decimal(23,10),t0e_a.FSTOCKINQUASELAUXQTY) AS '入库数量'
|
|
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID
|
|
,CONVERT(VARCHAR(36),'PRD_MO') AS 'FFORMID'
|
|
,t0e_a.FSTOCKINQUASELAUXQTY AS '生产数量',t1.FBASEACTUALQTY AS '领料数量'
|
|
,t1.FPERIOD
|
|
,CASE WHEN ISNULL(t0.FID,0) = 0 THEN CAST(1 AS decimal(23,10)) ELSE CONVERT(decimal(23,10),t1.FBASEACTUALQTY / t0e.FBASEUNITQTY) END AS 'QtyRatio'
|
|
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
|
|
UNION ALL
|
|
SELECT t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
|
|
,t0e.FSTOCKINQTY
|
|
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID
|
|
,CONVERT(VARCHAR(36),'SUB_SUBREQORDER') AS 'FFORMID'
|
|
,t0e.FQTY AS '生产数量',t1.FBASEACTUALQTY AS '领料数量'
|
|
,t1.FPERIOD
|
|
,CASE WHEN ISNULL(t0.FID,0) = 0 THEN CAST(1 AS decimal(23,10)) ELSE CONVERT(decimal(23,10),t1.FBASEACTUALQTY / t0e.FQTY) END AS 'QtyRatio'
|
|
FROM #委外订单领料成本 t1
|
|
LEFT JOIN T_SUB_REQORDER t0 on t0.FBILLNO = t1.FLOT_TEXT
|
|
LEFT JOIN T_SUB_REQORDERENTRY t0e on t0.FID = t0e.FID
|
|
)
|
|
, #整合数据 AS (
|
|
SELECT t0.FBILLNO AS 'MoBillNo'
|
|
,t0.FBILLNO AS 'PMoBillNo'
|
|
,CONVERT(varchar(1000),ROW_NUMBER() OVER (ORDER BY t0.FID,t0.FENTRYID,t0.FMATERIALID)) AS 'aPATH'
|
|
,CONVERT(varchar(1000),'0') AS 'PPATH'
|
|
,CONVERT(VARCHAR(8000),'') AS 'MPath'
|
|
,0 AS 'lv'
|
|
,t0.FID AS 'MoId'
|
|
,t0.FENTRYID AS 'MoEntryId'
|
|
,t0.FMATERIALID AS 'MoMaterialId'
|
|
,0 AS 'PMoId'
|
|
,0 AS 'PMoEntryId'
|
|
,0 AS 'PMoMaterialId'
|
|
,t0.TopMaterialId
|
|
,t0.FMATERIALID
|
|
,0 FLOT
|
|
,CONVERT(nvarchar(255),'') AS 'FLOT_TEXT'
|
|
,CONVERT(decimal(23,10),0) AS 'FAMOUNT'
|
|
,CONVERT(decimal(23,10),1) AS 'QtyRatio'
|
|
,CONVERT(decimal(23,10),1) AS 'TQtyRatio'
|
|
,CONVERT(decimal(23,10),0) AS '订单成本'
|
|
,CONVERT(decimal(23,10),0) AS '物料成本'
|
|
,t0.FQTY AS '领料数量'
|
|
,t0.FQTY AS '生产数量'
|
|
,t0.FPERIOD
|
|
,t0.入库数量
|
|
,t0.FFORMID
|
|
FROM #TopMo t0
|
|
UNION ALL
|
|
SELECT ISNULL(t0.FBILLNO,'') AS 'MoBillNo'
|
|
,tt.MoBillNo
|
|
,CONVERT(varchar(1000),CONCAT(tt.aPATH,'.',ROW_NUMBER() OVER (PARTITION BY tt.MoId,tt.MoEntryId ORDER BY t0.FMATERIALID))) AS 'aPATH'
|
|
,tt.aPATH
|
|
,CONVERT(varchar(8000),CONCAT(tt.MPath,ISNULL(tt.MoBillNo,''),'>'))
|
|
,tt.lv + 1 lv
|
|
,ISNULL(t0.FID,0) AS 'MoId'
|
|
,ISNULL(t0.FENTRYID,0) AS 'MoEntryId'
|
|
,ISNULL(t0.MoMaterialId, 0)
|
|
,tt.MoId AS 'PMoId'
|
|
,tt.MoEntryId AS 'PMoEntryId'
|
|
,tt.MoMaterialId AS 'PMoMaterialId'
|
|
,tt.TopMaterialId
|
|
,t0.FMATERIALID
|
|
,t0.FLOT
|
|
,t0.FLOT_TEXT
|
|
,CONVERT(decimal(23,10),t0.FAMOUNT * tt.QtyRatio)
|
|
,CONVERT(decimal(23,10),tt.QtyRatio * t0.QtyRatio)
|
|
,CONVERT(decimal(23,10),tt.QtyRatio)
|
|
,CONVERT(decimal(23,10),tt.订单成本)
|
|
,CONVERT(decimal(23,10),t0.FAMOUNT)
|
|
,CONVERT(decimal(23,10),t0.领料数量)
|
|
,ISNULL(t0.生产数量,t0.领料数量)
|
|
,t0.FPERIOD
|
|
,ISNULL(t0.入库数量,0) AS '入库数量'
|
|
,ISNULL(t0.FFORMID,'')
|
|
FROM #整合数据 tt
|
|
CROSS APPLY (
|
|
SELECT *
|
|
FROM #直接材料 t0
|
|
WHERE t0.FFORMID = tt.FFORMID
|
|
AND t0.FMOENTRYID = tt.MoEntryId
|
|
) t0
|
|
WHERE 1=1
|
|
AND CHARINDEX(tt.MoBillNo,tt.MPath) = 0
|
|
)
|
|
SELECT *
|
|
INTO #整合数据临时表
|
|
FROM #整合数据
|
|
;WITH #成本计算 AS (
|
|
SELECT
|
|
t0.FPRODUCTDIMEID
|
|
,t0.FPRODUCTNO
|
|
,t0.FPRODUCTID
|
|
,t0.FBILLID
|
|
,t0.FBILLENTRYID
|
|
,t2.FMATERIALID
|
|
,t2e.FEXPENSESITEMID
|
|
,t2e.FCOSTITEMID
|
|
,SUM(t2e.FQUALIFIEDINAMOUNT) AS '累计完工入库金额'
|
|
,SUM(t2e.FCURRINPUTAMOUNT) AS '累计投入金额'
|
|
,MAX(t2.FSUMQUALIFIEDINQTY) AS '累计完工入库数量'
|
|
,MAX(t2.FSUMCURRINPUTQTY) AS '累计投入数量'
|
|
,MAX(t3.FSUMQUALIFIEDINQTY) AS '累计完工入库数量2'
|
|
,MAX(t3.FSUMCURRINPUTQTY) AS '累计投入数量2'
|
|
,t2.FEXPTYPE
|
|
,tt.aPATH
|
|
FROM #整合数据临时表 tt
|
|
INNER JOIN T_CB_PROORDERDIME t0 on tt.MoEntryId = t0.FBILLENTRYID AND tt.MoId = t0.FBILLID
|
|
INNER JOIN V_CB_PROORDERINFO t1 ON t1.FPRODUCTDIMEID= t0.FPRODUCTDIMEID
|
|
INNER JOIN V_CB_COSTMATTERIAL t2 on t2.FID = t1.FID
|
|
INNER JOIN V_CB_COSTMATTERIALDETAIL t2e on t2.FENTRYID = t2e.FENTRYID
|
|
INNER JOIN V_CB_COSTCALEXPENSE t3 on t3.FID = t2.FID
|
|
CROSS APPLY(
|
|
SELECT TOP 1 1 AS 'val'
|
|
FROM V_HS_OUTACCTG t5
|
|
WHERE t5.FID = t1.FACCTGID
|
|
AND (tt.FPERIOD IS NULL OR t5.FYEAR *100 + t5.FPERIOD <= tt.FPERIOD)
|
|
ORDER BY t5.FYEAR *100 + t5.FPERIOD DESC
|
|
) t4
|
|
WHERE 1=1
|
|
AND tt.MoEntryId != 0
|
|
GROUP BY t0.FPRODUCTDIMEID,t0.FPRODUCTNO,t0.FPRODUCTID,t0.FBILLID,t0.FBILLENTRYID
|
|
,t2.FMATERIALID,t2e.FEXPENSESITEMID,t2e.FCOSTITEMID
|
|
,t2.FEXPTYPE
|
|
,tt.aPATH
|
|
)
|
|
, #费用分类 AS (
|
|
SELECT *
|
|
FROM (
|
|
SELECT SUM(t0.累计完工入库金额) AS '累计完工入库金额',t0.FBILLENTRYID
|
|
,t0.aPATH
|
|
,CASE t0.FEXPTYPE WHEN 0 THEN '直接材料' WHEN 1 THEN '间接材料' ELSE t1.FNAME END AS '费用分配'
|
|
FROM #成本计算 t0
|
|
LEFT JOIN V_BD_COST_RESTORE_EXPENSE t1 on t0.FEXPENSESITEMID = t1.FEXPID
|
|
GROUP BY t0.FBILLENTRYID,t0.FEXPTYPE,t0.aPATH,t1.FNAME
|
|
) t0
|
|
PIVOT(
|
|
SUM(t0.累计完工入库金额) FOR
|
|
t0.费用分配 IN (直接材料,间接材料,直接人工,职工薪酬,股份支付,劳动保护费,差旅费,业务招待费,办公费,折旧与摊销,租赁费,水电费,物料消耗,加工_修理_检测费,车辆使用费,其他,委外加工费,材料成本)
|
|
) AS t1
|
|
)
|
|
, #直接材料计算 AS (
|
|
SELECT tt.*
|
|
,CASE tt.MoId WHEN 0 THEN tt.物料成本 ELSE ISNULL(t2.累计完工入库金额,0) END '料工费'
|
|
,CASE tt.MoId WHEN 0 THEN t1.累计完工入库金额 ELSE ISNULL(t2.累计完工入库金额,0) END AS '累计完工入库金额'
|
|
,CASE tt.MoId WHEN 0 THEN t1.累计投入金额 ELSE ISNULL(t2.累计投入金额,0) END AS '累计投入金额'
|
|
,CASE tt.MoId WHEN 0 THEN t1.累计完工入库数量 ELSE ISNULL(t2.累计完工入库数量,1) END AS '累计完工入库数量'
|
|
,CASE tt.MoId WHEN 0 THEN t1.累计投入数量 ELSE ISNULL(t2.累计投入数量,1) END AS '累计投入数量'
|
|
,CASE t1.累计完工入库数量 WHEN 0 THEN 0 ELSE ISNULL(t1.累计完工入库数量,1)/ ISNULL(t1.累计投入数量,1) END '投入完工占比'
|
|
FROM #整合数据临时表 tt
|
|
OUTER APPLY (
|
|
SELECT
|
|
t0.FPRODUCTDIMEID
|
|
,t0.FPRODUCTNO
|
|
,t0.FBILLID
|
|
,t0.FBILLENTRYID
|
|
,t0.FMATERIALID
|
|
,SUM(t0.累计完工入库金额) AS '累计完工入库金额'
|
|
,SUM(t0.累计投入金额) AS '累计投入金额'
|
|
,MAX(t0.累计完工入库数量) '累计完工入库数量'
|
|
,MAX(t0.累计投入数量) AS '累计投入数量'
|
|
FROM #成本计算 t0
|
|
WHERE 1=1
|
|
AND t0.FEXPTYPE = 0
|
|
AND t0.aPATH = tt.PPATH
|
|
AND t0.FMATERIALID = tt.FMATERIALID
|
|
GROUP BY t0.FPRODUCTDIMEID,t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FMATERIALID
|
|
) t1
|
|
LEFT JOIN (
|
|
SELECT
|
|
t0.FPRODUCTDIMEID
|
|
,t0.FPRODUCTNO
|
|
,t0.FBILLID
|
|
,t0.FBILLENTRYID
|
|
,t0.FPRODUCTID
|
|
,SUM(t0.累计完工入库金额) AS '累计完工入库金额'
|
|
,SUM(t0.累计投入金额) AS '累计投入金额'
|
|
,MAX(t0.累计完工入库数量2) '累计完工入库数量'
|
|
,MAX(t0.累计投入数量2) AS '累计投入数量'
|
|
,t0.aPATH
|
|
FROM #成本计算 t0
|
|
WHERE 1=1
|
|
GROUP BY t0.FPRODUCTDIMEID,t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID
|
|
,t0.FPRODUCTID,t0.aPATH
|
|
) t2 on t2.aPATH = tt.aPATH AND t2.FPRODUCTID = tt.FMATERIALID
|
|
)
|
|
, #计算使用成本 AS (
|
|
SELECT tt.MoBillNo,tt.PMoBillNo,tt.FMATERIALID,tt.lv
|
|
,累计完工入库金额,累计投入金额
|
|
,累计完工入库数量,累计投入数量
|
|
,投入完工占比
|
|
,领料数量,生产数量
|
|
,CAST(tt.料工费 AS decimal(23,10)) AS '料工费'
|
|
,CAST(领料数量 / 生产数量 AS decimal(23,10)) '领料比例'
|
|
,aPATH,PPATH
|
|
,入库数量,FFORMID
|
|
,tt.MPath,tt.MoId,tt.MoEntryId,tt.MoMaterialId,tt.PMoId,tt.PMoEntryId
|
|
,tt.PMoMaterialId,tt.TopMaterialId
|
|
,tt.FLOT,tt.FLOT_TEXT,tt.FAMOUNT,tt.FPERIOD
|
|
FROM #直接材料计算 tt
|
|
WHERE tt.lv = 0
|
|
UNION ALL
|
|
SELECT tt.MoBillNo,tt.PMoBillNo,tt.FMATERIALID,tt.lv
|
|
,tt.累计完工入库金额,tt.累计投入金额
|
|
,tt.累计完工入库数量,tt.累计投入数量
|
|
,tt.投入完工占比
|
|
,tt.领料数量,tt.生产数量
|
|
,CAST(tt.领料数量 / tt.累计完工入库数量 * t0.领料比例 * tt.累计完工入库金额 * tt.投入完工占比 AS decimal(23,10))
|
|
,CAST(tt.领料数量 / tt.累计完工入库数量 * t0.领料比例 AS decimal(23,10))
|
|
,tt.aPATH,tt.PPATH
|
|
,tt.入库数量,tt.FFORMID
|
|
,tt.MPath,tt.MoId,tt.MoEntryId,tt.MoMaterialId,tt.PMoId,tt.PMoEntryId
|
|
,tt.PMoMaterialId,tt.TopMaterialId
|
|
,tt.FLOT,tt.FLOT_TEXT,tt.FAMOUNT,tt.FPERIOD
|
|
FROM #直接材料计算 tt
|
|
INNER JOIN #计算使用成本 t0 on tt.lv = t0.lv + 1 AND tt.PPATH = t0.aPATH
|
|
)
|
|
SELECT tt.*
|
|
,ISNULL(t0.直接材料,0) * tt.领料比例 AS '直接材料'
|
|
,ISNULL(t0.直接人工,0) * tt.领料比例 AS '直接人工'
|
|
,ISNULL(t0.间接材料,0) * tt.领料比例 AS '间接材料'
|
|
,ISNULL(t0.职工薪酬,0) * tt.领料比例 AS '职工薪酬'
|
|
,ISNULL(t0.股份支付,0) * tt.领料比例 AS '股份支付'
|
|
,ISNULL(t0.劳动保护费,0) * tt.领料比例 AS '劳动保护费'
|
|
,ISNULL(t0.差旅费,0) * tt.领料比例 AS '差旅费'
|
|
,ISNULL(t0.业务招待费,0) * tt.领料比例 AS '业务招待费'
|
|
,ISNULL(t0.办公费,0) * tt.领料比例 AS '办公费'
|
|
,ISNULL(t0.折旧与摊销,0) * tt.领料比例 AS '折旧与摊销'
|
|
,ISNULL(t0.租赁费,0) * tt.领料比例 AS '租赁费'
|
|
,ISNULL(t0.水电费,0) * tt.领料比例 AS '水电费'
|
|
,ISNULL(t0.物料消耗,0) * tt.领料比例 AS '物料消耗'
|
|
,ISNULL(t0.加工_修理_检测费,0) AS '加工_修理_检测费'
|
|
,ISNULL(t0.车辆使用费,0) * tt.领料比例 AS '车辆使用费'
|
|
,ISNULL(t0.其他,0) * tt.领料比例 AS '其他'
|
|
,ISNULL(t0.委外加工费,0) * tt.领料比例 AS '委外加工费'
|
|
,ISNULL(t0.材料成本,0) * tt.领料比例 AS '材料成本'
|
|
INTO #计算使用成本_临时表
|
|
FROM #计算使用成本 tt
|
|
LEFT JOIN #费用分类 t0 on tt.aPATH = t0.aPATH
|
|
ORDER BY CAST(CONCAT('/',REPLACE(tt.aPATH,'.','/'),'/') AS HIERARCHYID)
|
|
|
|
;WITH #实际工时归集 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 t0.*
|
|
,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'
|
|
,CAST(CONCAT('/',REPLACE(t0.aPATH,'.','/'),'/') AS HIERARCHYID) PATH_ID
|
|
,(CASE t0.MoId WHEN 0 THEN t0.料工费 ELSE 0 END) AS '外购材料'
|
|
FROM #计算使用成本_临时表 t0
|
|
LEFT JOIN #实际工时归集 t6 on t6.FPROORDERENTRYID = t0.MoEntryId
|
|
)
|
|
, #统计工时与成本 AS (
|
|
SELECT
|
|
t0.aPATH
|
|
,SUM(t0.外购材料) AS '外购材料'
|
|
,SUM(CASE t1.MoType WHEN 1 THEN t1.单位工时B ELSE 0 END) '普通C'
|
|
,SUM(CASE t1.MoType WHEN 2 THEN t1.单位工时B ELSE 0 END) '试制D'
|
|
,SUM(CASE t1.MoType WHEN 3 THEN t1.单位工时B ELSE 0 END) '返工E'
|
|
,SUM(CASE t1.MoType WHEN 4 THEN t1.单位工时B ELSE 0 END) '返工试制F'
|
|
,SUM(CASE t1.MoType WHEN 0 THEN t1.单位工时B ELSE 0 END) '其他G'
|
|
,SUM(CASE t1.MoType WHEN 1 THEN t1.单位工时B * t1.入库数量 * t1.领料比例 ELSE 0 END) '普通I'
|
|
,SUM(CASE t1.MoType WHEN 2 THEN t1.单位工时B * t1.入库数量 * t1.领料比例 ELSE 0 END) '试制J'
|
|
,SUM(CASE t1.MoType WHEN 3 THEN t1.单位工时B * t1.入库数量 * t1.领料比例 ELSE 0 END) '返工K'
|
|
,SUM(CASE t1.MoType WHEN 4 THEN t1.单位工时B * t1.入库数量 * t1.领料比例 ELSE 0 END) '返工试制L'
|
|
,SUM(CASE t1.MoType WHEN 0 THEN t1.单位工时B * t1.入库数量 * t1.领料比例 ELSE 0 END) '其他M'
|
|
FROM #工时 t0
|
|
INNER JOIN #工时 t1 ON t1.PATH_ID.IsDescendantOf(t0.PATH_ID) = 1
|
|
GROUP BY t0.aPATH
|
|
)
|
|
SELECT *
|
|
FROM #计算使用成本_临时表 t0
|
|
INNER JOIN #统计工时与成本 t1 on t0.aPATH = t1.aPATH |