143 lines
3.1 KiB
Transact-SQL
143 lines
3.1 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[GetLotDispositionLots] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[GetLotDispositionLots] @IssueID int AS BEGIN
|
|
SELECT
|
|
DISTINCT SQ.IssueIDs AS MRBsLinkedToLot,
|
|
DispoType.MRBDispoType,
|
|
SQP.IssueIDs AS IssueIDWithoutMRB,
|
|
CASE
|
|
WHEN L.LotStatusOptionID = 2 THEN 1
|
|
WHEN PATINDEX('%B%', DispoType.MRBDispoType) > 0
|
|
AND L.LotStatusOptionID <> 2 THEN 0
|
|
WHEN PATINDEX('%X%', DispoType.MRBDispoType) > 0
|
|
AND PATINDEX('%B%', DispoType.MRBDispoType) = 0 THEN 0
|
|
WHEN (
|
|
PATINDEX('%D%', DispoType.MRBDispoType) > 0
|
|
AND PATINDEX('%X%', DispoType.MRBDispoType) = 0
|
|
AND PATINDEX('%B%', DispoType.MRBDispoType) = 0
|
|
AND LS.LotStatusOptionID <> 6
|
|
)
|
|
AND (
|
|
LTRIM(RTRIM(Location)) <> 'QDB'
|
|
AND LTRIM(RTRIM(Location)) <> 'EDB'
|
|
) THEN 0
|
|
ELSE 1
|
|
END AS GoodToSubmit,
|
|
CASE
|
|
WHEN L.LotStatusOptionID = 2 THEN 'NA'
|
|
WHEN (
|
|
PATINDEX('%B%', DispoType.MRBDispoType) > 0
|
|
AND L.LotStatusOptionID <> 2
|
|
)
|
|
OR (
|
|
(
|
|
PATINDEX('%D%', DispoType.MRBDispoType) > 0
|
|
AND PATINDEX('%X%', DispoType.MRBDispoType) = 0
|
|
AND PATINDEX('%B%', DispoType.MRBDispoType) = 0
|
|
AND LS.LotStatusOptionID <> 6
|
|
AND (
|
|
LTRIM(RTRIM(Location)) <> 'QDB'
|
|
AND LTRIM(RTRIM(Location)) <> 'EDB'
|
|
)
|
|
)
|
|
) THEN 'MRB Disposition different from Lot Dispostion'
|
|
WHEN PATINDEX('%X%', DispoType.MRBDispoType) > 0
|
|
AND PATINDEX('%B%', DispoType.MRBDispoType) = 0 THEN 'MRB Dispo missing'
|
|
ELSE 'NA'
|
|
END AS SubmitErrorMessage,
|
|
L.LotID,
|
|
L.LotNumber,
|
|
L.IssueID,
|
|
L.DieLotNumber,
|
|
L.Description,
|
|
L.NewPartNo,
|
|
L.WipPartNo,
|
|
L.DiePartNo,
|
|
L.ProductFamily,
|
|
L.Gen,
|
|
L.Channel,
|
|
L.HexSize,
|
|
L.Voltage,
|
|
L.WaferCount,
|
|
L.DieCount,
|
|
L.Location,
|
|
L.TotalCost,
|
|
L.LotStatusOptionID,
|
|
S.ReleaseCount,
|
|
S.ScrapCount,
|
|
L.QualityCode,
|
|
LS.LotStatusOptionID,
|
|
LS.LotStatusOption
|
|
FROM
|
|
Lot L
|
|
INNER JOIN LotStatusOption LS ON L.LotStatusOptionID = LS.LotStatusOptionID
|
|
LEFT JOIN ScrapLot S ON L.LotNumber = S.LotNo
|
|
AND L.IssueID = S.IssueID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT L.LotID,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
DISTINCT ',' + CAST(ML.MRBNumber AS varchar(512)) + '_' + CAST(ISNULL(ML.DispoType, '') AS varchar(512))
|
|
FROM
|
|
vMRBLot ML
|
|
WHERE
|
|
LTRIM(RTRIM(L.LotNumber)) = LTRIM(RTRIM(ML.LotNumber)) FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS IssueIDs
|
|
FROM
|
|
Lot L
|
|
) AS SQ ON L.LotID = SQ.LotID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT L.LotID,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
DISTINCT ',' + CAST(ML.MRBNumber AS varchar(512))
|
|
FROM
|
|
vMRBLot ML
|
|
WHERE
|
|
LTRIM(RTRIM(L.LotNumber)) = LTRIM(RTRIM(ML.LotNumber)) FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS IssueIDs
|
|
FROM
|
|
Lot L
|
|
) AS SQP ON L.LotID = SQP.LotID
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT L.LotID,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
DISTINCT ',' + CAST(ISNULL(ML.DispoType, 'X') AS varchar(512))
|
|
FROM
|
|
vMRBLot ML
|
|
WHERE
|
|
LTRIM(RTRIM(L.LotNumber)) = LTRIM(RTRIM(ML.LotNumber)) FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS MRBDispoType
|
|
FROM
|
|
Lot L
|
|
) AS DispoType ON L.LotID = DispoType.LotID
|
|
WHERE
|
|
L.IssueID = @IssueID
|
|
END
|
|
GO |