Improved RO Search Performance

Improved Annotation Search Performance
Changed SQL to always do a drop and create rather than an ALTER
Changed SQL to always give a status after a CREATE
This commit is contained in:
Rich 2012-09-28 18:40:57 +00:00
parent 42b94eac97
commit d1e10d79c2

View File

@ -1,3 +1,6 @@
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemReplace]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [PasteItemReplace];
GO
/****** Object: StoredProcedure [dbo].[PasteItemReplace] Script Date: 03/20/2012 16:02:54 ******/
/*
declare @NewItemID int
@ -8,7 +11,7 @@ exec PasteItemReplace 398,397,20014,@dts,'bodine',@NewItemID output
*/
-- ItemID is item to replace
-- StartItemID is item to copy
ALTER PROCEDURE [dbo].[PasteItemReplace]
CREATE PROCEDURE [dbo].[PasteItemReplace]
(
@ItemID int=null, @StartItemID int=null,
@Type int=null, @DTS datetime, @UserID nvarchar(100),
@ -169,6 +172,8 @@ IF (@@Error = 0) PRINT 'Procedure Creation: PasteItemReplace Succeeded'
ELSE PRINT 'Procedure Creation: PasteItemReplace Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChronologyReport]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_ChronologyReport];
/****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 03/20/2012 17:50:44 ******/
SET ANSI_NULLS ON
GO
@ -179,7 +184,7 @@ GO
select * from vefn_chronologyreport(2) where type > 0 order by contentid,auditid
*/
/****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 05/18/2011 11:20:48 ******/
ALTER function [dbo].[vefn_ChronologyReport](@ProcItemID int)
CREATE function [dbo].[vefn_ChronologyReport](@ProcItemID int)
returns @Report table
(
src int,
@ -356,13 +361,16 @@ IF (@@Error = 0) PRINT 'Function: vefn_ChronologyReport Succeeded'
ELSE PRINT 'Function: vefn_ChronologyReport Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingAfter]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [PasteItemSiblingAfter];
GO
/****** Object: StoredProcedure [dbo].[PasteItemSiblingAfter] Script Date: 03/21/2012 15:25:31 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER PROCEDURE [dbo].[PasteItemSiblingAfter]
CREATE PROCEDURE [dbo].[PasteItemSiblingAfter]
(
@ItemID int=null, @StartItemID int=null, -- ItemID is destination, StartItemID is top of copy
@Type int=null, @DTS datetime, @UserID nvarchar(100),
@ -455,13 +463,16 @@ IF (@@Error = 0) PRINT 'Procedure Creation: PasteItemSiblingAfter Succeeded'
ELSE PRINT 'Procedure Creation: PasteItemSiblingAfter Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[PasteItemSiblingBefore]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [PasteItemSiblingBefore];
GO
/****** Object: StoredProcedure [dbo].[PasteItemSiblingBefore] Script Date: 03/21/2012 15:26:23 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER PROCEDURE [dbo].[PasteItemSiblingBefore]
CREATE PROCEDURE [dbo].[PasteItemSiblingBefore]
(
@ItemID int=null, @StartItemID int=null,
@Type int=null, @DTS datetime, @UserID nvarchar(100),
@ -568,6 +579,9 @@ GO
SET QUOTED_IDENTIFIER ON
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [getContentAuditsChronologyByItemID];
GO
/****** Object: StoredProcedure [getContentAuditsChronologyByItemID] ******/
/*
getContentAuditsChronologyByItemID 10154,10154,0
@ -575,7 +589,7 @@ getContentAuditsChronologyByItemID 42,42,0
getContentAuditsChronologyByItemID 9,9,0
getContentAuditsChronologyByItemID 146,146,1
*/
ALTER PROCEDURE [dbo].[getContentAuditsChronologyByItemID]
CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemID]
(
@ProcedureItemID int,
@SelectedItemID int,
@ -621,6 +635,8 @@ IF (@@Error = 0) PRINT 'StoredProcedure [getContentAuditsChronologyByItemID] Suc
ELSE PRINT 'StoredProcedure [getContentAuditsChronologyByItemID] Error on Creation'
go
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixSearchString]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
DROP FUNCTION [vefn_FixSearchString];
GO
/****** Object: UserDefinedFunction [dbo].[vefn_FixSearchString] Script Date: 03/26/2012 09:31:13 ******/
SET ANSI_NULLS ON
@ -651,7 +667,7 @@ select 17 ID,'%' ss union
select 18 ID,'C* - *' ss
) tt order by ID
*/
ALTER FUNCTION [dbo].[vefn_FixSearchString](@SearchString nvarchar(MAX))
CREATE FUNCTION [dbo].[vefn_FixSearchString](@SearchString nvarchar(MAX))
RETURNS nvarchar(MAX)
WITH EXECUTE AS OWNER
AS
@ -677,6 +693,9 @@ ELSE PRINT 'ScalerFunction [vefn_FixSearchString] Error on Creation'
go
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[restoreDeletedItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [restoreDeletedItem];
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
@ -690,7 +709,7 @@ SELECT ItemID FROM PartAudits WHERE DeleteStatus = 1
*/
ALTER PROCEDURE [dbo].[restoreDeletedItem]
CREATE PROCEDURE [dbo].[restoreDeletedItem]
(
@ItemID int,
@DeleteID int,
@ -787,6 +806,9 @@ IF (@@Error = 0) PRINT 'ScalerFunction [vefn_GetLastDelim] Succeeded'
ELSE PRINT 'ScalerFunction [vefn_GetLastDelim] Error on Creation'
go
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_tblChildItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_tblChildItems];
GO
/****** Object: UserDefinedFunction [dbo].[vefn_tblChildItems] Script Date: 03/28/2012 17:43:20 ******/
SET ANSI_NULLS ON
GO
@ -811,7 +833,7 @@ where FromID in (Select ContentID from vefn_ChildItems(@PreviousID))
AND (ToID = @ItemID or RangeID = @ItemID)
*/
ALTER FUNCTION [dbo].[vefn_tblChildItems](@ProcItemID int, @ItemID int, @IncludeDeletedChildren int)
CREATE FUNCTION [dbo].[vefn_tblChildItems](@ProcItemID int, @ItemID int, @IncludeDeletedChildren int)
RETURNS @Children TABLE
(
ItemID int PRIMARY KEY,
@ -959,6 +981,9 @@ GO
SET QUOTED_IDENTIFIER ON
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getAnnotationAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [getAnnotationAuditsChronologyByItemID];
GO
/****** Object: StoredProcedure [getAnnotationAuditsChronologyByItemID] ******/
/*
getAnnotationAuditsChronologyByItemID 13,13
@ -966,7 +991,7 @@ getAnnotationAuditsChronologyByItemID 30,8570
getAnnotationAuditsChronologyByItemID 30,8513
getAnnotationAuditsChronologyByItemID 30,8505
*/
ALTER procedure [dbo].[getAnnotationAuditsChronologyByItemID]
CREATE procedure [dbo].[getAnnotationAuditsChronologyByItemID]
(
@ProcItemID int,
@ItemID int
@ -1071,13 +1096,21 @@ begin
end
GO
IF (@@Error = 0) PRINT 'Function: vefn_GetUnitPrefix Succeeded'
ELSE PRINT 'Function: vefn_GetUnitPrefix Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_DocVersionSplit];
GO
/*
select * from vefn_DocVersionSplit('1,4')
select * from vefn_DocVersionSplit(null)
select * from vefn_DocVersionSplit('')
*/
ALTER FUNCTION [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
CREATE FUNCTION [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
RETURNS @IDs TABLE
(
VersionID int PRIMARY KEY,
@ -1101,11 +1134,21 @@ RETURN
END
GO
IF (@@Error = 0) PRINT 'Function: [vefn_DocVersionSplit] Succeeded'
ELSE PRINT 'Function: [vefn_DocVersionSplit] Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingAndChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_SiblingAndChildrenItems];
GO
/*
select * from vefn_SiblingAndChildrenItems('','3-')
*/
ALTER FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(10),@UnitPrefix varchar(MAX))
CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(10),@UnitPrefix varchar(MAX))
RETURNS @SiblingAndChildren TABLE
(
[ItemID] int PRIMARY KEY
@ -1210,7 +1253,56 @@ END
RETURN
END
GO
IF (@@Error = 0) PRINT 'Function: vefn_SiblingAndChildrenItems Succeeded'
ELSE PRINT 'Function: vefn_SiblingAndChildrenItems Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[FindAnnotations]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [FindAnnotations];
/****** Object: UserDefinedFunction [dbo].[FindAnnotations] Script Date: 09/28/2012 11:06:59 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/*
select * from [FindAnnotations]('12','',0,'')
*/
CREATE FUNCTION [dbo].[FindAnnotations](@AnnotationTypeList varchar(MAX), @SearchString varchar(MAX), @CaseSensitive int, @StepTypeList varchar(MAX))
RETURNS @Results TABLE
(
ItemID int Primary Key
)
WITH EXECUTE AS OWNER
BEGIN
insert into @Results
select Distinct I.ItemID from Items I
join Contents C on I.ContentID = C.ContentID
left Join Parts P on P.ItemID = I.ItemID
join Annotations A on A.ItemID = I.ItemID
join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID
where
(isnull(@SearchString,'')=''
OR (@CaseSensitive = 1 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
OR (@CaseSensitive = 0 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CI_AS))
AND
((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000)
or
((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))
or
(@StepTypeList like '%20040%' AND isnull(P.FromType,0) = 5)))
RETURN
END
GO
IF (@@Error = 0) PRINT 'Function: FindAnnotations Succeeded'
ELSE PRINT 'Function: FindAnnotations Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchAnnotationItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [vesp_SearchAnnotationItemAndChildren];
GO
/*
exec vesp_SearchAnnotationItemAndChildren Null,Null,'1',Null,0,"3-"
exec vesp_SearchAnnotationItemAndChildren Null,Null,'2',Null,0
@ -1219,7 +1311,7 @@ exec vesp_SearchAnnotationItemAndChildren Null,Null,'4',Null,0
exec vesp_SearchAnnotationItemAndChildren Null,Null,'5',Null,0
exec vesp_SearchAnnotationItemAndChildren Null,Null,'',Null,0
*/
ALTER PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int, @UnitPrefix nvarchar(MAX))
CREATE PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int, @UnitPrefix nvarchar(MAX))
WITH EXECUTE AS OWNER
AS
BEGIN
@ -1318,15 +1410,7 @@ select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID
join Annotations A on A.ItemID = I.ItemID
join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID
where
(isnull(@SearchString,'')=''
OR (@CaseSensitive = 1 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
OR (@CaseSensitive = 0 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CI_AS))
AND
((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000)
or
((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))
or
(@StepTypeList like '%20040%' AND IsRNO = -1)))
I.ItemID in(select ItemID from [FindAnnotations](@AnnotationTypeList, @SearchString, @CaseSensitive, @StepTypeList))
order by DvPath,OrdinalPath
OPTION (MAXRECURSION 10000)
END
@ -1337,6 +1421,9 @@ IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren
ELSE PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [vesp_SearchItemAndChildren];
GO
/*
exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,0,0,0
exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,1,0,0
@ -1361,7 +1448,7 @@ exec vesp_SearchItemAndChildren '','','PORV NEAR SG',2,0,0,0
exec vesp_SearchItemAndChildren '','','CHECK NORMAL',0,0,0,0
exec vesp_SearchItemAndChildren '','','turbine-driven',0,0,0,0
*/
ALTER PROCEDURE [dbo].[vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX),
CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX),
@SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX))
WITH EXECUTE AS OWNER
AS
@ -1481,6 +1568,9 @@ IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildren Succeeded
ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildren Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchROItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [vesp_SearchROItemAndChildren];
GO
/*
exec vesp_SearchROItemAndChildren '1,2,4','20007','1:00010000019C,0001000002AE'
exec vesp_SearchROItemAndChildren '1,2,4','','1:00010000019C,0001000002AE'
@ -1489,7 +1579,7 @@ exec vesp_SearchROItemAndChildren '1,2,4','20006','1'
exec vesp_SearchROItemAndChildren '1,2,4','20006',''
exec vesp_SearchROItemAndChildren '',Null,Null,'XXX-'
*/
ALTER PROCEDURE [dbo].[vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX))
CREATE PROCEDURE [dbo].[vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX))
WITH EXECUTE AS OWNER
AS
BEGIN
@ -1676,14 +1766,20 @@ from vefn_SiblingAndChildrenItems(@DocVersionList, @UnitPrefix) ZZ
where ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
order by DvPath,OrdinalPath
GO
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNew Succeeded'
ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNew Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[tr_tblItems_Update]') AND OBJECTPROPERTY(id,N'IsTrigger') = 1)
DROP TRIGGER [tr_tblItems_Update];
/****** Object: Trigger [dbo].[tr_tblItems_Update] Script Date: 04/25/2012 14:09:52 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/****** Object: Trigger [tr_tblItems_Update] ******/
ALTER trigger [dbo].[tr_tblItems_Update] on [dbo].[tblItems] for update as
CREATE trigger [dbo].[tr_tblItems_Update] on [dbo].[tblItems] for update as
begin
if exists (select * from inserted)
begin
@ -1833,3 +1929,181 @@ OPTION (MAXRECURSION 10000)
END
END
GO
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetROUsagesByProcedure Succeeded'
ELSE PRINT 'Procedure Creation: vesp_GetROUsagesByProcedure Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[FindRoUsages]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [FindRoUsages];
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/*
Declare @ROSearchString varchar(MAX)
set @ROSearchString='1:000200000089'
select * from FindRoUsages('1:000200000089')
*/
Create FUNCTION [dbo].[FindRoUsages](@ROSearchString varchar(Max))
RETURNS @Results TABLE
(
ContentID int Primary Key
)
WITH EXECUTE AS OWNER
BEGIN
insert into @Results
select ContentID from ROUsages RU
join vefn_SplitROSearch(@ROSearchString) RR
ON RR.RODBID = RU.RODBID and
RU.ROID like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS
UNION
select ContentID from Entries EE
Join DROUsages RU on RU.DocID = EE.DocID
join vefn_SplitROSearch(@ROSearchString) RR
ON RR.RODBID = RU.RODBID and
RU.ROID like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS
RETURN
END
GO
IF (@@Error = 0) PRINT 'Function: FindRoUsages Succeeded'
ELSE PRINT 'Function: FindRoUsages Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchROItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [vesp_SearchROItemAndChildren];
GO
/****** Object: StoredProcedure [dbo].[vesp_SearchROItemAndChildren] Script Date: 09/28/2012 09:02:50 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/*
exec vesp_SearchROItemAndChildren '1,2,4','20007','1:00010000019C,0001000002AE',''
exec vesp_SearchROItemAndChildren '1,2,4','','1:00010000019C,0001000002AE',''
exec vesp_SearchROItemAndChildren '1,2,4','20007','1:0001',''
exec vesp_SearchROItemAndChildren '1,2,4','20006','1',''
exec vesp_SearchROItemAndChildren '1,2,4','20006','',''
exec vesp_SearchROItemAndChildren '',Null,Null,'XXX-',''
exec vesp_SearchROItemAndChildren '1','','1:000200000089',''
exec vesp_SearchROItemAndChildren '1','','1:00010000019c',''
*/
CREATE PROCEDURE [dbo].[vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX))
WITH EXECUTE AS OWNER
AS
BEGIN
Declare @Delim char(1)
Set @Delim=char(7)
Declare @DelimNumber char(1)
Set @DelimNumber=char(17)
Declare @DelimStep char(1)
Set @DelimStep='.'
begin
with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID],
[pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as (
Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged]
,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged],
Cast('' as nvarchar(max)) PPath,
Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path,
0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix
FROM [Items] I
Join Contents C on C.ContentID=I.ContentID
JOIN vefn_DocVersionSplit(@DocVersionList) DV
ON I.[ItemID] = DV.[ItemID]
Union All
-- Children
select DVPath, [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]
,PATH + --''
case C.Type/10000
when 2 then
case P.FromType
when 3 then @DelimStep + 'Caution'
when 4 then @DelimStep + 'Note'
else '' end
else '' end
PPath,
--Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000
Path + case C.Type/10000
when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text
when 1 then @Delim + C.Number + @DelimNumber + C.Text
else
case P.FromType
--when 1 then 'PRC' + @Delim + cast(1 as varchar(3))
--when 2 then 'SEC' + @Delim + cast(1 as varchar(3))
when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3))
when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3))
when 5 then @DelimStep +'RNO' + @DelimStep
when 7 then @DelimStep +'Table' + @DelimStep
else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3))
end end Path,
case when P.FromType = 5 then -1 else 0 end IsRNO,
OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' ,
OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix
from Itemz Z
join Parts P on P.ContentID = Z.ContentID
join Items I on I.ItemID = P.ItemID
join Contents C on C.ContentID = I.ContentID
Union All
-- Siblings
select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
,null,null,null,null
,PPath,
--'1' +
PPath + case C.Type/10000
when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text
when 1 then @Delim + C.Number + @DelimNumber + C.Text
else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3))
end Path, 0,
POrdinalPath,
POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix
from Itemz Z
join Items I on I.PreviousID = Z.ItemID
join Contents C on C.ContentID = I.ContentID
--where Z.[Level] > 0
)
select DvPath, Path, 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
left join Entries E on C.ContentID = E.ContentID
left join Documents D on E.DocID = D.DocID
where
I.ContentID in(select ContentID from FindROUsages(@ROSearchString))
AND
((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000)
or
((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))
or
(@StepTypeList like '%20040%' AND IsRNO = -1)))
order by DvPath,OrdinalPath
OPTION (MAXRECURSION 10000)
END
END
GO
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Succeeded'
ELSE PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Error on Creation'
GO