--exec rb_GetMergePPBOMKeyMartQty 'WO2407100313',1,1,1 DECLARE @MO varchar(255),@MOSeq INT,@allmart bit=1,@OrgID INT=1 SET @MO = 'WO2407100313' SET @MOSeq = 1 IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#MATERGROUP') IS NOT NULL) BEGIN DROP TABLE [dbo].[#MATERGROUP] END CREATE TABLE #MATERGROUP( INDEXID INT IDENTITY(1,1) ,FID INT ,FENTRYID INT PRIMARY KEY ,FSEQ INT ,FMATERIALID INT ,FQTY DECIMAL(38,10) ,FBASEQTY DECIMAL(38,10) ,FNUMERATOR INT DEFAULT 1 ,FDENOMINATOR INT DEFAULT 1 ,FPOSITIONNO NVARCHAR(4000) ,FReplaceGroup int NOT NULL ) --获取需求数量不为0的子项明细 INSERT INTO #matergroup(FID,FENTRYID,FMATERIALID,FSeq,FQTY,FBaseQTY,FPositionNO,FReplaceGroup) SELECT t1e.FID,t1e.FENTRYID,FMATERIALID,FSEQ,FMUSTQTY,FBASEMUSTQTY,FPositionNO,t1e.FReplaceGroup FROM T_PRD_PPBOMENTRY t1e INNER JOIN T_PRD_PPBOMENTRY_C t1e_c ON t1e_c.FENTRYID = t1e.FENTRYID AND t1e_c.FSUPPLYORG= @OrgID WHERE t1e.FMOBILLNO = @MO AND FMOENTRYSEQ = @MOSeq AND t1e.FMATERIALTYPE = 1 --标准件 AND FMUSTQTY > CASE @allmart WHEN 0 THEN -1 ELSE 0 END AND t1e.FMATERIALID IN ( SELECT FMATERIALID FROM T_PRD_PPBOMENTRY WHERE FID=t1e.FID AND FMATERIALTYPE = 1 AND FMUSTQTY > CASE @allmart WHEN 0 THEN - 1 ELSE 0 END GROUP BY FMATERIALID HAVING COUNT(1) > 1 ) IF EXISTS(SELECT 1 FROM #matergroup) BEGIN /*---------------------------------------查询替代件start-------------------------------------------*/ INSERT INTO #matergroup(FID,FENTRYID,FMATERIALID,FSeq,FQTY,FBaseQTY,FPositionNO,FReplaceGroup) SELECT t1e.FID,t1e.FENTRYID,t1e.FMATERIALID,t1e.FSEQ,FMUSTQTY,FBASEMUSTQTY,t1e_c.FPositionNO,t1e.FReplaceGroup FROM T_PRD_PPBOMENTRY t1e INNER JOIN T_PRD_PPBOMENTRY_C t1e_c ON t1e_c.FENTRYID = t1e.FENTRYID INNER JOIN #matergroup tt on tt.FID = t1e.FID AND tt.FReplaceGroup = t1e.FREPLACEGROUP WHERE 1=1 AND t1e.FMATERIALTYPE = 3 --AND t1e.FENTRYID != tt.FENTRYID AND t1e.FMUSTQTY > CASE @allmart WHEN 0 THEN -1 ELSE 0 END /*---------------------------------------查询替代件end---------------------------------------------*/ /*------------------------------------------计算合并数量start---------------------------------*/ UPDATE t0 SET FQTY = ISNULL(t1.FQTY,0) ,FBaseQTY = ISNULL(t1.FBaseQTY,0) FROM #matergroup t0 OUTER APPLY ( SELECT t1.FMATERIALID,ROUND(SUM(ISNULL(tt.FQTY,0)),t2.FPrecision) AS 'FQTY' ,ROUND(SUM(ISNULL(tt.FBaseQTY,0)),t2.FPrecision) AS 'FBaseQTY' ,MIN(tt.FSEQ) AS 'MinSeq' FROM #matergroup tt INNER JOIN T_BD_MATERIALSTOCK t1 on t1.FMATERIALID = tt.FMATERIALID INNER JOIN T_BD_UNIT t2 on t2.FUNITID = t1.FStoreUnitID GROUP BY t1.FMATERIALID,t2.FPRECISION HAVING t1.FMATERIALID = t0.FMATERIALID AND MIN(tt.FSEQ) = t0.FSEQ ) t1 /*------------------------------------------计算合并数量end---------------------------------*/ /*-----------------------------------------分子分母start---------------------------------*/ MERGE INTO #matergroup tt USING T_PRD_PPBOM t0 on (tt.FID = t0.FID AND tt.FQTY > 0) WHEN MATCHED THEN UPDATE SET tt.FNUMERATOR = ROUND(tt.FQTY/t0.FQTY,4),tt.FDENOMINATOR = 1; /*-----------------------------------------分子分母end---------------------------------*/ SELECT MP.FNUMBER FParentMaterial,bom.FNUMBER FBOMID,p2.FMoId,B.FMOBILLNO,B.FMOEntrySeq,b.FMOEntryID,p2.FBaseQty ,y.FNUMBER FMOType,u2.FNUMBER FBaseUnitID,u3.FNUMBER FUnitID,p2.FParentOwnerTypeId ,m2.FNUMBER FMaterialID2,FChangeType,u1.FNUMBER FUnitID2,A.FMUSTQTY,p2.FQTY FProduceQty ,p2.FBILLNO FPPBOMNo,B.FID FPPBOMId,B.FENTRYID FPPBOMEntryId,B.FSeq FPPBOMEntrySeq ,d1.FNUMBER FWORKSHOPID,g.FNUMBER FOWNERID,g.FNUMBER FSUPPLYORG,B.FReplaceGroup,A.FPositionNO ,B.FMATERIALTYPE 'FMaterialType' FROM ( SELECT '2' FChangeType,p1.FMUSTQTY FMustQty,p1.FID,p1.FENTRYID,FPositionNO FROM #matergroup m INNER JOIN T_PRD_PPBOMENTRY p1 ON p1.FID = m.FID and p1.FENTRYID = m.FENTRYID union SELECT '3' FChangeType,m.FQTY FMustQty,p1.FID,p1.FENTRYID,CASE m.FQTY WHEN 0 THEN FPositionNO ELSE STUFF ( ( SELECT ','+FPositionNO FROM (SELECT DISTINCT FPositionNO,FMATERIALID FROM #matergroup m1 WHERE m1.FID=m.FID) B WHERE (FMATERIALID=m.FMATERIALID) FOR XML PATH(''),TYPE).value('(./text())[1]','VARCHAR(MAX)' ),1,1,'' ) END AS FPositionNO FROM #matergroup m INNER JOIN T_PRD_PPBOMENTRY p1 ON p1.FID = m.FID and p1.FENTRYID = m.FENTRYID ) A INNER JOIN T_PRD_PPBOMENTRY B ON B.FID=A.FID and B.FENTRYID=A.FENTRYID INNER JOIN T_BD_MATERIAL m2 ON m2.FMATERIALID=B.FMATERIALID INNER JOIN T_BD_UNIT u1 ON u1.FUNITID=B.FUNITID INNER JOIN T_PRD_PPBOM p2 ON p2.FID=B.FID INNER JOIN T_BD_DEPARTMENT d1 ON d1.FDEPTID=p2.FWORKSHOPID INNER JOIN T_PRD_PPBOMENTRY_C p3 ON p3.FID=B.FID and p3.FENTRYID=B.FENTRYID INNER JOIN T_ORG_Organizations g ON g.forgid=p2.FParentOwnerId inner JOIN T_BD_MATERIAL MP ON MP.FMATERIALID=p2.FMATERIALID INNER JOIN T_ENG_BOM bom ON bom.FID=p2.FBOMID INNER JOIN T_BD_UNIT u2 ON u2.FUNITID=p2.FBASEUNITID INNER JOIN T_BD_UNIT u3 ON u3.FUNITID=p2.FUNITID INNER JOIN T_BAS_BILLTYPE y ON y.FBILLTYPEID=p2.FMOType ORDER BY B.FID,B.FENTRYID,FChangeType END