diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index acef5058..a63eb5d1 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -9151,4 +9151,159 @@ ELSE PRINT 'Procedure Creation: CopyItemAndChildren Error on Creation' GO Delete From Formats where name like 'WPS%' PRINT 'Kewaunee formats removed' -GO \ No newline at end of file +GO + +/****** Object: StoredProcedure [CopyItemAndChildren] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[DeleteItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [DeleteItemAndChildren]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[DeleteItemAndChildren] +( + @ItemID int, + @UserID AS VARCHAR(100) +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + declare @DeleteID int + DECLARE @ContentID AS INT + DECLARE @NextItemID AS INT + DECLARE @PreviousItemID AS INT + DECLARE @ExternalChildCount AS INT + DECLARE @ExternalCount AS INT + DECLARE @Path AS VARCHAR(MAX) + DECLARE @Children AS TABLE + ( + ItemID INT PRIMARY KEY, + ContentID INT + ) + DECLARE @ExternalTrans TABLE + ( + [FromItemID] int, + [TransitionID] [int] NOT NULL, + [FromID] [int] NOT NULL, + [ToID] [int] NOT NULL, + [RangeID] [int] NOT NULL, + [Config] [nvarchar](max) NULL + ) + SET NOCOUNT ON + SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID + SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID + SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) where rangeid = toid or toid = @ItemID + SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) + SET @Path = [dbo].[ve_GetShortPath](@ItemID) + + IF @ExternalCount > 0 AND @NextItemID is null + BEGIN + RAISERROR ('###Cannot Delete Item###Step %d has External Transitions and has no next step - (%s)',16,1,@ItemID,@Path) + RETURN + END + + IF @ExternalChildCount > 0 + BEGIN + RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path) + RETURN + END + --deletelog + INSERT INTO DeleteLog (UserID) values (@UserID) + Select @DeleteID = SCOPE_IDENTITY() + --end deletelog + -- Get list of Children + INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID) + -- UPDATE PreviousID in Items WHERE ItemID = @NextItemID + UPDATE Items SET PreviousID = @PreviousItemID WHERE ItemID=@NextItemID + -- UPDATE DocVersion + UPDATE DocVersions SET ItemID=@NextItemID where ItemID = @ItemID + -- UPDATE Parts + IF @NextItemID is not NULL -- Remove Part Record + BEGIN + UPDATE PARTS SET ItemID = @NextItemID where ItemID=@ItemID + END + ELSE + BEGIN + DELETE FROM Parts WHERE ItemID=@ItemID + END + -- Get external transitions that point to the specified Item + -- These will need to be adjusted to point to the next Item. + INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID); + DECLARE @typeID int -- AnnotationType + SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' + IF(@typeID IS NULL) + BEGIN + INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') + SELECT @typeID = SCOPE_IDENTITY() + END + -- Add 'Verification Required' annotions for transtions that point to different step + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Transition Destination',@UserID + FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans) + -- Update content records for the transitions + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NextItemID) + From CONTENTS CC + JOIN Transitions TT ON TT.FromID = CC.ContentID + WHERE TransitionID in(Select TransitionID from @ExternalTrans where RangeID != @ItemID or RangeID = ToID) + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@PreviousItemID) + From CONTENTS CC + JOIN Transitions TT ON TT.FromID = CC.ContentID + WHERE TransitionID in(Select TransitionID from @ExternalTrans where RangeID = @ItemID and RangeID != ToID) + -- Update transitions that point to @ItemID to Point to @NextItemID + UPDATE TRANSITIONS + SET ToID = case when ToID = @ItemID then @NextItemID else ToID END, + RangeID = case when RangeID = @ItemID then @NextItemID else RangeID END + WHERE TransitionID in(Select TransitionID from @ExternalTrans where RangeID != @ItemID or RangeID = ToID) + UPDATE TRANSITIONS + SET ToID = case when ToID = @ItemID then @NextItemID else ToID END, + RangeID = case when RangeID = @ItemID then @PreviousItemID else RangeID END + WHERE TransitionID in(Select TransitionID from @ExternalTrans where RangeID = @ItemID and RangeID != ToID) + -- Delete Annotations for @ItemID and children + DELETE from Annotations where ItemID in(Select ItemID from @Children) + -- Delete Details associated with @ContentID and children + DELETE from Details where ContentID in(Select ContentID from @Children) + -- Delete Grids associated with @ContentID and children + DELETE from Grids where ContentID in(Select ContentID from @Children) + -- Delete Images associated with @ContentID and children + DELETE from Images where ContentID in(Select ContentID from @Children) + -- Delete Entries associated with @ContentID and children + DELETE from Entries where ContentID in(Select ContentID from @Children) + -- Delete ROUsages associated with @ContentID and children + DELETE from RoUsages where ContentID in(Select ContentID from @Children) + -- Delete ZTransitions records associated with @ContentID and children + DELETE FROM ZTransitions where TransitionID + in(SELECT TransitionID from Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID) + -- Delete Transitions associated with @ContentID and children + DELETE FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID + -- Delete Parts associated with @ContentID and children + DELETE from Parts where ContentID in(Select ContentID from @Children) + -- Delete ZContents associated with @ContentID and children + DELETE from ZContents where ContentID in(Select ContentID from @Children) + -- Disconnect Items from Each Other + DELETE from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null + -- Disconnect Items to be deleted from each other + Update Items set PreviousID = null where ItemID in (Select ItemID from @Children) and PreviousID Is Not Null + -- Delete Item Records + DELETE from Items where ItemID in(Select ItemID from @Children) + -- DELETE Contents + DELETE from Contents where ContentID in(Select ContentID from @Children) + --purge deletelog + DELETE from DeleteLog where DeleteID = @DeleteID + --end purge deletelog + IF( @@TRANCOUNT > 0 ) COMMIT +END TRY +BEGIN CATCH -- Catch Block + IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level + ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback + EXEC vlnErrorHandler +END CATCH +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: DeleteItemAndChildren Succeeded' +ELSE PRINT 'Procedure Creation: DeleteItemAndChildren Error on Creation' +GO