329 lines
5.2 KiB
Transact-SQL
329 lines
5.2 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[AnalyzeLotAncestry] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[AnalyzeLotAncestry] @LotNo varchar(20),
|
|
@IncidentTime datetime = NULL,
|
|
@LogIssueID int = NULL,
|
|
@LogDocumentType int = NULL,
|
|
@LogParms xml = NULL,
|
|
@AnalysisType CHAR(1) = NULL AS BEGIN
|
|
SET
|
|
NOCOUNT ON DECLARE @RootLotNo varchar(20) = @LotNo DECLARE @IncidentLotNo varchar(20) = @LotNo IF @LotNo LIKE '%.%' BEGIN
|
|
SET
|
|
@RootLotNo = LEFT(@LotNo, CHARINDEX('.', @LotNo)) + '1'
|
|
SET
|
|
@IncidentLotNo = @LotNo
|
|
END DECLARE @sql nvarchar(max) DECLARE @lots TABLE(LotNo varchar(20), Queried bit) DECLARE @results TABLE(
|
|
[WT_RECORD_CODE] [varchar](2) NULL,
|
|
[WT_LOT_NO] [varchar](10) NULL,
|
|
[WT_ACTION_DATE] [varchar](14) NULL,
|
|
[WT_LOT_1] [varchar](10) NULL,
|
|
[WT_LOT_2] [varchar](10) NULL,
|
|
[WT_LOT_3] [varchar](10) NULL,
|
|
[WT_LOT__4] [varchar](10) NULL,
|
|
[WT_LOT_5] [varchar](10) NULL
|
|
) DECLARE @transaction TABLE(
|
|
[WT_RECORD_CODE] [varchar](2) NULL,
|
|
[WT_LOT_NO] [varchar](10) NULL,
|
|
[WT_ACTION_DATE] [varchar](14) NULL,
|
|
[WT_LOT_TARGET] [varchar](10) NULL
|
|
) DECLARE @finalresults TABLE(
|
|
[ID] [int] NOT NULL IDENTITY(1, 1),
|
|
[ParentLotNo] [varchar](20) NOT NULL,
|
|
[LotNo] [varchar](20) NOT NULL,
|
|
[ActionTime] [datetime] NOT NULL,
|
|
[ActionType] [varchar](2) NOT NULL,
|
|
[IsAffected] bit NULL
|
|
) --INSERT INTO @lots(LotNo, Queried) VALUES (@RootLotNo, 0)
|
|
INSERT INTO
|
|
@lots(LotNo, Queried)
|
|
VALUES
|
|
(@IncidentLotNo, 0) WHILE EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@lots
|
|
WHERE
|
|
Queried = 0
|
|
) BEGIN
|
|
SELECT
|
|
TOP 1 @LotNo = LotNo
|
|
FROM
|
|
@lots
|
|
WHERE
|
|
Queried = 0
|
|
SET
|
|
@sql = FORMATMESSAGE(
|
|
'SELECT * FROM OPENQUERY(FAB2SPN, ' + '''SELECT WT_RECORD_CODE, WT_LOT_NO, WT_ACTION_DATE, WT_LOT_1, WT_LOT_2, WT_LOT_3, WT_LOT__4, WT_LOT_5 ' + 'FROM WT_RECORD ' + 'WHERE WT_WP_DIRECT_KEY = ''''3002%s '''' AND WT_RECORD_CODE IN (''''SP'''',''''CB'''')'') ',
|
|
@LotNo
|
|
)
|
|
DELETE FROM
|
|
@results
|
|
INSERT INTO
|
|
@results EXEC sp_executesql @sql
|
|
DELETE FROM
|
|
@transaction
|
|
INSERT INTO
|
|
@transaction(
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
[WT_LOT_TARGET]
|
|
)
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
[WT_LOT_TARGET]
|
|
FROM
|
|
(
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
WT_LOT_1 AS [WT_LOT_TARGET]
|
|
FROM
|
|
@results
|
|
UNION
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
WT_LOT_2 AS [WT_LOT_TARGET]
|
|
FROM
|
|
@results
|
|
UNION
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
WT_LOT_3 AS [WT_LOT_TARGET]
|
|
FROM
|
|
@results
|
|
UNION
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
WT_LOT__4 AS [WT_LOT_TARGET]
|
|
FROM
|
|
@results
|
|
UNION
|
|
SELECT
|
|
[WT_RECORD_CODE],
|
|
[WT_LOT_NO],
|
|
[WT_ACTION_DATE],
|
|
WT_LOT_5 AS [WT_LOT_TARGET]
|
|
FROM
|
|
@results
|
|
) subtable
|
|
WHERE
|
|
[WT_LOT_TARGET] <> ''
|
|
INSERT INTO
|
|
@lots(LotNo, Queried)
|
|
SELECT
|
|
DISTINCT WT_LOT_TARGET,
|
|
0
|
|
FROM
|
|
@transaction
|
|
WHERE
|
|
NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@lots l
|
|
WHERE
|
|
l.LotNo = WT_LOT_TARGET
|
|
)
|
|
UPDATE
|
|
@lots
|
|
SET
|
|
Queried = 1
|
|
WHERE
|
|
LotNo = @LotNo
|
|
INSERT INTO
|
|
@finalresults(
|
|
[ParentLotNo],
|
|
[LotNo],
|
|
[ActionTime],
|
|
[ActionType]
|
|
)
|
|
SELECT
|
|
RTRIM(WT_LOT_NO),
|
|
RTRIM(WT_LOT_TARGET),
|
|
CONVERT(
|
|
datetime,
|
|
STUFF(
|
|
STUFF(
|
|
STUFF(
|
|
STUFF(STUFF(WT_ACTION_DATE, 5, 0, '-'), 8, 0, '-'),
|
|
11,
|
|
0,
|
|
' '
|
|
),
|
|
14,
|
|
0,
|
|
':'
|
|
),
|
|
17,
|
|
0,
|
|
':'
|
|
),
|
|
20
|
|
),
|
|
WT_RECORD_CODE
|
|
FROM
|
|
@transaction
|
|
WHERE
|
|
WT_RECORD_CODE = 'SP'
|
|
INSERT INTO
|
|
@finalresults(
|
|
[ParentLotNo],
|
|
[LotNo],
|
|
[ActionTime],
|
|
[ActionType]
|
|
)
|
|
SELECT
|
|
RTRIM(WT_LOT_TARGET),
|
|
RTRIM(WT_LOT_NO),
|
|
CONVERT(
|
|
datetime,
|
|
STUFF(
|
|
STUFF(
|
|
STUFF(
|
|
STUFF(STUFF(WT_ACTION_DATE, 5, 0, '-'), 8, 0, '-'),
|
|
11,
|
|
0,
|
|
' '
|
|
),
|
|
14,
|
|
0,
|
|
':'
|
|
),
|
|
17,
|
|
0,
|
|
':'
|
|
),
|
|
20
|
|
),
|
|
WT_RECORD_CODE
|
|
FROM
|
|
@transaction
|
|
WHERE
|
|
WT_RECORD_CODE = 'CB'
|
|
END;
|
|
|
|
WITH relevantresults as (
|
|
SELECT
|
|
*
|
|
FROM
|
|
@finalresults
|
|
WHERE
|
|
(ActionTime >= @IncidentTime)
|
|
OR (@IncidentTime IS NULL)
|
|
),
|
|
affectedlots as (
|
|
SELECT
|
|
ID,
|
|
ParentLotNo,
|
|
LotNo,
|
|
ActionTime
|
|
FROM
|
|
relevantresults
|
|
WHERE
|
|
ParentLotNo = @IncidentLotNo
|
|
UNION
|
|
ALL
|
|
SELECT
|
|
rr.ID,
|
|
rr.ParentLotNo,
|
|
rr.LotNo,
|
|
rr.ActionTime
|
|
FROM
|
|
affectedlots
|
|
INNER JOIN relevantresults rr ON rr.ParentLotNo = affectedlots.LotNo
|
|
AND rr.ActionTime > affectedlots.ActionTime
|
|
)
|
|
UPDATE
|
|
@finalresults
|
|
SET
|
|
IsAffected = 1
|
|
WHERE
|
|
ID IN (
|
|
SELECT
|
|
ID
|
|
FROM
|
|
affectedlots
|
|
)
|
|
UPDATE
|
|
@finalresults
|
|
SET
|
|
IsAffected = 1
|
|
WHERE
|
|
LotNo = @IncidentLotNo
|
|
INSERT INTO
|
|
@finalresults(
|
|
ParentLotNo,
|
|
LotNo,
|
|
ActionTime,
|
|
ActionType,
|
|
IsAffected
|
|
)
|
|
SELECT
|
|
'',
|
|
@IncidentLotNo,
|
|
'01/01/2001',
|
|
'',
|
|
1
|
|
WHERE
|
|
NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@finalresults
|
|
WHERE
|
|
LotNo = @IncidentLotNo
|
|
AND IsAffected = 1
|
|
)
|
|
SELECT
|
|
*
|
|
FROM
|
|
@finalresults
|
|
ORDER BY
|
|
ActionTime IF @LogIssueID IS NOT NULL
|
|
AND @LogDocumentType IS NOT NULL BEGIN
|
|
INSERT INTO
|
|
LotSplitAnalysisLog(
|
|
[IssueID],
|
|
[DocumentType],
|
|
[LotNumber],
|
|
AnalysisType,
|
|
[AnalysisTime],
|
|
[AnalysisData]
|
|
)
|
|
SELECT
|
|
@LogIssueID,
|
|
@LogDocumentType,
|
|
@LotNo,
|
|
@AnalysisType,
|
|
GETDATE(),
|
|
(
|
|
SELECT
|
|
@LogParms AS 'parms',
|
|
(
|
|
SELECT
|
|
*
|
|
FROM
|
|
@finalresults FOR XML PATH('results'),
|
|
TYPE
|
|
) FOR XML PATH('log')
|
|
)
|
|
END
|
|
END
|
|
GO |