USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[ECN_TECNExtensionRejection] Script Date: 11/21/2024 11:29:04 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[ECN_TECNExtensionRejection] @ECNNumber INT, @UserID INT, @CurrentStep INT, @DocumentTypeID INT AS BEGIN -- 2019-02-15 add new fields SET NOCOUNT ON; DECLARE @ErrorMessage NVARCHAR(4000); DECLARE @ErrorSeverity INT; DECLARE @ErrorState INT; DECLARE @SubRoleID INT SET @SubRoleID = ( SELECT TOP 1 SubRoleID FROM Approval WHERE IssueID = @ECNNumber AND UserID = @UserID AND Step = @CurrentStep AND DocumentTypeID = @DocumentTypeID ) BEGIN TRY BEGIN TRAN UPDATE E SET Title = EH.Title, IssueDate = EH.IssueDate, SubmitedDate = EH.SubmitedDate, CloseDate = EH.CloseDate, OriginatorID = EH.OriginatorID, IsECN = EH.IsECN, IsTECN = EH.IsTECN, IsEmergencyTECN = EH.IsEmergencyTECN, ExpirationDate = EH.ExpirationDate, ExtensionDate = EH.ExtensionDate -- 10/16/2018 if this is a 2nd extension being rejected, restore the previous extension date , CancellationDate = EH.CancellationDate, AcknowledgementRequired = EH.AcknowledgementRequired, TrainingRequired = EH.TrainingRequired, AreaID = EH.AreaID, TechnologyID = EH.TechnologyID, PCRBRequired = EH.PCRBRequired, PCRBNumber = EH.PCRBNumber, TestProgramChangeRequired = EH.TestProgramChangeRequired, SPCChangeRequired = EH.SPCChangeRequired, NewPartFlowRequired = EH.NewPartFlowRequired, SPNChangeRequired = EH.SPNChangeRequired, ImplementationDetails = EH.ImplementationDetails, ImpactOnEnvironment = EH.ImpactOnEnvironment, ImpactOnEnvironmentDescription = EH.ImpactOnEnvironmentDescription, ImpactOnCapacity = EH.ImpactOnCapacity, ImpactOnCapacityDescription = EH.ImpactOnCapacityDescription, IsMA = EH.IsMA, IsRH = EH.IsRH, IsAU = EH.IsAU, IsIndustrial = EH.IsIndustrial, MaterialConsumptionChangeRequired = EH.MaterialConsumptionChangeRequired, MaterialConsumptionChangeDescription = EH.MaterialConsumptionChangeDescription, ReasonForChange = EH.ReasonForChange, DescriptionOfChange = EH.DescriptionOfChange, NotAFlowChange = EH.NotAFlowChange, AttachECN_TECNToLots = EH.AttachECN_TECNToLots, SPNFlowChangeAtSingleStep = EH.SPNFlowChangeAtSingleStep, SPNFlowChangeAtMultipleSteps = EH.SPNFlowChangeAtMultipleSteps, CurrentStep = EH.CurrentStep, TECNExtensionState = EH.TECNExtensionState, Deleted = EH.Deleted, CancellationApproved = EH.CancellationApproved, CancellationInProgress = EH.CancellationInProgress, CancellationApprovalDate = EH.CancellationApprovalDate, ExpirationProcessed = EH.ExpirationProcessed, ExpirationInProgress = EH.ExpirationInProgress, ExpirationProcessedlDate = EH.ExpirationProcessedlDate, ReSubmitted = EH.ReSubmitted, Converted = EH.Converted, ConvertedToType = EH.ConvertedToType, ConvertedToNumber = EH.ConvertedToNumber, ConvertedFromNumber = EH.ConvertedFromNumber, LastUpdateTimeStamp = EH.LastUpdateTimeStamp, CategoryID = EH.CategoryID, FIChangeRequired = EH.FIChangeRequired, NumberOfLotsAffected = EH.NumberOfLotsAffected, RecipeChange = EH.RecipeChange FROM ECN E INNER JOIN ECN_History EH ON E.ECNNumber = EH.ECNNumber WHERE E.ECNNumber = @ECNNumber -- Update the Attachments DELETE FROM ECNAttachment WHERE ECNNumber = @ECNNumber INSERT INTO ECNAttachment (ECNNumber, FileName, UserID, UploadDate, Path) SELECT ECNNumber, FileName, UserID, UploadDate, Path FROM ECNAttachment_History WHERE ECNNumber = @ECNNumber -- DELETE the history from the history tables DELETE FROM ECN_History WHERE ECNNumber = @ECNNumber DELETE FROM ECNAttachment_History WHERE ECNNumber = @ECNNumber -- Update the Approval Table -- 10/18/2018 remove UserID clause so all pending approvals are removed DELETE FROM Approval WHERE ItemStatus = 0 AND IssueID = @ECNNumber AND Step = @CurrentStep AND DocumentTypeID = @DocumentTypeID -- UPDATE THE APPROVAL LOG INSERT INTO ApprovalLog ( IssueID, UserID, SubRoleID, OperationType, OperationLog, DocumentTypeID ) VALUES ( @ECNNumber, @UserID, @SubRoleID, 'Denied Extension', 'Denied at step ' + CONVERT(NCHAR(10), @CurrentStep), @DocumentTypeID ) COMMIT END TRY BEGIN CATCH ROLLBACK SELECT @ErrorMessage = ERROR_MESSAGE() + ' Error while Rejecting the TECN Extension', @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(); RAISERROR ( @ErrorMessage, -- Message text. @ErrorSeverity, -- Severity. @ErrorState -- State. ); END CATCH -- Update the Approval Log History END GO