USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[MRBInsertLot] Script Date: 11/21/2024 11:29:05 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[MRBInsertLot] @LotID INT OUTPUT, @LotNumber VARCHAR(50), @DispoType CHAR(1), @Status CHAR(1), @DieLotNumber VARCHAR(50), @MRBNumber INT, @Description VARCHAR(100), @NewPartNo VARCHAR(50), @WipPartNo VARCHAR(50), @DiePartNo VARCHAR(50), @ProductFamily CHAR(10), @Gen VARCHAR(10), @Channel VARCHAR(50), @HexSize VARCHAR(10), @Voltage FLOAT, @WaferCount INT, @DieCount INT, @Location VARCHAR(50), @TotalCost FLOAT, @QualityCode NCHAR(10), @ExistingRowUpdated bit = NULL OUTPUT AS BEGIN -- 2019-04-19 TR: added code to update existing MRBLot and fix defect with MRB lot sum code, #35349 SET NOCOUNT ON; DECLARE @TotalLotCount INT DECLARE @TotalWaferCount INT DECLARE @TotalDieCount INT DECLARE @ExistingDispoType CHAR(1) DECLARE @ParentLotNumber VARCHAR(50) SELECT @ParentLotNumber = WP_LOT_FROM FROM vFAB2SPN_WP_RECORD WHERE WP_LOT_NO = @LotNumber SELECT @ExistingDispoType = DispoType FROM MRBLot WITH(NOLOCK) WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber IF EXISTS ( SELECT 1 FROM MRBLot WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber ) BEGIN -- Only DIspo type can be updated UPDATE MRBLot SET DispoType = @DispoType WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber SET @ExistingRowUpdated = 1 SET @LotID = ( SELECT TOP 1 LotID FROM MRBLot WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber ) IF EXISTS( SELECT MS.* FROM MRBLotsToBeSentToSPN MS WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber AND SentToSPN = 1 ) BEGIN -- This check needs to happen here instead of the IF EXISTS SQL statement above IF (@ExistingDispoType <> @DispoType) OR ( ( @ExistingDispoType IS NULL OR @ExistingDispoType = '' ) AND @DispoType IS NOT NULL ) OR ( @ExistingDispoType IS NOT NULL AND ( @DispoType IS NULL OR @DispoType = '' ) ) UPDATE MRBLotsToBeSentToSPN SET DispoType = @DispoType, IsDirty = 1, AddRemoveChangeMRBFlag = 'C', ParentLotNumber = @ParentLotNumber WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber END ELSE BEGIN UPDATE MRBLotsToBeSentToSPN SET DispoType = @DispoType, IsDirty = 1, ParentLotNumber = @ParentLotNumber WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber END END ELSE BEGIN INSERT INTO MRBLot( LotNumber, DieLotNumber, Status, DispoType, MRBNumber, Description, NewPartNo, WipPartNo, DiePartNo, ProductFamily, Gen, Channel, HexSize, Voltage, WaferCount, DieCount, Location, TotalCost, QualityCode ) VALUES ( @LotNumber, @DieLotNumber, @Status, @DispoType, @MRBNumber, @Description, @NewPartNo, @WipPartNo, @DiePartNo, @ProductFamily, @Gen, @Channel, @HexSize, @Voltage, @WaferCount, @DieCount, @Location, @TotalCost, @QualityCode ) SET @ExistingRowUpdated = 0 SET @LotID = CAST(SCOPE_IDENTITY() AS INT) IF EXISTS( SELECT MS.* FROM MRBLotsToBeSentToSPN MS WHERE MS.LotNumber = @LotNumber AND MS.MRBNumber = @MRBNumber AND SentToSPN = 1 ) BEGIN UPDATE MRBLotsToBeSentToSPN SET AddRemoveChangeMRBFlag = 'C', ParentLotNumber = @ParentLotNumber, IsDirty = 1, DispoType = @DispoType WHERE LotNumber = @LotNumber AND MRBNumber = @MRBNumber END ELSE BEGIN INSERT INTO MRBLotsToBeSentToSPN ( LotNumber, ParentLotNumber, MRBNumber, DispoType, AddRemoveChangeMRBFlag ) VALUES ( @LotNumber, @ParentLotNumber, @MRBNumber, @DispoType, 'A' ) END END SELECT @TotalLotCount = COUNT(*), @TotalWaferCount = SUM(ISNULL(WaferCount, 0)), @TotalDieCount = SUM(ISNULL(DieCount, 0)) FROM [MRBLot] WHERE MRBNumber = @MRBNumber UPDATE MRB SET NumberOfLotsAffected = ISNULL(@TotalLotCount, 0), NumberOfWafersAffected = ISNULL(@TotalWaferCount, 0), NumberOfDiesAffected = ISNULL(@TotalDieCount, 0) WHERE MRBNumber = @MRBNumber END GO