USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[LTGetLotTravelerCreationAndRevisionNotifyList] Script Date: 11/21/2024 11:29:05 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE PROCEDURE [dbo].[LTGetLotTravelerCreationAndRevisionNotifyList] -- Add the parameters for the stored procedure here @LotID INT, @UserID INT, @WorkRequestID INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; SELECT U.Email FROM LTNotifyUsers N INNER JOIN Users U ON N.UserID = U.UserID WHERE NotificationType = 2 UNION SELECT U.Email FROM Users U WHERE U.UserID = @UserID UNION -- Affected Departments SELECT DISTINCT U.Email FROM SubRole SR 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 SubRoleCategory = 'Department' AND SRC.SubRoleCategoryItem IN ( SELECT SubRoleCategoryItem FROM SubRoleCategory S INNER JOIN LTAffectedDepartment AD ON S.SubRoleCategoryID = AD.DepartmentID WHERE AD.LTWorkRequestID = @WorkRequestID ) UNION -- Affected Modules SELECT DISTINCT U.Email FROM SubRole SR 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 SubRoleCategory IN('ModuleManager', 'Issue_MM') AND SRC.SubRoleCategoryItem IN ( SELECT ModuleName FROM Module M INNER JOIN LTAffectedModule AM ON M.ModuleID = AM.ModuleID WHERE AM.LTWorkRequestID = @WorkRequestID ) UNION -- list of all approvers SELECT DISTINCT U.Email FROM Approval A INNER JOIN Users U ON A.UserID = U.UserID WHERE IssueID = @WorkRequestID AND DocumentTypeID = 6 -- Document Type 'Lot Traveler' END GO