Faster Search

This commit is contained in:
Rich 2009-05-19 19:51:31 +00:00
parent 291f354893
commit c6372a3f46

View File

@ -1,4 +1,4 @@
USE VEPROMS
/****** Object: StoredProcedure [addAnnotation] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addAnnotation]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [addAnnotation];
@ -8794,7 +8794,7 @@ CREATE FUNCTION [dbo].[ve_GetChildCount] (@ItemID int) RETURNS int WITH EXECUTE
declare @Count int;
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as (
Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
FROM [VEPROMS].[dbo].[Items]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
@ -8869,7 +8869,9 @@ with ContentZ(AllContents,PreviousID,HasChildren) as (
where PP.ContentID=@ContentID and PP.FromType = @FromType
Union All
--
Select ZZ.AllContents + '.' + cast(II.ContentID as varchar(max)) AllContents,II.ItemID PreviousID, case when Exists(select ItemID from Items where PreviousID = II.ItemID) then 1 else 0 end HasChildren
Select ZZ.AllContents + '.' + cast(II.ContentID as varchar(max)) AllContents,II.ItemID PreviousID, case when Exists(select ItemID from Items where PreviousID = II.ItemID) then 1 else 0 end
HasChildren
from Items II
Join ContentZ ZZ on II.PreviousID = ZZ.PreviousID
)
@ -9036,7 +9038,7 @@ CREATE FUNCTION [dbo].[ve_GetSiblingCount] (@ItemID int) RETURNS int WITH EXECUT
declare @Count int;
with Itemz([Direction], [ItemID], [PreviousID]) as (
Select 0 Direction,[ItemID], [PreviousID]
FROM [VEPROMS].[dbo].[Items]
FROM [Items]
where [ItemID]=@ItemID
-- Siblings Previous
Union All
@ -9114,6 +9116,54 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_AnnotationTypeSplit Succeed
ELSE PRINT 'TableFunction Creation: vefn_AnnotationTypeSplit Error on Creation'
GO
/****** Object: StoredProcedure [vefn_ChildrenItems] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_ChildrenItems];
GO
/*
select * from Transitions
where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184)))
AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184)))
*/
CREATE FUNCTION [dbo].[vefn_ChildrenItems](@ItemID int, @ParentID int)
RETURNS @Children TABLE
(
ItemID int PRIMARY KEY,
ContentID int
)
AS
BEGIN
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as (
Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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.[ParentID],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
)
insert into @Children select ItemID, ContentID from Itemz
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_ChildrenItems Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_ChildrenItems Error on Creation'
GO
/****** Object: StoredProcedure [vefn_DocVersionSplit] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_DocVersionSplit];
@ -9150,6 +9200,328 @@ IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_DocVersionSplit Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_DocVersionSplit Error on Creation'
GO
/****** Object: StoredProcedure [vefn_DVContent] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_DVContent]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_DVContent];
GO
/*
select contentID from vefn_DVContent('1')
*/
CREATE FUNCTION [dbo].[vefn_DVContent](@DocVersionList varchar(MAX))
RETURNS @DVContents TABLE
(
ContentID int PRIMARY KEY
)
AS
BEGIN
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as (
Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged]
FROM [Items]
where [ItemID] in (select [ItemID] from vefn_DocVersionSplit(@DocVersionList))
Union All
-- Children
select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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.[ParentID],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
)
insert into @DVContents select distinct ContentID from Itemz
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_DVContent Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_DVContent Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FindAffectedTransitions] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindAffectedTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_FindAffectedTransitions];
GO
/*
Select FromID,.dbo.ve_GetPath(FromID),ToID,dbo.ve_GetPath(ToID) from vefn_FindAffectedTransitions(185)
*/
CREATE FUNCTION [dbo].[vefn_FindAffectedTransitions](@ItemID int)
RETURNS @Children TABLE
(
FromID int,
ToID int
)
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 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [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] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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
)
insert into @Children
select ItemID [FromID], case when TT.ToID in(select ItemID from Itemz) 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) OR RangeID in(select ItemID from Itemz))
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindAffectedTransitions Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_FindAffectedTransitions Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FindContentText] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindContentText]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_FindContentText];
GO
/*
SELECT * From vefn_FindContentText('1','%RCP%')
*/
CREATE FUNCTION [dbo].[vefn_FindContentText](
@DocVersionList nvarchar(MAX)
,@SearchString varchar(MAX))
RETURNS @FoundContents TABLE
(
ContentID int PRIMARY KEY
,Type int
,Text varchar(max)
)
AS
BEGIN
IF(ISNULL(@DocVersionList,'')='')
BEGIN
INSERT INTO @FoundContents -- Do a case insensitive search
select ContentID,Type,Text from contents
where [Text] like @SearchString Collate SQL_Latin1_General_CP1_CI_AS
END
ELSE
BEGIN
INSERT INTO @FoundContents -- Do a case insensitive search
select ContentID,Type,Text from contents
where [ContentID] in (select [ContentID] from vefn_DVContent(@DocVersionList))
AND [Text] like @SearchString Collate SQL_Latin1_General_CP1_CI_AS
END
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindContentText Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_FindContentText Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FindExternalTransitions] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindExternalTransitions]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_FindExternalTransitions];
GO
/*
Select * from vefn_FindExternalTransitions(185)
*/
CREATE FUNCTION [dbo].[vefn_FindExternalTransitions](@ItemID int)
RETURNS @Children TABLE
(
FromID int,
ToID int
)
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 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [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] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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
)
insert into @Children
select ItemID [FromID], case when TT.ToID in(select ItemID from Itemz) 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) OR RangeID in(select ItemID from Itemz))
AND FromID not in(Select ContentID from ItemZ)
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindExternalTransitions Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_FindExternalTransitions 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];
GO
/*
Select * from vefn_FindInternalTransitions(185)
*/
CREATE FUNCTION [dbo].[vefn_FindInternalTransitions](@ItemID int)
RETURNS @Children TABLE
(
FromID int,
ToID int
)
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 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [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] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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
)
insert into @Children
select ItemID [FromID], case when TT.ToID in(select ItemID from Itemz) 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) OR RangeID in(select ItemID from Itemz))
AND FromID in(Select ContentID from ItemZ)
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindInternalTransitions Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_FindInternalTransitions Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FindText] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FindText]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_FindText];
GO
CREATE FUNCTION [dbo].[vefn_FindText](
@DocVersionList nvarchar(MAX)
,@SearchString varchar(MAX)
,@CaseSensitive as int
,@IncludeLinks as int
,@IncludeRtfFormatting as int
,@IncludeSpecialCharacters as int
,@StepTypeList varchar(MAX))
RETURNS @FoundContents TABLE
(
ContentID int PRIMARY KEY
)
AS
BEGIN
Declare @SearchString2 nvarchar(200)
Set @SearchString2 = case when @CaseSensitive = 2 then Cast(@SearchString as nvarchar(200)) else 'IGNORE_FULL_TEXT_SEARCH' end
Set @SearchString = .dbo.vefn_FixSearchString(@SearchString)
IF isnull(@SearchString,'')=''
BEGIN
insert into @FoundContents
select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C
where(dbo.vefn_AllSections(C.Type)>=10000)
or
(dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))
END
ELSE
IF @CaseSensitive = 0 -- Not Case Sensitive
BEGIN
insert into @FoundContents
select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchString) C
where
(.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) 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,',')))))
UNION
select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C
join Entries E on C.ContentID = E.ContentID
join Documents D on E.DocID = D.DocID
where
(D.DocAscii 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,',')))))
END
ELSE
BEGIN
IF @CaseSensitive = 1 -- Case Sensitive
BEGIN
insert into @FoundContents
select C.ContentID from vefn_FindContentText(@DocVersionList,@SearchString) C
where
(.dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
AND ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))))
UNION
select C.ContentID from (select * from Contents where ContentID in(select ContentID from vefn_DVContent(@DocVersionList))) C
join Entries E on C.ContentID = E.ContentID
join Documents D on E.DocID = D.DocID
where
(D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
AND
((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) or
((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))))
END
ELSE -- @CaseSensitive = 2 -- FullText Search
BEGIN
insert into @FoundContents
select C.ContentID from Contents C
left join Entries E on C.ContentID = E.ContentID
left join Documents D on E.DocID = D.DocID
where
(CONTAINS(C.text, @SearchString2) OR CONTAINS(D.DocAscii, @SearchString2))
AND
((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000)
or
((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,',')))))
END
END
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_FindText Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_FindText Error on Creation'
GO
/****** Object: StoredProcedure [vefn_FirstLink] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FirstLink]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
DROP FUNCTION [vefn_FirstLink];
@ -9325,6 +9697,172 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_RemoveExtraText Succeeded'
ELSE PRINT 'ScalarFunction Creation: vefn_RemoveExtraText Error on Creation'
GO
/****** Object: StoredProcedure [vefn_SiblingAndChildrenItems] ******/
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('1') II
join
*/
CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(10))
RETURNS @SiblingAndChildren TABLE
(
[ItemID] int PRIMARY KEY
, [DVPath] nvarchar(max)
, [Path] nvarchar(max)
, [Level] int
, [FromType] int
, [Ordinal] int
, [ParentID] int
, [PreviousID] int
, [ContentID] int
, [DTS] datetime
, [UserID] nvarchar(100)
, [pContentID] int
, [pDTS] datetime
, [pUserID] nvarchar(100)
, [IsRNO] int
-- , [PPath] nvarchar(max)
-- , [POrdinalPath] nvarchar(max)
, [OrdinalPath] nvarchar(max)
)
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([ItemID], [DVPath], [Level], [ParentID], [Ordinal], [PreviousID], [FromType], [ContentID], [DTS], [UserID],[pContentID],
[pDTS],[pUserID],PPath, [Path], [IsRNO], [POrdinalPath], [OrdinalPath]) as (
Select [I].[ItemID], DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID]
,0 as [pContentID],[I].[DTS] As [pDTS], [I].[UserID] As [pUserID],
Cast('' as nvarchar(max)) [PPath],
Cast(Case when C.Type < 20000 then @Delim + 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]
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 I.[ItemID], DVPath, [Level] + 1,Z.ItemID,0, I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],
P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID]
,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 C.Type/10000
when 0 then @Delim +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('000' + Cast(P.FromType as varchar(4)), 4) + '-' ,
OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001'
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 I.[ItemID], DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID]
,null,null,null,
PPath,
--'1' +
PPath + case C.Type/10000
when 0 then @Delim + 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('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5)
from Itemz Z
join Items I on I.PreviousID = Z.ItemID
join Contents C on C.ContentID = I.ContentID
--where Z.[Level] > 0
)
insert into @SiblingAndChildren
select I.[ItemID], [DvPath], [Path], I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],
[pContentID],[pDTS],[pUserID],[IsRNO]/*,[PPath],[POrdinalPath]*/,[OrdinalPath]
from ItemZ I
OPTION (MAXRECURSION 10000)
END
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItems Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_SiblingAndChildrenItems Error on Creation'
GO
/****** Object: StoredProcedure [vefn_SiblingChildrenItems] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingChildrenItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_SiblingChildrenItems];
GO
/*
select * from Transitions
where (ToID in(select ItemID From dbo.vefn_ChildrenItems(185,184))) OR (RangeID in(select ItemID From dbo.vefn_ChildrenItems(185,184)))
AND NOT (FromID in(Select ContentID From dbo.vefn_ChildrenItems(185,184)))
*/
CREATE FUNCTION [dbo].[vefn_SiblingChildrenItems](@ItemID int)
RETURNS @SiblingChildren TABLE
(
ItemID int PRIMARY KEY,
ContentID int
)
AS
BEGIN
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as (
Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
select [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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.[ParentID],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
)
insert into @SiblingChildren select ItemID, ContentID from Itemz
RETURN
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_SiblingChildrenItems Succeeded'
ELSE PRINT 'TableFunction Creation: vefn_SiblingChildrenItems Error on Creation'
GO
/****** Object: StoredProcedure [vefn_SplitInt] ******/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SplitInt]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
DROP FUNCTION [vefn_SplitInt];
@ -9492,7 +10030,7 @@ GO
CREATE PROCEDURE [dbo].[vesp_ListChildren] (@ItemID int) WITH EXECUTE AS OWNER AS BEGIN
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged]) as (
Select 0 [Level], 0 [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
FROM [VEPROMS].[dbo].[Items]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
@ -9627,7 +10165,7 @@ CREATE PROCEDURE [dbo].[vesp_ListItemAndChildren] (@ItemID int, @ParentID int) W
with Itemz([Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], [pDTS],[pUserID],[pLastChanged]) as (
Select 0 [Level], @ParentID [ParentID], 0 [Ordinal], [ItemID], [PreviousID],0 [FromType],[ContentID],[DTS],[UserID],[LastChanged]
,0 as [pContentID],[DTS] As [pDTS], [UserID] As [pUserID], [LastChanged] As [pLastChanged]
FROM [VEPROMS].[dbo].[Items]
FROM [Items]
where [ItemID]=@ItemID
Union All
-- Children
@ -9927,7 +10465,9 @@ exec vesp_SearchAnnotationItemAndChildren Null,Null,'4',Null,0
exec vesp_SearchAnnotationItemAndChildren Null,Null,'5',Null,0
exec vesp_SearchAnnotationItemAndChildren Null,Null,'',Null,0
*/
CREATE PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int) WITH EXECUTE AS OWNER
CREATE PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive
as int) WITH EXECUTE AS OWNER
AS
BEGIN
Declare @Delim char(1)
@ -10055,7 +10595,8 @@ exec vesp_SearchItemAndChildren '4','','#Link:Refer',1,2,0,0
exec vesp_SearchItemAndChildren '4','','200`F',0,1,0,0
exec vesp_SearchItemAndChildren '4','10000','',0,0,0,0
exec vesp_SearchItemAndChildren '4','','[0-9]`F',0,1,0,0
exec vesp_SearchItemAndChildren '','','RCP',0,0,0,0
exec vesp_SearchItemAndChildren '1','','"RCP"',2,0,0,0
exec vesp_SearchItemAndChildren '','','"RCP"',2,0,0,0
exec vesp_SearchItemAndChildren '','','%',0,0,0,0
exec vesp_SearchItemAndChildren '','20040','',0,0,0,0
exec vesp_SearchItemAndChildren '','10000','XYZZY',0,0,0,0
@ -10073,118 +10614,30 @@ exec vesp_SearchItemAndChildren '','','CHECK NORMAL',0,0,0,0
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) 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='.'
Declare @SearchString2 nvarchar(200)
Set @SearchString2 = case when @CaseSensitive = 2 then Cast(@SearchString as nvarchar(200)) else 'IGNORE_FULL_TEXT_SEARCH' end
Set @SearchString = .dbo.vefn_FixSearchString(@SearchString)
begin
with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID],
[pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath) as (
Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged]
,0 as [pContentID],[I].[DTS] As [pDTS], [I].[UserID] As [pUserID], [I].[LastChanged] As [pLastChanged],
Cast('' as nvarchar(max)) PPath,
Cast(Case when C.Type < 20000 then @Delim + 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
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] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [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 C.Type/10000
when 0 then @Delim +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'
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 + 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)
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] As [cDTS],C.[UserID] As [cUserID],C.[LastChanged] As [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 [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
(isnull(@SearchString,'')=''
OR (@CaseSensitive = 1 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
OR (@CaseSensitive = 0 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)
OR (@CaseSensitive = 2 AND CONTAINS(C.text, @SearchString2))
OR (@CaseSensitive = 1 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
OR (@CaseSensitive = 0 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)
OR (@CaseSensitive = 2 AND CONTAINS(D.DocAscii, @SearchString2))
)
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)))
select ZZ.DvPath, ZZ.Path, ZZ.[Level],ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID]
,II.[LastChanged]
,CC.[Number],CC.[Text],CC.[Type],CC.[FormatID],CC.[Config],CC.[DTS] As [cDTS],CC.[UserID] As [cUserID]
,CC.[LastChanged] As [cLastChanged],
PP.[ContentID] [pContentID], PP.[DTS] [pDTS],PP.[UserID] [pUserID], PP.[LastChanged] [pLastChanged],
(SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount],
(SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount],
(SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount],
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount],
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount],
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount],
(SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=CC.[ContentID]) [DetailCount],
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=CC.[ContentID]) [EntryCount],
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=CC.[ContentID]) [ItemCount],
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=CC.[ContentID]) [cPartCount],
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=CC.[ContentID]) [RoUsageCount],
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=CC.[ContentID]) [TransitionCount],
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=CC.[ContentID]) [ZContentCount]
from vefn_SiblingAndChildrenItems(@DocVersionList) ZZ
Join Items II on ZZ.ItemID=II.ItemID
Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType
Join Contents CC on CC.ContentID=ZZ.ContentID
where ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
order by DvPath,OrdinalPath
OPTION (MAXRECURSION 10000)
END
END
GO
-- Display the status of Proc creation
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildren Succeeded'