239 lines
4.8 KiB
Transact-SQL
239 lines
4.8 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[ECNSubmitForApproval] 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].[ECNSubmitForApproval] @ECNNumber 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
|
|
SET
|
|
@RHCount = (
|
|
SELECT
|
|
COUNT(*)
|
|
FROM
|
|
ECN E
|
|
WHERE
|
|
(
|
|
E.IsRH = 1
|
|
AND E.IsAU = 0
|
|
AND E.IsIndustrial = 0
|
|
AND E.IsMA = 0
|
|
)
|
|
AND E.ECNNumber = @ECNNumber
|
|
) 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 DECLARE @ErrorMessage NVARCHAR(4000);
|
|
|
|
DECLARE @ErrorSeverity INT;
|
|
|
|
DECLARE @ErrorState INT;
|
|
|
|
DECLARE @ConvertedFromNumber INT
|
|
SET
|
|
@ConvertedFromNumber = (
|
|
SELECT
|
|
ConvertedFromNumber
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
) BEGIN TRY BEGIN TRAN
|
|
UPDATE
|
|
ECN
|
|
SET
|
|
CurrentStep = 1,
|
|
SubmitedDate = GETDATE(),
|
|
CloseDate = NULL,
|
|
ConversionApprovalInProgress = CASE
|
|
WHEN @ConvertedFromNumber IS NULL THEN 0
|
|
ELSE 1
|
|
END
|
|
WHERE
|
|
ECNNumber = @ECNNumber -- UPDATE THE TECN, which this ECN was derived from
|
|
IF (@ConvertedFromNumber IS NOT NULL) BEGIN
|
|
UPDATE
|
|
ECN
|
|
SET
|
|
ConversionApprovalInProgress = 1
|
|
WHERE
|
|
ECNNumber = @ConvertedFromNumber
|
|
END -- make sure to delete any existing approval items before sumbitting/re-submitting an issue
|
|
DELETE FROM
|
|
Approval
|
|
WHERE
|
|
IssueID = @ECNNumber
|
|
AND DocumentTypeID = @DocumentTypeID -- UPDATE THE APPROVAL LOG
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@ECNNumber,
|
|
@UserID,
|
|
'Submit',
|
|
'Submitted the document',
|
|
@DocumentTypeID
|
|
) -- UPDATE THE APPROVAL LOG for a system initiated transaction
|
|
INSERT INTO
|
|
ApprovalLog (
|
|
IssueID,
|
|
UserID,
|
|
OperationType,
|
|
OperationLog,
|
|
DocumentTypeID
|
|
)
|
|
VALUES
|
|
(
|
|
@ECNNumber,
|
|
@UserID,
|
|
'Delete',
|
|
'Delete Existing Approval',
|
|
@DocumentTypeID
|
|
) DECLARE @WorkFlowNumber INT
|
|
SELECT
|
|
@WorkFlowNumber = WorkFlowNumber
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ECNNumber -- Trigger the approval based on the current roles for ECNs and TECNS only.
|
|
-- For Emergency TECNs the users will pick the approvers manually
|
|
IF @DocumentTypeID = 3 BEGIN -- IGNORE THE ITAR CHECK
|
|
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 = @ECNNumber,
|
|
@WorkFlowNumber = @WorkFlowNumber
|
|
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 COMMIT
|
|
END TRY BEGIN CATCH ROLLBACK
|
|
INSERT INTO
|
|
EventLog (
|
|
UserID,
|
|
DocumentType,
|
|
IssueID,
|
|
OperationType,
|
|
InsertTimeStamp,
|
|
Comments,
|
|
SysDocumentID
|
|
)
|
|
VALUES
|
|
(
|
|
@UserID,
|
|
'ECN',
|
|
@ECNNumber,
|
|
'Error',
|
|
GETDATE(),
|
|
'Error while submitting rthe Lot Dispo ' + CONVERT(VARCHAR(10), @ECNNumber) + ' ECN# ' + CONVERT(VARCHAR(10), @ECNNumber),
|
|
@ECNNumber
|
|
)
|
|
SELECT
|
|
@ErrorMessage = ERROR_MESSAGE() + CONVERT(VARCHAR(10), @ECNNumber) + ' ECN# ' + CONVERT(VARCHAR(10), @ECNNumber),
|
|
@ErrorSeverity = ERROR_SEVERITY(),
|
|
@ErrorState = ERROR_STATE();
|
|
|
|
RAISERROR (
|
|
@ErrorMessage,
|
|
-- Message text.
|
|
@ErrorSeverity,
|
|
-- Severity.
|
|
@ErrorState -- State.
|
|
);
|
|
|
|
END CATCH
|
|
END
|
|
GO |