USE [FabApprovalSystem] GO /****** Object: UserDefinedFunction [dbo].[fn_Get8DCAByUser] Script Date: 11/21/2024 11:31:55 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE FUNCTION [dbo].[fn_Get8DCAByUser] ( -- Add the parameters for the function here @UserID INT ) RETURNS TABLE AS RETURN ( -- Add the SELECT statement with parameter references here -- M_Suffix SELECT DISTINCT 'CorrectiveAction' AS DocumentType, 'CA' AS SubDoc, * FROM ( SELECT DISTINCT CA.CANo as IssueID, CA.CANo as DocID, CA.IssueDate, '' AS LotNos, pdg.Names AS 'PendingApprovers', CA.CATitle AS Title, CA.D2ProblemDescription IssueDescription, U2.FirstName + ' ' + U2.LastName AS Originator, CA.CACompleteDate SubmitedDate, CA.ClosedDate CloseDate, A.ItemStatus, CASE WHEN Status = 1 THEN NULL WHEN Status IN (10, 9, 3) THEN CA.D3DueDate WHEN Status IN (4, 5, 6, 7) THEN CA.D5D7DueDate WHEN Status = 11 THEN CA.FollowUpDate ELSE CA.D8DueDate END AS NextDueDate FROM _8DCorrectiveAction CA INNER JOIN Approval A ON A.IssueID = CA.CANo AND DocumentTypeID = 9 LEFT JOIN Users U2 ON CA.RequestorID = U2.UserID INNER JOIN Users U1 ON A.UserID = U1.UserID LEFT JOIN ( SELECT DISTINCT CA.CANo, STUFF ( ( SELECT '/' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50)) FROM Approval A INNER JOIN Users U ON A.UserID = U.UserID WHERE DocumentTypeID = 9 AND A.IssueID = CA.CANo AND ItemStatus = 0 FOR XML PATH('') ), 1, 1, '' ) AS Names FROM _8DCorrectiveAction CA ) AS pdg ON CA.CANo = pdg.CANo WHERE A.UserID = @UserID AND Status NOT IN (1, 11) AND CA.Deleted = 0 UNION SELECT DISTINCT CA.CANo as IssueID, CA.CANo as DocID, CA.IssueDate, '' AS LotNos, pdg.Names AS 'PendingApprovers', CA.CATitle AS Title, CA.D2ProblemDescription IssueDescription, U2.FirstName + ' ' + U2.LastName AS Originator, CA.CACompleteDate SubmitedDate, CA.ClosedDate CloseDate, A.ItemStatus, CASE WHEN Status = 1 THEN NULL WHEN Status IN (10, 9, 3) THEN CA.D3DueDate WHEN Status IN (4, 5, 6, 7) THEN CA.D5D7DueDate WHEN Status = 11 THEN CA.FollowUpDate ELSE CA.D8DueDate END AS NextDueDate FROM _8DCorrectiveAction CA LEFT JOIN Approval A ON A.IssueID = CA.CANo AND DocumentTypeID = 9 INNER JOIN Users U2 ON CA.RequestorID = U2.UserID LEFT JOIN ( SELECT DISTINCT CA.CANo, STUFF ( ( SELECT '/' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50)) FROM Approval A INNER JOIN Users U ON A.UserID = U.UserID WHERE DocumentTypeID = 9 AND A.IssueID = CA.CANo AND ItemStatus = 0 FOR XML PATH('') ), 1, 1, '' ) AS Names FROM _8DCorrectiveAction CA ) AS pdg ON CA.CANo = pdg.CANo WHERE CA.QAID = @UserID AND CA.ClosedDate IS NULL -- added the where clause below on 8/2/2019 RJK AND Status <> 1 AND CA.Deleted = 0 ) AS A ) GO