mesa-fab-approval/Programmability/Stored Procedures/GetLotDispositionsByUser.sql
Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

157 lines
3.4 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[GetLotDispositionsByUser] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author: <Author,,Name>
-- Create date: <Create Date,,>
-- Description: <Description,,>
-- =============================================
CREATE PROCEDURE [dbo].[GetLotDispositionsByUser] @UserID INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET
NOCOUNT ON;
--List of documents waiting on the user for approval/rejection
SELECT
DISTINCT *
FROM
(
SELECT
DISTINCT LD.IssueID,
IssueDate,
SQ.LotNo AS LotNos,
pdg.Names AS 'PendingApprovers',
IssueDescription,
U2.FirstName + ' ' + U2.LastName AS Originator,
SubmitedDate,
CloseDate
FROM
LotDisposition LD
INNER JOIN Approval A ON A.IssueID = LD.IssueID
AND DocumentTypeID = 1
INNER JOIN Users U2 ON LD.OriginatorID = U2.UserID
INNER JOIN Users U1 ON A.UserID = U1.UserID
LEFT JOIN (
SELECT
DISTINCT LD.IssueID,
STUFF (
(
SELECT
'/' + CAST(L.LotNumber AS varchar(512))
FROM
Lot L
WHERE
L.IssueID = LD.IssueID FOR XML PATH('')
),
1,
1,
''
) AS LotNo
FROM
LotDisposition LD
) AS SQ ON LD.IssueID = SQ.IssueID
LEFT JOIN (
SELECT
DISTINCT LD.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
DocumentTypeID = 1
AND A.IssueID = LD.IssueID
AND ItemStatus = 0
AND ItemStatus <> 2 FOR XML PATH('')
),
1,
1,
''
) AS Names
FROM
LotDisposition LD
) AS pdg ON LD.IssueID = pdg.IssueID
WHERE
A.UserID = @UserID
AND (ItemStatus = 0) --List of documents orginated by the user
UNION
ALL
SELECT
DISTINCT LD.IssueID,
IssueDate,
SQ.LotNo AS LotNos,
pdg.Names AS 'PendingApprovers',
IssueDescription,
U1.FirstName + ' ' + U1.LastName AS Originator,
SubmitedDate,
CloseDate
FROM
LotDisposition LD
INNER JOIN Users U1 ON LD.OriginatorID = U1.UserID
LEFT JOIN (
SELECT
DISTINCT LD.IssueID,
STUFF (
(
SELECT
'/' + CAST(L.LotNumber AS varchar(512))
FROM
Lot L
WHERE
L.IssueID = LD.IssueID FOR XML PATH('')
),
1,
1,
''
) AS LotNo
FROM
LotDisposition LD
) AS SQ ON LD.IssueID = SQ.IssueID
LEFT JOIN (
SELECT
DISTINCT LD.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
DocumentTypeID = 1
AND A.IssueID = LD.IssueID
AND ItemStatus = 0
AND ItemStatus <> 2 FOR XML PATH('')
),
1,
1,
''
) AS Names
FROM
LotDisposition LD
) AS pdg ON LD.IssueID = pdg.IssueID
WHERE
U1.UserID = @UserID
AND LD.IssueID NOT IN (
SELECT
IssueID
FROM
Approval
WHERE
IssueID = LD.IssueID
AND ItemStatus <> 2
AND DocumentTypeID = 1
)
) AS A
ORDER BY
A.IssueID DESC
END
GO