284 lines
		
	
	
		
			27 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
			
		
		
	
	
			284 lines
		
	
	
		
			27 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
| --restore database [VEPROMS] from disk = 'C:\Backups\20091211.BAK'
 | ||
| --╔═════════════════════════════════════════════════════════════════╗
 | ||
| --║ TODO: Need to update Transitions and ROs to reflect the new IDs ║
 | ||
| --╚═════════════════════════════════════════════════════════════════╝
 | ||
| --USE VEPROMS
 | ||
| -- Parameters
 | ||
| --DECLARE @StartItemID INT
 | ||
| --DECLARE @EndItemID INT
 | ||
| --DECLARE @UserID NVARCHAR(100)
 | ||
| -- <<< MS Word Sections >>>
 | ||
| --SET @StartItemID = 53;SET @EndItemID = 53		-- EO00 Cover
 | ||
| --SET @StartItemID = 53;SET @EndItemID = 54		-- EO00 Cover and Purpose
 | ||
| --SET @StartItemID = 374;SET @EndItemID = 374	-- EO00 Addendums 1
 | ||
| --SET @StartItemID = 374;SET @EndItemID = 124	-- EO00 Addendums 1 through 5
 | ||
| -- <<< Steps >>>
 | ||
| --SET @StartItemID = 1;SET @EndItemID = 1		-- EO00
 | ||
| --SET @StartItemID = 210;SET @EndItemID = 210		-- EO00 Step 1
 | ||
| --SET @StartItemID = 58;SET @EndItemID = 58		-- EO00 Step 4
 | ||
| --SET @StartItemID = 58;SET @EndItemID = 143	-- EO00 Step 4 through 7
 | ||
| --SET @StartItemID = 107;SET @EndItemID = 108	-- Substeps a and b of EO00 Step 4
 | ||
| --SET @StartItemID = 107;SET @EndItemID = 107	-- Substeps a of EO00 Step 4
 | ||
| --SET @StartItemID = 108;SET @EndItemID = 108	-- Substeps b of EO00 Step 4
 | ||
| --SET @UserID = 'KCopy'
 | ||
| -- Locals
 | ||
| --DECLARE @NewStartItemID INT -- New Start Item
 | ||
| --DECLARE @NewEndItemID INT -- New End Item
 | ||
| --DECLARE @DTS DATETIME -- DTS of all New Items
 | ||
| --SET @DTS = GETDATE() -- Get the current Date and Time
 | ||
| 
 | ||
| ALTER PROCEDURE [dbo].[CopyItemAndChildren]
 | ||
| (
 | ||
| 	@StartItemID INT,
 | ||
| 	@EndItemID INT,
 | ||
| 	@UserID NVARCHAR(100)
 | ||
| )
 | ||
| WITH EXECUTE AS OWNER
 | ||
| AS
 | ||
| BEGIN TRY -- Try Block
 | ||
| 
 | ||
| --╔═════════════════════════════════════════════════════════════════╗
 | ||
| --║ BEGIN TRANSACTION to make these changes temporary               ║
 | ||
| --╚═════════════════════════════════════════════════════════════════╝
 | ||
| 	BEGIN TRANSACTION
 | ||
| 
 | ||
| DECLARE @Children AS TABLE
 | ||
| (
 | ||
| 	ItemID INT PRIMARY KEY,
 | ||
| 	NewItemID INT,
 | ||
| 	ContentID INT,
 | ||
| 	NewContentID INT
 | ||
| )
 | ||
| DECLARE @NewDocuments AS TABLE
 | ||
| (
 | ||
| 	DocID INT PRIMARY KEY,
 | ||
| 	NewDocID INT
 | ||
| )
 | ||
| -- Get a list of all of the Items to be copied based upon StartItemID and EndItemID
 | ||
| -- If the StartItemID = EndItemID then it is a single item and it's children
 | ||
| INSERT INTO @Children SELECT ItemID,ItemID,ContentID,ContentID FROM vefn_ChildItemsRange(@StartItemID,@EndItemID)
 | ||
| -- <<< Copy Contents >>>
 | ||
| -- Create new content rows to match the existing rows.  Set the type to the Current ContentID temporarily
 | ||
| -- so that the new content rows can be associated with the existing content rows.
 | ||
| INSERT INTO Contents
 | ||
|   ([Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID])
 | ||
| 	select [Number],[Text],[ContentID],[FormatID],[Config],@DTS,@UserID
 | ||
|  from Contents where ContentID in(Select ContentID from @Children)
 | ||
| -- Update the @Children with the NewConentIDs
 | ||
| UPDATE NN set NN.NewContentID = CC.ContentID 
 | ||
| From Contents CC
 | ||
| Join @Children NN on NN.ContentID = CC.Type AND CC.DTS = @DTS and CC.UserID = @UserID
 | ||
| -- Reset the Type column in the Contents table with the Type column from the original Records. 
 | ||
| UPDATE CC set CC.Type = CC2.Type 
 | ||
| From Contents CC
 | ||
| Join @Children NN on NN.NewContentID = CC.ContentID
 | ||
| Join Contents CC2 on NN.ContentID = CC2.ContentID
 | ||
| -- Contents are done
 | ||
| 	-- SELECT * From Contents where DTS = @DTS and UserID = @UserID
 | ||
| -- <<< Copy Items >>>
 | ||
| -- Create new item rows based upon the current item rows and the @Children table, with the NewContentIDs
 | ||
| INSERT INTO [Items] ([PreviousID],[ContentID],[DTS],[UserID])
 | ||
|      SELECT II.[PreviousID], -- Leave the PreviousID as is for now
 | ||
| 			NN.NewContentID, @DTS, @UserID 
 | ||
| 			from @Children NN
 | ||
| 			join Items II on II.ContentID = NN.ContentID
 | ||
| -- Update the @Children with the NewItemIDs
 | ||
| UPDATE NN set NN.NewItemID = II.ItemID 
 | ||
| From Items II
 | ||
| Join @Children NN on NN.NewContentID = II.ContentID AND II.DTS = @DTS and II.UserID = @UserID
 | ||
| -- The @Children table is now complete
 | ||
| 	--SELECT * From @Children
 | ||
| -- Update the PreviousID in the new Item rows, to the new ItemIDs based upon the old ItemIDs
 | ||
| Update II Set II.[PreviousID] = NN.NewItemID
 | ||
| from Items II
 | ||
| Join @Children NN on NN.ItemID = II.PreviousID AND II.DTS = @DTS and II.UserID = @UserID
 | ||
| -- Get the new ItemIDs based upon the old ItemIDs
 | ||
| SELECT @NewStartItemID = NewItemID from @Children where ItemID = @StartItemID
 | ||
| SELECT @NewEndItemID = NewItemID from @Children where ItemID = @EndItemID
 | ||
| -- Set the PreviousID for the starting Item to null temporarily.  
 | ||
| -- This will be adjusted based upon where the step is inserted.
 | ||
| Update Items Set PreviousID = null where ItemID = @NewStartItemID
 | ||
| -- Items are done
 | ||
| 	--SELECT * From Items where DTS = @DTS and UserID = @UserID
 | ||
| -- <<< Copy Parts >>>
 | ||
| INSERT INTO [Parts] ([ContentID],[FromType],[ItemID],[DTS],[UserID])
 | ||
| Select NNF.NewContentID,[FromType],NNT.NewItemID, @DTS, @UserID from Parts PP 
 | ||
| JOIN @Children NNF on PP.ContentID = NNF.ContentID
 | ||
| JOIN @Children NNT on PP.ItemID = NNT.ItemID
 | ||
| -- Parts are done
 | ||
| 	-- SELECT * From Parts where DTS = @DTS and UserID = @UserID
 | ||
| -- <<< Copy Annotations >>>
 | ||
| INSERT INTO [Annotations] ([ItemID],[TypeID],[RtfText],[SearchText],[Config],[DTS],[UserID])
 | ||
|      Select NewItemID, TypeID, RtfText, SearchText, Config, @DTS, @UserID 
 | ||
| 			from Annotations AA Join @Children NN on AA.ItemID = NN.ItemID
 | ||
| -- Annotations are done
 | ||
| 	-- SELECT * From Annotations where DTS = @DTS and UserID = @UserID
 | ||
| -- <<< Copy Documents and Entries>>>
 | ||
| -- logic to create Entries for Library Documents
 | ||
| INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID])
 | ||
| 	SELECT NN.[NewContentID],EE.[DocID],@DTS,@UserID
 | ||
|   FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
 | ||
| 	JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') <> ''
 | ||
| -- Logic to create new documents for any documents used that do not have libttitles
 | ||
| INSERT INTO [Documents] ([LibTitle],[DocContent],[DocAscii],[Config],[DTS],[UserID],[FileExtension])
 | ||
|   OUTPUT CAST(INSERTED.[LibTitle] as INT),INSERTED.[DocID] INTO @NewDocuments
 | ||
| 	SELECT str(DD.[DocID]),[DocContent],[DocAscii],[Config],@DTS,@UserID,[FileExtension]
 | ||
|   FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
 | ||
| 	JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') = ''
 | ||
| UPDATE DD SET LibTitle = '' 
 | ||
| 	FROM Documents DD JOIN @NewDocuments ND on DD.[DocID] = ND.[NewDocID]
 | ||
| 	where DTS = @DTS and UserID = @UserID 
 | ||
| -- Documents are Done
 | ||
| 	-- SELECT * From Documents where DTS = @DTS and UserID = @UserID
 | ||
| -- Need logic to create entries for these newly created documents
 | ||
| INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID])
 | ||
| 	SELECT NN.[NewContentID],ND.[NewDocID],@DTS,@UserID
 | ||
|   FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
 | ||
| 	JOIN @NewDocuments ND on EE.[DocID] = ND.[DocID]
 | ||
| -- Entries are done
 | ||
| 	-- SELECT * From Entries EE JOIN Documents DD on ee.DocID = DD.DocID where EE.DTS = @DTS and EE.UserID = @UserID
 | ||
| -- <<< Copy RoUsages >>>
 | ||
| INSERT INTO [VEPROMS].[dbo].[RoUsages] ([ContentID],[ROID],[Config],[DTS],[UserID],[RODbID])
 | ||
| 	SELECT NN.[NewContentID],[ROID],[Config],@DTS,@UserID,[RODbID]
 | ||
| 		FROM [RoUsages] RR Join @Children NN on RR.ContentID = NN.ContentID
 | ||
| -- RoUsages are done
 | ||
| 	-- SELECT * From RoUsages where DTS = @DTS and UserID = @UserID
 | ||
| -- <<< Copy Transtions >>>
 | ||
| INSERT INTO [VEPROMS].[dbo].[Transitions] ([FromID],[ToID],[RangeID],[TranType],[Config],[DTS],[UserID])
 | ||
| 	SELECT NNF.[NewContentID],ISNULL(NNT.[NewItemID],[ToID]),ISNULL(NNR.[NewItemID],[RangeID]),[TranType],[Config],@DTS,@UserID
 | ||
| 	FROM [VEPROMS].[dbo].[Transitions] TT
 | ||
| 	JOIN @Children NNF on TT.[FromID] = NNF.[ContentID]
 | ||
| 	LEFT JOIN @Children NNT on TT.[ToID] = NNT.[ItemID]
 | ||
| 	LEFT JOIN @Children NNR on TT.[RangeID] = NNR.[ItemID]
 | ||
| -- Transitions are done
 | ||
| 	-- SELECT * From Transitions where DTS = @DTS and UserID = @UserID
 | ||
| --╔═════════════════════════════════════════════════════════════════╗
 | ||
| --║ Rollback to remove any of the changes just made.                ║
 | ||
| --╚═════════════════════════════════════════════════════════════════╝
 | ||
| 
 | ||
| --ROLLBACK -- Reset the data
 | ||
| COMMIT
 | ||
| --BEGIN TRANSACTION
 | ||
| --EXECUTE pasteItemSiblingBefore 230, @NewStartItemID, null, @DTS, @UserID
 | ||
| --COMMIT
 | ||
| --SELECT ItemID,ContentID,dbo.ve_GetShortPath(ItemID) from vefn_ChildItemsRange(107,108)
 | ||
| --SELECT * from Items where ItemID in
 | ||
| 
 | ||
| -- Create new items based upon this list
 | ||
| -- Create a list of Old2New ItemID, OldItemID, ContentID, OldContentID
 | ||
| -- Use logic for AddItemChild, AddItemSiblingAfter and AddItemSiblingBefore to insert the new structure
 | ||
| /*
 | ||
| 		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)
 | ||
| 		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
 | ||
| 		-- 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)
 | ||
| 		-- 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)
 | ||
| 		-- 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 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)
 | ||
| */
 | ||
| /*
 | ||
| 	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
 | ||
| */
 | ||
| --USE MASTER |