/****** Object: StoredProcedure [dbo].[Pro_YEB_MaterialInventory] Script Date: 2024-03-08 14:18:49 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO --sp_helptext Pro_YEB_MaterialInventory --exec Pro_YEB_MaterialInventory '','',0 --库存表状态报表 alter procedure [dbo].[Pro_YEB_MaterialInventory] ( @FNumber varchar (max) , @FStock varchar (max) , @Flag bit ) AS set nocount on --生成临时选取仓库 DECLARE @sStock varchar(max), @sNumber varchar(max) ----测试用数据 --set @sStock='' --set @sNumber='' set @sStock=@FStock set @sNumber=@FNumber if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpStockID')) BEGIN drop table #tmpStockID END Create Table #tmpStockID ( FID INT IDENTITY(1,1), FStockID INT , ) DECLARE @Strsql varchar(max) set @Strsql= 'insert into #tmpStockID SELECT distinct FSTOCKID FROM T_BD_STOCK where 1=1 '+@sStock EXEC(@Strsql) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpMaterialID')) BEGIN drop table #tmpMaterialID END Create Table #tmpMaterialID ( FID INT IDENTITY(1,1), FMaterialID INT , ) DECLARE @Ssql varchar(max) set @Ssql= 'insert into #tmpMaterialID SELECT distinct FMATERIALID FROM T_BD_MATERIAL where 1=1 and FUSEORGID=1 '+@sNumber -- and FNUMBER=''1.W003'' EXEC(@Ssql) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#Stock_Status_temp')) BEGIN drop table #Stock_Status_temp END Create Table #Stock_Status_temp ( 序号 INT IDENTITY(1,1), 物料内码 INT , 物料代码 varchar(100) null , 物料名称 varchar(255) null , 规格型号 varchar(255) null , 物料属性 varchar(50) null , 单位 varchar(30) null , 品牌 varchar(255) null , --FLT1 varchar(255) null , FLT int null , 安全库存 DECIMAL (18, 2) Null , 现有库存 DECIMAL (18, 2) Null , 预计入库 DECIMAL (18, 2) Null , 未推PR DECIMAL (18, 2) Null , 已分配量 DECIMAL (18, 2) Null , 理论结存 DECIMAL (18, 2) Null , 计划员 varchar(255) null , 采购员 varchar(100) null ) CREATE INDEX IDX_MaterialID ON #Stock_Status_temp (物料内码) --drop table #YC_Sum_MRP F_PKGR_Brand 品牌 L/T F_PKGR_HUMIDITYSENSITIVITY 采购员 insert into #Stock_Status_temp ( 物料内码 ,物料代码 ,物料名称 , 规格型号,物料属性,单位, 安全库存, 计划员) SELECT TM.fmaterialid AS 物料内码,TM.fnumber,n.FNAME AS 物料名称,n.FSPECIFICATION AS 规格型号, (case when TMB.FERPCLSID=1 THEN '外购' when TMB.FERPCLSID=2 THEN '自制' when TMB.FERPCLSID=3 THEN '委外' when TMB.FERPCLSID=5 THEN '虚拟' else '其他'END) '物料属性', TUL1.FNAME '单位',isnull(TMP.FPLANSAFESTOCKQTY,0) AS '安全库存' ,ISNULL(PL.FNAME,'') AS '计划员' FROM t_bd_material TM inner join T_BD_MATERIAL_L n on TM.FMATERIALID =n.FMATERIALID and n.FLOCALEID =2052 inner join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT OUTER JOIN T_BD_MATERIALBASE TMB on TM.FMATERIALID = TMB.FMATERIALID LEFT OUTER JOIN T_BD_MATERIALPLAN TMP ON TM.FMATERIALID=TMP.FMATERIALID LEFT OUTER JOIN T_BD_UNIT_L TUL1 ON ( TMS.FSTOREUNITID = TUL1.FUNITID AND TUL1.FLOCALEID = 2052) LEFT OUTER JOIN V_BD_PLANNER_L PL ON ( TMP.FPLANERID = PL.fid AND PL.FLOCALEID = 2052) where TM.FDOCUMENTSTATUS='C' AND TM.FFORBIDSTATUS ='A' and TMB.FERPCLSID<>5 and TM.FMATERIALID in ( SELECT distinct FMATERIALID FROM #tmpMaterialID) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tempINV')) BEGIN drop table #tempINV END -- 即时库存,可用库存 SELECT TM.fmaterialid AS 物料内码,TM.fnumber,n.FNAME AS 物料名称,n.FSPECIFICATION AS 规格型号, TUL1.FNAME '基本单位',t1.FSTOCKID ,TSK.FNUMBER AS FStockNumber,TSL.FNAME '仓库', t1.FBASEQTY '基本单位库存量', (isnull(t1.FBASEQTY,0) - isnull(TSUB.FBASELOCKQTY,0)) AS '可用库存' into #tempINV --SELECT * FROM t_bd_material TM inner join T_BD_MATERIAL_L n on TM.FMATERIALID =n.FMATERIALID and n.FLOCALEID =2052 inner join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT OUTER JOIN T_BD_MATERIALPLAN TMP ON TM.FMATERIALID=TMP.FMATERIALID inner join T_STK_INVENTORY t1 on TM.FMASTERID = t1.FMATERIALID AND TM.FUSEORGID = t1.FSTOCKORGID and t1.FBASEQTY > 0 LEFT OUTER JOIN T_ORG_ORGANIZATIONS_L O ON ( t1.FSTOCKORGID = O.FORGID AND O.FLOCALEID = 2052) --机构名称 INNER JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = t1.FSTOCKID AND ( TSK.FUSEORGID = t1.FSTOCKORGID)) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = t1.FSTOCKID AND TSL.FLOCALEID = 2052) LEFT OUTER JOIN T_BD_UNIT TUS ON TMS.FSTOREUNITID = TUS.FUNITID LEFT OUTER JOIN T_BD_UNIT_L TUL0 ON (TMS.FSTOREUNITID = TUL0.FUNITID AND TUL0.FLOCALEID = 2052) LEFT OUTER JOIN T_BD_UNIT_L TUL1 ON ( t1.FBASEUNITID = TUL1.FUNITID AND TUL1.FLOCALEID = 2052) --以下锁库和预留 LEFT OUTER JOIN ( SELECT TLKE.FSUPPLYINTERID finventryid,SUM (TLKE.FBASEQTY) fbaselockqty, SUM (TLKE.FSECQTY) fseclockqty FROM T_PLN_RESERVELINKENTRY TLKE INNER JOIN T_PLN_RESERVELINK TLKH ON TLKE.FID = TLKH.FID WHERE (TLKE.FSUPPLYFORMID = 'STK_Inventory' AND TLKE.FLINKTYPE = '4' ) GROUP BY TLKE.FSUPPLYINTERID) tsub ON t1.FID = TSUB.FINVENTRYID WHERE -- TM.FUSEORGID =100038 and ((t1.FBASEQTY <> 0) OR (t1.FSECQTY <> 0)) and TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tempINVSum')) BEGIN drop table #tempINVSum END --insert into #Stock_Status_temp ( 物料内码 ,物料代码 ,物料名称 , 规格型号,单位, 仓库内码, 仓库名称, 仓库代码 ,即时库存,可用库存) SELECT 物料内码,fnumber, 物料名称, 规格型号, min(基本单位)单位,min(FSTOCKID)FSTOCKID ,min( FStockNumber)FStockNumber, min(仓库)仓库, sum(基本单位库存量)基本单位库存量 ,sum(可用库存) 可用库存 into #tempINVSum FROM #tempINV group BY 物料内码,fnumber, 物料名称, 规格型号 --即时库存,可用库存 UPDATE t1 set t1.现有库存=isnull(t2.可用库存,0)--,t1.仓库内码=t2.FSTOCKID, t1.仓库名称=t2.仓库, t1.仓库代码=t2.FStockNumber FROM #Stock_Status_temp t1 inner join #tempINVSum t2 on t1.物料内码=t2.物料内码 --SELECT * FROM #Stock_Status_temp --在途量 (预计入库) --************************预计入库************************ UPDATE t1 set t1.预计入库=0 FROM #Stock_Status_temp t1 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmppoorder')) BEGIN drop table #tmppoorder END --采购订单 SELECT ddd.FPurchaseOrgID fstockorgid, ddd.FBILLNO 采购订单 ,ddd.FID AS 采购内码 , B.FENTRYID 采购订单分录,b.FMATERIALID 物料内码, ddd.FDATE fdate, TMS.FSTOCKID 仓库内码, FBASEUNITQTY 采购数量 , FREMAINSTOCKINQTY 剩余入库数量,FBASESTOCKINQTY 入库数量,ddd.FCLOSEDATE into #tmppoorder --SELECT * FROM t_pur_poorderentry b INNER JOIN t_pur_poorder ddd ON (ddd.FID = b.FID)-- AND FbusinessType NOT IN ('ZCCG', 'FYCG')) INNER JOIN t_pur_poorderentry_r r ON b.fentryid = r.fentryid INNER JOIN t_pur_poorderentry_d td ON b.fentryid = td.fentryid LEFT OUTER JOIN T_BD_MATERIALSTOCK TMS ON b.FMATERIALID = TMS.FMATERIALID WHERE ddd.FCANCELSTATUS='A'--AND ddd.fdocumentStatus = 'C' and b.FMRPCLOSESTATUS='A' and ddd.FCLOSESTATUS='A' and b.FMRPTERMINATESTATUS='A' and ddd.FBILLTYPEID not in( '6d01d059713d42a28bb976c90a121142','65445fa4673247')--外委订单类型 --ddd.FBILLNO ='CGDD000005' --AND (ddd.FDATE <=@FEDate) --AND (ddd.FCLOSEDATE>@FSDate or isnull(ddd.FCLOSEDATE,'')='' if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmppoorder1')) BEGIN drop table #tmppoorder1 END --更新和新增在途量数据 SELECT 物料内码,采购数量, 剩余入库数量,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmppoorder1 FROM #tmppoorder B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmppoorder3')) BEGIN drop table #tmppoorder3 END SELECT 物料内码,采购数量, 剩余入库数量, 仓库内码 into #tmppoorder3 FROM #tmppoorder1 B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID )--TM.FUSEORGID =1 and LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmppoorder2')) BEGIN drop table #tmppoorder2 END SELECT 物料内码,sum(采购数量)采购数量, sum(剩余入库数量)剩余入库数量 , min(仓库内码 )仓库内码 into #tmppoorder2 FROM #tmppoorder3 group BY 物料内码 --group BY 仓库内码,物料内码 ORDER BY 物料内码 --在途量 UPDATE t1 set t1.预计入库=isnull(t2.剩余入库数量,0) FROM #Stock_Status_temp t1 inner join #tmppoorder2 t2 on t1.物料内码=t2.物料内码 --生产订单 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpMo')) BEGIN drop table #tmpMo END --生产订单 SELECT (MO.FBILLNO) 生产单号 ,(MO.FID) 生产内码,(ME.FENTRYID) 生产单分录, ME.FMATERIALID 物料内码, (ME.FBASEUNITQTY) AS 生产数量, MA.FSTOCKINQUAQTY AS 基本入库数,MQ.FBASENOSTOCKINQTY AS 剩余入库数量 , TMS.FSTOCKID 仓库内码 into #tmpMo FROM T_PRD_MO MO inner join T_PRD_MOENTRY ME ON MO.FID =ME.FID inner JOIN T_PRD_MOENTRY_A MA ON MA.FID =ME.FID AND ME.FENTRYID =MA.FENTRYID inner JOIN T_PRD_MOENTRY_Q MQ ON MQ.FID =ME.FID AND ME.FENTRYID =MQ.FENTRYID LEFT OUTER JOIN T_BD_MATERIALSTOCK TMS ON ME.FMATERIALID = TMS.FMATERIALID WHERE MO.FCANCELSTATUS='A' and MA.FSTATUS in (2,3,4) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpMo1')) BEGIN drop table #tmpMo1 END --更新和新增在制量数据 SELECT 物料内码,生产数量, 剩余入库数量,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmpMo1 FROM #tmpMo B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpMo2')) BEGIN drop table #tmpMo2 END SELECT 物料内码,生产数量, 剩余入库数量, 仓库内码 into #tmpMo2 FROM #tmpMo1 B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID )--TM.FUSEORGID =1 and LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpMo3')) BEGIN drop table #tmpMo3 END SELECT 物料内码,sum(生产数量)采购数量, sum(剩余入库数量)剩余入库数量 , min(仓库内码 )仓库内码 into #tmpMo3 FROM #tmpMo2 group BY 物料内码 --group BY 仓库内码,物料内码 ORDER BY 物料内码 --预计入库 UPDATE t1 set t1.预计入库=isnull(t2.剩余入库数量,0) FROM #Stock_Status_temp t1 inner join #tmpMo3 t2 on t1.物料内码=t2.物料内码 --外委订单 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubMo')) BEGIN drop table #tmpSubMo END --外委订单 SELECT (MO.FBILLNO) 外委单号 ,(MO.FID) 外委单内码,(ME.FENTRYID) 外委单分录, ME.FMATERIALID 物料内码, (MA.FBASEUNITQTY) AS 生产数量, MA.FBASESTOCKINQTY AS 基本入库数,MA.FBASENOSTOCKINQTY AS 剩余入库数量 , TMS.FSTOCKID 仓库内码 into #tmpSubMo FROM T_SUB_REQORDER MO inner join T_SUB_REQORDERENTRY ME ON MO.FID =ME.FID inner JOIN T_SUB_REQORDERENTRY_A MA ON MA.FID =ME.FID AND ME.FENTRYID =MA.FENTRYID LEFT OUTER JOIN T_BD_MATERIALSTOCK TMS ON ME.FMATERIALID = TMS.FMATERIALID WHERE MO.FCANCELSTATUS='A' and ME.FSTATUS in (2,3,4) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubMo1')) BEGIN drop table #tmpSubMo1 END --更新和新增在制量数据 SELECT 物料内码,生产数量, 剩余入库数量,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmpSubMo1 FROM #tmpSubMo B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubMo2')) BEGIN drop table #tmpSubMo2 END SELECT 物料内码,生产数量, 剩余入库数量, 仓库内码 into #tmpSubMo2 FROM #tmpSubMo1 B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID )--TM.FUSEORGID =1 and LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubMo3')) BEGIN drop table #tmpSubMo3 END SELECT 物料内码,sum(生产数量)采购数量, sum(剩余入库数量)剩余入库数量 , min(仓库内码 )仓库内码 into #tmpSubMo3 FROM #tmpSubMo2 group BY 物料内码 --group BY 仓库内码,物料内码 ORDER BY 物料内码 --预计入库 UPDATE t1 set t1.预计入库=isnull(t1.预计入库,0)+t2.剩余入库数量 FROM #Stock_Status_temp t1 inner join #tmpSubMo3 t2 on t1.物料内码=t2.物料内码 --*******************END*****预计入库************************ --申购未转数(未推PR) --*******************strat***************************** --查询所有采购申请 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQ')) BEGIN drop table #TMPREQ END SELECT TS.FAPPLICATIONORGID fstockorgid, TS.FBILLNO 申请单号 ,TS.FID AS 申请内码 ,TSE.FENTRYID 申请分录,TSE.FMATERIALID 物料内码, ISNULL(TSE.FAUXPROPID, 0) FAUXPROPID, TS.FAPPLICATIONDATE fdate, TMS.FSTOCKID 仓库内码, FBASEUNITQTY 申请数量 ,TSEF.FREMAINQTY AS 未转数 INTO #TMPREQ FROM T_PUR_REQUISITION TS INNER JOIN T_PUR_REQENTRY TSE ON TSE.FID = TS.FID INNER JOIN T_PUR_REQENTRY_R TSEF ON (TSE.FID = TSEF.FID AND TSE.FENTRYID = TSEF.FENTRYID) INNER JOIN T_PUR_REQENTRY_S TSES ON (TSE.FID = TSES.FID AND TSE.FENTRYID = TSES.FENTRYID) LEFT JOIN T_BD_MATERIAL TM ON TSE.FMATERIALID=TM.FMATERIALID LEFT JOIN T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID WHERE 1=1 AND (FCLOSESTATUS='A')--AND (TS.FDOCUMENTSTATUS IN ('C')) and TSE.FMRPTERMINATESTATUS='A' AND (TS.FCANCELSTATUS IN ('A')) and TSE.FMRPCLOSESTATUS='A' if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQ1')) BEGIN drop table #TMPREQ1 END --更新和新增进检量数据 SELECT 物料内码,申请数量, 未转数,FAUXPROPID,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #TMPREQ1 FROM #TMPREQ B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQ3')) BEGIN drop table #TMPREQ3 END SELECT 物料内码,申请数量, 未转数,FAUXPROPID, 仓库内码 into #TMPREQ3 FROM #TMPREQ1 B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQ2')) BEGIN drop table #TMPREQ2 END SELECT 物料内码,sum(申请数量)申请数量, sum(未转数)未转数 --,FAUXPROPID, 仓库内码 into #TMPREQ2 FROM #TMPREQ3 group BY 物料内码 ORDER BY 物料内码 --申购未转数 UPDATE t1 set t1.未推PR=isnull(t2.未转数,0) FROM #Stock_Status_temp t1 inner join #TMPREQ2 t2 on t1.物料内码=t2.物料内码 --and t1.仓库内码=t2.仓库内码 and t1.包装内码=T2.FAUXPROPID -----查询委外订单 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQSUB')) BEGIN drop table #TMPREQSUB END SELECT MO.FSubOrgId fstockorgid, MO.FBILLNO 申请单号 ,MO.FID AS 申请内码 ,ME.FENTRYID 申请分录,ME.FMATERIALID 物料内码, ISNULL(ME.FAUXPROPID, 0) FAUXPROPID, MO.FDATE fdate, TMS.FSTOCKID 仓库内码, FBASEUNITQTY 申请数量 ,(ME.FQTY-FBasePurSelQty) AS 未转数 INTO #TMPREQSUB FROM T_SUB_REQORDER MO inner join T_SUB_REQORDERENTRY ME ON MO.FID =ME.FID inner JOIN T_SUB_REQORDERENTRY_A MA ON MA.FID =ME.FID AND ME.FENTRYID =MA.FENTRYID LEFT JOIN T_BD_MATERIAL TM ON ME.FMATERIALID=TM.FMATERIALID LEFT JOIN T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID WHERE 1=1 AND MO.FCANCELSTATUS='A' --AND MO.FDOCUMENTSTATUS='C' -- AND ME.FPRODUCTTYPE =1 AND ME.FSTATUS in (2,3,4) AND ISNULL(FCLOSEDATE,'')=''--未结案 and (ME.FQTY-FBasePurSelQty)>0 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQSUB1')) BEGIN drop table #TMPREQSUB1 END --更新和新增进检量数据 SELECT 物料内码,申请数量, 未转数,FAUXPROPID,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #TMPREQSUB1 FROM #TMPREQSUB B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQSUB2')) BEGIN drop table #TMPREQSUB2 END SELECT 物料内码,申请数量, 未转数,FAUXPROPID, 仓库内码 into #TMPREQSUB2 FROM #TMPREQSUB1 B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#TMPREQSUB3')) BEGIN drop table #TMPREQSUB3 END SELECT 物料内码,sum(申请数量)申请数量, sum(未转数)未转数 --,FAUXPROPID, 仓库内码 into #TMPREQSUB3 FROM #TMPREQSUB2 group BY 物料内码 ORDER BY 物料内码 --申购未转数 UPDATE t1 set t1.未推PR=isnull(t1.未推PR,0)+isnull(t2.未转数,0) FROM #Stock_Status_temp t1 inner join #TMPREQSUB3 t2 on t1.物料内码=t2.物料内码 --and t1.仓库内码=t2.仓库内码 and t1.包装内码=T2.FAUXPROPID --****************************未推PR*********************************************** --SELECT * FROM #Stock_Status_temp if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpPPBOM')) BEGIN drop table #tmpPPBOM END --(已分配量) --*****************生产未领量START*********************************** --查询截止结束日期之前所有生产用料数 --生产未领量 (已分配量) SELECT (MO.FBILLNO) 生产单号 ,(MO.FID) 生产内码,(ME.FENTRYID) 生产单分录, PE.FMATERIALID 物料内码,(PP.FID) 用料内码,PP.FBILLNO 用料单号,(PE.FENTRYID) 用料单分录, isnull(PC.FSTOCKID,0) 仓库内码,(PE.FMUSTQTY) AS 应发数量, PQ.FSELPICKEDQTY AS 领料选单数量,PQ.FBASENOPICKEDQTY AS 基本未领数量 ,PQ.FNOPICKEDQTY AS 未领数量 into #tmpPPBOM FROM T_PRD_MO MO inner join T_PRD_MOENTRY ME ON MO.FID =ME.FID inner JOIN T_PRD_MOENTRY_A MA ON MA.FID =ME.FID AND ME.FENTRYID =MA.FENTRYID inner join T_PRD_PPBOM PP on PP.FMOID=MO.FID AND ME.FENTRYID =PP.FMOENTRYID inner join T_PRD_PPBOMENTRY PE on PP.FID =PE.FID left join T_PRD_PPBOMENTRY_Q PQ on PP.FID =PQ.FID AND PE.FENTRYID =PQ.FENTRYID left join T_PRD_PPBOMENTRY_C PC on PP.FID =PC.FID AND PE.FENTRYID =PC.FENTRYID --WHERE 1=1 AND MO.FCANCELSTATUS='A' AND MO.FDOCUMENTSTATUS='C' -- AND ME.FPRODUCTTYPE =1 WHERE 1=1 AND MO.FCANCELSTATUS='A' --AND MO.FDOCUMENTSTATUS='C' -- AND ME.FPRODUCTTYPE =1 AND MA.FSTATUS in(2,3,4) AND ISNULL(FCLOSEDATE,'')=''--未结案 --更新和新增未发量数据 --SELECT * FROM #tmpPPBOM if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpPPBOM1')) BEGIN drop table #tmpPPBOM1 END SELECT 物料内码,应发数量, 基本未领数量 AS '未领数量',case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmpPPBOM1 FROM #tmpPPBOM B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpPPBOM3')) BEGIN drop table #tmpPPBOM3 END SELECT 物料内码,应发数量, 未领数量, 仓库内码 into #tmpPPBOM3 FROM #tmpPPBOM1 B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpPPBOM2')) BEGIN drop table #tmpPPBOM2 END SELECT 物料内码,sum(应发数量)应发数量, sum(未领数量)未领数量 ,min(仓库内码) 仓库内码 into #tmpPPBOM2 FROM #tmpPPBOM3 group BY 物料内码 ORDER BY 物料内码 --未发量 UPDATE t1 set t1.已分配量=t2.未领数量 FROM #Stock_Status_temp t1 inner join #tmpPPBOM2 t2 on t1.物料内码=t2.物料内码 --and t1.仓库内码=t2.仓库内码 and t1.包装内码=T2.FAUXPROPID --委外未领量 (已分配量) if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubBOM')) BEGIN drop table #tmpSubBOM END SELECT (MO.FBILLNO) 委外单号 ,(MO.FID) 委外内码,(ME.FENTRYID) 委外单分录, PE.FMATERIALID 物料内码,(PP.FID) 用料内码,PP.FBILLNO 用料单号,(PE.FENTRYID) 用料单分录, isnull(PC.FSTOCKID,0) 仓库内码,(PE.FMUSTQTY) AS 应发数量, PQ.FSELPICKEDQTY AS 领料选单数量,PQ.FBASENOPICKEDQTY AS 基本未领数量 ,PQ.FNOPICKEDQTY AS 未领数量 into #tmpSubBOM FROM T_SUB_REQORDER MO inner join T_SUB_REQORDERENTRY ME ON MO.FID =ME.FID inner JOIN T_SUB_REQORDERENTRY_A MA ON MA.FID =ME.FID AND ME.FENTRYID =MA.FENTRYID inner join T_SUB_PPBOM PP on PP.FSUBREQID=MO.FID AND ME.FENTRYID =PP.FSUBREQENTRYID inner join T_SUB_PPBOMENTRY PE on PP.FID =PE.FID left join T_SUB_PPBOMENTRY_Q PQ on PP.FID =PQ.FID AND PE.FENTRYID =PQ.FENTRYID left join T_SUB_PPBOMENTRY_C PC on PP.FID =PC.FID AND PE.FENTRYID =PC.FENTRYID --WHERE 1=1 AND MO.FCANCELSTATUS='A' AND MO.FDOCUMENTSTATUS='C' -- AND ME.FPRODUCTTYPE =1 WHERE 1=1 AND MO.FCANCELSTATUS='A' --AND MO.FDOCUMENTSTATUS='C' -- AND ME.FPRODUCTTYPE =1 AND ME.FSTATUS in (2,3,4) AND ISNULL(FCLOSEDATE,'')=''--未结案 --更新和新增未发量数据 --SELECT * FROM #tmpPPBOM if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubBOM1')) BEGIN drop table #tmpSubBOM1 END SELECT 物料内码,应发数量, 基本未领数量 AS '未领数量',case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmpSubBOM1 FROM #tmpSubBOM B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 AND TSL.FLOCALEID = 2052) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubBOM2')) BEGIN drop table #tmpSubBOM2 END SELECT 物料内码,应发数量, 未领数量, 仓库内码 into #tmpSubBOM2 FROM #tmpSubBOM1 B left JOIN T_BD_MATERIAL TM ON ( B.物料内码 = TM.FMATERIALID ) --TM.FUSEORGID =1 and LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) --and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSubBOM3')) BEGIN drop table #tmpSubBOM3 END SELECT 物料内码,sum(应发数量)应发数量, sum(未领数量)未领数量 ,min(仓库内码) 仓库内码 into #tmpSubBOM3 FROM #tmpSubBOM2 group BY 物料内码 ORDER BY 物料内码 --未发量 UPDATE t1 set t1.已分配量=ISNULL(t1.已分配量,0)+ISNULL(t2.未领数量,0) FROM #Stock_Status_temp t1 inner join #tmpSubBOM3 t2 on t1.物料内码=t2.物料内码 --and t1.仓库内码=t2.仓库内码 and t1.包装内码=T2.FAUXPROPID --*****************生产未领量END*********************************** ----不存在数据就重新增 --销售订单未出库 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSal')) BEGIN drop table #tmpSal END --销售订单未出库 SELECT (A.FBILLNO) AS 销售单号,(A.FID) 销售内码,(B.FENTRYID) 销售分录 ,(B.FSEQ) 销售序号, B.FMATERIALID AS 物料内码,B.FBASEUNITQTY 订单数, (C.FBASEREMAINOUTQTY+C.FBaseReturnQty) AS 未发数量,FBaseReturnQty, isnull(B.FSTOCKID,0) 仓库内码, A.FDATE into #tmpSal FROM T_SAL_ORDER A inner join T_SAL_ORDERENTRY B on A.FID =B.FID left join T_SAL_ORDERENTRY_R C ON C.FID=B.FID AND C.FENTRYID =B.FENTRYID left join T_SAL_ORDERENTRY_E D on D.FID=B.FID AND D.FENTRYID =B.FENTRYID WHERE 1=1 AND A.FCANCELSTATUS='A'and B.FMRPCLOSESTATUS='A' AND (A.FCLOSESTATUS='A') ORDER BY A.FDATE ,A.FID,B.FENTRYID,B.FMATERIALID if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSal1')) BEGIN drop table #tmpSal1 END --更新和新增销售未出数据 SELECT 物料内码,订单数, 未发数量,case when B.仓库内码<>0 then B.仓库内码 else isnull(tms.FSTOCKID,0) END 仓库内码 into #tmpSal1 FROM #tmpSal B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) left join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) LEFT OUTER JOIN T_BD_STOCK_L TSL ON (TSL.FSTOCKID = B.仓库内码 ) --WHERE (TM.FNUMBER >=@FSWL AND TM.FNUMBER <=@FEWL) and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSal2')) BEGIN drop table #tmpSal2 END SELECT 物料内码,订单数, 未发数量, 仓库内码 into #tmpSal2 FROM #tmpSal1 B left JOIN T_BD_MATERIAL TM ON (B.物料内码 = TM.FMATERIALID ) LEFT JOIN T_BD_STOCK TSK ON ( TSK.FMASTERID = B.仓库内码 ) WHERE TM.FMATERIALID in ( SELECT distinct 物料内码 FROM #Stock_Status_temp) -- and TSK.FSTOCKID IN ( SELECT distinct FStockID FROM #tmpStockID ) ORDER BY 物料内码 if exists(SELECT * FROM tempdb..sysobjects where id=object_id('tempdb..#tmpSal3')) BEGIN drop table #tmpSal3 END SELECT 物料内码,sum(订单数)订单数, sum(未发数量)未发数量 , min(仓库内码) 仓库内码 into #tmpSal3 FROM #tmpSal2 group BY 物料内码 ORDER BY 物料内码 --销售订单未出数量 UPDATE t1 set t1.已分配量=isnull(t1.已分配量,0)+t2.未发数量 --SELECT t2.* ,t1.物料代码 FROM #Stock_Status_temp t1 inner join #tmpSal3 t2 on t1.物料内码=t2.物料内码 --*******************END*已分配数*************** UPDATE t1 set t1.单位=isnull(TUL1.FNAME,'') --SELECT t1.单位,isnull(TUL1.FNAME,'') FROM #Stock_Status_temp t1 inner join t_bd_material TM on t1.物料内码=TM.FMATERIALID -- TM.FUSEORGID =1 and inner join T_BD_MATERIAL_L n on TM.FMATERIALID =n.FMATERIALID and n.FLOCALEID =2052 inner join T_BD_MATERIALSTOCK TMS ON TM.FMATERIALID = TMS.FMATERIALID inner join T_BD_MATERIALBASE TMB on TM.FMATERIALID = TMB.FMATERIALID LEFT OUTER JOIN T_BD_UNIT TUS ON TMS.FSTOREUNITID = TUS.FUNITID LEFT OUTER JOIN T_BD_UNIT_L TUL0 ON (TMS.FSTOREUNITID = TUL0.FUNITID AND TUL0.FLOCALEID = 2052) LEFT OUTER JOIN T_BD_UNIT_L TUL1 ON ( TMB.FBASEUNITID = TUL1.FUNITID AND TUL1.FLOCALEID = 2052) --where isnull(t1.单位,'')='' --*********************************** UPDATE t1 set t1.物料属性=(case when TMB.FERPCLSID=1 THEN '外购' when TMB.FERPCLSID=2 THEN '自制' when TMB.FERPCLSID=3 THEN '委外' when TMB.FERPCLSID=5 THEN '虚拟' else '其他'END) FROM #Stock_Status_temp t1 inner join t_bd_material TM on t1.物料内码=TM.FMATERIALID inner join T_BD_MATERIALBASE TMB on TM.FMATERIALID = TMB.FMATERIALID where TMB.FERPCLSID<>5 --SELECT * ,理论结存=现有库存+预计入库-已分配量 update t1 set t1.理论结存= isnull(现有库存,0)+isnull(预计入库,0)-isnull(已分配量,0) FROM #Stock_Status_temp t1 -- F_PKGR_Brand 品牌 L/T F_UKUB_EPdate F_PKGR_HUMIDITYSENSITIVITY 采购员 update t0 set t0.采购员 =isnull(TB.FName,''),t0.FLT =isnull(t1.FFixLeadTime,'0') , t0.品牌 = '' FROM #Stock_Status_temp t0 inner join t_bd_material TM on t0.物料内码=TM.FMATERIALID LEFT OUTER JOIN t_BD_MaterialPlan t1 on t1.FMATERIALID=TM.FMATERIALID LEFT OUTER JOIN t_bd_MaterialPurchase TP on TP.FMATERIALID=TM.FMATERIALID LEFT OUTER JOIN V_BD_BUYER_L TB ON (TP.FPurchaserId = TB.fid ) --SELECT FLT,* --update t1 set t1.FLT=(case when (isnull(t1.FLT1,'')='0'or isnull(t1.FLT1,'')='') then 0 else t1.FLT1 END) --FROM #Stock_Status_temp t1 where FLT1='' --delete FROM #Stock_Status_temp where TM.FDOCUMENTSTATUS='C' AND TM.FFORBIDSTATUS ='A' --TM.FDOCUMENTSTATUS='C' AND TM.FFORBIDSTATUS ='A'AND if @Flag = 1 BEGIN SELECT 序号,物料内码,物料代码,物料名称 , 规格型号,物料属性, 单位,isnull(安全库存,0) 安全库存,isnull(现有库存,0) 现有库存, isnull(预计入库,0)预计入库 , isnull(未推PR,0) 未推PR ,isnull(已分配量,0) 已分配量 ,isnull(理论结存,0)理论结存 , isnull(计划员, '')AS 计划员 , isnull(品牌, '')AS 品牌 , isnull(FLT,0)AS FLT , isnull(采购员, '')AS 采购员 FROM #Stock_Status_temp t1 --inner join t_bd_material TM on t1.物料内码=TM.FMATERIALID where isnull(理论结存,0) < 0 ORDER BY 物料代码 END else BEGIN SELECT 序号 ,物料内码 ,物料代码 ,物料名称 ,规格型号 ,物料属性 ,单位 ,isnull(安全库存,0)安全库存 ,isnull(现有库存,0) AS 现有库存 ,isnull(预计入库,0) 预计入库 ,isnull(未推PR,0) 未推PR ,isnull(已分配量,0) 已分配量 ,isnull(理论结存,0)理论结存 ,isnull(计划员, '') AS 计划员 ,isnull(品牌, '') AS 品牌 ,isnull(FLT, 0) AS FLT ,isnull(采购员, '') AS 采购员 FROM #Stock_Status_temp t1 --inner join t_bd_material TM on t1.物料内码=TM.FMATERIALID --where TM.FDOCUMENTSTATUS='C' AND TM.FFORBIDSTATUS ='A' --物料内码=129833 ORDER BY 物料代码 END