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 ) -- 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) 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 -- 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 -- 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) 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) 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 ) WITH EXECUTE AS OWNER AS begin select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) -- 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 ) 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) 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?') 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 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 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @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(3)) 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @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(3)) 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(3)) 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 ) 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'[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_GetUnitPrefix]; GO /* 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 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE function [dbo].[vefn_GetUnitPrefix](@config varchar(MAX)) returns varchar(MAX) begin declare @Xml xml set @Xml = cast(@config as xml) declare @UnitPrefix varchar(MAX) set @UnitPrefix = (select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') 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'[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_DocVersionSplit]; GO /* select * from vefn_DocVersionSplit('1,4') select * from vefn_DocVersionSplit(null) select * from vefn_DocVersionSplit('') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ 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 VersionID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config) from DocVersions where ItemID is not null else Insert into @IDs Select ID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config) from vefn_SplitInt(@DocVersionList,',') as T join DocVersions DV on 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'[vefn_SiblingAndChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_SiblingAndChildrenItems]; GO /* select * from vefn_SiblingAndChildrenItems('','3-') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(10),@UnitPrefix varchar(MAX)) 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], [UnitPrefix]) 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 + 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 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' else '' end else '' end PPath, 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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', 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 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 + 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(3)) end Path, 0, POrdinalPath, POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), UnitPrefix 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 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 ( ItemID int Primary Key ) WITH EXECUTE AS OWNER BEGIN insert into @Results select Distinct I.ItemID 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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(3)) 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 I.ItemID in(select ItemID 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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(3)) 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 D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) OR (@CaseSensitive = 0 AND D.DocAscii 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 */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - 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 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_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) order by DvPath,OrdinalPath 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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(3)) 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 RU.roid 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 DU.roid 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 RU.ROID 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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(3)) 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 1000) 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 1000) 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' 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(3)) --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) when 5 then @DelimStep +'RNO' + @DelimStep when 7 then @DelimStep +'Table' + @DelimStep else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) 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(3)) 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(3)) + 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(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO`' when 7 then '`Table`' else '`' + cast(ItemCount + 0 as varchar(3)) 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(3)) else case P.FromType when 1 then 'PRC`' + cast(ItemCount + 0 as varchar(3)) when 2 then '`SEC`' + cast(ItemCount + 0 as varchar(3)) when 3 then '`Caution`' + cast(ItemCount + 0 as varchar(3)) when 4 then '`Note`' + cast(ItemCount + 0 as varchar(3)) when 5 then '`RNO' when 7 then '`Table' else '`' + cast(ItemCount + 0 as varchar(3)) 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_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('1','turbine-driven',0,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 IF @CaseSensitive = 0 -- Not Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx) 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 (D.DocAscii 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,','))))) END ELSE BEGIN IF @CaseSensitive = 1 -- Case Sensitive BEGIN insert into @FoundContents select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchStringx) C where (.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchStringx Collate SQL_Latin1_General_CP1_CS_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 (D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_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 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) RETURN END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildItemsRange Succeeded' ELSE PRINT 'TableFunction Creation: vefn_ChildItemsRange Error on Creation' GO /****** Object: StoredProcedure [vefn_ChildrenItems] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) DROP FUNCTION [vefn_ChildrenItems]; 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 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 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 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) 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 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 where Level > 0) OR RangeID in(select ItemID from Itemz where Level > 0)) AND FromID not in(Select ContentID from ItemZ) 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 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 in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz)) AND FromID not in(Select ContentID from ItemZ) 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_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) RETURN @FormatID END END GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_GetInheritedFormat Succeeded' ELSE PRINT 'ScalarFunction Creation: vefn_GetInheritedFormat Error on Creation' GO /****** Object: StoredProcedure [vefn_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: StoredProcedure [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 ) 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 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 [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 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 UPDATE NN set NN.NewContentID = CC.ContentID From Contents CC Join @Children NN on NN.ContentID = CC.Type AND CC.DTS = @DTS and CC.UserID = @UserID -- Reset the Type column in the Contents table with the Type column from the original Records. UPDATE CC set CC.Type = CC2.Type From Contents CC Join @Children NN on NN.NewContentID = CC.ContentID Join Contents CC2 on NN.ContentID = CC2.ContentID -- Contents are done -- SELECT * From Contents where DTS = @DTS and UserID = @UserID -- <<< Copy 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 >>> 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 INSERT INTO [Items] ([PreviousID],[ContentID],[DTS],[UserID]) SELECT II.[PreviousID], -- Leave the PreviousID as is for now NN.NewContentID, @DTS, @UserID from @Children NN join Items II on II.ContentID = NN.ContentID -- Update the @Children with the NewItemIDs UPDATE NN set NN.NewItemID = II.ItemID From Items II Join @Children NN on NN.NewContentID = II.ContentID AND II.DTS = @DTS and II.UserID = @UserID DECLARE @NewItemID int SELECT @NewItemID = NewItemID FROM @Children WHERE ItemID = @StartItemID UPDATE NN SET NN.[NewFormatID] = CC.[FormatID] FROM @Children NN Join vefn_ChildItemsRange(@NewItemID,@NewItemID,@DestFormatID) CC ON NN.NewItemID = CC.ItemID -- The @Children table is now complete --SELECT * From @Children -- Update the PreviousID in the new Item rows, to the new ItemIDs based upon the old ItemIDs Update II Set II.[PreviousID] = NN.NewItemID from Items II Join @Children NN on NN.ItemID = II.PreviousID AND II.DTS = @DTS and II.UserID = @UserID -- Get the new ItemIDs based upon the old ItemIDs SELECT @NewStartItemID = NewItemID from @Children where ItemID = @StartItemID --SELECT @NewEndItemID = NewItemID from @Children where ItemID = @EndItemID -- Set the PreviousID for the starting Item to null temporarily. -- This will be adjusted based upon where the step is inserted. Update Items Set PreviousID = null where ItemID = @NewStartItemID -- Items are done --SELECT * From Items where DTS = @DTS and UserID = @UserID -- <<< Copy Parts >>> INSERT INTO [Parts] ([ContentID],[FromType],[ItemID],[DTS],[UserID]) Select NNF.NewContentID,[FromType],NNT.NewItemID, @DTS, @UserID from Parts PP JOIN @Children NNF on PP.ContentID = NNF.ContentID JOIN @Children NNT on PP.ItemID = NNT.ItemID -- Parts are done -- SELECT * From Parts where DTS = @DTS and UserID = @UserID -- <<< Copy Annotations >>> INSERT INTO [Annotations] ([ItemID],[TypeID],[RtfText],[SearchText],[Config],[DTS],[UserID]) Select NewItemID, TypeID, RtfText, SearchText, Config, @DTS, @UserID from Annotations AA Join @Children NN on AA.ItemID = NN.ItemID -- Annotations are done -- SELECT * From Annotations where DTS = @DTS and UserID = @UserID -- <<< Copy Documents and Entries>>> -- logic to create Entries for Library Documents INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID]) SELECT NN.[NewContentID],EE.[DocID],@DTS,@UserID FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') <> '' -- Logic to create new documents for any documents used that do not have 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 -- 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] -- 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) 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) G2 ON GG.ContentID = G2.ContentID WHERE Cast([Data] as varchar(max)) <> cast(G2.NewData as varchar(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 -- 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] -- -- 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 -- -- Update grid records for newly copied records to use correct TransitionIDs in the Transition tags 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 varchar(max)) <> CAST(G2.NewData as varchar(max)) SET @RowsAffected = @@RowCount END -- Add 'Verification Required' AnnotationType DECLARE @typeID int SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required' IF(@typeID IS NULL) BEGIN INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian') SELECT @typeID = SCOPE_IDENTITY() END -- Add "Verification Required" Annotation for each Transition whose transition format changes INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID]) SELECT NN.NewItemID, @typeID,'Verify Transition Format',@UserID FROM Transitions TR JOIN @Children NN on TR.FromID = NN.NewContentID JOIN Transitions TRO on TR.TranType = TRO.TransitionID WHERE .dbo.vefn_CompareTranFormat(NN.FormatID, NN.NewFormatID, TRO.TranType) <> 0 UPDATE TR SET TR.[TranType] = .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType) FROM Transitions TR JOIN @Children NN on TR.FromID = NN.NewContentID JOIN Transitions TRO on TR.TranType = TRO.TransitionID -- Transitions are done -- SELECT * From Transitions where DTS = @DTS and UserID = @UserID IF( @@TRANCOUNT > 0 ) COMMIT END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback EXEC vlnErrorHandler END CATCH GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: CopyItemAndChildren Succeeded' ELSE PRINT 'Procedure Creation: CopyItemAndChildren Error on Creation' GO /****** Object: StoredProcedure [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 ) 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_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(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 ) WITH EXECUTE AS OWNER AS begin select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) -- 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_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(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 ) 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) where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' 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 xyz.* from --( --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 dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' ---- 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,appl,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 --,dbo.ve_GetItemApplicability(ItemID) appl -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' ---- 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 dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' ---- 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,appl,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 --,dbo.ve_GetItemApplicability(ItemID) appl -- ,* -- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t -- inner join vefn_chronologyreport(@ProcedureItemID) r -- on t.icontentid = r.contentid ---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%' ---- where ActionDTS > procdts or dts > procdts -- ) ah --) z on y.contentid = z.contentid and y.auditid = z.auditid --) xyz -- where appl = '-1' or ',' + appl + ',' 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: 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 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 = isnull(r2.value('@Applicability','varchar(max)'),'-1') 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 if @apple = '-1' begin set @apple = '' 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) set @apple = substring(@apple,2,len(@apple)) end 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 [Relati@Parentsonship], [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 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) */ /***************************************************************************** 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) set @apple = '' select @apple = @apple + ',' + cast(id as varchar(10)) from [dbo].[vefn_ParentItems](@ItemID) cross apply vefn_SplitInt([dbo].[ve_GetItemApplicability](itemid),',') where [dbo].[ve_GetItemApplicability](itemid) != '-1' group by id having count(*) = (select count(*) from [dbo].[vefn_ParentItems](@ItemID) where [dbo].[ve_GetItemApplicability](itemid) != '-1') return substring(@apple,2,len(@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 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 >= @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_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_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], (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 where i.apple = 1 order by I.[Level] , I.[FromType], I.[Ordinal] 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 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE vesp_WillTransitionsBeValid ( @ItemID int, @NewAppl varchar(max) ) 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