201 lines
4.2 KiB
Transact-SQL
201 lines
4.2 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[ECNSubmitCancellation_Expiration] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
-- =============================================
|
|
-- Author: Rajesh Kotian
|
|
-- Create date: 09/21/2015
|
|
-- Description: The routine is called when the the user cancels an exisitng Approved and Active TECN
|
|
-- =============================================
|
|
CREATE PROCEDURE [dbo].[ECNSubmitCancellation_Expiration] -- Add the parameters for the stored procedure here
|
|
@ECNNumber INT,
|
|
@UserID INT,
|
|
@DocumentTypeID INT,
|
|
@ECNType VARCHAR(10),
|
|
@Step INT,
|
|
@SubRoleCategoriesClause VARCHAR(1000),
|
|
@OperationType INT,
|
|
-- 1: Cancellation , 2: Expiration
|
|
@AppoverCount INT OUT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET
|
|
NOCOUNT ON;
|
|
|
|
DECLARE @MaxStep INT
|
|
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
|
|
) -- Insert statements for procedure here
|
|
--SELECT @MaxStep = (SELECT MAX(WS.WorkflowStepNumber)
|
|
-- FROM DocumentType D
|
|
-- INNER JOIN Workflows W ON D.DocumentTypeID = W.DocumentTypeID
|
|
-- INNER JOIN WorkflowSteps WS ON WS.WorkflowID = W.WorkflowID
|
|
-- AND D.DocumentTypeID = @DocumentTypeID)
|
|
DECLARE @OperationTypeString VARCHAR(50) DECLARE @ConvertedToNumber INT
|
|
SET
|
|
@ConvertedToNumber = (
|
|
SELECT
|
|
ConvertedToNumber
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
) -- Set the flag for the TECN, which this ECN was derived from
|
|
IF (@ConvertedToNumber IS NOT NULL) BEGIN EXEC ECNDeleteDocument @UserID,
|
|
@ConvertedToNumber,
|
|
@ECNType
|
|
UPDATE
|
|
ECN
|
|
SET
|
|
ConvertedToNumber = NULL
|
|
WHERE
|
|
ECNNumber = @ECNNumber DECLARE @SubRoleID INT
|
|
SET
|
|
@SubRoleID = 212
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
SubRoleID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@ECNNumber,
|
|
@UserID,
|
|
@SubRoleID,
|
|
'Invalid-Deleted ECN# ' + CONVERT(NCHAR(10), @ConvertedToNumber),
|
|
'Delete Invalid ECN# ' + CONVERT(NCHAR(10), @ConvertedToNumber),
|
|
@DocumentTypeID
|
|
)
|
|
END IF @OperationType = 1 -- Cancellation
|
|
BEGIN
|
|
SET
|
|
@OperationTypeString = 'Cancellation'
|
|
UPDATE
|
|
ECN
|
|
SET
|
|
CurrentStep = @Step,
|
|
CancellationInProgress = 1,
|
|
CancellationDate = GETDATE(),
|
|
Cancelled = 1
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
END
|
|
ELSE BEGIN
|
|
SET
|
|
@OperationTypeString = 'Expiration'
|
|
UPDATE
|
|
ECN
|
|
SET
|
|
CurrentStep = @Step,
|
|
ExpirationInProgress = 1
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
END DECLARE @WorkFlowNumber INT
|
|
SELECT
|
|
@WorkFlowNumber = WorkFlowNumber
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
INSERT INTO
|
|
#TempApprovals
|
|
(
|
|
IssueID,
|
|
RoleName,
|
|
SubRole,
|
|
UserID,
|
|
SubRoleID,
|
|
ItemStatus,
|
|
Step,
|
|
AssignedDate,
|
|
NotifyDate,
|
|
RoleAssignedDate,
|
|
ApprovalType
|
|
) EXEC GetRoles @WorkflowStepNumber = @Step,
|
|
@WhereClause = @SubRoleCategoriesClause,
|
|
@CheckForITARCompliant = 0,
|
|
@DocumentTypeID = @DocumentTypeID,
|
|
@IssueID = @ECNNumber,
|
|
@WorkFlowNumber = @WorkFlowNumber
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@ECNNumber,
|
|
@UserID,
|
|
@OperationTypeString + ' Approval initiated',
|
|
'Submitted the document for ' + @OperationTypeString,
|
|
@DocumentTypeID
|
|
)
|
|
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
|
|
-- Update the Event Log
|
|
INSERT INTO
|
|
EventLog (
|
|
UserID,
|
|
IssueID,
|
|
DocumentType,
|
|
OperationType,
|
|
Comments
|
|
)
|
|
VALUES
|
|
(
|
|
@UserID,
|
|
@ECNNumber,
|
|
@ECNType,
|
|
'Initiate ' + @OperationTypeString,
|
|
'Initiate the' + + @OperationTypeString + ' of the document '
|
|
)
|
|
END
|
|
GO |