Improved performance of the SQL Stored procedures related to DeleteItemAndChildren.

Added output so that status can be seen as a procedure is deleted.
This commit is contained in:
Rich
2015-08-12 22:14:44 +00:00
parent c3f58a6df7
commit 312b0e4e2d
3 changed files with 101 additions and 54 deletions

View File

@@ -3551,32 +3551,19 @@ RETURNS @Children TABLE
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
)
DECLARE @ChildList AS TABLE
(
ItemID INT PRIMARY KEY,
ContentID INT,
Level INT
)
INSERT INTO @ChildList SELECT * FROM vefn_ChildItemz(@ItemID)
insert into @Children
select ItemID [FromItemID], case when TT.ToID in(select ItemID from Itemz) then TT.ToID else TT.RangeID end [ToID]
select ItemID [FromItemID], case when TT.ToID in(select ItemID from @ChildList) then TT.ToID else TT.RangeID end [ToID]
from Transitions TT
join Items II on II.ContentID=TT.FromID
where (ToID in(select ItemID from Itemz where Level > 0) OR RangeID in(select ItemID from Itemz where Level > 0))
AND FromID not in(Select ContentID from ItemZ)
where (ToID in(select ItemID from @ChildList where Level > 0) OR RangeID in(select ItemID from @ChildList where Level > 0))
AND FromID not in(Select ContentID from @ChildList)
OPTION (MAXRECURSION 10000)
RETURN
END
@@ -3612,32 +3599,19 @@ RETURNS @Children TABLE
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
)
DECLARE @ChildList AS TABLE
(
ItemID INT PRIMARY KEY,
ContentID INT,
Level INT
)
INSERT INTO @ChildList SELECT * FROM vefn_ChildItemz(@ItemID)
insert into @Children
select ItemID [FromItemID], TT.[TransitionID], TT.[FromID], TT.[ToID], TT.[RangeID], TT.[Config]
from Transitions TT
join Items II on II.ContentID=TT.FromID
where (ToID in(select ItemID from Itemz) OR RangeID in(select ItemID from Itemz))
AND FromID not in(Select ContentID from ItemZ)
where (ToID in(select ItemID from @ChildList) OR RangeID in(select ItemID from @ChildList))
AND FromID not in(Select ContentID from @ChildList)
OPTION (MAXRECURSION 10000)
RETURN
END
@@ -3647,6 +3621,56 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindExternalTransitions Suc
ELSE PRINT 'TableFunction Creation: vefn_FindExternalTransitions Error on Creation'
GO
/****** Object: StoredProcedure [vefn_ChildItemz] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildItemz]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_ChildItemz];
GO
/*
Select * from vefn_ChildItemz(185)
*/
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2015 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
CREATE FUNCTION [dbo].[vefn_ChildItemz](@ItemID int)
RETURNS @Children TABLE
(
ItemID int PRIMARY KEY,
ContentID int,
Level int
)
WITH EXECUTE AS OWNER
AS
BEGIN
with Itemz([Level], [ItemID], [ContentID]) as (
Select 0 [Level], [ItemID], [ContentID]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
select [Level] + 1, I.[ItemID], I.[ContentID]
from Itemz Z
join Parts P on P.ContentID = Z.ContentID
join Items I on I.ItemID = P.ItemID
-- Siblings
Union All
select [Level] , I.[ItemID], I.[ContentID]
from Itemz Z
join Items I on I.PreviousID = Z.ItemID
where Z.[Level] > 0
)
insert into @Children select ItemID, ContentID, Level from Itemz
OPTION (MAXRECURSION 10000)
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildItemz Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_ChildItemz Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FindInternalTransitions] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindInternalTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_FindInternalTransitions];
@@ -8930,12 +8954,9 @@ BEGIN TRY -- Try Block
SET NOCOUNT ON
SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID
SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID
SET @Path = [dbo].[ve_GetShortPath](@ItemID)
SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID) where rangeid = toid or toid = @ItemID
SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID)
SELECT @ItemType = Type FROM Contents Where ContentID = @ContentID
SET @Path = [dbo].[ve_GetShortPath](@ItemID)
-- Check to see if External Transitions point to the current item
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)
@@ -8948,6 +8969,9 @@ BEGIN TRY -- Try Block
RETURN
END
SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID)
SELECT @ItemType = Type FROM Contents Where ContentID = @ContentID
-- Check to see if External Transitions point to the current item
IF @ExternalChildCount > 0
BEGIN
RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path)
@@ -10995,4 +11019,4 @@ END CATCH
IF (@@Error = 0) PRINT 'Procedure Creation: addROImage Succeeded'
ELSE PRINT 'Procedure Creation: addROImage Error on Creation'
GO
PRINT '20150722 Fixed AddROImage for WCN'
PRINT '20150808 Improved performance for delete procedure'