- Added DeleteItemAndChildren Stored Procedure
- Added DeleteItemAndChildrenTest Stored Procedure - Added getExternalTransitions Stored Procedure - Added getExternalTransitionsToChildren Stored Procedure
This commit is contained in:
parent
7bc7129faf
commit
fd709f3fb7
@ -2221,6 +2221,295 @@ IF (@@Error = 0) PRINT 'Procedure Creation: deleteItem Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: deleteItem Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [DeleteItemAndChildren] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[DeleteItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [DeleteItemAndChildren];
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[DeleteItemAndChildren]
|
||||
(
|
||||
@ItemID int,
|
||||
@UserID AS VARCHAR(100)
|
||||
)
|
||||
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
|
||||
)
|
||||
DECLARE @ExternalTrans TABLE
|
||||
(
|
||||
[FromItemID] int,
|
||||
[TransitionID] [int] NOT NULL,
|
||||
[FromID] [int] NOT NULL,
|
||||
[ToID] [int] NOT NULL,
|
||||
[RangeID] [int] NOT NULL,
|
||||
[Config] [nvarchar](max) NULL
|
||||
)
|
||||
SET NOCOUNT ON
|
||||
SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID
|
||||
SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID
|
||||
SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID)
|
||||
SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID)
|
||||
SET @Path = [dbo].[ve_GetShortPath](@ItemID)
|
||||
|
||||
IF @ExternalCount > 0 AND @NextItemID is null
|
||||
BEGIN
|
||||
RAISERROR ('###Cannot Delete Item###Step %d has External Transitions and has no next step - (%s)',16,1,@ItemID,@Path)
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF @ExternalChildCount > 0
|
||||
BEGIN
|
||||
RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path)
|
||||
RETURN
|
||||
END
|
||||
-- Get list of Children
|
||||
INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID)
|
||||
-- UPDATE PreviousID in Items WHERE ItemID = @NextItemID
|
||||
UPDATE Items SET PreviousID = @PreviousItemID WHERE ItemID=@NextItemID
|
||||
-- UPDATE DocVersion
|
||||
UPDATE DocVersions SET ItemID=@NextItemID where ItemID = @ItemID
|
||||
-- UPDATE Parts
|
||||
IF @NextItemID is not NULL -- Remove Part Record
|
||||
BEGIN
|
||||
UPDATE PARTS SET ItemID = @NextItemID where ItemID=@ItemID
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
DELETE FROM Parts WHERE ItemID=@ItemID
|
||||
END
|
||||
-- Get external transitions that point to the specified Item
|
||||
-- These will need to be adjusted to point to the next Item.
|
||||
INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID);
|
||||
DECLARE @typeID int -- AnnotationType
|
||||
SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required'
|
||||
IF(@typeID IS NULL)
|
||||
BEGIN
|
||||
INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian')
|
||||
SELECT @typeID = SCOPE_IDENTITY()
|
||||
END
|
||||
-- Add 'Verification Required' annotions for transtions that point to different step
|
||||
INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID])
|
||||
SELECT ItemID, @typeID,'Verify Transition Destination',@UserID
|
||||
FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans)
|
||||
-- Update content records for the transitions
|
||||
Update CC
|
||||
Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@NextItemID)
|
||||
From CONTENTS CC
|
||||
JOIN Transitions TT ON TT.FromID = CC.ContentID
|
||||
WHERE TransitionID in(Select TransitionID from @ExternalTrans)
|
||||
-- Update transitions that point to @ItemID to Point to @NextItemID
|
||||
UPDATE TRANSITIONS
|
||||
SET ToID = case when ToID = @ItemID then @NextItemID else ToID END,
|
||||
RangeID = case when RangeID = @ItemID then @NextItemID else RangeID END
|
||||
WHERE TransitionID in(Select TransitionID from @ExternalTrans)
|
||||
-- Delete Annotations for @ItemID and children
|
||||
DELETE from Annotations where ItemID in(Select ItemID from @Children)
|
||||
-- Delete Details associated with @ContentID and children
|
||||
DELETE from Details where ContentID in(Select ContentID from @Children)
|
||||
-- Delete Entries associated with @ContentID and children
|
||||
DELETE from Entries where ContentID in(Select ContentID from @Children)
|
||||
-- Delete ROUsages associated with @ContentID and children
|
||||
DELETE from RoUsages where ContentID in(Select ContentID from @Children)
|
||||
-- Delete ZTransitions records associated with @ContentID and children
|
||||
DELETE FROM ZTransitions where TransitionID
|
||||
in(SELECT TransitionID from Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID)
|
||||
-- Delete Transitions associated with @ContentID and children
|
||||
DELETE FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID
|
||||
-- Delete Parts associated with @ContentID and children
|
||||
DELETE from Parts where ContentID in(Select ContentID from @Children)
|
||||
-- Delete ZContents associated with @ContentID and children
|
||||
DELETE from ZContents where ContentID in(Select ContentID from @Children)
|
||||
-- Disconnect Items from Each Other
|
||||
DELETE from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null
|
||||
-- Disconnect Items to be deleted from each other
|
||||
Update Items set PreviousID = null where ItemID in (Select ItemID from @Children) and PreviousID Is Not Null
|
||||
-- Delete Item Records
|
||||
DELETE from Items where ItemID in(Select ItemID from @Children)
|
||||
-- DELETE Contents
|
||||
DELETE from Contents where ContentID in(Select ContentID from @Children)
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
END TRY
|
||||
BEGIN CATCH -- Catch Block
|
||||
IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level
|
||||
ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback
|
||||
EXEC vlnErrorHandler
|
||||
END CATCH
|
||||
GO
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: DeleteItemAndChildren Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: DeleteItemAndChildren Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [DeleteItemAndChildrenTest] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[DeleteItemAndChildrenTest]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [DeleteItemAndChildrenTest];
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[DeleteItemAndChildrenTest]
|
||||
(
|
||||
@ItemID int,
|
||||
@UserID AS VARCHAR(100)
|
||||
)
|
||||
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
|
||||
)
|
||||
DECLARE @ExternalTrans TABLE
|
||||
(
|
||||
[FromItemID] int,
|
||||
[TransitionID] [int] NOT NULL,
|
||||
[FromID] [int] NOT NULL,
|
||||
[ToID] [int] NOT NULL,
|
||||
[RangeID] [int] NOT NULL,
|
||||
[Config] [nvarchar](max) NULL
|
||||
)
|
||||
SET NOCOUNT ON
|
||||
SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID
|
||||
SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID
|
||||
SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID)
|
||||
SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID)
|
||||
SET @Path = [dbo].[ve_GetShortPath](@ItemID)
|
||||
|
||||
IF @ExternalCount > 0 AND @NextItemID is null
|
||||
BEGIN
|
||||
PRINT '--->Cannot delete step ' + @Path + '.' + char(13) + '<===> It has External Transitions and has no next step'
|
||||
SELECT dbo.ve_GetShortPath(FromItemID) FromPath,
|
||||
dbo.ve_GetShortPath(ToID) ToPath FROM vefn_FindExternalTransitions(@ItemID)
|
||||
WHERE NOT EXISTS (SELECT * FROM Items WHERE PreviousID = @ItemID)
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF @ExternalChildCount > 0
|
||||
BEGIN
|
||||
PRINT '---> Cannot delete step ' + @Path + '.' + char(13) + '<===> It has External Transitions to it''s children'
|
||||
SELECT dbo.ve_GetShortPath(FromItemID) FromPath,
|
||||
dbo.ve_GetShortPath(ToID) ToPath FROM vefn_FindExternalChildTransitions(@ItemID)
|
||||
RETURN
|
||||
END
|
||||
|
||||
PRINT '@Path = ''' + @Path + ''''
|
||||
PRINT '@ItemID = ' + cast(@ItemID as varchar(10))
|
||||
PRINT '@ContentID = ' + isnull(cast(@ContentID as varchar(10)),'{NULL}')
|
||||
PRINT '@NextItemID = ' + isnull(cast(@NextItemID as varchar(10)),'{NULL}')
|
||||
PRINT '@PreviousItemID = ' + isnull(cast(@PreviousItemID as varchar(10)),'{NULL}')
|
||||
PRINT '@ExternalCount = ' + isnull(cast(@ExternalCount as varchar(10)),'{NULL}')
|
||||
PRINT '@ExternalChildCount = ' + isnull(cast(@ExternalChildCount as varchar(10)),'{NULL}')
|
||||
|
||||
PRINT '---' + char(13) +'Preparing to delete step ' + @Path+ char(13) + '---'
|
||||
-- Get list of Children
|
||||
INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID)
|
||||
PRINT 'Children'
|
||||
SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath, ContentID,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath FROM @Children
|
||||
|
||||
-- UPDATE PreviousID in Items WHERE ItemID = @NextItemID
|
||||
PRINT 'UPDATE Items Next'
|
||||
SELECT ItemID, [dbo].[ve_GetShortPath](@NextItemID) PathOfNextItem,[dbo].[ve_GetShortPath](PreviousID) PathOfDeletedItem, [dbo].[ve_GetShortPath](@PreviousItemID) NewPreviousPath
|
||||
FROM Items WHERE ItemID=@NextItemID
|
||||
-- UPDATE DocVersion
|
||||
PRINT 'UPDATE DocVersions ItemID'
|
||||
SELECT [dbo].[ve_GetShortPath](ItemID) MyPath, [dbo].[ve_GetShortPath](@NextItemID) NewPath
|
||||
FROM DocVersions WHERE ItemID=@ItemID
|
||||
SELECT VersionID, [dbo].[ve_GetShortPath](@NextItemID) NewPath
|
||||
FROM DocVersions WHERE ItemID=@ItemID
|
||||
-- UPDATE Parts
|
||||
IF @NextItemID is not NULL -- Remove Part Record
|
||||
BEGIN
|
||||
PRINT 'UPDATE Parts'
|
||||
SELECT ItemID,@NextItemID,[dbo].[ve_GetShortPath](ItemID) ItemPath, [dbo].[ve_GetShortPath](@NextItemID) NewItemPath
|
||||
FROM Parts WHERE ItemID=@ItemID
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'DELETE Parts'
|
||||
SELECT ContentID,FromType,[dbo].[ve_GetShortPath](ItemID) ItemPath FROM Parts WHERE ItemID=@ItemID
|
||||
END
|
||||
-- Get external transitions that point to the specified Item
|
||||
-- These will need to be adjusted to point to the next Item.
|
||||
INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID);
|
||||
DECLARE @typeID int -- AnnotationType
|
||||
SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required'
|
||||
IF(@typeID IS NULL)
|
||||
BEGIN
|
||||
PRINT 'ADD Verification Required'
|
||||
INSERT INTO [AnnotationTypes] ([Name],[UserID]) VALUES ('Verification Required','Volian')
|
||||
SELECT @typeID = SCOPE_IDENTITY()
|
||||
END
|
||||
-- Get list of External Transitions
|
||||
|
||||
PRINT 'UPDATE Transitions - ADD Annotations'
|
||||
SELECT [dbo].[ve_GetShortPathFromContentID](FromID)FromPath
|
||||
,[dbo].[ve_GetShortPath](ToID) ToPath
|
||||
,case when ToID = @ItemID then [dbo].[ve_GetShortPath](@NextItemID) else [dbo].[ve_GetShortPath](ToID) END NewToPath
|
||||
,[dbo].[ve_GetShortPath](RangeID) RangePath
|
||||
,case when RangeID = @ItemID then [dbo].[ve_GetShortPath](@NextItemID) else [dbo].[ve_GetShortPath](RangeID) END NewRangePath
|
||||
FROM Transitions
|
||||
WHERE TransitionID IN(Select TransitionID from @ExternalTrans)
|
||||
-- Delete Annotations for @ItemID and children
|
||||
PRINT 'DELETE Annotations'
|
||||
SELECT AnnotationID, [dbo].[ve_GetShortPath](ItemID) ItemPath from Annotations where ItemID in(Select ItemID from @Children)
|
||||
-- Delete Details associated with @ContentID and children
|
||||
PRINT 'DELETE Details'
|
||||
SELECT [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Details where ContentID in(Select ContentID from @Children)
|
||||
-- Delete Entries associated with @ContentID and children
|
||||
PRINT 'DELETE Entries'
|
||||
SELECT ContentID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Entries where ContentID in(Select ContentID from @Children)
|
||||
-- Delete ROUsages associated with @ContentID and children
|
||||
PRINT 'DELETE ROUsages'
|
||||
SELECT ROUsageID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from RoUsages where ContentID in(Select ContentID from @Children)
|
||||
-- Delete Transitions associated with @ContentID and children
|
||||
PRINT 'DELETE Transitions'
|
||||
SELECT TransitionID, [dbo].[ve_GetShortPathFromContentID](FromID)FromPath ,[dbo].[ve_GetShortPath](ToID) ToPath
|
||||
,[dbo].[ve_GetShortPath](RangeID) RangePath FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID
|
||||
-- Delete Parts associated with @ContentID and children
|
||||
PRINT 'DELETE Parts'
|
||||
SELECT ContentID, FromType,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Parts where ContentID in(Select ContentID from @Children)
|
||||
-- Delete ZContents associated with @ContentID and children
|
||||
PRINT 'DELETE XContents'
|
||||
SELECT ContentID,[dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from ZContents where ContentID in(Select ContentID from @Children)
|
||||
-- Disconnect Items from Each Other
|
||||
PRINT 'DISCONNECT Items from each other'
|
||||
SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath, [dbo].[ve_GetShortPath](PreviousID) PreviousPath from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null
|
||||
-- Delete Item Records
|
||||
PRINT 'DELETE Items'
|
||||
SELECT ItemID, [dbo].[ve_GetShortPath](ItemID) ItemPath from Items where ItemID in(Select ItemID from @Children)
|
||||
-- DELETE Contents
|
||||
PRINT 'DELETE Contents'
|
||||
SELECT ContentID, [dbo].[ve_GetShortPathFromContentID](ContentID) ContentPath from Contents where ContentID in(Select ContentID from @Children)
|
||||
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: DeleteItemAndChildrenTest Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: DeleteItemAndChildrenTest Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [deleteMembership] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[deleteMembership]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [deleteMembership];
|
||||
@ -4795,6 +5084,78 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getEntry Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: getEntry Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [getExternalTransitions] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getExternalTransitions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [getExternalTransitions];
|
||||
GO
|
||||
|
||||
/*
|
||||
exec getExternalTransitions 4984
|
||||
*/
|
||||
|
||||
CREATE PROCEDURE [dbo].[getExternalTransitions]
|
||||
(
|
||||
@ItemID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
SELECT
|
||||
TT.[TransitionID],
|
||||
TT.[FromID],
|
||||
TT.[ToID],
|
||||
TT.[RangeID],
|
||||
TT.[TranType],
|
||||
TT.[Config],
|
||||
TT.[DTS],
|
||||
TT.[UserID],
|
||||
TT.[LastChanged],
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount]
|
||||
from transitions tt
|
||||
join items ii on tt.FromID = ii.ContentID
|
||||
where TT.ToID = @ItemID AND TT.FromID not in(select ContentID from vefn_childItems(@ItemID))
|
||||
RETURN
|
||||
GO
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: getExternalTransitions Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: getExternalTransitions Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [getExternalTransitionsToChildren] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getExternalTransitionsToChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [getExternalTransitionsToChildren];
|
||||
GO
|
||||
|
||||
/*
|
||||
exec getExternalTransitionsToChildren 9392
|
||||
*/
|
||||
|
||||
CREATE PROCEDURE [dbo].[getExternalTransitionsToChildren]
|
||||
(
|
||||
@ItemID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
SELECT
|
||||
TT.[TransitionID],
|
||||
TT.[FromID],
|
||||
TT.[ToID],
|
||||
TT.[RangeID],
|
||||
TT.[TranType],
|
||||
TT.[Config],
|
||||
TT.[DTS],
|
||||
TT.[UserID],
|
||||
TT.[LastChanged],
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount]
|
||||
FROM vefn_childItems(@ItemID) II
|
||||
JOIN Transitions TT on TT.ToID = II.ItemID AND TT.ToID <> @ItemID
|
||||
where TT.FromID not in(select ContentID from vefn_childItems(@ItemID))
|
||||
RETURN
|
||||
GO
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: getExternalTransitionsToChildren Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: getExternalTransitionsToChildren Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [getFigure] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getFigure]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [getFigure];
|
||||
@ -9810,7 +10171,7 @@ Union All
|
||||
--where Z.[Level] > 0
|
||||
)
|
||||
Insert into @HighLevelStepTransitions
|
||||
select [ParentID],ItemID,Ordinal,dbo.ve_GetPath([ItemID]) Path,(Select Count(*) from Transitions where ToID=ItemID OR RangeID=ItemID ) TransCount
|
||||
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
|
||||
|
Loading…
x
Reference in New Issue
Block a user