From 173dd85ccfd486173283985786a420e997de0b77 Mon Sep 17 00:00:00 2001 From: Rich Date: Mon, 5 Nov 2012 21:55:27 +0000 Subject: [PATCH] Added "OPTION (MAXRECURSION 10000) to all recursive queries. Remove Change Manager stored procedure "getItemAuditsByItemID" --- PROMS/DataLoader/PROMS2010.SQL | 56 +- PROMS/DataLoader/PROMSFixes.Sql | 1379 +++++++++++++++++++++++++++++- PROMS/DataLoader/PROMStoAPPR.sql | 1 + PROMS/DataLoader/PROMStoCM.sql | 2 +- 4 files changed, 1387 insertions(+), 51 deletions(-) diff --git a/PROMS/DataLoader/PROMS2010.SQL b/PROMS/DataLoader/PROMS2010.SQL index ceece8dc..1752c837 100644 --- a/PROMS/DataLoader/PROMS2010.SQL +++ b/PROMS/DataLoader/PROMS2010.SQL @@ -8896,6 +8896,7 @@ select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousI 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 @@ -8965,40 +8966,6 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getItemAudits Succeeded' ELSE PRINT 'Procedure Creation: getItemAudits Error on Creation' GO -/****** 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 - -/***************************************************************************** - 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 - SELECT - [AuditID], - [ItemID], - [PreviousID], - [ContentID], - [DTS], - [UserID], - [DeleteStatus] - FROM [ItemAudits] - WHERE ItemID = @ItemID - ORDER BY AuditID DESC - 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 - /****** Object: StoredProcedure [getItemNextAndChildren] ******/ IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getItemNextAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getItemNextAndChildren]; @@ -9033,6 +9000,7 @@ select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousI 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 @@ -14545,6 +14513,7 @@ Union All where Z.Direction >= 0 ) Select @Count = Count(*) from Itemz +OPTION (MAXRECURSION 10000) return @Count END; GO -- Display the status of Proc creation @@ -14591,6 +14560,7 @@ Insert into @HighLevelStepTransitions select [ParentID],ItemID,Ordinal,dbo.ve_GetPath([ItemID]) Path from Itemz Order by ParentID,ItemID +OPTION (MAXRECURSION 10000) RETURN END GO @@ -14653,6 +14623,7 @@ where (Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) > 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 @@ -14780,6 +14751,7 @@ Union All where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz +OPTION (MAXRECURSION 10000) RETURN END GO @@ -14831,6 +14803,7 @@ 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 @@ -14885,6 +14858,7 @@ Union All where Z.[Level] > 0 ) insert into @Children select ItemID, ContentID from Itemz +OPTION (MAXRECURSION 10000) RETURN END GO @@ -15097,6 +15071,7 @@ 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 @@ -15199,6 +15174,7 @@ select ItemID [FromItemID], case when TT.ToID in(select ItemID from Itemz) then 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 @@ -15259,6 +15235,7 @@ select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[Range 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 @@ -15314,6 +15291,7 @@ select ItemID [FromItemID], case when TT.ToID in(select ItemID from Itemz) then 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 @@ -15373,6 +15351,7 @@ select TransitionID, FromID, TT.TranType, TT.ToID, TT.RangeID, CAST(TT.Config as 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 @@ -16250,7 +16229,7 @@ BEGIN where Z.FormatID is null ) Select @FormatID = FormatID from Itemz ZZ Where FormatID is not null - + OPTION (MAXRECURSION 10000) RETURN @FormatID END END @@ -16487,6 +16466,7 @@ select [ParentID],ItemID,dbo.ve_GetPath([ItemID]) ,(Select Count(*) from Transit ,(Select count(*) from vefn_FindExternalTransitions(ItemID)) ExternalTransitions ,(Select count(*) from vefn_FindInternalTransitions(ItemID)) InternalTransitions from Itemz +OPTION (MAXRECURSION 10000) RETURN END GO @@ -16908,6 +16888,7 @@ Union All join Items I on I.PreviousID = Z.ItemID ) insert into @SiblingChildren select ItemID, ContentID from Itemz +OPTION (MAXRECURSION 10000) RETURN END GO @@ -16953,6 +16934,7 @@ Union All join Items I on I.PreviousID = Z.ItemID ) insert into @Siblings select ItemID, ContentID from Itemz +OPTION (MAXRECURSION 10000) RETURN END GO @@ -17141,6 +17123,7 @@ 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 @@ -17569,6 +17552,7 @@ select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousI 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 @@ -17615,6 +17599,7 @@ 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 @@ -17735,6 +17720,7 @@ select I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousI 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 diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index 3cb5ba63..fb895c5f 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -754,28 +754,28 @@ AS declare @oldPreviousID int DECLARE @NextID int DECLARE @ContentID int -declare @fromtype int + declare @fromtype int IF @Level = 0 BEGIN - SET @NextID = @CurrentID - SELECT @PreviousID = PreviousID FROM Items WHERE ItemID = @CurrentID - END + 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 @NextID = ItemID FROM Items WHERE PreviousID = @CurrentID + SET @PreviousID = @CurrentID + END SELECT @ContentID = dbo.[ve_GetPartContentID](@ItemID) -select @fromtype = dbo.[ve_GetPartFromType](@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 + 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 + 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) @@ -787,17 +787,17 @@ update tblparts set deletestatus = 0, itemid = @itemid where contentid = @conten UPDATE tblROUsages SET DeleteStatus = 0 WHERE deletestatus = @deleteid --ContentID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) UPDATE tblTransitions SET DeleteStatus = 0 WHERE deletestatus = @deleteid --FromID IN (SELECT ContentID FROM ContentAudits WHERE DeleteStatus = @DeleteID) IF @NextID IS NOT NULL BEGIN - UPDATE Items SET PreviousID = @ItemID WHERE ItemID = @NextID + UPDATE Items SET PreviousID = @ItemID WHERE ItemID = @NextID IF @ContentID IS NOT NULL BEGIN - UPDATE Parts SET ItemID = @ItemID WHERE ItemID = @NextID and ContentID = @ContentID + UPDATE Parts SET ItemID = @ItemID WHERE ItemID = @NextID and ContentID = @ContentID --print 'old code' - END END + END --else -- begin --update parts set itemid = @itemid where contentid = @contentid and fromtype = @fromtype -- end - RETURN +RETURN go -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: restoreDeletedItem Succeeded' @@ -1011,6 +1011,7 @@ BEGIN where Z.[Level] > 0 ) insert into @Children select distinct ItemID, ContentID, DeleteStatus, ProcDTS, Path, OrdinalPath from Itemz + OPTION (MAXRECURSION 10000) END RETURN end @@ -2693,3 +2694,1351 @@ GO 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 + diff --git a/PROMS/DataLoader/PROMStoAPPR.sql b/PROMS/DataLoader/PROMStoAPPR.sql index b93cb93d..113cd76c 100644 --- a/PROMS/DataLoader/PROMStoAPPR.sql +++ b/PROMS/DataLoader/PROMStoAPPR.sql @@ -2764,6 +2764,7 @@ select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[Range 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 diff --git a/PROMS/DataLoader/PROMStoCM.sql b/PROMS/DataLoader/PROMStoCM.sql index e326d7f5..8544e2ff 100644 --- a/PROMS/DataLoader/PROMStoCM.sql +++ b/PROMS/DataLoader/PROMStoCM.sql @@ -1338,7 +1338,7 @@ end itemtype 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