235 lines
4.4 KiB
Transact-SQL
235 lines
4.4 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[GetLotGeneology] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[GetLotGeneology] @MainParentLotNo VARCHAR(50),
|
|
@IncidentStartTime VARCHAR(24),
|
|
@IncidentEndTime VARCHAR(24),
|
|
@ToolsCSV VARCHAR(100) = NULL AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET
|
|
NOCOUNT ON;
|
|
|
|
DECLARE @ChildLot VARCHAR(50) DECLARE @ParentLotNo VARCHAR(50) DECLARE @sql NVARCHAR(max) DECLARE @ResultsTable TABLE (
|
|
ChildLot VARCHAR(50),
|
|
ParentLot VARCHAR(50),
|
|
Processed BIT,
|
|
ID UNIQUEIDENTIFIER DEFAULT (NEWID()),
|
|
MainParentLotNo VARCHAR(50),
|
|
StartTime DATETIME NULL,
|
|
LotStatus NCHAR(5) NULL,
|
|
IsAffected BIT DEFAULT 0,
|
|
Comments VARCHAR(50) NULL
|
|
) DECLARE @ID UNIQUEIDENTIFIER
|
|
/*Start of Lot Geneaogy===========================================================================================================*/
|
|
INSERT INTO
|
|
@ResultsTable (
|
|
ChildLot,
|
|
ParentLot,
|
|
Processed,
|
|
MainParentLotNo,
|
|
StartTime,
|
|
LotStatus,
|
|
Comments
|
|
)
|
|
SELECT
|
|
WP_LOT_NO AS ChildLot,
|
|
WP_LOT_FROM AS ParentLot,
|
|
0,
|
|
@MainParentLotNo,
|
|
StartTime,
|
|
WP_STATUS,
|
|
'Main Lot'
|
|
FROM
|
|
vFAB2SPN_WP_RECORD WITH(NOLOCK)
|
|
WHERE
|
|
LTRIM(RTRIM(WP_LOT_FROM)) = LTRIM(RTRIM(@MainParentLotNo))
|
|
AND WP_ORIGIN_SW = 'S'
|
|
ORDER BY
|
|
WP_LOT_NO DECLARE @COUNT INT
|
|
SET
|
|
@COUNT = (
|
|
SELECT
|
|
COUNT(*)
|
|
FROM
|
|
@ResultsTable
|
|
) --PRINT @COUNT
|
|
IF NOT EXISTS(
|
|
SELECT
|
|
*
|
|
FROM
|
|
@ResultsTable
|
|
) BEGIN --PRINT 'HELLO'
|
|
SELECT
|
|
@MainParentLotNo AS ChildLot,
|
|
NULL
|
|
END
|
|
ELSE BEGIN WHILE EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@ResultsTable
|
|
WHERE
|
|
Processed = 0
|
|
) BEGIN
|
|
SELECT
|
|
TOP 1 @ChildLot = ChildLot,
|
|
@ID = ID
|
|
FROM
|
|
@ResultsTable
|
|
WHERE
|
|
Processed = 0 -- indicate that the record has been processed
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
Processed = 1
|
|
WHERE
|
|
ID = @ID
|
|
INSERT INTO
|
|
@ResultsTable (
|
|
ChildLot,
|
|
ParentLot,
|
|
Processed,
|
|
MainParentLotNo,
|
|
StartTime,
|
|
LotStatus
|
|
)
|
|
SELECT
|
|
WP_LOT_NO AS ChildLot,
|
|
WP_LOT_FROM AS ParentLot,
|
|
0,
|
|
@MainParentLotNo,
|
|
StartTime,
|
|
WP_STATUS
|
|
FROM
|
|
vFAB2SPN_WP_RECORD WITH(NOLOCK)
|
|
WHERE
|
|
WP_LOT_FROM = @ChildLot
|
|
AND WP_ORIGIN_SW = 'S'
|
|
END
|
|
END
|
|
/*End of Lot Geneaogy===========================================================================================================*/
|
|
SELECT
|
|
*
|
|
FROM
|
|
@ResultsTable -- update the "IsAffected = 1" flag for child lots if the split happened after the excursion
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
IsAffected = 1,
|
|
Comments = 'Affected Period'
|
|
WHERE
|
|
CONVERT(VARCHAR, StartTime, 25) >= @IncidentStartTime
|
|
AND LotStatus <> 'Z'
|
|
SELECT
|
|
*
|
|
FROM
|
|
@ResultsTable -- For the non affected child lots which may have been split before the excursion period, but may have gone through the affected tools during the excursion period
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
Processed = 0
|
|
WHERE
|
|
IsAffected = 0
|
|
DECLARE @ChildLotAffected TABLE(LotCount INT NULL) WHILE EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@ResultsTable
|
|
WHERE
|
|
Processed = 0
|
|
) BEGIN
|
|
SET
|
|
@ChildLot = (
|
|
SELECT
|
|
TOP 1 ChildLot
|
|
FROM
|
|
@ResultsTable
|
|
WHERE
|
|
Processed = 0
|
|
) IF @ToolsCSV IS NULL
|
|
OR @ToolsCSV = '' BEGIN
|
|
SET
|
|
@sql = FORMATMESSAGE(
|
|
'SELECT COUNT(*) FROM vFAB2SPN_WO_RECORD
|
|
WHERE WO_LOT_NO = ''%s''' + ' AND ((InTime BETWEEN ''%s'' AND ''%s'') OR (OutTime BETWEEN ''%s'' AND ''%s''))',
|
|
@ChildLot,
|
|
@IncidentStartTime,
|
|
@IncidentEndTime,
|
|
@IncidentStartTime,
|
|
@IncidentEndTime
|
|
)
|
|
END
|
|
ELSE BEGIN
|
|
SET
|
|
@sql = FORMATMESSAGE(
|
|
'SELECT COUNT(*) FROM vFAB2SPN_WO_RECORD
|
|
WHERE WO_LOT_NO = ''%s''' + ' AND WO_STATION_ID IN (''%s'') ' + ' AND ((InTime BETWEEN ''%s'' AND ''%s'') OR (OutTime BETWEEN ''%s'' AND ''%s''))',
|
|
@ChildLot,
|
|
@ToolsCSV,
|
|
@IncidentStartTime,
|
|
@IncidentEndTime,
|
|
@IncidentStartTime,
|
|
@IncidentEndTime
|
|
)
|
|
END PRINT @sql
|
|
DELETE FROM
|
|
@ChildLotAffected
|
|
INSERT INTO
|
|
@ChildLotAffected exec sp_executesql @sql DECLARE @tem INT
|
|
SELECT
|
|
@tem = LotCount
|
|
FROM
|
|
@ChildLotAffected --PRINT @tem
|
|
IF @tem > 0 BEGIN
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
Processed = 1,
|
|
IsAffected = 1
|
|
WHERE
|
|
ChildLot = @ChildLot
|
|
END
|
|
ELSE BEGIn
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
Processed = 1,
|
|
IsAffected = 0
|
|
WHERE
|
|
ChildLot = @ChildLot
|
|
END
|
|
END -- Insert the root
|
|
INSERT INTO
|
|
@ResultsTable (
|
|
ChildLot,
|
|
ParentLot,
|
|
Processed,
|
|
MainParentLotNo,
|
|
IsAffected,
|
|
Comments
|
|
)
|
|
SELECT
|
|
@MainParentLotNo AS ChildLot,
|
|
NULL AS ParentLot,
|
|
1,
|
|
@MainParentLotNo,
|
|
1,
|
|
'Affected Period'
|
|
UPDATE
|
|
@ResultsTable
|
|
SET
|
|
IsAffected = 0
|
|
WHERE
|
|
LotStatus = 'Z'
|
|
SELECT
|
|
*
|
|
FROM
|
|
@ResultsTable
|
|
END
|
|
GO |