Files
GateDge2023_ljy/07.珠海英搏尔/Enpower.Python/产品成本还原报表V8.0.sql
PastSaid fa480006a8 1
2024-07-16 10:33:50 +08:00

149 lines
4.3 KiB
Transact-SQL

IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#生产订单') IS NOT NULL)
DROP TABLE #生产订单
GO
IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#数据整合') IS NOT NULL)
DROP TABLE #数据整合
GO
IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#关联项目费用临时表') IS NOT NULL)
DROP TABLE [dbo].[#关联项目费用临时表]
GO
declare @sqlL varchar(max)
declare @billNo varchar(100),@materialNumber varchar(100)
declare @dbName varchar(100)
CREATE TABLE #生产订单(
[FBILLNO] nvarchar (255) NOT 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]
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 = 'WO2304230023'
SET @billNo = 'RO2403280019'
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)
CREATE TABLE #数据整合 (
MoBillNo varchar(255) not null
,PMoBillNo varchar(255) not null
,直接材料 decimal(23,10) NOT NULL
,领料比例 decimal(23,10) NOT NULL
,FPRODUCTDIMEID INT NOT NULL
,plevel int not null
,BillId int not null
,BillEntryId int not null
,FMATERIALID int not null
,lot_text varchar(255) null
,APath varchar(1000) null
,PPath varchar(1000) null
,MPath varchar(8000) null
)
DECLARE @num INT,@level int,@LoopCount int
SET @num = 1
SET @level =1
SET @LoopCount = 0;
INSERT INTO #数据整合
SELECT tt.FBILLNO,'',0,1,0,0
,tt.FID,tt.FENTRYID,tt.FMATERIALID,''
,CONVERT(varchar(1000),ROW_NUMBER() OVER (ORDER BY tt.FID,tt.FENTRYID))
,CONVERT(varchar(1000),'0'),''
FROM #生产订单 tt
WHILE(@num!=0 AND @LoopCount < 30)
BEGIN
INSERT INTO #数据整合
SELECT ISNULL(t5.FBILLNO,''),tt.MoBillNo,t0.成本 * tt.领料比例,t0.FPRODUCTDIMEID,@level
,ISNULL(t5e.FID,0),ISNULL(t5e.FENTRYID,0),t0.FMATERIALID,ISNULL(t4.FNUMBER,'')
,CONVERT(varchar(1000),CONCAT(tt.APath,'.',ROW_NUMBER() OVER (PARTITION BY tt.BillId ORDER BY tt.BillEntryId)))
,tt.APath,''
FROM #数据整合 tt
INNER JOIN T_CB_PROORDERDIME tt0 on tt.BillId != 0 AND tt.BillEntryId != 0
AND tt.BillId = tt0.FBILLID AND tt.BillEntryId = tt0.FBILLENTRYID
CROSS APPLY (
SELECT
t1.FPRODUCTDIMEID
,SUM(t1.FAMOUNT) '成本'
,t2.FMATERIALID,t2.FLOT
FROM V_CB_COSTALLORESULTSEND t1
INNER JOIN T_HS_INIVSTOCKDIMENSION t2 on t2.FENTRYID = t1.FDIMEENTRYID
INNER JOIN V_HS_OUTINSTOCKSEQ t3 on t3.FENTRYID = t1.FOUTINSTOCKID
WHERE tt0.FPRODUCTDIMEID = t1.FPRODUCTDIMEID
GROUP BY t1.FPRODUCTDIMEID,t2.FMATERIALID,t2.FLOT
) t0
LEFT JOIN T_BD_LOTMASTER t4 on t4.FLOTID = t0.FLOT
LEFT JOIN T_PRD_MO t5 on t5.FBILLNO = t4.FNUMBER
LEFT JOIN T_PRD_MOENTRY t5e on t5.FID = t5e.FID
WHERE tt.plevel = @level - 1
AND CHARINDEX(tt.MoBillNo,tt.MPath) = 0
SET @num = @@ROWCOUNT
SET @level += 1
SET @LoopCount += 1
END
SELECT
tt.*
,CASE ISNULL(t1.本期投入金额, 0) WHEN 0 THEN 0
ELSE (tt.直接材料 / ISNULL(t1.本期投入金额,0) * ISNULL(t1.本期完工入库金额,0))
END AS '完工金额'
FROM #数据整合 tt
OUTER APPLY (
SELECT
t1.FPRODUCTDIMEID
,t2.FMATERIALID
,SUM(t2.FQUALIFIEDINQTY) '本期完工入库数量'
,SUM(t2e.FQUALIFIEDINAMOUNT) AS '本期完工入库金额'
,SUM(t2.FCURRINPUTAMOUNT) AS '本期投入金额'
FROM V_CB_PROORDERINFO t1
INNER JOIN V_CB_COSTMATTERIAL t2 on t2.FID = t1.FID
INNER JOIN V_CB_COSTMATTERIALDETAIL t2e on t2.FENTRYID = t2e.FENTRYID
WHERE 1=1
AND t2.FEXPTYPE = 0
AND t1.FPRODUCTDIMEID = tt.FPRODUCTDIMEID
AND t2.FMATERIALID = tt.FMATERIALID
AND t2e.FEXPENSESITEMID = 20045
AND t2e.FCOSTITEMID = 20522
GROUP BY t1.FPRODUCTDIMEID
,t2.FMATERIALID
) t1