72 lines
2.5 KiB
Transact-SQL
72 lines
2.5 KiB
Transact-SQL
Declare @TopSections Table
|
|
(
|
|
VersionID int,
|
|
ProcID int,
|
|
ItemID int Primary Key,
|
|
ContentID int,
|
|
Level int,
|
|
FormatID int
|
|
);
|
|
with Itemz([VersionID], ProcID, [ItemID], [ContentID], [Level]) as
|
|
(Select DV.VersionID, DV.ItemID ProcID, [I].[ItemID], [I].[ContentID], 0
|
|
FROM [Items] I
|
|
JOIN vefn_DocVersionSplit('') DV
|
|
ON I.[ItemID] = DV.[ItemID]
|
|
Union All
|
|
-- Children
|
|
select Z.VersionID, Z.ProcID, I.[ItemID], I.[ContentID], Z.Level+1
|
|
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
|
|
Where Type < 20000
|
|
Union All
|
|
-- Siblings
|
|
select Z.VersionID, case when z.ProcID = z.ItemID then I.ItemID else Z.ProcID end ProcID, I.[ItemID], I.[ContentID], Z.Level
|
|
from Itemz Z
|
|
join Items I on I.PreviousID = Z.ItemID
|
|
)
|
|
insert into @TopSections
|
|
select ZZ.VersionID, ZZ.ProcID, ZZ.[ItemID], ZZ.[ContentID], ZZ.[Level], [FormatID]
|
|
from ItemZ ZZ
|
|
Join vefn_GetVersionFormatItems('') VI ON ZZ.ItemID=VI.ItemID
|
|
Where Level > 0
|
|
OPTION (MAXRECURSION 10000)
|
|
|
|
DECLARE @Procedures TABLE (
|
|
VersionID int,
|
|
ProcID int primary key,
|
|
PContentID int ,
|
|
SectionStart int
|
|
)
|
|
Insert into @Procedures
|
|
Select VersionID, ItemId, ContentID, xProcedure.value('@SectionStart','int') SectionStart From
|
|
(Select VI.VersionID,VI.ItemID,VI.ContentID,Cast(Config as xml) xConfig
|
|
from VEFN_GetVersionItems('') VI
|
|
Join Contents CC ON CC.ContentID = VI.ContentID
|
|
where type = 0) T1
|
|
outer apply xConfig.nodes('//Procedure') tProcedure(xProcedure)
|
|
|
|
Select PP.*, dbo.ve_getShortPath(SectionStart) PathToSectionStart, TS.ItemID, TS.FormatID, TS.Level
|
|
,case when PP.SectionStart is null THEN 'None'
|
|
When TS.ItemID is null THEN 'NotSection'
|
|
When TS.ProcID != PP.ProcID then 'NotInProc'
|
|
When Level > 1 then 'NotTopLevel'
|
|
else 'Good' end SectionStartStatus
|
|
from @Procedures PP
|
|
Left Join @TopSections TS ON PP.SectionStart = TS.ItemID
|
|
|
|
Select VersionID,GrandParentName,ParentName,FolderName,[Good],[None],[NotInProc],[NotSection],[NotTopLevel]
|
|
FROM (Select VN.*, PP.ProcID
|
|
,case when PP.SectionStart is null THEN 'None'
|
|
When TS.ItemID is null THEN 'NotSection'
|
|
When TS.ProcID != PP.ProcID then 'NotInProc'
|
|
When Level > 1 then 'NotTopLevel'
|
|
else 'Good' end SectionStartStatus
|
|
from @Procedures PP
|
|
Left Join @TopSections TS ON PP.SectionStart = TS.ItemID
|
|
Join VEFN_GetVersionNames() VN ON VN.VersionID = PP.VersionID) P1
|
|
PIVOT(COUNT(ProcID) FOR SectionStartStatus IN ( [Good],[None],[NotInProc],[NotSection],[NotTopLevel]))
|
|
AS AH2
|
|
Order By VersionID
|
|
|