Set NoCount On; If (db_name() in('master','model','msdn','tempdb')) begin DECLARE @ErrorMsg varchar(255) SET @ErrorMsg = 'Don''t add these procedures and functions to ' + db_name() PRINT '==========================================================================' PRINT '' PRINT @ErrorMsg PRINT '' PRINT 'You probably want to be in the VEPROMS database' PRINT '' PRINT '==========================================================================' RAISERROR (@ErrorMsg, 20, -1) with log RETURN end print 'Adding procedures and functions to ' + db_name() IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemReplace]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [PasteItemReplace]; GO /****** Object: StoredProcedure [dbo].[PasteItemReplace] Script Date: 03/20/2012 16:02:54 ******/ /* declare @NewItemID int declare @dts datetime set @newitemid = 0 set @dts = getdate() exec PasteItemReplace 398,397,20014,@dts,'bodine',@NewItemID output */ -- ItemID is item to replace -- StartItemID is item to copy /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 ) if exists (select * from tblitems where itemid = @ItemID and DeleteStatus !=0) BEGIN RAISERROR ('###Cannot Paste Step###This current step has been deleted in another session',16,1) RETURN END -- 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 DECLARE @DeleteID int INSERT INTO DeleteLog (UserID) VALUES (@UserID) SELECT @DeleteID = SCOPE_IDENTITY() 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) OPTION (MAXRECURSION 10000) 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 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) --delete from itemaudits where itemid = @newitemid delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid)) --delete from contentaudits where contentid = (select contentid from items where itemid = @newitemid) delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid)) DELETE from DeleteLog where DeleteID = @DeleteID 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 IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChronologyReport]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChronologyReport]; /****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 03/20/2012 17:50:44 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_chronologyreport(2) where type > 0 order by contentid,auditid */ /****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 05/18/2011 11:20:48 ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE function [dbo].[vefn_ChronologyReport](@ProcItemID int, @DTS datetime) returns @Report table ( src int, AuditID bigint, ContentID int, Number nvarchar(512), Text nvarchar(max), Type int, FormatID int, Config nvarchar(max), DTS datetime, UserID nvarchar(200), DeleteStatus int, ActionDTS datetime, ItemDTS datetime, LastAuditID int, DeletedAuditID int ) WITH EXECUTE AS OWNER AS BEGIN --added rhm/jcb 20121218i declare @tmpTable table ( icontentid int primary key ) insert into @tmpTable select icontentid from vefn_tblchilditems(@ProcItemID,@ProcItemID,1) --added jcb 20111122 --declare @dts datetime --set @dts = (select dts from items where itemid = @ProcItemID ) --set @dts = (SELECT .[dbo].[vefn_GetPreviousRevisionDTSByItemID] (@ProcItemID)) --end added jcb 20111122 insert into @Report SELECT 1 src, [AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid where Number is not null --added jcb 20111028_1827 and ca.contentid != (select contentid from items where itemid = @procitemid) and ca.contentid in (select icontentid from @tmpTable) --end added jcb 20111028_1827 --added jcb 20111122 --and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID )) and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > @dts) --and ca.dts > (select dts from items where itemid = @ProcItemID ) and ca.dts > @dts --end added jcb 20111122 -- UNION -- SELECT --2 src, -- cast(ident_current('contentaudits') + 1 as bigint) auditid ---- (select max(auditid) + 1 from contentaudits) [AuditID] ---- 0 [AuditID] -- ,ca.[ContentID] -- ,[Number] -- ,[Text] -- ,[Type] -- ,[FormatID] -- ,[Config] -- ,ca.[DTS] cadts -- ,ca.[UserID] -- ,ca.[DeleteStatus] -- ,ActionDTS -- ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS --,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID --,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID -- FROM tblContents ca ---- inner join tblitems ti on ca.contentid = ti.contentid --WHERE ca.DeleteStatus = 0 AND ----added jcb 20111028_1827 --ca.contentid != (select contentid from items where itemid = @procitemid) and ----end added jcb 20111028_1827 ----ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID )) ----added jcb 20111122 ----ca.ContentID in (SELECT [ContentID] FROM Contents where dts > (select dts from items where itemid = @ProcItemID )) --ca.ContentID in (SELECT [ContentID] FROM Contents where dts > @dts) ----end added jcb 20111122 ----order by ca.DTS,ActionDTS UNION SELECT 3 src, cast(ident_current('contentaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from contentaudits) [AuditID] -- 0 [AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM tblContents ca -- inner join tblitems ti on ca.contentid = ti.contentid WHERE ca.DeleteStatus = 0 AND --added jcb 20111028_1827 ca.contentid != (select contentid from items where itemid = @procitemid) and ca.contentid in (select icontentid from @tmpTable) --end added jcb 20111028_1827 --added jcb 20111122 --ca.dts > (select dts from items where itemid = @ProcItemID ) and (ca.dts > @dts or ca.actiondts > @dts) --end added jcb 20111122 UNION SELECT distinct 5 src, -- cast(ident_current('contentaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from contentaudits) [AuditID] ca.[AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid WHERE ca.DeleteStatus > 0 --added jcb 20111028_1827 --ca.contentid != (select contentid from items where itemid = @procitemid) and --end added jcb 20111028_1827 --added jcb 20111122 --ca.dts > (select dts from items where itemid = @ProcItemID ) and ca.contentid in (select icontentid from @tmpTable) and (ca.dts > @dts or ca.actiondts > @dts) --end added jcb 20111122 order by ca.DTS,ActionDTS insert into @Report SELECT 4 src, ca.[AuditID] ,ca.[ContentID] ,ca.[Number] ,ca.[Text] ,ca.[Type] ,ca.[FormatID] ,ca.[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ca.ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid inner join @Report rpt on ca.contentid = rpt.contentid and ca.auditid = rpt.lastauditid where ca.auditid not in (select auditid from @report) and rpt.lastauditid is not null and ca.contentid in (select icontentid from @tmpTable) return end GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: vefn_ChronologyReport Succeeded' ELSE PRINT 'Function: vefn_ChronologyReport Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingAfter]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [PasteItemSiblingAfter]; GO /****** Object: StoredProcedure [dbo].[PasteItemSiblingAfter] Script Date: 03/21/2012 15:25:31 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 if exists (select * from tblitems where itemid = @ItemID and DeleteStatus !=0) BEGIN RAISERROR ('###Cannot Paste Step###This current step has been deleted in another session',16,1) RETURN END -- 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) OPTION (MAXRECURSION 10000) 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 delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid)) delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid)) 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 IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingBefore]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [PasteItemSiblingBefore]; GO /****** Object: StoredProcedure [dbo].[PasteItemSiblingBefore] Script Date: 03/21/2012 15:26:23 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 if exists (select * from tblitems where itemid = @ItemID and DeleteStatus !=0) BEGIN RAISERROR ('###Cannot Paste Step###This current step has been deleted in another session',16,1) RETURN END -- 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) OPTION (MAXRECURSION 10000) 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 delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid)) delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid)) 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 IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetMyChronology]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetMyChronology]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetMyChronology] Script Date: 11/07/2012 18:09:17 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetMyChronology](@ProcItemID int, @ItemID int, @IncludeDeletedChildren int, @DTS datetime) RETURNS @Chrono TABLE ( [AuditID] bigint, [ContentID] int, [Number] nvarchar(max), [Text] nvarchar(max), [Type] int, [FormatID] int, [Config] nvarchar(max), [DTS] datetime, [UserID] nvarchar(max), [DeleteStatus] int, [ActionDTS] datetime, [ActionWhat] nvarchar(max), [ActionWhen] datetime, [Path] nvarchar(max), ItemID int, TypeName nvarchar(max), ordinalpath nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN insert into @Chrono select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath from ( select case when lastauditid is null then 'Added' when r.deletestatus > 0 then 'Deleted' when lastauditid = -1 then 'Changed' when DeletedAuditID is not null then 'Restored' -- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' else 'Changed' end actionwhat ,actiondts actionwhen -- ,case -- when lastauditid is null then dts -- when r.deletestatus > 0 then ActionDTS -- when lastauditid = -1 then dts -- when DeletedAuditID is not null then ActionDTS -- else dts -- end actionwhen ,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName ,* from vefn_tblchilditems (@ProcItemID,@ItemID,@IncludeDeletedChildren) t inner join vefn_chronologyreport(@ProcItemID,@DTS) r on t.icontentid = r.contentid -- where ActionDTS > procdts or dts > procdts ) ah order by OrdinalPath, contentid,auditid--actionwhen RETURN END go IF (@@Error = 0) PRINT 'TableFunction [vefn_GetMyChronology] Succeeded' ELSE PRINT 'TableFunction [vefn_GetMyChronology] Error on Creation' go /****** Object: StoredProcedure [dbo].[getContentAuditsChronologyByItemID] Script Date: 03/21/2012 15:58:26 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getContentAuditsChronologyByItemID]; GO /****** Object: StoredProcedure [getContentAuditsChronologyByItemID] ******/ /* getContentAuditsChronologyByItemID 10154,10154,0 getContentAuditsChronologyByItemID 42,42,0 getContentAuditsChronologyByItemID 9,9,0 getContentAuditsChronologyByItemID 146,146,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemID] ( @ProcedureItemID int, @SelectedItemID int, @IncludeDeletedChildren int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) -- select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah -- order by OrdinalPath, contentid,auditid--actionwhen RETURN end go -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getContentAuditsChronologyByItemID] Succeeded' ELSE PRINT 'StoredProcedure [getContentAuditsChronologyByItemID] Error on Creation' go /****** Object: StoredProcedure [getContentAuditsSummaryByItemID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsSummaryByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getContentAuditsSummaryByItemID]; GO /****** Object: StoredProcedure [getContentAuditsSummaryByItemID] ******/ /* getContentAuditsSummaryByItemID 146,146,0 getContentAuditsSummaryByItemID 42,42,0 getContentAuditsSummaryByItemID 9,9,0 getContentAuditsSummaryByItemID 146,146,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getContentAuditsSummaryByItemID] ( @ProcedureItemID int, @SelectedItemID int, @IncludeDeletedChildren int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin DECLARE @Chrono TABLE ( [AuditID] bigint, [ContentID] int, [Number] nvarchar(max), [Text] nvarchar(max), [Type] int, [FormatID] int, [Config] nvarchar(max), [DTS] datetime, [UserID] nvarchar(max), [DeleteStatus] int, [ActionDTS] datetime, [ActionWhat] nvarchar(max), [ActionWhen] datetime, [Path] nvarchar(max), ItemID int, TypeName nvarchar(max), ordinalpath nvarchar(max) ) insert into @Chrono select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) select * from @Chrono where AuditID is null OR AuditID in (select min(auditID) from @Chrono group by contentid UNION select max(auditID) from @Chrono group by contentid) order by OrdinalPath, contentid,auditid --select z.* from --( --select contentid,min(auditid) auditid from --( -- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah --) x --group by contentid --) y --inner join --( -- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah --) z on y.contentid = z.contentid and y.auditid = z.auditid --union --select z.* from --( --select contentid,max(auditid) auditid from --( -- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah --) x --group by contentid --) y --inner join --( -- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah --) z on y.contentid = z.contentid and y.auditid = z.auditid -- order by OrdinalPath, contentid,auditid--actionwhen RETURN end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getContentAuditsSummaryByItemID Succeeded' ELSE PRINT 'Procedure Creation: getContentAuditsSummaryByItemID Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixSearchString]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_FixSearchString]; GO /****** Object: UserDefinedFunction [dbo].[vefn_FixSearchString] Script Date: 03/26/2012 09:31:13 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select ID,ss,.dbo.vefn_FixSearchString(ss) from ( select 1 ID,'*' ss union select 2 ID,'50%' ss union select 3 ID,'IF*' ss union select 4 ID,'*then:' ss union select 5 ID,'530`F' ss union select 6 ID,'check' ss union select 7 ID,'RCP*Cooling' ss union select 8 ID,'14%[34%]' ss union select 9 ID,'\*' ss union select 10 ID,'\?' ss union select 11 ID,'_' ss union select 12 ID,'[' ss union select 13 ID,']' ss union select 14 ID,'%' ss union select 15 ID,'_' ss union select 16 ID,'-' ss union select 17 ID,'%' ss union select 18 ID,'C* - *' ss union select 19 ID,'' ss union select 20 ID,null ss ) tt order by ID */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FixSearchString](@SearchString nvarchar(MAX)) RETURNS nvarchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- This code adds % at the beginning and end if the beginning and end -- of the search string if it does not have % at the beginning or end Set @SearchString = replace(@SearchString,'[','[[]') Set @SearchString = replace(@SearchString,'_','[_]') Set @SearchString = replace(@SearchString,'%','[%]') Set @SearchString = replace(@SearchString,'*','%') Set @SearchString = replace(@SearchString,'?','_') Set @SearchString = replace(@SearchString,'\%','*') Set @SearchString = replace(@SearchString,'\_','?') Set @SearchString = replace(@SearchString,'-','\u8209?') Set @SearchString = replace(@SearchString,'\''A9','\u169?') -- copyright symbol Set @SearchString = replace(@SearchString,'\''AE','\u174?') -- Register symbol Set @SearchString = replace(@SearchString,'\\line ','\line ') -- newline Set @SearchString = replace(@SearchString,'\\','\u9586?') -- use a double backslash to search for a backslash IF(@SearchString like '[%]%') RETURN @SearchString IF(@SearchString like '%[%]') RETURN @SearchString Set @SearchString = replace('%' + @SearchString + '%','%%','%') RETURN @SearchString END GO -- Display the status IF (@@Error = 0) PRINT 'ScalerFunction [vefn_FixSearchString] Succeeded' ELSE PRINT 'ScalerFunction [vefn_FixSearchString] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[restoreDeletedItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [restoreDeletedItem]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* restoreDeletedItem 10133,1,10130,2 select dbo.ve_GetPartContentID(10133) select dbo.ve_GetPartFromType(10133) select itemid from parts where contentid = 10126 and fromtype = 6 SELECT ItemID FROM PartAudits WHERE DeleteStatus = 1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[restoreDeletedItem] ( @ItemID int, @DeleteID int, @CurrentID int, @Level int ) WITH EXECUTE AS OWNER AS DECLARE @PreviousID int declare @oldPreviousID int DECLARE @NextID int DECLARE @ContentID int declare @fromtype int IF @Level = 0 BEGIN SET @NextID = @CurrentID SELECT @PreviousID = PreviousID FROM Items WHERE ItemID = @CurrentID END IF @Level = 1 BEGIN SELECT @NextID = ItemID FROM Items WHERE PreviousID = @CurrentID SET @PreviousID = @CurrentID END SELECT @ContentID = dbo.[ve_GetPartContentID](@ItemID) select @fromtype = dbo.[ve_GetPartFromType](@ItemID) select @oldPreviousID = isnull(PreviousID,0) from tblItems where ItemID = @ItemID if @level = 2 begin select @NextID = itemid from parts where contentid = @contentid and fromtype = @fromtype end --restore parts from step being restored UPDATE tblParts SET DeleteStatus = 0 WHERE ItemID IN (SELECT ItemID FROM PartAudits WHERE DeleteStatus = @DeleteID) --print 'oldpreviousid: ' + cast(@oldpreviousid as varchar(10)) --print 'currentid: ' + cast(@currentid as varchar(10)) --restore of children in different order if(@oldPreviousID != @CurrentID and @Level = 2) begin update tblparts set deletestatus = 0, itemid = @itemid where contentid = @contentid and fromtype = @fromtype --print 'special code' end UPDATE tblContents SET DeleteStatus = 0, ActionDTS = getdate() WHERE ContentID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) UPDATE tblItems SET DeleteStatus = 0,PreviousID = CASE WHEN ItemID = @ItemID THEN @PreviousID ELSE PreviousID END WHERE ItemID IN (SELECT ItemID FROM ItemAudits WHERE DeleteStatus = @DeleteID) UPDATE tblGrids SET DeleteStatus = 0 WHERE ContentID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) UPDATE tblImages SET DeleteStatus = 0 WHERE ContentID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) UPDATE tblEntries SET DeleteStatus = 0 WHERE DocID IN (SELECT DocID FROM EntryAudits WHERE DeleteStatus = @DeleteID) UPDATE tblAnnotations SET DeleteStatus = 0, ActionDTS = getdate() WHERE deletestatus = @deleteid -- ItemID in (SELECT ItemID FROM ItemAudits WHERE DeleteStatus = @DeleteID) UPDATE tblROUsages SET DeleteStatus = 0 WHERE deletestatus = @deleteid --ContentID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) UPDATE tblTransitions SET DeleteStatus = 0 WHERE deletestatus = @deleteid --FromID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) IF @NextID IS NOT NULL BEGIN UPDATE Items SET PreviousID = @ItemID WHERE ItemID = @NextID UPDATE DocVersions SET ItemID = @ItemID WHERE ItemID = @NextID IF @ContentID IS NOT NULL BEGIN UPDATE Parts SET ItemID = @ItemID WHERE ItemID = @NextID and ContentID = @ContentID --print 'old code' END END --else -- begin --update parts set itemid = @itemid where contentid = @contentid and fromtype = @fromtype -- end RETURN go -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: restoreDeletedItem Succeeded' ELSE PRINT 'Procedure Creation: restoreDeletedItem Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetLastDelim] Script Date: 03/28/2012 17:58:48 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetLastDelim]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_GetLastDelim]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select .dbo.vefn_GetLastDelim(bozo) delim,bozo from ( select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using Backfill' bozo union select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps' bozo union select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1' bozo union select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1' bozo union select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1.RNO..1' bozo union select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1.RNO..1.3' bozo ) ah */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetLastDelim](@SearchString nvarchar(MAX)) RETURNS nvarchar(1) WITH EXECUTE AS OWNER AS BEGIN declare @patstr nvarchar(7) set @patstr = '%[' + char(7) + char(17) + '.]%' declare @patidx bigint set @patidx = patindex(@patstr,Reverse(@SearchString)) if @patidx = 0 return ' ' return substring(@SearchString,1 + len(@SearchString) - @patidx,1) END GO IF (@@Error = 0) PRINT 'ScalerFunction [vefn_GetLastDelim] Succeeded' ELSE PRINT 'ScalerFunction [vefn_GetLastDelim] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_tblChildItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_tblChildItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_tblChildItems] Script Date: 03/28/2012 17:43:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* declare @PreviousID as int declare @ItemID as int set @ItemID = 450 select @PreviousID = PreviousID from items where ItemID = @ItemID Select * from Items where ItemID = @ItemID select * from Transitions where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) select CC.Text from Transitions TT join contents CC on TT.FromID = CC.ContentID where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_tblChildItems](@ProcItemID int, @ItemID int, @IncludeDeletedChildren int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, IContentID int, IDeleteStatus int, ProcDTS datetime, Path nvarchar(max), OrdinalPath nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN declare @path nvarchar(max) declare @ppath nvarchar(max) declare @ordinalpath nvarchar(max) declare @pordinalpath nvarchar(max) declare @ordinal int declare @pitemid int select @path = path,@ordinalpath = ordinalpath,@ordinal = ordinal,@pitemid = parentid from vefn_ProcedureByProcID(@ProcItemID) where itemid = @ItemID if @pitemid = 0 begin set @pordinalpath = '' set @ppath = '' end else begin select @ppath = path,@pordinalpath = ordinalpath from vefn_ProcedureByProcID(@ProcItemID) where itemid = @pitemID end declare @procdts datetime select @procdts = dts from items where itemid = @ProcItemID Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' begin with Itemz([Level], [ItemID], [ContentID], DeleteStatus, ProcDTS, PPath, [Path], [POrdinalPath], [OrdinalPath], [FromType], [Ordinal]) as ( Select 0 [Level], [ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, @ppath [PPath], @path [Path], @pordinalpath [POrdinalPath], @ordinalpath [OrdinalPath], 0 [FromType],@ordinal [Ordinal] FROM [tblItems] I --inner join tblContents C on C.ContentID=I.ContentID where I.[ItemID]=@ItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + case when I.deletestatus != 0 then 'Old ' else '' end + cast(1 as varchar(4)) end end Path, OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001', P.[FromType],0 from Itemz Z join tblParts P on P.ContentID = Z.ContentID join tblItems I on I.ItemID = P.ItemID inner join tblContents C on C.ContentID=I.ContentID where @IncludeDeletedChildren = 1 or z.DeleteStatus = 0 Union All -- Children2 select [Level] + 1, I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + case when I.deletestatus != 0 then 'Old ' else '' end + cast(1 as varchar(4)) end end Path, OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001', P.[FromType],0 from Itemz Z join PartAudits P on P.ContentID = Z.ContentID join tblItems I on I.ItemID = P.ItemID and i.PreviousID is null inner join tblContents C on C.ContentID=I.ContentID where @IncludeDeletedChildren = 1 or z.DeleteStatus >= 0 -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + case when I.deletestatus != 0 then 'Old ' else '' end + cast(Ordinal + 2 as varchar(4)) end Path, POrdinalPath, POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), FromType,Z.[Ordinal] +1 from Itemz Z join tblItems I on I.PreviousID = Z.ItemID inner join tblContents C on C.ContentID=I.ContentID where Z.[Level] > 0 ) insert into @Children select distinct ItemID, ContentID, DeleteStatus, ProcDTS, Path, OrdinalPath from Itemz OPTION (MAXRECURSION 10000) END RETURN end go IF (@@Error = 0) PRINT 'TableFunction [vefn_tblChildItems] Succeeded' ELSE PRINT 'TableFunction [vefn_tblChildItems] Error on Creation' go /****** Object: StoredProcedure [dbo].[getAnnotationAuditsChronologyByItemID] Script Date: 04/02/2012 15:57:32 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAnnotationAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAnnotationAuditsChronologyByItemID]; GO /****** Object: StoredProcedure [getAnnotationAuditsChronologyByItemID] ******/ /* getAnnotationAuditsChronologyByItemID 13,13 getAnnotationAuditsChronologyByItemID 30,8570 getAnnotationAuditsChronologyByItemID 30,8513 getAnnotationAuditsChronologyByItemID 30,8505 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE procedure [dbo].[getAnnotationAuditsChronologyByItemID] ( @ProcItemID int, @ItemID int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin -- declare @dts datetime -- set @dts = (select dts from items where itemid = @procitemid) declare @tci table ( ItemID int, IContentID int, IDeleteStatus int, ProcDTS datetime, Path nvarchar(max), OrdinalPath nvarchar(max) ) insert into @tci select * from vefn_tblchilditems(@ProcItemID,@ItemID,0) select case when lastauditid is null and dts > itemdts then 'Added' when deletestatus > 0 then 'Deleted' when lastauditid = deletedauditid then 'Restored' else 'Changed' end ActionWhat ,case when lastauditid is null and dts > itemdts then dts when deletestatus > 0 then ActionDTS when lastauditid = deletedauditid then ActionDTS else dts end ActionWhen ,* from ( select cast(ident_current('annotationaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from annotationaudits) auditid -- 0 auditid ,aa.annotationid ,aa.itemid ,aa.typeid ,aa.rtftext ,aa.searchtext ,aa.config ,aa.dts ,aa.userid ,0 deletestatus ,aa.ActionDTS ,ii.contentid icontentid ,(select min(dts) from tblitems where itemid = ii.itemid) ItemDTS ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid) LastAuditID ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and deletestatus > 0 and aa.dts = dts) DeletedAuditID ,tci.ordinalpath from tblannotations aa inner join items ii on aa.itemid = ii.itemid join @tci tci on tci.itemid = ii.itemid where aa.deletestatus = 0 union select aa.auditid ,aa.annotationid ,aa.itemid ,aa.typeid ,aa.rtftext ,aa.searchtext ,aa.config ,aa.dts ,aa.userid ,aa.deletestatus ,aa.ActionDTS ,ii.contentid icontentid ,(select min(dts) from tblitems where itemid = ii.itemid) ItemDTS ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and aa.auditid > auditid ) LastAuditID ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and aa.auditid > auditid and deletestatus > 0 and aa.dts = dts) DeletedAuditID ,tci.ordinalpath from annotationaudits aa inner join items ii on aa.itemid = ii.itemid join @tci tci on tci.itemid = ii.itemid ) ah where itemid in (select itemid from @tci) and dts > @dts --(select dts from versions where versionid = (select max(versionid) from revisions rr inner join versions vv on rr.revisionid = vv.revisionid --inner join stages ss on vv.stageid = ss.stageid where itemid = @procitemid and ss.isapproved = 1)) order by ordinalpath,annotationid,auditid--actionwhen end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemID Succeeded' ELSE PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemID Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[ve_GetFolderPath]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [dbo].[ve_GetFolderPath]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Rich Mark Create Date: 01/01/2012 Description: Returns the Folder Path for a specified Document Version using recursion 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement Parameters: @VersionID Document Version ID Examples: Select VersionID,Name,dbo.ve_GetFolderPath(VersionID) from DocVersions order by VersionID; ========================================================================================================== */ Create Function [dbo].[ve_GetFolderPath] (@VersionID int) Returns VarChar(Max) With Execute as Owner as Begin Declare @Path VarChar(Max); With zFolders ([Level], FolderID, [Path]) as ( Select 1 as 'Level', dv.FolderID as 'FolderID', Cast(dv.[Name] as VarChar(Max)) as 'Path' From DocVersions dv with (NoLock) Where dv.VersionID = @VersionID Union All Select f.ParentID - (Select ParentID from Folders where FolderID = f.ParentID) as 'Level', f.ParentID as 'FolderID', Cast(f.[Name] + char(7) + zf.[Path] as VarChar(Max)) as 'Path' From Folders f with (NoLock) inner join zFolders zf on f.FolderID = zf.FolderID Where f.FolderID <> f.ParentID ) Select @Path = zf.[Path] From zFolders zf Where zf.[Level] = 0; return @Path; End Go IF (@@Error = 0) PRINT 'Function: [vefn_GetUnitPrefix] Succeeded' ELSE PRINT 'Function: [vefn_GetUnitPrefix] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [dbo].[vefn_GetUnitPrefix]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Rich Mark Create Date: 01/01/2012 Description: Returns the Unit Prefix from the specified Xml Configuration Data 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement Parameters: @Config Xml Configuration Data Examples: Select 'DocVersions' Type, VersionID, Config, .dbo.vefn_GetUnitPrefix(config) UnitPrefix from DocVersions UNION select 'Blank' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix UNION select 'Null' Type, 0 VersionID, null Config, .dbo.vefn_GetUnitPrefix(null) UnitPrefix UNION select 'XML with' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix UNION select 'XML without' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix UNION select 'XML empty' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix ========================================================================================================== */ Create Function [dbo].[vefn_GetUnitPrefix](@Config varchar(MAX)) Returns VarChar(Max) With Execute as Owner as Begin Declare @Xml xml; Declare @UnitPrefix VarChar(Max); Set @Xml = Cast(@Config as xml) Set @UnitPrefix = (Select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') as 'UnitPrefix' From @XML.nodes('//Unit') as tmpXml(v)) Return IsNull(@UnitPrefix,''); End Go IF (@@Error = 0) PRINT 'Function: [vefn_GetUnitPrefix] Succeeded' ELSE PRINT 'Function: [vefn_GetUnitPrefix] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [dbo].[vefn_DocVersionSplit]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Rich Mark Create Date: 01/01/2012 Description: Returns a table of document version info from a comma delimited list of specified document version IDs 08/20/2021 Jake Ropar: Add with (NoLock) statements to prevent table locking Parameters: @DocVersionList Comma delimited list of document version IDs (pass '' or null to retrieve all versions) Examples: select * from vefn_DocVersionSplit('1,4'); select * from vefn_DocVersionSplit(null); select * from vefn_DocVersionSplit(''); ========================================================================================================== */ Create Function [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX)) Returns @IDs Table ( VersionID Int Primary Key, ItemID Int, DVPath VarChar(Max), UnitPrefix VarChar(MAX) ) With Execute as Owner as Begin If(IsNull(@DocVersionList,'') = '') Insert into @IDs Select dv.VersionID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), dbo.vefn_GetUnitPrefix(dv.Config) From DocVersions dv with (NoLock) Where dv.ItemID is not null; Else Insert into @IDs Select t.ID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), .dbo.vefn_GetUnitPrefix(dv.config) From dbo.vefn_SplitInt(@DocVersionList,',') as t inner join DocVersions dv with (NoLock) on dv.VersionID = t.ID; Return; End Go IF (@@Error = 0) PRINT 'Function: [vefn_DocVersionSplit] Succeeded' ELSE PRINT 'Function: [vefn_DocVersionSplit] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vefn_SiblingAndChildrenItemsNewByWord]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [dbo].[vefn_SiblingAndChildrenItemsNewByWord]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Rich Mark Create Date: 01/01/2021 Description: Returns all items mathcing the specified search critera, filtered by a list of specified document versions 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions) @UnitPrefix The unit prefix to use when building the item path @SearchString Search string criteria @SearchStringx Alternate search string criteria @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections) Examples: select Text from vefn_SiblingAndChildrenItemsNewByWord('194','','%[^a-z]red[^a-z]%', '%[^a-z]red[^a-z]%',''); select Text from vefn_SiblingAndChildrenItemsNewByWord('194','','%[^a-zA-Z]step 25[^0-9a-zA-Z.vbpi:\\-]%','%[^a-zA-Z]step 25[^0-9a-zA-Z.vbpi:\\-]%',''); ========================================================================================================== */ Create Function [dbo].[vefn_SiblingAndChildrenItemsNewByWord](@DocVersionList VarChar(Max), @UnitPrefix VarChar(Max), @SearchString VarChar(Max), @SearchStringx VarChar(Max), @StepTypeList VarChar(Max), @includeLinks int, @includeRtfFormatting int , @includeSpecialCharacters int) Returns @SiblingAndChildren Table ( ILastChanged VarBinary(8), ItemID int Primary Key, DVPath nVarChar(Max), [Path] nVarChar(Max), FromType Int, Ordinal Int, ParentID Int, PreviousID Int, ContentID Int, DTS DateTime, UserID nVarChar(100), pContentID Int, pDTS DateTime, pUserID nVarChar(100), IsRNO Int, [Text] nVarChar(Max), DocAscii nVarChar(Max), Number nVarChar(256), CType Int, CFormatID Int, CConfig nVarChar(Max), CDTS DateTime, CUserID nVarChar(100), CLastChanged VarBinary(8), PLastChanged VarBinary(8) ) With Execute as Owner as Begin -- Declare Local Variables Declare @Delim Char(1); Declare @DelimNumber Char(1); Declare @DelimStep Char(1); declare @TextPrefix nVarChar(1); declare @TextSuffix nVarChar(1); -- Set Default Values Set @Delim = Char(7); Set @DelimNumber = Char(17); Set @DelimStep = '.'; Set @TextPrefix = ''; Set @TextSuffix = ''; -- Check Input Parameters If (@SearchString Like '[%]%') Set @TextPrefix = '~'; if (@SearchString Like '%[%]') Set @TextSuffix = '~'; With zItems (ILastChanged, ItemID, VersionID, [Path], FromType, Ordinal, ParentID, PreviousID, ContentID, DTS, UserID, pContentID, pDTS, pUserID, IsRNO, [Text], Number, PPath, CType, CFormatID, CConfig, CDTS, CUserID, CLastChanged, PLastChanged) as ( -- Parent Records Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged', i.ItemID as 'ItemID', dv.VersionID as 'VersionID', Cast((Case When (c.[Type] < 20000) Then @Delim + @UnitPrefix + IsNull(c.Number,'') + @DelimNumber + IsNull(c.[Text],'') Else '1' End) as nVarChar(Max)) as 'Path', 0 as 'FromType', 0 as 'Ordinal', 0 as 'ParentID', i.PreviousID as 'PreviousID', i.ContentID as 'ContentID', i.DTS as 'DTS', i.UserID as 'UserID', 0 as 'pContentID', i.DTS as 'pDTS', i.UserID as 'pUserID', 0 as 'IsRNO', c.[Text] as 'Text', c.Number as 'Number', Cast('' as nVarChar(Max)) as 'PPath', c.Type as 'CType', c.FormatID as 'CFormatID', c.Config as 'CConfig', c.DTS as 'CDTS', c.UserID as 'CUserID', Cast(c.LastChanged as VarBinary(8)) as 'CLastChanged', Cast(0 as VarBinary(8)) as 'PLastChanged' From Items i with (NoLock) join Contents c with (NoLock) on c.ContentID = i.ContentID join dbo.vefn_DocVersionSplit(@DocVersionList) dv on i.ItemID = dv.ItemID Union All -- Children Records Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged', i.ItemID as 'ItemID', zi.VersionID as 'VersionID', zi.Path + Case (c.[Type]/10000) When 0 Then @Delim + @UnitPrefix + IsNull(c.Number,'') + @DelimNumber + IsNull(c.Text,'') -- Procedure When 1 Then @Delim + IsNull(c.Number,'') + @DelimNumber + IsNull(c.Text,'') -- Section Else Case (p.FromType) When 3 Then @DelimStep +'Caution' + @DelimStep + Cast(1 as varchar(4)) When 4 Then @DelimStep +'Note' + @DelimStep + Cast(1 as varchar(4)) When 5 Then @DelimStep +'RNO' + @DelimStep When 7 Then @DelimStep +'Table' + @DelimStep + Cast(1 as varchar(4)) When 8 Then @DelimStep +'SupInfo' + @DelimStep Else Case When (zi.FromType < 3) Then @Delim Else @DelimStep End + Cast(1 as varchar(4)) End End as 'Path', p.FromType as 'FromType', 0 as 'Ordinal', zi.ItemID as 'ParentID', i.PreviousID as 'PreviousID', i.ContentID as 'ContentID', i.DTS as 'DTS', i.UserID as 'UserID', p.ContentID as 'pContentID', p.DTS as 'pDTS', p.UserID as 'pUserID', Case When (p.FromType = 5) Then -1 Else 0 End as 'IsRNO', c.Text as 'Text', c.Number as 'Number', zi.Path + Case (c.[Type]/10000) When 2 Then Case(p.FromType) When 3 Then @DelimStep + 'Caution' When 4 Then @DelimStep + 'Note' When 8 Then @DelimStep + 'SupInfo' Else '' End Else '' End as 'PPath', c.[Type] as 'CType', c.FormatID as 'CFormatID', c.Config as 'CConfig', c.DTS as 'CDTS', c.UserID as 'CUserID', Cast(c.LastChanged as varbinary(8)) as 'CLastChanged', Cast(p.LastChanged as varbinary(8)) as 'PLastChanged' From zItems zi join Parts p with (NoLock) on p.ContentID = zi.ContentID join Items i with (NoLock) on i.ItemID = p.ItemID join Contents c with (NoLock) on c.ContentID = i.ContentID Union All -- Sibling Records Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged', i.ItemID as 'ItemID', zi.VersionID as 'VersionID', zi.PPath + Case (c.[Type]/10000) When 0 Then @Delim + @UnitPrefix + IsNull(c.Number,'') + @DelimNumber + IsNull(c.Text,'') -- Procedure When 1 Then @Delim + IsNull(c.Number,'') + @DelimNumber + IsNull(c.Text,'') -- Section Else Case When (dbo.vefn_GetLastDelim(zi.Path) = '.') Then @DelimStep Else @Delim End + Cast(zi.Ordinal + 2 as varchar(4)) End as 'Path', zi.FromType as 'FromType', zi.Ordinal + 1 as 'Ordinal', zi.ParentID as 'ParentID', i.PreviousID as 'PreviousID', i.ContentID as 'ContentID', i.DTS as 'DTS', i.UserID as 'UserID', Null as 'pContentID', Null as 'pDTS', Null as 'pUserID', 0 as 'IsRNO', c.[text] as 'Text', c.Number as 'Number', zi.PPath as 'PPath', c.[Type] as 'CType', c.FormatID as 'CFormatID', c.Config as 'CConfig', c.DTS as 'CDTS', c.UserID as 'CUserID', Cast(c.LastChanged as varbinary(8)) as 'CLastChanged', Cast(0 as varbinary(8)) as 'PLastChanged' From zItems zi join Items i with (NoLock) on i.PreviousID = zi.ItemID join Contents c with (NoLock) on c.ContentID = i.ContentID ) Insert Into @SiblingAndChildren Select zi.ILastChanged, zi.ItemID, dv.DVPath, zi.Path, zi.FromType, zi.Ordinal, zi.ParentID, zi.PreviousID, zi.ContentID, zi.DTS, zi.UserID, zi.pContentID, zi.pDTS, zi.pUserID, zi.IsRNO, zi.Text, d.DocAscii, zi.Number, zi.CType, zi.CFormatID, zi.CConfig, zi.DTS, zi.CUserID, zi.CLastChanged, zi.PLastChanged From zItems zi join dbo.vefn_DocVersionSplit(@DocVersionList) dv on dv.VersionID = zi.VersionID left join Entries e with (NoLock) on e.ContentID = zi.ContentID left join Documents d with (NoLock) on d.DocID = e.DocID -- B2022-082: use the vefn_RemoveExtraText to get rid of rtf commands before comparing text Where (dbo.vefn_RemoveExtraText(@TextPrefix + zi.[Text] + @TextSuffix, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) like @SearchString Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchString Or dbo.vefn_RemoveExtraText(@TextPrefix + zi.[Text] + @TextSuffix, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) like @SearchStringx Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchStringx) And (IsNull(@StepTypeList,'') = '' or (dbo.vefn_AllSections(zi.CType) in (Select ID from dbo.vefn_SplitInt(@StepTypeList,',')))) Option (Recompile, MaxRecursion 10000); Return; End Go IF (@@Error = 0) PRINT 'Function: vefn_SiblingAndChildrenItems Succeeded' ELSE PRINT 'Function: vefn_SiblingAndChildrenItems Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[FindAnnotations]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [FindAnnotations]; /****** Object: UserDefinedFunction [dbo].[FindAnnotations] Script Date: 09/28/2012 11:06:59 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from [FindAnnotations]('12','',0,'') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[FindAnnotations](@AnnotationTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive int, @StepTypeList varchar(MAX)) RETURNS @Results TABLE ( AnnotationID int Primary Key ) WITH EXECUTE AS OWNER BEGIN insert into @Results select Distinct A.AnnotationID from Items I join Contents C on I.ContentID = C.ContentID left Join Parts P on P.ItemID = I.ItemID join Annotations A on A.ItemID = I.ItemID join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID where (isnull(@SearchString,'')='' OR (@CaseSensitive = 1 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND isnull(P.FromType,0) = 5))) RETURN END GO IF (@@Error = 0) PRINT 'Function: FindAnnotations Succeeded' ELSE PRINT 'Function: FindAnnotations Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchAnnotationItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SearchAnnotationItemAndChildren]; GO /* exec vesp_SearchAnnotationItemAndChildren Null,Null,'1',Null,0,"3-" exec vesp_SearchAnnotationItemAndChildren Null,Null,'2',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'3',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'4',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'5',Null,0 exec vesp_SearchAnnotationItemAndChildren Null,Null,'',Null,0 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int, @UnitPrefix nvarchar(MAX)) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,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] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged],AnnotationID SearchAnnotationID, SearchText, TT.Name AnnotationType, (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID join Annotations A on A.ItemID = I.ItemID join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID where A.AnnotationID in(select AnnotationID from [FindAnnotations](@AnnotationTypeList, @SearchString, @CaseSensitive, @StepTypeList)) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SearchItemAndChildren]; GO /* exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,0,0,0 exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,1,0,0 exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,2,0,0 exec vesp_SearchItemAndChildren '4','','#Link:Refer',1,2,0,0 exec vesp_SearchItemAndChildren '4','','200`F',0,1,0,0 exec vesp_SearchItemAndChildren '4','10000','',0,0,0,0 exec vesp_SearchItemAndChildren '4','','[0-9]`F',0,1,0,0 exec vesp_SearchItemAndChildren '','','RCP',0,0,0,0 exec vesp_SearchItemAndChildren '','','%',0,0,0,0 exec vesp_SearchItemAndChildren '','20040','',0,0,0,0 exec vesp_SearchItemAndChildren '','10000','XYZZY',0,0,0,0 exec vesp_SearchItemAndChildren '','10000','XYZZY',1,0,0,0 exec vesp_SearchItemAndChildren '','','%IF%',0,0,0,0 exec vesp_SearchItemAndChildren '','','%IF%',1,0,0,0 exec vesp_SearchItemAndChildren '','','%47%',1,0,0,0 exec vesp_SearchItemAndChildren '','','%47%',1,0,0,1 exec vesp_SearchItemAndChildren '','','condenser not av',0,0,0,0 exec vesp_SearchItemAndChildren '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 exec vesp_SearchItemAndChildren '','','DISPATCH NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildren '','','PORV NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildren '','','CHECK NORMAL',0,0,0,0 exec vesp_SearchItemAndChildren '','','turbine-driven',0,0,0,0 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX)) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,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] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID where (isnull(@SearchString,'')='' OR (@CaseSensitive = 1 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) OR (@CaseSensitive = 1 AND Replace(D.DocAscii,nchar(176),'\''B0') like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND Replace(D.DocAscii,nchar(176),'\''B0') like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) ) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildren Error on Creation' GO /****** Object: StoredProcedure [vesp_SearchItemAndChildrenNew] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildrenNew]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SearchItemAndChildrenNew]; GO /* exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,0,0,0 exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,1,0,0 exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,2,0,0 exec vesp_SearchItemAndChildrenNew '4','','#Link:Refer',1,2,0,0 exec vesp_SearchItemAndChildrenNew '4','','200`F',0,1,0,0 exec vesp_SearchItemAndChildrenNew '4','10000','',0,0,0,0 exec vesp_SearchItemAndChildrenNew '4','','[0-9]`F',0,1,0,0 exec vesp_SearchItemAndChildrenNew '1','','"RCP"',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','"RCP"',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','20040','',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%IF%',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%IF%',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,1 exec vesp_SearchItemAndChildrenNew '','','condenser not av',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','DISPATCH NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','PORV NEAR SG',2,0,0,0 exec vesp_SearchItemAndChildrenNew '','','CHECK NORMAL',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','(Resolved Transition Text)',0,0,0,0 exec vesp_SearchItemAndChildrenNew '','','%turbine-driven%',0,0,0,0 exec vesp_SearchItemAndChildrenNew '37','','rcp',0,0,0,0,'3-' -- Wolf Creek sample */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2019 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildrenNew] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX)) WITH EXECUTE AS OWNER AS Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) Declare @SearchStringx nvarchar(200) --kbr set @SearchStringx = replace(@SearchString,'\u8209?','-') --JSJ B2016-209 not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?') if (@IncludeLinks + @IncludeRtfFormatting + @IncludeSpecialCharacters = 0) begin if (@CaseSensitive = 0) Begin select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,ZZ.[ILastChanged] ,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID] ,ZZ.[cLastChanged], zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=ZZ.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItemsNew(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) ZZ --Join Items II on ZZ.ItemID=II.ItemID --Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType --Join Contents CC on CC.ContentID=ZZ.ContentID --where ZZ.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) order by DvPath end else begin select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,ZZ.[ILastChanged] ,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID] ,ZZ.[cLastChanged], zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=ZZ.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItemsNew(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) ZZ --Join Items II on ZZ.ItemID=II.ItemID --Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType --Join Contents CC on CC.ContentID=ZZ.ContentID --where ZZ.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) where zz.text Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or zz.text Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx or -- docascii are the word sections Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx order by DvPath end end -- no links else begin -- include linked text if (@CaseSensitive = 0) Begin select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,ZZ.[ILastChanged] ,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID] ,ZZ.[cLastChanged], zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=ZZ.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItemsNew(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) ZZ --Join Items II on ZZ.ItemID=II.ItemID --Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType --Join Contents CC on CC.ContentID=ZZ.ContentID --where ZZ.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) where .dbo.vefn_RemoveExtraText(zz.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchString or .dbo.vefn_RemoveExtraText(zz.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx or -- docascii are the word sections Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchString or Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx order by DvPath end else -- case sensitive begin select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,ZZ.[ILastChanged] ,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID] ,ZZ.[cLastChanged], zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=ZZ.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItemsNew(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) ZZ --Join Items II on ZZ.ItemID=II.ItemID --Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType --Join Contents CC on CC.ContentID=ZZ.ContentID --where ZZ.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) -- where .dbo.vefn_RemoveExtraText(replace(zz.Text,'\''b0', '\''B0'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like replace(@SearchString,'\''b0', '\''B0') or .dbo.vefn_RemoveExtraText(replace(zz.Text,'\''b0', '\''B0'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like replace(@SearchStringx,'\''b0', '\''B0') or -- docascii are the word sections Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx order by DvPath end end -- include links GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNew Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNew Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tr_tblItems_Update]') AND OBJECTPROPERTY(id,N'IsTrigger') = 1) DROP TRIGGER [tr_tblItems_Update]; /****** Object: Trigger [dbo].[tr_tblItems_Update] Script Date: 04/25/2012 14:09:52 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /****** Object: Trigger [tr_tblItems_Update] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE trigger [dbo].[tr_tblItems_Update] on [dbo].[tblItems] for update as begin if exists (select * from inserted) begin if update(PreviousID) or update(ContentID) or update(UserID) or update(DeleteStatus) begin insert into ItemAudits(ItemID,PreviousID,ContentID,DTS,UserID,DeleteStatus) select dd.ItemID,dd.PreviousID,dd.ContentID,dd.DTS,dd.UserID,dd.DeleteStatus from deleted dd inner join inserted ii on dd.ItemID = ii.ItemID where dd.deletestatus = 0 or ii.deletestatus != 0 end end end GO -- Display the status of Trigger alter IF (@@Error = 0) PRINT 'Trigger alteration: tr_tblItems_Update Succeeded' ELSE PRINT 'Trigger alteration: tr_tblItems_Update Error on Alteration' GO /****** Object: StoredProcedure [vesp_GetROUsagesByProcedure] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetROUsagesByProcedure]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetROUsagesByProcedure]; GO /* exec vesp_GetROUsagesByProcedure '1,2,4','20007','1:00010000019C,0001000002AE' exec vesp_GetROUsagesByProcedure '1,2,4','','1:00010000019C,0001000002AE' exec vesp_GetROUsagesByProcedure '1,2,4','20007','1:0001' exec vesp_GetROUsagesByProcedure '1,2,4','20006','1' exec vesp_GetROUsagesByProcedure '1,2,4','20006','' exec vesp_GetROUsagesByProcedure '1,2,4',Null,Null exec vesp_GetROUsagesByProcedure '1','','1:000700000124','' exec vesp_GetROUsagesByProcedure '','','1:0007000001C9,000700000124', '' exec vesp_SearchROItemAndChildren '1','','1:000700000124','' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetROUsagesByProcedure] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX)) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, FoundROID) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, null FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,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] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, --Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000 Path + case C.Type/10000 when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', null from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), null from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount], RRU.ROID FoundROID from ItemZ I join Contents C on C.ContentID = I.ContentID join (select contentid, ru.roid from ROusages RU join vefn_SplitROSearch(@ROSearchString) RR on case when len(RU.ROID) = 12 then RU.ROID +'0000' else RU.ROID end like RR.roid + '%' union select contentid, du.roid from DROusages DU join entries ee on DU.DOCID = EE.DOCID join vefn_SplitROSearch(@ROSearchString) RR on case when len(DU.ROID) = 12 then DU.ROID +'0000' else DU.ROID end like RR.roid + '%') RRU on RRU.ContentID = I.ContentID AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath /*having foundroid in ( select roid from vefn_SplitROSearch(@ROSearchString))*/ OPTION (MAXRECURSION 10000) END END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetROUsagesByProcedure Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetROUsagesByProcedure Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[FindRoUsages]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [FindRoUsages]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Declare @ROSearchString varchar(MAX) set @ROSearchString='1:000200000089' select * from FindRoUsages('1:000200000089') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create FUNCTION [dbo].[FindRoUsages](@ROSearchString varchar(Max)) RETURNS @Results TABLE ( ContentID int Primary Key ) WITH EXECUTE AS OWNER BEGIN insert into @Results select ContentID from ROUsages RU join vefn_SplitROSearch(@ROSearchString) RR ON RR.RODBID = RU.RODBID and RU.ROID like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS UNION select ContentID from Entries EE Join DROUsages RU on RU.DocID = EE.DocID join vefn_SplitROSearch(@ROSearchString) RR ON RR.RODBID = RU.RODBID and case when len(RU.ROID) = 12 then RU.ROID +'0000' else RU.ROID end like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS RETURN END GO IF (@@Error = 0) PRINT 'Function: FindRoUsages Succeeded' ELSE PRINT 'Function: FindRoUsages Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchROItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SearchROItemAndChildren]; GO /****** Object: StoredProcedure [dbo].[vesp_SearchROItemAndChildren] Script Date: 09/28/2012 09:02:50 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_SearchROItemAndChildren '1,2,4','20007','1:00010000019C,0001000002AE','' exec vesp_SearchROItemAndChildren '1,2,4','','1:00010000019C,0001000002AE','' exec vesp_SearchROItemAndChildren '1,2,4','20007','1:0001','' exec vesp_SearchROItemAndChildren '1,2,4','20006','1','' exec vesp_SearchROItemAndChildren '1,2,4','20006','','' exec vesp_SearchROItemAndChildren '',Null,Null,'XXX-','' exec vesp_SearchROItemAndChildren '1','','1:000200000089','' exec vesp_SearchROItemAndChildren '1','','1:00010000019c','' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX)) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' begin with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,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] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, --Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000 Path + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID left join Entries E on C.ContentID = E.ContentID left join Documents D on E.DocID = D.DocID where I.ContentID in(select ContentID from FindROUsages(@ROSearchString)) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) or (@StepTypeList like '%20040%' AND IsRNO = -1))) order by DvPath,OrdinalPath OPTION (MAXRECURSION 10000) END END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsTranFrom]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsTranFrom]; GO /****** Object: StoredProcedure [dbo].[vesp_ListItemsTranFrom] Script Date: 10/03/2012 10:06:38 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsTranFrom] WITH EXECUTE AS OWNER AS begin Select distinct I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=I.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=I.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=I.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=I.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=I.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=I.[ItemID]) [Transition_ToIDCount] from Items I join Transitions T on I.ContentID = T.FromID END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsTranFrom Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsTranFrom Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsTranTo]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsTranTo]; GO /****** Object: StoredProcedure [dbo].[vesp_ListItemsTranTo] Script Date: 10/03/2012 10:08:03 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsTranTo] WITH EXECUTE AS OWNER AS begin with Itemz(ItemID, ContentID, PreviousID, [Type]) as ( Select Distinct ItemID, C.ContentID, PreviousID, C.Type FROM [Items] I Join Contents C on C.ContentID = I.ContentID JOIN Transitions T on t.ToID = I.ItemID or t.RangeID = I.ItemID --where [ItemID]=@ItemID Union ALL -- Parent select I.ItemID,I.ContentID, I.PreviousID, C.Type 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 = I.ContentID -- Previous Union ALL select I.ItemID,I.ContentID, I.PreviousID, C.Type from Itemz Z join Items I on Z.PreviousID = I.ItemID Join Contents C on C.ContentID = I.ContentID where Z.Type >= 10000 ) Select distinct I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=Z.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=Z.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=Z.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=Z.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=Z.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=Z.[ItemID]) [Transition_ToIDCount] from Itemz Z join Items I on I.ItemID = Z.ItemID OPTION (MAXRECURSION 10000) END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsTranTo Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsTranTo Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsTranFromAndContent]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsTranFromAndContent]; GO /****** Object: StoredProcedure [dbo].[vesp_ListItemsTranFromAndContent] Script Date: 10/03/2012 10:52:31 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsTranFromAndContent] WITH EXECUTE AS OWNER AS begin Select distinct I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from Items I Join Contents C on I.ContentID = C.ContentID join Transitions T on I.ContentID = T.FromID END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsTranFromAndContent Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsTranFromAndContent Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsTranToAndContent]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsTranToAndContent]; GO GO /****** Object: StoredProcedure [dbo].[vesp_ListItemsTranToAndContent] Script Date: 10/03/2012 10:08:17 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsTranToAndContent] WITH EXECUTE AS OWNER AS begin with Itemz(ItemID, ContentID, PreviousID, [Type]) as ( Select Distinct ItemID, C.ContentID, PreviousID, C.Type FROM [Items] I Join Contents C on C.ContentID = I.ContentID JOIN Transitions T on t.ToID = I.ItemID or t.RangeID = I.ItemID --where [ItemID]=@ItemID Union ALL -- Parent select I.ItemID,I.ContentID, I.PreviousID, C.Type 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 = I.ContentID -- Previous Union ALL select I.ItemID,I.ContentID, I.PreviousID, C.Type from Itemz Z join Items I on Z.PreviousID = I.ItemID Join Contents C on C.ContentID = I.ContentID where Z.Type >= 10000 ) Select distinct I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from Itemz Z Join Items I on Z.ItemID = I.ItemID Join Contents C on I.ContentID = C.ContentID OPTION (MAXRECURSION 10000) END GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsTranToAndContent Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsTranToAndContent Error on Creation' GO /****** Object: StoredProcedure [vefn_SiblingAndChildrenItemsByProc] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingAndChildrenItemsByProc]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_SiblingAndChildrenItemsByProc]; GO /****** Object: UserDefinedFunction [dbo].[vefn_tblChildItems] Script Date: 05/18/2011 11:20:48 ******/ /* select * from vefn_SiblingAndChildrenItemsByProc(30) II join */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItemsByProc](@ProcID int) RETURNS @SiblingAndChildren TABLE ( [ItemID] int PRIMARY KEY , [DVPath] nvarchar(max) , [Path] nvarchar(max) , [Level] int , [FromType] int , [Ordinal] int , [ParentID] int , [PreviousID] int , [ContentID] int , [DTS] datetime , [UserID] nvarchar(100) , [pContentID] int , [pDTS] datetime , [pUserID] nvarchar(100) , [IsRNO] int -- , [PPath] nvarchar(max) -- , [POrdinalPath] nvarchar(max) , [OrdinalPath] nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' BEGIN with Itemz([ItemID], [DVPath], [Level], [ParentID], [Ordinal], [PreviousID], [FromType], [ContentID], [DTS], [UserID],[pContentID], [pDTS],[pUserID],PPath, [Path], [IsRNO], [POrdinalPath], [OrdinalPath]) as ( Select [I].[ItemID], '' DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], Cast('' as nvarchar(max)) [PPath], Cast(Case when C.Type < 20000 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) [Path], 0 IsRNO, Cast('' as nvarchar(max)) [POrdinalPath], Cast('0001' as nvarchar(max)) [OrdinalPath] FROM [Items] I Join Contents C on C.ContentID=I.ContentID WHERE I.[ItemID] = @ProcID Union All -- Children select I.[ItemID], DVPath, [Level] + 1,Z.ItemID,0, I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID], P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001' from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select I.[ItemID], DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID] ,null,null,null, PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' THEN @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5) from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) insert into @SiblingAndChildren select I.[ItemID], [DvPath], [Path], I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID], [pContentID],[pDTS],[pUserID],[IsRNO]/*,[PPath],[POrdinalPath]*/,[OrdinalPath] from ItemZ I OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItemsByProc Succeeded' ELSE PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItemsByProc Error on Creation' GO /****** Object: StoredProcedure [vefn_RemoveRange] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_RemoveRange]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_RemoveRange]; GO /* SELECT ContentID, text, [dbo].[vefn_RemoveRange](text,'') StrippedText from contents where contentid in (select top 25 ContentID from contents where text like '%[[]END>%') select top 25 * from contents where text like '%[[]END>%' SELECT ContentID, [dbo].[vefn_RemoveRange](text,'') StrippedText from contents where contentid =189 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_RemoveRange](@text nvarchar(MAX),@startToken nvarchar(MAX), @endToken nvarchar(MAX)) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int DECLARE @index2 int DECLARE @lenStartToken int DECLARE @lenEndToken int DECLARE @lastIndex int SET @lenStartToken = len(@startToken) SET @lenEndToken = len(@endToken) SET @index = CHARINDEX(@startToken , @text) SET @lastIndex = -1 while (@index != 0) BEGIN SET @index2 = CHARINDEX(@endToken , @text, @index + @lenStartToken) if (@index2>0) SET @text = substring(@text,1,@index-1) + substring(@text,@index2+@lenEndToken,len(@text)) SET @lastIndex = @index SET @index = CHARINDEX(@startToken , @text) if (@index = @lastIndex) SET @index = 0 END RETURN @text END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_RemoveRange Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_RemoveRange Error on Creation' GO /****** Object: StoredProcedure [ve_GetPath] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetPath]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetPath]; GO /* select ItemID, CC.Type, dbo.ve_GetPath(ItemID) from Items II join Contents CC on II.ContentID = CC.ContentID where ItemID in(111,265,266,267) */ -- drop function ve_GetPath /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetPath] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- declare @STructID int --set @StructID=11 declare @Path varchar(max); with Itemz(ItemCount,ItemID,PreviousID,FromType,CType,Number,Text,PPath, Path) as ( Select 1,ItemID,PreviousID,0,C.Type/10000,C.Number,C.Text, Cast(Case when C.Type < 20000 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') else '' end as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path from Items I join Contents C on I.ContentID = C.ContentID where ItemID=@ItemID Union All -- siblings Select ItemCount+1,I.PreviousID,II.PreviousID,0,C.Type/10000,Z.Number,Z.Text,PPath,cast(ItemCount + 1 as nvarchar(4)) + PPath from Items I join Contents C on I.ContentID = C.ContentID Join Items II on II.ItemID = I.PreviousID Join Itemz Z on I.ItemID=Z.ItemID where I.PreviousID != 0 Union All -- children select 1,I.ItemID,I.PreviousID,P.FromType,C.Type/10000,C.Number,C.Text, case C.Type/10000 when 0 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') when 1 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') +'`' + cast(ItemCount + 0 as varchar(4)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(4)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(4)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(4)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(4)) when 5 then '`RNO`' when 7 then '`Table`' when 8 then '`SupInfo`' else '`' + cast(ItemCount + 0 as varchar(4)) end end + PPath PPath, --'1' + case C.Type/10000 when 0 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') when 1 then '`' + Isnull(C.Number,'') +'`' + Isnull(C.Text,'') +'`' + cast(ItemCount + 0 as varchar(4)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(4)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(4)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(4)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(4)) when 5 then '`RNO' when 7 then '`Table' when 8 then '`SupInfo' else '`' + cast(ItemCount + 0 as varchar(4)) end end + PPath Path from Parts P join Items I on I.ContentID = P.ContentID join Contents C on I.ContentID = C.ContentID join Itemz Z on P.ItemID=Z.ItemID ) select @Path = path From Itemz where ItemCount=1 and CType=0 OPTION (MAXRECURSION 10000) return @Path END; GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: ve_GetPath Succeeded' ELSE PRINT 'ScalarFunction Creation: ve_GetPath Error on Creation' GO /****** Object: StoredProcedure [vefn_ProcedureByProcID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ProcedureByProcID]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ProcedureByProcID]; GO /****** Object: UserDefinedFunction [dbo].[vefn_ProcedureByProcID] Script Date: 05/18/2011 11:20:48 ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create FUNCTION [dbo].[vefn_ProcedureByProcID](@ProcID int) RETURNS @SiblingAndChildren TABLE ( [ItemID] int PRIMARY KEY , [DVPath] nvarchar(max) , [Path] nvarchar(max) , [Level] int , [FromType] int , [Ordinal] int , [ParentID] int , [PreviousID] int , [ContentID] int , [DTS] datetime , [UserID] nvarchar(100) , [pContentID] int , [pDTS] datetime , [pUserID] nvarchar(100) , [IsRNO] int -- , [PPath] nvarchar(max) -- , [POrdinalPath] nvarchar(max) , [OrdinalPath] nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' BEGIN insert into @SiblingAndChildren Select [I].[ItemID] , '' DVPath , Cast(Case when C.Type < 20000 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) [Path] ,0 [Level] ,0 [FromType] , 0 [Ordinal] , 0 [ParentID] , [PreviousID] ,[I].[ContentID] ,[I].[DTS] ,[I].[UserID] ,0 [pContentID] ,[I].[DTS] [pDTS] , [I].[UserID] [pUserID] ,0 IsRNO , Cast('0001' as nvarchar(max)) [OrdinalPath] FROM [Items] I Join Contents C on C.ContentID=I.ContentID WHERE I.[ItemID] = @ProcID END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ProcedureByProcID Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ProcedureByProcID Error on Creation' GO /****** Object: StoredProcedure [vefn_FindContentText] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindContentText]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindContentText]; GO /* SELECT * From vefn_FindContentText('1','%RCP%') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindContentText]( @DocVersionList nvarchar(MAX) ,@SearchString varchar(MAX) ,@IncludeLinks as int ,@IncludeRtfFormatting as int ,@IncludeSpecialCharacters as int) RETURNS @FoundContents TABLE ( ContentID int PRIMARY KEY ,Type int ,Text varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @Dashes varchar(25) set @Dashes = '\u8209?' if(@SearchString not like '%\u8209?%') BEGIN set @Dashes='-' END IF(ISNULL(@DocVersionList,'')='') BEGIN INSERT INTO @FoundContents -- Do a case insensitive search select ContentID,Type,Text from contents where replace(.dbo.vefn_RemoveExtraText(Replace([Text],'-','\u8209?'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters),'\u8209?',@Dashes) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS --where .dbo.vefn_RemoveExtraText(Replace(Replace([Text],'-','\u8209?'),'\','\u9586?'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS -- where Replace([Text],'-','\u8209?') like @SearchString Collate SQL_Latin1_General_CP1_CI_AS --where Replace(Replace([Text],'-','\u8209?'),'\u160?',' ') like @SearchString Collate SQL_Latin1_General_CP1_CI_AS END ELSE BEGIN INSERT INTO @FoundContents -- Do a case insensitive search select ContentID,Type,Text from contents where [ContentID] in (select [ContentID] from vefn_DVContent(@DocVersionList)) -- bug fix B2014-056 and B2014-102 now use vefn_RemoveExtraText which fixes searching for hard spaces and finding procedure text when it is bolded (or italics or underlined etc) AND Replace(.dbo.vefn_RemoveExtraText(Replace([Text],'-','\u8209?'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters),'\u8209?',@Dashes) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS --AND .dbo.vefn_RemoveExtraText(Replace(Replace([Text],'-','\u8209?'),'\','\u9586?'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS --AND Replace([Text],'-','\u8209?') like @SearchString Collate SQL_Latin1_General_CP1_CI_AS --AND Replace(Replace([Text],'-','\u8209?'),'\u160?',' ') like @SearchString Collate SQL_Latin1_General_CP1_CI_AS END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindContentText Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindContentText 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]; GO /* SELECT * From vefn_FindText('8','Dog',1,0,0,1,'') SELECT * From vefn_FindText('1','turbine\u8209?driven',0,0,0,0,'') SELECT * From vefn_FindText('1','trip',0,0,0,0,'') select * from vefn_FindText('1','',0,0,0,1,'20010,20008') select * from vefn_FindText('1',null,0,0,0,1,'20010,20008') select * from vefn_FindText('1',' ',0,0,0,1,'20010,20008') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindText]( @DocVersionList nvarchar(MAX) ,@SearchString varchar(MAX) ,@CaseSensitive as int ,@IncludeLinks as int ,@IncludeRtfFormatting as int ,@IncludeSpecialCharacters as int ,@StepTypeList varchar(MAX)) RETURNS @FoundContents TABLE ( ContentID int PRIMARY KEY ) WITH EXECUTE AS OWNER AS BEGIN Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) IF isnull(@SearchString,'%')='%' BEGIN insert into @FoundContents select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C where(isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or (dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) END ELSE BEGIN Declare @SearchStringx nvarchar(200) --kbr --set @SearchStringx = replace(@SearchString,'-','\u8209?') --kbr --set @SearchStringx = replace(replace(@SearchString,'-','\u8209?'),'\','\u9586?') --kbr set @SearchStringx = replace(@SearchString,'\u8209?','-') --JSJ B2016-209 not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?') IF @CaseSensitive = 0 -- Not Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchString,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION -- B2016-209 to find dashes in word sections select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchStringx Collate SQL_Latin1_General_CP1_CI_AS) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C join Entries E on C.ContentID = E.ContentID join Documents D on E.DocID = D.DocID where (Replace(D.DocAscii,nchar(176),'\''B0') like @SearchString OR Replace(D.DocAscii,nchar(176),'\''B0') like @SearchStringx Collate SQL_Latin1_General_CP1_CI_AS) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) END ELSE BEGIN IF @CaseSensitive = 1 -- Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchString,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) C where -- B2019-023 moved placement of Collate SQL_Latin1_CP1_CS_AS to before each like statement to enable case sensitive in Word sections (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like @SearchString) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) UNION -- B2016-209 to find dashes in word sections select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C join Entries E on C.ContentID = E.ContentID join Documents D on E.DocID = D.DocID where (Replace(D.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString OR Replace(D.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx) AND ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) END END END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindText Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindText Error on Creation' GO -- THIS IS STUFF THAT WE FIXED IN PROMS2010.SQL AND PUT IN HERE ALSO /****** Object: StoredProcedure [getItemAndChildren] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getItemAndChildren]; GO -- getItemAndChildren 111 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getItemAndChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] 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.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: getItemAndChildren Error on Creation' GO /****** Object: StoredProcedure [getItemNextAndChildren] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getItemNextAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getItemNextAndChildren]; GO -- getItemNextAndChildren 111 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getItemNextAndChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] 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.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getItemNextAndChildren Succeeded' ELSE PRINT 'Procedure Creation: getItemNextAndChildren Error on Creation' GO /****** Object: StoredProcedure [ve_GetSiblingCount] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetSiblingCount]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetSiblingCount]; GO /* select top 5 CC.Number,CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) HLStepCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type >= 10000 and CC.Type < 20000 order by dbo.ve_GetSiblingCount(ItemID) desc select top 5 CC.Number,CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) SectionCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type < 10000 order by dbo.ve_GetSiblingCount(ItemID) desc select top 5 CC.Text,Type,ItemID, dbo.ve_GetSiblingCount(ItemID) SubStepCount from Contents CC Join Parts PP on PP.ContentID = CC.ContentID where CC.Type >= 20000 order by dbo.ve_GetSiblingCount(ItemID) desc */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetSiblingCount] (@ItemID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN declare @Count int; with Itemz([Direction], [ItemID], [PreviousID]) as ( Select 0 Direction,[ItemID], [PreviousID] FROM [Items] where [ItemID]=@ItemID -- Siblings Previous Union All select -1 Direction,I.[ItemID], I.[PreviousID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.Direction <= 0 -- Siblings Next Union All select 1 Direction,I.[ItemID], I.[PreviousID] from Itemz Z join Items I on I.ItemID = Z.PreviousID where Z.Direction >= 0 ) Select @Count = Count(*) from Itemz OPTION (MAXRECURSION 10000) return @Count END; GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: ve_GetSiblingCount Succeeded' ELSE PRINT 'ScalarFunction Creation: ve_GetSiblingCount Error on Creation' GO /****** Object: StoredProcedure [vefn_AllHighLevelSteps] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_AllHighLevelSteps]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_AllHighLevelSteps]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_AllHighLevelSteps]() RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Ordinal int ,Path varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM (select II.ItemID ParentID, PP.ItemID, PreviousID, II.ContentID, II.DTS, II.UserID, II.LastChanged from Items II Join Contents CC on II.ContentID = CC.ContentID Join Parts PP on PP.ContentID = II.ContentID and FromType = 6 where CC.Type = 10000) TT -- Siblings Union All select [Level] ,Z.[ParentID],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 @HighLevelStepTransitions select [ParentID],ItemID,Ordinal,dbo.ve_GetPath([ItemID]) Path from Itemz Order by ParentID,ItemID OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_AllHighLevelSteps Succeeded' ELSE PRINT 'TableFunction Creation: vefn_AllHighLevelSteps Error on Creation' GO /****** Object: StoredProcedure [vefn_AllHighLevelStepTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_AllHighLevelStepTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_AllHighLevelStepTransitions]; GO /* select * from vefn_AllHighLevelStepTransitions() where ExternalTransitions > 0 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_AllHighLevelStepTransitions]() RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Ordinal int ,Path varchar(max) ,TransCount int ,ExternalTransitions int ,ExternalChildTransitions int ,InternalTransitions int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM (select II.ItemID ParentID, PP.ItemID, PreviousID, II.ContentID, II.DTS, II.UserID, II.LastChanged from Items II Join Contents CC on II.ContentID = CC.ContentID Join Parts PP on PP.ContentID = II.ContentID and FromType = 6 where CC.Type = 10000) TT -- Siblings Union All select [Level] ,Z.[ParentID],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 @HighLevelStepTransitions select [ParentID],ItemID,Ordinal,dbo.ve_GetShortPath([ItemID]) Path,(Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) TransCount ,(Select count(*) from vefn_FindExternalTransitions(ItemID)) ExternalTransitions ,(Select count(*) from vefn_FindExternalChildTransitions(ItemID)) ExternalChildTransitions ,(Select count(*) from vefn_FindInternalTransitions(ItemID)) InternalTransitions from Itemz where (Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) > 0 OR(Select count(*) from vefn_FindExternalTransitions(ItemID)) > 0 OR(Select count(*) from vefn_FindInternalTransitions(ItemID)) > 0 Order by ParentID,ItemID OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_AllHighLevelStepTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_AllHighLevelStepTransitions Error on Creation' GO /****** Object: StoredProcedure [vefn_ChildItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChildItems]; GO /* declare @PreviousID as int declare @ItemID as int set @ItemID = 450 select @PreviousID = PreviousID from items where ItemID = @ItemID Select * from Items where ItemID = @ItemID select * from Transitions where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) select CC.Text from Transitions TT join contents CC on TT.FromID = CC.ContentID where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) AND (ToID = @ItemID or RangeID = @ItemID) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_ChildItems](@ItemID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ItemID], [ContentID]) as ( Select 0 [Level], [ItemID], [ContentID] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation 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 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 OPTION (MAXRECURSION 10000) END RETURN 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]; GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_ChildrenItems](@ItemID int, @ParentID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 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,Z.ItemID,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.[ParentID],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 @Children select ItemID, ContentID from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildrenItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ChildrenItems Error on Creation' GO /****** Object: StoredProcedure [vefn_FindAffectedTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindAffectedTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindAffectedTransitions]; GO /* select top 1 * from items order by itemid desc Select FromID,.dbo.ve_GetPathFromContentID(FromID) ContentPath ,ToID,dbo.ve_GetPath(ToID) ToPath ,RangeID,dbo.ve_GetPath(RangeID) RangePath ,cc.Text from vefn_FindAffectedTransitions(2102) ttz join transitions tt on ttz.TransitionID = tt.TransitionID --join items ii on ii.ItemID = tt.fromID join contents cc on tt.FromID = cc.contentid */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindAffectedTransitions](@ItemID int) RETURNS @Transitions TABLE ( TransitionID int ) WITH EXECUTE AS OWNER AS BEGIN declare @Type int select @Type = CC.Type from Contents CC Join Items II ON II.ContentID = CC.ContentID Where ItemID = @ItemID 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 -- All 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 @Type >= 20000 OR Z.[Level] > 0 -- This would limit the siblings to the siblings of the children and not the initial ItemID ) , Itemz2([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 -- All 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 Itemz2 Z join Items I on Z.PreviousID = I.ItemID where @Type >= 20000 OR Z.[Level] > 0 -- This would limit the siblings to the siblings of the children and not the initial ItemID ) insert into @Transitions select TransitionID from Transitions TT where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) UNION select TransitionID from Transitions TT JOIN Itemz2 on ToID=ItemID and RangeID=ItemID and IsRange = 2 OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindAffectedTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindAffectedTransitions Error on Creation' GO /****** Object: StoredProcedure [vefn_FindExternalChildTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindExternalChildTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindExternalChildTransitions]; GO /* Select * from vefn_FindExternalChildTransitions(185) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindExternalChildTransitions](@ItemID int) RETURNS @Children TABLE ( FromItemID int, ToID int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ChildList AS TABLE ( ItemID INT PRIMARY KEY, ContentID INT, Level INT ) INSERT INTO @ChildList SELECT * FROM vefn_ChildItemz(@ItemID) insert into @Children select ItemID [FromItemID], case when TT.ToID in(select ItemID from @ChildList) 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 @ChildList where Level > 0) OR RangeID in(select ItemID from @ChildList where Level > 0)) AND FromID not in(Select ContentID from @ChildList) OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindExternalChildTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindExternalChildTransitions Error on Creation' GO /****** Object: StoredProcedure [vefn_FindExternalTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindExternalTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindExternalTransitions]; GO /* Select * from vefn_FindExternalTransitions(185) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindExternalTransitions](@ItemID int) RETURNS @Children TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ChildList AS TABLE ( ItemID INT PRIMARY KEY, ContentID INT, Level INT ) INSERT INTO @ChildList SELECT * FROM vefn_ChildItemz(@ItemID) insert into @Children select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[Config] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID in(select ItemID from @ChildList) OR RangeID in(select ItemID from @ChildList)) AND FromID not in(Select ContentID from @ChildList) OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindExternalTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindExternalTransitions Error on Creation' GO /****** Object: StoredProcedure [vefn_ChildItemz] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildItemz]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChildItemz]; GO /* Select * from vefn_ChildItemz(185) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2015 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_ChildItemz](@ItemID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int, Level int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ItemID], [ContentID]) as ( Select 0 [Level], [ItemID], [ContentID] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID, Level from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildItemz Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ChildItemz Error on Creation' GO /****** Object: StoredProcedure [vefn_FindInternalTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindInternalTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindInternalTransitions]; GO /* Select * from vefn_FindInternalTransitions(185) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindInternalTransitions](@ItemID int) RETURNS @Children TABLE ( FromItemID int, ToID 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 @Children select ItemID [FromItemID], 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) OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindInternalTransitions Succeeded' 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) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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) OPTION (MAXRECURSION 10000) 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_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 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 OPTION (MAXRECURSION 10000) END RETURN @FormatID 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_HighLevelStepTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_HighLevelStepTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_HighLevelStepTransitions]; GO /* select * from vefn_HighLevelStepTransitions(105,104) where TransCount > 0 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_HighLevelStepTransitions](@ItemID int, @ParentID int) RETURNS @HighLevelStepTransitions TABLE ( ParentID int ,ItemID int PRIMARY KEY ,Path varchar(max) ,TransCount int ,ExternalTransitions int ,InternalTransitions int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID -- Siblings Union All select [Level] ,Z.[ParentID],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 @HighLevelStepTransitions select [ParentID],ItemID,dbo.ve_GetPath([ItemID]) ,(Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) TransCount ,(Select count(*) from vefn_FindExternalTransitions(ItemID)) ExternalTransitions ,(Select count(*) from vefn_FindInternalTransitions(ItemID)) InternalTransitions from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_HighLevelStepTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_HighLevelStepTransitions Error on Creation' GO /****** Object: StoredProcedure [vefn_SiblingChildrenItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_SiblingChildrenItems]; GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_SiblingChildrenItems](@ItemID int) RETURNS @SiblingChildren TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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.[ParentID],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 ) insert into @SiblingChildren select ItemID, ContentID from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingChildrenItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_SiblingChildrenItems Error on Creation' GO /****** Object: Table Function [vefn_SiblingItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_SiblingItems]; GO /* select * from Transitions where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184))) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_SiblingItems](@ItemID int, @ParentID int) RETURNS @Siblings TABLE ( ItemID int PRIMARY KEY, ContentID int, Ordinal int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] ,0 [pContentID],[DTS] [pDTS], [UserID] [pUserID], [LastChanged] [pLastChanged] FROM [Items] where [ItemID]=@ItemID -- Siblings Union All select [Level] ,Z.[ParentID],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 ) insert into @Siblings select ItemID, ContentID, Ordinal from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_SiblingItems Error on Creation' GO /****** Object: StoredProcedure [vesp_CleanUpItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_CleanUpItems]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_CleanUpItems]; GO /* select *, .dbo.ve_GetParts(ContentID,6) SubSteps from items where contentid in(select contentid from contents where text like 'DISPATCH operator to open breaker%') select * from items where itemid in(298,299,436,440) select itemid from items where previousid is null and itemid not in (select itemid from parts) --select * from contents where text like 'foldout cip%' select count(*) from parts */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE procedure [dbo].[vesp_CleanUpItems] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION BEGIN with Itemz(ItemID) as( select itemid from items where previousid is null and itemid not in(1) and itemid not in (select itemid from parts) UNION ALL select ii.itemid from items ii join itemz zz on zz.itemid = ii.previousid ) delete from items where itemid in (select itemid from itemz) OPTION (MAXRECURSION 10000) END 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: vesp_CleanUpItems Succeeded' ELSE PRINT 'Procedure Creation: vesp_CleanUpItems 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]; GO -- vesp_ListChildren 17 -- drop procedure [getItemAndChildren] /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] 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.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListChildren Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListChildren Error on Creation' GO /****** Object: StoredProcedure [vesp_ListContentPath] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListContentPath]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListContentPath]; GO -- vesp_ListContentPath 148 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create PROCEDURE [dbo].[vesp_ListContentPath] ( @ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with ContentZ(BaseID,ContentID,ItemID,Number,Text,Item,Level,PreviousID) as ( Select II.ItemID,CC.ContentID,II.ItemID,CC.Number,CC.Text,1,1,II.PreviousID from Items II join Contents CC on CC.ContentID=II.ContentID where @ContentID=II.ContentID Union All -- Select BaseID,CC.ContentID,II.ItemID,CC.Number,CC.Text,ZZ.Item+1,ZZ.Level,II.PreviousID FROM ContentZ ZZ Join Items II on II.ItemID = ZZ.PreviousID Join Contents CC on II.ContentID = CC.ContentID where ZZ.PreviousID is not null Union All Select BaseID,CC.ContentID,II.ItemID,CC.Number,CC.Text,1,ZZ.Level+1,II.PreviousID FROM ContentZ ZZ Join Parts PP on ZZ.ItemID = PP.ItemID Join Contents CC on PP.ContentID = CC.ContentID Join Items II on II.ContentID = CC.ContentID where ZZ.PreviousID is null --and ZZ.ItemID in(717,715,711,662) ) Select ZZ.BaseID,ZZ.Level,MaxItem,ZZ.Number,ZZ.Text from ContentZ ZZ join (select BaseID, Level, max(item) MaxItem from ContentZ group by BaseID,Level) T1 on T1.BaseID=ZZ.BaseID and T1.Level = ZZ.Level where Item=1 order by ZZ.BaseID,ZZ.Level Desc, Item Desc OPTION (MAXRECURSION 10000) end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListContentPath Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListContentPath Error on Creation' GO /****** Object: StoredProcedure [vesp_ListItemAndChildren] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemAndChildren]; GO -- vesp_ListItemAndChildren 1,0 -- drop procedure [vesp_ListItemAndChildren] /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemAndChildren] (@ItemID int, @ParentID int) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 0 [Level], @ParentID [ParentID], 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,Z.ItemID,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.[ParentID],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 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemAndChildren Error on Creation' GO -- THIS IS STUFF THAT WE FIXED IN PROMStoCM.SQL AND PUT IN HERE ALSO /****** Object: StoredProcedure [getItemAuditsByItemID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getItemAuditsByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getItemAuditsByItemID]; GO /* getitemauditsbyitemid 10183 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getItemAuditsByItemID] ( @ItemID int ) WITH EXECUTE AS OWNER AS /* with Itemz([AuditType],[Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 'root' [AuditType], 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]= @ItemID Union All -- Children select 'chld' [AuditType], [Level] + 2,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID -- Siblings Union All select 'sibl' [AuditType], [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) */ select * from ( --get deleted previous item select 0 Level,ia.*,dbo.[ve_GetPartType](@ItemID) ItemType from itemaudits ia inner join itemaudits iaa on ia.itemid = iaa.previousid where iaa.itemid = @ItemID and ia.itemid not in (select itemid from items where itemid = ia.itemid) and ia.deletestatus in (select max(deletestatus) from itemaudits where itemid = ia.itemid) union --get deleted next item /* select 1 Level,ia.*,@itemtype ItemType from itemaudits ia where ia.previousid = @ItemID and ia.itemid not in (select itemid from items where itemid = ia.itemid) and ia.deletestatus in (select max(deletestatus) from itemaudits where itemid = ia.itemid) */ select 1 Level, ia.[AuditID], ia.[ItemID], ia.[PreviousID], ia.[ContentID], ia.[DTS], ia.[UserID], ti.[DeleteStatus] ,dbo.[ve_GetPartType](@ItemID) ItemType from itemaudits ia inner join tblitems ti on ia.itemid = ti.itemid where ia.previousid = @ItemID and ti.deletestatus > 0 and ia.dts = ti.dts union --get chillins select 2 Level,ia.*, case when pa.fromtype = 1 then 'Procedure' when pa.fromtype = 2 then 'Section' when pa.fromtype = 3 then 'Caution' when pa.fromtype = 4 then 'Note' when pa.fromtype = 5 then 'RNO' when pa.fromtype = 6 then 'Step' when pa.fromtype = 7 then 'Table' else 'Unknown' end itemtype from itemaudits ia inner join partaudits pa on ia.itemid = pa.itemid inner join items ii on pa.contentid = ii.contentid where ii.itemid = @ItemID and ia.itemid not in (select itemid from items where itemid = ia.itemid) and ia.deletestatus in (select max(deletestatus) from itemaudits where itemid = ia.itemid) ) ia order by deletestatus desc OPTION (MAXRECURSION 10000) --select * from itemz order by parentid,ordinal RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getItemAuditsByItemID Succeeded' ELSE PRINT 'Procedure Creation: getItemAuditsByItemID Error on Creation' GO -- THIS IS STUFF THAT WE FIXED IN PROMStoAPPR.SQL AND PUT IN HERE ALSO /****** Object: StoredProcedure [vefn_FindExternalFromTransitions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindExternalFromTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindExternalFromTransitions]; GO /* Select * from vefn_FindExternalFromTransitions(185) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create FUNCTION [dbo].[vefn_FindExternalFromTransitions](@ItemID int) RETURNS @Children TABLE ( [FromItemID] int, [TransitionID] [int] NOT NULL, [FromID] [int] NOT NULL, [ToID] [int] NOT NULL, [RangeID] [int] NOT NULL, [Config] [nvarchar](max) NULL ) 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 @Children select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[Config] from Transitions TT join Items II on II.ContentID=TT.FromID where (ToID not in(select ItemID from Itemz) OR RangeID not in(select ItemID from Itemz)) AND FromID in(Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindExternalFromTransitions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindExternalFromTransitions Error on Creation' GO /****** Object: StoredProcedure [dbo].[getAnnotationAuditsChronologyByItemIDandUnitID] Script Date: 10/10/2012 14:45:33 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAnnotationAuditsChronologyByItemIDandUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAnnotationAuditsChronologyByItemIDandUnitID]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /****** Object: StoredProcedure [getAnnotationAuditsChronologyByItemIDandUnitID] ******/ /* getAnnotationAuditsChronologyByItemIDandUnitID 13,13,1 getAnnotationAuditsChronologyByItemIDandUnitID 30,8570,1 getAnnotationAuditsChronologyByItemIDandUnitID 1,1,1 getAnnotationAuditsChronologyByItemIDandUnitID 30,8505,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create procedure [dbo].[getAnnotationAuditsChronologyByItemIDandUnitID] ( @ProcItemID int, @ItemID int, @UnitID int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin -- declare @dts datetime -- set @dts = (select dts from items where itemid = @procitemid) declare @tci table ( ItemID int, IContentID int, IDeleteStatus int, ProcDTS datetime, Path nvarchar(max), OrdinalPath nvarchar(max) ) insert into @tci select * from vefn_tblchilditems(@ProcItemID,@ItemID,0) select case when lastauditid is null and dts > itemdts then 'Added' when deletestatus > 0 then 'Deleted' when lastauditid = deletedauditid then 'Restored' else 'Changed' end ActionWhat ,case when lastauditid is null and dts > itemdts then dts when deletestatus > 0 then ActionDTS when lastauditid = deletedauditid then ActionDTS else dts end ActionWhen ,* from ( select cast(ident_current('annotationaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from annotationaudits) auditid -- 0 auditid ,aa.annotationid ,aa.itemid ,aa.typeid ,aa.rtftext ,aa.searchtext ,aa.config ,aa.dts ,aa.userid ,0 deletestatus ,aa.ActionDTS ,ii.contentid icontentid ,(select min(dts) from tblitems where itemid = ii.itemid) ItemDTS ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid) LastAuditID ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and deletestatus > 0 and aa.dts = dts) DeletedAuditID ,tci.ordinalpath from tblannotations aa inner join items ii on aa.itemid = ii.itemid join @tci tci on tci.itemid = ii.itemid where aa.deletestatus = 0 union select aa.auditid ,aa.annotationid ,aa.itemid ,aa.typeid ,aa.rtftext ,aa.searchtext ,aa.config ,aa.dts ,aa.userid ,aa.deletestatus ,aa.ActionDTS ,ii.contentid icontentid ,(select min(dts) from tblitems where itemid = ii.itemid) ItemDTS ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and aa.auditid > auditid ) LastAuditID ,(select max(auditid) from annotationaudits where annotationid = aa.annotationid and itemid = ii.itemid and aa.auditid > auditid and deletestatus > 0 and aa.dts = dts) DeletedAuditID ,tci.ordinalpath from annotationaudits aa inner join items ii on aa.itemid = ii.itemid join @tci tci on tci.itemid = ii.itemid ) ah where itemid in (select itemid from vefn_tblchilditems (@procitemid,@itemid,0)) and dts > @dts and (dbo.ve_GetItemDerivedApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemDerivedApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%') --(select dts from versions where versionid = (select max(versionid) from revisions rr inner join versions vv on rr.revisionid = vv.revisionid --inner join stages ss on vv.stageid = ss.stageid where itemid = @procitemid and ss.isapproved = 1)) order by ordinalpath,annotationid,auditid--actionwhen end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemIDandUnitID Succeeded' ELSE PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemIDandUnitID Error on Creation' GO /****** Object: StoredProcedure [dbo].[getContentAuditsChronologyByItemIDandUnitID] Script Date: 10/10/2012 12:48:39 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemIDandUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getContentAuditsChronologyByItemIDandUnitID]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /****** Object: StoredProcedure [getContentAuditsChronologyByItemIDandUnitID] ******/ /* getContentAuditsChronologyByItemIDandUnitID 10154,10154,0,1 getContentAuditsChronologyByItemIDandUnitID 42,42,0,1 getContentAuditsChronologyByItemIDandUnitID 1,1,0,1 getContentAuditsChronologyByItemIDandUnitID 146,146,1,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemIDandUnitID] ( @ProcedureItemID int, @SelectedItemID int, @IncludeDeletedChildren int, @UnitID int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) -- select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah where dbo.ve_GetItemDerivedApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemDerivedApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' -- order by OrdinalPath, contentid,auditid--actionwhen RETURN end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getContentAuditsChronologyByItemIDandUnitID Succeeded' ELSE PRINT 'Procedure Creation: getContentAuditsChronologyByItemIDandUnitID Error on Creation' GO /****** Object: StoredProcedure [dbo].[getContentAuditsSummaryByItemIDandUnitID] Script Date: 10/10/2012 12:56:01 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsSummaryByItemIDandUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getContentAuditsSummaryByItemIDandUnitID]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /****** Object: StoredProcedure [getContentAuditsSummaryByItemIDandUnitID] ******/ /* getContentAuditsSummaryByItemIDandUnitID 146,146,0,1 getContentAuditsSummaryByItemIDandUnitID 42,42,0,1 getContentAuditsSummaryByItemIDandUnitID 1,1,0,1 getContentAuditsSummaryByItemIDandUnitID 146,146,1,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create PROCEDURE [dbo].[getContentAuditsSummaryByItemIDandUnitID] ( @ProcedureItemID int, @SelectedItemID int, @IncludeDeletedChildren int, @UnitID int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin DECLARE @ProcId Int Set @ProcID = @ProcedureItemID DECLARE @Apples TABLE ( ProcID int, ItemId int, ContentID int Primary Key, Apple nvarchar(255), DerApple nvarchar(255) ) --Build Applicabilty table for the specified Procedure ID BEGIN with Itemz([Level],[Apple],[DerApple],[ParApple],[ItemID], [ContentID]) as (Select 0 ,xMasterSlave.value('@Applicability','nvarchar(255)') Apple ,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),dbo.ve_getItemDerivedApplicability(@ProcID)) DerApple ,cast(dbo.ve_getItemDerivedApplicability(@ProcID) as nvarchar(255)) ParApple ,[II].[ItemID], [II].[ContentID] FROM [Items] II JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave) Where II.[ItemID] = @ProcID Union All -- Children select ZZ.Level + 1 Level ,xMasterSlave.value('@Applicability','nvarchar(255)') Apple ,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),ZZ.DerApple) DerApple ,ZZ.DerApple ParApple , II.[ItemID], II.[ContentID] from Itemz ZZ join Parts PP on PP.ContentID = ZZ.ContentID join Items II on II.ItemID = PP.ItemID JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave) Union All -- Siblings select ZZ.Level ,xMasterSlave.value('@Applicability','nvarchar(255)') Apple ,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),ZZ.ParApple) DerApple ,ZZ.ParApple , II.[ItemID], II.[ContentID] from Itemz ZZ join Items II on II.PreviousID = ZZ.ItemID JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave) Where Level >= 1 ) insert into @Apples select @ProcID ProcID, ItemID, ContentID, Apple, DerApple--, [ItemID], [ContentID] from ItemZ II OPTION (MAXRECURSION 10000) END DECLARE @Chrono TABLE ( [AuditID] bigint, [ContentID] int, [Number] nvarchar(max), [Text] nvarchar(max), [Type] int, [FormatID] int, [Config] nvarchar(max), [DTS] datetime, [UserID] nvarchar(max), [DeleteStatus] int, [ActionDTS] datetime, [ActionWhat] nvarchar(max), [ActionWhen] datetime, [Path] nvarchar(max), ItemID int, TypeName nvarchar(max), ordinalpath nvarchar(max) ) -- Use the Applicability Table to limit Items included in the list of changes insert into @Chrono select Distinct VC.* from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) VC Left JOIN @Apples AA ON AA.ContentID = VC.ContentID Where aa.ContentID is null or AA.DerApple = '-1' or ',' + AA.DerApple + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' Declare @Audits TABLE ( AuditID int primary key ) -- Create a Unique list of Minimum and Maximum AuditIDs for Each ContentID insert into @Audits select min(auditID) from @Chrono group by contentid UNION select max(auditID) from @Chrono group by contentid -- Return the List Of Changes with the first Audit Record and the Last Audit Record select * from @Chrono where AuditID is null OR AuditID in (select AuditID from @Audits) order by OrdinalPath, contentid,auditid RETURN end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getContentAuditsSummaryByItemIDandUnitID Succeeded' ELSE PRINT 'Procedure Creation: getContentAuditsSummaryByItemIDandUnitID Error on Creation' GO /****** Object: StoredProcedure [dbo].[getCurrentRevisionByItemIDandUnitID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[getCurrentRevisionByItemIDandUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[getCurrentRevisionByItemIDandUnitID]; GO /****** Object: StoredProcedure [dbo].[getCurrentRevisionByItemIDandUnitID] Script Date: 06/22/2012 16:58:12 ******/ /* getCurrentRevisionByItemID 41 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getCurrentRevisionByItemIDandUnitID] ( @ItemID int, @UnitID int ) WITH EXECUTE AS OWNER AS SELECT [Revisions].[RevisionID], [ItemID], [TypeID], [RevisionNumber], [RevisionDate], [Notes], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Checks] WHERE [Checks].[RevisionID]=[Revisions].[RevisionID]) [CheckCount], (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) [VersionCount] FROM [Revisions] inner join ( select top 1 revisionid,mxvid from ( select rr.revisionid,max(vv.versionid) mxvid from items ii inner join revisions rr on ii.itemid = rr.itemid inner join versions vv on rr.revisionid = vv.revisionid inner join stages ss on vv.stageid = ss.stageid cross apply rr.config.nodes('Config/Applicability') t1(r1) where ss.isapproved = 1 and ii.itemid = @ItemID and r1.value('@Index','int') = @UnitID group by rr.revisionid union select null,null ) ds order by mxvid desc ) rr on [Revisions].revisionid = rr.revisionid -- WHERE [ItemID] = @ItemID -- ORDER BY [RevisionID] DESC RETURN GO IF (@@Error = 0) PRINT 'StoredProcedure [getCurrentRevisionByItemIDandUnitID] Succeeded' ELSE PRINT 'StoredProcedure [getCurrentRevisionByItemIDandUnitID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getDocumentByLibDoc] Script Date: 01/30/2012 14:08:10 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getDocumentByLibDoc]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getDocumentByLibDoc]; GO -- [dbo].[getDocumentByLibDoc] 'DOC_0000',4 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',3 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',2 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',1 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getDocumentByLibDoc] ( @LibDoc varchar(12), @VersionID int ) WITH EXECUTE AS OWNER AS DECLARE @DocID int select @DocID = docid from ( select distinct ah.docid,.dbo.vefn_GetVersionIDByItemID(ii.itemid) versionid from ( select dd.docid,ofn.value('@OriginalFileName','varchar(20)') origfilename,dts from (select docid,cast(config as xml) xconfig,dts from documents) dd cross apply xconfig.nodes('//History') t1(ofn) ) ah inner join entries ee on ah.docid = ee.docid inner join items ii on ee.contentid = ii.itemid where origfilename = @LibDoc + '.LIB' ) ah where versionid = @VersionID -- from (select docid,cast(config as xml) xconfig from documents) ah -- cross apply xconfig.nodes('//Config/History') t1(roc) -- where roc.value('@OriginalFileName','varchar(12)') = @LibDoc + '.LIB' SELECT [DocID], [LibTitle], [DocContent], [DocAscii], [Config], [DTS], [UserID], [LastChanged], [FileExtension], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[DocID]=[Documents].[DocID]) [DROUsageCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[DocID]=[Documents].[DocID]) [EntryCount], (SELECT COUNT(*) FROM [Pdfs] WHERE [Pdfs].[DocID]=[Documents].[DocID]) [PdfCount] FROM [Documents] WHERE [DocID]=@DocID SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [DROUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[DROUsages].[RODbID] WHERE [DROUsages].[DocID]=@DocID SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Entries] JOIN [Contents] ON [Contents].[ContentID]=[Entries].[ContentID] WHERE [Entries].[DocID]=@DocID SELECT [Pdfs].[DocID], [Pdfs].[DebugStatus], [Pdfs].[TopRow], [Pdfs].[PageLength], [Pdfs].[LeftMargin], [Pdfs].[PageWidth], [Pdfs].[PageCount], [Pdfs].[DocPdf], [Pdfs].[DTS], [Pdfs].[UserID], [Pdfs].[LastChanged] FROM [Pdfs] WHERE [Pdfs].[DocID]=@DocID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getDocumentByLibDoc Succeeded' ELSE PRINT 'Procedure Creation: getDocumentByLibDoc Error on Creation' GO /****** Object: StoredProcedure [dbo].[getRevisionByItemIDandRevisionNumberAndUnitID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[getRevisionByItemIDandRevisionNumberAndUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[getRevisionByItemIDandRevisionNumberAndUnitID]; GO /****** Object: StoredProcedure [dbo].[getRevisionByItemIDandRevisionNumberAndUnitID] Script Date: 06/25/2012 23:05:17 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getRevisionByItemIDandRevisionNumberAndUnitID] ( @ItemID int, @RevisionNumber nvarchar(50), @UnitID int ) WITH EXECUTE AS OWNER AS declare @RevisionID int set @RevisionID = (select revisionid from revisions rr cross apply rr.config.nodes('//Applicability') t1(r1) where itemid = @itemid and revisionnumber = @RevisionNumber and r1.value('@Index','int') = @UnitID) SELECT [RevisionID], [ItemID], [TypeID], [RevisionNumber], [RevisionDate], [Notes], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Checks] WHERE [Checks].[RevisionID]=[Revisions].[RevisionID]) [CheckCount], (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) [VersionCount] FROM [Revisions] WHERE [RevisionID]=@RevisionID SELECT [Checks].[CheckID], [Checks].[RevisionID], [Checks].[StageID], [Checks].[ConsistencyChecks], [Checks].[DTS], [Checks].[UserID], [Checks].[LastChanged], [Stages].[Name] [Stage_Name], [Stages].[Description] [Stage_Description], [Stages].[IsApproved] [Stage_IsApproved], [Stages].[DTS] [Stage_DTS], [Stages].[UserID] [Stage_UserID] FROM [Checks] JOIN [Stages] ON [Stages].[StageID]=[Checks].[StageID] WHERE [Checks].[RevisionID]=@RevisionID SELECT [Versions].[VersionID], [Versions].[RevisionID], [Versions].[StageID], [Versions].[DTS], [Versions].[UserID], [Versions].[LastChanged], [Versions].[PDF], [Versions].[SummaryPDF], [Stages].[Name] [Stage_Name], [Stages].[Description] [Stage_Description], [Stages].[IsApproved] [Stage_IsApproved], [Stages].[DTS] [Stage_DTS], [Stages].[UserID] [Stage_UserID] FROM [Versions] JOIN [Stages] ON [Stages].[StageID]=[Versions].[StageID] WHERE [Versions].[RevisionID]=@RevisionID RETURN GO IF (@@Error = 0) PRINT 'StoredProcedure [getRevisionByItemIDandRevisionNumberAndUnitID] Succeeded' ELSE PRINT 'StoredProcedure [getRevisionByItemIDandRevisionNumberAndUnitID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getRevisionsByItemIDandUnitID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[getRevisionsByItemIDandUnitID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[getRevisionsByItemIDandUnitID]; GO /****** Object: StoredProcedure [dbo].[getRevisionsByItemIDandUnitID] Script Date: 06/26/2012 16:22:32 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getRevisionsByItemIDandUnitID] ( @ItemID int, @UnitID int ) WITH EXECUTE AS OWNER AS SELECT [RevisionID], [ItemID], [TypeID], [RevisionNumber], [RevisionDate], [Notes], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Checks] WHERE [Checks].[RevisionID]=[Revisions].[RevisionID]) [CheckCount], (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) [VersionCount] FROM [Revisions] cross apply config.nodes('//Applicability') t1(r1) WHERE [ItemID] = @ItemID and r1.value('@Index','int') = @UnitID and (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) > 0 ORDER BY [RevisionID] DESC RETURN GO IF (@@Error = 0) PRINT 'StoredProcedure [getRevisionsByItemIDandUnitID] Succeeded' ELSE PRINT 'StoredProcedure [getRevisionsByItemIDandUnitID] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetItemApplicability] Script Date: 03/28/2012 17:58:48 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetItemApplicability]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetItemApplicability]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetItemApplicability] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @apple varchar(max) select @apple = r2.value('@Applicability','varchar(max)') from ( select itemid,cast(config as xml) xconfig from items ii join contents cc on ii.contentid = cc.contentid ) t1 outer apply xconfig.nodes('//MasterSlave') t2(r2) where itemid = @ItemID return @apple END GO IF (@@Error = 0) PRINT 'ScalerFunction [vefn_GetItemApplicability] Succeeded' ELSE PRINT 'ScalerFunction [vefn_GetItemApplicability] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ParentItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ParentItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_ParentItems] Script Date: 10/12/2012 16:12:01 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from [dbo].[vefn_ParentItems](212) select * from [dbo].[vefn_ParentItems](48) select * from [dbo].[vefn_ParentItems](49) select * from [dbo].[vefn_ParentItems](50) select * from [dbo].[vefn_ParentItems](51) select * from [dbo].[vefn_ParentItems](52) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_ParentItems](@ItemID int) RETURNS @Parents TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Relationship], [ItemID], [ContentID], [PreviousID]) as ( Select 1 [Relationship], [ItemID], [ContentID], [PreviousID] FROM [Items] where [ItemID]=@ItemID Union All -- Parents select 2 [Relationship], I.[ItemID], I.[ContentID], I.[PreviousID] from Itemz Z join Parts P on P.ItemID = Z.ItemID join Items I on I.ContentID = P.ContentID -- Siblings Union All select 0 [Relationship] , I.[ItemID], I.[ContentID], I.[PreviousID] from Itemz Z join Items I on Z.PreviousID = I.ItemID ) insert into @Parents select ItemID, ContentID from Itemz where Relationship > 0 OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: vefn_ParentItems Succeeded' ELSE PRINT 'Function: vefn_ParentItems Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetItemDerivedApplicability]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetItemDerivedApplicability]; GO /****** Object: UserDefinedFunction [dbo].[ve_GetItemDerivedApplicability] Script Date: 10/13/2012 00:57:34 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select [dbo].[ve_GetItemDerivedApplicability](48) select [dbo].[ve_GetItemDerivedApplicability](49) select [dbo].[ve_GetItemDerivedApplicability](50) select [dbo].[ve_GetItemDerivedApplicability](51) select [dbo].[ve_GetItemDerivedApplicability](52) --Prairie Island select [dbo].[ve_GetItemDerivedApplicability](29544) [ParentChild] select [dbo].[ve_GetItemDerivedApplicability](123816) [ParentChild] select [dbo].[ve_GetItemDerivedApplicability](125916) [ParentChild] select [dbo].[ve_GetItemDerivedApplicability](26955) [NonParentChild] */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetItemDerivedApplicability] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @apple varchar(max) select @apple = dbo.ve_getitemapplicability(@ItemID) if @apple is null begin declare @ParentID int select @ParentID = dbo.ve_getparentitem(@ItemID) if @parentid is not null set @apple = dbo.ve_GetItemDerivedApplicability(@ParentID) else begin select @apple = coalesce(@apple + ',','') + r2.value('@index','varchar(max)') from (select cast(config as xml) xconfig from docversions where versionid = dbo.vefn_GetVersionIDByItemID(@ItemID)) ah cross apply xconfig.nodes('//Slave') t2(r2) if(@apple is null) -- Non PC P/C Item BEGIN -- Get maximum Applicabilty declare @n int select @n=max(xSlave.value('@index','int')) from ( select versionID, Cast(config as xml) xConfig from DocVersions) t1 cross apply xconfig.nodes('//Slave') tSlave(xSlave) if(@n is not null) begin -- Build a list based upon the maximum with cte(ii) as (select 1 ii union all select ii+1 from cte where ii < @n) select @apple = coalesce(@apple+',','') + cast(ii as varchar(max)) from cte end if(@apple is null)Set @Apple='' END end end return @apple END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: ve_GetItemDerivedApplicability Succeeded' ELSE PRINT 'Function: ve_GetItemDerivedApplicability Error on Creation' GO ------- IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetItemAppliedApplicability]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetItemAppliedApplicability]; GO /****** Object: UserDefinedFunction [dbo].[ve_GetItemAppliedApplicability] Script Date: 09/17/2018 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select [dbo].[ve_GetItemAppliedApplicability](48) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetItemAppliedApplicability] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN declare @apple varchar(max) select @apple = dbo.ve_getitemapplicability(@ItemID) if(@apple is null)Set @Apple='' /*** begin declare @ParentID int select @ParentID = dbo.ve_getparentitem(@ItemID) if @parentid is not null set @apple = dbo.ve_GetItemDerivedApplicability(@ParentID) else begin select @apple = coalesce(@apple + ',','') + r2.value('@index','varchar(max)') from (select cast(config as xml) xconfig from docversions where versionid = dbo.vefn_GetVersionIDByItemID(@ItemID)) ah cross apply xconfig.nodes('//Slave') t2(r2) if(@apple is null) -- Non PC P/C Item BEGIN -- Get maximum Applicabilty declare @n int select @n=max(xSlave.value('@index','int')) from ( select versionID, Cast(config as xml) xConfig from DocVersions) t1 cross apply xconfig.nodes('//Slave') tSlave(xSlave) if(@n is not null) begin -- Build a list based upon the maximum with cte(ii) as (select 1 ii union all select ii+1 from cte where ii < @n) select @apple = coalesce(@apple+',','') + cast(ii as varchar(max)) from cte end if(@apple is null)Set @Apple='' END end end ***/ return @apple END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: ve_GetItemDerivedApplicability Succeeded' ELSE PRINT 'Function: ve_GetItemDerivedApplicability Error on Creation' GO ------- /****** Object: UserDefinedFunction [dbo].[vefn_GetParentItem] Script Date: 03/28/2012 17:58:48 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetParentItem]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetParentItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetParentItem] (@ItemID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN DECLARE @ParentID int; WITH Itemz([ItemID],[IsFound]) as ( select ii.itemid,0 from items ii where ii.itemid = @ItemID union all select ii.previousid,0 from items ii join itemz zz on ii.itemid = zz.itemid where ii.previousid is not null and zz.isfound = 0 union all select ii.itemid,1 from parts pp join itemz zz on pp.itemid = zz.itemid join items ii on ii.contentid = pp.contentid ) select top 1 @ParentID = itemid from itemz where isfound = 1 OPTION (MAXRECURSION 10000) RETURN @ParentID END GO IF (@@Error = 0) PRINT 'ScalerFunction [vefn_GetParentItem] Succeeded' ELSE PRINT 'ScalerFunction [vefn_GetParentItem] Error on Creation' go /****** Object: UserDefinedFunction [dbo].[vefn_CanTransitionBeCreated] Script Date: 10/14/2012 02:03:30 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CanTransitionBeCreated]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_CanTransitionBeCreated]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select dbo.vefn_CanTransitionBeCreated(49,51) select dbo.vefn_CanTransitionBeCreated(51,49) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_CanTransitionBeCreated](@fromID int, @toID int) RETURNS int AS BEGIN declare @rv int declare @tCount int declare @uCount int set @rv = 0 select @tCount = count(*) from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@toID),',') select @uCount = count(*) from ( select * from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@fromID),',') union select * from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@toID),',') ) ah if (@tCount = 0) or (@tCount >= @uCount) begin set @rv = 1 end return @rv END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: vefn_CanTransitionBeCreated Succeeded' ELSE PRINT 'Function: vefn_CanTransitionBeCreated Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetVersionIDByItemID] Script Date: 02/03/2012 16:48:32 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionIDByItemID]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_GetVersionIDByItemID]; GO /* select dbo.vefn_GetVersionIDByItemID(41) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create function [dbo].[vefn_GetVersionIDByItemID] (@ItemID int) returns int as begin declare @VersionID int; with itemz ( itemid,previousid,versionid ) as ( select itemid,previousid,null from items ii join contents cc on ii.contentid = cc.contentid where itemid = @ItemID --siblins union all select ii.itemid,ii.previousid,null from items ii join contents cc on ii.contentid = cc.contentid join itemz zz on zz.previousid = ii.itemid where zz.versionid is null --chillins union all select ii.itemid,ii.previousid,null from parts pp join items ii on ii.contentid = pp.contentid join contents cc on ii.contentid = cc.contentid join itemz zz on zz.itemid = pp.itemid where zz.versionid is null --docversions union all select 0,0,dv.versionid from docversions dv join itemz zz on dv.itemid = zz.itemid where zz.versionid is null ) select @VersionID = versionid from itemz zz where versionid is not null OPTION (MAXRECURSION 10000) return @VersionID end GO -- Display the status of Func creation IF (@@Error = 0) PRINT 'Function Creation: vefn_GetVersionIDByItemID Succeeded' ELSE PRINT 'Function Creation: vefn_GetVersionIDByItemID Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_WillTransitionBeValidFrom] Script Date: 10/16/2012 18:17:37 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_WillTransitionBeValidFrom]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_WillTransitionBeValidFrom]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select dbo.vefn_WillTransitionBeValidFrom(194,'2') select dbo.vefn_WillTransitionBeValidFrom(216,'2') select dbo.vefn_WillTransitionBeValidFrom(246,'2') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_WillTransitionBeValidFrom](@toID int, @newAppl varchar(max)) RETURNS int AS BEGIN declare @rv int declare @tCount int declare @uCount int set @rv = 0 select @tCount = count(*) from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@toID),',') select @uCount = count(*) from ( select * from vefn_SplitInt(@newAppl,',') union select * from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@toID),',') ) ah if @tCount >= @uCount begin set @rv = 1 end return @rv END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: vefn_WillTransitionBeValidFrom Succeeded' ELSE PRINT 'Function: vefn_WillTransitionBeValidFrom Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_WillTransitionBeValidTo] Script Date: 10/16/2012 18:20:23 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_WillTransitionBeValidTo]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_WillTransitionBeValidTo]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select dbo.vefn_WillTransitionBeValidTo(10617,'2') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_WillTransitionBeValidTo](@toID int, @newAppl varchar(max)) RETURNS int AS BEGIN declare @rv int declare @tCount int declare @uCount int set @rv = 0 select @tCount = count(*) from vefn_SplitInt(@newAppl,',') select @uCount = count(*) from ( select * from vefn_SplitInt(@newAppl,',') union select * from vefn_SplitInt([dbo].[ve_GetItemDerivedApplicability](@toID),',') ) ah if @tCount >= @uCount begin set @rv = 1 end return @rv END GO -- Display the status of TableFunction creation IF (@@Error = 0) PRINT 'Function: vefn_WillTransitionBeValidTo Succeeded' ELSE PRINT 'Function: vefn_WillTransitionBeValidTo Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_CanTransitionBeCreated] Script Date: 10/15/2012 14:37:32 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_CanTransitionBeCreated]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_CanTransitionBeCreated]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_CanTransitionBeCreated 46,180 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_CanTransitionBeCreated] ( @fromItemID int, @toItemID int ) AS BEGIN select dbo.vefn_CanTransitionBeCreated(@fromItemID,@toItemID) Status, dbo.ve_GetItemDerivedApplicability(@fromItemID) fromAppl, dbo.ve_GetItemDerivedApplicability(@toItemID) toAppl, dbo.ve_GetShortPath(@fromItemID) fromStep, dbo.ve_GetShortPath(@toItemID) toStep END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_CanTransitionBeCreated Succeeded' ELSE PRINT 'Procedure Creation: vesp_CanTransitionBeCreated Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_ListItemAndChildrenByUnit] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_ListItemAndChildrenByUnit]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[vesp_ListItemAndChildrenByUnit]; GO /****** Object: StoredProcedure [dbo].[vesp_ListItemAndChildrenByUnit] Script Date: 05/02/2012 23:16:53 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- vesp_ListItemAndChildrenByUnit 29546,0,'8' -- drop procedure [vesp_ListItemAndChildren] /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemAndChildrenByUnit] (@ItemID int, @ParentID int, @UnitID varchar(max)) WITH EXECUTE AS OWNER AS BEGIN with Itemz([apple],[Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as ( Select 1 [apple],0 [Level], @ParentID [ParentID], 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 case when s1.value('@Applicability','varchar(max)') is null or ',' + s1.value('@Applicability','varchar(max)') + ',' like '%,' + @UnitID + ',%' then 1 else 0 end apple ,[Level] + 1,Z.ItemID,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 join (select ContentID,cast(Config as xml) xConfig from Contents) C on C.ContentID = I.ContentID outer apply C.xConfig.nodes('//MasterSlave') m1(s1) where Z.[Apple] = 1 -- Siblings Union All select case when s1.value('@Applicability','varchar(max)') is null or ',' + s1.value('@Applicability','varchar(max)') + ',' like '%,' + @UnitID + ',%' then 1 else 0 end apple ,[Level] ,Z.[ParentID], case when Z.[Apple] = 1 then Z.[Ordinal] +1 else Z.[Ordinal] end, I.[ItemID], case when Z.[Apple] = 1 then I.[PreviousID] else Z.[PreviousID] end, [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null from Itemz Z join Items I on I.PreviousID = Z.ItemID join (select ContentID,cast(Config as xml) xConfig from Contents) C on C.ContentID = I.ContentID outer apply C.xConfig.nodes('//MasterSlave') m1(s1) where Z.[Level] > 0 ) select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], [pContentID],[pDTS],[pUserID],[pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], CASE WHEN I.ItemID IN (SELECT ParentID FROM ItemZ WHERE apple = 1) THEN (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) ELSE 0 END [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from ItemZ I join Contents C on C.ContentID = I.ContentID where i.apple = 1 order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) END GO -- Display the status of Procedure Creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemAndChildrenByUnit Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemAndChildrenByUnit Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_WillTransitionsBeValid] Script Date: 10/15/2012 14:37:32 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_WillTransitionsBeValid]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_WillTransitionsBeValid]; GO /* dbo.vesp_WillTransitionsBeValid 10616,'2' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [DBO].[vesp_WillTransitionsBeValid] ( @ItemID int, @NewAppl varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN select *, dbo.ve_GetShortPath(@ItemID) SrcStep, dbo.ve_GetShortPath(myitemid) TgtStep from ( select tt.toid MyItemID, dbo.vefn_WillTransitionBeValidFrom(tt.toid,@NewAppl) Valid, @NewAppl SrcAppl, dbo.ve_GetItemDerivedApplicability(tt.toid) TgtAppl from transitions tt inner join items ii on tt.fromid = ii.contentid where fromid in (select contentid from dbo.vefn_childitems(@ItemID)) union select ii.itemid MyItemID, dbo.vefn_WillTransitionBeValidTo(ii.itemid,@NewAppl) Valid, dbo.ve_GetItemDerivedApplicability(ii.itemid) SrcAppl, @NewAppl TgtAppl from transitions tt inner join items ii on tt.fromid = ii.contentid where toid in (select itemid from dbo.vefn_childitems(@ItemID)) ) ah where Valid = 0 END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_WillTransitionsBeValid Succeeded' ELSE PRINT 'Procedure Creation: vesp_WillTransitionsBeValid Error on Creation' GO /****** Object: StoredProcedure [dbo].[vefn_NextCount] Script Date: 02/05/2013 11:58:00 ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_NextCount]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP Function [vefn_NextCount]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create FUNCTION [dbo].[vefn_NextCount](@ItemID int) RETURNS Int WITH EXECUTE AS OWNER AS BEGIN declare @Count int; with Itemz([NextCnt], [ItemID], [PreviousID]) as ( Select 0 [NextCnt], [ItemID], [PreviousID] FROM [Items] where [ItemID]=@ItemID -- Siblings Union All select Z.[NextCnt] +1, I.[ItemID], I.[PreviousID] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) Select @Count = Count(*) from Itemz OPTION (MAXRECURSION 10000) RETURN @Count END GO IF (@@Error = 0) PRINT 'Function Creation: vefn_NextCount Succeeded' ELSE PRINT 'Function Creation: vefn_NextCount Error on Creation' GO /****** Object: StoredProcedure [vesp_ListItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItems]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItems]; GO --vesp_ListItems 1 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItems] ( @ItemID int = 0 ) WITH EXECUTE AS OWNER AS BEGIN with Itemz(knt, ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged]) as ( Select 0 knt, ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged] from Items where ItemID=@ItemID Union All -- Select Z.knt + 1,C.ItemID,C.PreviousID,C.ContentID,C.[DTS],C.[UserID],C.[LastChanged] from Items C Join Itemz Z on C.PreviousID=Z.ItemID ) Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[Itemz].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[Itemz].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[Itemz].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[Itemz].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[Itemz].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[Itemz].[ItemID]) [Transition_ToIDCount] from Itemz order by knt OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItems Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItems Error on Creation' GO /****** Object: StoredProcedure [vesp_ListItemsAndContent] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsAndContent]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsAndContent]; GO --vesp_ListItemsAndContent 1 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsAndContent] ( @ItemID int = 0 ) WITH EXECUTE AS OWNER AS BEGIN with Itemz(knt, ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged]) as ( Select 0 knt, ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged] from Items where ItemID=@ItemID Union All -- Select z.knt + 1, I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged] from Items I Join Itemz Z on I.PreviousID=Z.ItemID ) Select I.ItemID,I.PreviousID,I.ContentID,I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] from Itemz I Join Contents C on I.ContentID = C.ContentID Order by knt OPTION (MAXRECURSION 10000) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsAndContent Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsAndContent Error on Creation' GO /****** Object: StoredProcedure [vesp_SortProcedures] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SortProcedures]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SortProcedures]; GO /* select versionid, ff.folderid, ff.name,itemid from docversions dv join folders ff on dv.folderid=ff.folderid Westinghouse Data exec vesp_SortProcedures 1 -- Abnormal Procedures --exec vesp_SortProcedures 4 -- Emergency Operating Procedures - Rev 2 exec vesp_SortProcedures 5 -- System Operating Procedures exec vesp_SortProcedures 6 -- Maintenance, Test, Inspection, Surveillance Procedures --exec vesp_SortProcedures 7 -- Severe Accident Management Guidelines --exec vesp_SortProcedures 8 -- Emergency Response Guidelines exec vesp_SortProcedures 9 -- General Operating Procedures exec vesp_SortProcedures 11 -- Post 72-Hour Procedures 103811 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SortProcedures]( @VersionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @TopID int select @TopID = ItemID from DocVersions where versionID = @VersionID DECLARE @Procs TABLE ( ItemID int PRIMARY KEY, ProcNum nvarchar(255) ) DECLARE @Organize TABLE ( ItemID int PRIMARY KEY, NewPreviousID int ) DECLARE @NewTopID as int INSERT INTO @Procs select ZZ.ItemID, isnull(Replace(CC.Number,'\u8209?','-'),'') + ':' + substring('0000000000000000' + cast(ItemID as varchar(16)), 1+ len( cast(ItemID as varchar(16))), 16) ProcNum from vefn_SiblingItems(@TopID,0) ZZ Join Contents CC on CC.ContentID = ZZ.ContentID --INSERT INTO @Procs select ZZ.ItemID, isnull(Replace(Replace(CC.Number,'\u8209?','-'),'\','\u9586?'),'') + ':' + substring('0000000000000000' + cast(ItemID as varchar(16)), 1+ len( cast(ItemID as varchar(16))), 16) ProcNum from vefn_SiblingItems(@TopID,0) ZZ Join Contents CC on CC.ContentID = ZZ.ContentID --select * from @Procs order by ProcNum + cast(ItemID as nvarchar(max)) select top 1 @NewTopID = ItemID from @Procs order by ProcNum INSERT INTO @Organize select ItemID, (select top 1 ItemID from @Procs P2 where P1.ProcNum > P2.ProcNum order by P2.ProcNum DESC ) NewPreviousID from @Procs P1 order by isnull(ProcNum,'') + cast(ItemID as nvarchar(max)) --select * from @Organize Update DocVersions Set ItemID = @NewTopID where versionID = @VersionID Update II Set II.PreviousID = ZZ.NewPreviousID from Items II join @Organize ZZ On II.ItemID = ZZ.ItemID 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: vesp_SortProcedures Succeeded' ELSE PRINT 'Procedure Creation: vesp_SortProcedures Error on Creation' GO /****** Object: StoredProcedure [vefn_RemoveExtraText] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_RemoveExtraText]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_RemoveExtraText]; GO /* select text, .dbo.vefn_RemoveExtraText(text,2,0,0) StrippedText from Contents where ContentID=373 select text, .dbo.vefn_RemoveExtraText(text,1,0,0) StrippedText from Contents where ContentID=373 select text, .dbo.vefn_RemoveExtraText(text,0,0,0) StrippedText ,.dbo.vefn_FirstLink(text,0), PATINDEX('%[' + nchar(9516) + nchar(9574) + char(21) + ']%' , text) from Contents where ContentID=373 select .dbo.vefn_RemoveExtraText('\b Bold\b0',0,0,0) select .dbo.vefn_RemoveExtraText('\b Bold\b0',0,1,0) select .dbo.vefn_RemoveExtraText('A\u1?B\u12?C\u123?D\u1234?E',0,0,0) select .dbo.vefn_RemoveExtraText('A\u1?B\u12?C\u123?D\u1234?E',0,0,1) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_RemoveExtraText](@text nvarchar(MAX),@includeLink int, @includeRtfFormatting int , @includeSpecialCharacters int) RETURNS varchar(MAX) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int DECLARE @index2 int -- Replace Hard Hyphen with Hyphen SET @text = replace(@text,'\u8209?','-') --SET @text = replace(replace(@text,'\u8209?','-'),'\u9586?','\') -- Replace Hard Space with Space -- commenting out the bottom two lines will fix the global search for hard space bug (B2014-056) --SET @text = replace(@text,'\u160?',' ') --set @text = replace(@text,nchar(160),' ') -- Strip Links IF @includeLink = 0 -- Remove Links SET @text = [dbo].[vefn_RemoveRange](@text,'') IF @includeLink < 2 -- Remove Comments SET @text = [dbo].[vefn_RemoveRange](@text,'\v' ,'\v0') if(@includeRtfFormatting=0) -- Remove Rtf Formatting BEGIN -- B2022-082: underline/bold of word removes space between 2 words so was not finding cases SET @text = Replace(@text, '\ulnone\b0 ', ''); SET @text = Replace(@text, '\b0\ulnone ', ''); SET @text = Replace(@text, '\b0 ', ''); SET @text = Replace(@text, '\b ', ''); SET @text = Replace(@text, '\ulnone ', ''); SET @text = Replace(@text, '\ul0 ', ''); SET @text = Replace(@text, '\ul ', ''); SET @text = Replace(@text, '\i0 ', ''); SET @text = Replace(@text, '\i ', ''); SET @text = Replace(@text, '\super ', ''); SET @text = Replace(@text, '\sub ', ''); SET @text = Replace(@text, '\nosupersub ', ''); SET @text = Replace(@text, '\up2 ', ''); SET @text = Replace(@text, '\up0 ', ''); SET @text = Replace(@text, '\up3 ', ''); SET @text = Replace(@text, '\dn2 ', ''); SET @text = Replace(@text, '\dn3 ', ''); SET @text = Replace(@text, '\b0', ''); SET @text = Replace(@text, '\b', ''); SET @text = Replace(@text, '\ul0', ''); SET @text = Replace(@text, '\ul', ''); SET @text = Replace(@text, '\i0', ''); SET @text = Replace(@text, '\i', ''); SET @text = Replace(@text, '\super', ''); SET @text = Replace(@text, '\sub', ''); SET @text = Replace(@text, '\nosupersub', ''); SET @text = Replace(@text, '\up2', ''); SET @text = Replace(@text, '\up0', ''); SET @text = Replace(@text, '\up3', ''); SET @text = Replace(@text, '\dn2', ''); SET @text = Replace(@text, '\dn3', ''); END if(@includeSpecialCharacters=0) -- Remove Special Characters BEGIN SET @index = PATINDEX('%\u[0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+4,len(@text)) SET @index = PATINDEX('%\u[0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+5,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+6,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9][0-9]?%',@text) END SET @index = PATINDEX('%\u[0-9][0-9][0-9][0-9]?%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+7,len(@text)) SET @index = PATINDEX('%\u[0-9][0-9][0-9][0-9]?%',@text) END SET @index = PATINDEX('%\''[0-9A-Fa-f][0-9A-Fa-f]%',@text) while(@index != 0) BEGIN SET @text = substring(@text,1,@index-1) + substring(@text,@index+4,len(@text)) SET @index = PATINDEX('%\''[0-9A-Fa-f][0-9A-Fa-f]%',@text) END END -- Replace Hyphen with Hard Hyphen SET @text = replace(@text,'-','\u8209?') --SET @text = replace(replace(@text,'-','\u8209?'),'\','\u9586?') RETURN @text END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_RemoveExtraText Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_RemoveExtraText Error on Creation' GO /****** Object: Table Function [vefn_FindSpecialChars] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindSpecialChars]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindSpecialChars]; GO /* select * from vefn_FindSpecialChars('\u160?\ulnone \u8209?') select MIN(ContentID) MinContentID,Count(*) HowMany,UChar SpecialChar from Contents cross apply vefn_FindSpecialChars(text) SC where text like '%\u[0-9]%' group by UChar */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindSpecialChars](@text varchar(MAX)) RETURNS @SpecialChars TABLE ( uchar varchar(10) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index1 int DECLARE @index2 int SET @index1 = -1 SET @index1 = PATINDEX('%\u[0-9]%' , @text) WHILE (@index1 > 0) BEGIN SET @index2 = CHARINDEX('?' , @text, @index1 + 3) if @index2 > 0 BEGIN INSERT INTO @SpecialChars VALUES (substring(@text,@index1,1 + @index2-@index1)) SET @Text = substring(@text,@index2 + 1,len(@text)) END SET @index1 = PATINDEX('%\u[0-9]%' , @text) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindSpecialChars Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindSpecialChars Error on Creation' GO /****** Object: Table Function [vefn_FindSpecialChars2] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindSpecialChars2]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindSpecialChars2]; GO /* select * from vefn_FindSpecialChars2(nchar(255) + nchar(8209) + nchar(160)) select MIN(ContentID) MinContentID,Count(*) HowMany,UChar SpecialChar from Contents cross apply vefn_FindSpecialChars2(text) SC group by UChar */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindSpecialChars2](@text nvarchar(MAX)) RETURNS @SpecialChars TABLE ( uchar int ) WITH EXECUTE AS OWNER AS BEGIN WHILE (len(@text) > 0) BEGIN if(unicode(@text) > 127) INSERT INTO @SpecialChars VALUES (unicode(@text)) SET @Text = substring(@text,2,len(@text)) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindSpecialChars2 Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindSpecialChars2 Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[MoveItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [MoveItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[MoveItem](@ItemID int, @Index int) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @ItemsChanged TABLE ( ItemID int Primary Key ) DECLARE @Siblings TABLE ( ItemID int PRIMARY KEY, Ordinal int ) DECLARE @OldPreviousID int SELECT @OldPreviousID = PreviousID FROM [Items] where ItemID = @ItemID DECLARE @OldNextID int SELECT @OldNextID = ItemID FROM [Items] where PreviousID = @ItemID insert into @Siblings select * from vefn_AllSiblingItems(@ItemID) DECLARE @NewNextID int SELECT @NewNextID = ItemID from @Siblings where Ordinal = @index DECLARE @NewPreviousID int SELECT @NewPreviousID = ItemID from @Siblings where Ordinal = @index -1 --PRINT '****************************************************************' --PRINT '@ItemID = ' + isnull(Cast( @ItemID as varchar(20)),'{null}') --PRINT '@OldPreviousID = ' + isnull(Cast( @OldPreviousID as varchar(20)),'{null}') --PRINT '@OldNextID = ' + isnull(Cast( @OldNextID as varchar(20)),'{null}') --PRINT '@NewPreviousID = ' + isnull(Cast( @NewPreviousID as varchar(20)),'{null}') --PRINT '@NewNextID = ' + isnull(Cast( @NewNextID as varchar(20)),'{null}') Update Items set PreviousID = @NewPreviousID where ItemID = @ItemID Insert INTO @ItemsChanged Select @ItemID IF @OldNextID is not Null BEGIN Update Items set PreviousID = @OldPreviousID where ItemID = @OldNextID Insert INTO @ItemsChanged Select @OldNextID END IF @NewNextID is not Null BEGIN Update Items set PreviousID = @ItemID where ItemID = @NewNextID Insert INTO @ItemsChanged Select @NewNextID END IF @OldPreviousID is null BEGIN Update Parts set ItemID = @OldNextID where ItemID = @ItemID Update DocVersions set ItemID = @OldNextID where ItemID = @ItemID END IF @NewPreviousID is null BEGIN Update Parts set ItemID = @ItemID where ItemID = @NewNextID Update DocVersions set ItemID = @ItemID where ItemID = @NewNextID END SELECT ii.[ItemID], [PreviousID], ii.[ContentID], ii.[DTS], ii.[UserID], ii.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ii.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ii.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ii.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ii.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ii.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ii.[ItemID]) [Transition_ToIDCount] FROM [Items] ii WHERE ItemID in (Select ItemID from @ItemsChanged) IF( @@TRANCOUNT > 0 ) BEGIN PRINT 'COMMIT' COMMIT END END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) BEGIN PRINT 'ROLLBACK' ROLLBACK -- Only rollback if top level END ELSE IF( @@TRANCOUNT > 1 ) BEGIN PRINT 'COMMIT' COMMIT -- Otherwise commit. Top level will rollback END EXEC vlnErrorHandler END CATCH GO IF (@@Error = 0) PRINT 'Procedure Creation: MoveItem Succeeded' ELSE PRINT 'Procedure Creation: MoveItem Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_AllSiblingItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_AllSiblingItems]; GO /* DECLARE @ItemID int select @ItemID = ItemID from DocVersions where VersionID = 1 Select * from vefn_AllSiblingItems(@ItemID) order by Ordinal */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_AllSiblingItems](@ItemID int) RETURNS @Siblings TABLE ( ItemID int, Ordinal int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([ItemID], [PreviousID], [Ordinal]) as ( Select [ItemID], [PreviousID], case when [PreviousID] is null then 0 else -1 end FROM [Items] where [ItemID]=@ItemID -- Previous Siblings Union All select I.[ItemID], I.[PreviousID] ,case when I.[PreviousID] is null then 0 else Z.[Ordinal] -1 end from Itemz Z join Items I on I.ItemID = Z.PreviousID where Z.Ordinal < 0 -- Next Siblings Union All select I.[ItemID], I.[PreviousID] ,Z.[Ordinal] +1 from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.Ordinal >= 0 ) insert into @Siblings select ItemID, Ordinal from Itemz Where Ordinal >= 0 OPTION (MAXRECURSION 10000) RETURN END GO IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_AllSiblingItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_AllSiblingItems Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_JustSiblingItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_JustSiblingItems]; GO /* DECLARE @ItemID int select @ItemID = ItemID from DocVersions where VersionID = 1 Select * from vefn_JustSiblingItems(@ItemID) order by Ordinal */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_JustSiblingItems](@FirstItemID int) RETURNS @Siblings TABLE ( ItemID int PRIMARY KEY, Ordinal int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([ItemID],[Ordinal]) as ( Select [ItemID],0 FROM [Items] where [ItemID]=@FirstItemID -- Siblings Union All select I.[ItemID],Z.[Ordinal] +1 from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @Siblings select ItemID, Ordinal from Itemz OPTION (MAXRECURSION 10000) RETURN END GO IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_JustSiblingItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_JustSiblingItems Error on Creation' GO /****** Object: StoredProcedure [vesp_ResetFolderManualOrder] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ResetFolderManualOrder]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ResetFolderManualOrder]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ResetFolderManualOrder] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION update fld set Fld.ManualOrder =Fld.MyRow from (Select ROW_NUMBER() OVER(Partition by ParentID Order BY FolderID) MyRow,* from folders ) fld 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: vesp_ResetFolderManualOrder Succeeded' ELSE PRINT 'Procedure Creation: vesp_ResetFolderManualOrder Error on Creation' GO /****** Object: StoredProcedure [vesp_ResetFolderManualOrderAlphabetical] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ResetFolderManualOrderAlphabetical]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ResetFolderManualOrderAlphabetical]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ResetFolderManualOrderAlphabetical] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION update fld set Fld.ManualOrder =Fld.MyRow from (Select case when FolderID <> ParentID then ROW_NUMBER() OVER(Partition by ParentID Order BY Name) else 0 end MyRow,* from folders) fld 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: vesp_ResetFolderManualOrderAlphabetical Succeeded' ELSE PRINT 'Procedure Creation: vesp_ResetFolderManualOrderAlphabetical Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tr_Documents_Delete]') AND OBJECTPROPERTY(id,N'IsTrigger') = 1) DROP TRIGGER [tr_Documents_Delete]; /****** Object: Trigger [dbo].[tr_Documents_Delete] Script Date: 03/28/2013 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /****** Object: Trigger [tr_Documents_Delete] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE trigger [dbo].[tr_Documents_Delete] on [dbo].[Documents] instead of delete as begin update ii set DeleteStatus = Isnull((select max(DeleteID) from DeleteLog where SPID = @@spid),-1), DTS = getdate(), UserID = IsNull((select top 1 UserID from DeleteLog where SPID = @@spid order by deleteid desc),ii.UserID) from tblDocuments ii inner join deleted dd on dd.DocID = ii.DocID insert into DocumentAudits(DocID,LibTitle,DocContent,DocAscii,Config,DTS,UserID,FileExtension,DeleteStatus) select ii.DocID,ii.LibTitle,ii.DocContent,ii.DocAscii,ii.Config,ii.DTS,ii.UserID,ii.FileExtension,ii.DeleteStatus from tblDocuments ii inner join deleted dd on dd.DocID = ii.DocID where ii.DeleteStatus != 0 end GO -- Display the status of Trigger alter IF (@@Error = 0) PRINT 'Trigger alteration: tr_Documents_Delete Succeeded' ELSE PRINT 'Trigger alteration: tr_Documents_Delete Error on Alteration' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetVersionItems] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetVersionItems('') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionItems](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key ) WITH EXECUTE AS OWNER AS BEGIN BEGIN with Itemz([VersionID], [ItemID], [ContentID]) as (Select DV.VersionID, [I].[ItemID], [I].[ContentID] FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select Z.VersionID, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID Union All -- Siblings select Z.VersionID, I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @VersionItems select VersionID, [ItemID], [ContentID] from ItemZ I --Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) END RETURN END go IF (@@Error = 0) PRINT 'TableFunction [vefn_GetVersionItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetVersionItems] Error on Creation' /****** Object: StoredProcedure [getAffectedRoUsages] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAffectedRoUsages]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAffectedRoUsages]; GO /* getAffectedROUsages 1, '00010000019c0000', 'KBR Test', 'Changed', 'KBR' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getAffectedRoUsages] ( @RODbID int, @ROID nvarchar(16), @RODesc nvarchar(MAX), @Command nvarchar(10), @UserID nvarchar(100), @VersionList nvarchar(MAX) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @JustThisVersion TABLE ( ContentID int primary key ) Insert INTO @JustThisVersion SELECT Distinct ContentID From vefn_GetVersionItems(@VersionList) DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' -- Add "Verification Required" Annotation for each ROUsage INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Referenced Object (' + @RODesc + ') ' + @Command,@UserID FROM Items where CONTENTID in (SELECT ContentID FROM ROUSAGES where RODbID = @RODbID AND ROID = @ROID AND ContentID in (select ContentID from @JustThisVersion)) SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] WHERE [RoUsages].[RODbID]=@RODbID AND [RoUsages].[ROID]=@ROID AND [Contents].ContentID in (select ContentID from @JustThisVersion) END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getAffectedRoUsages Succeeded' ELSE PRINT 'Procedure Creation: getAffectedRoUsages Error on Creation' GO /****** Object: StoredProcedure [getAffectedDRoUsages] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAffectedDRoUsages]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAffectedDRoUsages]; GO /* getAffectedDROUsages 1, '00010000019c0000', 'KBR Test', 'Changed', 'KBR','' getAffectedDROUsages 1, '000300003D8E', 'KBR Test', 'Changed', 'KBR','' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getAffectedDRoUsages] ( @RODbID int, @ROID nvarchar(16), @RODesc nvarchar(MAX), @Command nvarchar(10), @UserID nvarchar(100), @VersionList nvarchar(max) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @JustThisVersion TABLE ( ContentID int primary key ) Insert INTO @JustThisVersion SELECT Distinct ContentID From vefn_GetVersionItems(@VersionList) DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' DECLARE @DRoUsages TABLE ( DRoUsageID int primary key ) Insert INTO @DRoUsages select DRoUsageID from DRoUsages where ROID like substring(@ROID,1,12) + '%' AND dbo.vefn_CompareROIDS(ROID,@ROID) > 0 -- Add "Verification Required" Annotation for each ROUsage INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT ItemID, @typeID,'Referenced Object (' + @RODesc + ') ' + @Command,@UserID FROM Items where CONTENTID in (SELECT ContentID FROM (select dr.* from DRoUsages dr join @DRoUsages dd on dr.DRoUsageid = dd.DRoUsageid) DR JOIN Entries EE on EE.DocID = DR.DocID where RODbID = @RODbID AND ContentID in (select ContentID from @JustThisVersion)) SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DRoUsages] JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] WHERE [DRoUsages].[DRoUsageID] in (select DRoUsageid from @DRoUsages) AND [Documents].[DocID] in (select EE.DocID from Entries EE where ContentID in (select ContentID from @JustThisVersion)) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getAffectedDRoUsages Succeeded' ELSE PRINT 'Procedure Creation: getAffectedDRoUsages Error on Creation' GO /****** Object: StoredProcedure [deleteAnnotationType] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteAnnotationType]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [deleteAnnotationType]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[deleteAnnotationType] ( @TypeID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [tblAnnotations] WHERE [TypeID]=@TypeID DELETE [AnnotationTypes] WHERE [TypeID] = @TypeID 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: deleteAnnotationType Succeeded' ELSE PRINT 'Procedure Creation: deleteAnnotationType Error on Creation' GO /****** Object: StoredProcedure [getJustFormat] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getJustFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getJustFormat]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getJustFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [FormatID]=@FormatID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getJustFormat Succeeded' ELSE PRINT 'Procedure Creation: getJustFormat Error on Creation' GO /****** Object: StoredProcedure [vesp_TurnChangeManagerOFF] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_TurnChangeManagerOFF]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_TurnChangeManagerOFF]; GO /****** Object: StoredProcedure [dbo].[vesp_TurnChangeManagerOFF] Script Date: 03/20/2012 16:02:54 ******/ /* exec vesp_TurnChangeManagerOFF */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_TurnChangeManagerOFF] WITH EXECUTE AS OWNER AS BEGIN DECLARE @cmd VARCHAR(MAX) SET @cmd = 'DISABLE TRIGGER tr_Annotations_Delete ON Annotations' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Contents_Delete ON Contents' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Documents_Delete ON Documents' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Entries_Delete ON Entries' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_GridAudits_insert ON GridAudits' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Grids_Delete ON Grids' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Images_Delete ON Images' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Items_Delete ON Items' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Parts_Delete ON Parts' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_ROUsages_Delete ON ROUsages' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblAnnotations_Update ON tblAnnotations' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblContents_Update ON tblContents' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblDocuments_Update ON tblDocuments' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblEntries_Update ON tblEntries' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblGrids_Update ON tblGrids' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblImages_Update ON tblImages' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblItems_Update ON tblItems' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblParts_Update ON tblParts' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblROUsages_Update ON tblROUsages' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_tblTransitions_Update ON tblTransitions' EXEC (@cmd) SET @cmd = 'DISABLE TRIGGER tr_Transitions_Delete ON Transitions' EXEC (@cmd) PRINT '***** Change Manager has been turned OFF *****' END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_TurnChangeManagerOFF Succeeded' ELSE PRINT 'Procedure Creation: vesp_TurnChangeManagerOFF Error on Creation' GO /****** Object: StoredProcedure [vesp_TurnChangeManagerON] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_TurnChangeManagerON]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_TurnChangeManagerON]; GO /****** Object: StoredProcedure [dbo].[vesp_TurnChangeManagerON] Script Date: 03/20/2012 16:02:54 ******/ /* exec vesp_TurnChangeManagerON */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_TurnChangeManagerON] WITH EXECUTE AS OWNER AS BEGIN DECLARE @cmd VARCHAR(MAX) SET @cmd = 'ENABLE TRIGGER tr_Annotations_Delete ON Annotations' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Contents_Delete ON Contents' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Documents_Delete ON Documents' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Entries_Delete ON Entries' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_GridAudits_insert ON GridAudits' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Grids_Delete ON Grids' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Images_Delete ON Images' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Items_Delete ON Items' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Parts_Delete ON Parts' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_ROUsages_Delete ON ROUsages' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblAnnotations_Update ON tblAnnotations' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblContents_Update ON tblContents' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblDocuments_Update ON tblDocuments' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblEntries_Update ON tblEntries' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblGrids_Update ON tblGrids' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblImages_Update ON tblImages' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblItems_Update ON tblItems' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblParts_Update ON tblParts' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblROUsages_Update ON tblROUsages' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_tblTransitions_Update ON tblTransitions' EXEC (@cmd) SET @cmd = 'ENABLE TRIGGER tr_Transitions_Delete ON Transitions' EXEC (@cmd) PRINT '***** Change Manager has been turned ON *****' END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_TurnChangeManagerON Succeeded' ELSE PRINT 'Procedure Creation: vesp_TurnChangeManagerON Error on Creation' GO /****** Object: TableFunction [vefn_FindROUsageIDs] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindROUsageIDs]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindROUsageIDs]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindROUsageIDs](@ContentAuditID int) RETURNS @IDs TABLE ( ROUsageID int PRIMARY KEY, ROUsageAction char(3) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ContentID int DECLARE @text varchar(max) SELECT @ContentID = ContentID,@text = Text FROM ContentAudits WHERE AuditID = @ContentAuditID DECLARE @index1 int DECLARE @index2 int DECLARE @tid varchar(max) DECLARE @trid int WHILE (LEN(@text) > 0) BEGIN SET @index1 = CHARINDEX('#Link:ReferencedObject' , @text) IF (@index1 > 0) BEGIN SET @text = RIGHT(@text, (LEN(@text) - (22 + @index1))) SET @index1 = CHARINDEX(' ', @text) SET @tid = LTRIM(LEFT(@text, @index1)) SET @trid = CAST(@tid AS INT) IF EXISTS (SELECT ROUsageID FROM tblROUsages WHERE ROUsageID = @trid AND DeleteStatus < 0) INSERT INTO @IDs VALUES (@trid, 'ADD') ELSE INSERT INTO @IDs VALUES (@trid, NULL) END ELSE SET @text = '' END INSERT INTO @IDs SELECT tt.ROUsageID,'DEL' FROM tblROUsages tt LEFT JOIN @IDs ti ON tt.ROUsageID = ti.ROUsageID WHERE tt.ContentID = @ContentID AND ti.ROUsageID IS NULL DELETE FROM @IDs WHERE ROUsageAction IS NULL RETURN END GO -- Display the status of func creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindROUsageIDs Succeeded' ELSE PRINT 'TableFunction Creation: vefn_FindROUsageIDs Error on Creation' GO /****** Object: TableFunction [vefn_GetVersionFormatItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionFormatItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionFormatItems]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionFormatItems](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key, FormatID int, ParentFormatID int ) WITH EXECUTE AS OWNER AS BEGIN BEGIN with Itemz([VersionID], [ItemID], [ContentID], [FormatID], [ParentFormatID]) as (Select DV.VersionID, [I].[ItemID], [I].[ContentID], isnull(C.[FormatID],isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID]))), isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID])) FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] join docversions DV2 on DV.[VersionID] = DV2.[VersionID] join folders F on DV2.[FolderID] = F.[FolderID] join folders P on P.[FolderID] = F.[ParentID] join Contents C on I.ContentID = C.ContentID Union All -- Children select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[FormatID]), Z.[FormatID] 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 Union All -- Siblings select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[ParentFormatID]), Z.[ParentFormatID] from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on I.ContentID = C.ContentID ) insert into @VersionItems select VersionID, [ItemID], [ContentID], [FormatID], [ParentFormatID] from ItemZ I --Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of func creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetVersionFormatItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetVersionFormatItems Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getDRoUsagesByROIDsAndVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getDRoUsagesByROIDsAndVersions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getDRoUsagesByROIDsAndVersions] ( @ROIDs nvarchar(MAX), @Versions nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DRoUsages] JOIN vefn_SplitROSearch(@ROIDs) SS ON [DRoUsages].RODBID = SS.[RODBID] and [DRoUsages].[ROID] like SS.[ROID] + '%' JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] Where [Documents].[DocID] in (Select Distinct [DocID] from [ENTRIES] JOIN [VEFN_GetVersionItems](@Versions) VV ON [Entries].ContentID = VV.ContentID) RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getDRoUsagesByROIDsAndVersions Succeeded' ELSE PRINT 'Procedure Creation: getDRoUsagesByROIDsAndVersions Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getRoUsagesByROIDsAndVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getRoUsagesByROIDsAndVersions]; GO CREATE PROCEDURE [dbo].[getRoUsagesByROIDsAndVersions] ( @ROIDs nvarchar(MAX), @Versions nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN vefn_SplitROSearch(@ROIDs) SS ON [RoUsages].RODBID = SS.[RODBID] and [RoUsages].[ROID] like SS.[ROID] + '%' JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] JOIN [VEFN_GetVersionItems](@Versions) VV ON [Contents].ContentID = VV.ContentID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getRoUsagesByROIDsAndVersions Succeeded' ELSE PRINT 'Procedure Creation: getRoUsagesByROIDsAndVersions Error on Creation' GO /****** Object: TableFunction [vefn_GetROTokens] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetROTokens]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetROTokens]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetROTokens](@text varchar(MAX)) RETURNS @Tokens TABLE ( Token varchar(MAX) ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @index int SET @index = -1 DECLARE @indexb int DECLARE @indexc int DECLARE @indexd int DECLARE @indexNext int DECLARE @indexReturn int WHILE (LEN(@text) > 0) BEGIN SET @index = PATINDEX('%<[A-Z]-%' , @text) SET @indexb = PATINDEX('%<[A-Z][A-Z0-9]-%' , @text) if((@index=0 and @indexb>0) or (@indexb > 0 and @index > @indexb)) SET @index = @indexb SET @indexc = PATINDEX('%<[A-Z][A-Z][A-Z0-9]-%' , @text) if((@index=0 and @indexc>0) or (@indexc > 0 and @index > @indexc)) SET @index = @indexc SET @indexd = PATINDEX('%<[A-Z][A-Z][A-Z][A-Z0-9]-%' , @text) if((@index=0 and @indexd>0) or (@indexd > 0 and @index > @indexd)) SET @index = @indexd IF @index = 0 BREAK SET @indexNext = @index + CHARINDEX('<' , substring(@text,@index+1,len(@text))) IF @IndexNext=@index SET @IndexNext = len(@text)+ 3 SET @indexReturn = @index + CHARINDEX(char(13) , substring(@text,@index+1,len(@text))) IF @IndexReturn=@index SET @IndexReturn = len(@text)+3 DECLARE @index2 int SET @index2 = @index + CHARINDEX('>' , substring(@text,@index,len(@text))) if @index2 = @index BREAK if(@index2 > @indexNext or @index2 > @indexReturn) SET @text = RIGHT(@text, (LEN(@text) - @index)) else BEGIN INSERT INTO @Tokens VALUES (substring(@text, @index,@index2-@index)) if(len(@text) > @index2) SET @text = substring(@text, @index2 , len(@text)) else SET @Text = '' END END RETURN END GO -- Display the status of func creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetROTokens Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetROTokens Error on Creation' GO /****** Object: TableFunction [vefn_GetVersionNames] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionNames]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionNames]; GO -- -- select * from vefn_GetVersionNames() -- /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionNames]() RETURNS @Versions TABLE ( VersionID int primary Key, GrandParentName nvarchar(100), ParentName nvarchar(100), FolderName nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @Versions select versionid,gf.name GrandParentName, pf.name ParentName, ff.name FolderName from docversions dv Join folders ff on ff.FolderID = DV.FolderID Join folders pf on pf.FolderID = ff.parentID Join folders gf on gf.FolderID = pf.parentid RETURN END GO -- Display the status of func creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetVersionNames Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetVersionNames Error on Creation' GO -- =========================================== End of Functions and Procedures -- Turn off Auto Close and Auto Shrink declare @CMD varchar(max) set @CMD = 'ALTER DATABASE [' + db_name() +'] SET AUTO_CLOSE OFF' exec(@CMD) GO declare @CMD varchar(max) set @CMD = 'ALTER DATABASE [' + db_name() +'] SET AUTO_SHRINK OFF' exec(@CMD) GO --added by JCB for Security and MultiUser support --ALTER TABLE Sessions add MachineName and ProcessID columns if they do not exist IF COL_LENGTH('Sessions','MachineName') IS NULL ALTER TABLE Sessions ADD [MachineName] [nvarchar](100) NOT NULL,[ProcessID] [int] NOT NULL; GO --ALTER TABLE Sessions change DTSActivity column to not null ALTER TABLE sessions ALTER COLUMN [DTSActivity] [datetime] NOT NULL GO --ALTER TABLE Sessions set DTSActivity column default value to getdate() IF OBJECT_ID('DF_Sessions_DTSActivity', 'D') IS NULL ALTER TABLE sessions ADD CONSTRAINT [DF_Sessions_DTSActivity] DEFAULT (getdate()) for [DTSActivity]; 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]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[purgeData] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION delete from [AnnotationAudits] dbcc checkident([AnnotationAudits],reseed,0) delete from [Applicabilities] dbcc checkident([Applicabilities],reseed,0) delete from [ApplicableStructures] delete from [Assignments] dbcc checkident([Assignments],reseed,0) delete from [Associations] dbcc checkident([Associations],reseed,0) delete from [Checks] dbcc checkident([Checks],reseed,0) delete from [ContentAudits] dbcc checkident([ContentAudits],reseed,0) delete from [DeleteLog] dbcc checkident([DeleteLog],reseed,0) delete from [Details] dbcc checkident([Details],reseed,0) delete from [DocumentAudits] dbcc checkident([DocumentAudits],reseed,0) delete from [DocVersions] dbcc checkident([DocVersions],reseed,0) delete from [DROUsages] dbcc checkident([DROUsages],reseed,0) delete from [EntryAudits] dbcc checkident([EntryAudits],reseed,0) delete from [Figures] dbcc checkident([Figures],reseed,0) delete from [Folders] dbcc checkident([Folders],reseed,0) delete from [GridAudits] dbcc checkident([GridAudits],reseed,0) delete from [ImageAudits] dbcc checkident([ImageAudits],reseed,0) delete from [ItemAudits] dbcc checkident([ItemAudits],reseed,0) delete from [Memberships] dbcc checkident([Memberships],reseed,0) delete from [PartAudits] dbcc checkident([PartAudits],reseed,0) delete from [Pdfs] delete from [Permissions] dbcc checkident([Permissions],reseed,0) delete from [ROFsts] dbcc checkident([ROFsts],reseed,0) delete from [ROImages] dbcc checkident([ROImages],reseed,0) delete from [Roles] dbcc checkident([Roles],reseed,0) delete from [ROUsageAudits] dbcc checkident([ROUsageAudits],reseed,0) delete from [tblAnnotations] dbcc checkident([tblAnnotations],reseed,0) delete from [tblEntries] delete from [tblGrids] delete from [tblImages] delete from [tblParts] delete from [tblROUsages] dbcc checkident([tblROUsages],reseed,0) delete from [TransitionAudits] dbcc checkident([TransitionAudits],reseed,0) delete from [Users] dbcc checkident([Users],reseed,0) delete from [Versions] dbcc checkident([Versions],reseed,0) delete from [ZContents] delete from [ZTransitions] delete from [AnnotationTypes] dbcc checkident([AnnotationTypes],reseed,0) delete from [Connections] dbcc checkident([Connections],reseed,0) delete from [Groups] dbcc checkident([Groups],reseed,0) delete from [Revisions] dbcc checkident([Revisions],reseed,0) delete from [RODbs] dbcc checkident([RODbs],reseed,0) delete from [Stages] dbcc checkident([Stages],reseed,0) delete from [tblDocuments] dbcc checkident([tblDocuments],reseed,0) delete from [tblTransitions] dbcc checkident([tblTransitions],reseed,0) delete from [tblItems] dbcc checkident([tblItems],reseed,0) delete from [tblContents] dbcc checkident([tblContents],reseed,0) delete from [Formats] dbcc checkident([Formats],reseed,0) delete from [Sessions] dbcc checkident([Sessions],reseed,0) delete from [Owners] dbcc checkident([Owners],reseed,0) 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: purgeData Succeeded' ELSE PRINT 'Procedure Creation: purgeData Error on Creation' GO /****** Object: StoredProcedure [getSessions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getSessions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getSessions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getSessions] WITH EXECUTE AS OWNER AS SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getSessions Succeeded' ELSE PRINT 'Procedure Creation: getSessions Error on Creation' GO /****** Object: StoredProcedure [updateSession] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[updateSession]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [updateSession]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[updateSession] ( @SessionID int, @UserID nvarchar(100), @DTSDtart datetime, @DTSEnd datetime=null, @DTSActivity datetime, @LastChanged timestamp, @MachineName nvarchar(100), @ProcessID int, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Sessions] SET [UserID]=@UserID, [DTSDtart]=@DTSDtart, [DTSEnd]=@DTSEnd, [DTSActivity]=@DTSActivity, [MachineName]=@MachineName, [ProcessID]=@ProcessID WHERE [SessionID]=@SessionID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Sessions] WHERE [SessionID]=@SessionID) RAISERROR('Session record has been deleted by another user', 16, 1) ELSE RAISERROR('Session has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Sessions] WHERE [SessionID]=@SessionID 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: updateSession Succeeded' ELSE PRINT 'Procedure Creation: updateSession Error on Creation' GO /****** Object: StoredProcedure [addSession] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addSession]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addSession]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addSession] ( @UserID nvarchar(100), @DTSDtart datetime, @DTSEnd datetime=null, @DTSActivity datetime, @MachineName nvarchar(100), @ProcessID int, @newSessionID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Sessions] ( [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [MachineName], [ProcessID] ) VALUES ( @UserID, @DTSDtart, @DTSEnd, @DTSActivity, @MachineName, @ProcessID ) SELECT @newSessionID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Sessions] WHERE [SessionID]=@newSessionID 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: addSession Succeeded' ELSE PRINT 'Procedure Creation: addSession Error on Creation' GO /****** Object: StoredProcedure [deleteSession] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteSession]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [deleteSession]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[deleteSession] ( @SessionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Sessions] WHERE [SessionID] = @SessionID 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: deleteSession Succeeded' ELSE PRINT 'Procedure Creation: deleteSession Error on Creation' GO /****** Object: StoredProcedure [getSession] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getSession]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getSession]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getSession] ( @SessionID int ) WITH EXECUTE AS OWNER AS SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE [SessionID]=@SessionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getSession Succeeded' ELSE PRINT 'Procedure Creation: getSession Error on Creation' GO /****** Object: StoredProcedure [existsSession] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[existsSession]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [existsSession]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[existsSession] ( @SessionID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Sessions] WHERE [SessionID]=@SessionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: existsSession Succeeded' ELSE PRINT 'Procedure Creation: existsSession Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionCleanup] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionBegin]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionBegin]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SessionBegin] ( @UserID nvarchar(100), @MachineName nvarchar(100), @ProcessID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- Cleanup Old Records before checking for Owner Records --delete old closed sessions DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is not null --delete old owners from inactive sessions DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate())) DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate())) --delete inactive sessions where last activity is before 15 minutes ago DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate()) DELETE FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate()) DELETE FROM Owners WHERE SessionID not in (SELECT SessionID FROM Sessions) DECLARE @oCount int SELECT @oCount = count(*) FROM Owners WHERE OwnerType = 4 IF @oCount > 0 BEGIN SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE [SessionID]=0 END ELSE BEGIN INSERT INTO [Sessions]([UserID],[MachineName],[ProcessID]) VALUES (@UserID, @MachineName, @ProcessID) SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE [SessionID]=SCOPE_IDENTITY() IF( @@TRANCOUNT > 0 ) COMMIT END 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: vesp_SessionBegin Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionBegin Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionPing] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionPing]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionPing]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SessionPing] ( @SessionID int ) WITH EXECUTE AS OWNER AS BEGIN --update active session dtsactivity value UPDATE Sessions SET DTSActivity = getdate() WHERE SessionID = @SessionID END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SessionPing Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionPing Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionPing] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionEnd]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionEnd]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SessionEnd] ( @SessionID int ) WITH EXECUTE AS OWNER AS BEGIN --delete unclosed owners for session being closed DELETE FROM Owners WHERE SessionID = @SessionID --update active session dtsend value UPDATE Sessions SET DTSEnd = getdate() WHERE SessionID = @SessionID END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SessionEnd Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionEnd Error on Creation' GO /****** Object: StoredProcedure [getOwners] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwners]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwners]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwners] WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwners Succeeded' ELSE PRINT 'Procedure Creation: getOwners Error on Creation' GO /****** Object: StoredProcedure [getOwnersBySessionID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwnersBySessionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwnersBySessionID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwnersBySessionID] ( @SessionID int ) WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] WHERE [SessionID] = @SessionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwnersBySessionID Succeeded' ELSE PRINT 'Procedure Creation: getOwnersBySessionID Error on Creation' GO /****** Object: StoredProcedure [updateOwner] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[updateOwner]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [updateOwner]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[updateOwner] ( @OwnerID int, @SessionID int, @OwnerType tinyint, @OwnerItemID int, @DTSStart datetime, @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Owners] SET [SessionID]=@SessionID, [OwnerType]=@OwnerType, [OwnerItemID]=@OwnerItemID, [DTSStart]=@DTSStart WHERE [OwnerID]=@OwnerID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Owners] WHERE [OwnerID]=@OwnerID) RAISERROR('Owner record has been deleted by another user', 16, 1) ELSE RAISERROR('Owner has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Owners] WHERE [OwnerID]=@OwnerID 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: updateOwner Succeeded' ELSE PRINT 'Procedure Creation: updateOwner Error on Creation' GO /****** Object: StoredProcedure [addOwner] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addOwner]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addOwner]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addOwner] ( @SessionID int, @OwnerType tinyint, @OwnerItemID int, @DTSStart datetime, @newOwnerID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Owners] ( [SessionID], [OwnerType], [OwnerItemID], [DTSStart] ) VALUES ( @SessionID, @OwnerType, @OwnerItemID, @DTSStart ) SELECT @newOwnerID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Owners] WHERE [OwnerID]=@newOwnerID 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: addOwner Succeeded' ELSE PRINT 'Procedure Creation: addOwner Error on Creation' GO /****** Object: StoredProcedure [deleteOwner] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteOwner]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [deleteOwner]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[deleteOwner] ( @OwnerID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Owners] WHERE [OwnerID] = @OwnerID 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: deleteOwner Succeeded' ELSE PRINT 'Procedure Creation: deleteOwner Error on Creation' GO /****** Object: StoredProcedure [getOwner] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwner]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwner]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwner] ( @OwnerID int ) WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] WHERE [OwnerID]=@OwnerID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwner Succeeded' ELSE PRINT 'Procedure Creation: getOwner Error on Creation' GO /****** Object: StoredProcedure [existsOwner] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[existsOwner]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [existsOwner]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[existsOwner] ( @OwnerID int ) WITH EXECUTE AS OWNER AS SELECT COUNT(*) FROM [Owners] WHERE [OwnerID]=@OwnerID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: existsOwner Succeeded' ELSE PRINT 'Procedure Creation: existsOwner Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionCanCheckOutItem] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionCanCheckOutItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionCanCheckOutItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* exec dbo.vesp_SessionCanCheckOutItem 17012,0 exec dbo.vesp_SessionCanCheckOutItem 17066,0 exec dbo.vesp_SessionCanCheckOutItem 17119,0 exec dbo.vesp_SessionCanCheckOutItem 554,1 exec dbo.vesp_SessionCanCheckOutItem 13,2 exec dbo.vesp_SessionCanCheckOutItem 8,2 exec dbo.vesp_SessionCanCheckOutItem 2,2 exec dbo.vesp_SessionCanCheckOutItem 9,3 */ CREATE PROCEDURE [dbo].[vesp_SessionCanCheckOutItem] ( @ObjectID int, @ObjectType int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @CheckOuts TABLE ( SessionID int ) --look to see if anyone else has a session. if they do, then cannot check out DECLARE @sCount int SELECT @sCount = count(*) FROM Sessions IF @ObjectType = 4 BEGIN SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE DTSEnd IS NULL END ELSE BEGIN DECLARE @ObjectAndEnhancedIDs Table ( ObjectID int ) IF @ObjectType = 0 BEGIN INSERT INTO @ObjectAndEnhancedIDs select ItemID from vefn_GetEnhancedProcedures(@ObjectID) END ELSE IF @ObjectType = 2 BEGIN INSERT INTO @ObjectAndEnhancedIDs select VersionID from vefn_GetEnhancedDocVersions(@ObjectID) END ELSE IF @ObjectType = 3 BEGIN INSERT INTO @ObjectAndEnhancedIDs select FolderID from vefn_GetEnhancedFolders(@ObjectID) END ELSE BEGIN INSERT INTO @ObjectAndEnhancedIDs select @ObjectID END INSERT INTO @CheckOuts SELECT DISTINCT SessionID FROM Owners WHERE OwnerItemID in (select ObjectID from @ObjectAndEnhancedIDs) AND OwnerType = @ObjectType IF @ObjectType = 2 BEGIN with ItemZ (VersionID,ItemID,PreviousID,SessionID) as( --> Procedure Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Items II on OO.OwnerItemID= II.ItemID Where OO.OwnerType=0 UNION ALL --> Document Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Entries EE ON OO.OwnerItemID = EE.DocID Join Items II on EE.ContentID= II.ContentID Where OO.OwnerType=1 UNION ALL --> Previous Owners Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ Join Items II ON II.ItemID = ZZ.PreviousID Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL UNION ALL -- Parts Owners Select null, II.ItemID, II.PreviousID, ZZ.SessionID from ItemZ ZZ Join Parts PP ON PP.ItemID = ZZ.ItemID Join Items II ON II.ContentID = PP.ContentID Where ZZ.VersionID IS NULL UNION ALL -- Version Owners Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ Join DocVersions DV ON ZZ.ItemID = DV.ItemID Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL ) --Select Distinct 'Phase 2b' Result, * from Itemz INSERT INTO @CheckOuts Select DIstinct SessionID from ItemZ where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) OPTION (MAXRECURSION 10000) -- B2017-144 Crash on Maximum Recursion END --look to see if object type is folder that no part of folder passed is checked out IF @ObjectType = 3 BEGIN with ItemZ (VersionID,ItemID,PreviousID,SessionID) as( --> Procedure Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Items II on OO.OwnerItemID= II.ItemID Where OO.OwnerType=0 UNION ALL --> Document Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Entries EE ON OO.OwnerItemID = EE.DocID Join Items II on EE.ContentID= II.ContentID Where OO.OwnerType=1 UNION ALL --> Previous Owners Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ Join Items II ON II.ItemID = ZZ.PreviousID Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL UNION ALL -- Parts Owners Select null, II.ItemID, II.PreviousID, ZZ.SessionID from ItemZ ZZ Join Parts PP ON PP.ItemID = ZZ.ItemID Join Items II ON II.ContentID = PP.ContentID Where ZZ.VersionID IS NULL UNION ALL -- Version Owners Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ Join DocVersions DV ON ZZ.ItemID = DV.ItemID Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL ) --Select Distinct 'Phase 2b' Result, * from Itemz INSERT INTO @CheckOuts Select DIstinct SessionID from ItemZ where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) OPTION (MAXRECURSION 10000) -- B2017-144 Crash on Maximum Recursion END SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE [SessionID] IN (SELECT SessionID FROM @CheckOuts) END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SessionCanCheckOutItem Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionCanCheckOutItem Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionCheckOutItem] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionCheckOutItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionCheckOutItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SessionCheckOutItem] ( @SessionID int, @ItemID int, @ItemType int, @OwnerID int OUTPUT ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO Owners (SessionID, OwnerItemID, OwnerType) VALUES (@SessionID, @ItemID, @ItemType) SELECT @OwnerID = SCOPE_IDENTITY() END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SessionCheckOutItem Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionCheckOutItem Error on Creation' GO /****** Object: StoredProcedure [vesp_SessionCheckInItem] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionCheckInItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionCheckInItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SessionCheckInItem] ( @OwnerID int ) WITH EXECUTE AS OWNER AS BEGIN DELETE FROM Owners WHERE OwnerID = @OwnerID END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SessionCheckInItem Succeeded' ELSE PRINT 'Procedure Creation: vesp_SessionCheckInItem Error on Creation' GO /****** Object: StoredProcedure [getOwnerByItemID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwnerByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwnerByItemID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwnerByItemID] ( @ItemID int, @ItemType int ) WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] WHERE [OwnerItemID]=@ItemID AND [OwnerType]=@ItemType RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwnerByItemID Succeeded' ELSE PRINT 'Procedure Creation: getOwnerByItemID Error on Creation' GO /****** Object: StoredProcedure [getOwnerBySessionIDandVersionID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwnerBySessionIDandVersionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwnerBySessionIDandVersionID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwnerBySessionIDandVersionID] ( @SessionID int, @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] oo INNER JOIN ( SELECT 0 ObjectType,ItemID ObjectID FROM dbo.vefn_GetVersionItems(@VersionID) UNION SELECT 1 ObjectType,ee.DocID ObjectID FROM dbo.vefn_GetVersionItems(@VersionID) vi INNER JOIN Contents cc ON vi.ContentID = cc.ContentID INNER JOIN Entries ee ON vi.ContentID = ee.ContentID UNION SELECT 2 ObjectType, @VersionID ObjectID ) tt ON oo.OwnerType = tt.ObjectType and oo.OwnerItemID = tt.ObjectID WHERE [SessionID] = @SessionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwnerBySessionIDandVersionID Succeeded' ELSE PRINT 'Procedure Creation: getOwnerBySessionIDandVersionID Error on Creation' GO /****** Object: StoredProcedure [getUserByUserID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getUserByUserID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getUserByUserID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getUserByUserID] ( @UserID varchar(100) ) WITH EXECUTE AS OWNER AS SELECT [UID], [UserID], [FirstName], [MiddleName], [LastName], [Suffix], [CourtesyTitle], [PhoneNumber], [CFGName], [UserLogin], [UserName], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[UID]=[Users].[UID]) [MembershipCount] FROM [Users] WHERE [UserID]=@UserID SELECT [Memberships].[UGID], [Memberships].[UID], [Memberships].[GID], [Memberships].[StartDate], [Memberships].[EndDate], [Memberships].[Config], [Memberships].[DTS], [Memberships].[UsrID], [Memberships].[LastChanged], [Groups].[GroupName] [Group_GroupName], [Groups].[GroupType] [Group_GroupType], [Groups].[Config] [Group_Config], [Groups].[DTS] [Group_DTS], [Groups].[UsrID] [Group_UsrID] FROM [Memberships] JOIN [Groups] ON [Groups].[GID]=[Memberships].[GID] JOIN [Users] ON [Memberships].[UID] = [Users].[UID] WHERE [Users].[UserID]=@UserID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getUserByUserID Succeeded' ELSE PRINT 'Procedure Creation: getUserByUserID Error on Creation' GO --need to check to see if security is already defined. if not then do this stuff declare @aCount int select @aCount = count(*) from assignments if @aCount = 0 begin --clean up security related tables EXEC sp_executesql N' delete from [Assignments]' EXEC sp_executesql N' dbcc checkident([Assignments],reseed,0)' EXEC sp_executesql N' delete from [Memberships]' EXEC sp_executesql N' dbcc checkident([Memberships],reseed,0)' EXEC sp_executesql N' delete from [Permissions]' EXEC sp_executesql N' dbcc checkident([Permissions],reseed,0)' EXEC sp_executesql N' delete from [Roles]' EXEC sp_executesql N' dbcc checkident([Roles],reseed,0)' EXEC sp_executesql N' delete from [Users]' EXEC sp_executesql N' dbcc checkident([Users],reseed,0)' EXEC sp_executesql N' delete from [Groups]' EXEC sp_executesql N' dbcc checkident([Groups],reseed,0)' --define Roles EXEC sp_executesql N' insert into Roles (Name,Title,DTS,UsrID) values (''Administrator'',''Manage Generic Data;Manage Security;Edit RO Values,Create FST,Update RO Values;Update Formats;PROMS Settings;Create/Update/Delete Folders,DocVersions,Procedures,Sections,Steps,All Annotations'',getdate(),''VEPROMS'')' EXEC sp_executesql N' insert into Roles (Name,Title,DTS,UsrID) values (''Set Administrator'',''Edit RO Values,Create FST,Update RO Values;Create/Update/Delete Folders,DocVersions,Procedures,Sections,Steps,All Set Annotations'',getdate(),''VEPROMS'')' EXEC sp_executesql N' insert into Roles (Name,Title,DTS,UsrID) values (''Writer'',''Create/Update/Delete Procedures,Sections,Steps,All Set Annotations'',getdate(),''VEPROMS'')' EXEC sp_executesql N' insert into Roles (Name,Title,DTS,UsrID) values (''Reviewer'',''Create/Update/Delete User Annotations'',getdate(),''VEPROMS'')' EXEC sp_executesql N' insert into Roles (Name,Title,DTS,UsrID) values (''RO Editor'',''Edit RO Values,Create FST'',getdate(),''VEPROMS'')' --define Permissions for Roles EXEC sp_executesql N' declare @rid int; select @rid = rid from roles where name = ''Administrator''; insert into permissions (rid,permlevel,versiontype,permvalue,permad,startdate,dts,usrid) values (@rid,1,3,15,0,getdate(),getdate(),''VEPROMS'')' EXEC sp_executesql N' declare @rid int; select @rid = rid from roles where name = ''Set Administrator''; insert into permissions (rid,permlevel,versiontype,permvalue,permad,startdate,dts,usrid) values (@rid,2,3,15,0,getdate(),getdate(),''VEPROMS'')' EXEC sp_executesql N' declare @rid int; select @rid = rid from roles where name = ''Writer''; insert into permissions (rid,permlevel,versiontype,permvalue,permad,startdate,dts,usrid) values (@rid,4,3,15,0,getdate(),getdate(),''VEPROMS'')' EXEC sp_executesql N' declare @rid int; select @rid = rid from roles where name = ''Reviewer''; insert into permissions (rid,permlevel,versiontype,permvalue,permad,startdate,dts,usrid) values (@rid,7,3,15,0,getdate(),getdate(),''VEPROMS'')' EXEC sp_executesql N' declare @rid int; select @rid = rid from roles where name = ''RO Editor''; insert into permissions (rid,permlevel,versiontype,permvalue,permad,startdate,dts,usrid) values (@rid,3,3,15,0,getdate(),getdate(),''VEPROMS'')' --define adminstrator Group EXEC sp_executesql N' insert into groups (groupname,dts,usrid) select name + ''s'',getdate(),''VEPROMS'' from roles where name = ''Administrator''' --define administrator Assignment EXEC sp_executesql N' insert into assignments (gid,rid,folderid,startdate,dts,usrid) select gg.gid,rr.rid,1,getdate(),getdate(),''VEPROMS'' from roles rr inner join groups gg on rr.name + ''s'' = gg.groupname' EXEC sp_executesql N' print ''MultiUser and Security Created''' end else begin EXEC sp_executesql N' print ''MultiUser and Security Exists''' end GO --added jcb 1st round fixes multiuser and security testting --ALTER TABLE Groups change GroupName column to 100 characters ALTER TABLE groups ALTER COLUMN [GroupName] [nvarchar](100) NOT NULL GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ResetSecurity]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ResetSecurity]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ResetSecurity] AS BEGIN DELETE FROM [Memberships] DELETE FROM [Assignments] WHERE [AID] != 1 DELETE FROM [Groups] WHERE [GID] != 1 DELETE FROM [Users] DECLARE @gid VARCHAR(10) SELECT @gid = x1.value('@Group','varchar(10)') FROM ( SELECT folderid,CAST(config as xml) xconfig FROM folders ff WHERE ff.folderid = 1 ) ah CROSS APPLY xconfig.nodes('//Security') t1(x1) UPDATE folders SET config = replace(config,'Security Group="' + @gid + '"','Security Group="1"') WHERE folderid = 1 END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ResetSecurity Succeeded' ELSE PRINT 'Procedure Creation: vesp_ResetSecurity Error on Creation' GO /****** Object: StoredProcedure [getRevisionsByItemID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getRevisionsByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getRevisionsByItemID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getRevisionsByItemID] ( @ItemID int ) WITH EXECUTE AS OWNER AS SELECT [RevisionID], [ItemID], [TypeID], [RevisionNumber], [RevisionDate], [Notes], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Checks] WHERE [Checks].[RevisionID]=[Revisions].[RevisionID]) [CheckCount], (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) [VersionCount] FROM [Revisions] WHERE [ItemID] = @ItemID and (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[RevisionID]=[Revisions].[RevisionID]) > 0 ORDER BY [RevisionID] DESC RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getRevisionsByItemID Succeeded' ELSE PRINT 'Procedure Creation: getRevisionsByItemID Error on Creation' GO /****** Object: StoredProcedure [getRoUsagesForDocVersion] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getRoUsagesForDocVersion]') AND OBJECTPROPERTY (id,N'IsProcedure') = 1) DROP PROCEDURE [getRoUsagesForDocVersion]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getRoUsagesForDocVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [ROUsageID], rr.[ContentID], [ROID], [Config], [DTS], [UserID], [LastChanged], [RODbID] FROM [RoUsages] rr INNER JOIN vefn_getversionitems(@VersionID) vi on rr.contentid = vi.contentid RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getRoUsagesForDocVersion Succeeded' ELSE PRINT 'Procedure Creation: getRoUsagesForDocVersion Error on Creation' GO /****** Object: StoredProcedure [vesp_ListTables3] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListTables3]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListTables3]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE procedure [dbo].[vesp_ListTables3] WITH EXECUTE AS OWNER AS begin select o.name TableName,c.name ColumnName, case c.system_type_id when 56 then 'int' when 231 then 'nvarchar' when 165 then 'varbinary' when 167 then 'varchar' when 239 then 'nchar' when 175 then 'char' when 61 then 'datetime' when 104 then 'bit' when 48 then 'TinyInt' when 127 then 'BigInt' when 241 then 'Xml' when 62 then 'float' when 189 then 'timestamp' else '???' + cast(c.system_type_id as varchar(10)) end ItemType, case c.system_type_id when 56 then '0' when 231 then case c.max_length when -1 then 'Max' else cast(c.max_length/2 as varchar(10)) end when 165 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 167 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 239 then case c.max_length when -1 then 'Max' else cast(c.max_length/2 as varchar(10)) end when 175 then case c.max_length when -1 then 'Max' else cast(c.max_length as varchar(10)) end when 61 then '0' when 104 then '0' when 48 then '0' when 189 then '0' else '0' end ItemSize, case when c.is_nullable=1 then 'Yes' else '' end AllowNulls, case when c.is_identity=1 then 'Identity' else dc.definition end DefaultValue, x.value Description from sys.objects o join sys.columns c on o.object_id=c.object_id left join sysconstraints cn on o.object_id=cn.id and c.column_id=cn.colid left join sys.default_constraints dc on dc.object_id = cn.constid left join sys.extended_properties x on x.major_id = o.OBJECT_ID AND x.minor_id=c.column_id AND x.Name='MS_Description' where o.type='U' order by o.name,c.column_id end GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListTables3 Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListTables3 Error on Creation' GO /****** Object: StoredProcedure [getOwnersByVersionID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwnersByVersionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getOwnersByVersionID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwnersByVersionID] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], oo.[LastChanged] FROM [Owners] oo JOIN vefn_GetVersionItems(@VersionID) vi ON oo.OwnerItemID = vi.ItemID WHERE oo.OwnerType = 0 UNION SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], oo.[LastChanged] FROM [Owners] oo JOIN [Entries] ee on oo.OwnerItemID = ee.DocID JOIN vefn_GetVersionItems(@VersionID) vi on ee.ContentID = vi.ContentID WHERE oo.OwnerType = 1 UNION SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], oo.[LastChanged] FROM [Owners] oo WHERE oo.OwnerType = 2 AND oo.OwnerItemID = @VersionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwnersByVersionID Succeeded' ELSE PRINT 'Procedure Creation: getOwnersByVersionID Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CompareROIDs]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_CompareROIDs]; /****** Object: UserDefinedFunction [dbo].[vefn_CompareROIDs] Script Date: 07/21/2014 17:50:44 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create function [DBO].[vefn_CompareROIDs] (@roid1 varchar(16), @roid2 varchar(16)) returns int as begin declare @len1 int declare @len2 int if @roid1 = @roid2 return 1 set @len1 = len(@roid1) set @len2 = len(@roid2) if @len1 = @len2 begin if @len1 = 16 and substring(@roid1,13,4) = '0000' and substring(@roid2,13,4) = '0041' return 2 if @len1 = 16 and substring(@roid2,13,4) = '0000' and substring(@roid1,13,4) = '0041' return 3 return 0 end if substring(@roid1,1,12) = substring(@roid2,1,12) return 4 return 0 end GO -- Display the status of ScalarFunction creation IF (@@Error = 0) PRINT 'Function: vefn_CompareROIDs Succeeded' ELSE PRINT 'Function: vefn_CompareROIDs Error on Creation' GO /****** Object: Index [IX_tblContentsForCopy] Script Date: 8/26/2014 8:55:16 PM ******/ IF NOT EXISTS (SELECT * FROM dbo.sysindexes WHERE name = 'IX_tblContentsForCopy') BEGIN CREATE NONCLUSTERED INDEX [IX_tblContentsForCopy] ON [dbo].[tblContents] ( [DTS] ASC, [UserID] ASC, [Type] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] END GO /****** Object: Index [IX_tblItemsForCopy1] Script Date: 8/27/2014 5:26:31 PM ******/ IF NOT EXISTS (SELECT * FROM dbo.sysindexes WHERE name = 'IX_tblItemsForCopy1') BEGIN CREATE NONCLUSTERED INDEX [IX_tblItemsForCopy1] ON [dbo].[tblItems] ( [ContentID] ASC, [DTS] ASC, [UserID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] END GO /****** Object: Index [IX_tblItemsForCopy2] Script Date: 8/27/2014 5:26:37 PM ******/ IF NOT EXISTS (SELECT * FROM dbo.sysindexes WHERE name = 'IX_tblItemsForCopy2') BEGIN CREATE NONCLUSTERED INDEX [IX_tblItemsForCopy2] ON [dbo].[tblItems] ( [PreviousID] ASC, [DTS] ASC, [UserID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] END GO /****** Object: Index [IX_contentsLastChanged] Script Date: 3/21/2017 11:24:00 AM ******/ IF EXISTS (SELECT * FROM dbo.sysIndexes WHERE name like 'IX_contentsLastChanged') DROP INDEX [IX_ContentsLastChanged] ON [dbo].[tblContents]; GO CREATE NONCLUSTERED INDEX [IX_contentsLastChanged] ON [dbo].[tblContents] ( [DeleteStatus] ASC, [LastChanged] DESC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO PRINT 'Added IX_contentsLastChanged Index. Speeds up session queries' 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 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 if exists (select * from tblitems where itemid = @StartItemID and DeleteStatus !=0) BEGIN RAISERROR ('###Cannot Paste Step###This step has been deleted',16,1) RETURN END 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 DECLARE @StartContentID INT Select @StartContentID = ContentID from Items where ItemID = @StartItemID 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 CASE when [ContentID] = @StartContentID and [Type]<20000 then 'Copy Of ' + [Number] else [Number] end, [Text],[ContentID],[FormatID],[Config],@DTS,@UserID from Contents where ContentID in(Select ContentID from @Children) -- Update the @Children with the NewConentIDs --print 'A ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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. --print 'B ' + cast(datediff(s,@dts,getdate()) as varchar(100)) DECLARE @SourceType INT Select @SourceType = Type from Contents where ContentID = @StartContentID if @SourceType = 0 BEGIN UPDATE CC set CC.Type = CC2.Type, CC.DTS = CC2.DTS, CC.UserID = CC2.UserID From Contents CC Join @Children NN on NN.NewContentID = CC.ContentID Join Contents CC2 on NN.ContentID = CC2.ContentID END else BEGIN 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 END --print 'B1 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- Contents are done -- SELECT * From Contents where DTS = @DTS and UserID = @UserID -- <<< Copy Grids >>> INSERT INTO [Grids]([ContentID],[Data],[Config],[DTS],[UserID]) SELECT NN.[NewContentID],[Data],[Config],@DTS,@UserID FROM [Grids] GG Join @Children NN on GG.ContentID = NN.ContentID -- <<< Copy Images >>> --print 'B2 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) INSERT INTO [Images]([ContentID],[ImageType],[FileName],[Data],[Config],[DTS],[UserID]) SELECT NN.[NewContentID],[ImageType],[FileName],[Data],[Config],@DTS,@UserID FROM [Images] II Join @Children NN on II.ContentID = NN.ContentID -- Create new item rows based upon the current item rows and the @Children table, with the NewContentIDs --print 'B3 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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 --print 'B4 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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 --print 'B5 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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 --print 'B6 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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. --print 'B7 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) Update Items Set PreviousID = null where ItemID = @NewStartItemID if @SourceType = 0 BEGIN UPDATE II SET II.DTS = II2.DTS, II.UserID = II2.UserID From Items II Join @Children NN on NN.NewItemID = II.ItemID Join Items II2 on NN.ItemID = II2.ItemID WHERE NN.ItemID = @StartItemID END --print 'C ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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 --print 'D ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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 --print 'E ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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 libtitles 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 --print 'F ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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] -- Logic to Create DROUsages for these newly created documents INSERT INTO [DROUsages] ([DocID],[ROID],[Config],[DTS],[UserID],[RODbID]) SELECT ND.[NewDocID],[ROID],[Config],@DTS,@UserID,[RODbID] FROM [DROUsages] RR JOIN @NewDocuments ND on RR.[DocID] = ND.[DocID] --print 'G ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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 [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 where Len([ROID]) < 12) C2 ON CC.ContentID = C2.ContentID WHERE [TEXT] <> C2.NewText SET @RowsAffected = @@RowCount END -- Update grid records for newly copied records to use correct RO usage ids in the RO tags SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE GG SET [Data] = G2.NewData FROM GRIDS GG JOIN (SELECT G1.ContentID, .dbo.vefn_FixROData(G1.Data, CAST([ROID] as int), [ROUsageID]) NewData FROM GRIDS G1 JOIN @Children NN on G1.ContentID = NN.NewContentID JOIN RoUsages RO on NN.NewContentID = RO.ContentID where Len([ROID]) < 12) G2 ON GG.ContentID = G2.ContentID WHERE Cast([Data] as nvarchar(max)) <> cast(G2.NewData as nvarchar(max)) 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 where Len(RON.[ROID]) < 12 --print 'H ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- 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],[IsRange],[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, [IsRange],[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] --print 'H1 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- -- 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 --print 'H2 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) --set nocount off -- -- Update grid records for newly copied records to use correct TransitionIDs in the Transition tags declare @grids table ( contentid int primary key, data xml ) insert into @grids select gg.contentid,gg.data from GRIDS GG where gg.contentid in (select nn.newcontentid from @Children NN JOIN Transitions TR on NN.NewContentID = TR.FromID JOIN Transitions TRO on TR.TranType = TRO.TransitionID) --print 'H2.1 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) --select * from @grids SET @RowsAffected=1 WHILE @RowsAffected > 0 BEGIN UPDATE GG SET [DATA] = G2.NewData FROM @GRIDS GG JOIN (SELECT G1.ContentID, .dbo.vefn_FixTransitionDataForCopy(G1.Data, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewData FROM @GRIDS G1 JOIN @Children NN on G1.ContentID = NN.NewContentID JOIN Transitions TR on NN.NewContentID = TR.FromID JOIN Transitions TRO on TR.TranType = TRO.TransitionID) G2 ON GG.ContentID = G2.ContentID WHERE Cast([DATA] as nvarchar(max)) <> CAST(G2.NewData as nvarchar(max)) SET @RowsAffected = @@RowCount END --print 'H2.2 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) update GG set data = g1.data from Grids gg join @grids g1 on gg.contentid = g1.contentid --print 'H3 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) --set nocount on -- 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 --print 'H4 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) 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 --print 'H5 ' + cast(datediff(s,@dts,getdate()) as varchar(100)) -- Transitions are done -- SELECT * From Transitions where DTS = @DTS and UserID = @UserID --print 'Z ' + cast(datediff(s,@dts,getdate()) as varchar(100)) --foldouts fixing code if exists (select * from contents where contentid in (select newcontentid from @children) and config like '%FloatingFoldout%') begin --insert into #mytemp select cc.contentid,xsteps.value('@FloatingFoldout','int') oldfoldoutid,(select newitemid from @children where itemid = xsteps.value('@FloatingFoldout','int')) newfoldoutid,xconfig into #mytemp from (select *,cast(config as xml) xconfig from contents where contentid in (select newcontentid from @children)) cc cross apply xconfig.nodes('Config/Step') tsteps(xsteps) --build @cmd string declare @cmd nvarchar(max) declare cmds cursor for select distinct 'update #mytemp set xconfig.modify(''replace value of (Config/Step/@FloatingFoldout)[1] with "' + cast(newfoldoutid as varchar(10)) + '"'') where xconfig.value(''(Config/Step/@FloatingFoldout)[1]'',''int'') = ' + cast(oldfoldoutid as varchar(10)) from #mytemp --execute cursor over rows open cmds fetch next from cmds into @cmd while @@fetch_status = 0 begin exec sp_executesql @cmd fetch next from cmds into @cmd end close cmds deallocate cmds --actually update contents update cc set config = cast(xconfig as varchar(max)) from contents cc join #mytemp mt on cc.contentid = mt.contentid --get rid of #mytemp drop table #mytemp end --end foldouts fixing code --section start DECLARE @NewContentID int Select @NewContentID = NewContentID from @Children where ItemID = @StartItemID DECLARE @Config varchar(max) DECLARE @XConfig xml select @Config = config from contents where contentid = @NewContentID select @XConfig = cast(@Config as xml) if @Config like '%SectionStart%' begin DECLARE @SectionStart int select @SectionStart = xproc.value('@SectionStart','int') from @xconfig.nodes('Config/Procedure') tproc(xproc) DECLARE @NewSectionStart int select @NewSectionStart = newitemid from @children where itemid = @SectionStart DECLARE @cmd2 nvarchar(max) set @cmd2 = ' declare @XConfig xml; set @XConfig = cast(''' + @Config + ''' as xml); set @XConfig.modify(''replace value of (Config/Procedure/@SectionStart)[1] with "' + cast(@NewSectionStart as nvarchar(10)) + '"''); update contents set config = cast(@XConfig as varchar(max)) where contentid = ' + cast(@NewContentID as nvarchar(10)) + ';' exec sp_executesql @cmd2 end --end section start 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: CopyItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: CopyItemAndChildren Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_removeUnUsedFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_removeUnUsedFormat]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2021 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_removeUnUsedFormat] ( @Name nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @tbl Table( removeid int) declare @baseid int insert into @tbl select formatid from formats where name like @name -- get the format id of the base format select @baseid = formatid from formats where name = 'base' -- assign deleted format with the base format update folders set FormatID = @baseid where FormatID in (select removeid from @tbl) update DocVersions set FormatID = @baseid where FormatID in (select removeid from @tbl) update tblContents set FormatID = @baseid where FormatID in (select removeid from @tbl) -- delete the contentAudits records that use the deleted format delete ContentAudits where FormatID in (select removeid from @tbl) -- delete the record out of formats delete Formats where FormatID in (select removeid from @tbl) 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 remove format IF (@@Error = 0) PRINT 'StoredProcedure [vesp_removeUnUsedFormat] Succeeded' ELSE PRINT 'StoredProcedure [vesp_removeUnUsedFormat] Error on Creation' go -- remove un-used formats exec vesp_removeUnUsedFormat 'WPS%' exec vesp_removeUnUsedFormat 'WPB%' exec vesp_removeUnUsedFormat 'VCBEPP%' exec vesp_removeUnUsedFormat 'BNPPdev%' exec vesp_removeUnUsedFormat 'BNPPgop%' exec vesp_removeUnUsedFormat 'BNPPckl%' PRINT 'Kewaunee, Point Beach, un-used Summer, Barakah Deviation, Barakah GOP (sample), Barakah Checklist formats removed' 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 2016 - 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 @ItemType 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 SET @Path = [dbo].[ve_GetShortPath](@ItemID) SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) where rangeid = toid or toid = @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 @ExternalCount > 0 AND @ItemType < 10000 BEGIN RAISERROR ('###Cannot Delete Item###Procedure %d has External Transitions to Procedure - (%s)',16,1,@ItemID,@Path) RETURN END SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) SELECT @ItemType = Type FROM Contents Where ContentID = @ContentID -- Check to see if External Transitions point to the current item 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) -- Remove Previously deleted transitions DELETE from tblTransitions where deletestatus = -1 and FromID in(SELECT ContentID FROM @Children) -- Remove Previously deleted rousages DELETE from tblrousages where deletestatus = -1 and contentID in(SELECT ContentID 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 /****** Object: StoredProcedure [vefn_FixTransitionDataForCopy] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixTransitionDataForCopy]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_FixTransitionDataForCopy]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FixTransitionDataForCopy] (@data XML,@TransitionID int,@TranType int,@OldToID int,@OldRangeID int, @NewID int, @NewToID int, @NewRangeID int, @NewTranType int) RETURNS XML WITH EXECUTE AS OWNER AS BEGIN -- Build Search String and Replace String DECLARE @offset int DECLARE @lookFor nvarchar(MAX) DECLARE @replaceWith nvarchar(MAX) DECLARE @text nvarchar(MAX) SET @text = Cast(@data as nvarchar(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 Cast(replace(@text,@lookFor,@replaceWith) as XML) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixTransitionDataForCopy Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_FixTransitionDataForCopy Error on Creation' GO /****** Object: StoredProcedure [vefn_FixROData] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixROData]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_FixROData]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create FUNCTION [dbo].[vefn_FixROData] (@data XML,@ROUsageID int,@NewROUsageID int) RETURNS XML 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 CAST(replace(CAST(@data AS NVarChar(max)),@lookFor,@replaceWith) AS XML) END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixROData Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_FixROData Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetVersionProcedureItems] Script Date: 1/5/2015 3:58:49 PM ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionProcedureItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionProcedureItems]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetVersionProcedureItems('') where procid = 63589 Select * from vefn_GetVersionProcedureItems('1') where procid = 63589 Select * from vefn_GetVersionProcedureItems('4') where procid = 63589 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionProcedureItems](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE ( VersionID int, ProcID int, ItemID int primary key, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN BEGIN with Itemz([VersionID], ProcID, [ItemID], [ContentID]) as (Select DV.VersionID, DV.ItemID ProcID, [I].[ItemID], [I].[ContentID] FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select Z.VersionID, Z.ProcID, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID Union All -- Siblings select Z.VersionID, case when z.ProcID = z.ItemID then I.ItemID else Z.ProcID end ProcID, I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) insert into @VersionItems select VersionID, ProcID, [ItemID], [ContentID] from ItemZ I --Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) END RETURN END GO IF (@@Error = 0) PRINT 'TableFunction vefn_GetVersionProcedureItems Succeeded' ELSE PRINT 'TableFunction vefn_GetVersionProcedureItems Error on Creation' /****** Object: StoredProcedure [getTransitionSearchResults] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchTransitions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[vesp_SearchTransitions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /****** Object: StoredProcedure [dbo].[vesp_SearchTransitions] Script Date: 1/7/2015 6:15:17 PM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* exec vesp_searchtransitions '1,2,4,6,7,11,12',6,'' */ CREATE PROCEDURE [dbo].[vesp_SearchTransitions] ( @DocVersionList varchar(max), @TranType int, @TranCategory varchar(20), -- added stepTypeList to fix bug B2015-055 - allows transition search in specified step elements @StepTypeList varchar(MAX) ) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' declare @itmp table ( vid int, pid int, iid int primary key, cid int ) declare @ctmp table ( vid int, pid int, iid int, cid int primary key ) declare @ttmp table ( itemid int, dvpath varchar(max), UnitPrefix varchar(MAX) ) insert into @itmp select * from vefn_getversionprocedureitems(@DocVersionList) insert into @ctmp select * from @itmp if @TranType = -1 and @TranCategory = '' begin insert into @ttmp select ii.ItemID,dv.DVPath,dv.UnitPrefix from vefn_DocVersionSplit(@DocVersionList) dv join @ctmp ct on dv.VersionID = ct.vid join Items ii on ct.cid = ii.ContentID join Transitions tt on ii.ContentID = tt.FromID end else if @TranType > -1 and @TranCategory = '' begin insert into @ttmp select ii.ItemID,dv.DVPath,dv.UnitPrefix from vefn_DocVersionSplit(@DocVersionList) dv join @ctmp ct on dv.VersionID = ct.vid join Items ii on ct.cid = ii.ContentID join Transitions tt on ii.ContentID = tt.FromID where tt.TranType = @TranType end else if @TranType = -1 and @TranCategory != '' begin insert into @ttmp select ii.ItemID,dv.DVPath,dv.UnitPrefix from vefn_DocVersionSplit(@DocVersionList) dv join @ctmp ct on dv.VersionID = ct.vid join Items ii on ct.cid = ii.ContentID join Transitions tt on ii.ContentID = tt.FromID join @itmp it on tt.ToID = it.iid where case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory end else begin insert into @ttmp select ii.ItemID,dv.DVPath,dv.UnitPrefix from vefn_DocVersionSplit(@DocVersionList) dv join @ctmp ct on dv.VersionID = ct.vid join Items ii on ct.cid = ii.ContentID join Transitions tt on ii.ContentID = tt.FromID join @itmp it on tt.ToID = it.iid where tt.TranType = @TranType and case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory end BEGIN with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], Cast('' as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) Path, 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select DVPath, [Level] + 1,Z.ItemID,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] ,PATH + --'' case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end PPath, Path + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, case when P.FromType = 5 then -1 else 0 end IsRNO, OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] ,null,null,null,null ,PPath, --'1' + PPath + case C.Type/10000 when 0 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, 0, POrdinalPath, POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID ) SELECT tt.dvpath,Z.Path, I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] FROM Itemz Z join [Items] I on Z.ItemID = I.ItemID join @ttmp tt on I.ItemID = tt.itemid join Contents C on C.ContentID = I.ContentID left join Parts P on i.ItemID = P.ItemID -- Where clase added for bug fix B2015-055 to allow transition search within selected step elements Where ((isnull(@StepTypeList,'') = '' /*and dbo.vefn_AllSections(C.Type)>=10000*/) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))))) OPTION (MAXRECURSION 10000) RETURN END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchTransitions Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchTransitions Error on Creation' GO /****** Object: TableFunction [vefn_GetVersionFormatSections] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionFormatSections]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionFormatSections]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionFormatSections](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key, FormatID int ) WITH EXECUTE AS OWNER AS BEGIN BEGIN with Itemz([VersionID], [ItemID], [ContentID], [FormatID], [ParentFormatID]) as (Select DV.VersionID, [I].[ItemID], [I].[ContentID], isnull(C.[FormatID],isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID]))), isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID])) FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] join docversions DV2 on DV.[VersionID] = DV2.[VersionID] join folders F on DV2.[FolderID] = F.[FolderID] join folders P on P.[FolderID] = F.[ParentID] join Contents C on I.ContentID = C.ContentID Union All -- Children select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[FormatID]), Z.[FormatID] 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 where c.Type < 20000 Union All -- Siblings select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[ParentFormatID]), Z.[ParentFormatID] from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on I.ContentID = C.ContentID ) insert into @VersionItems select VersionID, [ItemID], [ContentID], [FormatID] from ItemZ I --Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of func creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetVersionFormatSections Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetVersionFormatSections Error on Creation' GO /****** Object: StoredProcedure [vesp_GetFormatVersions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetFormatVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[vesp_GetFormatVersions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /****** Object: StoredProcedure [dbo].[vesp_GetFormatVersions] Script Date: 1/7/2015 6:15:17 PM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[vesp_GetFormatVersions] WITH EXECUTE AS OWNER AS BEGIN select ff.Name + ' - ' + ff.Description Title,vfi.FormatID,vn.VersionID from vefn_GetVersionNames() vn join vefn_GetVersionFormatSections('') vfi on vn.VersionID = vfi.VersionID join Formats ff on vfi.FormatID = ff.FormatID group by ff.Name + ' - ' + ff.Description,vfi.formatid,vn.VersionID return END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetFormatVersions Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetFormatVersions Error on Creation' GO /****** Object: StoredProcedure [vesp_GetTranTypesByFormatID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetTranTypesByFormatID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[vesp_GetTranTypesByFormatID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /****** Object: StoredProcedure [dbo].[vesp_GetTranTypesByFormatID] Script Date: 1/7/2015 6:15:17 PM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetTranTypesByFormatID 102 */ CREATE PROCEDURE [dbo].[vesp_GetTranTypesByFormatID] ( @FormatID int ) WITH EXECUTE AS OWNER AS BEGIN declare @t1 table ( formatid int, transindex int, transmenu varchar(max) ) declare @t2 table ( transindex int, formatid int ) insert into @t1 select ff.formatid,r1.value('@Index','int') transindex, r1.value('@TransMenu','varchar(max)') transmenu from Formats ff cross apply ff.Data.nodes('//TransTypes') t1(r1) where ff.FormatID = @FormatID union select ff.formatid,r1.value('@Index','int') transindex, r1.value('@TransMenu','varchar(max)') transmenu from Formats ff cross apply ff.Data.nodes('//TransTypes') t1(r1) where ff.FormatID = 1 insert into @t2 select transindex,max(formatid) formatid from @t1 group by transindex select t1.transindex,t1.transmenu from @t1 t1 join @t2 t2 on t1.formatid = t2.formatid and t1.transindex = t2.transindex order by t1.transindex RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetTranTypesByFormatID Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetTranTypesByFormatID Error on Creation' GO /****** Object: StoredProcedure [vesp_GetTransitionReportData] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetTransitionReportData]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [dbo].[vesp_GetTransitionReportData]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /****** Object: StoredProcedure [dbo].[vesp_GetTransitionReportData] Script Date: 1/7/2015 6:15:17 PM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* vesp_GetTransitionReportData 5, 6078 */ CREATE PROCEDURE [dbo].[vesp_GetTransitionReportData] ( @VersionID int, @ProcedureID int ) WITH EXECUTE AS OWNER AS BEGIN declare @itmp table ( vid int, pid int, iid int primary key, cid int ) declare @ctmp table ( vid int, pid int, iid int, cid int primary key ) declare @ttmp table ( tid int primary key ) insert into @itmp select * from vefn_getversionprocedureitems('') insert into @ctmp select * from @itmp insert into @ttmp select tt.TransitionID from Transitions tt join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid where ct.pid = @ProcedureID or it.pid = @ProcedureID --internal select 1 level,tt.*, (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount] from Transitions tt join @ttmp tp on tt.TransitionID = tp.tid join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid where ct.vid = it.vid and ct.pid = @ProcedureID and it.pid = @ProcedureID --external from union select 2 level,tt.*, (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount] from Transitions tt join @ttmp tp on tt.TransitionID = tp.tid join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid where ct.vid = it.vid and ct.pid = @ProcedureID and it.pid != @ProcedureID --external to union select 3 level,tt.*, (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount] from Transitions tt join @ttmp tp on tt.TransitionID = tp.tid join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid where ct.vid = it.vid and ct.pid != @ProcedureID and it.pid = @ProcedureID --outside from union select 4 level,tt.*, (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount] from Transitions tt join @ttmp tp on tt.TransitionID = tp.tid join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid where ct.vid != it.vid and ct.pid = @ProcedureID-- and ii.ItemID not in (select iid from @itmp) --outside to union select 5 level,tt.*, (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount] from Transitions tt join @ttmp tp on tt.TransitionID = tp.tid join @itmp it on tt.ToID = it.iid join @ctmp ct on tt.FromID = ct.cid where ct.vid != it.vid and it.pid = @ProcedureID --and ii.ContentID not in (select cid from @ctmp) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetTransitionReportData Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetTransitionReportData Error on Creation' GO /****** Object: StoredProcedure [PasteItemChild] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemChild]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [PasteItemChild]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2015 - Volian Enterprises, Inc. All rights reserved. Copies & Pastes into a level above the copied item, for example copied item is step pasted into a section. Example test: declare @NewItemID int declare @dts datetime set @newitemid = 0 set @dts = getdate() exec PasteItemChild 1493,484,20041,2,@dts,'KATHY',@NewItemID output *****************************************************************************/ CREATE PROCEDURE [dbo].[PasteItemChild] ( @ItemID int=null, @StartItemID int=null, -- ItemID is destination, StartItemID is top of copy @Type int=null, @FromType int=null, @DTS datetime, @UserID nvarchar(100), -- Type is step/section type for content record, fromtype is for parts @NewItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION if exists (select * from tblitems where itemid = @ItemID and DeleteStatus !=0) BEGIN RAISERROR ('###Cannot Paste Step###This current step has been deleted in another session',16,1) RETURN END -- 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 -- print 'testing PasteItemChild 1 ' + cast(dbo.ve_GetTransitionErrorCount() as varchar(20)) DECLARE @ChildID int, @ContentID int, @ParentContentID int, @LastChanged timestamp , @newLastChanged timestamp, @Error int, @Rowcount int, @ChildDeleted int SELECT @ChildID = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [PARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tblParts]') AND OBJECTPROPERTY(id,N'IsTable') = 1) BEGIN SELECT @ChildDeleted = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [tblPARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID and pp.DeleteStatus > 0 END -- No existing child - Add Parts record. Note that don't need to update any transition records if no existing children IF @ChildID is null BEGIN IF @ChildDeleted is not null DELETE FROM [tblParts] WHERE ItemID = @ChildDeleted EXECUTE AddPart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @newLastChanged output END ELSE -- Children exist: Update existing Parts record and adjust transition records that may have pointed to 1st child. BEGIN EXECUTE UpdatePart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @LastChanged, @newLastChanged output UPDATE [Items] SET [PreviousID]=@newItemID WHERE [ItemID]=@ChildID -- Update content records for the transitions, this only fixes the link portion. Code fixes the text. Update CC Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ChildID,@newItemID) From CONTENTS CC JOIN Transitions TT ON TT.FromID = CC.ContentID WHERE TT.ToID = @ChildID OR TT.RangeID = @ChildID -- Update transitions that pointed to @ItemID to point to @newItemID Update TRANSITIONS Set ToID = CASE ToID WHEN @ChildID THEN @newItemID ELSE ToID END, RangeID = CASE RangeID WHEN @ChildID THEN @newItemID ELSE RangeID END WHERE ToID = @ChildID OR RangeID = @ChildID 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 -- I don't expect to see any transitions that point to @ChildID. They should have changed in -- the update above to point to @newItemID. This is here for consistency with the other insert -- stored procedures 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(@ChildID,@newItemID) OR RangeID IN(@ChildID,@newItemID)) -- Transition Text gets updated in ItemInsertExt.cs IF( @@TRANCOUNT > 0 ) COMMIT PRINT 'Child Added ' + ltrim(str(@newItemID)) EXECUTE GetItem @newItemID delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid)) delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@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: PasteItemChild Succeeded' ELSE PRINT 'Procedure Creation: PasteItemChild Error on Creation' GO /****** Object: StoredProcedure [PasteDocVersionChild] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteDocVersionChild]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [PasteDocVersionChild]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2014 - Volian Enterprises, Inc. All rights reserved. Copies & Pastes into a docversion that does NOT have any existing procedures. Example test: declare @NewItemID int declare @dts datetime set @newitemid = 0 set @dts = getdate() exec PasteDocVersionChild 5,30,@dts,'KATHY',@NewItemID output *****************************************************************************/ CREATE PROCEDURE [dbo].[PasteDocVersionChild] ( @VersionID int=null, @StartItemID int=null, -- VersionID is destination (docversion), StartItemID is top of copy (i.e. procedure) @DTS datetime, @UserID nvarchar(100), @ThisVersionID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION if not exists (select * from DocVersions where versionid = @VersionID) BEGIN RAISERROR ('###Cannot Paste Procedure###This document version has been deleted in another session',16,1) RETURN END -- First make a copy of the input StartItemID (Procedure) -- DestFormatID is the formatid for the destination parent's format DECLARE @NewItemID int DECLARE @DestFormatID int SET @ThisVersionID = @VersionID SET @DestFormatID = .dbo.vefn_GetDocVersionInheritedFormat(@VersionID) EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT UPDATE [DOCVERSIONS] SET [ItemID] = @NewItemID where [VersionID]=@VersionID IF( @@TRANCOUNT > 0 ) COMMIT PRINT 'Child Added ' + ltrim(str(@newItemID)) EXECUTE GetDocVersion @ThisVersionID delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid)) delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@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: PasteDocVersionChild Succeeded' ELSE PRINT 'Procedure Creation: PasteDocVersionChild Error on Creation' GO /****** Object: StoredProcedure [vefn_GetDocVersionInheritedFormat] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetDocVersionInheritedFormat]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_GetDocVersionInheritedFormat]; GO CREATE FUNCTION [dbo].[vefn_GetDocVersionInheritedFormat] (@VersionID int) RETURNS int WITH EXECUTE AS OWNER AS BEGIN DECLARE @FormatID as int -- First get format for the input doc version begin with Itemz([Level], [VersionID], [FolderID], [ParentID], [FormatID]) as ( -- DocVersion From Item select 0 [Level], DV.VersionID, DV.FolderID, null, DV.FormatID from DocVersions DV where [VersionID] = @VersionID Union All -- Folders select [Level] + 1, 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 OPTION (MAXRECURSION 10000) END RETURN @FormatID END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_GetDocVersionInheritedFormat Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_GetDocVersionInheritedFormat Error on Creation' GO /*********the following funcion is for debugging copy/paste where transition text in content records does not get updated */ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetTransitionErrorCount]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetTransitionErrorCount]; /****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 03/20/2012 17:50:44 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select dbo.ve_GetTransitionErrorCount () print 'testing ' + cast(dbo.ve_GetTransitionErrorCount() as varchar(20)) */ CREATE FUNCTION [dbo].[ve_GetTransitionErrorCount] () RETURNS int WITH EXECUTE AS OWNER AS BEGIN DECLARE @Count int select @Count = count(*) from ( select dbo.ve_GetShortPathFromContentId(contentid) location, * from ( select contentid, text, tt.*, case when text like '%'+ case when tt.toid = tt.rangeid and tt.IsRange = 0 then '#Link:Transition:' + cast(TranType as nvarchar(2)) + ' ' + cast(TransitionID as nvarchar(10)) + ' ' + cast(ToID as nvarchar(10)) + '%' else '#Link:TransitionRange:' + cast(TranType as nvarchar(2)) + ' ' + cast(TransitionID as nvarchar(10)) + ' ' + cast(ToID as nvarchar(10)) + ' ' + cast(RangeID as nvarchar(10))+ '%' end then 'matches' else 'different' end ContentMatchesTrans, case when text like '%'+ '#Link:TransitionRange:' + cast(TranType as nvarchar(2)) + ' ' + cast(TransitionID as nvarchar(10)) + ' ' + cast(ToID as nvarchar(10)) + ' ' + cast(RangeID as nvarchar(10))+ '%' then 'matches' else 'different' end ContentMatchesRangeTrans from Contents cc join transitions tt on tt.fromid = cc.contentid) mm where ContentMatchesTrans = 'different') mm return @Count END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: ve_GetTransitionErrorCount Succeeded' ELSE PRINT 'ScalarFunction Creation: ve_GetTransitionErrorCount Error on Creation' GO --added by JCB for storing procedure xml for approved version --ALTER TABLE Versions add ApprovedXML if it does not exist IF COL_LENGTH('Versions','ApprovedXML') IS NULL ALTER TABLE Versions ADD [ApprovedXML] [NVARCHAR](MAX) NULL; GO /****** Object: StoredProcedure [addVersion] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addVersion]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addVersion] ( @RevisionID int, @StageID int, @PDF varbinary(MAX)=null, @SummaryPDF varbinary(MAX)=null, @ApprovedXML nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(200), @newVersionID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Versions] ( [RevisionID], [StageID], [PDF], [SummaryPDF], [ApprovedXML], [DTS], [UserID] ) VALUES ( @RevisionID, @StageID, @PDF, @SummaryPDF, @ApprovedXML, @DTS, @UserID ) SELECT @newVersionID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Versions] WHERE [VersionID]=@newVersionID 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: addVersion Succeeded' ELSE PRINT 'Procedure Creation: addVersion Error on Creation' GO /****** Object: StoredProcedure [getVersion] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getVersion]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [VersionID], [RevisionID], [StageID], [PDF], [SummaryPDF], [ApprovedXML], [DTS], [UserID], [LastChanged] FROM [Versions] WHERE [VersionID]=@VersionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getVersion Succeeded' ELSE PRINT 'Procedure Creation: getVersion Error on Creation' GO /****** Object: StoredProcedure [getVersions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getVersions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getVersions] WITH EXECUTE AS OWNER AS SELECT [VersionID], [RevisionID], [StageID], [PDF], [SummaryPDF], [ApprovedXML], [DTS], [UserID], [LastChanged] FROM [Versions] RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getVersions Succeeded' ELSE PRINT 'Procedure Creation: getVersions Error on Creation' GO /****** Object: StoredProcedure [getVersionsByRevisionID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersionsByRevisionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getVersionsByRevisionID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getVersionsByRevisionID] ( @RevisionID int ) WITH EXECUTE AS OWNER AS SELECT [Versions].[VersionID], [Versions].[RevisionID], [Versions].[StageID], [Versions].[PDF], [Versions].[SummaryPDF], [Versions].[ApprovedXML], [Versions].[DTS], [Versions].[UserID], [Versions].[LastChanged], [Stages].[Name] [Stage_Name], [Stages].[Description] [Stage_Description], [Stages].[IsApproved] [Stage_IsApproved], [Stages].[DTS] [Stage_DTS], [Stages].[UserID] [Stage_UserID] FROM [Versions] JOIN [Stages] ON [Stages].[StageID]=[Versions].[StageID] WHERE [Versions].[RevisionID]=@RevisionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getVersionsByRevisionID Succeeded' ELSE PRINT 'Procedure Creation: getVersionsByRevisionID Error on Creation' GO /****** Object: StoredProcedure [getVersionsByStageID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersionsByStageID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getVersionsByStageID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getVersionsByStageID] ( @StageID int ) WITH EXECUTE AS OWNER AS SELECT [Versions].[VersionID], [Versions].[RevisionID], [Versions].[StageID], [Versions].[PDF], [Versions].[SummaryPDF], [Versions].[ApprovedXML], [Versions].[DTS], [Versions].[UserID], [Versions].[LastChanged], [Revisions].[ItemID] [Revision_ItemID], [Revisions].[TypeID] [Revision_TypeID], [Revisions].[RevisionNumber] [Revision_RevisionNumber], [Revisions].[RevisionDate] [Revision_RevisionDate], [Revisions].[Notes] [Revision_Notes], [Revisions].[Config] [Revision_Config], [Revisions].[DTS] [Revision_DTS], [Revisions].[UserID] [Revision_UserID] FROM [Versions] JOIN [Revisions] ON [Revisions].[RevisionID]=[Versions].[RevisionID] WHERE [Versions].[StageID]=@StageID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getVersionsByStageID Succeeded' ELSE PRINT 'Procedure Creation: getVersionsByStageID Error on Creation' GO /****** Object: StoredProcedure [updateVersion] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[updateVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [updateVersion]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[updateVersion] ( @VersionID int, @RevisionID int, @StageID int, @PDF varbinary(MAX)=null, @SummaryPDF varbinary(MAX)=null, @ApprovedXML nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(200), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Versions] SET [RevisionID]=@RevisionID, [StageID]=@StageID, [PDF]=@PDF, [SummaryPDF]=@SummaryPDF, [ApprovedXML]=@ApprovedXML, [DTS]=@DTS, [UserID]=@UserID WHERE [VersionID]=@VersionID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Versions] WHERE [VersionID]=@VersionID) RAISERROR('Version record has been deleted by another user', 16, 1) ELSE RAISERROR('Version has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Versions] WHERE [VersionID]=@VersionID 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: updateVersion Succeeded' ELSE PRINT 'Procedure Creation: updateVersion Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetDisconnectedItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetDisconnectedItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetDisconnectedItems] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- select * from vefn_GetDisconnectedItems() /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetDisconnectedItems]() RETURNS @DiscItems TABLE ( ItemID int primary Key, ContentID int, UNIQUE (ContentID) ) WITH EXECUTE AS OWNER AS BEGIN declare @UsedItems Table ( itemid int primary key, contentid int) insert into @UsedItems Select ItemID, ContentID from vefn_GetVersiontblItems('') insert into @DiscItems select itemid,ii.contentid from ( Select ItemID,ii.ContentID from tblItems II where ItemID not in(select ItemID from @UsedItems)) ii Join Contents CC ON CC.ContentID = II.ContentID And CC.Type is not null UNION Select ItemId, ContentID from vefn_GetZeroFromType() RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetDisconnectedItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetDisconnectedItems] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_TransitionsToDisconnected]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_TransitionsToDisconnected]; GO /****** Object: UserDefinedFunction [dbo].[vefn_TransitionsToDisconnected] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- select * from vefn_TransitionsToDisconnected('1') /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION dbo.vefn_TransitionsToDisconnected(@DocVersionList nvarchar(MAX)) RETURNS @Transitions TABLE ( [TransitionID] int primary key ,[FromID] int ,[ToID] int ,[RangeID] int ,[IsRange] int ,[TranType] int ,[Config] nvarchar(max) ,[DTS] datetime ,[UserID] nvarchar(100) ,UNIQUE(FromID,TransitionID) ,UNIQUE(ToID,TransitionID) ) WITH EXECUTE AS OWNER AS BEGIN insert into @Transitions select [TransitionID],[FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID] from Transitions tt join vefn_GetVersionItems(@DocVersionList) vi on tt.FromID = vi.ContentID join vefn_GetDisconnectedItems() di on tt.ToID = di.ItemID RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_TransitionsToDisconnected] Succeeded' ELSE PRINT 'TableFunction [vefn_TransitionsToDisconnected] Error on Creation' GO /****** Object: StoredProcedure [getTransitionsToDisconnected] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getTransitionsToDisconnected]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getTransitionsToDisconnected]; GO /* exec getTransitionsToDisconnected */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getTransitionsToDisconnected] ( @DocVersionList nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[IsRange], TT.[TranType], TT.[Config], TT.[DTS], TT.[UserID], TT.[LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] from transitions tt join vefn_TransitionsToDisconnected(@DocVersionList) td on tt.TransitionID = td.TransitionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getTransitionsToDisconnected Succeeded' ELSE PRINT 'Procedure Creation: getTransitionsToDisconnected Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetNonEditableItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetNonEditableItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetNonEditableItems] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- select * from vefn_GetNonEditableItems() /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [DBO].[vefn_GetNonEditableItems]() RETURNS @NonEditItems TABLE ( ItemID int primary Key, ContentID int, UNIQUE (ContentID) ) WITH EXECUTE AS OWNER AS BEGIN insert into @NonEditItems select ii.ItemID,ah.ContentID from ( select cast(Config as xml) xconfig,ContentID from Contents where ContentID in ( select p1.ContentID from Parts p1 join Parts p2 on p1.ContentID = p2.ContentID where p1.FromType = 2 and p2.FromType = 6 ) and Config like '%edit%' ) ah cross apply xconfig.nodes('//SubSection') tSubsection(xSubsection) join Items ii on ah.ContentID = ii.ContentID where isnull(xSubsection.value('@Edit','varchar(1)'),'N') = 'N' RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetNonEditableItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetNonEditableItems] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_TransitionsToNonEditable]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_TransitionsToNonEditable]; GO /****** Object: UserDefinedFunction [dbo].[vefn_TransitionsToNonEditable] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- select * from vefn_TransitionsToNonEditable('1') /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2013 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION dbo.vefn_TransitionsToNonEditable(@DocVersionList nvarchar(MAX)) RETURNS @Transitions TABLE ( [TransitionID] int primary key ,[FromID] int ,[ToID] int ,[RangeID] int ,[IsRange] int ,[TranType] int ,[Config] nvarchar(max) ,[DTS] datetime ,[UserID] nvarchar(100) ,UNIQUE(FromID,TransitionID) ,UNIQUE(ToID,TransitionID) ) WITH EXECUTE AS OWNER AS BEGIN insert into @Transitions select [TransitionID],[FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID] from Transitions tt join vefn_GetVersionItems(@DocVersionList) vi on tt.FromID = vi.ContentID join vefn_GetNonEditableItems() di on tt.ToID in (select ItemID from vefn_StepChildItems(di.ItemID)) RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_TransitionsToNonEditable] Succeeded' ELSE PRINT 'TableFunction [vefn_TransitionsToNonEditable] Error on Creation' GO /****** Object: StoredProcedure [getTransitionsToNonEditable] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getTransitionsToNonEditable]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getTransitionsToNonEditable]; GO /* exec getTransitionsToNonEditable '8' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getTransitionsToNonEditable] ( @DocVersionList nvarchar(MAX) ) WITH EXECUTE AS OWNER AS SELECT TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[IsRange], TT.[TranType], TT.[Config], TT.[DTS], TT.[UserID], TT.[LastChanged], (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] from transitions tt join vefn_TransitionsToNonEditable(@DocVersionList) td on tt.TransitionID = td.TransitionID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getTransitionsToNonEditable Succeeded' ELSE PRINT 'Procedure Creation: getTransitionsToNonEditable Error on Creation' GO /****** Object: StoredProcedure [vefn_StepChildItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_StepChildItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_StepChildItems]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_StepChildItems](@ItemID int) RETURNS @Children TABLE ( ItemID int PRIMARY KEY, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ItemID], [ContentID]) as ( Select 0 [Level], [ItemID], [ContentID] FROM [Items] where [ItemID]=@ItemID Union All -- Children select [Level] + 1, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID and (Z.Level > 0 or p.FromType = 6) join Items I on I.ItemID = P.ItemID -- Siblings Union All select [Level] , I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_StepChildItems Succeeded' ELSE PRINT 'TableFunction Creation: vefn_StepChildItems Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getJustStage]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getJustStage]; GO /****** Object: StoredProcedure [dbo].[getJustStage] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create PROCEDURE [dbo].[getJustStage] ( @StageID int ) WITH EXECUTE AS OWNER AS SELECT [StageID], [Name], [Description], [IsApproved], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Checks] WHERE [Checks].[StageID]=[Stages].[StageID]) [CheckCount], (SELECT COUNT(*) FROM [Versions] WHERE [Versions].[StageID]=[Stages].[StageID]) [VersionCount] FROM [Stages] WHERE [StageID]=@StageID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getJustStage Succeeded' ELSE PRINT 'Procedure Creation: getJustStage Error on Creation' GO /****** Object: StoredProcedure [vesp_DeletePDFs] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_DeletePDFs]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_DeletePDFs]; GO /* exec vesp_DeletePDFs */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_DeletePDFs] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE FROM [Pdfs] 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: vesp_DeletePDFs Succeeded' ELSE PRINT 'Procedure Creation: vesp_DeletePDFs Error on Creation' GO /****** Object: StoredProcedure [getROImageByRODbID_FileName] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getROImagesByRODbID_FileName]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getROImagesByRODbID_FileName]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getROImagesByRODbID_FileName] ( @RODbID int, @FileName nvarchar(255) ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [RODbID]=@RODbID AND [FileName]=@FileName Order By [DTS] RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getROImagesByRODbID_FileName Succeeded' ELSE PRINT 'Procedure Creation: getROImagesByRODbID_FileName Error on Creation' GO /****** Object: StoredProcedure [vesp_GetDisconnectedItemsCount] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetDisconnectedItemsCount]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetDisconnectedItemsCount]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetDisconnectedItemsCount] WITH EXECUTE AS OWNER AS SELECT COUNT(*) HowMany FROM vefn_GetDisconnectedItems() RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetDisconnectedItemsCount Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetDisconnectedItemsCount Error on Creation' GO /****** Object: StoredProcedure [vesp_GetNonEditableItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetNonEditableItems]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_GetNonEditableItems; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetNonEditableItems] WITH EXECUTE AS OWNER AS SELECT I.[ItemID], I.[PreviousID], I.[ContentID], I.[DTS], I.[UserID], I.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount] FROM [Items] I JOIN vefn_GetNonEditableItems() NE on I.ItemID = NE.ItemID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetNonEditableItems Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetNonEditableItems Error on Creation' GO /****** Object: StoredProcedure [vesp_GetDatabaseSessions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetDatabaseSessions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_GetDatabaseSessions; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetDatabaseSessions] WITH EXECUTE AS OWNER AS select t1.SessionID,t1.UserID,t1.MachineName,t1.OwnerTypeName,t1.HowMany,t1.Status, t2.FolderName,t2.GrandParentName,t2.ParentName,t2.ItemPath,t2.DTSStart from ( select ss.SessionID,UserID,MachineName,ISNULL(OwnerType,0) OwnerType,ISNULL(OwnerTypeName,'Nothing') OwnerTypeName,ISNULL(HowMany,0) HowMany, case when DATEDIFF(SECOND,DTSActivity,GETDATE()) > 60 then 'IN-ACTIVE (' + CAST(DATEDIFF(SECOND,DTSActivity,GETDATE()) as varchar(10)) + ' Seconds)' else 'Active' end Status from Sessions ss left join (select SessionID,OwnerType,case OwnerType when 0 then 'Procedure' when 1 then 'Document' when 2 then 'Working Draft' else 'Database' end OwnerTypeName,count(*) HowMany from Owners group by SessionID,OwnerType) oo on ss.SessionID = oo.SessionID where ss.DTSEnd is null ) t1 left join ( select oo.SessionID,oo.OwnerID,oo.DTSStart,oo.OwnerType, dbo.ve_GetShortPath(oo.OwnerItemID) ItemPath, vn.FolderName,vn.GrandParentName,vn.ParentName from Owners oo join vefn_GetVersionItems('') vi on oo.OwnerItemID = vi.ItemID join vefn_GetVersionNames() vn on vi.VersionID = vn.VersionID where oo.OwnerType = 0 union select distinct oo.SessionID,oo.OwnerID,oo.DTSStart,oo.OwnerType, case when isnull(LibTitle,'') = '' then dbo.ve_getshortpathfromcontentid(ee.contentid) else 'Library Document: ' + LibTitle end ItemPath, vn.FolderName,vn.GrandParentName,vn.ParentName from Owners oo join Documents dd on oo.OwnerItemID = dd.DocID join Entries ee on oo.OwnerItemID = ee.DocID join vefn_GetVersionItems('') vi on ee.ContentID = vi.ContentID join vefn_GetVersionNames() vn on vi.VersionID = vn.VersionID where oo.OwnerType = 1 union select oo.SessionID,oo.OwnerID,oo.DTSStart,oo.OwnerType, dv.Name ItemPath,vn.FolderName,vn.GrandParentName,vn.ParentName from Owners oo join DocVersions dv on oo.OwnerItemID = dv.VersionID join vefn_GetVersionNames() vn on dv.VersionID = vn.VersionID where oo.OwnerType = 2 ) t2 on t1.SessionID = t2.SessionID and t1.OwnerType = t2.OwnerType order by t1.SessionID,t1.OwnerType RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetDatabaseSessions Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetDatabaseSessions Error on Creation' GO /****** Object: StoredProcedure [vesp_ListContentsAfterLastChanged] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListContentsAfterLastChanged]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_ListContentsAfterLastChanged; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListContentsAfterLastChanged] ( @LastChanged timestamp ) WITH EXECUTE AS OWNER AS BEGIN SELECT cc.[ContentID], cc.[Number], cc.[Text], cc.[Type], cc.[FormatID], cc.[Config], cc.[DTS], cc.[UserID], cc.[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=cc.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=cc.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=cc.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=cc.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=cc.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=cc.[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=cc.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=cc.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=cc.[ContentID]) [ZContentCount] FROM [Contents] cc WHERE cc.LastChanged > @LastChanged RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListContentsAfterLastChanged Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListContentsAfterLastChanged Error on Creation' GO /****** Object: StoredProcedure [vesp_ListContentsAfterLastChanged2] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListContentsAfterLastChanged2]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_ListContentsAfterLastChanged2; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListContentsAfterLastChanged2] ( @LastChanged bigint, @UserID nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN SELECT cc.[ContentID], CONVERT(bigint,cc.[LastChanged]) LastContentChange FROM [Contents] cc WHERE CONVERT(bigint,cc.LastChanged) > @LastChanged -- AND cc.UserID != @UserID ORDER BY LastChanged RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListContentsAfterLastChanged2 Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListContentsAfterLastChanged2 Error on Creation' GO /****** Object: StoredProcedure[getOwnerBySessionIDandFolderID] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getOwnerBySessionIDandFolderID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE getOwnerBySessionIDandFolderID; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2015 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getOwnerBySessionIDandFolderID] ( @SessionID int, @FolderID int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @VersionID int SELECT @VersionID = VersionID from DocVersions WHERE FolderID = @FolderID SELECT [OwnerID], [SessionID], [OwnerType], [OwnerItemID], [DTSStart], [LastChanged] FROM [Owners] oo INNER JOIN ( -- 0 is procedures SELECT 0 ObjectType,ItemID ObjectID FROM dbo.vefn_GetVersionItems(@VersionID) UNION -- 1 is documents SELECT 1 ObjectType,ee.DocID ObjectID FROM dbo.vefn_GetVersionItems(@VersionID) vi INNER JOIN Contents cc ON vi.ContentID = cc.ContentID INNER JOIN Entries ee ON vi.ContentID = ee.ContentID UNION -- 2 is DocVersions SELECT 2 ObjectType, @VersionID ObjectID UNION -- 3 is Folders SELECT 3 ObjectType, @FolderID ObjectID ) tt ON oo.OwnerType = tt.ObjectType and oo.OwnerItemID = tt.ObjectID WHERE [SessionID] = @SessionID RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getOwnerBySessionIDandFolderID Succeeded' ELSE PRINT 'Procedure Creation: getOwnerBySessionIDandFolderID Error on Creation' GO /****** Object: StoredProcedure [vesp_ListItemsAfterLastChanged] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsAfterLastChanged]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_ListItemsAfterLastChanged; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsAfterLastChanged] ( @LastChanged bigint, @UserID nvarchar(100) ) WITH EXECUTE AS OWNER AS BEGIN SELECT isnull(dbo.ve_GetParentItem(ii.[ItemID]),0) ParentID,MAX(CONVERT(bigint,ii.[LastChanged])) LastItemChange FROM [Items] ii WHERE CONVERT(bigint,ii.LastChanged) > @LastChanged -- AND cc.UserID != @UserID GROUP BY dbo.ve_GetParentItem(ii.[ItemID]) ORDER BY MAX(CONVERT(bigint,ii.[LastChanged])) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ListItemsAfterLastChanged Succeeded' ELSE PRINT 'Procedure Creation: vesp_ListItemsAfterLastChanged Error on Creation' GO /****** Object: StoredProcedure [ve_GetShortPath] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[ve_GetShortPath]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [ve_GetShortPath]; GO /* select ItemID, CC.Type, dbo.ve_GetPath(ItemID) from Items II join Contents CC on II.ContentID = CC.ContentID where ItemID in(111,265,266,267) */ -- drop function ve_GetPath /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[ve_GetShortPath] (@ItemID int) RETURNS varchar(max) WITH EXECUTE AS OWNER AS BEGIN -- declare @STructID int --set @StructID=11 declare @Path varchar(max); with Itemz(ItemCount,ItemID,PreviousID,FromType,CType,Number,Text,PPath, Path) as ( Select 1,ItemID,PreviousID,0,C.Type/10000,C.Number,C.Text, Cast(Case when C.Type < 20000 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) else '' end as nvarchar(max)) PPath, Cast(Case when C.Type < 20000 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) else '1' end as nvarchar(max)) Path from Items I join Contents C on I.ContentID = C.ContentID where ItemID=@ItemID Union All -- siblings Select ItemCount+1,I.PreviousID,II.PreviousID,0,C.Type/10000,Z.Number,Z.Text,PPath,cast(ItemCount + 1 as nvarchar(4)) + PPath from Items I join Contents C on I.ContentID = C.ContentID Join Items II on II.ItemID = I.PreviousID Join Itemz Z on I.ItemID=Z.ItemID where I.PreviousID != 0 Union All -- children select 1,I.ItemID,I.PreviousID,P.FromType,C.Type/10000,C.Number,C.Text, case C.Type/10000 when 0 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) when 1 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) +'`' + cast(ItemCount + 0 as varchar(4)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(4)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(4)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(4)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(4)) when 5 then '`RNO`' when 7 then '`Table`' when 8 then '`SupInfo`' else '`' + cast(ItemCount + 0 as varchar(4)) end end + PPath PPath, --'1' + case C.Type/10000 when 0 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) when 1 then '`' + [dbo].[ve_GetShortPart](C.Number,C.Text) +'`' + cast(ItemCount + 0 as varchar(4)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(4)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(4)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(4)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(4)) when 5 then '`RNO' when 7 then '`Table' when 8 then '`SupInfo' else '`' + cast(ItemCount + 0 as varchar(4)) end end + PPath Path from Parts P join Items I on I.ContentID = P.ContentID join Contents C on I.ContentID = C.ContentID join Itemz Z on P.ItemID=Z.ItemID ) select @Path = path From Itemz where ItemCount=1 and CType=0 OPTION (MAXRECURSION 10000) return REPLACE(REPLACE(@Path,'\u8209?','-'),'u9586?','\\') END; GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: ve_GetShortPath Succeeded' ELSE PRINT 'ScalarFunction Creation: ve_GetShortPath Error on Creation' GO /****** Object: StoredProcedure [addROImage] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addROImage]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE addROImage; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addROImage] ( @RODbID int, @FileName nvarchar(255), @Content varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newImageID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION IF exists(select * from ROImages where @rodbid = rodbid and @FileName=FileName and @DTS = DTS) BEGIN select @newImageID = ImageID from ROImages where @rodbid = rodbid and @FileName=FileName and @DTS = DTS END ELSE BEGIN INSERT INTO [ROImages] ( [RODbID], [FileName], [Content], [Config], [DTS], [UserID] ) VALUES ( @RODbID, @FileName, @Content, @Config, @DTS, @UserID ) SELECT @newImageID= SCOPE_IDENTITY() END SELECT @newLastChanged=[LastChanged] FROM [ROImages] WHERE [ImageID]=@newImageID 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 IF (@@Error = 0) PRINT 'Procedure Creation: addROImage Succeeded' ELSE PRINT 'Procedure Creation: addROImage Error on Creation' GO PRINT '20150808 Improved performance for delete procedure' /****** Object: UserDefinedFunction [dbo].[vefn_GetEnhancedFolders] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedFolders]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedFolders]; GO /* select * from vefn_GetEnhancedFolders(11) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION dbo.[vefn_GetEnhancedFolders](@FolderID as int) RETURNS @AllValues TABLE ( FolderID int PRIMARY KEY, [Type] int, [Name] varchar(100), VersionID int ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @AllValues select DISTINCT ddenh.folderid, xxEnhanced.value('@Type', 'int') xxType, xxEnhanced.value('@Name', 'varchar(20)') xxName, xxEnhanced.value('@VersionID', 'int') xxVersionID from (select *, cast(config as xml) xconfig from docversions) dv cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) join (select *, cast(config as xml) xconfig from docversions) denh on xEnhanced.value('@VersionID', 'int') = denh.VersionID cross apply denh.xconfig.nodes('//Enhanced') ttEnhanced(xxEnhanced) join (select *, cast(config as xml) xconfig from docversions) ddenh on xxEnhanced.value('@VersionID', 'int') = ddenh.VersionID where denh.FolderID = @FolderID or dv.folderid = @FolderID RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetEnhancedFolders Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetEnhancedFolders Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetEnhancedDocVersions] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedDocVersions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedDocVersions]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select * from vefn_GetEnhancedDocVersions(6) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION dbo.[vefn_GetEnhancedDocVersions](@VersionID as int) RETURNS @AllValues TABLE ( VersionID int PRIMARY KEY, [Type] int, [Name] varchar(100), FolderID int ) WITH EXECUTE AS OWNER AS BEGIN INSERT INTO @AllValues select DISTINCT xxEnhanced.value('@VersionID', 'int') xxVersionID, xxEnhanced.value('@Type', 'int') xxType, xxEnhanced.value('@Name', 'varchar(20)') xxName, ddenh.folderid from (select *, cast(config as xml) xconfig from docversions) dv cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) join (select *, cast(config as xml) xconfig from docversions) denh on xEnhanced.value('@VersionID', 'int') = denh.VersionID cross apply denh.xconfig.nodes('//Enhanced') ttEnhanced(xxEnhanced) join (select *, cast(config as xml) xconfig from docversions) ddenh on xxEnhanced.value('@VersionID', 'int') = ddenh.VersionID where denh.VersionID = @VersionID or dv.VersionID = @VersionID RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetEnhancedDocVersions Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetEnhancedDocVersions Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_GetEnhancedProcedures] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedProcedures]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION vefn_GetEnhancedProcedures; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION dbo.[vefn_GetEnhancedProcedures](@ItemID int) RETURNS @VersionItems TABLE ( VersionID int, ItemID int primary key, ContentID int ) WITH EXECUTE AS OWNER AS BEGIN with ItemZ(ItemId, EnhID, Level) as (Select ItemID,xEnhanced.value('@ItemID','int') EnhID, 0 from Items II Join (Select ContentID, cast(config as xml) xconfig From Contents) CC On CC.ContentID = II.ContentID outer apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) Where ItemID = @ItemID Union ALL Select II.ItemID,xEnhanced.value('@ItemID','int') EnhID, ZZ.Level+1 from Items II Join ItemZ ZZ on ZZ.EnhID = II.ItemID Join (Select ContentID, cast(config as xml) xconfig From Contents) CC On CC.ContentID = II.ContentID outer apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) Where zz.Level < 2) INSERT INTO @VersionItems Select distinct dbo.vefn_GetVersionIDByItemID(ZZ.ItemID) VersionID, ZZ.ItemID, II.ContentID from ItemZ ZZ Join Items II on II.ItemID = ZZ.ItemID OPTION (MAXRECURSION 10000) RETURN END GO -- Display the status IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetEnhancedProcedures Succeeded' ELSE PRINT 'TableFunction Creation: vefn_GetEnhancedProcedures Error on Creation' GO PRINT '20160106 Enhanced Documents' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionTblItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionTblItems]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetVersionTblItems] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetVersionTblItems('') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionTblItems](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key ) WITH EXECUTE AS OWNER AS BEGIN BEGIN with Itemz([VersionID], [ItemID], [ContentID]) as (Select DV.VersionID, [I].[ItemID], [I].[ContentID] FROM [tblItems] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select Z.VersionID, I.[ItemID], I.[ContentID] from Itemz Z join tblParts P on P.ContentID = Z.ContentID join tblItems I on I.ItemID = P.ItemID Union All -- Siblings select Z.VersionID, I.[ItemID], I.[ContentID] from Itemz Z join tblItems I on I.PreviousID = Z.ItemID ) insert into @VersionItems select VersionID, [ItemID], [ContentID] from ItemZ I --Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ) OPTION (MAXRECURSION 10000) END RETURN END go IF (@@Error = 0) PRINT 'TableFunction [vefn_GetVersionTblItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetVersionTblItems] Error on Creation' GO /****** Object: StoredProcedure [addROImage] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_PurgeDisconnectedData]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_PurgeDisconnectedData; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_PurgeDisconnectedData] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION delete from tblParts where FromType=0 declare @UsedItems Table ( itemid int primary key, contentID int ) insert into @UsedItems Select ItemID, ContentID from vefn_GetVersiontblItems('') select 'Working Drafts' Query, FolderName,Dv.* from DocVersions DV JOIN VEFN_GetVersionNames() VN ON DV.VersionID = VN.VersionID declare @DiscItems Table ( itemid int primary key, ContentID int) insert into @DiscItems Select ItemID, II.ContentID from tblItems II Join tblContents CC ON CC.ContentID = II.ContentID where ItemID not in(select ItemID from @UsedItems) And CC.Type is not null delete from [Checks] where RevisionID in (select RevisionID from Revisions where ItemID in (select itemid from @DiscItems)) delete from [Versions] where RevisionID in (select RevisionID from Revisions where ItemID in (select itemid from @DiscItems)) delete from [Revisions] where ItemID in (select itemid from @DiscItems) delete from [AnnotationAudits] where ItemID in (select itemid from @DiscItems) delete from [ItemAudits] where ItemID in (select itemid from @DiscItems) delete from [tblParts] where ItemID in (select itemid from @DiscItems) delete from [DocVersions] where ItemID in (select itemid from @DiscItems) delete from [PartAudits] where ItemID in (select itemid from @DiscItems) delete from [tblAnnotations] where ItemID in (select itemid from @DiscItems) delete from [Details] where contentID in (select contentid from @DiscItems) delete from [ZContents] where contentID in (select contentid from @DiscItems) delete from [tblGrids] where contentID in (select contentid from @DiscItems) delete from [tblImages] where contentID in (select contentid from @DiscItems) delete from [ContentAudits] where contentID in (select contentid from @DiscItems) delete from [tblROUsages] where contentID in (select contentid from @DiscItems) delete from [EntryAudits] where contentID in (select contentid from @DiscItems) delete from [tblEntries] where contentID in (select contentid from @DiscItems) delete from [GridAudits] where contentID in (select contentid from @DiscItems) delete from [ImageAudits] where contentID in (select contentid from @DiscItems) delete from [ItemAudits] where contentID in (select contentid from @DiscItems) delete from [tblParts] where contentID in (select contentid from @DiscItems) delete from [PartAudits] where contentID in (select contentid from @DiscItems) delete from [ROUsageAudits] where contentID in (select contentid from @DiscItems) delete from [ztransitions] where transitionid in(select transitionid from [tblTransitions] where fromid in (select contentid from @DiscItems)) delete from [ztransitions] where transitionid in(select transitionid from [tblTransitions] where toid in (select itemid from @DiscItems)) delete from [ztransitions] where transitionid in(select transitionid from [tblTransitions] where rangeid in (select itemid from @DiscItems)) delete from [tblTransitions] where fromid in (select contentid from @DiscItems) delete from [tblTransitions] where toid in (select itemid from @DiscItems) delete from [tblTransitions] where rangeid in (select itemid from @DiscItems) delete from [tblItems] where PreviousID in (select itemid from @DiscItems) delete from [tblItems] where ItemID in (select itemid from @DiscItems) delete from [tblItems] where contentID in (select contentid from @DiscItems) delete from [tblContents] where contentID in (select contentid from @DiscItems) 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 IF (@@Error = 0) PRINT 'Procedure Creation: vesp_PurgeDisconnectedData Succeeded' ELSE PRINT 'Procedure Creation: vesp_PurgeDisconnectedData Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'ClearCBOverrideForProcedure') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE ClearCBOverrideForProcedure; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].ClearCBOverrideForProcedure ( @ItemID int=null ) WITH EXECUTE AS OWNER AS begin DECLARE @CBConfigs TABLE ( [ContentID] int, xConfig xml ) insert into @CBConfigs select ContentID, cast(Config as xml) xConfig from Contents where config like '%CBOverride%' and contentid in (select icontentid from vefn_tblchilditems(@ItemID,@ItemID,0)) Update @CBConfigs Set xConfig.modify('delete //@CBOverride') From @CBConfigs Update @CBConfigs Set xConfig.modify('delete //Step[not(node())and not(./@*)]') From @CBConfigs UPDATE CC SET config = cast(xconfig as varchar(max)) FROM CONTENTS CC Join @CBConfigs CB on cc.contentid = cb.contentid where cc.contentid in (select contentid from @CBConfigs) SELECT [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] where contentid in (select contentid from @CBConfigs) end go -- Display the status of ClearCBOverrideForProcedure IF (@@Error = 0) PRINT 'StoredProcedure [ClearCBOverrideForProcedure] Succeeded' ELSE PRINT 'StoredProcedure [ClearCBOverrideForProcedure] Error on Creation' go PRINT '20160126 Improved performance for checkouts' PRINT '20160226 11:00 SQL Code Version ' SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_PurgeEnhanced]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_PurgeEnhanced]; GO /* */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_PurgeEnhanced] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @Enh TABLE ( ID int, xConfig xml ) insert into @Enh SELECT VersionID,xConfig FROM (Select cast(config as xml) xconfig,* from DocVersions) t1 Cross Apply xconfig.nodes('//Enhanced[1]') tEnhanced(xEnhanced) Update @Enh Set xConfig.modify('delete //Enhanced') From @Enh Update DV Set Config = cast(xconfig as varchar(max)) From Docversions DV Join @Enh EE ON EE.ID = DV.VersionID --select * from @Enh delete from @enh insert into @enh SELECT ContentID,xConfig FROM (Select cast(config as xml) xconfig,* from Contents) t1 Cross Apply xconfig.nodes('//Enhanced[1]') tEnhanced(xEnhanced) Update @Enh Set xConfig.modify('delete //Enhanced') From @Enh Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC Join @Enh EE ON EE.ID = CC.ContentID 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 'StoredProcedure [vesp_PurgeEnhanced] Succeeded' ELSE PRINT 'StoredProcedure [vesp_PurgeEnhanced] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ConvertEnhancedDocVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ConvertEnhancedDocVersions]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ConvertEnhancedDocVersions] ( @svid int, @enhvid int, @enhid int, @enhttl varchar(255), @enhx int, @enhtok varchar(1) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION --print 'BGDV-1' update docversions set config = replace(config,'>', '>') where VersionID =@svid --print 'BGDV-2' update docversions set config = replace(config,'>', '>') where VersionID =@enhvid 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 'StoredProcedure [vesp_ConvertEnhancedDocVersions] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ConvertEnhancedDocVersions] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ConvertEnhancedItems]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ConvertEnhancedItems]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ConvertEnhancedItems] ( @svid int, @bvid int, @dvid int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @EnhItems TABLE ( ItemID int, ContentID int, SrcConfig1 varchar(255), SrcConfig2 varchar(255), ProcName varchar(8), RecID varchar(8), BGItemID int, BGContentID int, BGConfig varchar(255), DVItemID int, DVContentID int, DVConfig varchar(255) ) -- Procedures Insert into @EnhItems select VI.ItemID, VI.ContentID ,case when vibg.itemid is null then '' else '' end ,case when vidv.itemid is null then '' else '' end , VI.ProcName,null RecID , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID, case when vibg.itemid is null then '' else '' end , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID, case when vidv.itemid is null then '' else '' end from vefn_GetOldEnhancedProcs(@svid) VI Left Join vefn_GetOldEnhancedProcs(@bvid) VIBG ON VI.ProcName = VIBG.ProcName Left Join vefn_GetOldEnhancedProcs(@dvid) VIDV ON VI.ProcName = VIDV.ProcName WHERE VIBG.ItemID is not null or VIDV.ItemID is not null --Sections and Steps Insert into @EnhItems select VI.ItemID, VI.ContentID ,case when vibg.itemid is null then '' else '' end ,case when vidv.itemid is null then '' else '' end , VI.ProcName,VI.RecID , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID, case when vibg.itemid is null then '' else '' end , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID, case when vidv.itemid is null then '' else '' end from vefn_GetOldEnhancedItems(@svid) VI Left Join vefn_GetOldEnhancedItems(@bvid) VIBG ON VI.ProcName = VIBG.ProcName AND '0L' + substring(VI.RecID,3,6) = VIBG.RecID Left Join vefn_GetOldEnhancedItems(@dvid) VIDV ON VI.ProcName = VIDV.ProcName AND '0L' + substring(VI.RecID,3,6) = VIDV.RecID WHERE VIBG.ItemID is not null or VIDV.ItemID is not null --select * from @EnhItems Declare @EnhEach Table ( ContentID int primary key, Change1 varchar(255), Change2 varchar(255) ) insert into @EnhEach Select EI.ContentID,EI.SrcConfig1,EI.srcConfig2 from @EnhItems EI Join Contents CC ON CC.ContentID = EI.ContentID insert into @EnhEach Select EI.bgContentID,EI.BGConfig,null from @EnhItems EI Join Contents CC ON CC.ContentID = EI.bgContentID insert into @EnhEach Select EI.dvContentID,EI.DVConfig,null from @EnhItems EI Join Contents CC ON CC.ContentID = EI.dvContentID Update CC Set Config = cast(cast(Replace(Replace(Config,'>' + Change1 +'' + isnull(Change2,'') +' 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 'StoredProcedure [vesp_ConvertEnhancedItems] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ConvertEnhancedItems] Error on Creation' go -- ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedLinks]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedLinks]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetEnhancedLinks]() RETURNS @Enhanced TABLE ( svid int, bvid int, dvid int ) WITH EXECUTE AS OWNER AS BEGIN declare @tbl table ( FolderName varchar(255), VersionID int, ItemID int, ContentID int, ProcName varchar(10), LinkType varchar(4), RecID int, ShortName varchar(20) ) insert into @tbl select vn.FolderName,VI.VersionID, VI.ItemID, t1.ContentID, ProcName, case substring(RecIDText,2,1) when '0' then 'None' when 'L' then 'Link' else substring(RecIDText,2,1) end LinkType , cast(substring(RecIDText,3,6) as int) RecID, ff.ShortName from (select cc.Contentid , xHistory.value('@ProcName','varchar(20)') ProcName, xHistory.value('@RecID','varchar(20)') RecIDText from (select *, cast(config as xml) xconfig from contents) cc cross apply xconfig.nodes('//History') tHistory(xHistory)) t1 Join vefn_getversionItems('') vi on t1.contentID = vi.contentID JOIN VEFN_GetVersionNames() VN ON VI.VersionID = VN.VersionID JOIN DocVersions DV ON VI.VersionID = DV.VersionID Join Folders FF ON FF.FolderID = DV.FolderID DECLARE @LinkCounts TABLE ( EnhancedID int, LinkFolder varchar(255), LinkShortName varchar(20), SourceID int, SourceFolder varchar(255), SourceShortName varchar(20), HowMany int, AllLinks int ) insert into @LinkCounts select t3.*,t4.HowMany AllLinks from (select t1.versionID EnhancedID, t1.FolderName LinkFolder, t1.ShortName LinkShortName, t2.VersionID SourceID, t2.FolderName SourceFolder, T2.ShortName SourceShortName, Count(*) HowMany from (select * from @tbl where LinkType = 'Link') t1 join (select * from @tbl where LinkType != 'Link') t2 on t1.ProcName = t2.ProcName and T1.RecID = T2.RecID group by t1.versionID, t1.FolderName, T1.ShortName, t2.versionID, t2.FolderName, t2.ShortName) t3 Join (select FolderName LinkFolder, 'All' SourceFolder, count(*) HowMany from @tbl where LinkType = 'Link' group by FolderName) t4 on t3.LinkFolder = t4.linkfolder Order By LinkFolder, T3.HowMany Desc --print '---3---' --select * from @LinkCounts declare @LinkSummary TABLE ( EnhancedID int, LinkFolder varchar(255), LinkShortName varchar(25), SourceID int, SourceFolder varchar(255), SourceShortName varchar(25), HowMany int, AllLinks int, RowNo int ) begin WITH TOP3 AS ( SELECT *, ROW_NUMBER() over ( PARTITION BY [EnhancedID] order by [HowMany] DESC ) AS RowNo FROM @LinkCounts ) insert into @linkSummary SELECT * FROM TOP3 WHERE RowNo <= 1 end declare @myXML xml set @myXML=cast(' ' as xml) declare @linktbl TABLE ( Plant VARCHAR(25), LinkType VARCHAR(25), FolderFrom VARCHAR(25), FolderTo VARCHAR(25) ) insert into @linktbl select xLink.value('@Plant','varchar(25)') Plant ,xLink.value('@Type','varchar(25)') LinkType ,xLink.value('@From','varchar(25)') FolderFrom ,xLink.value('@To','varchar(25)') FolderTo from @myxml.nodes('//Link') tLink(xLink) declare @LnkPaths table ( Plant VarChar(20), FolderFrom Varchar(20), Background Varchar(20), Deviation Varchar(20) ) Insert into @LnkPaths select distinct plant,FolderFrom , (select min(FolderTo) from @linktbl lt1 where lt1.plant=lt.plant and lt1.folderfrom = lt.folderfrom and lt1.linktype='bck.lnk') Background , (select min(FolderTo) from @linktbl lt1 where lt1.plant=lt.plant and lt1.folderfrom = lt.folderfrom and lt1.linktype='dvt.lnk') Deviation from @linktbl lt where LinkType in('BCK.LNK','DVT.LNK') insert into @Enhanced select isnull(SourceID,0) svid,isnull(BackgroundID,0) bvid,isnull(DeviationID,0) dvid from (select Plant ,T1.SourceID,FolderFrom ,isnull(BackgroundID,LS1.EnhancedID) BackgroundID,BackGround ,isnull(DeviationID, LS2.EnhancedID) DeviationID, Deviation from (select distinct Plant, (select Min(VersionID) from DocVersions dv Join Folders ff on dv.folderid = ff.folderid where ShortName = FolderFrom and ff.title like '%' + plant + '%') SourceID, FolderFrom, (select Min(VersionID) from DocVersions dv Join Folders ff on dv.folderid = ff.folderid where ShortName = Background and ff.title like '%' + plant + '%') BackgroundID, Background, (select Min(VersionID) from DocVersions dv Join Folders ff on dv.folderid = ff.folderid where ShortName = Deviation and ff.title like '%' + plant + '%') DeviationID, Deviation from @LnkPaths where Plant IN(Select Distinct Plant from @LnkPaths LP Join Folders FF ON FF.Title Like '%' + Plant + '%')) T1 left Join @LinkSummary LS1 ON T1.SourceID = LS1.SourceID AND LS1.LinkShortName like '%.BCK' left Join @LinkSummary LS2 ON T1.SourceID = LS2.SourceID AND LS2.LinkShortName like '%.DVT' Where T1.SourceID is not null) T2 where BackgroundID is not null or DeviationID is not null Return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetEnhancedLinks] Succeeded' ELSE PRINT 'TableFunction [vefn_GetEnhancedLinks] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetOldEnhancedProcs]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetOldEnhancedProcs]; GO /* -- Byron USE VEPROMS_BYR select VI.ItemID, VI.ContentID, VI.ProcName , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID from vefn_GetOldEnhancedProcs(6) VI Left Join vefn_GetOldEnhancedProcs(8) VIBG ON VI.ProcName = VIBG.ProcName Left Join vefn_GetOldEnhancedProcs(9) VIDV ON VI.ProcName = VIDV.ProcName USE MASTER -- Catawba USE VEPROMS_CNS select VI.ItemID, VI.ContentID, VI.ProcName , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID from vefn_GetOldEnhancedProcs(7) VI Left Join vefn_GetOldEnhancedProcs(12) VIBG ON VI.ProcName = VIBG.ProcName Left Join vefn_GetOldEnhancedProcs(0) VIDV ON VI.ProcName = VIDV.ProcName USE MASTER */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetOldEnhancedProcs](@VersionID as int) RETURNS @Enhanced TABLE ( ItemID int, ContentID int, ProcName varchar(8) ) WITH EXECUTE AS OWNER AS BEGIN insert into @Enhanced select ItemID,ContentID,ProcName From ( select ItemID,CC.ContentID ,xHistory.value('@ProcName','varchar(8)') ProcName ,row_Number() over(partition by xHistory.value('@ProcName','varchar(8)') order by ItemID) RowOrder from (select ContentID, cast(config as xml) xConfig from Contents where Type = 0 ) CC Cross Apply xConfig.nodes('//History') tHistory(xHistory) JOIN VEFN_GETVERSIONITEMS(cast(@VersionID as varchar(12))) VI ON VI.CONTENTID = CC.CONTENTID --JOIN VEFN_GetVersionNames() VN ON VI.VersionID = VN.VersionID )T1 Where rowOrder = 1 Return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetOldEnhancedProcs] Succeeded' ELSE PRINT 'TableFunction [vefn_GetOldEnhancedProcs] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetOldEnhancedItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetOldEnhancedItems]; GO /* select count(*) from vefn_GetOldEnhancedItems(6) select count(*) from vefn_GetOldEnhancedItems(8) where RecID like '0l%' select count(*) from vefn_GetOldEnhancedItems(9) where RecID like '0l%' -- Byron USE VEPROMS_BYR select VI.ItemID, VI.ContentID, VI.ProcName,VI.RecID , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID from vefn_GetOldEnhancedItems(6) VI Left Join vefn_GetOldEnhancedItems(8) VIBG ON VI.ProcName = VIBG.ProcName AND '0L' + substring(VI.RecID,3,6) = VIBG.RecID Left Join vefn_GetOldEnhancedItems(9) VIDV ON VI.ProcName = VIDV.ProcName AND '0L' + substring(VI.RecID,3,6) = VIDV.RecID WHERE VIBG.ItemID is not null or VIDV.ItemID is not null USE MASTER -- Catawba USE VEPROMS_CNS select VI.ItemID, VI.ContentID, VI.ProcName, VI.RecID , VIBG.ItemID BGItemID, VIBG.ContentID BGContentID , VIDV.ItemID DVItemID, VIDV.ContentID DVContentID from vefn_GetOldEnhancedItems(7) VI Left Join vefn_GetOldEnhancedItems(12) VIBG ON VI.ProcName = VIBG.ProcName AND '0L' + substring(VI.RecID,3,6) = VIBG.RecID Left Join vefn_GetOldEnhancedItems(0) VIDV ON VI.ProcName = VIDV.ProcName AND '0L' + substring(VI.RecID,3,6) = VIDV.RecID WHERE VIBG.ItemID is not null --or VIDV.ItemID is not null USE MASTER */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetOldEnhancedItems](@VersionID as int) RETURNS @Enhanced TABLE ( ItemID int, ContentID int, ProcName varchar(8), RecID varchar(8), Primary Key (ProcName,RecID) ) WITH EXECUTE AS OWNER AS BEGIN insert into @Enhanced select ItemID, ContentID,ProcName,RecID From ( select VI.ItemID, CC.ContentID ,xHistory.value('@ProcName','varchar(8)') ProcName ,xHistory.value('@RecID','varchar(8)') RecID ,row_Number() over(partition by xHistory.value('@ProcName','varchar(8)'), xHistory.value('@RecID','varchar(8)') order by VI.ItemID) RowOrder from (select ContentID, cast(config as xml) xConfig from Contents where Type != 0 ) CC Cross Apply xConfig.nodes('//History') tHistory(xHistory) JOIN VEFN_GETVERSIONPROCEDUREITEMS(cast(@VersionID as varchar(12))) VI ON VI.CONTENTID = CC.CONTENTID --Where ProcID in(select ItemID from vefn_GetOldEnhancedProcs(@VersionID)) JOIN vefn_GetOldEnhancedProcs(@VersionID) vep on vi.ProcID = VEP.ItemID AND xHistory.value('@ProcName','varchar(8)')= vep.ProcName --JOIN VEFN_GetVersionNames() VN ON VI.VersionID = VN.VersionID )T1 Where rowOrder = 1 Return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetOldEnhancedItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetOldEnhancedItems] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ConvertEnhanced]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ConvertEnhanced]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ConvertEnhanced] ( @svid int, @bvid int, @dvid int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION IF( @svid != 0 AND @bvid != 0) -- Background DocVersions exec vesp_ConvertEnhancedDocVersions @svid,@bvid,1,'Background',6,'B' IF( @svid != 0 AND @dvid != 0) -- Deviation DocVersions exec vesp_ConvertEnhancedDocVersions @svid,@dvid,2,'Deviation',20,'D' IF( @svid != 0 AND ( @bvid != 0 OR @dvid != 0)) -- Enhanced Items exec vesp_ConvertEnhancedItems @svid, @bvid, @dvid 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 'StoredProcedure [vesp_ConvertEnhanced] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ConvertEnhanced] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ConvertAllEnhanced]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ConvertAllEnhanced]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ConvertAllEnhanced] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @svid int declare @bvid int declare @dvid int declare @source varchar(255) declare @background varchar(255) declare @deviation varchar(255) Exec vesp_PurgeEnhanced Print 'Purge Enhanced' declare enh cursor for select * from vefn_GetEnhancedLinks() open enh fetch next from enh into @svid,@bvid,@dvid while @@fetch_status = 0 begin SELECT @SOURCE = FOLDERNAME FROM vefn_GetVersionNames() where VersionID = @svid SELECT @Background = FOLDERNAME FROM vefn_GetVersionNames() where VersionID = @bvid SELECT @Deviation = FOLDERNAME FROM vefn_GetVersionNames() where VersionID = @dvid Print 'Converting ' + @Source + ' => ' + isnull(@Background,'N/A') + ' => ' + isnull(@Deviation, 'N/A') Exec vesp_ConvertEnhanced @svid,@bvid,@dvid fetch next from enh into @svid,@bvid,@dvid end close enh deallocate enh 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 'StoredProcedure [vesp_ConvertAllEnhanced] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ConvertAllEnhanced] Error on Creation' go PRINT 'Added Enhanced Document Conversion Code' IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetNewEnhancedData]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetNewEnhancedData]; GO /* select * from vefn_GetNewEnhancedData(28825) */ /****** Object: Table Function [vefn_GetNewEnhancedData] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetNewEnhancedData]( @ItemID int, @EnhType int) RETURNS @OldEnhancedData TABLE ( ItemID int, ContentID int, EItemID int, EType int ) WITH EXECUTE AS OWNER AS BEGIN insert into @OldEnhancedData select ii.ItemId,cc.ContentID , xEnhanced.value('@ItemID','int') EItemID , xEnhanced.value('@Type','int') EType from (Select *, cast(config as xml) xConfig from contents) CC Join Items II ON II.ContentID = CC.ContentID cross Apply xConfig.nodes('//Enhanced[@Type=sql:variable("@EnhType")]') tEnhanced(xEnhanced) where ItemID = @ItemID return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetNewEnhancedData] Succeeded' ELSE PRINT 'TableFunction [vefn_GetNewEnhancedData] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetOldEnhancedData]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetOldEnhancedData]; GO /* select * from vefn_GetOldEnhancedData(28825) */ /****** Object: Table Function [vefn_GetOldEnhancedData] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetOldEnhancedData]( @ItemID int) RETURNS @OldEnhancedData TABLE ( ItemID int, ContentID int, ProcName nvarchar(10), RecID nvarchar(10) ) WITH EXECUTE AS OWNER AS BEGIN insert into @OldEnhancedData select ii.ItemId,cc.ContentID , xHistory.value('@ProcName','nvarchar(10)') ProcName , xHistory.value('@RecID','nvarchar(10)') RecID from (Select *, cast(config as xml) xConfig from contents) CC Join Items II ON II.ContentID = CC.ContentID cross Apply xConfig.nodes('//History') tHistory(xHistory) where ItemID = @ItemID return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetOldEnhancedData] Succeeded' ELSE PRINT 'TableFunction [vefn_GetOldEnhancedData] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedItemsAndChildren]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedItemsAndChildren]; GO /****** Object: Table Function [vefn_GetEnhancedItemsAndChildren] *****/ /* select * from vefn_GetEnhancedItemsAndChildren(17013,1) select * from vefn_GetEnhancedItemsAndChildren(17067,0) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetEnhancedItemsAndChildren](@ProcID int,@EnhType int) RETURNS @VersionItems TABLE ( [Level] int, [FromType] int, [Ordinal] int, [ParentID] int, [ItemID] int primary key, [PreviousID] int, [ContentID] int, [Number] varchar(250), [Text] NVARCHAR(MAX), [Type] INT, [FormatID] int, [EItemID] int, [EType] int ) WITH EXECUTE AS OWNER AS BEGIN with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as ( Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged] FROM [Items] where [ItemID]=@ProcID Union All -- Children select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID --join (select * from Items where ContentID Not in(Select ContentID from entries)) I on I.ItemID = P.ItemID where p.fromtype in(2,3,4) -- Sections, Cautions, Notes or (z.FromType = 2 and p.FromType=6) -- High Level Step -- Siblings Union All select [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) insert into @versionitems select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID], C.[Number],C.[Text],C.[Type] , C.[FormatID] , xEnhanced.value('@ItemID','int') EItemID , xEnhanced.value('@Type','int') EType from ItemZ I join (select * , cast(config as xml) xConfig from Contents) C on C.ContentID = I.ContentID -- sql:variable("@EnhType") allows a variable to be used in a xPath query to limit -- the results to Enhanced Nodes that have type = outer apply xConfig.nodes('//Enhanced[@Type=sql:variable("@EnhType")]') tEnhanced(xEnhanced) where I.ContentID not in (select contentid from entries) order by I.[Level] , I.[FromType], I.[Ordinal] OPTION (MAXRECURSION 10000) RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetEnhancedItemsAndChildren] Succeeded' ELSE PRINT 'TableFunction [vefn_GetEnhancedItemsAndChildren] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedIssues]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedIssues]; GO /****** Object: Table Function [vefn_GetEnhancedIssues] ******/ /* select * from vefn_getEnhancedIssues1(17066) select * from vefn_getEnhancedIssues1(17067) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetEnhancedIssues]( @EnhancedID int) RETURNS @EnhancedIssues TABLE ( SourceID int, [sNumber] varchar(250), [sText] NVARCHAR(MAX), [sType] INT, [sProcName] NVARCHAR(10), [sRecID] NVARCHAR(10), EnhanceID int, [eNumber] varchar(250), [eeText] NVARCHAR(MAX), [eType] INT, [eProcName] NVARCHAR(10), [eRecID] NVARCHAR(10), Status varchar(10) ) WITH EXECUTE AS OWNER AS BEGIN declare @SourceID as int select @SourceID = xEnhanced.value('@ItemID','int') from (select cast(config as xml) xConfig from contents where contentID in(select ContentID from Items where ItemID = @EnhancedID)) CC cross apply xConfig.nodes('//Enhanced') tEnhanced(xEnhanced) declare @Type int select @Type = xEnhanced.value('@Type','int') from (select cast(config as xml) xConfig from contents where contentID in(select ContentID from Items where ItemID = @SourceID)) CC cross apply xConfig.nodes('//Enhanced') tEnhanced(xEnhanced) where xEnhanced.value('@ItemID','int') = @EnhancedID Insert into @EnhancedIssues select vcs.ItemID SourceID, vcs.[Number] sNumber, vcs.[Text] sText, vcs.[Type] sType,sod.ProcName sProcName,sod.RecID sRecID , vce.ItemID EnhancedID, vce.[Number] eNumber, vce.[Text] eText, vce.[Type] eType,eod.ProcName sProcName ,eod.RecID eRecID , case when ISNULL(eod.RecID,'00') like '0L%' and vcs.itemid is null then 'Delete' when vcs.itemid is null then 'Unlinked' when vce.itemid is null then 'Insert' when ISNULL(vcs.text,'') != isnull(vce.Text,'') then 'Different' else 'Same' end Status from vefn_GetEnhancedItemsAndChildren(@SourceID,@Type) vcs full Join vefn_GetEnhancedItemsAndChildren(@EnhancedID,0) vce on vcs.EItemID = vce.ItemID outer apply vefn_GetOldEnhancedData(vcs.ItemID) sod outer apply vefn_GetOldEnhancedData(vce.ItemID) eod RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetEnhancedIssues] Succeeded' ELSE PRINT 'TableFunction [vefn_GetEnhancedIssues] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedIssueCount]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedIssueCount]; GO /****** Object: Table Function [vefn_GetEnhancedIssueCount] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetEnhancedIssueCount]( @EnhancedID int) RETURNS @EnhancedIssueCount TABLE ( Deleted int, Inserted int, Changed int, Same int, Unlinked int ) WITH EXECUTE AS OWNER AS BEGIN insert into @EnhancedIssueCount select sum(case Status when 'Delete' then 1 else 0 end) Deleted , sum(case Status when 'Insert' then 1 else 0 end) Inserted , sum(case Status when 'Different' then 1 else 0 end) Changed , sum(case Status when 'Same' then 1 else 0 end) Same , sum(case Status when 'Unlinked' then 1 else 0 end) Unlinked from vefn_GetEnhancedIssues(@EnhancedID) RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetEnhancedIssueCount] Succeeded' ELSE PRINT 'TableFunction [vefn_GetEnhancedIssueCount] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetEnhancedDocuments]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetEnhancedDocuments]; GO /****** Object: Table Function [vefn_GetEnhancedDocuments] ******/ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetEnhancedDocuments]() RETURNS @EnhancedDocuments TABLE ( VersionID int, FolderName varchar(250), ItemID int, ProcNum varchar(250), ProcName varchar(1000), EnhType int, EnhItemID int ) WITH EXECUTE AS OWNER AS BEGIN insert into @EnhancedDocuments select VN.VersionID,VN.FolderName, VI.ItemID , replace(cc.Number,'\u8209?','-') ProcNum, replace(cc.Text,'\u8209?','-') ProcName --, replace(replace(cc.Number,'\u8209?','-'),'\u9586?','\') ProcNum, replace(replace(cc.Text,'\u8209?','-'),'\u9586?','\') ProcName , xEnhanced.value('@Type','int') EnhType, xenhanced.value('@ItemID','int') EnhItemID --, xEnhanced.query('.') qEnhanced from (select *, cast(config as xml) xconfig from Contents Where config like '%Enhanced%' and Type =0) CC JOIN VEFN_GetVersionItems('') VI ON VI.ContentID = CC.ContentID JOIN VEFN_GetVersionNames() VN ON VI.VersionID = VN.VersionID cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) where xEnhanced.value('@Type','int') > 0 return END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetEnhancedDocuments] Succeeded' ELSE PRINT 'TableFunction [vefn_GetEnhancedDocuments] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListUnlinkedItems]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListUnlinkedItems]; GO /* Sample vesp_ListUnlinkedItems 28825,1 vesp_ListUnlinkedItems 28827,1 vesp_ListUnlinkedItems 29245,1 vesp_ListUnlinkedItems 12217,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListUnlinkedItems] ( @ItemID int, @EnhType int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @EItemID int set @EItemID = (select top 1 VIS.EItemID from vefn_AllSiblingItems(@ItemID)--Find All Siblings outer apply vefn_GetNewEnhancedData(ItemID,@EnhType) VIS -- That are Linked where EitemID is not null) if @EItemID is null BEGIN select @EItemID = epp.ItemID from (select * from Parts where ItemID in(select itemID from vefn_AllSiblingItems(@ItemID)))SPP -- FindParent JOIN ITEMS SII ON sPP.ContentID = sII.ContentID -- Get Parent Content ID outer apply vefn_GetNewEnhancedData(SII.ItemID,@EnhType) VIS -- Get Enhanced ID for Parent JOIN ITEMS EII ON VIS.EItemID = EII.ItemID -- Get Enhanced Parent Content ID JOIN PARTS EPP ON EPP.ContentID = EII.ContentID and SPP.FromType = epp.FromType -- Get first Child END if @EItemID is null BEGIN select @EItemID = DV2.ItemID from (select *,cast(config as xml) xconfig from DocVersions where ItemID in(select itemID from vefn_AllSiblingItems(@ItemID))) SDV -- Source DocVersion cross apply (select * from vefn_GetEnhancedDocVersions(SDV.VersionID) where @EnhType = Type) EDV -- Enhanced DocVersion Join DocVersions DV2 ON DV2.VersionID = EDV.VersionID -- First Procedure END Select ItemID,PreviousID,II.ContentID,II.[DTS],II.[UserID],II.[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[II].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[II].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[II].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[II].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[II].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[II].[ItemID]) [Transition_ToIDCount] from Items II Left Join Entries EE ON II.ContentID = EE.ContentID where ItemID In (select SIB.ItemID from vefn_AllSiblingItems(@EItemID) SIB outer apply vefn_GetNewEnhancedData(ItemID,0) VIE Where VIE.EItemID is null) and EE.ContentID is null END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [vesp_ListUnlinkedItems] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ListUnlinkedItems] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ListItemsToRefresh]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ListItemsToRefresh]; GO /* Sample vesp_ListItemsToRefresh 17078 vesp_ListItemsToRefresh 17066 vesp_ListItemsToRefresh 17083 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_ListItemsToRefresh] ( @ProcID int ) WITH EXECUTE AS OWNER AS BEGIN Select ItemID,PreviousID,ContentID,[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[II].[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[II].[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Children] WHERE [Children].[PreviousID]=[II].[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[II].[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[II].[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[II].[ItemID]) [Transition_ToIDCount] from Items II where ItemID In (select EnhanceID from vefn_GetEnhancedIssues(@ProcID) where Status ='Different') END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [vesp_ListItemsToRefresh] Succeeded' ELSE PRINT 'StoredProcedure [vesp_ListItemsToRefresh] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_PurgeEnhancedItemsAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_PurgeEnhancedItemsAndChildren]; GO /* vesp_PurgeEnhancedItemsAndChildren 43092 -- caution vesp_PurgeEnhancedItemsAndChildren 43090 -- step/caution vesp_PurgeEnhancedItemsAndChildren 43089 -- section vesp_PurgeEnhancedItemsAndChildren 17067 -- procedure */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_PurgeEnhancedItemsAndChildren](@EnhanceID int) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @SourceID int select @SourceID=EItemID from VEFN_GetNewEnhancedData(@EnhanceID,0) DECLARE @EnhType int select @EnhType = xEnhanced.value('@Type','int') from (select *, cast(config as xml) xConfig from Contents where ContentID in (Select ContentID from ITEMS where ItemID = @SourceID)) CC cross apply xconfig.nodes('//Enhanced[@ItemID=sql:variable("@EnhanceID")]') tEnhanced(xEnhanced) declare @Enh1 TABLE ( ID int, xConfig xml ) insert into @Enh1 select CC.ContentID, CC.xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN vefn_ChildItems(@SourceID) VCI ON VCI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VCI.itemid,@EnhType) VEN Update @Enh1 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh1 declare @Enh2 TABLE ( ID int, xConfig xml ) insert into @Enh2 select CC.ContentID, CC.xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN vefn_ChildItems(@EnhanceID) VCI ON VCI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VCI.itemid,0) VEN set @EnhType=0 Update @Enh2 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh2 Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC Join @Enh1 EE ON EE.ID = CC.ContentID Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC Join @Enh2 EE ON EE.ID = CC.ContentID SELECT [ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] where ContentID in (Select ID From @Enh1 UNION Select ID From @Enh2) 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 'StoredProcedure [vesp_PurgeEnhancedItemsAndChildren] Succeeded' ELSE PRINT 'StoredProcedure [vesp_PurgeEnhancedItemsAndChildren] Error on Creation' go /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetNonEnhancedDocVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetNonEnhancedDocVersions]; GO CREATE PROCEDURE [dbo].[vesp_GetNonEnhancedDocVersions] WITH EXECUTE AS OWNER AS BEGIN SELECT [VersionID], [FolderID], [VersionType], [Name], [Title], [ItemID], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Associations] WHERE [Associations].[VersionID]=dv.[VersionID]) [AssociationCount] FROM (select *, cast(config as xml) xconfig from [DocVersions] ) dv outer apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) Where xEnhanced is null return END GO IF (@@Error = 0) PRINT 'StoredProcedure [vesp_GetNonEnhancedDocVersions] Succeeded' ELSE PRINT 'StoredProcedure [vesp_GetNonEnhancedDocVersions] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_PurgeEnhancedDocVersionsAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_PurgeEnhancedDocVersionsAndChildren]; GO /* vesp_PurgeEnhancedDocVersionsAndChildren 8 -- Background vesp_PurgeEnhancedDocVersionsAndChildren 9 -- Deviation */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_PurgeEnhancedDocVersionsAndChildren](@EnhanceID int) -- @EnhanceID -- Enhanced VersionID WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @SourceID int -- Source VersionID select @SourceID = xEnhanced.value('@VersionID','int') from (select *, cast(config as xml) xconfig from DocVersions) DV cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) where VersionID = @EnhanceID DECLARE @EnhType int select @EnhType = xEnhanced.value('@Type','int') from (select *, cast(config as xml) xConfig from DocVersions where VersionID = @SourceID) DV cross apply xconfig.nodes('//Enhanced[@VersionID=sql:variable("@EnhanceID")]') tEnhanced(xEnhanced) -- Fix DocVersion Records declare @Enh TABLE ( ID int, xConfig xml ) insert into @Enh select DV.VersionID,DV.xConfig from (select *, cast(config as xml) xConfig from DocVersions where VersionID in(@SourceID,@EnhanceID)) DV Update @Enh Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh Update @Enh Set xConfig.modify('delete //Enhanced[@Type="0"]') From @Enh declare @Enh1 TABLE ( ID int, xConfig xml ) insert into @Enh1 -- Links to Enhanced from Source select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@SourceID as varchar(25))) VI ON VI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VI.itemid,@EnhType) VEN Update @Enh1 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh1 declare @Enh2 TABLE ( ID int, xConfig xml ) insert into @Enh2 -- Links to Enhanced from Source select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@EnhanceID as varchar(25))) VI ON VI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VI.itemid,0) VEN set @EnhType=0 Update @Enh2 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh2 Update DV Set Config = cast(xConfig as varchar(max)) From DocVersions DV -- Remove Links from DocVersions Join @Enh EE ON EE.ID = DV.VersionID Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Source Join @Enh1 EE ON EE.ID = CC.ContentID Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Enhanced Join @Enh2 EE ON EE.ID = CC.ContentID SELECT [ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] where ContentID in (Select ID From @Enh1 UNION Select ID From @Enh2) 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 'StoredProcedure [vesp_PurgeEnhancedDocVersionsAndChildren] Succeeded' ELSE PRINT 'StoredProcedure [vesp_PurgeEnhancedDocVersionsAndChildren] Error on Creation' go -- AddToPromsFixes_Convert16to32 IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetOldEnhancedProcItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetOldEnhancedProcItems]; GO /* select * from vefn_GetOldEnhancedProcItems(17012) select * from vefn_GetOldEnhancedProcItems(17066) select * from vefn_GetOldEnhancedProcItems(17012) VE join vefn_GetOldEnhancedProcItems(17066) VS on ve.Procname = vs.ProcName and substring(VE.RecID,3,8) = substring(VS.RecID,3,8) select * from vefn_GetOldEnhancedProcItems(17014) select * from vefn_GetOldEnhancedProcItems(17015) select * from vefn_GetOldEnhancedProcItems(17029) select * from vefn_GetOldEnhancedProcItems(17033) select * from vefn_GetOldEnhancedProcItems(17045) select * from vefn_GetOldEnhancedProcItems(99043) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetOldEnhancedProcItems](@ItemID as int) RETURNS @Enhanced TABLE ( ItemID int, ContentID int, ProcName varchar(255), RecID varchar(10) ) WITH EXECUTE AS OWNER AS BEGIN declare @ProcNum varchar(255) select @ProcNum = replace(Number,'\u8209?','-') from contents CC --select @ProcNum = replace(replace(Number,'\u8209?','-'),'\u9586?','\') from contents CC join Items II on II.ContentID = CC.ContentID Where ItemID = @ItemID Begin with Itemz([FromType], [Level], [ItemID], [ContentID]) as ( Select 1 [FromType], 0 [Level], [ItemID], [ContentID] FROM [Items] where [ItemID]=@ItemID Union All -- Children select P.FromType, [Level] + 1, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID where Z.FromType <= 2 or P.FromType in (3,4) Union All -- Siblings select Z.FromType, [Level] , I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID where Z.[Level] > 0 ) Insert into @Enhanced select ItemID,ContentID,ProcName,RecID from ( select II.ItemID,II.ContentID , isnull(xHistory.value('@ProcName','varchar(255)'),@ProcNum) ProcName , xHistory.value('@RecID','varchar(255)') RecID , Row_Number() over (partition by isnull(xHistory.value('@ProcName','varchar(255)'),@ProcNum) , xHistory.value('@RecID','varchar(255)') order by ItemID) RowOrder from Itemz II Join (select *, Cast(config as xml) xConfig from Contents) CC ON CC.ContentID = II.ContentID Cross Apply xConfig.nodes('//History') tHistory(xHistory) ) T1 where RowOrder = 1 OPTION (MAXRECURSION 10000) END RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_GetOldEnhancedProcItems] Succeeded' ELSE PRINT 'TableFunction [vefn_GetOldEnhancedProcItems] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_Get16to32EnhancedProcItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_Get16to32EnhancedProcItems]; GO /* select * from vefn_Get16to32EnhancedProcItems(17012,17066,1) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_Get16to32EnhancedProcItems](@SourceID int, @EnhanceID int, @EnhType int) RETURNS @EnhItems TABLE ( SrcItemID int, SrcContentID int, SrcConfig varchar(255), ProcName varchar(255), RecID varchar(8), EnhItemID int, EnhContentID int, EnhConfig varchar(255), EnhProcName varchar(255), EnhRecID varchar(8) ) BEGIN Insert into @EnhItems-- Procedures select @SourceID SrcItemID, (select ContentID from Items Where ItemID = @SourceID) SrcContentID ,'' SrcConfig ,isnull(VSO.ProcName,replace(CCS.Number,'\u8209?','-')) SrcProcName, null SrcRecID --,isnull(VSO.ProcName,replace(replace(CCS.Number,'\u8209?','-'),'\u9586?','\')) SrcProcName, null SrcRecID ,@EnhanceID EnhItemID, (select ContentID from Items Where ItemID = @EnhanceID) EnhContentID ,'' EnhConfig ,isnull(VEO.ProcName ,replace(CCE.Number,'\u8209?','-')) EnhProcNam, null EnhRecID --,isnull(VEO.ProcName ,replace(replace(CCE.Number,'\u8209?','-'),'\u9586?','\')) EnhProcNam, null EnhRecID From vefn_GetOldEnhancedData(@SourceID) VSO cross apply vefn_GetOldEnhancedData(@EnhanceID) VEO JOIN Contents CCS ON VSO.ContentID = CCs.ContentID JOIN Contents CCE ON VEO.ContentID = CCE.ContentID Insert into @EnhItems--Sections and Steps select VS.ItemID, VS.ContentID ,'' SrcConfig ,VS.ProcName SrcProcName, VS.RecID RecID ,VE.ItemID EnhItemID, VE.ContentID EnhContentID ,'' EnhConfig ,VE.ProcName EnhProcName, VE.RecID EnhRecID from vefn_GetOldEnhancedProcItems(@SourceID) VS join vefn_GetOldEnhancedProcItems(@EnhanceID) VE on ve.Procname = vs.ProcName and substring(VE.RecID,2,8) = 'L' + substring(VS.RecID,3,8) --select * from @EnhItems RETURN END GO IF (@@Error = 0) PRINT 'TableFunction [vefn_Get16to32EnhancedProcItem] Succeeded' ELSE PRINT 'TableFunction [vefn_Get16to32EnhancedProcItem] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_Get16BitEnhancedContents]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_Get16BitEnhancedContents]; GO /* vesp_Get16BitEnhancedContents 17012,17066,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_Get16BitEnhancedContents](@SourceID int, @EnhanceID int, @EnhType int) -- @EnhanceID -- Enhanced VersionID WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @EnhItems TABLE ( SrcItemID int, SrcContentID int, SrcConfig varchar(255), ProcName varchar(255), RecID varchar(8), EnhItemID int, EnhContentID int, EnhConfig varchar(255), EnhProcName varchar(255), EnhRecID varchar(8) ) Insert into @EnhItems select * from vefn_Get16to32EnhancedProcItems(@SourceID,@EnhanceID,@EnhType) SELECT [ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] where ContentID in (Select SrcContentID from @EnhItems union Select EnhContentID from @EnhItems) 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 'StoredProcedure [vesp_Get16BitEnhancedContents] Succeeded' ELSE PRINT 'StoredProcedure [vesp_Get16BitEnhancedContents] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_Convert16to32EnhancedContents]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_Convert16to32EnhancedContents]; GO /* vesp_Convert16to32EnhancedContents 17012,17066,1 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_Convert16to32EnhancedContents](@SourceID int, @EnhanceID int, @EnhType int) -- @EnhanceID -- Enhanced VersionID WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @EnhItems TABLE ( SrcItemID int, SrcContentID int, SrcConfig varchar(255), ProcName varchar(255), RecID varchar(8), EnhItemID int, EnhContentID int, EnhConfig varchar(255), EnhProcName varchar(255), EnhRecID varchar(8) ) Insert into @EnhItems select * from vefn_Get16to32EnhancedProcItems(@SourceID,@EnhanceID,@EnhType) Update CC Set Config = cast(cast(Replace(Config,'>' + SrcConfig +'' + EnhConfig +' 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 'StoredProcedure [vesp_Convert16to32EnhancedContents] Succeeded' ELSE PRINT 'StoredProcedure [vesp_Convert16to32EnhancedContents] Error on Creation' go PRINT 'Enhanced Document Synchronization code.' /****** Object: StoredProcedure [vesp_GetUnusedRoFstsCount] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetUnusedRoFstsCount]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetUnusedRoFstsCount]; GO /* exec vesp_GetUnusedRoFstsCount */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetUnusedRoFstsCount] WITH EXECUTE AS OWNER AS Select COUNT(*) HowMany From ROFSTS where ROFstID not in(Select ROFSTID from Associations) RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetUnusedRoFstsCount Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetUnusedRoFstsCount Error on Creation' GO /****** Object: StoredProcedure [vesp_GetUnusedRoFstsCount] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetUnusedFiguresCount]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetUnusedFiguresCount]; GO /* exec vesp_GetUnusedFiguresCount */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetUnusedFiguresCount] WITH EXECUTE AS OWNER AS Select COUNT(*) HowMany from Figures where ROFstID not in(Select ROFSTID from Associations) RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetUnusedFiguresCount Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetUnusedFiguresCount Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_RemoveUnusedRoFstsAndFigures]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_RemoveUnusedRoFstsAndFigures]; GO /* vesp_RemoveUnusedRoFstsAndFigures */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_RemoveUnusedRoFstsAndFigures] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION Delete From Figures where ROFstID not in(Select ROFSTID from Associations) Delete From ROFSTS where ROFstID not in(Select ROFSTID from Associations) 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 'StoredProcedure [vesp_RemoveUnusedRoFstsAndFigures] Succeeded' ELSE PRINT 'StoredProcedure [vesp_RemoveUnusedRoFstsAndFigures] Error on Creation' go /****** Object: StoredProcedure [vesp_GetUnusedROAssociationsCount] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetUnusedROAssociationsCount]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetUnusedROAssociationsCount]; GO /* exec vesp_GetUnusedROAssociationsCount */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetUnusedROAssociationsCount] WITH EXECUTE AS OWNER AS --SELECT COUNT(*) HowMany FROM vefn_GetDisconnectedItems() begin with cte as ( Select *, Row_Number() over (partition by VersionID order by associationID ) MyRank from Associations ) select count(*) HowMany from CTE where MyRank > 1 end RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetUnusedROAssociationsCount Succeeded' ELSE PRINT 'Procedure Creation: vesp_GetUnusedROAssociationsCount Error on Creation' GO /****** Object: StoredProcedure [vesp_CleanUpROAssociations] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_CleanUpROAssociations]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_CleanUpROAssociations]; GO /* vesp_CleanUpROAssociations */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_CleanUpROAssociations] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION BEGIN with cte as ( Select *, Row_Number() over (partition by VersionID order by associationID ) MyRank from Associations ) delete CTE where MyRank > 1 END 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 'StoredProcedure [vesp_CleanUpROAssociations] Succeeded' ELSE PRINT 'StoredProcedure [vesp_CleanUpROAssociations] Error on Creation' go /****** Object: StoredProcedure [addPdf] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addPdf]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addPdf]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addPdf] ( @DocID int, @DebugStatus int, @TopRow int, @PageLength int, @LeftMargin int, @PageWidth int, @PageCount float, @DocPdf varbinary(MAX)=null, @DTS datetime, @UserID nvarchar(100), @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION IF not exists(select * FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth) BEGIN INSERT INTO [Pdfs] ( [DocID], [DebugStatus], [TopRow], [PageLength], [LeftMargin], [PageWidth], [PageCount], [DocPdf], [DTS], [UserID] ) VALUES ( @DocID, @DebugStatus, @TopRow, @PageLength, @LeftMargin, @PageWidth, @PageCount, @DocPdf, @DTS, @UserID ) END SELECT @newLastChanged=[LastChanged] FROM [Pdfs] WHERE [DocID]=@DocID AND [DebugStatus]=@DebugStatus AND [TopRow]=@TopRow AND [PageLength]=@PageLength AND [LeftMargin]=@LeftMargin AND [PageWidth]=@PageWidth 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: addPdf Succeeded' ELSE PRINT 'Procedure Creation: addPdf Error on Creation' GO /****** Object: Index [IX_itemsLastChanged] Script Date: 3/21/2017 11:24:00 AM ******/ IF EXISTS (SELECT * FROM dbo.sysIndexes WHERE name like 'IX_ItemsLastChanged') DROP INDEX [IX_ItemsLastChanged] ON [dbo].[tblItems]; GO CREATE NONCLUSTERED INDEX [IX_ItemsLastChanged] ON [dbo].[tblItems] ( [DeleteStatus] ASC, [LastChanged] DESC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO PRINT 'Added IX_ItemsLastChanged Index. Speeds up session queries' GO /****** Object: StoredProcedure [getJustROImage] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getJustROImage]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getJustROImage]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getJustROImage] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [ImageID]=@ImageID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getJustROImage Succeeded' ELSE PRINT 'Procedure Creation: getJustROImage Error on Creation' GO /****** Object: StoredProcedure [deleteAllDocVersionPdfs] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteAllDocVersionPdfs]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [deleteAllDocVersionPdfs]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[deleteAllDocVersionPdfs] ( @VersionID int ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DELETE [Pdfs] WHERE [DocID] IN(select EE.DocID from vefn_GetVersionItems(cast(@VersionID as varchar(20))) VI Join Entries EE ON EE.ContentID= VI.ContentID) 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: deleteAllDocVersionPdfs Succeeded' ELSE PRINT 'Procedure Creation: deleteAllDocVersionPdfs Error on Creation' GO /****** Object: StoredProcedure [addFiguresByROFstIDandImageIDs] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addFiguresByROFstIDandImageIDs]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addFiguresByROFstIDandImageIDs]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[addFiguresByROFstIDandImageIDs] ( @ROFstID int, @ImageIDs varchar(max) ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Figures] ( [ROFstID] ,[ImageID] ,[Config] ,[DTS] ,[UserID] ) select distinct FF.ROFstID, II.ID ImageID, '' Config, FF.DTS, FF.UserID from ROFsts FF , vefn_SplitInt(@ImageIDs,',') II where ROFstID=@ROFstID and II.ID not in (select ImageID from Figures where ROFstID = @ROFstID) SELECT [FigureID] ,[ROFstID] ,[ImageID] ,[Config] ,[DTS] ,[UserID] ,[LastChanged] FROM [Figures] WHERE [ROFstID]=@ROFstID 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: addFiguresByROFstIDandImageIDs Succeeded' ELSE PRINT 'Procedure Creation: addFiguresByROFstIDandImageIDs Error on Creation' GO /****** Object: StoredProcedure [vesp_FixHyphens] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_FixHyphens]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_FixHyphens]; GO /* exec vesp_DeletePDFs */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_FixHyphens] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION Update Contents set Text = Replace(Replace(Replace(Replace(Replace(Replace(Replace(Text,'\emdash','\u8209?'),'\endash','\u8209?'),'\u8213?','\u8209?'),'\u8212?','\u8209?'),'\u8211?','\u8209?'),'\u8210?','\u8209?'),'\u8208?','\u8209?') where Text Like '%\u8208?%' or Text Like '%\u8210?%' or Text Like '%\u8211?%' or Text Like '%\u8212?%' or Text Like '%\u8213?%' or Text Like '%\endash%' or Text Like '%\emdash%' 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: vesp_FixHyphens Succeeded' ELSE PRINT 'Procedure Creation: vesp_FixHyphens Error on Creation' GO /****** Object: StoredProcedure [getUsers] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getUsers]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getUsers]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getUsers] WITH EXECUTE AS OWNER AS SELECT [UID], [UserID], [FirstName], [MiddleName], [LastName], [Suffix], [CourtesyTitle], [PhoneNumber], [CFGName], [UserLogin], [UserName], [Config], [DTS], [UsrID], [LastChanged], (SELECT COUNT(*) FROM [Memberships] WHERE [Memberships].[UID]=[Users].[UID]) [MembershipCount] FROM [Users] ORDER BY UserID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getUsers Succeeded' ELSE PRINT 'Procedure Creation: getUsers Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetZeroFromType]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetZeroFromType]; GO /****** Object: UserDefinedFunction [dbo].[vefn_GetZeroFromType] ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* Select * from vefn_GetZeroFromType() */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetZeroFromType]() RETURNS @DiscItems TABLE ( ItemID int primary Key, ContentID int, UNIQUE (ContentID) ) WITH EXECUTE AS OWNER AS BEGIN with ItemZ (BaseID, ItemID, ContentID) as (Select PP.ContentID BaseID, II.ItemID, II.ContentID from Items II Join Parts PP ON PP.ItemID = II.ItemID where FromType = 0 Union All -- Children select z.BaseID, I.[ItemID], I.[ContentID] from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID Union All -- Siblings select z.BaseID, I.[ItemID], I.[ContentID] from Itemz Z join Items I on I.PreviousID = Z.ItemID ) --select *, dbo.ve_GetShortPath(ItemID) Location from ItemZ insert into @DiscItems Select ItemID, ContentID from ItemZ RETURN END go IF (@@Error = 0) PRINT 'TableFunction [vefn_GetZeroFromType] Succeeded' ELSE PRINT 'TableFunction [vefn_GetZeroFromType] Error on Creation' GO -- B2017-227 Added code to support Export/Import of Enhanced Documents /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /****** Object: Trigger [tr_tblContents_Update] ******/ ALTER trigger [dbo].[tr_tblContents_Update] on [dbo].[tblContents] for update as begin if exists (select * from inserted) begin if update(Number) or update(Text) or update(Type) or update(FormatID) or update(DeleteStatus) begin insert into ContentAudits(ContentID,Number,Text,Type,FormatID,Config,DTS,UserID,DeleteStatus,ActionDTS) select dd.ContentID,dd.Number,dd.Text,dd.Type,dd.FormatID,dd.Config,dd.DTS,dd.UserID,dd.DeleteStatus,dd.ActionDTS from deleted dd inner join inserted ii on dd.ContentID = ii.ContentID where dd.Text not like '%' -- Insert Export Node into the Source and Enhanced DocVersion records Update DV set Config = Replace(Cast(xConfig as nvarchar(max)),'',@ExportNode + '') from DocVersions DV Join @DV DV2 on DV2.VersionID = DV.VersionID 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 'StoredProcedure [vesp_BuildDocVersionExport] Succeeded' ELSE PRINT 'StoredProcedure [vesp_BuildDocVersionExport] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'vesp_BuildContentsExport') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_BuildContentsExport]; GO /* select Count(*) AuditsBefore from ContentAudits select top 5 CC.ContentID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from Contents) CC cross apply xconfig.nodes('//Export') tExport(xExport) EXEC [vesp_BuildContentsExport] 13 select Count(*) AuditsAfter from ContentAudits select top 5 CC.ContentID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from Contents) CC cross apply xconfig.nodes('//Export') tExport(xExport) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- Add Unique IDs for Each Enhanced Link in the Contents records CREATE PROCEDURE [dbo].[vesp_BuildContentsExport](@SourceID int) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- Update the DocVersion Records as the Content records are being saved with the Export node Exec vesp_BuildDocVersionExport @SourceID -- Create a list of Source and Enhanced VersionIDs declare @VersionList varchar(max) select @VersionList = Coalesce(@VersionList+',','') + cast(VersionId as varchar(10)) from ( select VersionID from DocVersions DV where VersionID = @SourceID Union select VersionID from (Select *, Cast(config as xml) xConfig from DocVersions) DV cross apply xConfig.nodes('//Enhanced[@VersionID=sql:variable("@SourceID")]') tEnhanced(xEnhanced)) T1 -- Temporary table of ContentID and config as XML for record in the Specified DocVersion VersionIDs that have Export Nodes Declare @Config TABLE ( ContentID int, xConfig xml ) -- Build the temporary table Insert into @Config select CC.ContentID, xconfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(@VersionList) VI ON VI.ContentID = CC.ContentID cross Apply xConfig.nodes('//Export') tExport(xExport) -- Delete the existing Export nodes so that the new nodes can be added. update @Config Set xConfig.modify('delete //Export') From @Config -- Update the Config field in the Content records with the old Export node removed. update CC set Config = cast(xConfig as NVarchar(max)) from Contents CC join @Config C1 ON C1.ContentID = CC.ContentID -- Temporary table with new link nodes Declare @NewLinkData TABLE ( ContentID int, EContentID int, ItemLink int, LinkNode nvarchar(250) ) -- The following code build the Export node based upon Dense_Rank() which is similar to a record count -- only it is based upon the Source ItemID and returns a unique integer value insert into @NewLinkData select distinct t1.ContentID, II.ContentID EContentID , DENSE_RANK() Over (Order by t1.ItemID) ItemLink , '' LinkNode From ( select ItemID, vi.VersionID, VI.ContentID, xEnhanced.query('.') qEnhanced ,xEnhanced.value('@Type','int') EType ,xEnhanced.value('@ItemID','int') EItemID from (Select *, cast(config as xml) xconfig from Contents where config Like '%Enhanced%') CC JOIN VEFN_GetVersionItems(cast(@SourceID as nvarchar(10))) VI ON VI.ContentID = CC.ContentID cross Apply xConfig.nodes('//Enhanced') tEnhanced(xEnhanced)) T1 JOIN Items II ON II.ItemID = EItemID Where EType!=0 -- Add the Export Node created in the temprorary table for the Source document Update CC set Config = Replace(Config,'',LinkNode + '') From tblContents CC Join @NewLinkData LD ON LD.ContentID = CC.ContentID -- Add the Export Node created in the tempoary table for the Enhanced document Update CC set Config = Replace(Config,'',LinkNode + '') From tblContents CC Join @NewLinkData LD ON LD.EContentID = CC.ContentID 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 'StoredProcedure [vesp_BuildContentsExport] Succeeded' ELSE PRINT 'StoredProcedure [vesp_BuildContentsExport] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'vesp_BuildContentsEnhanced') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_BuildContentsEnhanced]; GO /* select Count(*) AuditsBefore from ContentAudits select top 5 CC.ContentID, xEnhanced.query('.') qEnhanced from (select *, Cast(config as xml) xconfig from Contents) CC cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) EXEC [vesp_BuildContentsEnhanced] 17 select Count(*) AuditsAfter from ContentAudits select top 5 CC.ContentID, xEnhanced.query('.') qEnhanced from (select *, Cast(config as xml) xconfig from Contents) CC cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2017 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- Create Enahnced Nodes for an Enahnced document and its related Source document CREATE PROCEDURE [dbo].[vesp_BuildContentsEnhanced](@EnhancedID int) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION declare @SourceID int -- Source VersionID -- Get SourceID from EnhancedID select @SourceID = xEnhanced.value('@VersionID','int') from (select *, cast(config as xml) xconfig from DocVersions) DV cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) where VersionID = @EnhancedID DECLARE @EnhType int -- Get the Enhanced Type from the DocVersion record select @EnhType = xEnhanced.value('@Type','int') from (select *, cast(config as xml) xConfig from DocVersions where VersionID = @SourceID) DV cross apply xconfig.nodes('//Enhanced[@VersionID=sql:variable("@EnhancedID")]') tEnhanced(xEnhanced) -- Fix DocVersion Records -- Temporary Table used to delete old Enhanced Nodes in the source document declare @Enh1 TABLE ( ID int, xConfig xml ) insert into @Enh1 -- Links to Enhanced from Source select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@SourceID as varchar(25))) VI ON VI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VI.itemid,@EnhType) VEN -- delete the Enhanced node from the config Update @Enh1 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh1 -- Update the content record removing the Enhanced node from config Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Source Join @Enh1 EE ON EE.ID = CC.ContentID -- Temporary Table used to delete old Enhanced Nodes in the enhanced document declare @Enh2 TABLE ( ID int, xConfig xml ) insert into @Enh2 -- Links to Source from Enhanced select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@EnhancedID as varchar(25))) VI ON VI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VI.itemid,0) VEN --set @EnhType=0 -- delete the Enhanced node from the config Update @Enh2 Set xConfig.modify('delete //Enhanced[@Type=0]') From @Enh2 -- Update the content record removing the Enhanced node from config Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Enhanced Join @Enh2 EE ON EE.ID = CC.ContentID -- Temporary Table used to store the Export LinkID with the ContentID and the ItemID for the Source Document declare @Source TABLE ( Type int, ContentID int, ItemID int, LinkID int primary Key ) -- Build the table based upon the Export Nodes in the Source document insert into @Source Select @EnhType dvType, CC.ContentID, vi.ItemID, xExport.value('@LinkID','int') LinkID from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@SourceID as varchar(10))) VI ON VI.ContentID = CC.ContentID Join (select *, cast(config as xml)xdvConfig from DocVersions) DV ON VI.VersionID= DV.VersionID cross apply xConfig.nodes('//Export') tExport(xExport) --cross apply xDVConfig.nodes('//Enhanced') tdvEnhanced(xdvEnhanced) -- Temporary Table used to store the Export LinkID with the ContentID and the ItemID for the Enhanced Document declare @Enhanced TABLE ( Type int, ContentID int, ItemID int, LinkID int primary key ) -- Build the table based upon the Export Nodes in the Enhanced document insert into @Enhanced Select xdvEnhanced.value('@Type','int') dvType, CC.ContentID, vi.ItemID, xExport.value('@LinkID','int') LinkID from (select *, cast(config as xml) xConfig from Contents) CC JOIN VEFN_GetVersionItems(cast(@EnhancedID as varchar(10))) VI ON VI.ContentID = CC.ContentID Join (select *, cast(config as xml)xdvConfig from DocVersions) DV ON VI.VersionID= DV.VersionID cross apply xConfig.nodes('//Export') tExport(xExport) cross apply xDVConfig.nodes('//Enhanced') tdvEnhanced(xdvEnhanced) -- Temporary Table of ContentIDs and New Enhanced Node Text declare @Links TABLE ( ContentID int primary key, LinkText nvarchar(250) ) --Build the temporary table with the new enhanced Nodes insert into @links select SS.ContentID, '' EnhancedNode from @Source SS join @Enhanced EE on EE.LinkID = SS.LinkID UNION select EE.ContentID, '' EnhancedNode from @Source SS join @Enhanced EE on EE.LinkID = SS.LinkID -- Update content records insering the Enhanced Nodes from the temporary table. Update CC set Config = Replace(Config,'',LinkText + '') From Contents CC Join @Links LD ON LD.ContentID = CC.ContentID 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 'StoredProcedure [vesp_BuildContentsEnhanced] Succeeded' ELSE PRINT 'StoredProcedure [vesp_BuildContentsEnhanced] Error on Creation' go ---The following Formats/Config column was added for User Control of Format (UCF), but needed to be added before existing procedures. --- Added for additional config column on formats to store UCF data. Also modified existing queries to get UCF Data for Formats --- Note that vefn_GetVersionFormatItems was also modified as part of this work to return the parentformatId IF NOT EXISTS(SELECT * FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'Formats' AND COLUMN_NAME = 'Config') ALTER TABLE Formats ADD Config nvarchar(MAX) NULL; go -- Display the status IF (@@Error = 0) PRINT 'Altered table [Formats] Succeeded' ELSE PRINT 'Altered table [Formats] Error on Alter' go /****** Object: StoredProcedure [getChildFormats] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getChildFormats]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getChildFormats]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getChildFormats] ( @ParentID int ) WITH EXECUTE AS OWNER AS with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select * from ( select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz) T1 WHERE [ParentID]=@ParentID AND [FormatID]<>@ParentID AND (Description not like '%(Unused)%' or (ContentCount + DocVersionCount + FolderCount + ChildCount > 0)) RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getChildFormats Succeeded' ELSE PRINT 'Procedure Creation: getChildFormats Error on Creation' GO /****** Object: StoredProcedure [getFormats] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormats]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormats]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getFormats] WITH EXECUTE AS OWNER AS BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select * from ( select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz) t1 where Description not like '%(Unused)%' or (ContentCount + DocVersionCount + FolderCount + ChildCount > 0) END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getFormats Succeeded' ELSE PRINT 'Procedure Creation: getFormats Error on Creation' GO /****** Object: StoredProcedure [getAllFormats] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAllFormats]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAllFormats]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getAllFormats] WITH EXECUTE AS OWNER AS SELECT * From (SELECT [FormatID], [ParentID], [Name], [Description], [Data], [Config], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] ) T1 RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getAllFormats Succeeded' ELSE PRINT 'Procedure Creation: getAllFormats Error on Creation' GO ----- /****** Object: StoredProcedure [vesp_SearchSepcifiedApplicability] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchSepcifiedApplicability]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SearchSepcifiedApplicability]; GO /* exec vesp_SearchSepcifiedApplicability '16','','',0,0,0,0,'','3' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_SearchSepcifiedApplicability] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX), @ApplicSetting varchar(MAX)) WITH EXECUTE AS OWNER AS select ZZ.DvPath, ZZ.Path, ZZ.[Level],ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] ,II.[LastChanged] ,CC.[Number],CC.[Text],CC.[Type],CC.[FormatID],CC.[Config],CC.[DTS] [cDTS],CC.[UserID] [cUserID] ,CC.[LastChanged] [cLastChanged], PP.[ContentID] [pContentID], PP.[DTS] [pDTS],PP.[UserID] [pUserID], PP.[LastChanged] [pLastChanged], (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=CC.[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=CC.[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=CC.[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=CC.[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=CC.[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=CC.[ContentID]) [cPartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=CC.[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=CC.[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=CC.[ContentID]) [ZContentCount] from vefn_SiblingAndChildrenItems(@DocVersionList, @UnitPrefix) ZZ Join Items II on ZZ.ItemID=II.ItemID Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType Join Contents CC on CC.ContentID=ZZ.ContentID where ZZ.ContentID in (select ContentID from vefn_FindSpecificApplicUsage(@DocVersionList, @ApplicSetting)) order by DvPath,OrdinalPath GO IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchSepcifiedApplicability Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchSepcifiedApplicability Error on Creation' GO ----- /****** Object: StoredProcedure [vefn_FindSpecificApplicUsage] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindSpecificApplicUsage]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_FindSpecificApplicUsage]; GO /* exec vefn_FindSpecificApplicUsage '16','3' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FindSpecificApplicUsage]( @DocVersionList nvarchar(MAX) ,@ApplicSetting varchar(MAX)) RETURNS @FoundContents TABLE ( ContentID int PRIMARY KEY ) WITH EXECUTE AS OWNER AS BEGIN insert into @FoundContents select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C join items ii on ii.ContentID = C.ContentID where ','+ dbo.ve_GetItemAppliedApplicability(ii.ItemID ) + ',' like '%,' + @ApplicSetting + ',%' RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vefn_FindSpecificApplicUsage Succeeded' ELSE PRINT 'Procedure Creation: vefn_FindSpecificApplicUsage Error on Creation' GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2018 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ ---- ************************* UCF Changes ************************************* IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addFormat]; GO CREATE PROCEDURE [dbo].[addFormat] ( @ParentID int, @Name nvarchar(100), @Description nvarchar(250)=null, @Data xml, @Config nvarchar(MAX)=null, @GenMac xml=null, @DTS datetime, @UserID nvarchar(100), @newFormatID int output, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION INSERT INTO [Formats] ( [ParentID], [Name], [Description], [Data], [Config], [GenMac], [DTS], [UserID] ) VALUES ( @ParentID, @Name, @Description, @Data, @Config, @GenMac, @DTS, @UserID ) SELECT @newFormatID= SCOPE_IDENTITY() SELECT @newLastChanged=[LastChanged] FROM [Formats] WHERE [FormatID]=@newFormatID 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 'StoredProcedure [addFormat] Succeeded' ELSE PRINT 'StoredProcedure [addFormat] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[updateFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [updateFormat]; GO CREATE PROCEDURE [dbo].[updateFormat] ( @FormatID int, @ParentID int, @Name nvarchar(100), @Description nvarchar(250)=null, @Data xml, @Config nvarchar(MAX), @GenMac xml=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [Formats] SET [ParentID]=@ParentID, [Name]=@Name, [Description]=@Description, [Data]=@Data, [Config]=@Config, [GenMac]=@GenMac, [DTS]=@DTS, [UserID]=@UserID WHERE [FormatID]=@FormatID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [Formats] WHERE [FormatID]=@FormatID) RAISERROR('Format record has been deleted by another user', 16, 1) ELSE RAISERROR('Format has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [Formats] WHERE [FormatID]=@FormatID 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 'StoredProcedure [updateFormat] Succeeded' ELSE PRINT 'StoredProcedure [updateFormat] Error on Creation' go ALTER TABLE Formats ALTER COLUMN Data Xml NULL IF (@@Error = 0) PRINT 'Alter Table Formats Succeeded' ELSE PRINT 'Alter Table Formats Error on Alter' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormatListUsed]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormatListUsed]; GO CREATE PROCEDURE [dbo].[getFormatListUsed] WITH EXECUTE AS OWNER AS BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[GenMac],[DTS],[UserID],[Config]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[GenMac],[DTS],[UserID],[Config] FROM [dbo].[Formats] where formatid in ((select formatid from folders union select formatid from docversions union select formatid from contents) ) and name != 'base' --and DATALENGTH(Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[Config] from formats fs join formatz fz on fz.FormatID = fs.ParentID --where fs.Data is null) where fs.Data is not null and DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] from Formats where formatid in (select distinct formatid from formatz) END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getFormatListUsed] Succeeded' ELSE PRINT 'StoredProcedure [getFormatListUsed] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormat]; GO CREATE PROCEDURE [dbo].[getFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz WHERE [FormatID]=@FormatID END SELECT [Contents].[ContentID], [Contents].[Number], [Contents].[Text], [Contents].[Type], [Contents].[FormatID], [Contents].[Config], [Contents].[DTS], [Contents].[UserID], [Contents].[LastChanged] FROM [Contents] WHERE [Contents].[FormatID]=@FormatID SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[FormatID]=@FormatID SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged], [Connections].[Name] [Connection_Name], [Connections].[Title] [Connection_Title], [Connections].[ConnectionString] [Connection_ConnectionString], [Connections].[ServerType] [Connection_ServerType], [Connections].[Config] [Connection_Config], [Connections].[DTS] [Connection_DTS], [Connections].[UsrID] [Connection_UsrID] FROM [Folders] JOIN [Connections] ON [Connections].[DBID]=[Folders].[DBID] WHERE [Folders].[FormatID]=@FormatID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getFormat] Succeeded' ELSE PRINT 'StoredProcedure [getFormat] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormatByName]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormatByName]; GO CREATE PROCEDURE [dbo].[getFormatByName] ( @Name varchar(255) ) WITH EXECUTE AS OWNER AS DECLARE @FormatID INT Set @FormatID = (select FormatID from Formats where Name = @Name) BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz WHERE [FormatID]=@FormatID END SELECT [Contents].[ContentID], [Contents].[Number], [Contents].[Text], [Contents].[Type], [Contents].[FormatID], [Contents].[Config], [Contents].[DTS], [Contents].[UserID], [Contents].[LastChanged] FROM [Contents] WHERE [Contents].[FormatID]=@FormatID SELECT [DocVersions].[VersionID], [DocVersions].[FolderID], [DocVersions].[VersionType], [DocVersions].[Name], [DocVersions].[Title], [DocVersions].[ItemID], [DocVersions].[FormatID], [DocVersions].[Config], [DocVersions].[DTS], [DocVersions].[UserID], [DocVersions].[LastChanged], [Folders].[ParentID] [Folder_ParentID], [Folders].[DBID] [Folder_DBID], [Folders].[Name] [Folder_Name], [Folders].[Title] [Folder_Title], [Folders].[ShortName] [Folder_ShortName], [Folders].[FormatID] [Folder_FormatID], [Folders].[ManualOrder] [Folder_ManualOrder], [Folders].[Config] [Folder_Config], [Folders].[DTS] [Folder_DTS], [Folders].[UsrID] [Folder_UsrID] FROM [DocVersions] JOIN [Folders] ON [Folders].[FolderID]=[DocVersions].[FolderID] WHERE [DocVersions].[FormatID]=@FormatID SELECT [Folders].[FolderID], [Folders].[ParentID], [Folders].[DBID], [Folders].[Name], [Folders].[Title], [Folders].[ShortName], [Folders].[FormatID], [Folders].[ManualOrder], [Folders].[Config], [Folders].[DTS], [Folders].[UsrID], [Folders].[LastChanged], [Connections].[Name] [Connection_Name], [Connections].[Title] [Connection_Title], [Connections].[ConnectionString] [Connection_ConnectionString], [Connections].[ServerType] [Connection_ServerType], [Connections].[Config] [Connection_Config], [Connections].[DTS] [Connection_DTS], [Connections].[UsrID] [Connection_UsrID] FROM [Folders] JOIN [Connections] ON [Connections].[DBID]=[Folders].[DBID] WHERE [Folders].[FormatID]=@FormatID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getFormatByName] Succeeded' ELSE PRINT 'StoredProcedure [getFormatByName] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormatByParentID_Name]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormatByParentID_Name]; GO CREATE PROCEDURE [dbo].[getFormatByParentID_Name] ( @ParentID int, @Name nvarchar(20) ) WITH EXECUTE AS OWNER AS BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz WHERE [ParentID]=@ParentID AND [Name]=@Name END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getFormatByParentID_Name] Succeeded' ELSE PRINT 'StoredProcedure [getFormatByParentID_Name] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getParentFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getParentFormat]; GO CREATE PROCEDURE [dbo].[getParentFormat] ( @ParentID int ) WITH EXECUTE AS OWNER AS BEGIN with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz WHERE [FormatID]=@ParentID END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getParentFormat] Succeeded' ELSE PRINT 'StoredProcedure [getParentFormat] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getJustFormat]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getJustFormat]; GO CREATE PROCEDURE [dbo].[getJustFormat] ( @FormatID int ) WITH EXECUTE AS OWNER AS with formatz([FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged]) as (select [FormatID], [ParentID],[Name],[Description],[Data],[Config],[GenMac],[DTS],[UserID],[LastChanged] FROM [dbo].[Formats] fs where DATALENGTH(fs.Data) > 5 union all -- Child formats select fs.[FormatID], fs.[ParentID], fs.[Name], fs.[Description], fz.[Data], fs.[Config], fz.[GenMac], fs.[DTS], fs.[UserID], fs.[LastChanged] from formats fs join formatz fz on fz.FormatID = fs.ParentID where DATALENGTH(fs.Data) = 5) -- the DATALENGTH(fs.Data) = 5 is how to check for empty xml (Data's type is xml) select *, (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formatz].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formatz].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formatz].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formatz].[FormatID]) [ChildCount] from Formatz WHERE [FormatID]=@FormatID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getJustFormat] Succeeded' ELSE PRINT 'StoredProcedure [getJustFormat] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFormatNoUCF]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getFormatNoUCF]; GO CREATE PROCEDURE [dbo].[getFormatNoUCF] ( @FormatID int ) WITH EXECUTE AS OWNER AS SELECT [FormatID], [ParentID], [Name], [Description], [Data], [Config], [GenMac], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Contents] WHERE [Contents].[FormatID]=[Formats].[FormatID]) [ContentCount], (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[FormatID]=[Formats].[FormatID]) [DocVersionCount], (SELECT COUNT(*) FROM [Folders] WHERE [Folders].[FormatID]=[Formats].[FormatID]) [FolderCount], (SELECT COUNT(*) FROM [Formats] [Children] WHERE [Children].[ParentID]=[Formats].[FormatID]) [ChildCount] FROM [Formats] WHERE [FormatID]=@FormatID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [getFormatNoUCF] Succeeded' ELSE PRINT 'StoredProcedure [getFormatNoUCF] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetItemsMatchingFormatItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetItemsMatchingFormatItems]; GO CREATE FUNCTION [dbo].[vefn_GetItemsMatchingFormatItems](@ItemID int, @OldFormatID int, @NewFormatID int) RETURNS @Items TABLE ( ItemID int, ContentID int primary key, FormatID int ) WITH EXECUTE AS OWNER AS BEGIN BEGIN -- recursive, walk through content, items and parts table to find children -- ('with' makes it recursive, which is called cte, common table expressions, in sql) with Itemz([ItemID], [ContentID], [FormatID], [Level]) as (Select [I].[ItemID], [I].[ContentID], C.[FormatID], 0 FROM [Items] I join Contents C on I.ContentID = C.ContentID where I.ItemID = @ItemID and (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) Union All -- Children : get sections off procedures and subsections off sections select I.[ItemID], I.[ContentID], C.[FormatID], Z.[Level]+1 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 where C.Type < 20000 and (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) and (Z.[FormatID] is null or Z.[FormatID] = @OldFormatID or Z.FormatID = @NewFormatID) Union All -- Siblings : get remaining items (procedure and section) select I.[ItemID], I.[ContentID], C.[FormatID], Z.[Level] from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on I.ContentID = C.ContentID where C.Type < 20000 and Z.[Level] > 0 ) insert into @Items select [ItemID], [ContentID], [FormatID] from ItemZ I where ([FormatID] = @OldFormatID or [FormatID] = @NewFormatID) and [ItemID] != @ItemID OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [vefn_GetItemsMatchingFormatItems] Succeeded' ELSE PRINT 'StoredProcedure [vefn_GetItemsMatchingFormatItems] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionMatchingFormatItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetVersionMatchingFormatItems]; GO CREATE FUNCTION [dbo].[vefn_GetVersionMatchingFormatItems](@DocVersionList varchar(MAX), @OldFormatID int, @NewFormatID int) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key, FormatID int ) WITH EXECUTE AS OWNER AS BEGIN BEGIN -- recursive, walk through content, items and parts table to find children -- ('with' makes it recursive, which is called cte, common table expressions, in sql) with Itemz([VersionID], [ItemID], [ContentID], [FormatID]) as (Select DV.VersionID, [I].[ItemID], [I].[ContentID], C.[FormatID] FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] -- get first procedure for each doc version in list join docversions DV2 on DV.[VersionID] = DV2.[VersionID] join Contents C on I.ContentID = C.ContentID where (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) Union All -- Children : get sections off procedures and subsections off sections select Z.VersionID, I.[ItemID], I.[ContentID], C.[FormatID] 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 where C.Type < 20000 and (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) and (Z.[FormatID] is null or Z.[FormatID] = @OldFormatID or Z.FormatID = @NewFormatID) Union All -- Siblings : get remaining items (procedure and section) select Z.VersionID, I.[ItemID], I.[ContentID], C.[FormatID] from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on I.ContentID = C.ContentID where C.Type < 20000 ) insert into @VersionItems select VersionID, [ItemID], [ContentID], [FormatID] from ItemZ I where [FormatID] = @OldFormatID or [FormatID] = @NewFormatID OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [vefn_GetVersionMatchingFormatItems] Succeeded' ELSE PRINT 'StoredProcedure [vefn_GetVersionMatchingFormatItems] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetFolderMatchingFormatItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_GetFolderMatchingFormatItems]; GO CREATE FUNCTION [dbo].[vefn_GetFolderMatchingFormatItems](@FolderID int, @OldFormatID int, @NewFormatID int) RETURNS @VersionItems TABLE ( VersionID int, ItemID int, ContentID int primary key, FormatID int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @DocVersionList NVARCHAR(MAX) -- get list of docversions for a folder: BEGIN With Folderz([FolderID]) as ( select FF.FolderID from Folders FF Where FF.FolderID = @FolderID UNION ALL select FF.FolderID from Folders FF Join Folderz ZZ on FF.ParentID = ZZ.FolderID Where FF.FolderID != @FolderID and (FF.FormatID is null or FF.FormatID = @OldFormatID or FF.FormatID = @NewFormatID) ) select @DocVersionList = coalesce(@DocVersionList+',','')+cast(VersionId as varchar(255)) from Folderz ZZ Left Join DocVersions DV ON DV.FolderID = ZZ.FolderID where VersionID is not null and (DV.FormatID is null or DV.FormatID = @OldFormatID or DV.FormatID = @NewFormatID) order by versionID OPTION (MAXRECURSION 10000) END BEGIN -- recursive, walk through content, items and parts table to find children -- ('with' makes it recursive, which is called cte, common table expressions, in sql) with Itemz([VersionID], [ItemID], [ContentID], [FormatID]) as ( Select DV.VersionID, [I].[ItemID], [I].[ContentID], C.[FormatID] FROM [Items] I JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] -- get first procedure for each doc version in list join docversions DV2 on DV.[VersionID] = DV2.[VersionID] join Contents C on I.ContentID = C.ContentID where (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) Union All -- Children : get sections off procedures and subsections off sections select Z.VersionID, I.[ItemID], I.[ContentID], C.[FormatID] 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 where C.Type < 20000 and (C.FormatID is null or C.FormatID = @OldFormatID or C.FormatID = @NewFormatID) and (Z.[FormatID] is null or Z.[FormatID] = @OldFormatID or Z.FormatID = @NewFormatID) Union All -- Siblings : get remaining items (procedure and section) select Z.VersionID, I.[ItemID], I.[ContentID], C.[FormatID] from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on I.ContentID = C.ContentID where C.Type < 20000 ) insert into @VersionItems select VersionID, [ItemID], [ContentID], [FormatID] from ItemZ I where [FormatID] = @OldFormatID or [FormatID] = @NewFormatID OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'StoredProcedure [vefn_GetFolderMatchingFormatItems] Succeeded' ELSE PRINT 'StoredProcedure [vefn_GetFolderMatchingFormatItems] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ClearOverrideFormatsByFolder]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ClearOverrideFormatsByFolder]; GO CREATE PROCEDURE [dbo].[vesp_ClearOverrideFormatsByFolder](@FolderID int, @FormatID int, @NewFormatID int) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ClearedContents TABLE ( ContentID int ) DECLARE @ClearedFolders TABLE ( FolderID int ) DECLARE @ClearedDocVersions TABLE ( VersionID int ) insert into @ClearedContents select cc.ContentID from (select contentid from contents where formatid is not null) cc join vefn_GetFolderMatchingFormatItems(@FolderID, @FormatID, @NewFormatID) vi on vi.ContentID = cc.ContentID -- update any folders & docversions that are using that formatid to clear them, i.e. so they inherit. To do this -- get lists of folders & docversions that have non-null format ids that should be null. BEGIN With Folderz([FolderID], [FormatID]) as ( select FF.FolderID, FF.FormatID from Folders FF Where FF.FolderID = @FolderID UNION ALL select FF.FolderID, FF.FormatID from Folders FF Join Folderz ZZ on FF.ParentID = ZZ.FolderID Where FF.FolderID != @FolderID and (FF.FormatID is null or FF.FormatID = @FormatID or FF.FormatID = @NewFormatID) ) insert into @ClearedFolders select ZZ.FolderID from Folderz ZZ where ZZ.FormatID is not null and ZZ.FolderID != @FolderID -- don't include folder passed in, only do children (folder is done in code) OPTION (MAXRECURSION 10000) END BEGIN With Folderz([FolderID]) as ( select FF.FolderID from Folders FF Where FF.FolderID = @FolderID UNION ALL select FF.FolderID from Folders FF Join Folderz ZZ on FF.ParentID = ZZ.FolderID Where FF.FolderID != @FolderID and (FF.FormatID is null or FF.FormatID = @FormatID or FF.FormatID = @NewFormatID) ) insert into @ClearedDocVersions select DV.VersionID from Folderz ZZ Left Join DocVersions DV ON DV.FolderID = ZZ.FolderID where VersionID is not null and DV.FormatID is not null and (DV.FormatID = @FormatID or DV.FormatID = @NewFormatID) OPTION (MAXRECURSION 10000) END update Folders set formatid = null where FolderID in (select FolderID from @ClearedFolders) update DocVersions set formatid = null where VersionID in (select VersionID from @ClearedDocVersions) -- now update all of the contents that were found update contents set formatid = null where contentID in (select contentid from @ClearedContents) select [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM contents where contentid in (select ContentID from @ClearedContents) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByFolder Succeeded' ELSE PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByFolder Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ClearOverrideFormatsByDocVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ClearOverrideFormatsByDocVersion]; GO CREATE PROCEDURE [dbo].[vesp_ClearOverrideFormatsByDocVersion](@DocVersionList varchar(MAX), @FormatID int, @NewFormatID int) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ClearedContents TABLE ( ContentID int ) insert into @ClearedContents select cc.ContentID from (select contentid from contents where formatid is not null) cc join vefn_GetVersionMatchingFormatItems(@DocVersionList, @FormatID, @NewFormatID) vi on vi.ContentID = cc.ContentID --where vi.FormatID = @FormatID --and vi.ParentFormatID = @FormatID update contents set formatid = null where contentID in (select contentid from @ClearedContents) select [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM contents where contentid in (select ContentID from @ClearedContents) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByDocVersion Succeeded' ELSE PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByDocVersion Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_ClearOverrideFormatsByItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_ClearOverrideFormatsByItem]; GO CREATE PROCEDURE [dbo].[vesp_ClearOverrideFormatsByItem](@ItemID int, @FormatID int, @NewFormatID int) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ClearedContents TABLE ( ContentID int ) -- to test with the Ginna database: -- vesp_ClearOverrideFormatsByItem 36421, 205 insert into @ClearedContents select cc.ContentID from (select contentid, FormatID from contents where formatid is not null) cc join vefn_GetItemsMatchingFormatItems(@ItemID, @FormatID, @NewFormatID) ci on ci.ContentID = cc.ContentID update contents set formatid = null where contentID in (select contentid from @ClearedContents) select [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM contents where contentid in (select ContentID from @ClearedContents) RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByItem Succeeded' ELSE PRINT 'Procedure Creation: vesp_ClearOverrideFormatsByItem Error on Creation' GO IF COL_LENGTH('Formats','Name') = 40 ALTER TABLE [Formats] ALTER COLUMN [Name] [NVARCHAR](100) NOT NULL IF (@@Error = 0) PRINT 'Alter Table Formats Succeeded' ELSE PRINT 'Alter Table Formats Error on Alter' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_UpdateVersionFormatForUCF]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE vesp_UpdateVersionFormatForUCF; GO CREATE PROCEDURE [dbo].vesp_UpdateVersionFormatForUCF ( @VersionList nvarchar(MAX), @OldFormatID int, @NewFormatID int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @ClearedContents TABLE ( ContentID int ) -- save the content ids that will have there format changed so that these can be returned to the application -- for a refresh. insert into @ClearedContents select contentid from contents where formatID=@OldFormatID and ContentID in (select distinct ContentID from vefn_GetVersionItems(@VersionList) ) -- reset the oldformat to the newformat. This is used when during an import of procedure(s) in the case where -- all procedures in a set that use the oldformat should be set to the newformat (UCF formats) UPDATE [Contents] SET FormatID=@NewFormatID WHERE FormatID=@OldFormatID AND ContentID in (select distinct ContentID from vefn_GetVersionItems(@VersionList) ) select [ContentID], [Number], [Text], [Type], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM contents where contentid in (select ContentID from @ClearedContents) END RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: vesp_UpdateVersionFormatForUCF Succeeded' ELSE PRINT 'Procedure Creation: vesp_UpdateVersionFormatForUCF Error on Creation' GO /****** Object: Table Function [vefn_SiblingAndChildrenItemsNew] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingAndChildrenItemsNew]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_SiblingAndChildrenItemsNew]; GO /* select * from vefn_SiblingAndChildrenItemsNew('37','3-', '%rcp%','%rcp%','') where Text like '%rcp%' */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2019 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create FUNCTION [dbo].[vefn_SiblingAndChildrenItemsNew](@DocVersionList varchar(MAX),@UnitPrefix varchar(MAX),@SearchString varchar(MAX),@SearchStringx varchar(MAX), @StepTypeList varchar(MAX)) RETURNS @SiblingAndChildren TABLE ( [ILastChanged] varbinary(8) , [ItemID] int PRIMARY KEY , [DVPath] nvarchar(max) , [Path] nvarchar(max) , [FromType] int , [Ordinal] int , [ParentID] int , [PreviousID] int , [ContentID] int , [DTS] datetime , [UserID] nvarchar(100) , [pContentID] int , [pDTS] datetime , [pUserID] nvarchar(100) , [IsRNO] int , Text nvarchar(max) , DocAscii nvarchar(max) , Number nvarchar(256) , CType int , CFormatID int , CConfig nvarchar(max) , CDTS datetime , CUserID nvarchar(100) , CLastChanged varbinary(8) , PLastChanged varbinary(8) ) WITH EXECUTE AS OWNER AS BEGIN Declare @Delim char(1) Set @Delim=char(7) Declare @DelimNumber char(1) Set @DelimNumber=char(17) Declare @DelimStep char(1) Set @DelimStep='.' BEGIN with Itemz([ILastChanged], [ItemID], VersionID,[Path], [FromType],[Ordinal], [ParentID], [PreviousID], [ContentID], [DTS], [UserID],[pContentID], [pDTS],[pUserID],[IsRNO], Text, Number, PPath, CType, CFormatID, CConfig, CDTS, CUserID, CLastChanged, PLastChanged) as ( Select Cast(I.LastChanged as varbinary(8)) ILastChanged,[I].[ItemID], VersionID, Cast(Case when C.Type < 20000 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) [Path] , 0 [FromType], 0 [Ordinal], 0 [ParentID], [PreviousID],[I].[ContentID],[I].[DTS],[I].[UserID] ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID],0 IsRNO, C.Text, C.Number, Cast('' as nvarchar(max)) [PPath], C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID, Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(0 as varbinary(8)) PLastChanged FROM [Items] I Join Contents C on C.ContentID=I.ContentID JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID] Union All -- Children select Cast(I.LastChanged as varbinary(8)) ILastChanged,I.[ItemID], VersionID, Path + case C.Type/10000 when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Procedure when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Section else case P.FromType --when 1 then 'PRC' + @Delim + cast(1 as varchar(4)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(4)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep + cast(1 as varchar(4)) when 8 then @DelimStep +'SupInfo' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4)) end end Path, P.[FromType],0 [Ordinal], Z.ItemID [ParentID],I.[PreviousID], I.[ContentID],I.[DTS],I.[UserID], P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID], case when P.FromType = 5 then -1 else 0 end IsRNO, C.Text,c.Number, Path + case C.Type/10000 when 2 then case P.FromType when 3 then @DelimStep + 'Caution' when 4 then @DelimStep + 'Note' when 8 then @DelimStep + 'SupInfo' else '' end else '' end [PPath], C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID, Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(P.LastChanged as varbinary(8)) PLastChanged from Itemz Z join Parts P on P.ContentID = Z.ContentID join Items I on I.ItemID = P.ItemID join Contents C on C.ContentID = I.ContentID Union All -- Siblings select Cast(I.LastChanged as varbinary(8)) ILastChanged,I.[ItemID], VersionID, PPath + case C.Type/10000 when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Procedure when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Section else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4)) end Path, [FromType],Z.[Ordinal] +1,Z.[ParentID], I.[PreviousID], I.[ContentID],I.[DTS],I.[UserID] ,null,null,null, 0 IsRNO, C.Text, C.Number, PPath, C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID, Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(0 as varbinary(8)) PLastChanged from Itemz Z join Items I on I.PreviousID = Z.ItemID join Contents C on C.ContentID = I.ContentID --where Z.[Level] > 0 ) insert into @SiblingAndChildren select ZZ.ILastChanged,ZZ.[ItemID], dvpath, [Path],[FromType],[Ordinal], [ParentID], [PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID], [pContentID],[pDTS],[pUserID],[IsRNO],Text,DocAscii, Number, CType, CFormatID, CConfig, CDTS, CUserID, CLastChanged, PLastChanged From Itemz ZZ join vefn_DocVersionSplit(@DocVersionList) DV ON DV.VersionID=zz.VersionID Left Join Entries EE ON EE.ContentID=ZZ.ContentID Left Join Documents DD ON DD.DocID = ee.DocID where (text like @SearchString OR Replace(DD.DocAscii,nchar(176),'\''B0') like @SearchString or text like @SearchStringx OR Replace(DD.DocAscii,nchar(176),'\''B0') like @SearchStringx ) and (isnull(@StepTypeList,'') = '' or (dbo.vefn_AllSections(CType) in (Select ID from vefn_SplitInt(@StepTypeList,',')))) OPTION (MAXRECURSION 10000) END RETURN END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItemsNew Succeeded' ELSE PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItemsNew Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addItemChild]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addItemChild]; GO CREATE PROCEDURE [dbo].[addItemChild] ( @ItemID int=null, @Number nvarchar(256)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @FromType 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 @ChildID int, @ContentID int, @ParentContentID int, @LastChanged timestamp , @newLastChanged timestamp, @Error int, @Rowcount int, @ChildDeleted int SELECT @ChildID = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [PARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tblParts]') AND OBJECTPROPERTY(id,N'IsTable') = 1) BEGIN SELECT @ChildDeleted = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged FROM [ITEMS] ii LEFT JOIN [tblPARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType WHERE ii.[ItemID]=@ItemID and pp.DeleteStatus > 0 END EXECUTE AddContent @Number, @Text, @Type, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem null, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output IF @ChildID is null -- No existing child - Add Parts record BEGIN IF @ChildDeleted is not null BEGIN -- INSERT INTO [PartAudits] ([ContentID],[FromType],[ItemID],[DTS],[UserID],[DeleteStatus]) -- SELECT [ContentID],[FromType],[ItemID],[DTS],[UserID],[DeleteStatus] FROM [tblParts] -- WHERE ItemID = @ChildDeleted DELETE FROM [tblParts] WHERE ItemID = @ChildDeleted END EXECUTE AddPart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @newLastChanged output END ELSE -- Update existing Parts record BEGIN EXECUTE UpdatePart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @LastChanged, @newLastChanged output UPDATE [Items] SET [PreviousID]=@newItemID WHERE [ItemID]=@ChildID -- 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 = @ChildID OR TT.RangeID = @ChildID -- Update transitions that pointed to @ItemID to point to @newItemID Update TRANSITIONS Set ToID = CASE ToID WHEN @ChildID THEN @newItemID ELSE ToID END, RangeID = CASE RangeID WHEN @ChildID THEN @newItemID ELSE RangeID END WHERE ToID = @ChildID OR RangeID = @ChildID -- 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 -- I don't expect to see any transitions that point to @ChildID. They should have changed in -- the update above to point to @newItemID. This is here for consistency with the other insert -- stored procedures 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(@ChildID,@newItemID) OR RangeID IN(@ChildID,@newItemID)) -- Transition Text gets updated in ItemInsertExt.cs END IF( @@TRANCOUNT > 0 ) COMMIT PRINT 'Child Added ' + ltrim(str(@newItemID)) 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: addItemChild Succeeded' ELSE PRINT 'Procedure Creation: addItemChild Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addItemSiblingAfter]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addItemSiblingAfter]; GO CREATE PROCEDURE [dbo].[addItemSiblingAfter] ( @ItemID int=null, @Number nvarchar(256)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @newItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION DECLARE @NextID int, @ContentID int, @newLastChanged timestamp, @NewType int SELECT @NewType=ISNULL(@Type,[Type]) FROM [ITEMS] II JOIN [CONTENTS] CC ON II.[ContentID]=CC.[ContentID] WHERE [ItemID]=@ItemID SELECT @NextID = [ItemID] FROM [ITEMS] WHERE [PreviousID]=@ItemID EXECUTE AddContent @Number, @Text, @NewType, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem @ItemID, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output UPDATE [ITEMS] SET [PreviousID]=@newItemID, [DTS]=@DTS, [UserID]=@UserID where [ItemID]=@NextID -- Should be UpdateItem -- 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 -- 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: addItemSiblingAfter Succeeded' ELSE PRINT 'Procedure Creation: addItemSiblingAfter Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addItemSiblingBefore]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [addItemSiblingBefore]; GO CREATE PROCEDURE [dbo].[addItemSiblingBefore] ( @ItemID int=null, @Number nvarchar(256)=null, @Text nvarchar(MAX)=null, @FormatID int=null, @Config nvarchar(MAX)=null, @Type int=null, @DTS datetime, @UserID nvarchar(100), @newItemID int output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION 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 EXECUTE AddContent @Number, @Text, @NewType, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output EXECUTE AddItem @PreviousID, @ContentID, @DTS, @UserID , @newItemID output, @newLastChanged output UPDATE [ITEMS] SET [PreviousID]=@newItemID where [ItemID]=@ItemID -- Should be UpdateItem UPDATE [PARTS] SET [ItemID]=@newItemID where [ItemID]=@ItemID -- Should be UpdatePart 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 PRINT 'Sibling Added Before ' + ltrim(str(@newItemID)) 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: addItemSiblingBefore Succeeded' ELSE PRINT 'Procedure Creation: addItemSiblingBefore Error on Creation' GO /*************** May 2020 - Modifications to search queries to allow for 'ByWord'. To do this a sql prefix and suffix were added * If search string's adjacent character is text '[^a-zA-Z]' (for example 'red' prefix is next to 'r', suffix is next to 'd') * If search string's adjacent character is numeric '[^0-9a-zA-Z.vbpi:\\-]' (for example 10%, prefix is next to '1') */ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixSearchStringByWord]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_FixSearchStringByWord]; GO /* select .dbo.vefn_FixSearchStringByWord('0%', '[^0-9A-Z.vbpi:\\-]', '') select .dbo.vefn_FixSearchStringByWord('step 25', '[^a-z]', '[^0-9A-Z.vbpi:\\-]') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_FixSearchStringByWord](@SearchString nvarchar(MAX), @Prefix nvarchar(64), @Suffix nvarchar(64)) RETURNS nvarchar(MAX) WITH EXECUTE AS OWNER AS BEGIN -- This code adds % at the beginning and end if the beginning and end -- of the search string if it does not have % at the beginning or end Set @SearchString = replace(@SearchString,'[','[[]') Set @SearchString = replace(@SearchString,'_','[_]') Set @SearchString = replace(@SearchString,'%','[%]') Set @SearchString = replace(@SearchString,'*','%') Set @SearchString = replace(@SearchString,'?','_') Set @SearchString = replace(@SearchString,'\%','*') Set @SearchString = replace(@SearchString,'\_','?') Set @SearchString = replace(@SearchString,'-','\u8209?') Set @SearchString = replace(@SearchString,'\''A9','\u169?') -- copyright symbol Set @SearchString = replace(@SearchString,'\''AE','\u174?') -- Register symbol Set @SearchString = replace(@SearchString,'\\line ','\line ') -- newline Set @SearchString = replace(@SearchString,'\\','\u9586?') -- use a double backslash to search for a backslash IF(@SearchString like '[%]%') RETURN '%' + @Prefix + SubString(@SearchString,2,len(@SearchString)) -- beginning of text IF(@SearchString like '%[%]') RETURN SubString(@SearchString, 0, len(@SearchString)-1) + @Suffix + '%' -- end of text Set @SearchString = replace('%' + @Prefix + @SearchString + @Suffix + '%','%%','%') RETURN @SearchString END GO -- Display the status IF (@@Error = 0) PRINT 'ScalerFunction [vefn_FixSearchStringByWord] Succeeded' ELSE PRINT 'ScalerFunction [vefn_FixSearchStringByWord] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Rich Mark Create Date: 01/01/2020 Description: Returns all items mathcing the specified search critera, filtered by a list of specified Document Versions and Step Types 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace, also changed all Select (*) statements to Select (1) for performace reasons Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions) @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections) @SearchString Search string criteria @CaseSensitive Indicator for Case Sensitive Search (0 = False, 1 = True) @IncludeLinks Indicator to include Links in results (0 = False, 1 = True) @IncludeRtfFormatting Indicator to include RTF Formatting in results (0 = False, 1 = True) @IncludeSpecialCharacters Indicator to include Special Characters in results (0 = False, 1 = True) @UnitPrefix Specified Unit Prefix if any @ByWordPrefix Word Prefix for the specified search string criteria @ByWordSuffix Word Suffix for the specified search string criteria Examples: exec vesp_SearchItemAndChildrenNewByWord '194','','red',0,0,0,0,'','[^a-z]','[^a-z]'; exec vesp_SearchItemAndChildrenNewByWord '194','','0%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''; exec vesp_SearchItemAndChildrenNewByWord '194','','10%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''; exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]','[^0-9A-Z.vbpi:\\-]'; exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','','[^0-9A-Z.vbpi:\\-]'; exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''; exec vesp_SearchItemAndChildrenNewByWord '194','','step 25',0,0,0,1,'','[^a-zA-Z]','[^0-9a-zA-Z.vbpi:\\-]'; exec vesp_SearchItemAndChildrenNewByWord '194','','25',0,0,0,0,'','',''; ========================================================================================================== */ Create Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord] (@DocVersionList VarChar(Max), @StepTypeList VarChar(Max), @SearchString VarChar(Max), @CaseSensitive Int, @IncludeLinks Int, @IncludeRtfFormatting Int, @IncludeSpecialCharacters Int, @UnitPrefix VarChar(Max), @ByWordPrefix VarChar(64), @ByWordSuffix VarChar(64)) With Execute As Owner As Begin Set NoCount On; -- Declare Local Variables Declare @TextPrefix nVarChar(1); Declare @TextSuffix nVarChar(1); Declare @SearchStringx nVarChar(200); -- Set Default Values Set @TextPrefix = ''; Set @TextSuffix = ''; Set @SearchString = dbo.vefn_FixSearchStringByWord(@SearchString, @ByWordPrefix, @ByWordSuffix); If (@SearchString like '[%]%') Set @TextPrefix = '~'; If (@SearchString like '%[%]') Set @TextSuffix = '~'; Set @SearchStringx = Replace(@SearchString,'\u8209?','-') -- [John Jenko] B2016-209: not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?') If (@IncludeLinks + @IncludeRtfFormatting + @IncludeSpecialCharacters = 0) Begin If (@CaseSensitive = 0) Begin --Select 'Case #1: No Links/RtfFormatting/SpecialCharacters & Not Case Sensitive'; Select z.DvPath as 'DvPath', z.[Path] as 'Path', z.FromType as 'FromType', z.Ordinal as 'Ordinal', z.ParentID as 'ParentID', z.ItemID as 'ItemID', z.PreviousID as 'PreviousID', z.ContentID as 'ContentID', z.DTS as 'DTS', z.UserID as 'UserID', z.ILastChanged as 'ILastChanged', z.Number as 'Number', z.[Text] as 'Text', z.CType as 'Type', z.CFormatID as 'FormatID', z.CConfig as 'Config', z.CDTS as 'CDTS', z.CUserID as 'CUserID', z.CLastChanged as 'cLastChanged', z.pContentID as 'pContentID', z.pDTS as 'pDTS', z.pUserID as 'pUserID', z.PLastChanged as 'pLastChanged', (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount', (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount', (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount', (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount', (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount', (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount', (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount', (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount', (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount', (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount', (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount', (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount', (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount', (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount', (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount' From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) z Order By z.DvPath Asc Option (Recompile); End Else Begin --Select 'Case #2: No Links/RtfFormatting/SpecialCharacters & Case Sensitive'; Select z.DvPath as 'DvPath', z.[Path] as 'Path', z.FromType as 'FromType', z.Ordinal as 'Ordinal', z.ParentID as 'ParentID', z.ItemID as 'ItemID', z.PreviousID as 'PreviousID', z.ContentID as 'ContentID', z.DTS as 'DTS', z.UserID as 'UserID', z.ILastChanged as 'ILastChanged', z.Number as 'Number', z.[Text] as 'Text', z.CType as 'Type', z.CFormatID as 'FormatID', z.CConfig as 'Config', z.CDTS as 'CDTS', z.CUserID as 'CUserID', z.CLastChanged as 'cLastChanged', z.pContentID as 'pContentID', z.pDTS as 'pDTS', z.pUserID as 'pUserID', z.PLastChanged as 'pLastChanged', (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount', (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount', (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount', (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount', (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount', (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount', (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount', (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount', (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount', (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount', (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount', (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount', (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount', (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount', (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount' From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) z Where (@TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or @TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx) Order By z.DvPath Asc Option (Recompile); End End -- no links Else Begin -- include linked text If (@CaseSensitive = 0) Begin --Select 'Case #3: Include Links/RtfFormatting/SpecialCharacters & Not Case Sensitive'; Select z.DvPath as 'DvPath', z.[Path] as 'Path', z.FromType as 'FromType', z.Ordinal as 'Ordinal', z.ParentID as 'ParentID', z.ItemID as 'ItemID', z.PreviousID as 'PreviousID', z.ContentID as 'ContentID', z.DTS as 'DTS', z.UserID as 'UserID', z.ILastChanged as 'ILastChanged', z.Number as 'Number', z.[Text] as 'Text', z.CType as 'Type', z.CFormatID as 'FormatID', z.CConfig as 'Config', z.CDTS as 'CDTS', z.CUserID as 'CUserID', z.CLastChanged as 'cLastChanged', z.pContentID as 'pContentID', z.pDTS as 'pDTS', z.pUserID as 'pUserID', z.PLastChanged as 'pLastChanged', (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount', (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount', (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount', (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount', (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount', (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount', (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount', (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount', (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount', (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount', (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount', (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount', (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount', (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount', (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount' From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) z Where (dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchString Or dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchString Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx) Order By z.DvPath Asc Option (Recompile); End Else -- case sensitive Begin --Select 'Case #4: Include Links/RtfFormatting/SpecialCharacters & Case Sensitive'; Select z.DvPath as 'DvPath', z.[Path] as 'Path', z.FromType as 'FromType', z.Ordinal as 'Ordinal', z.ParentID as 'ParentID', z.ItemID as 'ItemID', z.PreviousID as 'PreviousID', z.ContentID as 'ContentID', z.DTS as 'DTS', z.UserID as 'UserID', z.ILastChanged as 'ILastChanged', z.Number as 'Number', z.[Text] as 'Text', z.CType as 'Type', z.CFormatID as 'FormatID', z.CConfig as 'Config', z.CDTS as 'CDTS', z.CUserID as 'CUserID', z.CLastChanged as 'cLastChanged', z.pContentID as 'pContentID', z.pDTS as 'pDTS', z.pUserID as 'pUserID', z.PLastChanged as 'pLastChanged', (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount', (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount', (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount', (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount', (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount', (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount', (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount', (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount', (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount', (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount', (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount', (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount', (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount', (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount', (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount' From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList, @includeLinks, @includeRtfFormatting, @includeSpecialCharacters) z Where (dbo.vefn_RemoveExtraText(Replace(@TextPrefix + z.Text + @TextSuffix,'\''b0', '\''B0'), @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like Replace(@SearchString,'\''b0', '\''B0') Or dbo.vefn_RemoveExtraText(Replace(@TextPrefix + z.Text + @TextSuffix,'\''b0', '\''B0'), @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like Replace(@SearchStringx,'\''b0', '\''B0') Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx) Order By z.DvPath Asc Option (Recompile); End End -- include links End Go IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Succeeded' ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Error on Creation' GO 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 2020 - 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 @ItemType 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 @ItemType = Type FROM Contents Where ContentID = @ContentID SET @Path = [dbo].[ve_GetShortPath](@ItemID) SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) where rangeid = toid or toid = @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 @ExternalCount > 0 AND @ItemType < 10000 BEGIN RAISERROR ('###Cannot Delete Item###Procedure %d has External Transitions to Procedure - (%s)',16,1,@ItemID,@Path) RETURN END IF @ExternalCount > 0 AND @ItemType < 20000 -- B2020-091 (was not checking for sections) BEGIN RAISERROR ('###Cannot Delete Item###Procedure %d has External Transitions to Section - (%s)',16,1,@ItemID,@Path) RETURN END SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID) -- Check to see if External Transitions point to the current item 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) -- Remove Previously deleted transitions DELETE from tblTransitions where deletestatus = -1 and FromID in(SELECT ContentID FROM @Children) -- Remove Previously deleted rousages DELETE from tblrousages where deletestatus = -1 and contentID in(SELECT ContentID 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 IF (@@Error = 0) PRINT 'Procedure Creation: [DeleteItemAndChildren] Succeeded' ELSE PRINT 'Procedure Creation: [DeleteItemAndChildren] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SessionCanCheckOutItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_SessionCanCheckOutItem]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* exec dbo.vesp_SessionCanCheckOutItem 1,2 exec dbo.vesp_SessionCanCheckOutItem 21,3 */ CREATE PROCEDURE [dbo].[vesp_SessionCanCheckOutItem] ( @ObjectID int, @ObjectType int ) WITH EXECUTE AS OWNER AS BEGIN DECLARE @CheckOuts TABLE ( SessionID int ) --look to see if anyone else has a session. if they do, then cannot check out DECLARE @sCount int SELECT @sCount = count(*) FROM Sessions IF @ObjectType = 4 BEGIN SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE DTSEnd IS NULL END ELSE BEGIN DECLARE @ObjectAndEnhancedIDs Table ( ObjectID int ) IF @ObjectType = 0 BEGIN INSERT INTO @ObjectAndEnhancedIDs select ItemID from vefn_GetEnhancedProcedures(@ObjectID) END ELSE IF @ObjectType = 2 BEGIN INSERT INTO @ObjectAndEnhancedIDs select VersionID from vefn_GetEnhancedDocVersions(@ObjectID) INSERT INTO @ObjectAndEnhancedIDs -- B2020-094: Check current docversion select VersionID from DocVersions where VersionId = @ObjectID END ELSE IF @ObjectType = 3 BEGIN INSERT INTO @ObjectAndEnhancedIDs select FolderID from vefn_GetEnhancedFolders(@ObjectID) INSERT INTO @ObjectAndEnhancedIDs -- B2020-094: Check current folder select FolderID from Folders where FolderID = @ObjectID END ELSE BEGIN INSERT INTO @ObjectAndEnhancedIDs select @ObjectID END INSERT INTO @CheckOuts SELECT DISTINCT SessionID FROM Owners WHERE OwnerItemID in (select ObjectID from @ObjectAndEnhancedIDs) AND OwnerType = @ObjectType IF @ObjectType = 2 BEGIN with ItemZ (VersionID,ItemID,PreviousID,SessionID) as( --> Procedure Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Items II on OO.OwnerItemID= II.ItemID Where OO.OwnerType=0 UNION ALL --> Document Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Entries EE ON OO.OwnerItemID = EE.DocID Join Items II on EE.ContentID= II.ContentID Where OO.OwnerType=1 UNION ALL --> Previous Owners Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ Join Items II ON II.ItemID = ZZ.PreviousID Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL UNION ALL -- Parts Owners Select null, II.ItemID, II.PreviousID, ZZ.SessionID from ItemZ ZZ Join Parts PP ON PP.ItemID = ZZ.ItemID Join Items II ON II.ContentID = PP.ContentID Where ZZ.VersionID IS NULL UNION ALL -- Version Owners Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ Join DocVersions DV ON ZZ.ItemID = DV.ItemID Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL ) --Select Distinct 'Phase 2b' Result, * from Itemz INSERT INTO @CheckOuts Select DIstinct SessionID from ItemZ where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) OPTION (MAXRECURSION 10000) -- B2017-144 Crash on Maximum Recursion END --look to see if object type is folder that no part of folder passed is checked out IF @ObjectType = 3 BEGIN with ItemZ (VersionID,ItemID,PreviousID,SessionID) as( --> Procedure Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Items II on OO.OwnerItemID= II.ItemID Where OO.OwnerType=0 UNION ALL --> Document Owners select null,II.ItemID, PreviousID, SessionID from Owners OO Join Entries EE ON OO.OwnerItemID = EE.DocID Join Items II on EE.ContentID= II.ContentID Where OO.OwnerType=1 UNION ALL --> Previous Owners Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ Join Items II ON II.ItemID = ZZ.PreviousID Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL UNION ALL -- Parts Owners Select null, II.ItemID, II.PreviousID, ZZ.SessionID from ItemZ ZZ Join Parts PP ON PP.ItemID = ZZ.ItemID Join Items II ON II.ContentID = PP.ContentID Where ZZ.VersionID IS NULL UNION ALL -- Version Owners Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ Join DocVersions DV ON ZZ.ItemID = DV.ItemID Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL ) --Select Distinct 'Phase 2b' Result, * from Itemz INSERT INTO @CheckOuts Select DIstinct SessionID from ItemZ where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) OPTION (MAXRECURSION 10000) -- B2017-144 Crash on Maximum Recursion END SELECT [SessionID], [UserID], [DTSDtart], [DTSEnd], [DTSActivity], [LastChanged], [MachineName], [ProcessID], (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE [SessionID] IN (SELECT SessionID FROM @CheckOuts) END END GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CheckAllXML]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_CheckAllXML]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2021 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_CheckAllXML](@DocVersionID int) returns xml begin --temp table for sibling itemid declare @tItems table (ItemID int) insert into @tItems select itemid from vefn_siblingitems((select itemid from docversions where versionid = @docversionid),0) --temp table for max checkid declare @tChecks table (CheckID int) insert into @tChecks select max(cc.checkid) checkid from checks cc inner join stages ss on cc.stageid = ss.stageid inner join revisions rr on cc.revisionid = rr.revisionid inner join @tItems ii on rr.itemid = ii.itemid -- B2021-025: get only items in procedures in this docversion where ss.isapproved = 1 group by rr.itemid --temp table for multi valued roids declare @mvROIDS table (ROID varchar(max)) insert into @mvROIDS select roid from (select distinct r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue from checks cc join @tchecks tc on cc.checkid = tc.checkid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)) t1 group by roid having count(*) > 1 --temp table for multi valued transitionids declare @mvTransitions table (TransitionID int) insert into @mvTransitions select transitionid from (select distinct r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue from checks cc cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)) t1 group by transitionid having count(*) > 1 --temp table for multi valued docids declare @mvLibDocs table (DocID int) insert into @mvLibDocs select docid from (select distinct r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate from checks cc cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)) t1 group by docid having count(*) > 1 --temp table for roids declare @tROIDS table (ItemID int,ROID varchar(max),ROValue varchar(max),CheckID int) insert into @tROIDS select rr.itemid,r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue, cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1) --temp table for transitions declare @tTransitions table (ItemID int,TransitionID int,TransitionValue varchar(max),CheckID int) insert into @tTransitions select rr.itemid,r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1) --temp table for libdocs declare @tLibDocs table (ItemID int, DocID int, DocDate datetime,CheckID int) insert into @tLibDocs select rr.itemid,r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1) --get all inconsitencies accross set declare @ChkXML xml set @ChkXML = ( select (--ro inconsistencies accross set select ROCheck.ItemID,ROCheck.ROID,ROCheck.ROValue from @tROIDS ROCheck inner join @tChecks tc on ROCheck.checkid = tc.checkid inner join @tItems ti on ROCheck.itemid = ti.itemid inner join @mvROIDS mv on ROCheck.roid = mv.roid order by ROCheck.itemid for xml auto,root('ROChecks'),type ), (--transition inconsistencies accross set select TransitionCheck.ItemID,TransitionCheck.TransitionID,TransitionCheck.TransitionValue from @tTransitions TransitionCheck inner join @tChecks tc on TransitionCheck.checkid = tc.checkid inner join @tItems ti on TransitionCheck.itemid = ti.itemid inner join @mvTransitions mv on TransitionCheck.TransitionID = mv.TransitionID order by TransitionCheck.itemid for xml auto,root('TransitionChecks'),type ), (--libdoc inconsistencies accross set select LibDocCheck.ItemID,LibDocCheck.DocID,LibDocCheck.DocDate from @tLibDocs LibDocCheck inner join @tChecks tc on LibDocCheck.checkid = tc.checkid inner join @tItems ti on LibDocCheck.itemid = ti.itemid inner join @mvLibDocs mv on LibDocCheck.docid = mv.docid order by LibDocCheck.itemid for xml auto,root('LibDocChecks'),type ) for xml path(''),ROOT ('ConsistencyChecks'),type ) return @ChkXML end GO IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded' ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getContentAuditsChronologyByItemID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2021 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemID] ( @ProcedureItemID int, @SelectedItemID int, @IncludeDeletedChildren int, @DTS datetime ) WITH EXECUTE AS OWNER AS begin select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) order by OrdinalPath, contentid,auditid -- B2021-031: Grouping/ordering in Chronology Report not always correct -- select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath -- from -- ( -- select -- case -- when lastauditid is null then 'Added' -- when r.deletestatus > 0 then 'Deleted' -- when lastauditid = -1 then 'Changed' -- when DeletedAuditID is not null then 'Restored' ---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored' -- else 'Changed' -- end actionwhat --,actiondts actionwhen ---- ,case ---- when lastauditid is null then dts ---- when r.deletestatus > 0 then ActionDTS ---- when lastauditid = -1 then dts ---- when DeletedAuditID is not null then ActionDTS ---- else dts ---- end actionwhen --,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where ActionDTS > procdts or dts > procdts -- ) ah -- order by OrdinalPath, contentid,auditid--actionwhen RETURN end GO IF (@@Error = 0) PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Succeeded' ELSE PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChronologyReport]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChronologyReport]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2021 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE function [dbo].[vefn_ChronologyReport](@ProcItemID int, @DTS datetime) returns @Report table ( src int, AuditID bigint, ContentID int, Number nvarchar(512), Text nvarchar(max), Type int, FormatID int, Config nvarchar(max), DTS datetime, UserID nvarchar(200), DeleteStatus int, ActionDTS datetime, ItemDTS datetime, LastAuditID int, DeletedAuditID int ) WITH EXECUTE AS OWNER AS BEGIN --added rhm/jcb 20121218i declare @tmpTable table ( icontentid int primary key ) insert into @tmpTable select icontentid from vefn_tblchilditems(@ProcItemID,@ProcItemID,1) --added jcb 20111122 --declare @dts datetime --set @dts = (select dts from items where itemid = @ProcItemID ) --set @dts = (SELECT .[dbo].[vefn_GetPreviousRevisionDTSByItemID] (@ProcItemID)) --end added jcb 20111122 insert into @Report SELECT 1 src, [AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid where Number is not null --added jcb 20111028_1827 and ca.contentid != (select contentid from items where itemid = @procitemid) and ca.contentid in (select icontentid from @tmpTable) --end added jcb 20111028_1827 --added jcb 20111122 --and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID )) and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > @dts) --and ca.dts > (select dts from items where itemid = @ProcItemID ) and ca.dts > @dts --end added jcb 20111122 -- UNION -- SELECT --2 src, -- cast(ident_current('contentaudits') + 1 as bigint) auditid ---- (select max(auditid) + 1 from contentaudits) [AuditID] ---- 0 [AuditID] -- ,ca.[ContentID] -- ,[Number] -- ,[Text] -- ,[Type] -- ,[FormatID] -- ,[Config] -- ,ca.[DTS] cadts -- ,ca.[UserID] -- ,ca.[DeleteStatus] -- ,ActionDTS -- ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS --,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID --,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID -- FROM tblContents ca ---- inner join tblitems ti on ca.contentid = ti.contentid --WHERE ca.DeleteStatus = 0 AND ----added jcb 20111028_1827 --ca.contentid != (select contentid from items where itemid = @procitemid) and ----end added jcb 20111028_1827 ----ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID )) ----added jcb 20111122 ----ca.ContentID in (SELECT [ContentID] FROM Contents where dts > (select dts from items where itemid = @ProcItemID )) --ca.ContentID in (SELECT [ContentID] FROM Contents where dts > @dts) ----end added jcb 20111122 ----order by ca.DTS,ActionDTS UNION SELECT 3 src, cast(ident_current('contentaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from contentaudits) [AuditID] -- 0 [AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM tblContents ca -- inner join tblitems ti on ca.contentid = ti.contentid WHERE ca.DeleteStatus = 0 --AND --added jcb 20111028_1827 --ca.contentid != (select contentid from items where itemid = @procitemid) -- B2020-156: Procedure not listed in change reports and ca.contentid in (select icontentid from @tmpTable) --end added jcb 20111028_1827 --added jcb 20111122 --ca.dts > (select dts from items where itemid = @ProcItemID ) and (ca.dts > @dts or ca.actiondts > @dts) --end added jcb 20111122 UNION SELECT distinct 5 src, -- cast(ident_current('contentaudits') + 1 as bigint) auditid -- (select max(auditid) + 1 from contentaudits) [AuditID] ca.[AuditID] ,ca.[ContentID] ,[Number] ,[Text] ,[Type] ,[FormatID] ,[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid WHERE ca.DeleteStatus > 0 --added jcb 20111028_1827 --ca.contentid != (select contentid from items where itemid = @procitemid) and --end added jcb 20111028_1827 --added jcb 20111122 --ca.dts > (select dts from items where itemid = @ProcItemID ) and ca.contentid in (select icontentid from @tmpTable) and (ca.dts > @dts or ca.actiondts > @dts) --end added jcb 20111122 order by ca.DTS,ActionDTS insert into @Report SELECT 4 src, ca.[AuditID] ,ca.[ContentID] ,ca.[Number] ,ca.[Text] ,ca.[Type] ,ca.[FormatID] ,ca.[Config] ,ca.[DTS] cadts ,ca.[UserID] ,ca.[DeleteStatus] ,ca.ActionDTS ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID ,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID FROM ContentAudits ca -- inner join tblitems ti on ca.contentid = ti.contentid inner join @Report rpt on ca.contentid = rpt.contentid and ca.auditid = rpt.lastauditid where ca.auditid not in (select auditid from @report) and rpt.lastauditid is not null and ca.contentid in (select icontentid from @tmpTable) return end go IF (@@Error = 0) PRINT 'TableFunction [vefn_ChronologyReport] Succeeded' ELSE PRINT 'TableFunction [vefn_ChronologyReport] Error on Creation' go IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CheckAllXML]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_CheckAllXML]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2021 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_CheckAllXML](@DocVersionID int) returns xml begin --temp table for sibling itemid declare @tItems table (ItemID int) insert into @tItems select itemid from vefn_siblingitems((select itemid from docversions where versionid = @docversionid),0) --temp table for max checkid declare @tChecks table (CheckID int) insert into @tChecks select max(cc.checkid) checkid from checks cc inner join stages ss on cc.stageid = ss.stageid inner join revisions rr on cc.revisionid = rr.revisionid inner join @tItems ii on rr.itemid = ii.itemid -- B2021-025: get only items in procedures in this docversion where ss.isapproved = 1 group by rr.itemid --temp table for multi valued roids declare @mvROIDS table (ROID varchar(max)) insert into @mvROIDS select roid from (select distinct r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue from checks cc join @tchecks tc on cc.checkid = tc.checkid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)) t1 group by roid having count(*) > 1 --temp table for multi valued transitionids declare @mvTransitions table (TransitionID int) insert into @mvTransitions select transitionid from (select distinct r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue from checks cc cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1) join @tChecks tc on tc.CheckID=cc.CheckID -- B2021-037 transition part of approval inconsistencies report ) t1 group by transitionid having count(*) > 1 --temp table for multi valued docids declare @mvLibDocs table (DocID int) insert into @mvLibDocs select docid from (select distinct r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate from checks cc cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)) t1 group by docid having count(*) > 1 --temp table for roids declare @tROIDS table (ItemID int,ROID varchar(max),ROValue varchar(max),CheckID int) insert into @tROIDS select rr.itemid,r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue, cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1) --temp table for transitions declare @tTransitions table (ItemID int,TransitionID int,TransitionValue varchar(max),CheckID int) insert into @tTransitions select rr.itemid,r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1) --temp table for libdocs declare @tLibDocs table (ItemID int, DocID int, DocDate datetime,CheckID int) insert into @tLibDocs select rr.itemid,r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1) --get all inconsitencies accross set declare @ChkXML xml set @ChkXML = ( select (--ro inconsistencies accross set select ROCheck.ItemID,ROCheck.ROID,ROCheck.ROValue from @tROIDS ROCheck inner join @tChecks tc on ROCheck.checkid = tc.checkid inner join @tItems ti on ROCheck.itemid = ti.itemid inner join @mvROIDS mv on ROCheck.roid = mv.roid order by ROCheck.itemid for xml auto,root('ROChecks'),type ), (--transition inconsistencies accross set select TransitionCheck.ItemID,TransitionCheck.TransitionID,TransitionCheck.TransitionValue from @tTransitions TransitionCheck inner join @tChecks tc on TransitionCheck.checkid = tc.checkid inner join @tItems ti on TransitionCheck.itemid = ti.itemid inner join @mvTransitions mv on TransitionCheck.TransitionID = mv.TransitionID order by TransitionCheck.itemid for xml auto,root('TransitionChecks'),type ), (--libdoc inconsistencies accross set select LibDocCheck.ItemID,LibDocCheck.DocID,LibDocCheck.DocDate from @tLibDocs LibDocCheck inner join @tChecks tc on LibDocCheck.checkid = tc.checkid inner join @tItems ti on LibDocCheck.itemid = ti.itemid inner join @mvLibDocs mv on LibDocCheck.docid = mv.docid order by LibDocCheck.itemid for xml auto,root('LibDocChecks'),type ) for xml path(''),ROOT ('ConsistencyChecks'),type ) return @ChkXML end GO IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded' ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAssociationsByVersionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getAssociationsByVersionID]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2022 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getAssociationsByVersionID] ( @VersionID int ) WITH EXECUTE AS OWNER AS begin SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged] -- B2022-010 -- the following was slowing down getting associations -- which slowed down opening Search and any other time we got this information -- note that the ROFst information is not needed --, --[ROFsts].[RODbID] [ROFst_RODbID], --[ROFsts].[ROLookup] [ROFst_ROLookup], --[ROFsts].[Config] [ROFst_Config], --[ROFsts].[DTS] [ROFst_DTS], --[ROFsts].[UserID] [ROFst_UserID] FROM [Associations] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Associations].[ROFstID] WHERE [Associations].[VersionID]=@VersionID RETURN end GO IF (@@Error = 0) PRINT 'Procedure Creation: [getAssociationsByVersionID] Succeeded' ELSE PRINT 'Procedure Creation: [getAssociationsByVersionID] Error on Creation' GO If Exists(Select * From sys.views Where Name = N'vwSysInfo_IndexFragmentation') Drop View [dbo].[vwSysInfo_IndexFragmentation]; Go SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 08/23/2021 Description: (System Info) Master View for Table Index Fragmentation ========================================================================================================== */ Create View [dbo].[vwSysInfo_IndexFragmentation] As Select s.[name] as 'SchemaName', t.[name] as 'TableName', i.[name] as 'IndexName', i.is_primary_key as 'IsPrimaryKey', i.fill_factor as 'FillFactor', ips.[avg_fragmentation_in_percent] as 'AvgFragmentation', ips.[page_count] as 'PageCount', ips.index_level as 'IndexLevel', ips.index_depth as 'IndexDepth', Case When (ips.[avg_fragmentation_in_percent] > 30) Then 'Rebuild' When (ips.[avg_fragmentation_in_percent] > 5) Then 'Reorganize' Else 'None' End as 'SuggestedAction' From sys.[dm_db_index_physical_stats] (DB_ID(), NULL, NULL, NULL, NULL) as ips inner join sys.[tables] t With (NoLock) on t.[object_id] = ips.[object_id] inner join sys.[schemas] s With (NoLock) on t.[schema_id] = s.[schema_id] inner join sys.[indexes] i With (NoLock) on i.[object_id] = ips.[object_id] And i.[index_id] = ips.[index_id] Where ips.[database_id] = DB_ID() and not i.[name] is null; Go IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Succeeded' ELSE PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Error on Creation' GO If Exists(Select * From sys.views Where Name = N'vwSysInfo_UserTables') Drop View [dbo].[vwSysInfo_UserTables]; Go SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 08/23/2021 Description: (System Info) Master View for User Tables with Columns ========================================================================================================== */ Create View [dbo].[vwSysInfo_UserTables] As Select OBJECT_SCHEMA_NAME(t.[object_id],DB_ID()) as 'SchemaName', t.[name] as 'TableName', ac.[name] as 'ColumnName', ac.[column_id]as 'ColumnOrder', ty.[name] as 'DataType', ac.[max_length] as 'MaxLength', ac.[precision] as 'Precision', ac.[scale] as 'Scale', ac.[is_nullable] as 'IsNullable', ac.[is_ansi_padded] as 'IsAnsiPadded', ac.[is_identity] as 'IsIdentity', object_definition(ac.[default_object_id]) as 'DefaultValue' From sys.[tables] t With (NoLock) inner join sys.[all_columns] ac With (NoLock) on t.[object_id] = ac.[object_id] inner join sys.[types] ty With (NoLock) on ac.[system_type_id] = ty.[system_type_id] and ac.[user_type_id] = ty.[user_type_id] Where t.[is_ms_shipped] = 0; -- Indicates if table is from Microsoft or User Created GO IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_UserTables] Succeeded' ELSE PRINT 'View Creation: [vwSysInfo_UserTables] Error on Creation' GO IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_UtilityCheckIndexes]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP Procedure [dbo].[vesp_UtilityCheckIndexes]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 08/23/2021 Description: Rebuild / Reorganize all Indexes in the database based on their current average fragmentation Note** @LowerFragCutoff value should always be less than the @UpperFragCutoff value, if not then @@LowerFragCutoff value witll be automatically set to the @UpperFragCutoff value Parameters: @UpperFragCutoff Fragmentation Cutoff Value for Rebuild vs Reorganize (30.0 Recommended) @LowerFragCutoff Average Fragmentation Cutoff Value for Initial Index Selection (10.0 Recommended) @IsPrint Print the Commands Indicator (1 = Print Commands, 0 = Dont Print Commands) @IsExecute Execute the Commands Indicator (1 = Execute Commands, 0 = Dont Execute Commands) Examples: exec [dbo].[vesp_UtilityCheckIndexes] null, null, null, null; -- Use default values and only execute the commands exec [dbo].[vesp_UtilityCheckIndexes] null, null, 1, 0; -- Use the Upper Cutoff and Lower Cutoff default values and only print the commands exec [dbo].[vesp_UtilityCheckIndexes] null, null, 0, 1; -- Use the Upper Cutoff and Lower Cutoff default values and only execute the commands exec [dbo].[vesp_UtilityCheckIndexes] 30.0, null, 1, 0; -- Override Upper Cutoff, use the Lower Cutoff default value and print and execute the commands ========================================================================================================== */ Create Procedure [dbo].[vesp_UtilityCheckIndexes] (@UpperFragCutoff float = null, @LowerFragCutoff float = null, @IsPrint Bit = null, @IsExecute Bit = null) With Execute As Owner As Begin Set NoCount On; -- Declare Local Variables Declare @ObjectID int; Declare @IndexID int; Declare @PartitionCount bigint; Declare @SchemaName nvarchar(130); Declare @ObjectName nvarchar(130); Declare @IndexName nvarchar(130); Declare @PartitionNum bigint; Declare @IndexAvgFrag float; Declare @Command nvarchar(4000); -- Set Default Values If (@UpperFragCutoff is null) Set @UpperFragCutoff = 10.0; If (@LowerFragCutoff is null) Set @LowerFragCutoff = 2.0; If (@IsPrint is null) Set @IsPrint = 0; If (@IsExecute is null) Set @IsExecute = 1; -- Check if Lower Cutoff is greater than Upper Cutoff If (@LowerFragCutoff > @UpperFragCutoff) Set @LowerFragCutoff = @UpperFragCutoff; -- Conditionally select tables and indexes from the sys.dm_db_index_physical_stats function -- and convert object and index IDs to names. Select object_id as 'ObjectID', index_id as 'IndexID', partition_number as 'PartitionNum', avg_fragmentation_in_percent as 'AvgFrag' Into #work_to_do From sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED') Where avg_fragmentation_in_percent > @LowerFragCutoff AND index_id > 0; -- Declare the cursor for the list of partitions to be processed. Declare cursor_Partitions Cursor For Select ObjectID, IndexID, PartitionNum, AvgFrag From #work_to_do; -- Open the cursor. Open cursor_Partitions; -- Loop through the partitions. While (1=1) Begin; Fetch Next From cursor_Partitions Into @ObjectID, @IndexID, @PartitionNum, @IndexAvgFrag; IF (@@FETCH_STATUS < 0) Break; Select @ObjectName = QUOTENAME(o.name), @SchemaName = QUOTENAME(s.name) From sys.objects as o join sys.schemas as s on s.schema_id = o.schema_id Where o.object_id = @ObjectID; Select @IndexName = QUOTENAME(name) From sys.indexes Where object_id = @ObjectID AND index_id = @IndexID; Select @PartitionCount = Count(*) From sys.partitions Where object_id = @ObjectID AND index_id = @IndexID; Set @Command = ''; -- Determine whether to rebuild or reorganize IF (@IndexAvgFrag < @UpperFragCutoff) Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REORGANIZE;'; IF (@IndexAvgFrag >= @UpperFragCutoff) Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REBUILD;'; IF (@PartitionCount > 1) Set @Command = @Command + N' PARTITION=' + Cast(@PartitionNum AS nvarchar(10)); -- Print command if enabled If (@IsPrint = 1) Print @Command; -- Execute command if enabled If (@IsExecute = 1) Exec (@Command); End; -- Close and deallocate the cursor Close cursor_Partitions; Deallocate cursor_Partitions; -- Drop the temporary table Drop Table #work_to_do; Return; End Go IF (@@Error = 0) PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Succeeded' ELSE PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblEntriesDeleteStatusDocID') Drop Index [IX_tblEntriesDeleteStatusDocID] on [dbo].[tblEntries] Go CREATE NONCLUSTERED INDEX [IX_tblEntriesDeleteStatusDocID] ON [dbo].[tblEntries] ([DeleteStatus] ASC) INCLUDE ([DocID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblEntriesDeleteStatusDocID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblEntriesDeleteStatusDocID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblAnnotationsDeleteStatusAnnotationID') Drop Index [IX_tblAnnotationsDeleteStatusAnnotationID] on [dbo].[tblAnnotations] Go CREATE NONCLUSTERED INDEX [IX_tblAnnotationsDeleteStatusAnnotationID] ON [dbo].[tblAnnotations] ([DeleteStatus] ASC) INCLUDE ([AnnotationID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblAnnotationsDeleteStatusAnnotationID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblAnnotationsDeleteStatusAnnotationID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblContentsDeleteStatusContentID') Drop Index [IX_tblContentsDeleteStatusContentID] on [dbo].[tblContents] Go CREATE NONCLUSTERED INDEX [IX_tblContentsDeleteStatusContentID] ON [dbo].[tblContents] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblContentsDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblContentsDeleteStatusContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblDocumentsDeleteStatusDocID') Drop Index [IX_tblDocumentsDeleteStatusDocID] on [dbo].[tblDocuments] Go CREATE NONCLUSTERED INDEX [IX_tblDocumentsDeleteStatusDocID] ON [dbo].[tblDocuments] ([DeleteStatus] ASC) INCLUDE ([DocID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblDocumentsDeleteStatusDocID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblDocumentsDeleteStatusDocID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblGridsDeleteStatusContentID') Drop Index [IX_tblGridsDeleteStatusContentID] on [dbo].[tblGrids] Go CREATE NONCLUSTERED INDEX [IX_tblGridsDeleteStatusContentID] ON [dbo].[tblGrids] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblGridsDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblGridsDeleteStatusContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblImagesDeleteStatusContentID') Drop Index [IX_tblImagesDeleteStatusContentID] on [dbo].[tblImages] Go CREATE NONCLUSTERED INDEX [IX_tblImagesDeleteStatusContentID] ON [dbo].[tblImages] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblImagesDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblImagesDeleteStatusContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblItemsDeleteStatusItemID') Drop Index [IX_tblItemsDeleteStatusItemID] on [dbo].[tblItems] Go CREATE NONCLUSTERED INDEX [IX_tblItemsDeleteStatusItemID] ON [dbo].[tblItems] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblItemsDeleteStatusItemID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblItemsDeleteStatusItemID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemIDContentID') Drop Index [IX_tblPartsDeleteStatusItemIDContentID] on [dbo].[tblParts] Go CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemIDContentID] ON [dbo].[tblParts] ([DeleteStatus] ASC) INCLUDE ([ItemID], [ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemIDContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemIDContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemID') Drop Index [IX_tblPartsDeleteStatusItemID] on [dbo].[tblParts] Go CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemID] ON [dbo].[tblParts] ([DeleteStatus] ASC) INCLUDE ([ItemID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusContentID') Drop Index [IX_tblPartsDeleteStatusContentID] on [dbo].[tblParts] Go CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusContentID] ON [dbo].[tblParts] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusContentID') Drop Index [IX_tblROUsagesDeleteStatusContentID] on [dbo].[tblROUsages] Go CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusContentID] ON [dbo].[tblROUsages] ([DeleteStatus] ASC) INCLUDE ([ContentID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusContentID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusRODbID') Drop Index [IX_tblROUsagesDeleteStatusRODbID] on [dbo].[tblROUsages] Go CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusRODbID] ON [dbo].[tblROUsages] ([DeleteStatus] ASC) INCLUDE (RODbID) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusRODbID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusRODbID] Error on Creation' GO If Exists (Select * From sys.Indexes Where Name = N'IX_tblTransitionsDeleteStatusTransitionID') Drop Index [IX_tblTransitionsDeleteStatusTransitionID] on [dbo].[tblTransitions] Go CREATE NONCLUSTERED INDEX [IX_tblTransitionsDeleteStatusTransitionID] ON [dbo].[tblTransitions] ([DeleteStatus] ASC) INCLUDE (TransitionID) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblTransitionsDeleteStatusTransitionID] Succeeded' ELSE PRINT 'Index Creation:[IX_tblTransitionsDeleteStatusTransitionID] Error on Creation' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getGridIds]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getGridIds]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2022 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getGridIds] WITH EXECUTE AS OWNER AS begin SELECT [ContentID] FROM [Grids] RETURN end GO IF (@@Error = 0) PRINT 'Procedure Creation: [getGridIds] Succeeded' ELSE PRINT 'Procedure Creation: [getGridIds] Error on Creation' GO /* ========================================================================================================== Begin: B2022-026 RO Memory reduction coding (Jakes Merge) [Version 2.0] Notes** If you need to rollback to the previous version for some reason and undo the changes for v2.0 then run the corresponding "PROMSRollback (v2.0).sql" file ========================================================================================================== */ /* ---------------------------------------------------------------------------------- Tables: ---------------------------------------------------------------------------------- [RofstHeader] [RofstDatabase] [RofstChild] [RofstDefaultValue] ---------------------------------------------------------------------------------- Indexes: ---------------------------------------------------------------------------------- [IX_RofstID_Roid] on [dbo].[RofstChild] [IX_RofstID_DbiID_ParentID] on [dbo].[RofstChild] */ -- If RofstHeader and other tables already exist then don't drop and recreate them IF Not Exists(SELECT * FROM sys.objects Where name = 'RofstHeader' AND type in (N'U')) Begin -- Rofst Tables SET ANSI_NULLS ON SET QUOTED_IDENTIFIER ON /****** Object: Table [dbo].[RofstChild] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE TABLE [dbo].[RofstChild]( [RofstChildID] [int] IDENTITY(1,1) NOT NULL, [RofstID] [int] NOT NULL, [dbiID] [int] NOT NULL, [ID] [int] NOT NULL, [ParentID] [int] NOT NULL, [type] [int] NOT NULL, [title] [varchar](max) NOT NULL, [roid] [varchar](50) NOT NULL, [appid] [varchar](max) NULL, [value] [varchar](max) NULL, CONSTRAINT [PK_RofstChild] PRIMARY KEY CLUSTERED ( [RofstChildID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] IF (@@Error = 0) PRINT 'Table Creation: [RofstChild] Succeeded' ELSE PRINT 'Table Creation: [RofstChild] Error on Creation' /****** Object: Table [dbo].[RofstDatabase] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE TABLE [dbo].[RofstDatabase]( [RofstID] [int] NOT NULL, [dbiID] [int] NOT NULL, [dbiType] [int] NOT NULL, [dbiAW] [int] NOT NULL, [dbiTitle] [varchar](max) NOT NULL, [dbiAP] [varchar](max) NOT NULL, [ID] [int] NOT NULL, [ParentID] [int] NOT NULL, CONSTRAINT [PK_RofstDatabase_1] PRIMARY KEY CLUSTERED ( [RofstID] ASC, [dbiID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] IF (@@Error = 0) PRINT 'Table Creation: [RofstDatabase] Succeeded' ELSE PRINT 'Table Creation: [RofstDatabase] Error on Creation' /****** Object: Table [dbo].[RofstDefaultValue] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE TABLE [dbo].[RofstDefaultValue]( [RofstID] [int] NOT NULL, [roid] [varchar](50) NOT NULL, [value] [varchar](max) NOT NULL, [AccPageID] [varchar](max) NULL, CONSTRAINT [PK_RofstDefaultValue] PRIMARY KEY CLUSTERED ( [RofstID] ASC, [roid] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] IF (@@Error = 0) PRINT 'Table Creation: [RofstDefaultValue] Succeeded' ELSE PRINT 'Table Creation: [RofstDefaultValue] Error on Creation' /****** Object: Table [dbo].[RofstHeader] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE TABLE [dbo].[RofstHeader]( [RofstID] [int] NOT NULL, [hSize] [int] NOT NULL, [hMonth] [int] NOT NULL, [hDay] [int] NOT NULL, [hcYear] [int] NOT NULL, [hcMonth] [int] NOT NULL, [hcDay] [int] NOT NULL, [hcHour] [int] NOT NULL, [hcMin] [int] NOT NULL, [hcSec] [int] NOT NULL, [hcHund] [int] NOT NULL, [CreateUserID] [varchar](50) NOT NULL, [CreateDate] [datetime] NOT NULL, [LoadedDate] [datetime] NULL, CONSTRAINT [PK_RofstHeader] PRIMARY KEY CLUSTERED ( [RofstID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] IF (@@Error = 0) PRINT 'Table Creation: [RofstHeader] Succeeded' ELSE PRINT 'Table Creation: [RofstHeader] Error on Creation' /****** Object: Index [IX_RofstID_DbiID_ParentID] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE NONCLUSTERED INDEX [IX_RofstID_DbiID_ParentID] ON [dbo].[RofstChild] ( [RofstID] ASC, [dbiID] ASC, [ParentID] ASC ) INCLUDE([ID],[type],[title],[roid],[appid],[value]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] IF (@@Error = 0) PRINT 'Index Creation: [IX_RofstID_DbiID_ParentID] Succeeded' ELSE PRINT 'Index Creation: [IX_RofstID_DbiID_ParentID] Error on Creation' /****** Object: Index [IX_RofstID_Roid] Script Date: 6/6/2022 11:18:32 AM ******/ CREATE NONCLUSTERED INDEX [IX_RofstID_Roid] ON [dbo].[RofstChild] ( [RofstID] ASC, [roid] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] IF (@@Error = 0) PRINT 'Index Creation: [IX_RofstID_Roid] Succeeded' ELSE PRINT 'Index Creation: [IX_RofstID_Roid] Error on Creation' ALTER TABLE [dbo].[RofstDatabase] ADD CONSTRAINT [DF_RofstDatabase_ParentID] DEFAULT ((0)) FOR [ParentID] ALTER TABLE [dbo].[RofstHeader] ADD CONSTRAINT [DF_RofstHeader_CreateUserID] DEFAULT ('SYSTEM') FOR [CreateUserID] ALTER TABLE [dbo].[RofstHeader] ADD CONSTRAINT [DF_RofstHeader_CreateDate] DEFAULT (getdate()) FOR [CreateDate] ALTER TABLE [dbo].[RofstChild] WITH CHECK ADD CONSTRAINT [FK_RofstChild_RofstDatabase] FOREIGN KEY([RofstID], [dbiID]) REFERENCES [dbo].[RofstDatabase] ([RofstID], [dbiID]) ON DELETE CASCADE ALTER TABLE [dbo].[RofstChild] CHECK CONSTRAINT [FK_RofstChild_RofstDatabase] ALTER TABLE [dbo].[RofstDatabase] WITH CHECK ADD CONSTRAINT [FK_RofstDatabase_RofstHeader] FOREIGN KEY([RofstID]) REFERENCES [dbo].[RofstHeader] ([RofstID]) ON DELETE CASCADE ALTER TABLE [dbo].[RofstDatabase] CHECK CONSTRAINT [FK_RofstDatabase_RofstHeader] ALTER TABLE [dbo].[RofstDefaultValue] WITH CHECK ADD CONSTRAINT [FK_RofstDefaultValue_RofstHeader] FOREIGN KEY([RofstID]) REFERENCES [dbo].[RofstHeader] ([RofstID]) ON DELETE CASCADE ALTER TABLE [dbo].[RofstDefaultValue] CHECK CONSTRAINT [FK_RofstDefaultValue_RofstHeader] ALTER TABLE [dbo].[RofstHeader] WITH CHECK ADD CONSTRAINT [FK_RofstHeader_ROFsts] FOREIGN KEY([RofstID]) REFERENCES [dbo].[ROFsts] ([ROFstID]) ON DELETE CASCADE ALTER TABLE [dbo].[RofstHeader] CHECK CONSTRAINT [FK_RofstHeader_ROFsts] IF (@@Error = 0) PRINT 'Table/FK Constraints: Succeeded' ELSE PRINT 'Table/FK Constraints: Error on Creation' End -- Rofst Tables Go /* ---------------------------------------------------------------------------------- Functions: ---------------------------------------------------------------------------------- [dbo].[vefn_Clean] [dbo].[vefn_ParseStringListToTable] [dbo].[vefn_NumOfOccurrences] [dbo].[vefn_RofstDataReplaceVars] [dbo].[vefn_RofstDataReplaceApplTagsWithDefaults] [dbo].[vefn_RofstDataGetLoadStatus] */ /****** Object: UserDefinedFunction [dbo].[vefn_Clean] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_Clean' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_Clean] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 4/21/2022 -- Description: Cleans (Trim) the string value passed -- Optional: Truncate is string is passed a specified max length -- Optional: Convert any null values to an empty string or leave as null -- ========================================================================================== Create Function [dbo].[vefn_Clean] ( @Value VarChar(Max), @ConvertNulls bit = 0, @MaxLength Int = null ) Returns VarChar(Max) As Begin Declare @RetVal VarChar(Max); If (Len(IsNull(@Value,'')) > 0) Begin Set @RetVal = LTrim(RTrim(@Value)); If (Not @MaxLength is null And Len(@RetVal) > @MaxLength) Set @RetVal = Left(@RetVal, @MaxLength); End If (@ConvertNulls = 1) Set @RetVal = IsNull(@RetVal, ''); Return @RetVal; End GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_Clean] Succeeded' ELSE PRINT 'Function Creation: [vefn_Clean] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_ParseStringListToTable] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_ParseStringListToTable' AND type in (N'TF')) DROP FUNCTION [dbo].[vefn_ParseStringListToTable] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/26/2018 -- Description: Splits a delimited list of strings into a table of string values -- ========================================================================================== Create Function [dbo].[vefn_ParseStringListToTable] ( @List VarChar(Max), @Delimeter VarChar(1) = null ) Returns @RetVal Table (ListPosition Int Identity(1,1) Not Null, ListValue VarChar(Max) Not Null) With Execute As Owner As Begin Declare @Position Int; Declare @TextPosition Int; Declare @Length smallint; Declare @String VarChar(Max); Declare @TempString VarChar(Max); Declare @LeftOver VarChar(Max); Set @TextPosition = 1; Set @LeftOver = ''; Set @Delimeter = IsNull(@Delimeter, ','); If (DataLength(@List) = 1) Insert @RetVal (ListValue) Values (Cast(@List as VarChar(Max))); Else Begin While (@TextPosition <= DataLength(@List) / 2) Begin Set @Length = (4000 - DataLength(@LeftOver) / 2); Set @TempString = LTrim(@LeftOver + Substring(@List, @TextPosition, @Length)); Set @TextPosition = @TextPosition + @Length; Set @Position = CharIndex(@Delimeter, @TempString); While (@Position > 0) Begin Set @String = Substring(@TempString, 1, @Position - 1); Insert @RetVal (ListValue) Values (Cast(@String as VarChar(Max))); Set @TempString = LTrim(Substring(@TempString, @Position + 1, Len(@TempString))); Set @Position = CharIndex(@Delimeter, @TempString); End Set @LeftOver = @TempString; End End If (LTrim(RTrim(@LeftOver)) <> '') Insert @RetVal (ListValue) Values (Cast(@LeftOver as VarChar(Max))); Return; End GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_ParseStringListToTable] Succeeded' ELSE PRINT 'Function Creation: [vefn_ParseStringListToTable] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_NumOfOccurrences] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_NumOfOccurrences' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_NumOfOccurrences] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/1/2022 -- Description: Returns the number of occurences of a specific value in a specified string -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_NumOfOccurrences](@Text VarChar(Max), @Value VarChar(Max)) Returns Int WITH EXECUTE AS OWNER AS BEGIN Declare @ValueCount Int; If (Len(@Value) = 0) Set @ValueCount = 0; Else Set @ValueCount = (Len(@Text) - Len(Replace(@Text, @Value, ''))) / Len(@Value); Return @ValueCount; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_NumOfOccurrences] Succeeded' ELSE PRINT 'Function Creation: [vefn_NumOfOccurrences] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataReplaceVars] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceVars' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceVars] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/25/2022 -- Description: Replaces Any Variables and returns the rest of the value string -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceVars](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @EqualsIndex Int; Declare @EndIndex Int; Declare @NameValPairStartIndex Int; Declare @NameValPairEndIndex Int; Declare @VarPair VarChar(Max); Declare @VarName VarChar(Max); Declare @VarValue VarChar(Max); -- Replace Any "" Tags with the Default Value first Select @RetVal = dbo.vefn_RofstDataReplaceApplTagsWithDefaults(@Values); If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); While(@NameValPairStartIndex > 0 And @NameValPairStartIndex < @EndIndex) Begin -- Get Name Value Pair [ex. {EGS=1214}] Set @VarPair = SubString(@RetVal, @NameValPairStartIndex, (@NameValPairEndIndex - @NameValPairStartIndex) + 1); -- Remove Name Value Pair From Return Val Set @RetVal = Replace(@RetVal, @VarPair, ''); -- Get Variable Name and Value Set @EqualsIndex = PatIndex('%=%', @VarPair); If (@EqualsIndex > 0) Begin Set @VarName = SubString(@VarPair, 2, @EqualsIndex - 2); Set @VarValue = SubString(@VarPair, @EqualsIndex + 1, Len(@VarPair) - @EqualsIndex - 1); Set @VarName = Concat('{', @VarName, '}'); -- Replace All Occurences Set @RetVal = Replace(@RetVal, @VarName, @VarValue); End -- Get Updated Index Values If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); End -- End While(@ReplaceVarEndTagIndex > 0) Return @RetVal; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataReplaceApplTagsWithDefaults] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceApplTagsWithDefaults' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceApplTagsWithDefaults] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/25/2022 -- Description: Replaces any "" tags with the default value -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceApplTagsWithDefaults](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @DefaultValue VarChar(Max) = ''; Declare @StartTagIndex Int; Declare @EndTagIndex Int; Declare @StartTagValue VarChar(Max); Set @RetVal = @Values; Set @StartTagIndex = PatIndex('%%', @RetVal); While (@StartTagIndex > 0) Begin Set @StartTagValue = SubString(@RetVal, @StartTagIndex, (@EndTagIndex - @StartTagIndex) + 5); Set @DefaultValue = Replace(@StartTagValue, '%', @DefaultValue); Set @DefaultValue = RTrim(SubString(@DefaultValue, 0, @EndTagIndex)); Set @RetVal = Replace(@RetVal, @StartTagValue, @DefaultValue); Set @StartTagIndex = PatIndex('%%', @RetVal); End -- While (@StartTagIndex > 0) Return @RetVal; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceApplTagsWithDefaults] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceApplTagsWithDefaults] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataGetLoadStatus] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataGetLoadStatus' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataGetLoadStatus] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 05/20/2022 -- Description: Gets the current load status for a Rofst Binary -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataGetLoadStatus](@RofstID Int) Returns Int WITH EXECUTE AS OWNER AS BEGIN Declare @RofstHeaderStatusID Int; Declare @NumOfRecordsStart Int; Declare @NumOfRecordsEnd Int; Declare @CreateDate DateTime; Declare @LoadedDate DateTime; -- Set Default Values Set @RofstHeaderStatusID = 0; -- [Unknown] Set @NumOfRecordsStart = -1; Set @NumOfRecordsEnd = -1; -- Get RofstHeader Data Select @CreateDate = CreateDate, @LoadedDate = LoadedDate From RofstHeader with (NoLock) Where RofstID = @RofstID; -- Check Current Status of RofstHeader/Data If (@CreateDate is null) Begin Set @RofstHeaderStatusID = 1; -- [Not Loaded] End Else If (Not @LoadedDate is null) Begin Set @RofstHeaderStatusID = 3; -- [Load Complete] End Else If (@LoadedDate is null) Begin -- Check if the record count for Rofst Default Values is still increasing --Declare @cnt Int = 4000000; Declare @cnt Int = 2000000; Select @NumOfRecordsStart = Count(1) From vwRofstData_RofstDefaultValues Where RofstID = @RofstID; While (@cnt > 0) Set @cnt = @Cnt -1; Select @NumOfRecordsEnd = Count(1) From vwRofstData_RofstDefaultValues Where RofstID = @RofstID; If (@NumOfRecordsStart < @NumOfRecordsEnd) Set @RofstHeaderStatusID = 2; -- [In Progress] Else Set @RofstHeaderStatusID = 4; -- [Load Failed] End Else Begin Set @RofstHeaderStatusID = 0; -- [Unknown] End Return @RofstHeaderStatusID; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataGetLoadStatus] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataGetLoadStatus] Error on Creation' GO /* ---------------------------------------------------------------------------------- Views: ---------------------------------------------------------------------------------- [dbo].[vwRofstData_RofstChildren] [dbo].[vwRofstData_RofstDatabases] [dbo].[vwRofstData_RofstDefaultValues] [dbo].[vwRofstData_RofstHeaders] [dbo].[vwRofstData_RofstHeaderStatuses] */ /****** Object: View [dbo].[vwRofstData_RofstChildren] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstChildren' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstChildren] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for RofstChildren (RoChild & Groups) ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstChildren] As Select rc.RofstChildID as 'RofstChildID', rd.RofstID as 'RofstID', -- RoDatabase Info rd.dbiID as 'dbiID', rd.dbiType as 'dbiType', rd.dbiAW as 'dbiAW', rd.dbiTitle as 'dbiTitle', rd.dbiAP as 'dbiAP', -- RoChild Info rc.ID as 'ID', rc.ParentID as 'ParentID', rc.[type] as 'type', Case When (rc.[type] = 1) Then 'Single Line Text' -- Fixed Length Text When (rc.[type] = 2) Then 'Table' When (rc.[type] = 3) Then 'Multiple Line Text' When (rc.[type] = 4) Then 'X/Y Plot' When (rc.[type] = 8) Then 'Image' Else 'Unknown' End as 'TypeDescription', rc.title as 'title', rc.roid as 'roid', rc.appid as 'appid', rc.[value] as 'value', Case When (Not rc.[value] is null) Then rd.dbiAP + '-' + rc.appid Else null End as 'AccPageID' From RofstChild rc With (NoLock) inner join RofstDatabase rd With (NoLock) on rc.RofstID = rd.RofstID and rc.dbiID = rd.dbiID; GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstChildren] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstChildren] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstDatabases] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstDatabases' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstDatabases] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for RofstDatabases ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstDatabases] As Select rd.RofstID as 'RofstID', rd.dbiID as 'dbiID', rd.dbiType as 'dbiType', rd.dbiAW as 'dbiAW', rd.dbiTitle as 'dbiTitle', rd.dbiAP as 'dbiAP', rd.ID as 'ID', rd.ParentID as 'ParentID' From RofstDatabase rd With (NoLock) GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstDatabases] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstDatabases] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstDefaultValues] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstDefaultValues' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstDefaultValues] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for Rofst Roid Default Values ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstDefaultValues] As Select rdv.RofstID as 'RofstID', rdv.roid as 'roid', rdv.[value] as 'value', rdv.AccPageID as 'AccPageID' From RofstDefaultValue rdv With (NoLock) GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstDefaultValues] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstDefaultValues] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstHeaderStatuses] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstHeaderStatuses' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstHeaderStatuses] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 05/20/2022 Description: (RofstData) Master View for RofstHeader Statuses (0) Unknown (1) Not Loaded (2) In Progress (3) Load Complete (4) Load Failed ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstHeaderStatuses] As Select '0' as 'RofstHeaderStatusID', 'Unknown' as 'RofstHeaderStatus' Union All Select '1' as 'RofstHeaderStatusID', 'Not Loaded' as 'RofstHeaderStatus' Union All Select '2' as 'RofstHeaderStatusID', 'In Progress' as 'RofstHeaderStatus' Union All Select '3' as 'RofstHeaderStatusID', 'Load Complete' as 'RofstHeaderStatus' Union All Select '4' as 'RofstHeaderStatusID', 'Load Failed' as 'RofstHeaderStatus' GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstHeaderStatuses] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstHeaderStatuses] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstHeaders] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstHeaders' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstHeaders] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for RofstHeaders ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstHeaders] As Select rh.RofstID as 'RofstID', hs.RofstHeaderStatusID as 'RofstHeaderStatusID', hs.RofstHeaderStatus as 'RofstHeaderStatus', rh.hSize as 'hSize', rh.hMonth as 'hMonth', rh.hDay as 'hDay', rh.hcYear as 'hcYear', rh.hcMonth as 'hcMonth', rh.hcDay as 'hcDay', rh.hcHour as 'hcHour', rh.hcMin as 'hcMin', rh.hcSec as 'hcSec', rh.hcHund as 'hcHund', rh.LoadedDate as 'LoadedDate', rh.CreateUserID as 'CreateUserID', rh.CreateDate as 'CreateDate' From RofstHeader rh With (NoLock) inner join vwRofstData_RofstHeaderStatuses hs on hs.RofstHeaderStatusID = dbo.vefn_RofstDataGetLoadStatus(rh.RofstID) GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstHeaders] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstHeaders] Error on Creation' GO /* ---------------------------------------------------------------------------------- Stored Procs: (Update Existing) ---------------------------------------------------------------------------------- [dbo].[updateROFst] [dbo].[getROImage] [dbo].[getROFstsByRODbID] [dbo].[getROFsts] [dbo].[getRoFstBySize] [dbo].[getROFstByRODbID_DTS] [dbo].[getROFst] [dbo].[getRODb] [dbo].[getJustROFst] [dbo].[getFiguresByImageID] [dbo].[getDocVersion] */ /****** Object: StoredProcedure [dbo].[updateROFst] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'updateROFst' AND type in (N'P')) DROP PROCEDURE [dbo].[updateROFst] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[updateROFst] ( @ROFstID int, @RODbID int, @ROLookup varbinary(MAX), @Config nvarchar(MAX)=null, @DTS datetime, @UserID nvarchar(100), @LastChanged timestamp, @newLastChanged timestamp output ) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION UPDATE [ROFsts] SET [RODbID]=@RODbID, --[ROLookup]=@ROLookup, [Config]=@Config, [DTS]=@DTS, [UserID]=@UserID WHERE [ROFstID]=@ROFstID AND [LastChanged]=@LastChanged IF @@ROWCOUNT = 0 BEGIN IF NOT exists(select * from [ROFsts] WHERE [ROFstID]=@ROFstID) RAISERROR('ROFst record has been deleted by another user', 16, 1) ELSE RAISERROR('ROFst has been edited by another user', 16, 1) END SELECT @newLastChanged=[LastChanged] FROM [ROFsts] WHERE [ROFstID]=@ROFstID 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 IF (@@Error = 0) PRINT 'Procedure Creation: [updateROFst] Succeeded' ELSE PRINT 'Procedure Creation: [updateROFst] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getROImage] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getROImage' AND type in (N'P')) DROP PROCEDURE [dbo].[getROImage] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getROImage] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [ImageID], [RODbID], [FileName], [Content], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(1) FROM [Figures] WHERE [Figures].[ImageID]=[ROImages].[ImageID]) [FigureCount] FROM [ROImages] WHERE [ImageID]=@ImageID SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], --[ROFsts].[ROLookup] [ROFst_ROLookup], null as [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Figures] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Figures].[ROFstID] WHERE [Figures].[ImageID]=@ImageID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getROImage] Succeeded' ELSE PRINT 'Procedure Creation: [getROImage] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getROFstsByRODbID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getROFstsByRODbID' AND type in (N'P')) DROP PROCEDURE [dbo].[getROFstsByRODbID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getROFstsByRODbID] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [ROFsts].[ROFstID], [ROFsts].[RODbID], --[ROFsts].[ROLookup], null as [ROLookup], [ROFsts].[Config], [ROFsts].[DTS], [ROFsts].[UserID], [ROFsts].[LastChanged], (SELECT COUNT(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT COUNT(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFsts].[RODbID]=@RODbID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getROFstsByRODbID] Succeeded' ELSE PRINT 'Procedure Creation: [getROFstsByRODbID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getROFsts] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getROFsts' AND type in (N'P')) DROP PROCEDURE [dbo].[getROFsts] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getROFsts] WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], --[ROLookup], null as [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT Count(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getROFsts] Succeeded' ELSE PRINT 'Procedure Creation: [getROFsts] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getRoFstBySize] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getRoFstBySize' AND type in (N'P')) DROP PROCEDURE [dbo].[getRoFstBySize] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO Create PROCEDURE [dbo].[getRoFstBySize] ( @RODbID int, @Len int ) WITH EXECUTE AS OWNER AS select [ROFstID], [RODbID], --[ROLookup], null as [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT Count(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] from [ROFsts] where len(rolookup) = @len and [RODbID] = @RODbID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getRoFstBySize] Succeeded' ELSE PRINT 'Procedure Creation: [getRoFstBySize] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getROFstByRODbID_DTS] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getROFstByRODbID_DTS' AND type in (N'P')) DROP PROCEDURE [dbo].[getROFstByRODbID_DTS] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getROFstByRODbID_DTS] ( @RODbID int, @DTS datetime ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], --[ROLookup], null as [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT Count(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [RODbID]=@RODbID AND [DTS]=@DTS RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getROFstByRODbID_DTS] Succeeded' ELSE PRINT 'Procedure Creation: [getROFstByRODbID_DTS] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getROFst] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getROFst' AND type in (N'P')) DROP PROCEDURE [dbo].[getROFst] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], -- [ROLookup], null as [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT Count(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFstID]=@ROFstID SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [DocVersions].[FolderID] [DocVersion_FolderID], [DocVersions].[VersionType] [DocVersion_VersionType], [DocVersions].[Name] [DocVersion_Name], [DocVersions].[Title] [DocVersion_Title], [DocVersions].[ItemID] [DocVersion_ItemID], [DocVersions].[FormatID] [DocVersion_FormatID], [DocVersions].[Config] [DocVersion_Config], [DocVersions].[DTS] [DocVersion_DTS], [DocVersions].[UserID] [DocVersion_UserID] FROM [Associations] JOIN [DocVersions] ON [DocVersions].[VersionID]=[Associations].[VersionID] WHERE [Associations].[ROFstID]=@ROFstID SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROImages].[RODbID] [ROImage_RODbID], [ROImages].[FileName] [ROImage_FileName], [ROImages].[Content] [ROImage_Content], [ROImages].[Config] [ROImage_Config], [ROImages].[DTS] [ROImage_DTS], [ROImages].[UserID] [ROImage_UserID] FROM [Figures] JOIN [ROImages] ON [ROImages].[ImageID]=[Figures].[ImageID] WHERE [Figures].[ROFstID]=@ROFstID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getROFst] Succeeded' ELSE PRINT 'Procedure Creation: [getROFst] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getRODb] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getRODb' AND type in (N'P')) DROP PROCEDURE [dbo].[getRODb] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getRODb] ( @RODbID int ) WITH EXECUTE AS OWNER AS SELECT [RODbID], [ROName], [FolderPath], [DBConnectionString], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [DROUsages] WHERE [DROUsages].[RODbID]=[RODbs].[RODbID]) [DROUsageCount], (SELECT Count(1) FROM [ROFsts] WHERE [ROFsts].[RODbID]=[RODbs].[RODbID]) [ROFstCount], (SELECT Count(1) FROM [ROImages] WHERE [ROImages].[RODbID]=[RODbs].[RODbID]) [ROImageCount], (SELECT Count(1) FROM [RoUsages] WHERE [RoUsages].[RODbID]=[RODbs].[RODbID]) [RoUsageCount] FROM [RODbs] WHERE [RODbID]=@RODbID SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [Documents].[LibTitle] [Document_LibTitle], [Documents].[DocContent] [Document_DocContent], [Documents].[DocAscii] [Document_DocAscii], [Documents].[Config] [Document_Config], [Documents].[DTS] [Document_DTS], [Documents].[UserID] [Document_UserID], [Documents].[FileExtension] [Document_FileExtension] FROM [DROUsages] JOIN [Documents] ON [Documents].[DocID]=[DROUsages].[DocID] WHERE [DROUsages].[RODbID]=@RODbID SELECT [ROFsts].[ROFstID], [ROFsts].[RODbID], --[ROFsts].[ROLookup], null as [ROLookup], [ROFsts].[Config], [ROFsts].[DTS], [ROFsts].[UserID], [ROFsts].[LastChanged] FROM [ROFsts] WHERE [ROFsts].[RODbID]=@RODbID SELECT [ROImages].[ImageID], [ROImages].[RODbID], [ROImages].[FileName], [ROImages].[Content], [ROImages].[Config], [ROImages].[DTS], [ROImages].[UserID], [ROImages].[LastChanged] FROM [ROImages] WHERE [ROImages].[RODbID]=@RODbID SELECT [RoUsages].[ROUsageID], [RoUsages].[ContentID], [RoUsages].[ROID], [RoUsages].[Config], [RoUsages].[DTS], [RoUsages].[UserID], [RoUsages].[LastChanged], [RoUsages].[RODbID], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [RoUsages] JOIN [Contents] ON [Contents].[ContentID]=[RoUsages].[ContentID] WHERE [RoUsages].[RODbID]=@RODbID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getRODb] Succeeded' ELSE PRINT 'Procedure Creation: [getRODb] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getJustROFst] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getJustROFst' AND type in (N'P')) DROP PROCEDURE [dbo].[getJustROFst] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getJustROFst] ( @ROFstID int ) WITH EXECUTE AS OWNER AS SELECT [ROFstID], [RODbID], --[ROLookup], null as [ROLookup], [Config], [DTS], [UserID], [LastChanged], (SELECT Count(1) FROM [Associations] WHERE [Associations].[ROFstID]=[ROFsts].[ROFstID]) [AssociationCount], (SELECT Count(1) FROM [Figures] WHERE [Figures].[ROFstID]=[ROFsts].[ROFstID]) [FigureCount] FROM [ROFsts] WHERE [ROFstID]=@ROFstID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getJustROFst] Succeeded' ELSE PRINT 'Procedure Creation: [getJustROFst] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getFiguresByImageID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getFiguresByImageID' AND type in (N'P')) DROP PROCEDURE [dbo].[getFiguresByImageID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getFiguresByImageID] ( @ImageID int ) WITH EXECUTE AS OWNER AS SELECT [Figures].[FigureID], [Figures].[ROFstID], [Figures].[ImageID], [Figures].[Config], [Figures].[DTS], [Figures].[UserID], [Figures].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], --[ROFsts].[ROLookup] [ROFst_ROLookup], null as [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Figures] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Figures].[ROFstID] WHERE [Figures].[ImageID]=@ImageID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getFiguresByImageID] Succeeded' ELSE PRINT 'Procedure Creation: [getFiguresByImageID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[getDocVersion] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'getDocVersion' AND type in (N'P')) DROP PROCEDURE [dbo].[getDocVersion] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Create Date: Description: ========================================================================================================== */ CREATE PROCEDURE [dbo].[getDocVersion] ( @VersionID int ) WITH EXECUTE AS OWNER AS SELECT [VersionID], [FolderID], [VersionType], [Name], [Title], [ItemID], [FormatID], [Config], [DTS], [UserID], [LastChanged], (SELECT COUNT(1) FROM [Associations] WHERE [Associations].[VersionID]=[DocVersions].[VersionID]) [AssociationCount] FROM [DocVersions] WHERE [VersionID]=@VersionID SELECT [Associations].[AssociationID], [Associations].[VersionID], [Associations].[ROFstID], [Associations].[Config], [Associations].[DTS], [Associations].[UserID], [Associations].[LastChanged], [ROFsts].[RODbID] [ROFst_RODbID], --[ROFsts].[ROLookup] [ROFst_ROLookup], null as [ROFst_ROLookup], [ROFsts].[Config] [ROFst_Config], [ROFsts].[DTS] [ROFst_DTS], [ROFsts].[UserID] [ROFst_UserID] FROM [Associations] JOIN [ROFsts] ON [ROFsts].[ROFstID]=[Associations].[ROFstID] WHERE [Associations].[VersionID]=@VersionID RETURN GO IF (@@Error = 0) PRINT 'Procedure Creation: [getDocVersion] Succeeded' ELSE PRINT 'Procedure Creation: [getDocVersion] Error on Creation' GO /* ---------------------------------------------------------------------------------- Stored Procs: (Create New) ---------------------------------------------------------------------------------- [dbo].[vesp_RofstHeaderInsert] [dbo].[vesp_RofstHeaderFinalizeLoad] [dbo].[vesp_RofstDataSearch] [dbo].[vesp_RofstDataGetValueDifferences] [dbo].[vesp_RofstDataGetRofstByID] [dbo].[vesp_RofstDataGetHeaderRofstByID] [dbo].[vesp_RofstDataGetDatabases] [dbo].[vesp_RofstDataGetDatabaseByID] [dbo].[vesp_RofstDataGetChildrenByType] [dbo].[vesp_RofstDataGetChildrenByRoid] [dbo].[vesp_RofstDataGetChildrenByRofstID] [dbo].[vesp_RofstDataGetChildrenByID] [dbo].[vesp_RofstDataGetChildByRoid] [dbo].[vesp_RofstDataGetChildByID] [dbo].[vesp_RofstDataGetChildByAccPageID] [dbo].[vesp_RofstDatabaseInsert] [dbo].[vesp_RofstChildInsert] */ /****** Object: StoredProcedure [dbo].[vesp_RofstHeaderInsert] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstHeaderInsert' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstHeaderInsert] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Inserts New Rofst Header Record ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstHeaderInsert] ( @RofstID Int, @hSize Int, @hMonth Int, @hDay Int, @hcYear Int, @hcMonth Int, @hcDay Int, @hcHour Int, @hcMin Int, @hcSec Int, @hcHund Int, @UserID VarChar(50) ) With Execute as Owner As Begin -- Clear Existing Values (If Any) Delete From RofstHeader Where RofstID = @RofstID; -- Create RofstHeader records and Set LoadedDate to null Insert Into RofstHeader (RofstID, hSize, hMonth, hDay, hcYear, hcMonth, hcDay, hcHour, hcMin, hcSec, hcHund, LoadedDate, CreateUserID, CreateDate) Values (@RofstID, @hSize, @hMonth, @hDay, @hcYear, @hcMonth, @hcDay, @hcHour, @hcMin, @hcSec, @hcHund, null, @UserID, GetDate()); Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstHeaderInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstHeaderInsert] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstHeaderFinalizeLoad] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstHeaderFinalizeLoad' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstHeaderFinalizeLoad] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Finalizes Rofst Header Record / Updates LoadedDate if Success ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstHeaderFinalizeLoad] ( @RofstID Int ) With Execute as Owner As Begin -- Set LoadedDate on RofstHeader Update RofstHeader Set LoadedDate = GetDate() Where RofstID = @RofstID; -- Rebuild/Reorganize Indexes Exec [dbo].[vesp_UtilityCheckIndexes] 20.0, 5.0, 0, 1; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstHeaderFinalizeLoad] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstHeaderFinalizeLoad] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataSearch] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataSearch' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataSearch] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: RO Default Value Search @SearchTypeID => (1) Starts With (2) Ends With (3) Contains (4) Exact Match ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataSearch] ( @RofstID int, @Value VarChar(Max) = null, @SearchTypeID Int = 1, -- Starts With @MaxNumOfRecords Int = null ) With Execute as Owner As Begin -- Remove any leading/trailing white spaces Set @Value = dbo.vefn_Clean( @Value, 0, null ); -- Escape any % signs in the search value Set @Value = Replace( @Value, '%', '[%]' ); -- Format search value If (Len(@Value) = 0) Set @Value = null; -- Create Temp Results Table Create Table #SearchResults (roid VarChar(50) Not Null, [value] VarChar(Max), RowNum Int Not Null Primary Key); -- Select roids/values based on search criteria Insert Into #SearchResults (roid, [value], RowNum) Select rdv.roid, rdv.[value], Row_Number() Over (Order By rdv.[value] Asc, rdv.roid Asc) as 'RowNum' From vwRofstData_RofstDefaultValues rdv Where rdv.RofstID = @RofstID And ((@Value is null) Or (@SearchTypeID = 1 And rdv.[value] like @Value + '%') -- Starts With Or (@SearchTypeID = 2 And rdv.[value] like '%' + @Value) -- Ends With Or (@SearchTypeID = 3 And rdv.[value] like '%' + @Value + '%') -- Contains Or (@SearchTypeID = 4 And rdv.[value] = @Value)) -- Exact Match Order By rdv.[value] Asc, rdv.roid Asc Option (Recompile); -- Return the specified number of results Select sr.roid, sr.[value] From #SearchResults sr Where (@MaxNumOfRecords is null Or sr.RowNum <= @MaxNumOfRecords) Order By sr.RowNum Asc; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataSearch] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataSearch] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetValueDifferences] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetValueDifferences' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetValueDifferences] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Value Differences between (2) Rofst (Ro.fst) Files ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetValueDifferences] ( @OriginalRofstID Int, @CurrentRofstID Int ) With Execute as Owner As Begin Declare @Differences Table (OriginalRoid VarChar(25), OriginalValue VarChar(Max), CurrentRoid VarChar(25), CurrentValue VarChar(Max)); With OriginalRofst as ( Select rc.roid, rc.[value] From vwRofstData_RofstChildren rc Where rc.RofstID = @OriginalRofstID And Not rc.[value] is null ), CurrentRofst as ( Select rc.roid, rc.[value] From vwRofstData_RofstChildren rc Where rc.RofstID = @CurrentRofstID And Not rc.[value] is null ) Insert Into @Differences (OriginalRoid, OriginalValue, CurrentRoid, CurrentValue) Select o.roid, o.[value], c.roid, c.[value] From OriginalRofst o left outer join CurrentRofst c on c.roid = o.roid Where o.[value] <> c.[value]; Select OriginalRoid as 'Roid', Case When (CurrentValue is null) Then 1 Else 0 End as 'IsDeleted', Case When (Not CurrentValue is null) Then 1 Else 0 End as 'IsModified' From @Differences; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetValueDifferences] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetValueDifferences] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetRofstByID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetRofstByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetRofstByID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofsts Info by ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetRofstByID] ( @RofstID int, @IncludeRoLookup Bit ) With Execute as Owner As Begin Select r.ROFstID, r.RODbID, Case (@IncludeRoLookup) When 1 Then r.ROLookup Else null End as 'ROLookup', r.DTS, r.UserID, r.LastChanged From ROFsts r with (NoLock) Where r.RofstID = @RofstID; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetRofstByID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetRofstByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetHeaderRofstByID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetHeaderRofstByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetHeaderRofstByID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Header Info by ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetHeaderRofstByID] ( @RofstID int ) With Execute as Owner As Begin Select rh.RofstID as 'RofstID', rh.RofstHeaderStatusID as 'RofstHeaderStatusID', rh.RofstHeaderStatus as 'RofstHeaderStatus', rh.hSize as 'hSize', rh.hMonth as 'hMonth', rh.hDay as 'hDay', rh.hcYear as 'hcYear', rh.hcMonth as 'hcMonth', rh.hcDay as 'hcDay', rh.hcHour as 'hcHour', rh.hcMin as 'hcMin', rh.hcSec as 'hcSec', rh.hcHund as 'hcHund', rh.LoadedDate as 'LoadedDate', rh.CreateUserID as 'CreateUserID', rh.CreateDate as 'CreateDate' From vwRofstData_RofstHeaders rh Where rh.RofstID = @RofstID; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetHeaderRofstByID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetHeaderRofstByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetDatabases] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetDatabases' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetDatabases] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets all Rofst Databases for a specified Rofst File ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetDatabases] ( @RofstID int ) With Execute as Owner As Begin Select rd.RofstID, rd.dbiID, rd.dbiType, rd.dbiAW, rd.dbiTitle, rd.dbiAP, rd.ID, rd.ParentID From vwRofstData_RofstDatabases rd Where rd.RofstID = @RofstID Order By rd.dbiID Asc; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetDatabases] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetDatabases] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetDatabaseByID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetDatabaseByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetDatabaseByID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Database Info by ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetDatabaseByID] ( @RofstID int, @dbiID int ) With Execute as Owner As Begin Select rd.RofstID, rd.dbiID, rd.dbiType, rd.dbiAW, rd.dbiTitle, rd.dbiAP, rd.ID, rd.ParentID From vwRofstData_RofstDatabases rd Where rd.RofstID = @RofstID And rd.dbiID = @dbiID; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetDatabaseByID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetDatabaseByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildrenByType] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildrenByType' AND type in (N'P')) DROP PROCEDURE[dbo].[vesp_RofstDataGetChildrenByType] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Children Info by Type ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildrenByType] ( @RofstID int, @ValueTypes VarChar(Max) ) With Execute as Owner As Begin -- Remove any leading/trailing white spaces Set @ValueTypes = dbo.vefn_Clean( @ValueTypes, 0, null ); -- Format search value If (Len(@ValueTypes) = 0) Set @ValueTypes = null; With ValueTypes as ( Select Cast(x.ListValue as Int) as 'ListValue' From dbo.vefn_ParseStringListToTable(@ValueTypes, ',') as x ) Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Left outer join ValueTypes vt on vt.ListValue = rc.[type] Where rc.RofstID = @RofstID And Not rc.[value] is null And (@ValueTypes is null Or Not vt.ListValue is null) Option (Recompile); Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByType] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByType] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildrenByRoid] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildrenByRoid' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildrenByRoid] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Children (RoChild) Info by Roid ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildrenByRoid] ( @RofstID int, @Roid VarChar(50) ) With Execute as Owner As Begin With RoParent as ( Select RofstID, dbiID, ID, [type], title, roid From vwRofstData_RofstChildren Where RofstID = @RofstID And roid = @Roid ) Select rc.RofstID, rc.dbiID, -- Ro Parent Info rp.[type] as 'ParentType', rp.title as 'ParentTitle', rp.roid as 'ParentRoid', -- Ro Child Info rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From RoParent rp inner join vwRofstData_RofstChildren rc on rc.RofstID = rp.RofstID and rc.dbiID = rp.dbiID and rc.ParentID = rp.ID Order By rc.ID Asc; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByRoid] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByRoid] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildrenByRofstID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildrenByRofstID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildrenByRofstID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets All Rofst Children Info by Rofst ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildrenByRofstID] ( @RofstID int ) With Execute as Owner As Begin Select rc.RofstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And Not rc.[value] is null Order By rc.dbiID Asc, rc.[type] Asc, rc.roid Asc; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByRofstID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByRofstID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildrenByID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildrenByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildrenByID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Children Info by DbiID and Object ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildrenByID] ( @RofstID int, @DbiID int, @ID Int ) With Execute as Owner As Begin Select rc.RofstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.dbiID = @DbiID And rc.ParentID = @ID Order By rc.ID Asc; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildrenByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildByRoid] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByRoid' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByRoid] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Child Info by Roid ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByRoid] ( @RofstID int, @Roid VarChar(50) ) With Execute as Owner As Begin Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.roid = @Roid; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByRoid] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByRoid] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildByID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Child Info by dbiID and Object ID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByID] ( @RofstID int, @DbiID int, @ID Int ) With Execute as Owner As Begin Select rc.RofstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.dbiID = @DbiID And rc.ID = @ID; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildByAccPageID] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByAccPageID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByAccPageID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Gets Rofst Child Info by AccPageID ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByAccPageID] ( @RofstID int, @AccPageID VarChar(50) ) With Execute as Owner As Begin Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.AccPageID = @AccPageID; Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDatabaseInsert] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDatabaseInsert' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDatabaseInsert] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Inserts New Rofst Database Record ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDatabaseInsert] ( @RofstID Int, @dbiID Int, @dbiType Int, @dbiAW Int, @dbiTitle VarChar(Max), @dbiAP VarChar(Max), @ID Int, @ParentID Int ) With Execute as Owner As Begin Insert Into RofstDatabase (RofstID, dbiID, dbiType, dbiAW, dbiTitle, dbiAP, ID, ParentID) Values (@RofstID, @dbiID, @dbiType, @dbiAW, @dbiTitle, @dbiAP, @ID, @ParentID ); Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDatabaseInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDatabaseInsert] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstChildInsert] Script Date: 06/23/2022 ******/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstChildInsert' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstChildInsert] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/23/2022 Description: Inserts New Rofst Child Record / Default Values ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstChildInsert] ( @RofstID Int, @ID Int, @ParentID Int, @dbiID Int, @type Int, @title VarChar(Max), @roid VarChar(50), @appid VarChar(Max) = null, @value VarChar(Max) = null ) With Execute as Owner As Begin Declare @AccPageID VarChar(Max) = null; Declare @DefaultValues VarChar(Max); -- Create Rofst Child/Group Record Insert Into RofstChild (RofstID, ID, ParentID, dbiID, [type], title, roid, appid, [value]) Values (@RofstID, @ID, @ParentID, @dbiID, @type, @title, @roid, @appid, @value); -- Check for appid, if exists, then insert the default value for each return type if multi-value If (Len(@appid) > 0) Begin -- Get Accessory Page ID Select @AccPageID = Concat(d.dbiAP, '-', @appid) From RofstDatabase d with (NoLock) Where d.RofstID = @RofstID And d.dbiID = @dbiID; -- Insert Rofst Default Value (Parent RoChild) [roid = 12] Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Values (@RofstID, @roid, Replace(@title, '\u160?', ' '), @AccPageID); -- Insert Rofst Default Value(s) (Children RoChild) [roid = 16] (Do Not Insert Duplicates) Select @DefaultValues = Replace(dbo.vefn_RofstDataReplaceVars(@value), '{', ''); With ChildrenValues as ( Select (x.ListPosition + 40) as 'OffsetIndex', Case When (PatIndex('%=%', x.ListValue) > 0) Then Right(x.ListValue, Len(x.ListValue)-PatIndex('%=%', x.ListValue)) Else x.ListValue End as 'DefaultValue' From [dbo].[vefn_ParseStringListToTable](@DefaultValues, '}') x Where Len(x.ListValue) > 0 ) Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, Cast(Format(Min(OffsetIndex), 'D4') as VarChar(4))) as 'roid', DefaultValue as 'value', null as 'AccPageID' From ChildrenValues Group By DefaultValue Order By Min(OffsetIndex) Asc End -- (Len(@appid) > 0) Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstChildInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstChildInsert] Error on Creation' GO /* ========================================================================================================== End: B2022-026 RO Memory reduction coding (Jakes Merge) [Version 2.0] ========================================================================================================== */ /* ========================================================================================================== Start: B2022-083: Support Conditional RO Values (v2.1) ========================================================================================================== */ /* ---------------------------------------------------------------------------------- Tables: ---------------------------------------------------------------------------------- [RofstExtension] [Created] */ -- If RofstExtension table already exists then don't drop and recreate it IF Not Exists(SELECT * FROM sys.objects Where name = 'RofstExtension' AND type in (N'U')) Begin SET ANSI_NULLS ON SET QUOTED_IDENTIFIER ON CREATE TABLE [dbo].[RofstExtension]( [Offset] [int] NOT NULL, [RoidExt] [varchar](4) NOT NULL, [AccPageExt] [varchar](5) NOT NULL, CONSTRAINT [PK_RofstExtension] PRIMARY KEY CLUSTERED ( [Offset] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] IF (@@Error = 0) PRINT 'Table Creation: [RofstExtension] Succeeded' ELSE PRINT 'Table Creation: [RofstExtension] Error on Creation' IF (@@Error = 0) Begin Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (1,'0041','A'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (2,'0042','B'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (3,'0043','C'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (4,'0044','D'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (5,'0045','E'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (6,'0046','F'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (7,'0047','G'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (8,'0048','H'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (9,'0049','I'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (10,'004A','J'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (11,'004B','K'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (12,'004C','L'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (13,'004D','M'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (14,'004E','N'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (15,'004F','O'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (16,'0050','P'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (17,'0051','Q'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (18,'0052','R'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (19,'0053','S'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (20,'0054','T'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (21,'0055','U'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (22,'0056','V'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (23,'0057','W'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (24,'0058','X'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (25,'0059','Y'); Insert Into RofstExtension (Offset, RoidExt, AccPageExt) Values (26,'005A','Z'); End End Go /* ---------------------------------------------------------------------------------- Functions: ---------------------------------------------------------------------------------- [dbo].[vefn_RofstDataCleanUnitInfoTags] [Created] [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults] [Created] [dbo].[vefn_RofstDataReplaceVars] [Modified] */ /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataCleanUnitInfoTags] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataCleanUnitInfoTags' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataCleanUnitInfoTags] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 06/21/2022 -- Description: Removes any legacy legacy unit info variables and fixes older applicability tags -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataCleanUnitInfoTags](@Values VarChar(Max), @RemoveUnitInfoVars bit = 0) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Set @RetVal = dbo.vefn_Clean(@Values, 1, null); If (Len(@RetVal) > 0) Begin -- Make Sure all tag/var instances are upper case & Remove any internal spaces Set @RetVal = Replace(@RetVal, 'U-OTHER TEXT', 'U-OTHERTEXT'); Set @RetVal = Replace(@RetVal, 'U-OTHER NUMBER', 'U-OTHERNUMBER'); Set @RetVal = Replace(@RetVal, 'U-OTHER NAME', 'U-OTHERNAME'); Set @RetVal = Replace(@RetVal, 'U-OTHER ID', 'U-OTHERID'); Set @RetVal = Replace(@RetVal, '', ''); If (@RemoveUnitInfoVars > 0) Begin -- Remove any Unit Info Variables Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); End End Return @RetVal; END Go IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataCleanUnitInfoTags] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataCleanUnitInfoTags] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceLegacyTagsWithDefaults' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 06/21/2022 -- Description: Replaces any legacy applicability tags with the default value -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @DefaultValue VarChar(Max) = ''; Declare @StartTagIndex Int; Declare @EndTagIndex Int; Declare @StartTagValue VarChar(Max); Declare @StartValIndex Int; Declare @EndValIndex Int; Declare @TagName VarChar(Max); Declare @LegacyTagNames VarChar(Max) = 'U-ID,U-NUMBER,U-NAME,U-TEXT,U-OTHERID,U-OTHERNUMBER,U-OTHERNAME,U-OTHERTEXT'; -- Make Sure all tag instances are upper case & Remove any internal spaces Set @RetVal = dbo.vefn_RofstDataCleanUnitInfoTags(@Values, 0); Declare LegacyTags_Cursor Cursor Fast_Forward For Select '{' + x.ListValue + '{' as 'TagName' From [dbo].[vefn_ParseStringListToTable](@LegacyTagNames, ',') x Open LegacyTags_Cursor Fetch Next From LegacyTags_Cursor Into @TagName While (@@FETCH_STATUS = 0) Begin -- Get Start/End Index of Tag Set @StartTagIndex = PatIndex('%' + @TagName + '%', @RetVal); Set @EndTagIndex = PatIndex('%}}%', @RetVal); While (@StartTagIndex > 0) Begin Set @StartTagValue = SubString(@RetVal, @StartTagIndex, (@EndTagIndex - @StartTagIndex) + 2); Set @StartValIndex = PatIndex('%=%', @StartTagValue); Set @EndValIndex = PatIndex('%}%', @StartTagValue); Set @DefaultValue = SubString(@StartTagValue, @StartValIndex + 1, (@EndValIndex - @StartValIndex) - 1); Set @RetVal = Replace(@RetVal, @StartTagValue, @DefaultValue); Set @StartTagIndex = PatIndex('%' + @TagName + '%', @RetVal); Set @EndTagIndex = PatIndex('%}}%', @RetVal); End -- While (@StartTagIndex > 0) Fetch Next From LegacyTags_Cursor Into @TagName End Close LegacyTags_Cursor; Deallocate LegacyTags_Cursor; Return @RetVal; END Go IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceLegacyTagsWithDefaults] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceLegacyTagsWithDefaults] Error on Creation' GO /****** Object: UserDefinedFunction [dbo].[vefn_RofstDataReplaceVars] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceVars' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceVars] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/25/2022 -- Description: Replaces Any Variables and returns the rest of the value string -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceVars](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @EqualsIndex Int; Declare @EndIndex Int; Declare @NameValPairStartIndex Int; Declare @NameValPairEndIndex Int; Declare @VarPair VarChar(Max); Declare @VarName VarChar(Max); Declare @VarValue VarChar(Max); -- Replace Any "" Tags with the Default Value first Select @RetVal = dbo.vefn_RofstDataReplaceApplTagsWithDefaults(@Values); -- Replace Any Legacy Applicability Tags with the Default Value second Select @RetVal = dbo.vefn_RofstDataReplaceLegacyTagsWithDefaults(@RetVal); If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); While(@NameValPairStartIndex > 0 And @NameValPairStartIndex < @EndIndex) Begin -- Get Name Value Pair [ex. {EGS=1214}] Set @VarPair = SubString(@RetVal, @NameValPairStartIndex, (@NameValPairEndIndex - @NameValPairStartIndex) + 1); -- Remove Name Value Pair From Return Val Set @RetVal = Replace(@RetVal, @VarPair, ''); -- Get Variable Name and Value Set @EqualsIndex = PatIndex('%=%', @VarPair); If (@EqualsIndex > 0) Begin Set @VarName = SubString(@VarPair, 2, @EqualsIndex - 2); Set @VarValue = SubString(@VarPair, @EqualsIndex + 1, Len(@VarPair) - @EqualsIndex - 1); Set @VarName = Concat('{', @VarName, '}'); -- Replace All Occurences Set @RetVal = Replace(@RetVal, @VarName, @VarValue); End -- Get Updated Index Values If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); End -- End While(@ReplaceVarEndTagIndex > 0) Return @RetVal; END Go IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Error on Creation' GO /* ---------------------------------------------------------------------------------- Views: ---------------------------------------------------------------------------------- [dbo].[vwRofstData_RofstExtensions] [Created] [dbo].[vwRofstData_RofstValueTypes] [Created] [dbo].[vwRofstData_RofstBaseRoids] [Created] [dbo].[vwRofstData_RofstChildren] [Modified] */ /****** Object: View [dbo].[vwRofstData_RofstExtensions] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstExtensions' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstExtensions] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/21/2024 Description: (RofstData) Master View for RofstExtensions ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstExtensions] As Select re.Offset as 'Offset', re.RoidExt as 'RoidExt', re.AccPageExt as 'AccPageExt' From RofstExtension re With (NoLock) GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstExtensions] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstExtensions] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstValueTypes] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstValueTypes' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstValueTypes] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/21/2022 Description: (RofstData) Master View for Rofst Value Types (0) Unknown (1) Single Line Text (2) Table (3) Multiple Line Text (4) X/Y Plot (8) Image ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstValueTypes] As Select '0' as 'TypeID', 'Unknown' as 'TypeDescription' Union All Select '1' as 'TypeID', 'Single Line Text' as 'TypeDescription' -- Fixed Length Text Union All Select '2' as 'TypeID', 'Table' as 'TypeDescription' Union All Select '3' as 'TypeID', 'Multiple Line Text' as 'TypeDescription' Union All Select '4' as 'TypeID', 'X/Y Plot' as 'TypeDescription' Union All Select '8' as 'TypeID', 'Image' as 'TypeDescription' GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstValueTypes] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstValueTypes] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstBaseRoids] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstBaseRoids' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstBaseRoids] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for Rofst Base Roid / AccPageID Values ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstBaseRoids] As Select RofstID as 'RofstID', Left(roid, 12) as 'BaseRoid', Left(AccPageID, (Len(AccPageID)-2)) as 'BaseAccPageID' From vwRofstData_RofstDefaultValues Where AccPageID like '%.A'; GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstBaseRoids] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstBaseRoids] Error on Creation' GO /****** Object: View [dbo].[vwRofstData_RofstChildren] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vwRofstData_RofstChildren' AND type in (N'V')) DROP VIEW [dbo].[vwRofstData_RofstChildren] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2024 Description: (RofstData) Master View for RofstChildren (RoChild & Groups) ========================================================================================================== */ Create View [dbo].[vwRofstData_RofstChildren] As Select rc.RofstChildID as 'RofstChildID', rd.RofstID as 'RofstID', -- RoDatabase Info rd.dbiID as 'dbiID', rd.dbiType as 'dbiType', rd.dbiAW as 'dbiAW', rd.dbiTitle as 'dbiTitle', rd.dbiAP as 'dbiAP', -- RoChild Info rc.ID as 'ID', rc.ParentID as 'ParentID', rc.[type] as 'type', IsNull(vt.TypeDescription, 'Unknown') as 'TypeDescription', rc.title as 'title', rc.roid as 'roid', rc.appid as 'appid', rc.[value] as 'value', Case When (Not rc.[value] is null) Then rd.dbiAP + '-' + rc.appid Else null End as 'AccPageID' From RofstChild rc With (NoLock) inner join RofstDatabase rd With (NoLock) on rc.RofstID = rd.RofstID and rc.dbiID = rd.dbiID left outer join vwRofstData_RofstValueTypes vt on vt.TypeID = rc.[type]; GO IF (@@Error = 0) PRINT 'View Creation: [vwRofstData_RofstChildren] Succeeded' ELSE PRINT 'View Creation: [vwRofstData_RofstChildren] Error on Creation' GO /* ---------------------------------------------------------------------------------- Stored Procs: ---------------------------------------------------------------------------------- [dbo].[vesp_RofstDataGetChildByID] [Deleted] [dbo].[vesp_RofstDataGetExtensions] [Created] [dbo].[vesp_RofstChildInsert] [Modified] [dbo].[vesp_RofstDataSearch] [Modified] [dbo].[vesp_RofstDataGetChildByAccPageID] [Modified] [dbo].[vesp_RofstDataGetChildByRoid] [Modified] */ /****** Object: StoredProcedure [dbo].[vesp_RofstHeaderInsert] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByID] GO IF (@@Error = 0) PRINT 'Procedure Deletion: [vesp_RofstDataGetChildByID] Succeeded' ELSE PRINT 'Procedure Deletion: [vesp_RofstDataGetChildByID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetExtensions] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetExtensions' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetExtensions] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 06/21/2022 Description: Gets the Ro Lookup Extensions ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetExtensions] With Execute as Owner As Begin Select re.Offset, re.RoidExt, re.AccPageExt From vwRofstData_RofstExtensions re Order By re.Offset Asc; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetExtensions] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetExtensions] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstChildInsert] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstChildInsert' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstChildInsert] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstChildInsert] ( @RofstID Int, @ID Int, @ParentID Int, @dbiID Int, @type Int, @title VarChar(Max), @roid VarChar(50), @appid VarChar(Max) = null, @value VarChar(Max) = null ) With Execute as Owner As Begin Declare @BaseAccPageID VarChar(Max) = null; Declare @DefaultValues VarChar(Max); -- Create Rofst Child/Group Record --> [Roid = (12) Digits] Insert Into RofstChild (RofstID, ID, ParentID, dbiID, [type], title, roid, appid, [value]) Values (@RofstID, @ID, @ParentID, @dbiID, @type, @title, @roid, @appid, @value); -- Check for appid, if exists, then insert the default value for each return type if multi-value If (Len(@appid) > 0) Begin -- Get Accessory Page ID Select @BaseAccPageID = dbo.vefn_RofstDataCleanUnitInfoTags(Concat(d.dbiAP, '-', @appid), 1) From RofstDatabase d with (NoLock) Where d.RofstID = @RofstID And d.dbiID = @dbiID; -- Insert Rofst Default Value(s) (Children RoChild) --> [Roid = (16) Digits] Select @DefaultValues = Replace(dbo.vefn_RofstDataReplaceVars(@value), '{', ''); With ChildrenValues as ( Select x.ListPosition as 'OffsetIndex', Case When (PatIndex('%=%', x.ListValue) > 0) Then Right(x.ListValue, Len(x.ListValue)-PatIndex('%=%', x.ListValue)) Else x.ListValue End as 'DefaultValue' From [dbo].[vefn_ParseStringListToTable](@DefaultValues, '}') x Where Len(x.ListValue) > 0 ) Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, re.RoidExt) as 'roid', Case When (Len(RTrim(LTrim(cv.DefaultValue))) > 0 ) Then dbo.vefn_RofstDataCleanUnitInfoTags(cv.DefaultValue, 0) Else '[TBD]' End as 'value', Concat(@BaseAccPageID, '.', re.AccPageExt) as 'AccPageID' From ChildrenValues cv inner join vwRofstData_RofstExtensions re on re.Offset = cv.OffsetIndex Order By cv.OffsetIndex Asc End -- (Len(@appid) > 0) Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstChildInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstChildInsert] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataSearch] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataSearch' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataSearch] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: RO Default Value Search @SearchTypeID => (1) Starts With (2) Ends With (3) Contains (4) Exact Match ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataSearch] ( @RofstID int, @Value VarChar(Max) = null, @SearchTypeID Int = 1, -- Starts With @OnlyRoid16 Bit = 1, -- Return Only Roid16 Records @MaxNumOfRecords Int = null ) With Execute as Owner As Begin -- Remove any leading/trailing white spaces Set @Value = dbo.vefn_Clean( @Value, 0, null ); -- Escape any % signs in the search value Set @Value = Replace( @Value, '%', '[%]' ); -- Format search value If (Len(@Value) = 0) Set @Value = null; -- Create Temp Results Table Create Table #SearchResults (roid VarChar(50) Not Null, [value] VarChar(Max), RowNum Int Not Null Primary Key); -- Select roids/values based on search criteria Insert Into #SearchResults (roid, [value], RowNum) Select rdv.roid, rdv.[value], Row_Number() Over (Order By rdv.[value] Asc, rdv.roid Asc) as 'RowNum' From vwRofstData_RofstDefaultValues rdv Where rdv.RofstID = @RofstID And (@OnlyRoid16 = 0 Or Len(rdv.roid) = 16) And ((@Value is null) Or (@SearchTypeID = 1 And rdv.[value] like @Value + '%') -- Starts With Or (@SearchTypeID = 2 And rdv.[value] like '%' + @Value) -- Ends With Or (@SearchTypeID = 3 And rdv.[value] like '%' + @Value + '%') -- Contains Or (@SearchTypeID = 4 And rdv.[value] = @Value)) -- Exact Match Order By rdv.[value] Asc, rdv.roid Asc Option (Recompile); -- Return the specified number of results Select sr.roid, sr.[value] From #SearchResults sr Where (@MaxNumOfRecords is null Or sr.RowNum <= @MaxNumOfRecords) Order By sr.RowNum Asc; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataSearch] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataSearch] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildByAccPageID] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByAccPageID' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByAccPageID] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: Check if the AccPageID passed in has a specific Return Value Type Extension (.A, .B, .C, etc.) If so, then strip off the return value specific extension to get the BaseAccPageID for the lookup. Use the BaseAccPageID to lookup the BaseRoid, then use the Roid to lookup the Ro Child Object Note** Using the AccPageID to first lookup the roid, then using the roid to lookup the data is significantly faster than directly looking up the data using the AccPageID because of the indexes ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByAccPageID] ( @RofstID int, @AccPageID VarChar(50) ) With Execute as Owner As Begin Declare @BaseAccPageID VarChar(Max); Declare @Roid VarChar(Max); If (PatIndex('%.[A-Z]', @AccPageID) > 0) Set @BaseAccPageID = Left(@AccPageID, Len(@AccPageID)-2); Else Set @BaseAccPageID = @AccPageID; -- First use the AccPageID to get the BaseRoid Select @Roid = rb.BaseRoid From vwRofstData_RofstBaseRoids rb Where rb.RofstID = @RofstID And rb.BaseAccPageID = @BaseAccPageID; -- Then use the Roid to lookup the Ro Child Object Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.roid = @Roid; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Error on Creation' GO /****** Object: StoredProcedure [dbo].[vesp_RofstDataGetChildByRoid] ***********************/ If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstDataGetChildByRoid' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstDataGetChildByRoid] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: The data in the Rofst Children table currently only goes down to the (12) digit roid level. To look up a specific return type value (16) digit roid for a RO object, you first have to load the base RO object by its (12) digit roid in code, and then look for the specific return value in the RO objects children collection because the values for any multiple/variable return type formats can vary at runtime, based on your current selected DocVersion and the Selected Slave (Unit) / OtherChild Override. ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByRoid] ( @RofstID int, @Roid VarChar(50) ) With Execute as Owner As Begin -- Only use the first (12) characters to lookup an RoChild by its roid -- If its a (16) digit roid, then use its last (4) characters [roidExt ==> specific to a return type value] -- to select the specified return value format type in the code once all of the children Ro Return types have -- been loaded into memory in the code Set @Roid = Left(@Roid + '00000000', 12); Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.roid = @Roid; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByRoid] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByRoid] Error on Creation' GO -- Delete All Existing Rofst Table Data Delete From RofstHeader; /* ========================================================================================================== End: B2022-083: Support Conditional RO Values (v2.1) ========================================================================================================== */ /* ========================================================================================================== Start: B2022-049 Unlink single procedure for enhanced (if data got corrupted) ========================================================================================================== */ If Exists(SELECT * FROM sys.objects Where name = 'vesp_PurgeProcLinkedItemsAndChildren' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_PurgeProcLinkedItemsAndChildren] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2022 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ Create PROCEDURE [dbo].[vesp_PurgeProcLinkedItemsAndChildren](@EnhanceID int, @EnhType int) WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- Only unlink for the input procedure number & its children. Do not follow the links, i.e. source or enhanced. This -- can be used for removing link information if the links between the 2, source & enhanced, get corrupted. declare @Enh1 TABLE ( ID int, xConfig xml ) insert into @Enh1 select CC.ContentID, CC.xConfig from (select *, cast(config as xml) xConfig from Contents) CC JOIN vefn_ChildItems(@EnhanceID) VCI ON VCI.ContentID = CC.ContentID cross apply VEFN_GetNewEnhancedData(VCI.itemid,@EnhType) VEN Update @Enh1 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh1 Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC Join @Enh1 EE ON EE.ID = CC.ContentID SELECT [ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[LastChanged], (SELECT COUNT(1) FROM [Details] WHERE [Details].[ContentID]=[Contents].[ContentID]) [DetailCount], (SELECT COUNT(1) FROM [Entries] WHERE [Entries].[ContentID]=[Contents].[ContentID]) [EntryCount], (SELECT COUNT(1) FROM [Grids] WHERE [Grids].[ContentID]=[Contents].[ContentID]) [GridCount], (SELECT COUNT(1) FROM [Images] WHERE [Images].[ContentID]=[Contents].[ContentID]) [ImageCount], (SELECT COUNT(1) FROM [Items] WHERE [Items].[ContentID]=[Contents].[ContentID]) [ItemCount], (SELECT COUNT(1) FROM [Parts] WHERE [Parts].[ContentID]=[Contents].[ContentID]) [PartCount], (SELECT COUNT(1) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[Contents].[ContentID]) [RoUsageCount], (SELECT COUNT(1) FROM [Transitions] WHERE [Transitions].[FromID]=[Contents].[ContentID]) [TransitionCount], (SELECT COUNT(1) FROM [ZContents] WHERE [ZContents].[ContentID]=[Contents].[ContentID]) [ZContentCount] FROM [Contents] where ContentID in (Select ID From @Enh1) 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 IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_PurgeProcLinkedItemsAndChildren] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_PurgeProcLinkedItemsAndChildren] Error on Creation' GO /* ========================================================================================================== End: B2022-049 Unlink single procedure for enhanced (if data got corrupted) [Version 2.xx] ========================================================================================================== */ /* ========================================================================================================== Start: B2022-088: [JPR] Find Doc Ro button not working in Word Sections B2022-098: [JPR] ROs not being resolved in Word Sections ========================================================================================================== */ IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_RofstDataGetChildByAccPageID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP Procedure [dbo].[vesp_RofstDataGetChildByAccPageID]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: Check if the AccPageID passed in has a specific Return Value Type Extension (.A, .B, .C, etc.) If so, then strip off the return value specific extension to get the BaseAccPageID for the lookup. Use the BaseAccPageID to lookup the BaseRoid, then use the Roid to lookup the Ro Child Object Note** Using the AccPageID to first lookup the roid, then using the roid to lookup the data is significantly faster than directly looking up the data using the AccPageID because of the indexes ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetChildByAccPageID] ( @RofstID int, @AccPageID VarChar(50) ) With Execute as Owner As Begin Declare @BaseAccPageID VarChar(Max); Declare @BaseRoid VarChar(Max); -- Check if AccPageID has a valid extension If ((PatIndex('%.[A-Z]', @AccPageID) > 0) And ((Select Count(1) From vwRofstData_RofstBaseRoids Where BaseAccPageID = @AccPageID) <= 0)) Set @BaseAccPageID = Left(@AccPageID, Len(@AccPageID)-2); Else Set @BaseAccPageID = @AccPageID; -- Use the AccPageID to get the BaseRoid Select @BaseRoid = rb.BaseRoid From vwRofstData_RofstBaseRoids rb Where rb.RofstID = @RofstID And rb.BaseAccPageID = @BaseAccPageID; -- Then use the BaseRoid to lookup the Ro Child Object Select rc.ROFstID, rc.dbiID, rc.ID, rc.ParentID, rc.[type], rc.title, rc.roid, rc.appid, rc.[value], rc.AccPageID From vwRofstData_RofstChildren rc Where rc.RofstID = @RofstID And rc.roid = @BaseRoid; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetChildByAccPageID] Error on Creation' GO IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_RofstDataGetBaseAccPageKeys]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP Procedure [dbo].[vesp_RofstDataGetBaseAccPageKeys]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /*****************************************************************************? Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 08/11/2022 Description: Gets all the Base AccPageKeys that end with a "." period followed by an Alpha Character (A through Z) ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstDataGetBaseAccPageKeys] ( @RofstID int ) With Execute as Owner As Begin Select BaseAccPageID From vwRofstData_RofstBaseRoids Where BaseAccPageID like '%.[A-Z]'; Return; End GO IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstDataGetBaseAccPageKeys] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstDataGetBaseAccPageKeys] Error on Creation' GO If Exists(Select * From sys.objects Where type = 'FN' And object_id = OBJECT_ID('[dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults]')) Drop Function [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults]; SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 06/21/2022 -- Description: Replaces any legacy applicability tags with the default value -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceLegacyTagsWithDefaults](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @DefaultValue VarChar(Max) = ''; Declare @StartTagIndex Int; Declare @EndTagIndex Int; Declare @StartTagValue VarChar(Max); Declare @StartValIndex Int; Declare @EndValIndex Int; Declare @TagName VarChar(Max); Declare @LegacyTagNames VarChar(Max) = 'U-ID,U-NUMBER,U-NAME,U-TEXT,U-OTHERID,U-OTHERNUMBER,U-OTHERNAME,U-OTHERTEXT'; -- Make Sure all tag instances are upper case & Remove any internal spaces Set @RetVal = dbo.vefn_RofstDataCleanUnitInfoTags(@Values, 0); -- Remove any instances of double "}" that have a spaces between them ex: "} }" Set @RetVal = Replace(@RetVal, '} }', '}}'); Declare LegacyTags_Cursor Cursor Fast_Forward For Select '{' + x.ListValue + '{' as 'TagName' From [dbo].[vefn_ParseStringListToTable](@LegacyTagNames, ',') x Open LegacyTags_Cursor Fetch Next From LegacyTags_Cursor Into @TagName While (@@FETCH_STATUS = 0) Begin -- Get Start/End Index of Tag Set @StartTagIndex = PatIndex('%' + @TagName + '%', @RetVal); Set @EndTagIndex = PatIndex('%}}%', @RetVal); While (@StartTagIndex > 0) Begin Set @StartTagValue = SubString(@RetVal, @StartTagIndex, (@EndTagIndex - @StartTagIndex) + 2); Set @StartValIndex = PatIndex('%=%', @StartTagValue); Set @EndValIndex = PatIndex('%}%', @StartTagValue); Set @DefaultValue = SubString(@StartTagValue, @StartValIndex + 1, (@EndValIndex - @StartValIndex) - 1); Set @RetVal = Replace(@RetVal, @StartTagValue, @DefaultValue); Set @StartTagIndex = PatIndex('%' + @TagName + '%', @RetVal); Set @EndTagIndex = PatIndex('%}}%', @RetVal); End -- While (@StartTagIndex > 0) Fetch Next From LegacyTags_Cursor Into @TagName End Close LegacyTags_Cursor; Deallocate LegacyTags_Cursor; Return @RetVal; END Go IF (@@Error = 0) PRINT 'Procedure Creation: [vefn_RofstDataReplaceLegacyTagsWithDefaults] Succeeded' ELSE PRINT 'Procedure Creation: [vefn_RofstDataReplaceLegacyTagsWithDefaults] Error on Creation' GO /* ========================================================================================================== End: B2022-088: [JPR] Find Doc Ro button not working in Word Sections B2022-098: [JPR] ROs not being resolved in Word Sections ========================================================================================================== */ /* ========================================================================================================== Start: B2022-104: SearchReferenced Objects in PROMS is not finding any results ========================================================================================================== */ If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesRODbIDDeleteStatusContentID') Drop Index [IX_tblROUsagesRODbIDDeleteStatusContentID] on [dbo].[tblROUsages] Go CREATE NONCLUSTERED INDEX [IX_tblROUsagesRODbIDDeleteStatusContentID] ON [dbo].[tblROUsages] ([RODbID],[DeleteStatus]) INCLUDE ([ContentID],[ROID]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] GO IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesRODbIDDeleteStatusContentID] Succeeded' ELSE PRINT 'Index Creation: [IX_tblROUsagesRODbIDDeleteStatusContentID] Error on Creation' GO If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataFormatRoidKey' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataFormatRoidKey] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 08/19/2022 -- Description: Cleans/Formats the specified roid key, with its return value ext if applicable -- ========================================================================================== Create Function [dbo].[vefn_RofstDataFormatRoidKey](@Roid VarChar(25), @Check16Digits bit = 0) Returns VarChar(Max) With Execute As Owner Begin Declare @RoidKey VarChar(Max) = ''; -- Trim Start/End and Replace Any Nulls with Empty Spaces ('') Set @RoidKey = dbo.vefn_Clean(@Roid, 1, null); -- Check if Roid is Null/Empty If (Len(@RoidKey) > 0) Begin -- Roid Cleanup / Consistency Checks Set @RoidKey = Upper(@RoidKey); -- Force Upper Case Set @RoidKey = Replace(@RoidKey, '', ''); -- Replace Any Abbreviated Unit Info Tags Set @RoidKey = Replace(@RoidKey, ' ', ''); -- Remove Any Internal Spaces -- Check if Roid is a Unit Info Tag or RO Child If (Not @RoidKey like '= 1) Set @RoidKey = Left(@RoidKey, 12) + '0041'; -- Check Roid Extension (If Any) and Fix Default Extension ifusing the old format "0000" If (Len(@RoidKey) = 16 And Right(@RoidKey, 4) = '0000') Set @RoidKey = Left(@RoidKey, 12) + '0041'; End End Return @RoidKey; End Go IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataFormatRoidKey] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataFormatRoidKey] Error on Creation' GO If Exists(Select * From sys.objects Where type = 'TF' And object_id = OBJECT_ID('[dbo].[FindRoUsages]')) Drop Function [dbo].[FindRoUsages]; Go SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- ========================================================================================== -- Author: Rich Mark -- Create Date: 01/01/2018 -- Description: Returns the ContentIDs for any Procedure/WordSections that are currently -- using any RO values in the @ROSearchString -- -- Modified: [2022.08.19 - Jake Ropar] -- Moved the logic for the Roid case statements into a new function [dbo].[vefn_RofstDataFormatRoidKey]. -- This standard roid formatting logic can now be utilized by any other objects in the database -- like (Views/Procs/FUnctions/etc.) to ensure consistency when comparing roids. -- I also added additional logic to support any (16) digit roids that are still using the older default -- roid ext of "0000" instead of the new standard format "0041". -- -- Examples: 1) Declare @ROSearchString VarChar(Max) = '1:000200000089'; Select * From FindRoUsages(ROSearchString); -- 2) Select * From FindRoUsages('1:000200000089'); -- ========================================================================================== Create Function [dbo].[FindRoUsages](@ROSearchString VarChar(Max)) Returns @Results Table ( ContentID int Primary Key ) With Execute as Owner Begin Insert Into @Results Select ru.ContentID as 'ContentID' From ROUsages ru with (NoLock) inner join vefn_SplitROSearch(@ROSearchString) rr on rr.RODbID = ru.RODbID And dbo.vefn_RofstDataFormatRoidKey(ru.Roid, 1) like rr.Roid + '%' Collate SQL_Latin1_General_CP1_CI_AS Union Select e.ContentID as 'ContentID' From Entries e with (NoLock) inner join DROUsages ru with (NoLock) on ru.DocID = e.DocID inner join vefn_SplitROSearch(@ROSearchString) rr on rr.RODbID = ru.RODbID And dbo.vefn_RofstDataFormatRoidKey(ru.Roid, 1) like rr.Roid + '%' Collate SQL_Latin1_General_CP1_CI_AS Option (Recompile); Return; End Go IF (@@Error = 0) PRINT 'Function Creation: [FindRoUsages] Succeeded' ELSE PRINT 'Function Creation: [FindRoUsages] Error on Creation' GO /* ========================================================================================================== End: B2022-104: SearchReferenced Objects in PROMS is not finding any results ========================================================================================================== */ /* ========================================================================================================== Begin: B2022-121: RO values containing curly braces around values that are NOT multi return values do not resolved in Word Sections. ========================================================================================================== */ IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_RofstChildInsert]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP Procedure [dbo].[vesp_RofstChildInsert]; GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: Inserts the RO Child object and associated return values ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstChildInsert] ( @RofstID Int, @ID Int, @ParentID Int, @dbiID Int, @type Int, @title VarChar(Max), @roid VarChar(50), @appid VarChar(Max) = null, @value VarChar(Max) = null ) With Execute as Owner As Begin Declare @BaseAccPageID VarChar(Max) = null; Declare @DefaultValues VarChar(Max); Declare @RoidExt VarChar(Max); Declare @AccPageExt VarChar(Max); -- Create Rofst Child/Group Record --> [Roid = (12) Digits] Insert Into RofstChild (RofstID, ID, ParentID, dbiID, [type], title, roid, appid, [value]) Values (@RofstID, @ID, @ParentID, @dbiID, @type, @title, @roid, @appid, @value); -- Check for appid, if exists, then insert the default value for each return type if multi-value If (Len(@appid) > 0) Begin -- Get Accessory Page ID Select @BaseAccPageID = dbo.vefn_RofstDataCleanUnitInfoTags(Concat(d.dbiAP, '-', @appid), 1) From RofstDatabase d with (NoLock) Where d.RofstID = @RofstID And d.dbiID = @dbiID; Select @DefaultValues = dbo.vefn_RofstDataReplaceVars(@value); If (PatIndex('%=%', @DefaultValues) > 0) Begin -- Insert Rofst Default Values (Multi-Values) --> [Roid = (16) Digits] Select @DefaultValues = Replace(@DefaultValues, '{', ''); With ChildrenValues as ( Select x.ListPosition as 'OffsetIndex', Case When (PatIndex('%=%', x.ListValue) > 0) Then Right(x.ListValue, Len(x.ListValue)-PatIndex('%=%', x.ListValue)) Else x.ListValue End as 'DefaultValue' From [dbo].[vefn_ParseStringListToTable](@DefaultValues, '}') x Where Len(x.ListValue) > 0 ) Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, re.RoidExt) as 'roid', Case When (Len(RTrim(LTrim(cv.DefaultValue))) > 0 ) Then dbo.vefn_RofstDataCleanUnitInfoTags(cv.DefaultValue, 0) Else '[TBD]' End as 'value', Concat(@BaseAccPageID, '.', re.AccPageExt) as 'AccPageID' From ChildrenValues cv inner join vwRofstData_RofstExtensions re on re.Offset = cv.OffsetIndex Order By cv.OffsetIndex Asc End Else Begin -- Insert Rofst Default Value (Single Value) --> [Roid = (16) Digits] Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, re.RoidExt) as 'roid', Case When (Len(RTrim(LTrim(@DefaultValues))) > 0 ) Then dbo.vefn_RofstDataCleanUnitInfoTags(@DefaultValues, 0) Else '[TBD]' End as 'value', Concat(@BaseAccPageID, '.', re.AccPageExt) as 'AccPageID' From vwRofstData_RofstExtensions re Where re.Offset = 1; End End -- (Len(@appid) > 0) Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstChildInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstChildInsert] Error on Creation' GO If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceVars' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceVars] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/25/2022 -- Description: Replaces Any Variables and returns the rest of the value string -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceVars](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @EqualsIndex Int; Declare @EndIndex Int; Declare @NameValPairStartIndex Int; Declare @NameValPairEndIndex Int; Declare @VarPair VarChar(Max); Declare @VarName VarChar(Max); Declare @VarValue VarChar(Max); -- Replace Any "" Tags with the Default Value first Select @RetVal = dbo.vefn_RofstDataReplaceApplTagsWithDefaults(@Values); -- Replace Any Legacy Applicability Tags with the Default Value second Select @RetVal = dbo.vefn_RofstDataReplaceLegacyTagsWithDefaults(@RetVal); If (PatIndex('%=%', @RetVal) > 0) Begin If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); While(@NameValPairStartIndex > 0 And @NameValPairStartIndex < @EndIndex) Begin -- Get Name Value Pair [ex. {EGS=1214}] Set @VarPair = SubString(@RetVal, @NameValPairStartIndex, (@NameValPairEndIndex - @NameValPairStartIndex) + 1); -- Remove Name Value Pair From Return Val Set @RetVal = Replace(@RetVal, @VarPair, ''); -- Get Variable Name and Value Set @EqualsIndex = PatIndex('%=%', @VarPair); If (@EqualsIndex > 0) Begin Set @VarName = SubString(@VarPair, 2, @EqualsIndex - 2); Set @VarValue = SubString(@VarPair, @EqualsIndex + 1, Len(@VarPair) - @EqualsIndex - 1); Set @VarName = Concat('{', @VarName, '}'); -- Replace All Occurences Set @RetVal = Replace(@RetVal, @VarName, @VarValue); End -- Get Updated Index Values If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); End -- End While(@ReplaceVarEndTagIndex > 0) End Return @RetVal; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Error on Creation' GO /* ========================================================================================================== End: B2022-121: RO values containing curly braces around values that are NOT multi return values do not resolved in Word Sections. ========================================================================================================== */ /* ========================================================================================================== Begin: B2022-124: [JPR] Blank RO Values (All Spaces) printing as ? ========================================================================================================== */ If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataReplaceVars' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataReplaceVars] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 3/25/2022 -- Description: Replaces Any Variables and returns the rest of the value string -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataReplaceVars](@Values VarChar(Max)) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = ''; Declare @EqualsIndex Int; Declare @EndIndex Int; Declare @NameValPairStartIndex Int; Declare @NameValPairEndIndex Int; Declare @VarPair VarChar(Max); Declare @VarName VarChar(Max); Declare @VarValue VarChar(Max); -- Replace Any "" Tags with the Default Value first Select @RetVal = dbo.vefn_RofstDataReplaceApplTagsWithDefaults(@Values); -- Replace Any Legacy Applicability Tags with the Default Value second Select @RetVal = dbo.vefn_RofstDataReplaceLegacyTagsWithDefaults(@RetVal); If (PatIndex('%=%', @RetVal) > 0) Begin If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = DataLength(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); While(@NameValPairStartIndex > 0 And @NameValPairStartIndex < @EndIndex) Begin -- Get Name Value Pair [ex. {EGS=1214}] Set @VarPair = SubString(@RetVal, @NameValPairStartIndex, (@NameValPairEndIndex - @NameValPairStartIndex) + 1); -- Remove Name Value Pair From Return Val Set @RetVal = Replace(@RetVal, @VarPair, ''); -- Get Variable Name and Value Set @EqualsIndex = PatIndex('%=%', @VarPair); If (@EqualsIndex > 0) Begin Set @VarName = SubString(@VarPair, 2, @EqualsIndex - 2); Set @VarValue = SubString(@VarPair, @EqualsIndex + 1, Len(@VarPair) - @EqualsIndex - 1); Set @VarName = Concat('{', @VarName, '}'); -- Replace All Occurences Set @RetVal = Replace(@RetVal, @VarName, @VarValue); End -- Get Updated Index Values If (PatIndex('%{{A%', @RetVal) > 0) Set @EndIndex = PatIndex('%{{A%', @RetVal); Else Set @EndIndex = Len(@RetVal) -1; Set @NameValPairStartIndex = PatIndex('%{%', @RetVal); Set @NameValPairEndIndex = PatIndex('%}%', @RetVal); End -- End While(@ReplaceVarEndTagIndex > 0) End Return @RetVal; END GO IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataReplaceVars] Error on Creation' GO If Exists(SELECT * FROM sys.objects Where name = 'vefn_RofstDataCleanUnitInfoTags' AND type in (N'FN')) DROP FUNCTION [dbo].[vefn_RofstDataCleanUnitInfoTags] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ -- ========================================================================================== -- Author: Jake Ropar -- Create Date: 06/21/2022 -- Description: Removes any legacy legacy unit info variables and fixes older applicability tags -- ========================================================================================== CREATE FUNCTION [dbo].[vefn_RofstDataCleanUnitInfoTags](@Values VarChar(Max), @RemoveUnitInfoVars bit = 0) Returns VarChar(Max) WITH EXECUTE AS OWNER AS BEGIN Declare @RetVal VarChar(Max) = @Values; If (Len(@RetVal) > 0) Begin Set @RetVal = dbo.vefn_Clean(@Values, 1, null); -- Make Sure all tag/var instances are upper case & Remove any internal spaces Set @RetVal = Replace(@RetVal, 'U-OTHER TEXT', 'U-OTHERTEXT'); Set @RetVal = Replace(@RetVal, 'U-OTHER NUMBER', 'U-OTHERNUMBER'); Set @RetVal = Replace(@RetVal, 'U-OTHER NAME', 'U-OTHERNAME'); Set @RetVal = Replace(@RetVal, 'U-OTHER ID', 'U-OTHERID'); Set @RetVal = Replace(@RetVal, '', ''); If (@RemoveUnitInfoVars > 0) Begin -- Remove any Unit Info Variables Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); Set @RetVal = Replace(@RetVal, '', ''); End End Return @RetVal; END Go IF (@@Error = 0) PRINT 'Function Creation: [vefn_RofstDataCleanUnitInfoTags] Succeeded' ELSE PRINT 'Function Creation: [vefn_RofstDataCleanUnitInfoTags] Error on Creation' GO If Exists(SELECT * FROM sys.objects Where name = 'vesp_RofstChildInsert' AND type in (N'P')) DROP PROCEDURE [dbo].[vesp_RofstChildInsert] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2020 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ /* ========================================================================================================== Author: Jake Ropar Create Date: 03/24/2022 Description: Inserts the RO Child object and associated return values ========================================================================================================== */ Create Procedure [dbo].[vesp_RofstChildInsert] ( @RofstID Int, @ID Int, @ParentID Int, @dbiID Int, @type Int, @title VarChar(Max), @roid VarChar(50), @appid VarChar(Max) = null, @value VarChar(Max) = null, @missingDefaultValue VarChar(Max) = null ) With Execute as Owner As Begin Declare @BaseAccPageID VarChar(Max) = null; Declare @DefaultValues VarChar(Max); Declare @RoidExt VarChar(Max); Declare @AccPageExt VarChar(Max); -- Default missing value if Null (Null values not allowed for the [value] field in the RofstDefaultValue table if (DataLength(IsNull(@missingDefaultValue, '')) <= 0) Set @missingDefaultValue = '[TBD]'; -- Create Rofst Child/Group Record --> [Roid = (12) Digits] Insert Into RofstChild (RofstID, ID, ParentID, dbiID, [type], title, roid, appid, [value]) Values (@RofstID, @ID, @ParentID, @dbiID, @type, @title, @roid, @appid, @value); -- Check for appid, if exists, then insert the default value for each return type if multi-value If (Len(@appid) > 0) Begin -- Get Accessory Page ID Select @BaseAccPageID = dbo.vefn_RofstDataCleanUnitInfoTags(Concat(d.dbiAP, '-', @appid), 1) From RofstDatabase d with (NoLock) Where d.RofstID = @RofstID And d.dbiID = @dbiID; Select @DefaultValues = dbo.vefn_RofstDataReplaceVars(@value); If (PatIndex('%=%', @DefaultValues) > 0) Begin -- Insert Rofst Default Values (Multi-Values) --> [Roid = (16) Digits] Select @DefaultValues = Replace(@DefaultValues, '{', ''); With ChildrenValues as ( Select x.ListPosition as 'OffsetIndex', Case When (PatIndex('%=%', x.ListValue) > 0) Then Right(x.ListValue, Len(x.ListValue)-PatIndex('%=%', x.ListValue)) Else x.ListValue End as 'DefaultValue' From [dbo].[vefn_ParseStringListToTable](@DefaultValues, '}') x Where Len(x.ListValue) > 0 ) Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, re.RoidExt) as 'roid', Case When (DataLength(cv.DefaultValue) > 0) Then dbo.vefn_RofstDataCleanUnitInfoTags(cv.DefaultValue, 0) Else @missingDefaultValue End as 'value', Concat(@BaseAccPageID, '.', re.AccPageExt) as 'AccPageID' From ChildrenValues cv inner join vwRofstData_RofstExtensions re on re.Offset = cv.OffsetIndex Order By cv.OffsetIndex Asc End Else Begin -- Insert Rofst Default Value (Single Value) --> [Roid = (16) Digits] Insert Into RofstDefaultValue (RofstID, roid, [value], AccPageID) Select @RofstID as 'RofstID', Concat(@roid, re.RoidExt) as 'roid', Case When (DataLength(@DefaultValues) > 0) Then dbo.vefn_RofstDataCleanUnitInfoTags(@DefaultValues, 0) Else @missingDefaultValue End as 'value', Concat(@BaseAccPageID, '.', re.AccPageExt) as 'AccPageID' From vwRofstData_RofstExtensions re Where re.Offset = 1; End End -- (Len(@appid) > 0) Return; End Go IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_RofstChildInsert] Succeeded' ELSE PRINT 'Procedure Creation: [vesp_RofstChildInsert] Error on Creation' GO /* ========================================================================================================== End: B2022-124: [JPR] Blank RO Values (All Spaces) printing as ? ========================================================================================================== */ ----------------------------------------------------------------------------- /* --------------------------------------------------------------------------- | ADD New Code Before this Block | | Change Date and Description | --------------------------------------------------------------------------- */ ----------------------------------------------------------------------------- -- Rebuild / Reorganize All Indexes exec [dbo].[vesp_UtilityCheckIndexes]; IF (@@Error = 0) PRINT 'Running vesp_UtilityCheckIndexes Succeeded' ELSE PRINT 'Running vesp_UtilityCheckIndexes Failed to Execute' GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetSQLCodeRevision]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [vesp_GetSQLCodeRevision]; GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2022 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_GetSQLCodeRevision] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block BEGIN TRANSACTION -- Change information in the next line when you are done set nocount on DECLARE @RevDate varchar(255) DECLARE @RevDescription varchar(255) set @RevDate = '10/03/2022 2:00 PM' set @RevDescription = 'B2022-124: [JPR] Blank RO Values (All Spaces) printing as ?' Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription 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 'StoredProcedure [vesp_GetSQLCodeRevision] Succeeded' ELSE PRINT 'StoredProcedure [vesp_GetSQLCodeRevision] Error on Creation' go Exec vesp_GetSQLCodeRevision;