229 lines
6.7 KiB
Transact-SQL
229 lines
6.7 KiB
Transact-SQL
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
|
||
,OMATERAILID int
|
||
,MOBOMID INT
|
||
,FSRCFORMID VARCHAR(255)
|
||
,FSRCBILLNO VARCHAR(255)
|
||
,FSRCINTERID INT
|
||
,FSRCENTRYID INT
|
||
,FSEQ INT
|
||
,FBOMID INT
|
||
,BOMLEVEL VARCHAR(255)
|
||
,TOPBILLNO VARCHAR(255)
|
||
,FFORECASTGROUP 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
|
||
--,t0_lk.FSTABLENAME
|
||
--,t0_lk.FSTABLEID
|
||
--,t0_lk.FSBILLID
|
||
,t0_lk.FSID
|
||
,t0e_Q.FSRCSPLITID
|
||
,'' BOMLevel
|
||
INTO #TMP_MO_PART
|
||
FROM T_PRD_MO t0 --生产订单表头
|
||
INNER JOIN T_PRD_MOENTRY t0e ON t0e.FID=t0.FID --生产订单表体
|
||
INNER JOIN T_PRD_MOENTRY_Q t0e_Q on t0e.FENTRYID = t0e_Q.FENTRYID
|
||
LEft JOIN T_PRD_MOENTRY_LK t0_lk on t0e.FENTRYID = t0_lk.FENTRYID
|
||
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.FFORECASTGROUPFRIST = 'WO2312270043'
|
||
AND t0e.FSRCBILLTYPE='PLN_PLANORDER' /*确保是通过MRP运算下推的单据*/
|
||
AND t0e_Q.FSRCSPLITID = 0
|
||
|
||
|
||
INSERT INTO #TMP_MO
|
||
SELECT
|
||
tt.FID
|
||
,tt.FBILLNO
|
||
,tt.FDATE
|
||
,tt.FENTRYID
|
||
,tt.FMATERIALID
|
||
,tt.OMATERAILID
|
||
,tt.MOBomId
|
||
,tt.FSRCFORMID --'顶级需求来源类型'
|
||
,tt.FSRCBILLNO --'顶级需求来源单号'
|
||
,tt.FSRCINTERID /*顶级需求来源单内码*/
|
||
,tt.FSRCENTRYID /*顶级需求来源分录号*/ ---来源于同一预测单同一行的这两个值一定相同
|
||
,tt.FSEQ
|
||
,tt.FBomId /*可以用预测订单的FBomId取匹配BOM多级展开的首层号*/
|
||
,tt.BOMLevel
|
||
,t0.FBILLNO
|
||
,tt.FFORECASTGROUP
|
||
--into #TMP_MO
|
||
FROM
|
||
#TMP_MO_PART tt
|
||
INNER JOIN (
|
||
SELECT
|
||
FID,MOBomId,FBOMID,FSEQ,FSRCINTERID,FSRCENTRYID,FBILLNO,FDATE,len(FBILLNO) Billnolen,OMATERAILID,FMATERIALID,FSID
|
||
,ROW_NUMBER() over(partition BY MOBomId,FBOMID,FSEQ,FSRCINTERID,FSRCENTRYID,FDATE,len(FBILLNO),OMATERAILID,FMATERIALID order by FBILLNO) ROWID
|
||
FROM
|
||
#TMP_MO_PART
|
||
WHERE FMATERIALID = OMATERAILID
|
||
) t0 ON 1=1
|
||
AND 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 tt.OMATERAILID = t0.FMATERIALID
|
||
AND t0.Billnolen = len(tt.FBILLNO)
|
||
--AND tt.fsid = t0.FSID
|
||
WHERE 1 = 1
|
||
--AND 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.fid)
|
||
,1 'BOMLEVEL'
|
||
,t0.FID AS 'TOPID'
|
||
,''
|
||
,t0.FID
|
||
FROM
|
||
T_ENG_BOM t0
|
||
INNER JOIN #TMP_MO t3 on t3.FBOMID = t0.FID AND t3.FMATERIALID = t0.FMATERIALID
|
||
WHERE 1 = 1
|
||
AND t3.FMATERIALID = t3.OMATERAILID
|
||
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,t0.oid order by t0.fseq)
|
||
,t0.BOMLEVEL + 1
|
||
,t0.TOPID
|
||
,CONCAT(t0.showlevel,'-',CAST(dense_rank() over(partition BY t0.topid,t0.oid,t0.fid 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 OR t2.FERPCLSID = 5 )
|
||
AND t0.BOMLEVEL = @level
|
||
|
||
SET @num = @@ROWCOUNT
|
||
SET @level += 1
|
||
SET @LoopCount += 1
|
||
END
|
||
|
||
SELECT
|
||
*
|
||
INTO #TMP_TOP_BOM_GROUP
|
||
FROM #TMP_TOP_BOM_SET
|
||
WHERE 1 = 1
|
||
GROUP BY FID,FNUMBER,FMATERIALID,FSEQ,BOMLEVEL,TOPID,showlevel,oId
|
||
|
||
SELECT FID,FBILLNO,FENTRYID,FDATE,FMATERIALID,OMATERAILID,MOBOMID,FSRCENTRYID,FSRCINTERID,FSEQ,FBOMID,TOPBILLNO,BOMLEVEL,FFORECASTGROUP
|
||
INTO #TMP_MO_GROUP
|
||
FROM #TMP_MO
|
||
GROUP BY FID,FBILLNO,FENTRYID,FDATE,FMATERIALID,OMATERAILID,MOBOMID,FSRCENTRYID,FSRCINTERID,FSEQ,FBOMID,TOPBILLNO,BOMLEVEL,FFORECASTGROUP
|
||
|
||
--更新临时表数据
|
||
UPDATE t0 SET t0.BOMLEVEL = ISNULL(t0.TOPBILLNO,'') + ISNULL(t1.showlevel ,'')
|
||
FROM #TMP_MO_GROUP t0 LEFT JOIN #TMP_TOP_BOM_GROUP t1 on t0.FMATERIALID = t1.FMATERIALID AND t0.MOBOMID = t1.FID AND t0.FBOMID = t1.TOPID
|
||
|
||
----更新到数据库
|
||
--UPDATE t0e SET t0e.FFORECASTGROUP = t1.BOMLEVEL,t0e.FFORECASTGROUPFRIST = t1.TOPBILLNO
|
||
--FROM T_PRD_MOENTRY t0e INNER JOIN #TMP_MO_GROUP 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.TOPID = 8062230
|
||
--order by t0.FSEQ,t0.BOMLEVEL
|
||
--SELECT t0.*,t1.FENTRYID FROM #TMP_MO_GROUP t0 RIGHT join T_PRD_MOENTRY t1 on t0.FID = t1.FID AND t0.FENTRYID = t1.FENTRYID WHERE 1 = 1 AND t1.FFORECASTGROUPFRIST = 'WO2312270043'。
|
||
--SELECT t0.*
|
||
-- ,t0_lk.FSTABLENAME
|
||
-- ,t0_lk.FSTABLEID
|
||
-- ,t0_lk.FSBILLID
|
||
-- ,t0_lk.FSID
|
||
-- ,t0e_Q.FSRCSPLITBILLNO
|
||
-- ,t0e_Q.FSRCSPLITID
|
||
-- ,t0e_Q.FSRCSPLITSEQ
|
||
-- ,t0e_Q.FSRCSPLITENTRYID
|
||
-- --INTO #TMP_MO_PART
|
||
-- FROM #TMP_MO_GROUP t0
|
||
-- LEft JOIN T_PRD_MOENTRY_LK t0_lk on t0.FENTRYID = t0_lk.FENTRYID
|
||
-- INNER JOIN T_PRD_MOENTRY_Q t0e_Q on t0.FENTRYID = t0e_Q.FENTRYID
|
||
-- WHERE 1 = 1
|
||
--AND FBOMID =8237478 AND MOBOMID =8237478
|
||
--AND topbillno='WO2311080183'
|
||
--SELECT * FROM #TMP_MO WHERE 1 = 1
|
||
--AND FBOMID <> MOBOMID
|
||
--AND FBOMID = 6339745 --AND topbillno='WO2308090009' --查询临时表的数据
|
||
DROP TABLE #TMP_MO_GROUP
|
||
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 |