161 lines
3.7 KiB
Transact-SQL
161 lines
3.7 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: UserDefinedFunction [dbo].[fn_GetMRBByUserPrev] 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_GetMRBByUserPrev] (
|
|
-- 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 'MRB' AS DocumentType,
|
|
'MRB' AS SubDoc,
|
|
*
|
|
FROM
|
|
(
|
|
SELECT
|
|
DISTINCT M.MRBNumber as IssueID,
|
|
M.MRBRaisedDate AS IssueDate,
|
|
SQ.LotNo AS LotNos,
|
|
pdg.Names AS 'PendingApprovers',
|
|
Title,
|
|
IssueDescription,
|
|
U2.FirstName + ' ' + U2.LastName AS Originator,
|
|
SubmitedDate,
|
|
CloseDate,
|
|
A.ItemStatus
|
|
FROM
|
|
MRB M
|
|
INNER JOIN Approval A ON A.IssueID = M.MRBNumber
|
|
AND DocumentTypeID = 2
|
|
INNER JOIN Users U2 ON M.Owner = U2.UserID
|
|
INNER JOIN Users U1 ON A.UserID = U1.UserID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT M.MRBNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
'/' + CAST(L.LotNumber AS varchar(512))
|
|
FROM
|
|
MRBLot L
|
|
WHERE
|
|
L.MRBNumber = M.MRBNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS LotNo
|
|
FROM
|
|
MRB M
|
|
) AS SQ ON M.MRBNumber = SQ.MRBNumber
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT M.MRBNumber,
|
|
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 = 2
|
|
AND A.IssueID = M.MRBNumber
|
|
AND ItemStatus = 0 FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Names
|
|
FROM
|
|
MRB M
|
|
) AS pdg ON M.MRBNumber = pdg.MRBNumber
|
|
WHERE
|
|
A.UserID = @UserID
|
|
AND (ItemStatus = 0) --List of documents orginated by the user
|
|
UNION
|
|
ALL
|
|
SELECT
|
|
DISTINCT M.MRBNumber AS IssueID,
|
|
M.MRBRaisedDate AS IssueDate,
|
|
SQ.LotNo AS LotNos,
|
|
pdg.Names AS 'PendingApprovers',
|
|
Title,
|
|
IssueDescription,
|
|
U1.FirstName + ' ' + U1.LastName AS Originator,
|
|
M.SubmitedDate AS SubmitedDate,
|
|
M.CloseDate AS CloseDate,
|
|
AP.ItemStatus
|
|
FROM
|
|
MRB M
|
|
INNER JOIN Users U1 ON M.Owner = U1.UserID
|
|
LEFT JOIN Approval AP ON M.MRBNumber = AP.IssueID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT M.MRBNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
'/' + CAST(L.LotNumber AS varchar(512))
|
|
FROM
|
|
MRBLot L
|
|
WHERE
|
|
L.MRBNumber = M.MRBNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS LotNo
|
|
FROM
|
|
MRB M
|
|
) AS SQ ON M.MRBNumber = SQ.MRBNumber
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT M.MRBNumber,
|
|
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 = 2
|
|
AND A.IssueID = M.MRBNumber
|
|
AND ItemStatus = 0 FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Names
|
|
FROM
|
|
MRB M
|
|
) AS pdg ON M.MRBNumber = pdg.MRBNumber
|
|
WHERE
|
|
U1.UserID = @UserID
|
|
AND AP.DocumentTypeID = 2
|
|
AND M.MRBNumber NOT IN (
|
|
SELECT
|
|
IssueID
|
|
FROM
|
|
Approval
|
|
WHERE
|
|
IssueID = M.MRBNumber
|
|
AND ItemStatus = 1
|
|
AND DocumentTypeID = 2
|
|
)
|
|
) AS A
|
|
)
|
|
GO |