DECLARE @needNum DECIMAL(23,6) ,@sDate varchar(100) ,@eDate varchar(100) ,@dbName varchar(100) SET @needNum = 20 SET @sDate = '2024-02-24' SET @eDate = '2024-03-24' select @dbName = db_name() 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 ,BOMLEVEL int ,IsProduct int default 0 ,物料个数分组合计 int ) SELECT t0.FMATERIALID ,ISNULL(t3.sumQTY,0) AS 即时库存 ,ISNULL(t4.sumBASENOPICKEDQTY,0) AS 未发数 ,ISNULL(t5.sumNoStockInQty,0) AS 在制数 ,CASE WHEN CHARINDEX('TC',t0.FNUMBER) = 1 THEN 0 ELSE ISNULL(t1.数量 - t1.未发数量,0) END 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 '可用库存' ,ISNULL(t6.进检量,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.FNOPICKEDQTY) 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 LEFT JOIN ( SELECT t0e.FMATERIALID,SUM(FBASEUNITQTY-FINSTOCKBASEQTY + FRETURNBASEQTY) AS '进检量' FROM T_PUR_RECEIVE t0 INNER JOIN T_PUR_RECEIVEENTRY t0e on t0.FID = t0e.FID INNER JOIN T_PUR_RECEIVEENTRY_R t0e_r on t0e.FID = t0e_r.FID AND t0e.FENTRYID = t0e_r.FENTRYID INNER JOIN T_PUR_RECEIVEENTRY_S t0e_s on t0e.FID = t0e_s.FID AND t0e.FENTRYID = t0e_s.FENTRYID WHERE t0.FDOCUMENTSTATUS = 'C' AND t0.FCANCELSTATUS = 'A' AND t0.FCLOSESTATUS = 'A' AND t0.FDATE BETWEEN @sDate AND @eDate GROUP BY t0e.FMATERIALID ) t6 on t6.FMATERIALID = t0.FMATERIALID WHERE t0.FDOCUMENTSTATUS = 'C' AND t0.FFORBIDSTATUS = 'A' UPDATE #Material_Stock_Statu SET 可用库存 = 即时库存 - 未发数 - 受订量 + 在制数 + 在途量; WITH #TMPMATERIALNUM AS ( --把需要分析的物料id跟数据量分组统计 SELECT tt.MATERIALID,SUM(tt.needNum) needNum FROM ( SELECT CASE @dbName WHEN 'AIS20231110222743' THEN 101521 ELSE 782449 END AS 'MATERIALID' ,10 needNum --UNION ALL --SELECT --CASE @dbName WHEN 'AIS20231110222743' THEN 101530 ELSE 808372 END AS 'MATERIALID' --,30 needNum ) tt GROUP BY tt.MATERIALID ), #ProMaterial AS( SELECT t0.FMASTERID ,t0.FMATERIALID ,t0.FNUMBER ,t0.FUSEORGID ,t1.needNum AS 'ProMaterialQty' FROM T_BD_MATERIAL t0 INNER JOIN #TMPMATERIALNUM t1 on t0.FMATERIALID = t1.MATERIALID WHERE t0.FDOCUMENTSTATUS = 'C' )INSERT INTO #MATERIAL_LACKANALYE SELECT ROW_NUMBER() OVER (ORDER BY t0.FMATERIALID) ,t0.FMATERIALID ,t1.FID ,t2.FNUMBER ,t2_l.FNAME ,t0.ProMaterialQty ,t3.可用库存 ,(CASE CHARINDEX('TC',t0.FNUMBER) WHEN 1 THEN 0 - t0.ProMaterialQty ELSE (CASE WHEN t3.可用库存 > t0.ProMaterialQty THEN 0 ELSE t3.可用库存 - t0.ProMaterialQty END) END) ,0 'BOMLEVEL',1 'IsProduct',1 '物料个数分组合计' FROM #ProMaterial t0 CROSS APPLY ( SELECT TOP 1 tt.FID,tt.FMATERIALID FROM T_ENG_BOM tt WHERE 1 = 1 AND t0.FMATERIALID = tt.FMATERIALID AND tt.FDOCUMENTSTATUS = 'C' AND tt.FFORBIDSTATUS = 'A' ORDER BY tt.FID DESC ) t1 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 DECLARE @num INT,@level int,@LoopCount int SET @num = 1 SET @level =0 SET @LoopCount = 0; WHILE (@num != 0 AND @LoopCount < 10) BEGIN WITH t1 AS( SELECT tt.FMATERIALID ,ISNULL(t2.FID,0) AS 'BomId' ,ABS(tt.汇总_分析需求数) '汇总_分析需求数' ,t3.可用库存 ,(CASE WHEN t3.可用库存 > (ABS(tt.汇总_分析需求数) - ISNULL(t4.上级_实际需求数,0)) THEN 0 ELSE t3.可用库存 - (ABS(tt.汇总_分析需求数) - ISNULL(t4.上级_实际需求数,0)) END) AS '实际需求数' ,@level + 1 lv ,tt.物料个数分组合计 FROM ( --获取BOM子项物料 SELECT t1.FMATERIALID,COUNT(1) AS '物料个数分组合计' ,SUM(t0.物料_实际需求数 * (t1.FNUMERATOR / t1.FDENOMINATOR)) AS '汇总_分析需求数' 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 OUTER APPLY ( --获取最新层级物料的最新BOM SELECT TOP 1 tt3.FID,tt3.FNUMBER,tt3.FMATERIALID FROM T_ENG_BOM tt3 WHERE 1 = 1 AND tt3.FDOCUMENTSTATUS = 'C' AND tt3.FFORBIDSTATUS = 'A' AND tt.FMATERIALID = tt3.FMATERIALID ORDER BY tt3.FID DESC ) t2 LEFT JOIN #Material_Stock_Statu t3 on t3.FMATERIALID = tt.FMATERIALID OUTER APPLY ( --统计BOM子项物料已存在临时表中的物料的需求数 SELECT ABS(SUM(tt4.物料_实际需求数)) AS '上级_实际需求数' FROM #MATERIAL_LACKANALYE tt4 WHERE tt4.MaterialId = tt.FMATERIALID GROUP BY tt4.MaterialId ) t4 ) INSERT INTO #MATERIAL_LACKANALYE(MaterialId,BomId,物料_分析需求数,物料_可用库存数,物料_实际需求数,BOMLEVEL,物料个数分组合计) SELECT t1.FMATERIALID,t1.BomId,t1.汇总_分析需求数,t1.可用库存,t1.实际需求数,t1.lv,t1.物料个数分组合计 FROM t1 SET @num = @@ROWCOUNT SET @level += 1 SET @LoopCount += 1 END SELECT ROW_NUMBER() OVER (ORDER BY t0.BOMLEVEL,t1.FNumber) 'FIDENTITYID' ,t0.MATERIALID,t0.IsProduct,t1_l.FNAME,t1.FNUMBER ,t0.物料_分析需求数,t0.物料_实际需求数 ,t2.即时库存 AS '物料_即时库存',t2.未发数 AS '物料_未发数',t2.在制数 AS '物料_在制数' ,t2.受订量 AS '物料_受订量',t2.在途量 AS '物料_在途量',t2.可用库存 AS '物料_可用库存数',t2.进检量 AS '物料_进检量' ,t0.物料个数分组合计 FROM ( SELECT t0.MATERIALID ,SUM(t0.物料_实际需求数) AS '物料_实际需求数' ,SUM(t0.物料_分析需求数) AS '物料_分析需求数' ,MAX(t0.BOMLEVEL) AS 'BOMLEVEL' ,MAX(t0.IsProduct) AS 'IsProduct' ,SUM(t0.物料个数分组合计) AS '物料个数分组合计' FROM #MATERIAL_LACKANALYE t0 GROUP BY t0.MATERIALID ) 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 INNER JOIN #Material_Stock_Statu t2 on t2.FMATERIALID = t0.MATERIALID DROP TABLE #MATERIAL_LACKANALYE DROP TABLE #Material_Stock_Statu