Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

134 lines
2.6 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[EnableOOOStatus] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author: <Author,,Name>
-- Create date: <Create Date,,>
-- Description: <Description,,>
-- =============================================
CREATE PROCEDURE [dbo].[EnableOOOStatus] @OOOUserID INT,
@DelegatedTo INT,
@OOOStartDate DATETIME,
@OOOExpirationDate DATETIME,
@ReturnValue INT = 0 OUTPUT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET
NOCOUNT ON;
DECLARE @PENDING INT DECLARE @DENIED INT
SET
@PENDING = 0
SET
@DENIED = 2
SET
@ReturnValue = 0 -- Success
-- check to see if there the user already was schduled for an OOO
IF EXISTS (
SELECT
*
FROM
OOOTemp
WHERE
Processed = 0
AND OOOUserID = @OOOUserID
AND @OOOStartDate > GETDATE()
) BEGIN
SET
@ReturnValue = 1 RETURN;
END IF EXISTS (
SELECT
*
FROM
Users
WHERE
OOO = 1
AND UserID = @OOOUserID
) BEGIN
SET
@ReturnValue = 2 RETURN;
END -- Check if the delegator is already a delgator for some other user
-- A user can be as assigned a Delegator to only 1 user at a time.
IF EXISTS (
SELECT
*
FROM
Users
WHERE
DelegatedTo = @DelegatedTo
AND @DelegatedTo <> 0
) BEGIN
SET
@ReturnValue = 3 RETURN;
END -- set the ooo status for a future date from the UI
IF @OOOStartDate > GETDATE() BEGIN
INSERT INTO
OOOTemp (
OOOUserID,
DelegatedTo,
OOOStartDate,
OOOExpirationDate
)
VALUES
(
@OOOUserID,
@DelegatedTo,
@OOOStartDate,
@OOOExpirationDate
) RETURN;
END
ELSE BEGIN TRAN -- TODO
-- What if the OOO user has DOA for some other user
INSERT INTO
OOODelegatedRoles (UserID, DelegatedSubRoleID, Active) (
SELECT
@OOOUserID,
UserSubRoleID,
1
FROM
UserSubRole
WHERE
UserID = @OOOUserID
) -- UPDATE THE SubRole ID Table with Delegated User
UPDATE
UserSubRole
SET
UserID = @DelegatedTo,
Delegated = 1
WHERE
UserID = @OOOUserID -- UPDATE THE APPROVAL Log table
UPDATE
Approval
SET
UserID = @DelegatedTo,
Delegated = 1
WHERE
UserID = @OOOUserID
AND (
ItemStatus = @PENDING
OR ItemStatus = @DENIED
) -- Pending OR DENIED
-- Set the Flag in the users table
UPDATE
Users
SET
OOO = 1,
OOOStartDate = @OOOStartDate,
OOOExpirationDate = @OOOExpirationDate,
DelegatedTo = @DelegatedTo
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