Files
GateDge2023_ljy/03.珠海市汇威精密制造有限公司/HUIWEI.Python/ProductionMaterialsReport/sql/缺料分析查询报表.sql
PastSaid e1e6cba475 a
2024-04-22 09:39:19 +08:00

248 lines
7.7 KiB
Transact-SQL

DECLARE @needNum DECIMAL(23,6)
,@sDate varchar(100)
,@eDate varchar(100)
SET @needNum = 20
SET @sDate = '2024-03-01'
SET @eDate = '2024-03-24'
CREATE TABLE #TMPMATERIALINFO(MATERIALID int,needNum decimal(23,6))
INSERT INTO #TMPMATERIALINFO
SELECT
101521 AS 'MATERIALID'
,10 needNum
Union
SELECT
101530 AS 'MATERIALID'
,30 needNum
SELECT MATERIALID,SUM(needNum) needNum
INTO #TMPMATERIALNUM
FROM #TMPMATERIALINFO
GROUP BY MATERIALID
DROP TABLE #TMPMATERIALINFO
--SELECT @needNum AS 'needNum'
--,t0.FMATERIALID AS 'MATERIALID'
--INTO #TMPMATERIALNUM
--FROM T_BD_MATERIAL t0
--WHERE t0.FDOCUMENTSTATUS = 'C'
-- --AND t0.FMATERIALID = 100245
-- --AND t0.FMATERIALID = 122599
-- AND t0.FNUMBER IN ('1.02','1.05')
-- --AND t0.FMATERIALID IN (100259,100235)
SELECT t0.FMASTERID
,t0.FMATERIALID
,t0.FNUMBER
,t0.FUSEORGID
,t1.needNum AS 'ProMaterialQty'
INTO #ProMaterial
FROM T_BD_MATERIAL t0
INNER JOIN #TMPMATERIALNUM t1 on t0.FMATERIALID = t1.MATERIALID
WHERE t0.FDOCUMENTSTATUS = 'C'
CREATE TABLE #PRO_MATERIAL_LACKANALYE(
FIDENTITYID int not null default 0
,ProMaterialId int not null default 0
,BomId int
,产品代码 varchar(100) default ''
,产品名称 varchar(100) default ''
,产品_分析需求数 decimal(23,6) default 0
,产品_即时库存 decimal(23,6) default 0
,产品_未发数 decimal(23,6) default 0
,产品_在制数 decimal(23,6) default 0
,产品_受订量 decimal(23,6) default 0
,产品_在途量 decimal(23,6) default 0
,产品_可用库存数 decimal(23,6) default 0
,产品_实际需求数 decimal(23,6) default 0
,BOMLEVEL int
,IsProduct int
,物料个数分组合计 int
)
CREATE TABLE #MATERIAL_LACKANALYE(
FIDENTITYID int not null default 0
,MaterialId int not null default 0
,BomId int
,物料代码 varchar(100) default ''
,物料名称 varchar(100) default ''
,物料_分析需求数 decimal(23,6) default 0
,物料_即时库存 decimal(23,6) default 0
,物料_未发数 decimal(23,6) default 0
,物料_在制数 decimal(23,6) default 0
,物料_受订量 decimal(23,6) default 0
,物料_在途量 decimal(23,6) default 0
,物料_可用库存数 decimal(23,6) default 0
,物料_实际需求数 decimal(23,6) default 0
,BOMLEVEL int
,IsProduct int
,物料个数分组合计 int
)
SELECT t0.FMATERIALID
,ISNULL(t3.sumQTY,0) AS 即时库存
,ISNULL(t4.sumBASENOPICKEDQTY,0) AS 未发数
,ISNULL(t5.sumNoStockInQty,0) AS 在制数
,ISNULL(t1.数量 - t1.未发数量,0) AS '受订量'
,ISNULL(t2.数量 - t2.入库数量,0) AS '在途量'
,(ISNULL(t3.sumQTY,0) - ISNULL(t4.sumBASENOPICKEDQTY,0) + ISNULL(t5.sumNoStockInQty,0) - ISNULL(t1.数量 - t1.未发数量,0) + ISNULL(t2.数量 - t2.入库数量,0)) AS '可用库存'
INTO #Material_Stock_Statu
FROM T_BD_MATERIAL t0
LEFT JOIN (
SELECT
t0e.FMATERIALID,SUM(t0e.FQTY) AS '数量'
,SUM((t0e_r.FBASEREMAINOUTQTY + t0e_r.FBASERETURNQTY)) AS '未发数量'
FROM T_SAL_ORDER t0
INNER JOIN T_SAL_ORDERENTRY t0e on t0.FID = t0e.FID
INNER JOIN T_SAL_ORDERENTRY_R t0e_r on t0e.FID = t0e_r.FID AND t0e_r.FENTRYID = t0e.FENTRYID
WHERE t0.FDOCUMENTSTATUS = 'C'
AND t0.FCANCELSTATUS = 'A'
AND t0.FCLOSESTATUS = 'A'
AND t0.FDATE between @sDate AND @eDate
GROUP BY t0e.FMATERIALID
) t1 on t1.FMATERIALID = t0.FMATERIALID
LEFT JOIN (
SELECT
t0e.FMATERIALID,SUM(t0e.FQTY) AS '数量'
,SUM(t0e_r.FREMAINSTOCKINQTY) AS '剩余入库数量'
,SUM(t0e_r.FBASESTOCKINQTY) AS '入库数量'
FROM T_PUR_POORDER t0
INNER JOIN T_PUR_POORDERENTRY t0e on t0.FID = t0e.FID AND t0.FBUSINESSTYPE != 'ZCCG' AND t0.FBUSINESSTYPE != 'FYCG'
INNER JOIN T_PUR_POORDERENTRY_R t0e_r on t0e.FID = t0e_r.FID AND t0e_r.FENTRYID = t0e.FENTRYID
WHERE t0.FDOCUMENTSTATUS = 'C'
AND t0.FCANCELSTATUS = 'A'
AND t0.FCLOSESTATUS = 'A'
AND t0.FDATE BETWEEN @sDate AND @eDate
GROUP BY t0e.FMATERIALID
) t2 on t2.FMATERIALID = t0.FMATERIALID
LEFT JOIN (
SELECT tt0.FMATERIALID,tt0.FSTOCKORGID,SUM(tt0.FBASEQTY) AS sumQTY
FROM T_STK_INVENTORY tt0
GROUP BY tt0.FMATERIALID,tt0.FSTOCKORGID
) t3 on t3.FMATERIALID = t0.FMASTERID AND t3.FSTOCKORGID = t0.FUSEORGID
LEFT JOIN (
SELECT t0e.FMATERIALID,SUM(t0e_q.FBASENOPICKEDQTY) sumBASENOPICKEDQTY
FROM T_PRD_PPBOMENTRY t0e
INNER JOIN T_PRD_PPBOMENTRY_Q t0e_q on t0e.FENTRYID = t0e_q.FENTRYID
INNER JOIN T_PRD_MOENTRY_A t0e_a on t0e_a.FENTRYID = t0e.FMOENTRYID
WHERE t0e_a.FSTATUS = 4
GROUP BY t0e.FMATERIALID
) t4 on t4.FMATERIALID = t0.FMATERIALID
LEFT JOIN (
SELECT t0e.FMATERIALID,SUM(t0e_q.FNOSTOCKINQTY) AS sumNoStockInQty
FROM T_PRD_MOENTRY t0e
INNER JOIN T_PRD_MOENTRY_Q t0e_q on t0e.FENTRYID = t0e_q.FENTRYID
INNER JOIN T_PRD_MOENTRY_A t0e_a on t0e_a.FENTRYID = t0e.FENTRYID
WHERE t0e_a.FSTATUS = 4
GROUP BY t0e.FMATERIALID
) t5 on t5.FMATERIALID = t0.FMATERIALID
WHERE t0.FDOCUMENTSTATUS = 'C'
AND t0.FFORBIDSTATUS = 'A'
INSERT INTO #MATERIAL_LACKANALYE
SELECT
ROW_NUMBER() OVER (ORDER BY t0.FMATERIALID)
,t0.FMATERIALID
,t1.FID
,t2.FNUMBER
,t2_l.FNAME
,t0.ProMaterialQty
,t3.即时库存
,t3.未发数
,t3.在制数
,t3.受订量
,t3.在途量
,t3.可用库存
,(CASE
WHEN t3.可用库存 > t0.ProMaterialQty THEN 0
ELSE t3.可用库存 - t0.ProMaterialQty
END)
,0
,1
,1
FROM #ProMaterial t0
INNER JOIN (
SELECT tt.FID,tt.FMATERIALID,ROW_NUMBER() OVER (PARTITION BY tt.FMATERIALID ORDER BY tt.FID DESC) AS 'rn' FROM T_ENG_BOM tt
WHERE 1 = 1
AND tt.FDOCUMENTSTATUS = 'C'
AND tt.FFORBIDSTATUS = 'A'
) t1 on t0.FMATERIALID = t1.FMATERIALID AND t1.rn = 1 --AND t0.FUSEORGID = t1.FUSEORGID
INNER JOIN T_BD_MATERIAL t2 on t2.FMATERIALID = t1.FMATERIALID
INNER JOIN T_BD_MATERIAL_L t2_l on t2_l.FMATERIALID = t1.FMATERIALID AND t2_l.FLOCALEID = 2052
LEFT JOIN #Material_Stock_Statu t3 on t1.FMATERIALID = t3.FMATERIALID
WHERE 1 = 1
--AND EXISTS (SELECT COUNT(1) FROM T_ENG_BOM tt GROUP BY tt.FMATERIALID HAVING MAX(tt.FID) = t1.FID)
--AND t1.FDOCUMENTSTATUS = 'C'
--AND t1.FFORBIDSTATUS = 'A'
ORDER BY
t0.FNUMBER
--INSERT INTO #MATERIAL_LACKANALYE
--SELECT * FROM #PRO_MATERIAL_LACKANALYE
DECLARE @num INT,@level int,@LoopCount int
SET @num = 1
SET @level =0
SET @LoopCount = 0;
WHILE (@num <> 0 AND @LoopCount < 10)
BEGIN
INSERT INTO #MATERIAL_LACKANALYE(MaterialId,BomId,物料_分析需求数,物料_即时库存,物料_未发数,物料_在制数,物料_受订量,物料_在途量,物料_可用库存数,物料_实际需求数,BOMLEVEL,物料个数分组合计,IsProduct)
SELECT
tt.FMATERIALID
,ISNULL(t2.FID,0) AS BomId
,ABS(tt.汇总_分析需求数)
,t3.即时库存
,t3.未发数
,t3.在制数
,t3.受订量
,t3.在途量
,t3.可用库存
,(CASE
WHEN t3.可用库存 > (ABS(tt.汇总_分析需求数) + ISNULL(t4.上级_实际需求数,0)) THEN 0
ELSE t3.可用库存 - (ABS(tt.汇总_分析需求数) + ISNULL(t4.上级_实际需求数,0))
END) AS '实际需求数'
,@level + 1
,tt.co
,0
FROM (
SELECT
t1.FMATERIALID
,SUM(t0.物料_实际需求数 * (t1.FNUMERATOR / t1.FDENOMINATOR)) AS '汇总_分析需求数'
,count(1) co
FROM
#MATERIAL_LACKANALYE t0
INNER JOIN T_ENG_BOMCHILD t1 on t0.BomId = t1.FID
WHERE 1 = 1
AND t0.BOMLEVEL = @level
GROUP BY t1.FMATERIALID
) tt
LEFT JOIN (
SELECT tt3.FID,tt3.FNUMBER,tt3.FMATERIALID,ROW_NUMBER() OVER (PARTITION BY tt3.FMATERIALID ORDER BY tt3.FID DESC) AS 'rn'
FROM T_ENG_BOM tt3
WHERE 1 = 1 AND tt3.FDOCUMENTSTATUS = 'C' AND tt3.FFORBIDSTATUS = 'A'
) t2 ON t2.rn = 1 AND tt.FMATERIALID = t2.FMATERIALID
LEFT JOIN #Material_Stock_Statu t3 on t3.FMATERIALID = tt.FMATERIALID
LEFT JOIN (
SELECT tt.MaterialId,sum(tt.物料_实际需求数) AS '上级_实际需求数' FROM #MATERIAL_LACKANALYE tt GROUP BY tt.MaterialId
) t4 on t4.MaterialId = tt.FMATERIALID
SET @num = @@ROWCOUNT
SET @level += 1
SET @LoopCount += 1
END
UPDATE t0 SET
t0.物料代码 = t1.FNUMBER
,t0.物料名称 = t1_l.FNAME
FROM #MATERIAL_LACKANALYE t0
INNER JOIN T_BD_MATERIAL t1 on t0.MaterialId = t1.FMATERIALID
INNER JOIN T_BD_MATERIAL_L t1_l on t0.MaterialId = t1_l.FMATERIALID AND t1_l.FLOCALEID = 2052
SELECT t0.* FROM #MATERIAL_LACKANALYE t0
DROP TABLE #ProMaterial
DROP TABLE #TMPMATERIALNUM
DROP TABLE #PRO_MATERIAL_LACKANALYE
DROP TABLE #MATERIAL_LACKANALYE
DROP TABLE #Material_Stock_Statu