71 lines
5.6 KiB
Transact-SQL
71 lines
5.6 KiB
Transact-SQL
USE [VEPROMS]
|
||
GO
|
||
/****** Object: UserDefinedFunction [dbo].[vefn_FindAffectedTransitions] Script Date: 10/20/2010 06:57:24 ******/
|
||
SET ANSI_NULLS ON
|
||
GO
|
||
SET QUOTED_IDENTIFIER ON
|
||
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
|
||
*/
|
||
|
||
ALTER 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
|
||
RETURN
|
||
END
|