USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[ExpireOOOStatus] Script Date: 11/21/2024 11:29:04 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE PROCEDURE [dbo].[ExpireOOOStatus] -- Add the parameters for the stored procedure here @OOOUserID INT, @DelegatedTo INT = -1 AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; --DECLARE @DelegatedTo INT DECLARE @PENDING INT DECLARE @DENIED INT SET @PENDING = 0 SET @DENIED = 2 -- default of -1 is passed from the Web UI, because of limited time to code in to extract the delegated person IF @DelegatedTo = -1 BEGIN SELECT @DelegatedTo = DelegatedTo FROM Users WHERE UserID = @OOOUserID END BEGIN TRAN -- set all the current task to the original user UPDATE Approval SET UserID = @OOOUserID, Delegated = 0 WHERE UserID = @DelegatedTo AND Delegated = 1 AND ( ItemStatus = @PENDING OR ItemStatus = @DENIED ) AND SubRoleID IN ( SELECT SubRoleID FROM OOODelegatedRoles O INNER JOIN UserSubRole U ON O.DelegatedSubRoleID = U.UserSubRoleID WHERE O.UserID = @OOOUserID And Active = 1 ) -- Set the Subrole for the user to its original state UPDATE UserSubRole SET UserID = @OOOUserID, Delegated = 0 WHERE UserID = @DelegatedTo AND Delegated = 1 AND SubRoleID IN ( SELECT SubRoleID FROM OOODelegatedRoles O INNER JOIN UserSubRole U ON O.DelegatedSubRoleID = U.UserSubRoleID WHERE O.UserID = @OOOUserID And Active = 1 ) UPDATE OOODelegatedRoles SET Active = 0 WHERE UserID = @OOOUserID AND Active = 1 UPDATE Users SET OOO = 0, OOOStartDate = NULL, OOOExpirationDate = NULL, DelegatedTo = NULL WHERE UserID = @OOOUserID -- TODO -- Trigger to update the Delegated column in the Approval table when inserting new aapproval records -- Create the Log of the delgate process COMMIT TRAN END GO