USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[LTCreateLotTraveler] 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].[LTCreateLotTraveler] -- Add the parameters for the stored procedure here @LTLotID INT, @WorkRequestID INT, @UserID INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; DECLARE @NewLotTravelerRevisionID INT DECLARE @NewRevisionNumber INT DECLARE @ErrorMessage NVARCHAR(4000); DECLARE @ErrorSeverity INT; DECLARE @ErrorState INT; IF EXISTS ( SELECT * FROM LTLotTravelerRevisionAttrib WHERE LTLotID = @LTLotID ) BEGIN SET @NewRevisionNumber = ( SELECT MAX(RevisionNumber) + 1 FROM LTLotTravelerRevisionAttrib WHERE LTLotID = @LTLotID ) END ELSE BEGIN SET @NewRevisionNumber = 0 END DECLARE @LotNumber VARCHAR(50) BEGIN TRY --BEGIN TRAN SET @LotNumber = ( SELECT LotNUmber FROM LTLot WHERE ID = @LTLotID ) INSERT INTO LTLotTravelerRevisionAttrib ( LTLotID, IsCurrentRevision, RevisionNumber, TravelerLastUpdatedBy, TraverlerLastUpdatedDatetime ) VALUES ( @LTLotID, 1, @NewRevisionNumber, @UserID, GETDATE() ) SET @NewLotTravelerRevisionID = SCOPE_IDENTITY() UPDATE LTLotTravelerRevisionAttrib SET IsCurrentRevision = 0 WHERE LTLotID = @LTLotID AND ID <> @NewLotTravelerRevisionID --PRINT @NewLotTravelerRevisionID EXEC LTCreateLotTravHoldSteps @NewLotTravelerRevisionID, @WorkRequestID UPDATE LTLot SET IsTravelerGenerated = 1, TravelerCreatedBy = @UserID, TravelerCreateDate = GETDATE(), LotTravelerCurrentRevision = @NewRevisionNumber WHERE ID = @LTLotID INSERT INTO LTLotTravelerHistory ( UserID, LTLotID, TravelerRevisionAttribID, Operation, Comments ) VALUES ( @UserID, @LTLotID, @NewLotTravelerRevisionID, 'Create', 'Lot Traveler Created' ) --COMMIT TRAN END TRY BEGIN CATCH --ROLLBACK INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( @UserID, 'LotTraveler', @LTLotID, 'Error', GETDATE(), 'Error while creating Travler for Lot# ' + @LotNumber + ' WorkRequest# ' + CONVERT(VARCHAR(10), @WorkRequestID), @WorkRequestID ) SELECT @ErrorMessage = ERROR_MESSAGE() + 'Error while creating Travler for Lot# ' + CONVERT(VARCHAR(10), @LotNumber) + ' WorkRequest# ' + CONVERT(VARCHAR(10), @WorkRequestID), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(); RAISERROR ( @ErrorMessage, -- Message text. @ErrorSeverity, -- Severity. @ErrorState -- State. ); END CATCH END GO