USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[LTSubmitForApproval_05012017] 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].[LTSubmitForApproval_05012017] @WorkRequestID INT, @UserID INT, @DocumentTypeID INT, @SubRoleCategoriesClause VARCHAR(1000), @AppoverCount INT OUT, @AllowedITAR INT OUT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; SET @AppoverCount = 0; 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 SET @CurrentDate = GETDATE() DECLARE @RHCount INT DECLARE @CheckForITARCompliant INT DECLARE @ITARRowCount INT SET @CheckForITARCompliant = 0 SET @AllowedITAR = 1 SELECT @RHCount = ( SELECT COUNT(*) FROM [TEMIRWAP019].[FAB2SPN].[dbo].[MP_RECORD] WITH(NOLOCK) WHERE MP_ITAR_CONTROLLED_SW = 'Y' AND MP_PART_NUMBER = ( SELECT WIPPartNumber FROM LTWorkRequest WHERE ID = @WorkRequestID ) ) IF (@RHCount > 0) BEGIN -- get the ITAR accessibility SET @CheckForITARCompliant = 1 -- need to exclude users who are not ITAR compliance SELECT @ITARRowCount = COUNT(*) FROM dbo.fnIsUserITARCompliant(@UserID) IF (@ITARRowCount = 0) BEGIN SET @AllowedITAR = 0 DROP TABLE #TempApprovals return; END END UPDATE LTWorkRequest SET CurrentStep = 1, SubmitedDate = GETDATE(), CloseDate = NULL WHERE ID = @WorkRequestID -- make sure to delete any existing approval items before sumbitting/re-submitting an issue DELETE FROM Approval WHERE IssueID = @WorkRequestID AND DocumentTypeID = @DocumentTypeID -- UPDATE THE APPROVAL LOG INSERT INTO ApprovalLog ( IssueID, UserID, OperationType, OperationLog, DocumentTypeID ) VALUES ( @WorkRequestID, @UserID, 'Submit', 'Submitted the document', @DocumentTypeID ) -- UPDATE THE APPROVAL LOG for a system initiated transaction INSERT INTO ApprovalLog ( IssueID, UserID, OperationType, OperationLog, DocumentTypeID ) VALUES ( @WorkRequestID, @UserID, 'Delete', 'Delete Existing Approval', @DocumentTypeID ) -- Trigger the approval based on the current roles for ECNs and TECNS only. -- For Emergency TECNs the users will pick the approvers manually 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 = @WorkRequestID 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 END GO