IF EXISTS(SELECT * FROM SYS.PROCEDURES WHERE NAME='PROC_UPDATE_BOMLEVEL') DROP PROCEDURE dbo.PROC_UPDATE_BOMLEVEL; GO CREATE PROCEDURE PROC_UPDATE_BOMLEVEL AS BEGIN CREATE TABLE #TMP_MO --创建临时表#TMP ( FID INT ,FBILLNO VARCHAR(255) ,FDATE DATE ,FENTRYID INT ,FMATERIALID INT ,MOBOMID INT ,FSRCFORMID VARCHAR(255) ,FSRCBILLNO VARCHAR(255) ,FSRCINTERID INT ,FSRCENTRYID INT ,FSEQ INT ,FBOMID INT ,BOMLEVEL VARCHAR(255) ,TOPBILLNO VARCHAR(255) ); CREATE INDEX [#TMP_MO_FID] ON #TMP_MO(FID); --INSERT INTO #TMP_MO /*计划订单一旦投放,T_PLN_RESERVELINKENTRY里计划订单将转移到生产订单 */ SELECT t0e.FID ,t0.FBILLNO ,t0.FDATE ,t0e.FENTRYID ,t0e.FMATERIALID ,t0e.FBomId MOBomId ,t1.FSRCFORMID --'顶级需求来源类型' ,t1.FSRCBILLNO --'顶级需求来源单号' ,t1.FSRCINTERID /*顶级需求来源单内码*/ ,t1.FSRCENTRYID /*顶级需求来源分录号*/ ---来源于同一预测单同一行的这两个值一定相同 ,t2e.FSEQ ,t2e.FBomId /*可以用预测订单的FBomId取匹配BOM多级展开的首层号*/ ,t2e.FMATERIALID OMATERAILID ,t0e.FFORECASTGROUP ,'' BOMLevel INTO #TMP_MO_PART FROM T_PRD_MO t0 --生产订单表头 INNER JOIN T_PRD_MOENTRY t0e ON t0e.FID=t0.FID --生产订单表体 INNER JOIN T_PLN_RESERVELINKENTRY t1e ON t1e.FINTSUPPLYID = t0e.FID AND t1e.FINTSUPPLYENTRYID = t0e.FENTRYID--预留表表体 INNER JOIN T_PLN_RESERVELINK t1 ON t1.FID=t1e.FID AND t1.FSRCFORMID = 'PLN_FORECAST'--预留表表头 INNER JOIN T_PLN_FORECASTENTRY t2e ON t2e.FID = t1.FSRCINTERID AND t2e.FENTRYID = t1.FSRCENTRYID--预测单表体 WHERE 1 = 1 --t0.FBILLNO='WO2401100002' /*测试生产订单*/ --AND t0e.FFORECASTGROUP='' /*层数为空*/ AND t0e.FSRCBILLTYPE='PLN_PLANORDER' /*确保是通过MRP运算下推的单据*/ INSERT INTO #TMP_MO SELECT tt.FID ,tt.FBILLNO ,tt.FDATE ,tt.FENTRYID ,tt.FMATERIALID ,tt.MOBomId ,tt.FSRCFORMID --'顶级需求来源类型' ,tt.FSRCBILLNO --'顶级需求来源单号' ,tt.FSRCINTERID /*顶级需求来源单内码*/ ,tt.FSRCENTRYID /*顶级需求来源分录号*/ ---来源于同一预测单同一行的这两个值一定相同 ,tt.FSEQ ,tt.FBomId /*可以用预测订单的FBomId取匹配BOM多级展开的首层号*/ ,tt.BOMLevel ,t0.FBILLNO --into #TMP_MO FROM #TMP_MO_PART tt INNER JOIN ( SELECT MOBomId,FBOMID,FSEQ,FSRCINTERID,FSRCENTRYID,FBILLNO,FDATE,len(FBILLNO) Billnolen ,ROW_NUMBER() over(partition BY MOBomId,FBOMID,FSEQ,FSRCINTERID,FSRCENTRYID,FDATE,len(FBILLNO) order by FBILLNO) ROWID FROM #TMP_MO_PART WHERE FBOMID =MOBomId ) t0 ON tt.FBOMID = t0.FBOMID AND tt.FSEQ = t0.FSEQ AND tt.FSRCINTERID = t0.FSRCINTERID AND tt.FSRCENTRYID = t0.FSRCENTRYID AND tt.FDATE = t0.FDATE AND t0.ROWID =1 AND t0.Billnolen = len(tt.FBILLNO) WHERE tt.FFORECASTGROUP = '' CREATE TABLE #TMP_TOP_BOM_SET( FID int ,FNUMBER varchar(80) ,FMATERIALID int ,FSEQ int ,BOMLEVEL int ,TOPID int ,showlevel varchar(80) ,oId int ) CREATE INDEX [#TMP_TOP_BOM_SET_FID] ON #TMP_TOP_BOM_SET(FID); INSERT INTO #TMP_TOP_BOM_SET SELECT t0.FID ,t0.FNUMBER ,t0.FMATERIALID ,ROW_NUMBER() over(partition BY t0.FID order by t0.FMATERIALID) ,1 'BOMLEVEL' ,t0.FID AS 'TOPID' ,'' ,t0.FID FROM T_ENG_BOM t0 INNER JOIN #TMP_MO t3 on t3.FBOMID = t0.FID WHERE 1 = 1 GROUP BY t0.FID ,t0.FNUMBER ,t0.FMATERIALID DECLARE @num INT,@level int,@LoopCount int SET @num = 1 SET @level =1 SET @LoopCount = 0; WHILE (@num <> 0 AND @LoopCount < 30) BEGIN INSERT INTO #TMP_TOP_BOM_SET SELECT t3.FID ,t3.FNUMBER ,t3.FMATERIALID ,ROW_NUMBER() over(partition BY t0.TOPID order by t0.fseq) ,t0.BOMLEVEL + 1 ,t0.TOPID ,CONCAT(t0.showlevel,'-',CAST(dense_rank() over(partition BY t0.topid order by t1.fseq) as VARCHAR)) ,t0.FID FROM #TMP_TOP_BOM_SET t0 INNER JOIN T_ENG_BOMCHILD t1 on t0.FID = t1.FID INNER JOIN T_BD_MATERIALBASE t2 on t2.FMATERIALID = t1.FMATERIALID INNER JOIN T_ENG_BOM t3 on t1.FMATERIALID = t3.FMATERIALID WHERE 1 = 1 AND (t2.FERPCLSID = 2 ) AND t0.BOMLEVEL = @level SET @num = @@ROWCOUNT SET @level += 1 SET @LoopCount += 1 END SELECT ROW_NUMBER() over(partition BY TOPID order by FSEQ) AS rowId, * INTO #TMP_TOP_BOM_GROUP FROM #TMP_TOP_BOM_SET WHERE 1 = 1 GROUP BY FID,FNUMBER,FMATERIALID,FSEQ,BOMLEVEL,TOPID,showlevel,oId --更新临时表数据 UPDATE t0 SET t0.BOMLEVEL = t0.TOPBILLNO + t1.showlevel FROM #TMP_MO t0 INNER JOIN #TMP_TOP_BOM_GROUP t1 on t0.MOBOMID = t1.FID AND t0.FBOMID = t1.TOPID --更新到数据库 --UPDATE t0e SET t0e.FFORECASTGROUP = t1.BOMLEVEL --FROM T_PRD_MOENTRY t0e INNER JOIN #TMP_MO t1 on t0e.FBOMID = t1.MOBOMID AND t0e.FENTRYID = t1.FENTRYID SELECT t0.*,t1.fnumber FROM #TMP_TOP_BOM_GROUP t0 INNER JOIN T_BD_MATERIAL t1 on t0.fmaterialid = t1.fmaterialid --WHERE t0.OID = 6339745 order by t0.FSEQ,t0.BOMLEVEL SELECT * FROM #TMP_MO WHERE 1 = 1 --AND FBOMID <> MOBOMID --AND FBOMID = 6339745 AND topbillno='WO2308090009' --查询临时表的数据 DROP TABLE #TMP_MO_PART DROP TABLE #TMP_TOP_BOM_SET DROP TABLE #TMP_TOP_BOM_GROUP DROP TABLE #TMP_MO --删除临时表#TMP END --SET STATISTICS TIME ON --EXEC PROC_UPDATE_BOMLEVEL --SET STATISTICS TIME OFF