USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[GetRoles] Script Date: 11/21/2024 11:29:04 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[GetRoles] @WorkflowStepNumber INT, @WhereClause NVARCHAR(1000), @CheckForITARCompliant BIT, @DocumentTypeID INT, @IssueID INT, @WorkFlowNumber INT = 1 AS BEGIN SET NOCOUNT ON; DECLARE @Sql NVARCHAR(3000) -- 2018/12/21 - Special Business Logic For Parts Requests IF @DocumentTypeID = 10 AND @WhereClause LIKE '%Tech Lead%' BEGIN -- We need to assign a Tech Lead based on who is selected on the document itself SELECT DISTINCT CONVERT(NVARCHAR(20), @IssueID) AS IssueID, R.RoleName, SRC.SubRoleCategoryItem AS [SubRole], U.UserID, SR.SubRoleID, 0 AS [ItemStatus], WS.WorkflowStepNumber AS [Step], GETDATE() AS [AssignedDate], GETDATE() AS [NotifyDate], GETDATE() AS [RoleAssignedDate], ApprovalType FROM DocumentType D INNER JOIN PartsRequest PR ON PR.PRNumber = @IssueID INNER JOIN Workflows W ON D.DocumentTypeID = W.DocumentTypeID AND WorkFlowNumber = @WorkFlowNumber INNER JOIN WorkFlowSteps WS ON W.WorkflowID = WS.WorkflowID INNER JOIN Role R ON WS.RoleID = R.RoleID INNER JOIN SubRole SR ON R.RoleID = SR.RoleID INNER JOIN SubRoleCategory SRC ON SR.SubRoleCategoryID = SRC.SubRoleCategoryID INNER JOIN Users U ON U.UserID = PR.TechLeadID WHERE D.DocumentTypeID = @DocumentTypeID AND WorkflowStepNumber = @WorkflowStepNumber AND SRC.SubRoleCategoryItem = 'Tech Lead' END IF @CheckForITARCompliant = 0 -- do not check for ITAR compliant users SET @Sql = N ' SELECT DISTINCT ' + CONVERT(NVARCHAR(20), @IssueID) + ' AS IssueID, R.RoleName, SRC.SubRoleCategoryItem AS ''SubRole'', U.UserID, SR.SubRoleID, 0 AS ''ItemStatus'', WS.WorkflowStepNumber AS ''Step'', GETDATE() AS ''AssignedDate'', GETDATE() AS ''NotifyDate'', GETDATE() AS ''RoleAssignedDate'', ApprovalType FROM DocumentType D INNER JOIN Workflows W ON D.DocumentTypeID = W.DocumentTypeID AND WorkFlowNumber = ' + CONVERT(VARCHAR(10), @WorkFlowNumber) + ' INNER JOIN WorkFlowSteps WS ON W.WorkflowID = WS.WorkflowID INNER JOIN Role R ON WS.RoleID = R.RoleID INNER JOIN SubRole SR ON R.RoleID = SR.RoleID INNER JOIN SubRoleCategory SRC ON SR.SubRoleCategoryID = SRC.SubRoleCategoryID INNER JOIN UserSubRole USR ON SR.SubRoleID = USR.SubRoleID INNER JOIN Users U ON U.UserID = USR.UserID WHERE D.DocumentTypeID = ' + CONVERT(VARCHAR(10), @DocumentTypeID) + ' AND WorkflowStepNumber = ' + CONVERT(VARCHAR(10), @WorkflowStepNumber) + ' AND SRC.SubRoleCategoryItem IN ' + @WhereClause ELSE SET @Sql = N ' SELECT DISTINCT ' + CONVERT(NVARCHAR(20), @IssueID) + ' AS IssueID, R.RoleName, SRC.SubRoleCategoryItem AS ''SubRole'', U.UserID, SR.SubRoleID, 0 AS ''ItemStatus'', WS.WorkflowStepNumber AS ''Step'', GETDATE() AS ''AssignedDate'', GETDATE() AS ''NotifyDate'', GETDATE() AS ''RoleAssignedDate'', ApprovalType FROM DocumentType D INNER JOIN Workflows W ON D.DocumentTypeID = W.DocumentTypeID AND WorkFlowNumber = ' + CONVERT(VARCHAR(10), @WorkFlowNumber) + ' INNER JOIN WorkFlowSteps WS ON W.WorkflowID = WS.WorkflowID INNER JOIN Role R ON WS.RoleID = R.RoleID INNER JOIN SubRole SR ON R.RoleID = SR.RoleID INNER JOIN SubRoleCategory SRC ON SR.SubRoleCategoryID = SRC.SubRoleCategoryID INNER JOIN UserSubRole USR ON SR.SubRoleID = USR.SubRoleID INNER JOIN Users U ON U.UserID = USR.UserID INNER JOIN dbo.fnGetITARUsers() IT ON U.LoginID = IT.UserID WHERE D.DocumentTypeID = ' + CONVERT(VARCHAR(10), @DocumentTypeID) + ' AND WorkflowStepNumber = ' + CONVERT(VARCHAR(10), @WorkflowStepNumber) + ' AND SRC.SubRoleCategoryItem IN ' + @WhereClause EXEC (@Sql) END GO