mesa-fab-approval/Programmability/Stored Procedures/PartsRequestSubmitForApproval.sql
Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

163 lines
3.3 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[PartsRequestSubmitForApproval] Script Date: 11/21/2024 11:29:05 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[PartsRequestSubmitForApproval] @PRNumber int,
@UserID int AS BEGIN DECLARE @DocumentTypeID int = 10 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 @initialtrancount int = @ @TRANCOUNT BEGIN TRANSACTION BEGIN TRY
UPDATE
PartsRequest
SET
SubmitDate = GETDATE(),
CurrentStep = 0,
CloseDate = NULL
WHERE
PRNumber = @PRNumber -- make sure to delete any existing approval items before sumbitting/re-submitting an issue
DELETE FROM
Approval
WHERE
IssueID = @PRNumber
AND DocumentTypeID = @DocumentTypeID IF @ @ROWCOUNT > 0 BEGIN -- UPDATE THE APPROVAL LOG for a system initiated transaction
INSERT INTO
ApprovalLog (
IssueID,
UserID,
OperationType,
OperationLog,
DocumentTypeID
)
VALUES
(
@PRNumber,
@UserID,
'Delete',
'Delete Existing Approval',
@DocumentTypeID
)
END -- UPDATE THE APPROVAL LOG
INSERT INTO
ApprovalLog (
IssueID,
UserID,
OperationType,
OperationLog,
DocumentTypeID
)
VALUES
(
@PRNumber,
@UserID,
'Submit',
'Submitted the document',
@DocumentTypeID
) DECLARE @SubRoleCategoriesClause varchar(100)
SET
@SubRoleCategoriesClause = '(''' + dbo.fnPartsRequestGetSubRolesForNextStep(@PRNumber) + ''')' PRINT @SubRoleCategoriesClause DECLARE @WorkFlowNumber int
SET
@WorkFlowNumber = (
SELECT
MIN(WorkflowNumber)
FROM
Workflows
WHERE
WorkflowName = 'PRWkFlow'
)
INSERT INTO
#TempApprovals
(
IssueID,
RoleName,
SubRole,
UserID,
SubRoleID,
ItemStatus,
Step,
AssignedDate,
NotifyDate,
RoleAssignedDate,
ApprovalType
) EXEC GetRoles @WorkflowStepNumber = 1,
@WhereClause = @SubRoleCategoriesClause,
@CheckForITARCompliant = 0,
@DocumentTypeID = @DocumentTypeID,
@IssueID = @PRNumber,
@WorkFlowNumber = @WorkFlowNumber IF (
SELECT
COUNT(*)
FROM
#TempApprovals) = 0
BEGIN RAISERROR(
'Parts Request submit error - no approvers found',
16,
1
)
END -- INSERT 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)
DROP TABLE #TempApprovals
UPDATE
PartsRequest
SET
CurrentStep = 1
WHERE
PRNumber = @PRNumber COMMIT TRANSACTION
END TRY BEGIN CATCH ROLLBACK TRANSACTION DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE() DECLARE @ErrorSeverity INT = ERROR_SEVERITY() DECLARE @ErrorState INT = ERROR_STATE()
INSERT INTO
EventLog (
UserID,
DocumentType,
IssueID,
OperationType,
InsertTimeStamp,
Comments
)
VALUES
(
@UserID,
'PR',
@PRNumber,
'Error',
GETDATE(),
LEFT(
'Error while submitting PR: ' + @ErrorMessage,
500
)
) IF @initialtrancount > 0 BEGIN TRANSACTION RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState);
END CATCH
END
GO