Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

385 lines
7.8 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[GetLotDispositionReport] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[GetLotDispositionReport] @IssueID varchar(100) = NULL,
@OriginatorID int = NULL,
@Title varchar(100) = NULL,
@ProductFamilies varchar(max) = NULL,
@LotNumbers varchar(max) = NULL,
@Location varchar(50) = NULL,
@LocationCompare int = NULL,
@PendingApproverID int = NULL,
@SubmitDateFrom date = NULL,
@SubmitDateTo date = NULL,
@CloseDateFrom date = NULL,
@CloseDateTo date = NULL,
@ResponsibilityIDs varchar(max) = NULL,
@ResponsibilityIssueIDs varchar(max) = NULL,
@DispositionByOCAP bit = NULL,
@IssueDescription varchar(100) = NULL,
@ReasonForDisposition varchar(100) = NULL,
@ScrapCost money = NULL,
@ScrapCostCompare int = NULL,
@ScrapWaferQty int = NULL,
@ScrapWaferQtyCompare int = NULL,
@ScrapDieQty int = NULL,
@ScrapDieQtyCompare int = NULL,
@BaseURL varchar(100) = NULL,
@Username varchar(100) = '' AS BEGIN
SET
XACT_ABORT ON
INSERT INTO
ReportLog([ProcName], [Username], [Parms])
SELECT
OBJECT_NAME(@ @PROCID),
@Username,
(
SELECT
@IssueID AS IssueID,
@OriginatorID AS OriginatorID,
@Title AS Title,
@ProductFamilies AS ProductFamilies,
@LotNumbers AS LotNumbers,
@Location AS [Location],
@LocationCompare AS LocationCompare,
@PendingApproverID AS PendingApproverID,
@SubmitDateFrom AS SubmitDateFrom,
@SubmitDateTo AS SubmitDateTo,
@CloseDateFrom AS CloseDateFrom,
@CloseDateTo AS CloseDateTo,
@ResponsibilityIDs AS ResponsibilityIDs,
@ResponsibilityIssueIDs AS ResponsibilityIssueIDs,
@DispositionByOCAP AS DispositionByOCAP,
@IssueDescription AS IssueDescription,
@ReasonForDisposition AS ReasonForDisposition,
@ScrapCost AS ScrapCost,
@ScrapCostCompare AS ScrapCostCompare,
@ScrapWaferQty AS ScrapWaferQty,
@ScrapWaferQtyCompare AS ScrapWaferQtyCompare,
@ScrapDieQty AS ScrapDieQty,
@ScrapDieQtyCompare AS ScrapDieQtyCompare,
@BaseURL AS BaseURL FOR XML PATH
)
SELECT
LD.IssueID,
OriginatorU.FirstName + ' ' + OriginatorU.LastName AS Originator,
Title,
STUFF(
(
SELECT
DISTINCT ' / ' + RTRIM(L.ProductFamily) + RTRIM(L.Gen)
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
ORDER BY
1 FOR XML PATH('')
),
1,
3,
''
) AS ProductFamily,
STUFF(
(
SELECT
DISTINCT ' / ' + RTRIM(L.LotNumber)
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
ORDER BY
1 FOR XML PATH('')
),
1,
3,
''
) AS LotNumbers,
STUFF(
(
SELECT
DISTINCT ' / ' + RTRIM(L.Location)
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
ORDER BY
1 FOR XML PATH('')
),
1,
3,
''
) AS Locations,
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 = 1
AND A.IssueID = LD.IssueID
AND ItemStatus = 0 FOR XML PATH('')
),
1,
1,
''
) AS PendingApprovers,
SubmitedDate,
CloseDate,
R.ResponsibilityName,
RI.Issue,
LD.DispositionByOCAP,
IssueDescription,
ReasonForDisposition,
LDLotSummary.*,
(
SELECT
'`* ' + A.Comments
FROM
Approval A
WHERE
A.DocumentTypeID = 1
AND A.IssueID = LD.IssueID
AND ItemStatus = 1
AND ISNULL(A.Comments, '') <> ''
ORDER BY
A.ApprovalID FOR XML PATH('')
) AS ApprovalComments,
(
SELECT
'`* ' + A.Filename
FROM
Attachment A
WHERE
A.IssueID = LD.IssueID
ORDER BY
A.UploadDate FOR XML PATH('')
) AS AttachmentFilenames,
@BaseURL + '/LotDisposition/Edit?issueID=' + CONVERT(varchar(20), LD.IssueID) AS [URL]
FROM
LotDisposition LD
LEFT OUTER JOIN Users OriginatorU ON OriginatorU.UserID = LD.OriginatorID
LEFT OUTER JOIN Responsibility R ON R.ResponsibilityID = LD.ResponsibilityID
LEFT OUTER JOIN ResponsibilityIssue RI ON RI.ResponsibilityIssueID = LD.ResponsibilityIssueID
CROSS APPLY dbo.fnLotDispositionLotSummary(LD.IssueID) AS LDLotSummary
WHERE
(
ISNULL(@IssueID, '') = ''
OR CONVERT(varchar(20), LD.IssueID) LIKE '%' + @IssueID + '%'
)
AND (
ISNULL(@OriginatorID, -1) = -1
OR LD.OriginatorID = @OriginatorID
)
AND (
ISNULL(@Title, '') = ''
OR LD.Title LIKE '%' + @Title + '%'
)
AND (
ISNULL(@ProductFamilies, '') = ''
OR EXISTS (
SELECT
1
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
AND RTRIM(L.ProductFamily) + RTRIM(L.Gen) IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@ProductFamilies)
)
OR EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@ProductFamilies)
WHERE
Val = '(Any)'
)
)
)
AND (
ISNULL(@LotNumbers, '') = ''
OR EXISTS (
SELECT
1
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
AND L.LotNumber IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@LotNumbers)
)
)
)
AND (
ISNULL(@Location, '') = ''
OR EXISTS (
SELECT
1
FROM
Lot L
WHERE
L.IssueID = LD.IssueID
AND (
(
@LocationCompare = -1
AND L.[Location] <= @Location
)
OR (
ISNULL(@LocationCompare, 0) = 0
AND L.[Location] = @Location
)
OR (
@LocationCompare = 1
AND L.[Location] >= @Location
)
)
)
)
AND (
ISNULL(@PendingApproverID, -1) = -1
OR EXISTS (
SELECT
1
FROM
Approval A
WHERE
A.DocumentTypeID = 1
AND A.IssueID = LD.IssueID
AND ItemStatus = 0
AND A.UserID = @PendingApproverID
)
)
AND (
@SubmitDateFrom IS NULL
OR @SubmitDateFrom < CONVERT(date, SubmitedDate)
)
AND (
@SubmitDateTo IS NULL
OR CONVERT(date, SubmitedDate) < @SubmitDateTo
)
AND (
@CloseDateFrom IS NULL
OR @CloseDateFrom < CONVERT(date, CloseDate)
)
AND (
@CloseDateTo IS NULL
OR CONVERT(date, CloseDate) < @CloseDateTo
)
AND (
ISNULL(@ResponsibilityIDs, '') = ''
OR LD.ResponsibilityID IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@ResponsibilityIDs)
)
OR EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@ResponsibilityIDs)
WHERE
Val = '-1'
)
)
AND (
ISNULL(@ResponsibilityIssueIDs, '') = ''
OR LD.ResponsibilityIssueID IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@ResponsibilityIssueIDs)
)
OR EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@ResponsibilityIssueIDs)
WHERE
Val = '-1'
)
)
AND (
@DispositionByOCAP IS NULL
OR LD.DispositionByOCAP = @DispositionByOCAP
)
AND (
ISNULL(@IssueDescription, '') = ''
OR IssueDescription LIKE '%' + @IssueDescription + '%'
)
AND (
ISNULL(@ReasonForDisposition, '') = ''
OR ReasonForDisposition LIKE '%' + @ReasonForDisposition + '%'
)
AND (
@ScrapCost IS NULL
OR (
(
@ScrapCostCompare = -1
AND LDLotSummary.TotalScrapCost <= @ScrapCost
AND LDLotSummary.TotalScrapCost > 0
)
OR (
ISNULL(@ScrapCostCompare, 0) = 0
AND LDLotSummary.TotalScrapCost = @ScrapCost
)
OR (
@ScrapCostCompare = 1
AND LDLotSummary.TotalScrapCost >= @ScrapCost
)
)
)
AND (
@ScrapWaferQty IS NULL
OR (
(
@ScrapWaferQtyCompare = -1
AND LDLotSummary.TotalScrapWaferCount <= @ScrapWaferQty
AND LDLotSummary.TotalScrapWaferCount > 0
)
OR (
ISNULL(@ScrapWaferQtyCompare, 0) = 0
AND LDLotSummary.TotalScrapWaferCount = @ScrapWaferQty
)
OR (
@ScrapWaferQtyCompare = 1
AND LDLotSummary.TotalScrapWaferCount >= @ScrapWaferQty
)
)
)
AND (
@ScrapDieQty IS NULL
OR (
(
@ScrapDieQtyCompare = -1
AND LDLotSummary.TotalScrapDieCount <= @ScrapDieQty
AND LDLotSummary.TotalScrapDieCount > 0
)
OR (
ISNULL(@ScrapDieQtyCompare, 0) = 0
AND LDLotSummary.TotalScrapDieCount = @ScrapDieQty
)
OR (
@ScrapDieQtyCompare = 1
AND LDLotSummary.TotalScrapDieCount >= @ScrapDieQty
)
)
)
ORDER BY
LD.IssueID
END
GO