USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[LTCreateWorkRequestRevision_05012017] Script Date: 11/21/2024 11:29:05 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE PROCEDURE [dbo].[LTCreateWorkRequestRevision_05012017] @UserID INT, @ChangeComments VARCHAR(1000), @CurrentStep INT, @LTWorkRequestID INT, @Title VARCHAR(100), @LotType CHAR(1), @EngLotStartRequired INT, @LotTypeConversion INT, @QualLot INT, @PurposeOfRequest VARCHAR(1000), @PlannedLotStartDate DATETIME, @PlannedScheduledCloseDate DATETIME, @ChargeDepartment VARCHAR(50), @AllocationToUse VARCHAR(100), @PredictedCyleTime INT, @DeptChargedForRawWafers VARCHAR(50), @EstimatedBinCLoseDate DATETIME = NULL, @WIPArea NCHAR(10), @TotalQty INT = NULL, @StartQty INT, @LotStartDate DATETIME, @LotNumber VARCHAR(50), @WIPPartNumber VARCHAR(50), @PartDescription VARCHAR(100), @DefaultEPISiliconPartNumber VARCHAR(50), @ProcessFlow NCHAR(10), @EmployeeID NCHAR(10), @VerbComment VARCHAR(1000), @RecordSiliconLotInSPNTapeTagTotrav INT, @SiliconLotNoCassette1 VARCHAR(500), @SiliconOnHand BIT, @SiliconExpectedDueDate DATETIME, @SiliconComments VARCHAR(500), @ReticleOnHand BIT, @ReticleExpectedDueDate DATETIME, @ReticleComments VARCHAR(1000), @SPNTransferOnHand BIT, @SPNTransferExpectedDueDate DATETIME, @SPNTransferComments VARCHAR(500), @ProbeCardOnHand BIT, @ProbeCardExpectedDueDate DATETIME, @ProbeCardComments VARCHAR(500), @ProbeRecipeOnHand BIT, @ProbeRecipeExpectedDueDate DATETIME, @ProbeRecipeComments VARCHAR(500), @ProcessChangeDetailsOnHand BIT, @ProcessChangeDetailsDueDate DATETIME, @PCRBNumber VARCHAR(50), @LotStartCheckListComments VARCHAR(1000), @NewWorkRequestID INT OUT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; --DECLARE @NewWorkRequestID INT DECLARE @OriginatorID INT DECLARE @CurrentRevision INT DECLARE @ErrorMessage NVARCHAR(4000); DECLARE @ErrorSeverity INT; DECLARE @ErrorState INT; DECLARE @ID INT; DECLARE @SWRNumber INT; DECLARE @IsITAR BIT; SELECT @OriginatorID = OriginatorID, @CurrentRevision = Revision, @SWRNumber = SWRNumber, @IsITAR = IsITAR FROM LTWorkRequest WHERE ID = @LTWorkRequestID BEGIN TRY BEGIN TRAN INSERT INTO LTWorkRequest ( OriginatorID, SWRNumber, OriginatedDate, IsCurrentRevision, PreviousWorkRequestID ) VALUES ( @OriginatorID, @SWRNumber, GETDATE(), 1, @LTWorkRequestID ) SET @NewWorkRequestID = CAST(SCOPE_IDENTITY() AS INT) -- UPDATE THE PREVIOUS VERSION UPDATE LTWorkRequest SET IsCurrentRevision = 0, RecordLockIndicator = 0, RecordLockedBy = NULL, RecordLockedDate = NULL WHERE ID = @LTWorkRequestID UPDATE LTWorkRequest SET Title = @Title, OriginatorID = @OriginatorID, Revision = @CurrentRevision + 1, CurrentStep = @CurrentStep, IsCurrentRevision = 1, RecordLockIndicator = 1, RecordLockedBy = @UserID, RecordLockedDate = GETDATE(), SubmitedDate = ( SELECT SubmitedDate FROM LTWorkRequest WHERE ID = @LTWorkRequestID ), LotType = @LotType, EngLotStartRequired = @EngLotStartRequired, LotTypeConversion = @LotTypeConversion, QualLot = @QualLot, PurposeOfRequest = @PurposeOfRequest, PlannedLotStartDate = @PlannedLotStartDate, PlannedScheduledCloseDate = @PlannedScheduledCloseDate, ChargeDepartment = @ChargeDepartment, AllocationToUse = @AllocationToUse, PredictedCyleTime = @PredictedCyleTime, EstimatedBinCLoseDate = @EstimatedBinCLoseDate, IsITAR = @IsITAR, WIPArea = '3002', TotalQty = @TotalQty, StartQty = @StartQty, LotStartDate = @LotStartDate, LotNumber = @LotNumber, WIPPartNumber = @WIPPartNumber, PartDescription = @PartDescription, DefaultEPISiliconPartNumber = @DefaultEPISiliconPartNumber, ProcessFlow = @ProcessFlow, EmployeeID = @EmployeeID, VerbComment = @VerbComment, RecordSiliconLotInSPNTapeTagTotrav = @RecordSiliconLotInSPNTapeTagTotrav, SiliconLotNoCassette1 = @SiliconLotNoCassette1, SiliconOnHand = @SiliconOnHand, SiliconExpectedDueDate = @SiliconExpectedDueDate, SiliconComments = @SiliconComments, ReticleOnHand = @ReticleOnHand, ReticleExpectedDueDate = @ReticleExpectedDueDate, ReticleComments = @ReticleComments, SPNTransferOnHand = @SPNTransferOnHand, SPNTransferExpectedDueDate = @SPNTransferExpectedDueDate, SPNTransferComments = @SPNTransferComments, ProbeCardOnHand = @ProbeCardOnHand, ProbeCardExpectedDueDate = @ProbeCardExpectedDueDate, ProbeCardComments = @ProbeCardComments, ProbeRecipeOnHand = @ProbeRecipeOnHand, ProbeRecipeExpectedDueDate = @ProbeRecipeExpectedDueDate, ProbeRecipeComments = @ProbeRecipeComments, ProcessChangeDetailsOnHand = @ProcessChangeDetailsOnHand, ProcessChangeDetailsDueDate = @ProcessChangeDetailsDueDate, LotStartCheckListComments = @LotStartCheckListComments, PCRBNumber = @PCRBNumber WHERE ID = @NewWorkRequestID -- Insert into Affected Modules INSERT INTO LTAffectedModule (ModuleID, LTWorkRequestID) SELECT ModuleID, @NewWorkRequestID FROM LTAffectedModule WHERE LTWorkRequestID = @LTWorkRequestID -- Insert into Affected Depts INSERT INTO LTAffectedDepartment (DepartmentID, LTWorkRequestID) SELECT DepartmentID, @NewWorkRequestID FROM LTAffectedDepartment WHERE LTWorkRequestID = @LTWorkRequestID -- Insert into Add EPI INSERT INTO LTMaterial ( EPISiliconPartNumber, Quantity, Supplier, Source, LTWorkRequestID, PreviousMaterialID ) SELECT EPISiliconPartNumber, Quantity, Supplier, Source, @NewWorkRequestID, ID FROM LTMaterial WHERE LTWorkRequestID = @LTWorkRequestID -- Insert Hold Steps -- Insert into WorkRequest Attachment EXEC LTCreateHoldStepsRevision @NewWorkRequestID, @LTWorkRequestID UPDATE Approval SET IssueID = @NewWorkRequestID WHERE IssueID = @LTWorkRequestID AND DocumentTypeID = 6 INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( @UserID, 'WorkRequest', @SWRNumber, 'Revision History', GETDATE(), @ChangeComments, @NewWorkRequestID ) -- Record the Revision History COMMIT END TRY BEGIN CATCH ROLLBACK INSERT INTO EventLog ( UserID, DocumentType, IssueID, OperationType, InsertTimeStamp, Comments, SysDocumentID ) VALUES ( @UserID, 'WorkRequest', @SWRNumber, 'Error', GETDATE(), 'Error while creating revision for SWR# ' + CONVERT(VARCHAR(10), @SWRNumber) + ' WorkRequest# ' + CONVERT(VARCHAR(10), @LTWorkRequestID), @LTWorkRequestID ) SELECT @ErrorMessage = ERROR_MESSAGE() + CONVERT(VARCHAR(10), @SWRNumber) + ' WorkRequest# ' + CONVERT(VARCHAR(10), @LTWorkRequestID), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(); RAISERROR ( @ErrorMessage, -- Message text. @ErrorSeverity, -- Severity. @ErrorState -- State. ); END CATCH END GO