330 lines
7.0 KiB
Transact-SQL
330 lines
7.0 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[_8DSubmitForApproval] 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].[_8DSubmitForApproval] @CANo INT,
|
|
@UserID INT,
|
|
@DocumentTypeID INT,
|
|
@SubRoleCategoriesClause VARCHAR(1000),
|
|
@AppoverCount INT OUT,
|
|
@WorkFlowNumber INT = 1 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 @CheckForITARCompliant INT
|
|
SET
|
|
@CheckForITARCompliant = 0 DECLARE @CurrentStep INT = 1
|
|
UPDATE
|
|
_8DCorrectiveAction
|
|
SET
|
|
CurrentStep = @CurrentStep,
|
|
ClosedDate = NULL,
|
|
ApprovalStatus = 1,
|
|
CACompleteDate = GETDATE(),
|
|
CACompletedBy = @UserID
|
|
WHERE
|
|
CANo = @CANo -- make sure to delete any existing approval items before sumbitting/re-submitting an issue
|
|
DELETE FROM
|
|
Approval
|
|
WHERE
|
|
IssueID = @CANo
|
|
AND DocumentTypeID = @DocumentTypeID -- UPDATE THE APPROVAL LOG
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@CANo,
|
|
@UserID,
|
|
'Submit',
|
|
'Submitted the document',
|
|
@DocumentTypeID
|
|
) -- UPDATE THE APPROVAL LOG for a system initiated transaction
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@CANo,
|
|
@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 = @CANo --=======================================================
|
|
DECLARE @RoleExceptionName VARCHAR(50) DECLARE @RoleExceptionWorkFlowStepNumber VARCHAR(50) DECLARE @ApprovalType TINYINT DECLARE @AddtionalRoleID INT DECLARE @AddtionalRoleName VARCHAR(50) DECLARE @AdditionalSubRoleID INT DECLARE @AdditionalSubRoleName VARCHAR(50) -- Exception Roles WHERE the Role does not have fixed approvers.
|
|
-- The approver/s will be determined based on the issue
|
|
IF @DocumentTypeID = 9
|
|
OR @DocumentTypeID = 12 BEGIN
|
|
SELECT
|
|
@RoleExceptionName = R.RoleName,
|
|
@RoleExceptionWorkFlowStepNumber = WorkflowStepNumber
|
|
FROM
|
|
WorkflowSteps W
|
|
INNER JOIN Role R ON W.RoleID = R.RoleID
|
|
AND RulesApply = 1
|
|
INNER JOIN Workflows Wf On Wf.WorkflowID = W.WorkflowID
|
|
AND WorkFlowNumber = @WorkFlowNumber
|
|
WHERE
|
|
DocumentTypeID = @DocumentTypeID
|
|
AND RoleName = '8DQA' IF @RoleExceptionWorkFlowStepNumber = @CurrentStep BEGIN
|
|
SELECT
|
|
@UserID = QAID
|
|
FROM
|
|
_8DCorrectiveAction
|
|
WHERE
|
|
CANo = @CANo
|
|
SET
|
|
@ApprovalType = 1
|
|
SELECT
|
|
@AddtionalRoleID = R.RoleID,
|
|
@AddtionalRoleName = R.RoleName,
|
|
@AdditionalSubRoleID = SubRoleID,
|
|
@AdditionalSubRoleName = SubRoleCategoryItem
|
|
FROM
|
|
[Role] R
|
|
INNER JOIN SubRole SR ON R.RoleID = SR.RoleID
|
|
INNER JOIN SubRoleCategory SBR ON SR.SubRoleCategoryID = SBR.SubRoleCategoryID
|
|
WHERE
|
|
R.RoleName = @RoleExceptionName
|
|
INSERT INTO
|
|
#TempApprovals
|
|
(
|
|
IssueID,
|
|
RoleName,
|
|
SubRole,
|
|
UserID,
|
|
SubRoleID,
|
|
ItemStatus,
|
|
Step,
|
|
AssignedDate,
|
|
NotifyDate,
|
|
RoleAssignedDate,
|
|
ApprovalType
|
|
)
|
|
VALUES
|
|
(
|
|
@CANo,
|
|
@AddtionalRoleName,
|
|
@AdditionalSubRoleName,
|
|
@UserID,
|
|
@AdditionalSubRoleID,
|
|
0,
|
|
@CurrentStep,
|
|
GETDATE(),
|
|
GETDATE(),
|
|
GETDATE(),
|
|
@ApprovalType
|
|
)
|
|
END -- REQUESTOR=====================================
|
|
SELECT
|
|
@RoleExceptionName = R.RoleName,
|
|
@RoleExceptionWorkFlowStepNumber = WorkflowStepNumber
|
|
FROM
|
|
WorkflowSteps W
|
|
INNER JOIN Role R ON W.RoleID = R.RoleID
|
|
AND RulesApply = 1
|
|
INNER JOIN Workflows Wf On Wf.WorkflowID = W.WorkflowID
|
|
AND WorkFlowNumber = @WorkFlowNumber
|
|
WHERE
|
|
DocumentTypeID = @DocumentTypeID
|
|
AND RoleName = '8DRequestor' IF @RoleExceptionWorkFlowStepNumber = @CurrentStep BEGIN
|
|
SELECT
|
|
@UserID = RequestorID
|
|
FROM
|
|
_8DCorrectiveAction
|
|
WHERE
|
|
CANo = @CANo
|
|
SET
|
|
@ApprovalType = 1
|
|
SELECT
|
|
@AddtionalRoleID = R.RoleID,
|
|
@AddtionalRoleName = R.RoleName,
|
|
@AdditionalSubRoleID = SubRoleID,
|
|
@AdditionalSubRoleName = SubRoleCategoryItem
|
|
FROM
|
|
[Role] R
|
|
INNER JOIN SubRole SR ON R.RoleID = SR.RoleID
|
|
INNER JOIN SubRoleCategory SBR ON SR.SubRoleCategoryID = SBR.SubRoleCategoryID
|
|
WHERE
|
|
R.RoleName = @RoleExceptionName
|
|
INSERT INTO
|
|
#TempApprovals
|
|
(
|
|
IssueID,
|
|
RoleName,
|
|
SubRole,
|
|
UserID,
|
|
SubRoleID,
|
|
ItemStatus,
|
|
Step,
|
|
AssignedDate,
|
|
NotifyDate,
|
|
RoleAssignedDate,
|
|
ApprovalType
|
|
)
|
|
VALUES
|
|
(
|
|
@CANo,
|
|
@AddtionalRoleName,
|
|
@AdditionalSubRoleName,
|
|
@UserID,
|
|
@AdditionalSubRoleID,
|
|
0,
|
|
@CurrentStep,
|
|
GETDATE(),
|
|
GETDATE(),
|
|
GETDATE(),
|
|
@ApprovalType
|
|
)
|
|
END
|
|
END IF @DocumentTypeID = 6 -- Lot Traveler
|
|
BEGIN
|
|
SELECT
|
|
@RoleExceptionName = R.RoleName,
|
|
@RoleExceptionWorkFlowStepNumber = WorkflowStepNumber
|
|
FROM
|
|
WorkflowSteps W
|
|
INNER JOIN Role R ON W.RoleID = R.RoleID
|
|
AND RulesApply = 1
|
|
INNER JOIN Workflows Wf On Wf.WorkflowID = W.WorkflowID
|
|
AND WorkFlowNumber = @WorkFlowNumber
|
|
WHERE
|
|
DocumentTypeID = @DocumentTypeID IF @RoleExceptionWorkFlowStepNumber = @CurrentStep BEGIN IF @RoleExceptionName = 'Originator' BEGIN
|
|
SELECT
|
|
@UserID = OriginatorID
|
|
FROM
|
|
LTWorkRequest
|
|
WHERE
|
|
ID = @CANo
|
|
SET
|
|
@ApprovalType = 1
|
|
SELECT
|
|
@AddtionalRoleID = R.RoleID,
|
|
@AddtionalRoleName = R.RoleName,
|
|
@AdditionalSubRoleID = SubRoleID,
|
|
@AdditionalSubRoleName = SubRole
|
|
FROM
|
|
[Role] R
|
|
INNER JOIN SubRole SR ON R.RoleID = SR.RoleID
|
|
WHERE
|
|
R.RoleName = @RoleExceptionName
|
|
INSERT INTO
|
|
#TempApprovals
|
|
(
|
|
IssueID,
|
|
RoleName,
|
|
SubRole,
|
|
UserID,
|
|
SubRoleID,
|
|
ItemStatus,
|
|
Step,
|
|
AssignedDate,
|
|
NotifyDate,
|
|
RoleAssignedDate,
|
|
ApprovalType
|
|
)
|
|
VALUES
|
|
(
|
|
@CANo,
|
|
@AddtionalRoleName,
|
|
@AdditionalSubRoleName,
|
|
@UserID,
|
|
@AdditionalSubRoleID,
|
|
0,
|
|
@CurrentStep,
|
|
GETDATE(),
|
|
GETDATE(),
|
|
GETDATE(),
|
|
@ApprovalType
|
|
)
|
|
END
|
|
END
|
|
END --=======================================================
|
|
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 |