diff --git a/PROMS/SQL/PROMS2010.SQL b/PROMS/SQL/PROMS2010.SQL index 69c6bc1a..d9b05900 100644 --- a/PROMS/SQL/PROMS2010.SQL +++ b/PROMS/SQL/PROMS2010.SQL @@ -967,10 +967,14 @@ BEGIN TRY -- Try Block SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Next Step Transition Destination',@UserID + FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS + where ToID IN(@newItemID) OR RangeID IN(@newItemID)) INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Verify Transition Destination',@UserID FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS - where ToID IN(@NextID,@newItemID) OR RangeID IN(@NextID,@newItemID)) + where ToID IN(@NextID) OR RangeID IN(@NextID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT EXECUTE GetItem @newItemID @@ -1740,6 +1744,233 @@ IF (@@Error = 0) PRINT 'Procedure Creation: addZTransition Succeeded' ELSE PRINT 'Procedure Creation: addZTransition Error on Creation' GO +/****** Object: StoredProcedure [CopyItemAndChildren] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[CopyItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [CopyItemAndChildren]; +GO + +CREATE PROCEDURE [dbo].[CopyItemAndChildren] +( + @StartItemID INT, + @DestFormatID INT, + @UserID NVARCHAR(100), + @NewStartItemID int output +) +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, + FormatID INT, + NewFormatID INT +) +DECLARE @NewDocuments AS TABLE +( + DocID INT PRIMARY KEY, + NewDocID INT +) +-- Locals +DECLARE @DTS DATETIME -- DTS of all New Items +SET @DTS = GETDATE() -- Get the current Date and Time +-- 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,FormatID,FormatID FROM vefn_ChildItemsRange(@StartItemID,@StartItemID,null) +-- <<< 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 +DECLARE @NewItemID int +SELECT @NewItemID = NewItemID + FROM @Children + WHERE ItemID = @StartItemID +UPDATE NN SET NN.[NewFormatID] = CC.[FormatID] + FROM @Children NN + Join vefn_ChildItemsRange(@NewItemID,@NewItemID,@DestFormatID) CC + ON NN.NewItemID = CC.ItemID +-- 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 +-- 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],CAST([ROUsageID] as nvarchar(16)),[Config],@DTS,@UserID,[RODbID] + FROM [RoUsages] RR Join @Children NN on RR.ContentID = NN.ContentID +-- Update content records for newly copied records to use correct RO usage ids in the RO tags +DECLARE @RowsAffected int +SET @RowsAffected=1 +WHILE @RowsAffected > 0 +BEGIN +UPDATE CC SET [TEXT] = C2.NewText + FROM CONTENTS CC + JOIN (SELECT C1.ContentID, .dbo.vefn_FixROText(C1.Text, CAST([ROID] as int), [ROUsageID]) NewText + FROM CONTENTS C1 + JOIN @Children NN on C1.ContentID = NN.NewContentID + JOIN RoUsages RO on NN.NewContentID = RO.ContentID) C2 ON CC.ContentID = C2.ContentID + WHERE [TEXT] <> C2.NewText + SET @RowsAffected = @@RowCount +END +UPDATE RON SET [ROID] = ROO.[ROID] + FROM RoUsages RON + JOIN @Children NN on RON.ContentID = NN.NewContentID + JOIN RoUsages ROO on CAST(RON.ROID as int) = ROO.RoUsageID + +-- RoUsages are done + -- SELECT * From RoUsages where DTS = @DTS and UserID = @UserID + +-- <<< Copy Transtions >>> +-- Note that the inserted record has the 'TranType' field set to old transitionid. This is done +-- so that the next step can replace the old transitionid with the new transitionid in the +-- content record's transition tokens. The TranType gets reset after the content records are +-- updated. +-- Also note that the 'toid/rangeid' may need converted to newly copied ids or may not. If it's +-- not a range, then it always is converted to new, if there is a new. If it's a range, both +-- the toid & the rangeid must be new in order for the conversion to be correct. You cannot +-- have part of the range pointing to the new and part of the range pointing to the original +-- locations. + +INSERT INTO .[dbo].[Transitions] ([FromID],[ToID],[RangeID],[TranType],[Config],[DTS],[UserID]) + SELECT NNF.[NewContentID], + -- if both toid & range are null, use the original toid & rangeid + CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [ToID] ELSE NNT.[NewItemID] END, + CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [RangeID] ELSE NNR.[NewItemID] END, + [TransitionID],[Config],@DTS,@UserID + FROM .[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] +-- -- Update content records for newly copied records to use correct TransitionIDs in the Transition tags +SET @RowsAffected=1 +WHILE @RowsAffected > 0 +BEGIN +UPDATE CC SET [TEXT] = C2.NewText + FROM CONTENTS CC + JOIN (SELECT C1.ContentID, .dbo.vefn_FixTransitionTextForCopy(C1.Text, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewText + FROM CONTENTS C1 + JOIN @Children NN on C1.ContentID = NN.NewContentID + JOIN Transitions TR on NN.NewContentID = TR.FromID + JOIN Transitions TRO on TR.TranType = TRO.TransitionID) C2 ON CC.ContentID = C2.ContentID + WHERE [TEXT] <> C2.NewText + SET @RowsAffected = @@RowCount +END +-- Add 'Verification Required' AnnotationType + DECLARE @typeID int + 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" Annotation for each Transition whose transition format changes +INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT NN.NewItemID, @typeID,'Verify Transition Format',@UserID + FROM Transitions TR + JOIN @Children NN on TR.FromID = NN.NewContentID + JOIN Transitions TRO on TR.TranType = TRO.TransitionID + WHERE .dbo.vefn_CompareTranFormat(NN.FormatID, NN.NewFormatID, TRO.TranType) <> 0 +UPDATE TR SET TR.[TranType] = .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType) + FROM Transitions TR + JOIN @Children NN on TR.FromID = NN.NewContentID + JOIN Transitions TRO on TR.TranType = TRO.TransitionID +-- Transitions are done + -- SELECT * From Transitions where DTS = @DTS and UserID = @UserID + + 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 +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: CopyItemAndChildren Succeeded' +ELSE PRINT 'Procedure Creation: CopyItemAndChildren Error on Creation' +GO + /****** Object: StoredProcedure [deleteAnnotation] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteAnnotation]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [deleteAnnotation]; @@ -3513,7 +3744,7 @@ GO exec getAffectedTransitions 2102 */ -Create PROCEDURE [dbo].[getAffectedTransitions] +CREATE PROCEDURE [dbo].[getAffectedTransitions] ( @ItemID int ) @@ -6622,6 +6853,37 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getPartsByItemID Succeeded' ELSE PRINT 'Procedure Creation: getPartsByItemID Error on Creation' GO +/****** Object: StoredProcedure [getPastedAffectedTransitions] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getPastedAffectedTransitions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getPastedAffectedTransitions]; +GO + +CREATE PROCEDURE [dbo].[getPastedAffectedTransitions] +( + @ItemID int +) +WITH EXECUTE AS OWNER +AS + +SELECT + TT.[TransitionID], + [FromID], + [ToID], + [RangeID], + [TranType], + [Config], + [DTS], + [UserID], + [LastChanged], + (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] +FROM [Transitions] TT join vefn_ChildItems(@ItemID) CC on CC.ContentID = TT.FromID +RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getPastedAffectedTransitions Succeeded' +ELSE PRINT 'Procedure Creation: getPastedAffectedTransitions Error on Creation' +GO + /****** Object: StoredProcedure [getPermission] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getPermission]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getPermission]; @@ -8051,6 +8313,362 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getZTransitionsByTransitionID Succee ELSE PRINT 'Procedure Creation: getZTransitionsByTransitionID Error on Creation' GO +/****** Object: StoredProcedure [PasteItemReplace] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemReplace]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [PasteItemReplace]; +GO + +-- ItemID is item to replace +-- StartItemID is item to copy +CREATE PROCEDURE [dbo].[PasteItemReplace] +( + @ItemID int=null, @StartItemID int=null, + @Type int=null, @DTS datetime, @UserID nvarchar(100), + @NewItemID int output +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + 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 + ) + + -- First check if the replaced item can be deleted, i.e. it doesn't have transitions + -- pointing to it or children. + + 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 + + -- Copy the item, 'NewItemID' represents the new item(s) + -- DestFormatID is the formatid for the destination parent's format + DECLARE @DestFormatID int + SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) + EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT + + -- Adjust the next/previous to point to the new item + + DECLARE @PreviousID int + SELECT @PreviousID = [PreviousID] + FROM [ITEMS] II + WHERE [ItemID]=@ItemID + UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID + UPDATE [CONTENTS] SET [Type]=@Type + FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] + WHERE [ItemID]=@NewItemID + UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [PreviousID]=@ItemID + UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID + + -- UPDATE DocVersion if this was a procedure + UPDATE DocVersions SET ItemID=@NewItemID where ItemID = @ItemID + + -- If there were 'external transitions' that pointed to the original + -- top replaced step, adjust them to point to the new top. + INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID) + IF (SELECT COUNT(*) from @ExternalTrans) > 0 + BEGIN + -- Update content records for the transitions + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NewItemID) + 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 @NewItemID else ToID END, + RangeID = case when RangeID = @ItemID then @NewItemID else RangeID END + WHERE TransitionID in(Select TransitionID from @ExternalTrans) + + 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 pointed to top step + -- and need to point to + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Replaced Step Transition Destination',@UserID + FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans) + + END + -- Remove the old one + + -- Get list of Children + INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID) + -- 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 + EXECUTE GetItem @NewItemID +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: PasteItemReplace Succeeded' +ELSE PRINT 'Procedure Creation: PasteItemReplace Error on Creation' +GO + +/****** Object: StoredProcedure [PasteItemSiblingAfter] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingAfter]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [PasteItemSiblingAfter]; +GO + +CREATE PROCEDURE [dbo].[PasteItemSiblingAfter] +( + @ItemID int=null, @StartItemID int=null, -- ItemID is destination, StartItemID is top of copy + @Type int=null, @DTS datetime, @UserID nvarchar(100), + @NewItemID int output +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + -- First make a copy of the input StartItemID + -- DestFormatID is the formatid for the destination parent's format + DECLARE @DestFormatID int + SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) + EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT + -- Adjust previous field + DECLARE @NextID int + SELECT @NextID = [ItemID] + FROM [ITEMS] + WHERE [PreviousID]=@ItemID + IF @NextID is not null -- step after the copy point. Adjust it's previous to point to the new step + BEGIN + UPDATE [ITEMS] SET [PreviousID]=@NewItemID, [DTS]=@DTS, [UserID]=@UserID where [ItemID]=@NextID + END + UPDATE [ITEMS] SET [PreviousID]=@ItemID where [ItemID]=@NewItemID + UPDATE [CONTENTS] SET [Type]=@Type + FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] + WHERE [ItemID]=@NewItemID + + + -- Check for Transitions that point to the Next Step + BEGIN + -- Get a list of Transitions which need to change children of @ItemID that point to @NextID + DECLARE @NextStepTransitions TABLE + ( + [TransitionID] int PRIMARY KEY, + [FromID] [int], + [ToID] [int], + [RangeID] [int], + [TranType] [int], + [Config] [nvarchar](max) + ) + Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@NextID,@ItemID) + IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions + BEGIN + -- Update all transitions in the list to point to @newItemID + Update TT + Set TT.ToID = CASE TT.ToID WHEN @NextID THEN @NewItemID ELSE TT.ToID END, + TT.RangeID = CASE TT.RangeID WHEN @NextID THEN @NewItemID ELSE TT.RangeID END + From TRANSITIONS TT + JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID + -- Update content records for the transitions + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@NextID,@NewItemID) + From CONTENTS CC + JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID + END + END + -- Add 'Verification Required' AnnotationType + DECLARE @typeID int + 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" Annotation for each Transition that points to @newItemID or @NextID + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Next Step Transition Destination',@UserID + FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS + where ToID IN(@newItemID) OR RangeID IN(@newItemID)) + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Transition Destination',@UserID + FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS + where ToID IN(@NextID) OR RangeID IN(@NextID)) + -- Transition Text gets updated in ItemInsertExt.cs + + IF( @@TRANCOUNT > 0 ) COMMIT + EXECUTE GetItem @NewItemID +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: PasteItemSiblingAfter Succeeded' +ELSE PRINT 'Procedure Creation: PasteItemSiblingAfter Error on Creation' +GO + +/****** Object: StoredProcedure [PasteItemSiblingBefore] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingBefore]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [PasteItemSiblingBefore]; +GO + +CREATE PROCEDURE [dbo].[PasteItemSiblingBefore] +( + @ItemID int=null, @StartItemID int=null, + @Type int=null, @DTS datetime, @UserID nvarchar(100), + @NewItemID int output +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + -- First make a copy of the input CopyStartID + -- DestFormatID is the formatid for the destination parent's format + DECLARE @DestFormatID int + SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0) + EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT + -- First adjust previous fields, may also have to do parts, if before first one in list. + DECLARE @PreviousID int, @ContentID int, @newLastChanged timestamp, @NewType int + SELECT @PreviousID = [PreviousID], @NewType=ISNULL(@Type,[Type]) + FROM [ITEMS] II + JOIN [CONTENTS] CC ON CC.[ContentID]=II.[CONTENTID] + WHERE [ItemID]=@ItemID + UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [ItemID]=@ItemID + UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID + UPDATE [CONTENTS] SET [Type]=@Type + FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID] + WHERE [ItemID]=@NewItemID + UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID + UPDATE [DOCVERSIONS] SET [ItemID] = @NewItemID where [ItemID]=@ItemID + + IF @PreviousID is null -- The step is replacing the first step + BEGIN + -- Update content records for the transitions + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NewItemID) + From CONTENTS CC + JOIN Transitions TT ON TT.FromID = CC.ContentID + WHERE TT.ToID = @ItemID OR TT.RangeID = @ItemID + -- Update transitions that pointed to @ItemID to point to @newItemID + Update TRANSITIONS + Set ToID = CASE ToID WHEN @ItemID THEN @NewItemID ELSE ToID END, + RangeID = CASE RangeID WHEN @ItemID THEN @NewItemID ELSE RangeID END + WHERE ToID = @ItemID OR RangeID = @ItemID + END + ELSE -- Check for Transitions that point to the Next Step + BEGIN + -- Get a list of Transitions which need to change children of @ItemID that point to @NextID + DECLARE @NextStepTransitions TABLE + ( + [TransitionID] int PRIMARY KEY, + [FromID] [int], + [ToID] [int], + [RangeID] [int], + [TranType] [int], + [Config] [nvarchar](max) + ) + Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@ItemID,@PreviousID) + IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions + BEGIN + -- Update all transitions in the list to point to @newItemID + Update TT + Set TT.ToID = CASE TT.ToID WHEN @ItemID THEN @NewItemID ELSE TT.ToID END, + TT.RangeID = CASE TT.RangeID WHEN @ItemID THEN @NewItemID ELSE TT.RangeID END + From TRANSITIONS TT + JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID + -- Update content records for the transitions + Update CC + Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@ItemID,@NewItemID) + From CONTENTS CC + JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID + END + END + -- Add 'Verification Required' AnnotationType + DECLARE @typeID int + 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" Annotation for each Transition that points to @newItemID or @NextID + INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) + SELECT ItemID, @typeID,'Verify Transition Destination',@UserID + FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS + where ToID IN(@ItemID,@NewItemID) OR RangeID IN(@ItemID,@NewItemID)) + -- Transition Text gets updated in ItemInsertExt.cs + IF( @@TRANCOUNT > 0 ) COMMIT + EXECUTE GetItem @NewItemID +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: PasteItemSiblingBefore Succeeded' +ELSE PRINT 'Procedure Creation: PasteItemSiblingBefore Error on Creation' +GO + /****** Object: StoredProcedure [purgeData] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[purgeData]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [purgeData]; @@ -10336,6 +10954,54 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ChildItems Error on Creation' GO +/****** Object: StoredProcedure [vefn_ChildItemsRange] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildItemsRange]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_ChildItemsRange]; +GO + +CREATE FUNCTION [dbo].[vefn_ChildItemsRange](@StartItemID int, @EndItemID int, @DestFormat int) +RETURNS @Children TABLE +( +ItemID int PRIMARY KEY, +ContentID int, +FormatID int +) +WITH EXECUTE AS OWNER +AS +BEGIN +DECLARE @FormatID int +SELECT @FormatID = isnull(@DestFormat,.dbo.vefn_GetInheritedFormat(@StartItemID,1)) +BEGIN +with Itemz([Level], [ItemID], [ContentID], [FormatID], [FoundEnd]) as ( +Select 0 [Level], [ItemID], I.[ContentID], IsNull(C.[FormatID], @FormatID), case [ItemID] when @EndItemID then 1 else 0 end [FoundEnd] +FROM [Items] I +JOIN [Contents] C on I.ContentID = C.ContentID +where [ItemID]=@StartItemID +Union All +-- Children +select [Level] + 1, I.[ItemID], I.[ContentID], IsNull(C.[FormatID], Z.[FormatID]), case I.[ItemID] when @EndItemID then 1 else 0 end [FoundEnd] +from Itemz Z +join Parts P on P.ContentID = Z.ContentID +join Items I on I.ItemID = P.ItemID +JOIN [Contents] C on I.ContentID = C.ContentID +-- Siblings +Union All +select [Level] , I.[ItemID], I.[ContentID], IsNull(C.[FormatID], Z.[FormatID]), case I.[ItemID] when @EndItemID then 1 else 0 end [FoundEnd] +from Itemz Z +join Items I on I.PreviousID = Z.ItemID +JOIN [Contents] C on I.ContentID = C.ContentID +where FoundEnd = 0 +) +insert into @Children select ItemID, ContentID, FormatID from Itemz +RETURN +END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildItemsRange Succeeded' +ELSE PRINT 'TableFunction Creation: vefn_ChildItemsRange Error on Creation' +GO + /****** Object: StoredProcedure [vefn_ChildrenItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChildrenItems]; @@ -10385,6 +11051,46 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildrenItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ChildrenItems Error on Creation' GO +/****** Object: StoredProcedure [vefn_CompareTranFormat] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CompareTranFormat]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_CompareTranFormat]; +GO + +/* + Determines if two transition formats are same string. + returns 0 if identical, 1 if similar (range for range, item for item), 2 if totally different +*/ +CREATE FUNCTION [dbo].[vefn_CompareTranFormat] (@FormatID int, @NewFormatID int, @TranType int) RETURNS int +WITH EXECUTE AS OWNER +AS +BEGIN + -- + IF @FormatID = @NewFormatID + RETURN @TranType + DECLARE @TransFormat varchar(max) + DECLARE @NewTransFormat varchar(max) + SET @TransFormat = isnull(.dbo.vefn_GetTransFormat(@FormatID, @TranType),'') + SET @NewTransFormat = isnull(.dbo.vefn_GetTransFormat(@NewFormatID, @TranType),'') + RETURN CASE + WHEN @TransFormat = @NewTransFormat THEN 0 -- transition formats are identical + WHEN @TransFormat LIKE '%{Last Step}%' THEN + CASE + WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 1 -- both ranges, but different format + ELSE 2 -- totally different format, not even same type (was single, changed to range) + END + ELSE + CASE + WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 2 -- totally different format, not even same type (was range, changed to single) + ELSE 1 -- both single, but different format + END + END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_CompareTranFormat Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_CompareTranFormat Error on Creation' +GO + /****** Object: StoredProcedure [vefn_DocVersionSplit] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_DocVersionSplit]; @@ -10726,6 +11432,61 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindInternalTransitions Suc ELSE PRINT 'TableFunction Creation: vefn_FindInternalTransitions Error on Creation' GO +/****** Object: StoredProcedure [vefn_FindInternalTransitionsForCopy] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindInternalTransitionsForCopy]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_FindInternalTransitionsForCopy]; +GO + +/* +Select * from vefn_FindInternalTransitionsForCopy(10277) +*/ +CREATE FUNCTION [dbo].[vefn_FindInternalTransitionsForCopy](@ItemID int) +RETURNS @Transitions TABLE +( + TransitionID int, + FromID int, + TranType int, + ToID int, + RangeID int, + OldTransition int +) +WITH EXECUTE AS OWNER +AS +BEGIN +with Itemz([Level], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( + Select 0 [Level], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] + ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] + FROM [Items] + where [ItemID]=@ItemID +Union All +-- Children + select [Level] + 1,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] + from Itemz Z + join Parts P on P.ContentID = Z.ContentID + join Items I on I.ItemID = P.ItemID +-- Siblings +Union All + select [Level] ,Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,null,null,null,null + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + where Z.[Level] > 0 +) +insert into @Transitions +select TransitionID, FromID, TT.TranType, TT.ToID, TT.RangeID, CAST(TT.Config as int) --case when TT.ToID in(select ItemID from Itemz) then TT.ToID else TT.RangeID end [ToID] + from Transitions TT + join Items II on II.ContentID=TT.FromID +where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) +AND FromID in(Select ContentID from ItemZ) +RETURN +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindInternalTransitionsForCopy Succeeded' +ELSE PRINT 'TableFunction Creation: vefn_FindInternalTransitionsForCopy Error on Creation' +GO + /****** Object: StoredProcedure [vefn_FindText] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindText]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindText]; @@ -10816,6 +11577,62 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindText Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindText Error on Creation' GO +/****** Object: StoredProcedure [vefn_FirstLink] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FirstLink]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_FirstLink]; +GO + +/* +select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 2) +select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 1) +select .dbo.vefn_FirstLink('asdasdadsasd' + char(21) + 'asdasdasd\vasdasdasd', 0) +*/ + +-- This is only used for testing by vefn_RemoveExtraText +CREATE FUNCTION [dbo].[vefn_FirstLink](@text nvarchar(MAX),@includeLink int) +RETURNS int +AS +BEGIN +DECLARE @index int +SET @index = 0 +if(@includeLink = 2) + RETURN 0 +if(@includeLink = 1) + return CHARINDEX('\v' , @text) +DECLARE @index2 int +SET @index = PATINDEX('%[' + nchar(9574)+nchar(9516)+nchar(21) + ']%',@text) +return @index +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FirstLink Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_FirstLink Error on Creation' +GO + +/****** Object: StoredProcedure [vefn_FixROText] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixROText]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_FixROText]; +GO + +CREATE FUNCTION [dbo].[vefn_FixROText] +(@Text varchar(MAX),@ROUsageID int,@NewROUsageID int) +RETURNS varchar(MAX) +WITH EXECUTE AS OWNER +AS +BEGIN + -- Build Search String and Replace String + DECLARE @lookFor varchar(MAX) + DECLARE @replaceWith varchar(MAX) + SET @lookFor = '#Link:ReferencedObject:' + ltrim(str(@ROUsageID)) + ' ' + SET @replaceWith = '#Link:ReferencedObject:' + ltrim(str(@NewROUsageID)) + ' ' + return replace(@text,@lookFor,@replaceWith) +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixROText Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_FixROText Error on Creation' +GO + /****** Object: StoredProcedure [vefn_FixSearchString] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixSearchString]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_FixSearchString]; @@ -10922,6 +11739,130 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixTransitionText Succeede ELSE PRINT 'ScalarFunction Creation: vefn_FixTransitionText Error on Creation' GO +/****** Object: StoredProcedure [vefn_FixTransitionTextForCopy] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixTransitionTextForCopy]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_FixTransitionTextForCopy]; +GO + +CREATE FUNCTION [dbo].[vefn_FixTransitionTextForCopy] +(@Text varchar(MAX),@TransitionID int,@TranType int,@OldToID int,@OldRangeID int, @NewID int, @NewToID int, @NewRangeID int, @NewTranType int) +RETURNS varchar(MAX) +WITH EXECUTE AS OWNER +AS +BEGIN + + -- Build Search String and Replace String + DECLARE @offset int + DECLARE @lookFor varchar(MAX) + DECLARE @replaceWith varchar(MAX) + SET @lookFor = '#Link:Transition:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) + SET @offset = CHARINDEX(@lookFor,@Text) + if(@offset = 0) + BEGIN + + SET @lookFor = '#Link:TransitionRange:' + ltrim(str(@TranType)) + ' ' + ltrim(str(@TransitionID)) + SET @offset = CHARINDEX(@lookFor,@Text) + SET @replaceWith = '#Link:TransitionRange:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + + ' ' + ltrim(str(@NewToID)) + ' ' + ltrim(str(@NewRangeID)) + SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) + ' ' + ltrim(str(@OldRangeID)) + END + ELSE + BEGIN + SET @replaceWith = '#Link:Transition:' + ltrim(str(@NewTranType)) + ' ' + ltrim(str(@NewID)) + + ' ' + ltrim(str(@NewToID)) + SET @lookFor = @lookFor + ' ' + ltrim(str(@OldToID)) + END + return replace(@text,@lookFor,@replaceWith) +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixTransitionTextForCopy Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_FixTransitionTextForCopy Error on Creation' +GO + +/****** Object: StoredProcedure [vefn_GetFormatField] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetFormatField]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_GetFormatField]; +GO + +/* +Select * from vefn_GetFormatField('Font') +Select * from vefn_GetFormatField('PSADJBNGROW') +Select * from vefn_GetFormatField('SectionTitle') +Select * from vefn_GetFormatField('PrintNoTitle') +*/ + +CREATE FUNCTION [dbo].[vefn_GetFormatField](@find varchar(255)) +RETURNS @FormatFields TABLE +( + FormatID int + ,Name varchar(20) + ,Description varchar(250) + ,Path varchar(max) + ,Value varchar(255) +) +WITH EXECUTE AS OWNER +AS +BEGIN + INSERT INTO @FormatFields + Select FormatID, Name, Description, + case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + + + '@' + v.value('local-name(.)','varchar(max)') Path + , v.value('.', 'varchar(255)') Value + FROM Formats + CROSS APPLY Data.nodes('//*/@*') TempXML(v) + OUTER APPLY v.nodes('..') TempXML1(v1) + OUTER APPLY v1.nodes('..') TempXML2(v2) + OUTER APPLY v2.nodes('..') TempXML3(v3) + OUTER APPLY v3.nodes('..') TempXML4(v4) + OUTER APPLY v4.nodes('..') TempXML5(v5) + OUTER APPLY v5.nodes('..') TempXML6(v6) + OUTER APPLY v6.nodes('..') TempXML7(v7) + OUTER APPLY v7.nodes('..') TempXML8(v8) + OUTER APPLY v8.nodes('..') TempXML9(v9) + where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' + OR v.value('.', 'varchar(255)') like '%' + @find + '%' + UNION + Select FormatID, Name, Description, + case when v9.exist('.') is null THEN '' ELSE v9.value('local-name(.)','varchar(max)') + '/' END + + case when v8.exist('.') is null THEN '' ELSE v8.value('local-name(.)','varchar(max)') + '/' END + + case when v7.exist('.') is null THEN '' ELSE v7.value('local-name(.)','varchar(max)') + '/' END + + case when v6.exist('.') is null THEN '' ELSE v6.value('local-name(.)','varchar(max)') + '/' END + + case when v5.exist('.') is null THEN '' ELSE v5.value('local-name(.)','varchar(max)') + '/' END + + case when v4.exist('.') is null THEN '' ELSE v4.value('local-name(.)','varchar(max)') + '/' END + + case when v3.exist('.') is null THEN '' ELSE v3.value('local-name(.)','varchar(max)') + '/' END + + case when v2.exist('.') is null THEN '' ELSE v2.value('local-name(.)','varchar(max)') + '/' END + + case when v1.exist('.') is null THEN '' ELSE v1.value('local-name(.)','varchar(max)') + '/' END + + + v.value('local-name(.)','varchar(max)') Path + , '{node}' + FROM Formats + CROSS APPLY Data.nodes('//*') TempXML(v) + OUTER APPLY v.nodes('..') TempXML1(v1) + OUTER APPLY v1.nodes('..') TempXML2(v2) + OUTER APPLY v2.nodes('..') TempXML3(v3) + OUTER APPLY v3.nodes('..') TempXML4(v4) + OUTER APPLY v4.nodes('..') TempXML5(v5) + OUTER APPLY v5.nodes('..') TempXML6(v6) + OUTER APPLY v6.nodes('..') TempXML7(v7) + OUTER APPLY v7.nodes('..') TempXML8(v8) + OUTER APPLY v8.nodes('..') TempXML9(v9) + where v.value('local-name(.)', 'varchar(255)') like '%' + @find + '%' + RETURN +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetFormatField Succeeded' +ELSE PRINT 'TableFunction Creation: vefn_GetFormatField Error on Creation' +GO + /****** Object: StoredProcedure [vefn_GetFormatValues] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetFormatValues]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetFormatValues]; @@ -10963,6 +11904,123 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetFormatValues Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetFormatValues Error on Creation' GO +/****** Object: StoredProcedure [vefn_GetInheritedFormat] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetInheritedFormat]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_GetInheritedFormat]; +GO + +/* Samples +Select TranType, .dbo.vefn_GetInheritedFormat(355) TransFormat + from(Select 1 TranType UNION Select 2 TranType UNION Select 3 TranType UNION + Select 4 TranType UNION Select 5 TranType UNION Select 6 TranType UNION + Select 7 TranType UNION Select 8 TranType UNION Select 9 TranType UNION Select 10 TranType) TT + +Select top 25 ItemID, TranType, .dbo.vefn_GetInheritedFormat(ItemID) TransFormat + From Transitions TR + Join Items II on II.ContentID = TR.FromID + +*/ +/* + local is a 'boolean' (0=false, 1=true) to state whether to look at the item itself or + only its parent +*/ +CREATE FUNCTION [dbo].[vefn_GetInheritedFormat] (@ItemID int, @local int) RETURNS int +WITH EXECUTE AS OWNER +AS +BEGIN + DECLARE @FormatID as int + -- First get the Active Format + begin + with Itemz([Level], [PreviousID], [ItemID], [ParentID], [FolderID], [FormatID]) as ( + Select 0 [Level], [PreviousID], [ItemID], null, null, + case when @local = 1 then (Select FormatID from Contents CC where [CC].[ContentID] = [II].[ContentID]) + else null end FormatID + FROM [Items] II + where [ItemID]=@ItemID + Union All + -- Parent Item + select [Level] + 1, I.[PreviousID], I.[ItemID], null, null, C.FormatID + from Itemz Z + join Parts P on P.ItemID = Z.ItemID + join Items I on I.ContentID = P.ContentID + join Contents C on C.ContentID = P.ContentID + where Z.FormatID is null + -- Siblings Item + Union All + select [Level] , I.[PreviousID] , I.[ItemID], null, null, Z.FormatID + from Itemz Z + join Items I on Z.PreviousID = I.ItemID + where Z.FormatID is null + Union All + -- DocVersion From Item + select [Level] + 1, null, null, DV.FolderID, null, DV.FormatID + from Itemz Z + join DocVersions DV on DV.ItemID = Z.ItemID + where Z.FormatID is null + Union All + -- Folders + select [Level] + 1, null, null, FF.ParentID, FF.FolderID, FF.FormatID + from Itemz Z + join Folders FF on FF.FolderID = Z.ParentID and FF.ParentID <> FF.FolderID + where Z.FormatID is null + ) + Select @FormatID = FormatID from Itemz ZZ Where FormatID is not null + + RETURN @FormatID + END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_GetInheritedFormat Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_GetInheritedFormat Error on Creation' +GO + +/****** Object: StoredProcedure [vefn_GetNewTranType] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetNewTranType]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_GetNewTranType]; +GO + +/* Samples + +SELECT .dbo.[vefn_GetNewTranType] (1, 2, 6) +SELECT .dbo.[vefn_GetNewTranType] (1, 2, 7) +SELECT .dbo.[vefn_GetNewTranType] (27, 29, 10) +SELECT .dbo.[vefn_GetNewTranType] (29, 27, 10) +SELECT .dbo.[vefn_GetNewTranType] (27, 31, 10) +--SELECT .dbo.[vefn_GetNewTranType] (29, 27, 10) + +*/ +CREATE FUNCTION [dbo].[vefn_GetNewTranType] (@FormatID int, @NewFormatID int, @TranType int) RETURNS int +WITH EXECUTE AS OWNER +AS +BEGIN + -- + IF @FormatID = @NewFormatID + RETURN @TranType + DECLARE @TransFormat varchar(max) + DECLARE @NewTransFormat varchar(max) + SET @TransFormat = isnull(.dbo.vefn_GetTransFormat(@FormatID, @TranType),'') + SET @NewTransFormat = isnull(.dbo.vefn_GetTransFormat(@NewFormatID, @TranType),'') + RETURN CASE + WHEN @TransFormat = @NewTransFormat THEN @TranType + WHEN @TransFormat LIKE '%{Last Step}%' THEN + CASE + WHEN @NewTransFormat LIKE '%{Last Step}%' THEN @TranType + ELSE 3 -- This is a default 'range' type, all transition formats have it! + END + ELSE + CASE + WHEN @NewTransFormat LIKE '%{Last Step}%' THEN 0 + ELSE @TranType -- This is a default 'single' type, all transition formats have it! + END + END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_GetNewTranType Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_GetNewTranType Error on Creation' +GO + /****** Object: StoredProcedure [vefn_GetNullFormatValues] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetNullFormatValues]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetNullFormatValues]; @@ -11005,6 +12063,84 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetNullFormatValues Succeed ELSE PRINT 'TableFunction Creation: vefn_GetNullFormatValues Error on Creation' GO +/****** Object: StoredProcedure [vefn_GetTokens] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetTokens]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_GetTokens]; +GO + +/* +select * from vefn_GetTokens('abc{Header1}def{Header2}ghi') +*/ +CREATE FUNCTION [dbo].[vefn_GetTokens](@text varchar(64)) +RETURNS @Tokens TABLE +( + Token varchar(64) +) +WITH EXECUTE AS OWNER +AS +BEGIN +DECLARE @index int +SET @index = -1 +WHILE (LEN(@text) > 0) + BEGIN + SET @index = CHARINDEX('{' , @text) + IF @index = 0 + BREAK + DECLARE @index2 int + SET @index2 = CHARINDEX('}' , @text) + if @index2 = 0 + BREAK + INSERT INTO @Tokens VALUES (substring(@text, @index,1+@index2-@index)) + SET @text = RIGHT(@text, (LEN(@text) - @index2)) + END + RETURN +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetTokens Succeeded' +ELSE PRINT 'TableFunction Creation: vefn_GetTokens Error on Creation' +GO + +/****** Object: StoredProcedure [vefn_GetTransFormat] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetTransFormat]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_GetTransFormat]; +GO + +/* Samples +select .dbo.vefn_GetTransFormat(1,6) +select .dbo.vefn_GetTransFormat(1,1) +select .dbo.vefn_GetTransFormat(1,2) +select .dbo.vefn_GetTransFormat(1,3) + +*/ +CREATE FUNCTION [dbo].[vefn_GetTransFormat] (@FormatID int, @TranType int) RETURNS varchar(max) +WITH EXECUTE AS OWNER +AS +BEGIN + + -- Walk up the Formats (inheritance) looking for the TransFormat + Declare @TransFormat as varchar(MAX) + BEGIN + with Formatz([MyOrder],[FormatID],[ParentID],[Data]) as ( + Select 0,FormatID, ParentID, Data From Formats where FormatID=@FormatID + Union All + Select [MyOrder]+1,FF.FormatID, FF.ParentID, FF.Data From Formats FF + Join Formatz ZZ on ZZ.ParentID=FF.FormatID + Where ZZ.FormatID <> ZZ.ParentID) + Select Top 1 @TransFormat=v.value('./@TransFormat', 'varchar(MAX)') + FROM Formatz + CROSS APPLY Data.nodes('//TransTypes') TempXML(v) + where v.value('./@TransType', 'int')=@TranType + order by [MyOrder] + END + return @TransFormat +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_GetTransFormat Succeeded' +ELSE PRINT 'ScalarFunction Creation: vefn_GetTransFormat Error on Creation' +GO + /****** Object: StoredProcedure [vefn_HighLevelStepTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_HighLevelStepTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_HighLevelStepTransitions]; @@ -11592,6 +12728,81 @@ IF (@@Error = 0) PRINT 'Procedure Creation: vesp_CleanUpItems Succeeded' ELSE PRINT 'Procedure Creation: vesp_CleanUpItems Error on Creation' GO +/****** Object: StoredProcedure [vesp_GetFormatFields] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetFormatFields]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [vesp_GetFormatFields]; +GO + +/* +vesp_GetFormatFields 'PrintNoTitle' +vesp_GetFormatFields 'Sep' +vesp_GetFormatFields 'TabFormat' +vesp_GetFormatFields 'ShowSectionTitles' +vesp_GetFormatFields 'Caution' +vesp_GetFormatFields 'Ident' +*/ + +CREATE PROCEDURE [dbo].[vesp_GetFormatFields] +( + @find varchar(255) +) +WITH EXECUTE AS OWNER +AS +BEGIN + declare @pivotlist varchar(max) + select @pivotlist = stuff((select distinct ',[' + [Name] + ']' from vefn_GetFormatField(@find) + order by ',[' + [Name] + ']' for xml path('')),1,1,'') + DECLARE @query VARCHAR(max) + SET @query = 'SELECT * FROM (Select Name,''Format Description'' Path,'''' Value, Description From Formats) T1 PIVOT ( Max(Description) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' + EXECUTE(@query) + SET @query = 'SELECT * FROM (Select Name,''FormatID'' Path,'''' Value, FormatID From Formats) T1 PIVOT ( Max(FormatID) FOR [Name] IN (' + @pivotlist + ') ) As Pivot2' + EXECUTE(@query) + SET @query = 'SELECT * FROM (Select Name,Path,Value From vefn_GetFormatField(''' + @find + ''')) T1 PIVOT ( Count(Name) FOR [Name] IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,VALUE' + print @Query + EXECUTE(@query) +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetFormatFields Succeeded' +ELSE PRINT 'Procedure Creation: vesp_GetFormatFields Error on Creation' +GO + +/****** Object: StoredProcedure [vesp_GetFormatGroupFields] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetFormatGroupFields]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [vesp_GetFormatGroupFields]; +GO + +/* +vesp_GetFormatGroupFields 'PrintNoTitle' +vesp_GetFormatGroupFields 'Sep' +vesp_GetFormatGroupFields 'TabFormat' +vesp_GetFormatGroupFields 'ShowSectionTitles' +vesp_GetFormatGroupFields 'Caution' +vesp_GetFormatGroupFields 'Ident' +vesp_GetFormatGroupFields 'SectionTitleLen' +*/ + +CREATE PROCEDURE [dbo].[vesp_GetFormatGroupFields] +( + @find varchar(255) +) +WITH EXECUTE AS OWNER +AS +BEGIN + declare @pivotlist varchar(max) + select @pivotlist = stuff((select distinct ',[' + substring([Name],1,3) + ']' from vefn_GetFormatField(@find) + order by ',[' + substring([Name],1,3) + ']' for xml path('')),1,1,'') + DECLARE @query VARCHAR(max) + SET @query = 'SELECT * FROM (Select substring([Name],1,3) FormatGroup,Path,Value From vefn_GetFormatField(''' + @find + ''')) T1 PIVOT ( Count(FormatGroup) FOR FormatGroup IN (' + @pivotlist + ') ) AS Pivot1 ORDER BY PATH,VALUE' + print @Query + EXECUTE(@query) +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetFormatGroupFields Succeeded' +ELSE PRINT 'Procedure Creation: vesp_GetFormatGroupFields Error on Creation' +GO + /****** Object: StoredProcedure [vesp_ListChildren] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListChildren];