USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[LTCreateLotTravHoldSteps] Script Date: 11/21/2024 11:29:05 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE PROCEDURE [dbo].[LTCreateLotTravHoldSteps] -- Add the parameters for the stored procedure here @LotTravelerRevisionID INT, @LTWorkRequestID INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; DECLARE @ID INT DECLARE @BaseFlow VARCHAR(50) DECLARE @Location VARCHAR(50) DECLARE @OperSequence NCHAR(10) DECLARE @Operation VARCHAR(50) DECLARE @OperationDescription VARCHAR(100) DECLARE @ChangeInstructions VARCHAR(1000) DECLARE @UpdatedBy INT DECLARE @tempLTHoldStepID INT DECLARE @LotNumber VARCHAR(50) DECLARE @SPNCurrentSeqForTheLot NCHAR(10) DECLARE @SPNCurrentLotLocation NCHAR(10) DECLARE CurHoldSteps CURSOR FOR SELECT ID, BaseFlow, Location, OperSequence, Operation, OperationDescription, ChangeInstructions, UpdatedBy FROM LTHoldStep WHERE LTWorkRequestID = @LTWorkRequestID SET @LotNumber = ( SELECT TOP 1 L.LotNumber FROM LTLotTravelerRevisionAttrib LTA INNER JOIN LTLot L ON LTA.LTLotID = L.ID WHERE LTA.ID = @LotTravelerRevisionID ) SET @SPNCurrentLotLocation = ( SELECT WP_CURRENT_LOCATION FROM vFAB2SPN_WP_RECORD WP WHERE WP_LOT_NO = @LotNumber ) OPEN CurHoldSteps; FETCH NEXT FROM CurHoldSteps INTO @ID, @BaseFlow, @Location, @OperSequence, @Operation, @OperationDescription, @ChangeInstructions, @UpdatedBy WHILE @ @FETCH_STATUS = 0 BEGIN -- Get the current location and operation for the respective lot -- only allow add hol step at a current location or a location which has not been passed yet INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( 999, 'LotTraveler', 9999, 'Logging', GETDATE(), 'Oper Seq -' + ISNULL(@OperSequence, 'NULL') + ' @SPNCurrentLotLocation - ' + ISNULL(@SPNCurrentLotLocation, 'NULL') + 'WO_LOT_NO = ' + ISNULL(@LotNumber, 'NULL') + 'WO_LOCATION = ' + ISNULL(@Location, 'NULL') + 'WO_PROCESS = ' + ISNULL(@BaseFlow, 'NULL') + 'LotTravelerRevisionID = ' + ISNULL( CONVERT(NCHAR(10), @LotTravelerRevisionID), 'NULL' ), 99999 ) IF (@SPNCurrentLotLocation <= @Location) BEGIN INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( 999, 'LotTraveler', 9999, 'Logging', GETDATE(), 'Oper Seq -' + ISNULL(@OperSequence, 'NULL') + ' @SPNCurrentLotLocation - ' + ISNULL(@SPNCurrentLotLocation, 'NULL') + 'WO_LOT_NO = ' + ISNULL(@LotNumber, 'NULL') + 'WO_LOCATION = ' + ISNULL(@Location, 'NULL') + 'WO_PROCESS = ' + ISNULL(@BaseFlow, 'NULL') + 'LotTravelerRevisionID = ' + ISNULL( CONVERT(NCHAR(10), @LotTravelerRevisionID), 'NULL' ), 99999 ) -- get the Seq Number of the Hold Step that was entered in the WR SET @SPNCurrentSeqForTheLot = ( SELECT MAX(SEQ) FROM vFAB2SPN_WO_RECORD WO INNER JOIN vSPNPDB_FLOWLOCS F ON WO.WO_PROCESS = F.PROCESS AND WO.WO_LOCATION = F.LOC AND WO.WO_OPER_NO = F.OPER WHERE WO_LOT_NO = @LotNumber AND WO_LOCATION = @Location AND WO_PROCESS = @BaseFlow ) IF (@OperSequence > @SPNCurrentSeqForTheLot) OR (@SPNCurrentSeqForTheLot IS NULL) OR (@OperSequence IS NULL) BEGIN INSERT INTO LTLotTravelerHoldSteps ( Location, OperSequence, Operation, OperationDescription, ChangeInstructions, LotTravelerRevisionID, UpdatedBy ) VALUES ( @Location, @OperSequence, @Operation, @OperationDescription, @ChangeInstructions, @LotTravelerRevisionID, @UpdatedBy ) SET @tempLTHoldStepID = SCOPE_IDENTITY() INSERT INTO LTLotTravAttachment ( FileGUID, FileName, DocType, Comments, LotTravelerRevisionID, LTLotTravHoldStepID, UploadDateTime, UploadedByID ) SELECT FileGUID, FileName, DocType, Comments, @LotTravelerRevisionID, @tempLTHoldStepID, UploadDateTime, UploadedByID FROM LTWorkRequestAttachment WHERE HoldStepID = @ID END END FETCH NEXT FROM CurHoldSteps INTO @ID, @BaseFlow, @Location, @OperSequence, @Operation, @OperationDescription, @ChangeInstructions, @UpdatedBy END CLOSE CurHoldSteps; DEALLOCATE CurHoldSteps; END GO