USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[SubmitForApproval_LotDisposition] 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].[SubmitForApproval_LotDisposition] @IssueID INT, @UserID INT, @PERequired BIT, @MRBRequired BIT, @DocumentTypeID INT, @SubRoleCategoriesClause VARCHAR(1000), @AppoverCount INT OUT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; CREATE TABLE #TempApprovals ( [IssueID] [int] NULL, [RoleName] [nvarchar](50) NULL, [SubRole] [nvarchar](50) NOT NULL, [UserID] [int] NOT NULL, [SubRoleID] [int] NOT NULL, [ItemStatus] [int] NULL, [Step] [int] NULL, [NotifyDate] [datetime] NULL, [AssignedDate] [datetime] NULL, [RoleAssignedDate] [datetime] NULL, [ApprovalType] [tinyint] NULL ) DECLARE @CurrentDate DATETIME DECLARE @ErrorMessage NVARCHAR(4000); DECLARE @ErrorSeverity INT; DECLARE @ErrorState INT; SET @CurrentDate = GETDATE() DECLARE @RHCount INT DECLARE @CheckForITARCompliant INT SET @RHCount = ( SELECT COUNT(*) FROM dbo.fnGetLot_RH(@IssueID) ) BEGIN TRY BEGIN TRAN UPDATE LotDisposition SET CurrentStep = 1, SubmitedDate = GETDATE() WHERE IssueID = @IssueID -- make sure to delete any existing approval items before sumbitting/re-submitting an issue DELETE FROM Approval WHERE IssueID = @IssueID AND DocumentTypeID = @DocumentTypeID -- UPDATE THE APPROVAL LOG INSERT INTO ApprovalLog ( IssueID, UserID, OperationType, OperationLog, DocumentTypeID ) VALUES ( @IssueID, @UserID, 'Submit', 'Submitted the document', @DocumentTypeID ) -- UPDATE THE APPROVAL LOG for a system initiated transaction INSERT INTO ApprovalLog ( IssueID, UserID, OperationType, OperationLog, DocumentTypeID ) VALUES ( @IssueID, @UserID, 'Delete', 'Delete Existing Approval', @DocumentTypeID ) IF @RHCount > 0 SET @CheckForITARCompliant = 1 ELSE SET @CheckForITARCompliant = 0 INSERT INTO #TempApprovals ( IssueID, RoleName, SubRole, UserID, SubRoleID, ItemStatus, Step, AssignedDate, NotifyDate, RoleAssignedDate, ApprovalType ) EXEC GetRoles @WorkflowStepNumber = 1, @WhereClause = @SubRoleCategoriesClause, @CheckForITARCompliant = @CheckForITARCompliant, @DocumentTypeID = @DocumentTypeID, @IssueID = @IssueID SET @AppoverCount = ( SELECT COUNT(*) FROM #TempApprovals) IF @AppoverCount > 0 BEGIN -- INSEERT INTO THE ACTUAL TABLE INSERT INTO Approval ( IssueID, RoleName, SubRole, UserID, SubRoleID, ItemStatus, Step, AssignedDate, NotifyDate, RoleAssignedDate, ApprovalType, DocumentTypeID ) ( SELECT DISTINCT *, @DocumentTypeID AS DocumentTypeID FROM #TempApprovals) END DROP TABLE #TempApprovals COMMIT END TRY BEGIN CATCH ROLLBACK INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( @UserID, 'Lot Disposition', @IssueID, 'Error', GETDATE(), 'Error while submitting rthe Lot Dispo ' + CONVERT(VARCHAR(10), @IssueID) + ' Lot Dispo# ' + CONVERT(VARCHAR(10), @IssueID), @IssueID ) SELECT @ErrorMessage = ERROR_MESSAGE() + CONVERT(VARCHAR(10), @IssueID) + ' Lot Dispo# ' + CONVERT(VARCHAR(10), @IssueID), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(); RAISERROR ( @ErrorMessage, -- Message text. @ErrorSeverity, -- Severity. @ErrorState -- State. ); END CATCH END GO