USE [FabApprovalSystem] GO /****** Object: UserDefinedFunction [dbo].[fn_GetExpiredTECNByOriginator] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE FUNCTION [dbo].[fn_GetExpiredTECNByOriginator] ( -- Add the parameters for the function here @UserID INT, @MaxDays INT ) RETURNS TABLE AS RETURN ( SELECT DISTINCT 'ECN' AS DocumentType, CASE WHEN E.IsECN = 1 THEN 'ECN' WHEN E.IsTECN = 1 THEN 'TECN' WHEN E.IsEmergencyTECN = 1 THEN 'E-TECN' ELSE 'ECN' END AS SubDoc, E.ECNNumber AS IssueID, E.ECNNumber AS DocID, IssueDate, '' AS LotNos, ISNULL(pdg.Names, '') AS 'PendingApprovers', Title, DescriptionOfChange AS IssueDescription, U1.FirstName + ' ' + U1.LastName AS Originator, SubmitedDate, CloseDate, ItemStatus, NULL AS NextDueDate FROM ECN E INNER JOIN Users U1 ON E.OriginatorID = U1.UserID LEFT JOIN Approval AP ON E.ECNNumber = AP.IssueID LEFT JOIN ( SELECT DISTINCT E.ECNNumber AS IssueID, 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 ( A.DocumentTypeID = 3 OR A.DocumentTypeID = 4 OR A.DocumentTypeID = 5 ) AND A.IssueID = E.ECNNumber AND ItemStatus = 0 FOR XML PATH('') ), 1, 1, '' ) AS Names FROM ECN E ) AS pdg ON E.ECNNumber = pdg.IssueID WHERE E.OriginatorID = @UserID AND E.IsTECN = 1 AND ( ( ExtensionDate IS NULL AND DATEDIFF(dd, ExpirationDate, GETDATE()) BETWEEN 0 AND @MaxDays ) OR ( DATEDIFF(dd, ExtensionDate, GETDATE()) BETWEEN 0 AND @MaxDays ) ) AND CloseDate IS NOT NULL AND ExpirationDate < GETDATE() AND Deleted = 0 ) GO