170 lines
4.1 KiB
Transact-SQL
170 lines
4.1 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: UserDefinedFunction [dbo].[fn_GetECNsByUser] Script Date: 11/21/2024 11:31:55 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
-- =============================================
|
|
-- Author: <Author,,Name>
|
|
-- Create date: <Create Date,,>
|
|
-- Description: <Description,,>
|
|
-- =============================================
|
|
CREATE FUNCTION [dbo].[fn_GetECNsByUser] (
|
|
-- 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 'ECN' AS DocumentType,
|
|
*
|
|
FROM
|
|
(
|
|
SELECT
|
|
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,
|
|
pdg.Names AS 'PendingApprovers',
|
|
Title,
|
|
DescriptionOfChange AS IssueDescription,
|
|
U2.FirstName + ' ' + U2.LastName AS Originator,
|
|
SubmitedDate,
|
|
CloseDate,
|
|
A.ItemStatus,
|
|
NULL AS NextDueDate
|
|
FROM
|
|
ECN E
|
|
INNER JOIN Approval A ON A.IssueID = E.ECNNumber
|
|
AND (
|
|
A.DocumentTypeID = 3
|
|
OR A.DocumentTypeID = 4
|
|
OR A.DocumentTypeID = 5
|
|
)
|
|
INNER JOIN Users U2 ON E.OriginatorID = U2.UserID
|
|
INNER JOIN Users U1 ON A.UserID = U1.UserID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT E.ECNNumber AS IssueID,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
'/' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50)) + '(' + A.RoleName + ')'
|
|
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
|
|
A.UserID = @UserID
|
|
AND E.Deleted = 0
|
|
AND (
|
|
ItemStatus = 0
|
|
OR (
|
|
ItemStatus = 2
|
|
AND DisplayDeniedDocument = 1
|
|
)
|
|
OR (
|
|
A.ItemStatus = 8
|
|
AND (
|
|
ExtensionDate > GETDATE()
|
|
OR ExpirationDate > GETDATE()
|
|
)
|
|
)
|
|
)
|
|
AND E.CancellationApproved = 0 --List of documents orginated by the user
|
|
UNION
|
|
ALL
|
|
SELECT
|
|
DISTINCT 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,
|
|
AP.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)) + '(' + A.RoleName + ')'
|
|
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
|
|
U1.UserID = @UserID
|
|
AND E.Deleted = 0
|
|
AND E.CancellationApproved = 0
|
|
AND E.ECNNumber NOT IN (
|
|
SELECT
|
|
IssueID
|
|
FROM
|
|
Approval
|
|
WHERE
|
|
IssueID = E.ECNNumber
|
|
AND ItemStatus <> 2
|
|
AND ItemStatus <> 8
|
|
AND (
|
|
DocumentTypeID = 3
|
|
OR DocumentTypeID = 4
|
|
)
|
|
)
|
|
) AS A
|
|
)
|
|
GO |