225 lines
7.6 KiB
Transact-SQL
225 lines
7.6 KiB
Transact-SQL
declare @sqlL varchar(max)
|
|
declare @billNo varchar(100),@materialNumber varchar(100)
|
|
,@sYear int,@sMonth int
|
|
,@eYear int,@eMonth int
|
|
SELECT @sYear = 0,@eYear = 0,@sMonth = 0,@eMonth = 0
|
|
|
|
--SELECT @sYear = 2024,@eYear = 2024,@sMonth = 2,@eMonth = 2
|
|
SET @sqlL = N'
|
|
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.FBASEUNITQTY AS FQTY
|
|
INTO ##查找对应工单
|
|
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
|
|
'
|
|
SET @billNo = ''
|
|
SET @materialNumber = ''
|
|
--SET @billNo = 'RO2405090020'
|
|
--SET @billNo = 'TO2405210015'
|
|
--SET @billNo = 'WO2405160002'
|
|
--SET @billNo = 'WO2405080005'
|
|
--SET @billNo = 'TO2404290033'
|
|
--SET @billNo = 'TO2403250007'
|
|
--SET @billNo = 'WO2403210039'
|
|
--SET @billNo = 'RO2403130015'
|
|
--SET @billNo = 'RO2403280019'
|
|
--SET @billNo = 'TO2310120003'
|
|
--SET @billNo = 'WO2310020141'
|
|
--SET @billNo = 'WO2310240123'
|
|
--SET @billNo = 'WO2310240112'
|
|
|
|
--SET @materialNumber = '03.70.0143'
|
|
IF @billNo != ''
|
|
BEGIN
|
|
SET @sqlL = @sqlL + N' AND t0.FBILLNO = ''' + @billNo + ''''
|
|
END
|
|
|
|
IF @materialNumber != ''
|
|
BEGIN
|
|
SET @sqlL = @sqlL + N' AND t1.FNUMBER = ''' + @materialNumber + ''''
|
|
END
|
|
|
|
IF @sYear != 0 OR @sYear != 0 OR @sMonth != 0 OR @eMonth != 0
|
|
BEGIN
|
|
SET @sqlL=CONCAT(@sqlL, ' AND ISNULL(YEAR(FCOSTDATE),0) BETWEEN ',@sYear,' AND ', @eYear)
|
|
SET @sqlL=CONCAT(@sqlL, ' AND ISNULL(MONTH(FCOSTDATE),0) BETWEEN ',@sMonth,' AND ', @eMonth)
|
|
END
|
|
--SELECT @sqlL
|
|
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 'FQTY'
|
|
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 t1e.FLOT,t1e.FLOT_TEXT,t1e.FMATERIALID,'SUB_SUBREQORDER' AS 'FFORMID'
|
|
,SUM(ISNULL(t1e_a.FAMOUNT,0)) FAMOUNT,t1e.FSUBREQENTRYID AS FMOENTRYID
|
|
,SUM(t1e.FBASEACTUALQTY) AS 'FQTY'
|
|
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 t0.FID,t0.FBILLNO,t0e.FENTRYID,t0e.FMATERIALID AS MoMaterialId,t0e.FBOMID
|
|
,CONVERT(decimal(23,10),0) AS '入库数量'
|
|
,t1.FLOT,t1.FLOT_TEXT,t1.FMATERIALID,t1.FAMOUNT,t1.FMOENTRYID
|
|
,CONVERT(VARCHAR(36),t1.FFORMID) AS 'FFORMID'
|
|
,t0e.FBASEUNITQTY,t1.FQTY
|
|
,CASE WHEN t1.FQTY > ISNULL(t0e.FBASEUNITQTY,0) THEN 1 ELSE CONVERT(decimal(23,10),t1.FQTY / ISNULL(t0e.FBASEUNITQTY,t1.FQTY)) 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
|
|
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),t1.FFORMID) AS 'FFORMID'
|
|
,t0e.FQTY AS 'FBASEUNITQTY',t1.FQTY
|
|
,CASE WHEN t1.FQTY > ISNULL(t0e.FQTY,0) THEN 1 ELSE CONVERT(decimal(23,10),t1.FQTY / ISNULL(t0e.FQTY,t1.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),t0.FBILLNO) 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'
|
|
,t0.FQTY AS '领料数量'
|
|
,t0.FQTY AS '生产数量'
|
|
,t0.入库数量
|
|
,t0.FFORMID
|
|
,0 AS 'isTrue'
|
|
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(t0.FBILLNO,'')))
|
|
,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),t0.FQTY)
|
|
,t0.FBASEUNITQTY
|
|
,ISNULL(t0.入库数量,0) AS '入库数量'
|
|
,ISNULL(t0.FFORMID,'')
|
|
,CASE WHEN t0.FBILLNO = tt.MoBillNo THEN 1 ELSE 0 END AS 'isTrue'
|
|
FROM #整合数据 tt
|
|
CROSS APPLY (
|
|
SELECT *
|
|
FROM #领料单 t0
|
|
WHERE t0.FFORMID = tt.FFORMID
|
|
AND t0.FMOENTRYID = tt.MoEntryId
|
|
--AND CHARINDEX(t0.FBILLNO,tt.MPath) = 0
|
|
) t0
|
|
WHERE 1=1
|
|
AND tt.isTrue = 0
|
|
)
|
|
,#工单费用明细 AS (
|
|
SELECT
|
|
t0.FBILLID
|
|
,t0.FBILLENTRYID
|
|
,t0.FBILLSEQ
|
|
--,t2_l.FNAME AS '成本项目'
|
|
,t1e.FCOSTITEMID
|
|
--,t3_l.FNAME AS '费用项目'
|
|
,t1e.FEXPENSESITEMID
|
|
,t1e.FQUALIFIEDINAMOUNT AS 'FAMOUNT'
|
|
FROM (SELECT MoEntryId FROM #整合数据 WHERE MoId > 0) tt
|
|
INNER JOIN T_CB_PROORDERDIME t0 on t0.FBILLENTRYID = tt.MoEntryId
|
|
INNER JOIN V_CB_PROORDERINFO t0e ON t0e.FPRODUCTDIMEID = t0.FPRODUCTDIMEID
|
|
INNER JOIN V_CB_COSTCALEXPENSE t1 ON t1.FID = t0e.FID
|
|
INNER JOIN V_CB_COSTCALEXPENSEDETAIL t1e ON t1.FENTRYID = t1e.FENTRYID
|
|
)
|
|
, #费用项目 AS (
|
|
SELECT *
|
|
FROM (SELECT FBILLENTRYID AS 'EXP_BILLENTRYID',t1.fieldName AS '费用项目',FAMOUNT
|
|
FROM #工单费用明细 t0
|
|
LEFT JOIN (
|
|
SELECT '直接人工' AS 'FNAME',4655037 AS 'FEXPID','O1' AS 'fieldName'
|
|
UNION ALL SELECT '职工薪酬',4655057,'O2'
|
|
UNION ALL SELECT '股份支付',0,'O3'
|
|
UNION ALL SELECT '劳动保护费',0,'O4'
|
|
UNION ALL SELECT '差旅费',20138,'O5'
|
|
UNION ALL SELECT '差旅费',4655087,'O5'
|
|
UNION ALL SELECT '业务招待费',20137,'O6'
|
|
UNION ALL SELECT '办公费',20142,'O7'
|
|
UNION ALL SELECT '折旧与摊销',4655095,'O8'
|
|
UNION ALL SELECT '租赁费',20602,'O9'
|
|
UNION ALL SELECT '水电费',4655100,'O10'
|
|
UNION ALL SELECT '物料消耗',4655098,'O11'
|
|
UNION ALL SELECT '加工、修理、检测费',0,'O12'
|
|
UNION ALL SELECT '车辆使用费',0,'O13'
|
|
UNION ALL SELECT '制造费用-其他',4655093,'O14'
|
|
UNION ALL SELECT '委外加工费',20048,'O15'
|
|
UNION ALL SELECT '材料成本',20045,'O16'
|
|
) t1 on t0.FEXPENSESITEMID = t1.FEXPID
|
|
) t0
|
|
PIVOT
|
|
(
|
|
SUM(t0.FAMOUNT) FOR
|
|
t0.费用项目 IN (O1,O2,O3,O4,O5,O6,O7,O8,O9,O10,O11,O12,O13,O14,O15,O16)
|
|
) AS t1
|
|
)
|
|
, #成本项目 AS (
|
|
SELECT *
|
|
FROM (
|
|
SELECT FBILLENTRYID AS 'COST_BILLENTRYID',FAMOUNT
|
|
,t2_l.成本项目
|
|
FROM #工单费用明细 t0
|
|
LEFT JOIN (
|
|
SELECT FCOSTITEMID,CONCAT('P',ROW_NUMBER() OVER (ORDER BY t2_l.FCOSTITEMID)) 成本项目
|
|
FROM T_HS_COSTITEM_L t2_l
|
|
WHERE t2_l.FLOCALEID = 2052
|
|
) t2_l on t0.FCOSTITEMID = t2_l.FCOSTITEMID
|
|
) t0
|
|
PIVOT
|
|
(
|
|
SUM(t0.FAMOUNT) FOR
|
|
t0.成本项目 IN (P1,P2,P3,P4,P5,P6,P7,P8,P9,P10,P11,P12)
|
|
) AS t1
|
|
)
|
|
SELECT *
|
|
FROM #整合数据 tt
|
|
LEFT JOIN #成本项目 t0 on tt.MoEntryId = t0.COST_BILLENTRYID
|
|
LEFT JOIN #费用项目 t1 on tt.MoEntryId = t1.EXP_BILLENTRYID
|
|
DROP TABLE ##查找对应工单
|