173 lines
3.6 KiB
Transact-SQL
173 lines
3.6 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[MRBInsertSplitLotsNotInMRB_HoldFlagReportTable] Script Date: 11/21/2024 11:29:05 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[MRBInsertSplitLotsNotInMRB_HoldFlagReportTable] -- Add the parameters for the stored procedure here
|
|
@MRBNumber INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET
|
|
NOCOUNT ON;
|
|
|
|
DECLARE @SplitTransactions TABLE(
|
|
LotNumber VARCHAR(10) NULL,
|
|
ParentLotNumber VARCHAR(10) NULL,
|
|
Processed INT NULL
|
|
) DECLARE @TempData TABLE(
|
|
LotNumber VARCHAR(10) NULL,
|
|
ActualParentLotNumber VARCHAR(10) NULL
|
|
) DECLARE @ErrorMessage NVARCHAR(4000);
|
|
|
|
DECLARE @ErrorSeverity INT;
|
|
|
|
DECLARE @ErrorState INT;
|
|
|
|
DECLARE @LotNo VARCHAR(10) DECLARE @ParentLotNo VARCHAR(10) DECLARE @OriginalLotNo VARCHAR(10) DECLARE @OriginalParentLotNo VARCHAR(10) DECLARE @Found BIT DECLARE @CNT INT DECLARE @LoopCTR INT -- Insert statements for procedure here
|
|
INSERT INTO
|
|
@SplitTransactions (LotNumber, ParentLotNumber, Processed)
|
|
SELECT
|
|
LotNumber,
|
|
ParentLotNumber,
|
|
0
|
|
from
|
|
MRBLotsToBeSentToSPN M
|
|
WHERE
|
|
MRBNumber = @MRBNumber
|
|
AND NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
MRBHoldFlagReport R
|
|
WHERE
|
|
R.LotNo = M.LotNumber
|
|
AND R.MRBNumber = M.MRBNumber
|
|
) WHILE EXISTS(
|
|
SELECT
|
|
1
|
|
FROM
|
|
@SplitTransactions
|
|
WHERE
|
|
Processed = 0
|
|
) BEGIN --PRINT 'INSIDE'
|
|
SELECT
|
|
TOP 1 @LotNo = LotNumber,
|
|
@ParentLotNo = ParentLotNumber
|
|
FROM
|
|
@SplitTransactions
|
|
WHERE
|
|
Processed = 0
|
|
SET
|
|
@OriginalLotNo = @LotNo
|
|
SET
|
|
@OriginalParentLotNo = @ParentLotNo
|
|
SET
|
|
@Found = 0
|
|
SET
|
|
@LoopCTR = 0 WHILE (@Found = 0) BEGIN
|
|
SET
|
|
@LoopCTR = @LoopCTR + 1 IF @LoopCTR > 50 BEGIN
|
|
SELECT
|
|
@ErrorMessage = 'Problems with Inserting SPN Splits for MRBNumber ' + CONVERT(VARCHAR(10), @MRBNumber),
|
|
@ErrorSeverity = ERROR_SEVERITY(),
|
|
@ErrorState = ERROR_STATE();
|
|
|
|
RAISERROR (
|
|
@ErrorMessage,
|
|
-- Message text.
|
|
@ErrorSeverity,
|
|
-- Severity.
|
|
@ErrorState -- State.
|
|
);
|
|
|
|
END -- search the LotNumber in the MRBFlagReport table based on the Parent lotnumber
|
|
SELECT
|
|
@CNT = COUNT(*)
|
|
FROM
|
|
MRBHoldFlagReport
|
|
WHERE
|
|
LotNo IN (
|
|
SELECT
|
|
LotNumber
|
|
FROM
|
|
MRBLotsToBeSentToSPN
|
|
WHERE
|
|
MRBNumber = @MRBNumber
|
|
AND LotNumber = @ParentLotNo
|
|
) --PRINT 'CNT = ' + CONVERT(VARCHAR(5),@CNT)
|
|
IF @CNT >= 1 BEGIN
|
|
SET
|
|
@Found = 1 --PRINT 'FND = ' + CONVERT(VARCHAR(5),@Found)
|
|
UPDATE
|
|
@SplitTransactions
|
|
SET
|
|
Processed = 1
|
|
WHERE
|
|
LotNumber = @OriginalLotNo
|
|
AND ParentLotNumber = @OriginalParentLotNo -- INSERT INTO THE MRBFlagReportTable
|
|
INSERT INTO
|
|
MRBHoldFlagReport (
|
|
MRBNumber,
|
|
LotNo,
|
|
TransactionType,
|
|
PartNo,
|
|
CurrentLocation,
|
|
CurrentOperation,
|
|
StartQty,
|
|
CurrentQty,
|
|
LotStatus,
|
|
OperStatus,
|
|
Successful,
|
|
Comment,
|
|
PriorMRB_DispoType,
|
|
PriorMRBHoldLocation,
|
|
PriorMRBHoldOperation,
|
|
CurrentMRB_DispoType,
|
|
CurrentMRBHoldLocation,
|
|
CurrentMRBHoldOperation,
|
|
TransactionDatetime,
|
|
InsertDateTimeStamp
|
|
)
|
|
SELECT
|
|
MRBNumber,
|
|
@OriginalLotNo,
|
|
TransactionType,
|
|
PartNo,
|
|
CurrentLocation,
|
|
CurrentOperation,
|
|
StartQty,
|
|
CurrentQty,
|
|
LotStatus,
|
|
OperStatus,
|
|
Successful,
|
|
Comment,
|
|
PriorMRB_DispoType,
|
|
PriorMRBHoldLocation,
|
|
PriorMRBHoldOperation,
|
|
CurrentMRB_DispoType,
|
|
CurrentMRBHoldLocation,
|
|
CurrentMRBHoldOperation,
|
|
TransactionDatetime,
|
|
GETDATE()
|
|
FROM
|
|
MRBHoldFlagReport
|
|
WHERE
|
|
LotNo = @ParentLotNo BREAK;
|
|
|
|
END -- if the LotNumber not found in the MRBHoldFlagReport
|
|
-- get the Parent of that Lot Number and reset the Parentlotnumber and loop
|
|
--PRINT 'Lot' + @LotNo
|
|
SELECT
|
|
@ParentLotNo = ParentLotNumber
|
|
FROM
|
|
MRBLotsToBeSentToSPN
|
|
WHERE
|
|
LotNumber = @ParentLotNo
|
|
AND MRBNumber = @MRBNumber
|
|
END
|
|
END
|
|
END
|
|
GO |