187 lines
7.3 KiB
Transact-SQL
187 lines
7.3 KiB
Transact-SQL
USE [MESAPI_V2]
|
||
GO
|
||
/****** Object: StoredProcedure [dbo].[rb_GetMergePPBOMKeyMartQty] Script Date: 2024/9/23 15:53:03 ******/
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
GO
|
||
|
||
|
||
|
||
|
||
|
||
-- =============================================
|
||
-- Author: <沃比:XPS>
|
||
-- Create date: <20230130>
|
||
-- Last date: <20230915>
|
||
-- Description: <得获取合并生产用料清单相同主料的需求>
|
||
-- =============================================
|
||
ALTER PROCEDURE [dbo].[rb_GetMergePPBOMKeyMartQty]
|
||
@MO varchar(255),@MOSeq INT,@allmart bit=1,@OrgID INT=1
|
||
AS
|
||
BEGIN
|
||
SET NOCOUNT ON;
|
||
BEGIN TRY
|
||
BEGIN TRAN
|
||
/*-----------------------------------------------------------------------------------------------------------------------*/
|
||
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)
|
||
)
|
||
|
||
INSERT INTO #matergroup(FID,FENTRYID,FMATERIALID,FSeq,FQTY,FBaseQTY,FPositionNO)
|
||
SELECT t1.FID,t1.FENTRYID,FMATERIALID,FSEQ,FMUSTQTY,FBASEMUSTQTY,FPositionNO
|
||
FROM T_PRD_PPBOMENTRY t1
|
||
INNER JOIN T_PRD_PPBOMENTRY_C tc ON tc.FID = t1.FID AND tc.FENTRYID = t1.FENTRYID AND tc.FSUPPLYORG= @OrgID
|
||
WHERE t1.FMOBILLNO = @MO AND FMOENTRYSEQ = @MOSeq AND FMATERIALTYPE = 1
|
||
AND FMUSTQTY > CASE @allmart WHEN 0 THEN -1 ELSE 0 END
|
||
AND T1.FMATERIALID IN (
|
||
SELECT FMATERIALID FROM T_PRD_PPBOMENTRY
|
||
WHERE FID=t1.FID AND FMATERIALTYPE = 1
|
||
AND FMUSTQTY > CASE @allmart WHEN 0 THEN -1 ELSE 0 END
|
||
GROUP BY FMATERIALID
|
||
HAVING COUNT(1) > 1
|
||
)
|
||
--SELECT * FROM #matergroup
|
||
/*-----------------------------------------------------------------------------------------------------------------------*/
|
||
IF EXISTS(SELECT 1 FROM #matergroup)
|
||
BEGIN
|
||
/*-----------------------------------------------------------------------------------------------------------------------*/
|
||
--/*优先合并到替代主料*/
|
||
--create table #group (FMATERIALID int,FEntryID INT primary key)
|
||
--insert into #group
|
||
--SELECT p.FMATERIALID,p.FENTRYID FROM #matergroup g INNER JOIN T_PRD_PPBOMENTRY p ON P.FID=G.FID AND P.FENTRYID=G.FENTRYID
|
||
--WHERE p.FREPLACEGROUP in(
|
||
-- SELECT FREPLACEGROUP FROM T_PRD_PPBOMENTRY WHERE FMOBILLNO=@MO and FMOENTRYSEQ=@MOSeq GROUP BY FREPLACEGROUP HAVING count(*)>1
|
||
--)
|
||
--UPDATE M SET FQTY=(SELECT ROUND(SUM(ISNULL(FQTY,0)),U.FPrecision) FROM #matergroup q INNER JOIN T_BD_MATERIALSTOCK s ON s.FMATERIALID=q.FMATERIALID
|
||
-- INNER JOIN T_BD_UNIT u ON u.FUNITID=s.FStoreUnitID GROUP BY s.FMATERIALID,U.FPrecision HAVING s.FMATERIALID=M.FMATERIALID)
|
||
-- ,FBaseQTY=(SELECT ROUND(SUM(ISNULL(FBaseQTY,0)),U.FPrecision) FROM #matergroup q INNER JOIN T_BD_MATERIALSTOCK s ON s.FMATERIALID=q.FMATERIALID
|
||
-- INNER JOIN T_BD_UNIT u ON u.FUNITID=s.FStoreUnitID GROUP BY s.FMATERIALID,U.FPrecision HAVING s.FMATERIALID=M.FMATERIALID)
|
||
--FROM #matergroup M INNER JOIN #group g ON m.FENTRYID=g.FEntryID
|
||
--WHERE g.FEntryID in(SELECT MIN(FEntryID) FEntryID FROM #group GROUP BY FMATERIALID)
|
||
|
||
UPDATE M SET FQTY=(
|
||
SELECT ROUND(SUM(ISNULL(FQTY,0)),U.FPrecision)
|
||
FROM #matergroup q
|
||
INNER JOIN T_BD_MATERIALSTOCK s ON s.FMATERIALID = q.FMATERIALID
|
||
INNER JOIN T_BD_UNIT u ON u.FUNITID = s.FStoreUnitID
|
||
GROUP BY s.FMATERIALID,U.FPrecision
|
||
HAVING s.FMATERIALID=M.FMATERIALID),FBaseQTY = (
|
||
SELECT ROUND(SUM(ISNULL(FBaseQTY,0)),U.FPrecision)
|
||
FROM #matergroup q
|
||
INNER JOIN T_BD_MATERIALSTOCK s ON s.FMATERIALID=q.FMATERIALID
|
||
INNER JOIN T_BD_UNIT u ON u.FUNITID=s.FStoreUnitID
|
||
GROUP BY s.FMATERIALID,U.FPrecision
|
||
HAVING s.FMATERIALID=M.FMATERIALID
|
||
)
|
||
FROM #matergroup M
|
||
WHERE FSEQ in(
|
||
SELECT MIN(FSEQ) FSEQ
|
||
FROM #matergroup
|
||
GROUP BY FMATERIALID
|
||
)
|
||
--and not exists(
|
||
-- SELECT FENTRYID FROM #group WHERE FENTRYID=m.FENTRYID
|
||
--)
|
||
|
||
UPDATE M SET FQTY=0,FBaseQTY=0
|
||
FROM #matergroup M
|
||
WHERE FSEQ not in(
|
||
SELECT MIN(FSEQ) FSEQ FROM #matergroup GROUP BY FMATERIALID
|
||
)
|
||
--and FENTRYID NOT IN(
|
||
-- SELECT MIN(FENTRYID) FENTRYID FROM #group WHERE FMATERIALID=M.FMATERIALID GROUP BY FMATERIALID
|
||
--)
|
||
/*-----------------------------------------------------------------------------------------------------------------------*/
|
||
DECLARE @PQTY DECIMAL(38,10),@PBASEQTY DECIMAL(38,10)
|
||
SELECT @PQTY=FQTY,@PBASEQTY=FBASEQTY FROM T_PRD_PPBOM WHERE FMOBILLNO=@MO and FMOENTRYSEQ=@MOSeq
|
||
|
||
DECLARE @i int=1,@j int
|
||
SELECT @j=max(IndexID) FROM #matergroup
|
||
while @i<=@j
|
||
begin
|
||
declare @molecule DECIMAL(38,10),@md decimal(38,10),@out_molecule int,@out_denominator int
|
||
SELECT @molecule=FQTY FROM #matergroup WHERE IndexID=@i
|
||
if @molecule>0 /*当应发数量为0时,不需要处理分子、分母*/
|
||
begin
|
||
UPDATE #matergroup SET FNUMERATOR=ROUND(@molecule/@PQTY,4),FDENOMINATOR=1
|
||
WHERE IndexID=@i
|
||
end
|
||
SET @i=@i + 1
|
||
end
|
||
--drop table #group
|
||
/*-----------------------------------------------------------------------------------------------------------------------*/
|
||
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
|
||
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
|
||
|
||
DROP TABLE #matergroup
|
||
|
||
COMMIT TRAN
|
||
END TRY
|
||
BEGIN CATCH
|
||
--SELECT
|
||
-- ERROR_NUMBER() AS ErrorNumber
|
||
-- ,ERROR_SEVERITY() AS ErrorSeverity
|
||
-- ,ERROR_STATE() AS ErrorState
|
||
-- ,ERROR_PROCEDURE() AS ErrorProcedure
|
||
-- ,ERROR_LINE() AS ErrorLine
|
||
-- ,ERROR_MESSAGE() AS ErrorMessage;
|
||
--ROLLBACK TRAN
|
||
END CATCH
|
||
|
||
SET NOCOUNT OFF;
|
||
|
||
|
||
END
|
||
|
||
|
||
|
||
|