C2020-009 Search By Word
This commit is contained in:
@@ -15485,6 +15485,370 @@ IF (@@Error = 0) PRINT 'Procedure Creation: addItemSiblingBefore Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: addItemSiblingBefore Error on Creation'
|
||||
GO
|
||||
|
||||
/*************** May 2020 - Modifications to search queries to allow for 'ByWord'. To do this a sql prefix and suffix were added
|
||||
* If search string's adjacent character is text '[^a-zA-Z]' (for example 'red' prefix is next to 'r', suffix is next to 'd')
|
||||
* If search string's adjacent character is numeric '[^0-9a-zA-Z.vbpi:\\-]' (for example 10%, prefix is next to '1')
|
||||
*/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_FixSearchStringByWord]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
|
||||
DROP FUNCTION [vefn_FixSearchStringByWord];
|
||||
GO
|
||||
|
||||
/*
|
||||
select .dbo.vefn_FixSearchStringByWord('0%', '[^0-9A-Z.vbpi:\\-]', '')
|
||||
select .dbo.vefn_FixSearchStringByWord('step 25', '[^a-z]', '[^0-9A-Z.vbpi:\\-]')
|
||||
*/
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE FUNCTION [dbo].[vefn_FixSearchStringByWord](@SearchString nvarchar(MAX), @Prefix nvarchar(64), @Suffix nvarchar(64))
|
||||
RETURNS nvarchar(MAX)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
-- This code adds % at the beginning and end if the beginning and end
|
||||
-- of the search string if it does not have % at the beginning or end
|
||||
Set @SearchString = replace(@SearchString,'[','[[]')
|
||||
Set @SearchString = replace(@SearchString,'_','[_]')
|
||||
Set @SearchString = replace(@SearchString,'%','[%]')
|
||||
Set @SearchString = replace(@SearchString,'*','%')
|
||||
Set @SearchString = replace(@SearchString,'?','_')
|
||||
Set @SearchString = replace(@SearchString,'\%','*')
|
||||
Set @SearchString = replace(@SearchString,'\_','?')
|
||||
Set @SearchString = replace(@SearchString,'-','\u8209?')
|
||||
Set @SearchString = replace(@SearchString,'\''A9','\u169?') -- copyright symbol
|
||||
Set @SearchString = replace(@SearchString,'\''AE','\u174?') -- Register symbol
|
||||
Set @SearchString = replace(@SearchString,'\\line ','\line ') -- newline
|
||||
Set @SearchString = replace(@SearchString,'\\','\u9586?') -- use a double backslash to search for a backslash
|
||||
IF(@SearchString like '[%]%') RETURN '%' + @Prefix + SubString(@SearchString,2,len(@SearchString)) -- beginning of text
|
||||
IF(@SearchString like '%[%]') RETURN SubString(@SearchString, 0, len(@SearchString)-1) + @Suffix + '%' -- end of text
|
||||
Set @SearchString = replace('%' + @Prefix + @SearchString + @Suffix + '%','%%','%')
|
||||
RETURN @SearchString
|
||||
END
|
||||
GO
|
||||
-- Display the status
|
||||
IF (@@Error = 0) PRINT 'ScalerFunction [vefn_FixSearchStringByWord] Succeeded'
|
||||
ELSE PRINT 'ScalerFunction [vefn_FixSearchStringByWord] Error on Creation'
|
||||
go
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_SiblingAndChildrenItemsNewByWord]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
|
||||
DROP FUNCTION [vefn_SiblingAndChildrenItemsNewByWord];
|
||||
GO
|
||||
/*
|
||||
select Text from vefn_SiblingAndChildrenItemsNewByWord('194','','%[^a-z]red[^a-z]%', '%[^a-z]red[^a-z]%','')
|
||||
select Text from vefn_SiblingAndChildrenItemsNewByWord('194','','%[^a-zA-Z]step 25[^0-9a-zA-Z.vbpi:\\-]%','%[^a-zA-Z]step 25[^0-9a-zA-Z.vbpi:\\-]%','')
|
||||
*/
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItemsNewByWord](@DocVersionList varchar(MAX),@UnitPrefix varchar(MAX),@SearchString varchar(MAX),@SearchStringx varchar(MAX), @StepTypeList varchar(MAX))
|
||||
RETURNS @SiblingAndChildren TABLE
|
||||
(
|
||||
[ILastChanged] varbinary(8)
|
||||
, [ItemID] int PRIMARY KEY
|
||||
, [DVPath] nvarchar(max)
|
||||
, [Path] nvarchar(max)
|
||||
, [FromType] int
|
||||
, [Ordinal] int
|
||||
, [ParentID] int
|
||||
, [PreviousID] int
|
||||
, [ContentID] int
|
||||
, [DTS] datetime
|
||||
, [UserID] nvarchar(100)
|
||||
, [pContentID] int
|
||||
, [pDTS] datetime
|
||||
, [pUserID] nvarchar(100)
|
||||
, [IsRNO] int
|
||||
, Text nvarchar(max)
|
||||
, DocAscii nvarchar(max)
|
||||
, Number nvarchar(256)
|
||||
, CType int
|
||||
, CFormatID int
|
||||
, CConfig nvarchar(max)
|
||||
, CDTS datetime
|
||||
, CUserID nvarchar(100)
|
||||
, CLastChanged varbinary(8)
|
||||
, PLastChanged varbinary(8)
|
||||
)
|
||||
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 @TextPrefix nvarchar(1)
|
||||
declare @TextSuffix nvarchar(1)
|
||||
set @TextPrefix = ''
|
||||
set @TextSuffix = ''
|
||||
if (@SearchString like '[%]%') set @TextPrefix = '~'
|
||||
if (@SearchString like '%[%]') set @TextSuffix = '~'
|
||||
BEGIN
|
||||
with Itemz([ILastChanged], [ItemID], VersionID,[Path], [FromType],[Ordinal], [ParentID], [PreviousID], [ContentID], [DTS], [UserID],[pContentID],
|
||||
[pDTS],[pUserID],[IsRNO], Text, Number, PPath, CType, CFormatID, CConfig, CDTS, CUserID, CLastChanged, PLastChanged) as (
|
||||
Select Cast(I.LastChanged as varbinary(8)) ILastChanged,[I].[ItemID], VersionID,
|
||||
Cast(Case when C.Type < 20000 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') else '1' end as nvarchar(max)) [Path]
|
||||
, 0 [FromType], 0 [Ordinal], 0 [ParentID], [PreviousID],[I].[ContentID],[I].[DTS],[I].[UserID]
|
||||
,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID],0 IsRNO, C.Text, C.Number,
|
||||
Cast('' as nvarchar(max)) [PPath], C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID,
|
||||
Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(0 as varbinary(8)) PLastChanged
|
||||
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 Cast(I.LastChanged as varbinary(8)) ILastChanged,I.[ItemID], VersionID,
|
||||
Path + case C.Type/10000
|
||||
when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Procedure
|
||||
when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Section
|
||||
else
|
||||
case P.FromType
|
||||
--when 1 then 'PRC' + @Delim + cast(1 as varchar(4))
|
||||
--when 2 then 'SEC' + @Delim + cast(1 as varchar(4))
|
||||
when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(4))
|
||||
when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(4))
|
||||
when 5 then @DelimStep +'RNO' + @DelimStep
|
||||
when 7 then @DelimStep +'Table' + @DelimStep + cast(1 as varchar(4))
|
||||
when 8 then @DelimStep +'SupInfo' + @DelimStep
|
||||
else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(4))
|
||||
end end Path,
|
||||
P.[FromType],0 [Ordinal], Z.ItemID [ParentID],I.[PreviousID], I.[ContentID],I.[DTS],I.[UserID],
|
||||
P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],
|
||||
case when P.FromType = 5 then -1 else 0 end IsRNO,
|
||||
C.Text,c.Number,
|
||||
Path + case C.Type/10000
|
||||
when 2 then
|
||||
case P.FromType
|
||||
when 3 then @DelimStep + 'Caution'
|
||||
when 4 then @DelimStep + 'Note'
|
||||
when 8 then @DelimStep + 'SupInfo'
|
||||
else '' end
|
||||
else '' end [PPath], C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID,
|
||||
Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(P.LastChanged as varbinary(8)) PLastChanged
|
||||
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 Cast(I.LastChanged as varbinary(8)) ILastChanged,I.[ItemID], VersionID, PPath + case C.Type/10000
|
||||
when 0 then @Delim + @UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Procedure
|
||||
when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'') -- Section
|
||||
else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(4))
|
||||
end Path,
|
||||
[FromType],Z.[Ordinal] +1,Z.[ParentID], I.[PreviousID], I.[ContentID],I.[DTS],I.[UserID]
|
||||
,null,null,null,
|
||||
0 IsRNO,
|
||||
C.Text, C.Number,
|
||||
PPath, C.Type CType, C.FormatID CFormatID, C.Config CConfig, C.Dts CDTS,C.UserID CUSERID,
|
||||
Cast(C.LastChanged as varbinary(8)) CLastChanged, Cast(0 as varbinary(8)) PLastChanged
|
||||
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 ZZ.ILastChanged,ZZ.[ItemID], dvpath, [Path],[FromType],[Ordinal], [ParentID], [PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID],
|
||||
[pContentID],[pDTS],[pUserID],[IsRNO],Text,DocAscii, Number, CType, CFormatID, CConfig, CDTS, CUserID, CLastChanged, PLastChanged
|
||||
From Itemz ZZ
|
||||
join vefn_DocVersionSplit(@DocVersionList) DV ON DV.VersionID=zz.VersionID
|
||||
Left Join Entries EE ON EE.ContentID=ZZ.ContentID
|
||||
Left Join Documents DD ON DD.DocID = ee.DocID
|
||||
where (@TextPrefix+text+@TextSuffix like @SearchString OR Replace(DD.DocAscii,nchar(176),'\''B0') like @SearchString or @TextPrefix+text+@TextSuffix like @SearchStringx OR
|
||||
Replace(DD.DocAscii,nchar(176),'\''B0') like @SearchStringx )
|
||||
and (isnull(@StepTypeList,'') = '' or (dbo.vefn_AllSections(CType) in (Select ID from vefn_SplitInt(@StepTypeList,','))))
|
||||
OPTION (MAXRECURSION 10000)
|
||||
END
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
|
||||
IF (@@Error = 0) PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Succeeded'
|
||||
ELSE PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_SearchItemAndChildrenNewByWord];
|
||||
GO
|
||||
/*
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','red',0,0,0,0,'','[^a-z]','[^a-z]'
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','0%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','10%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]','[^0-9A-Z.vbpi:\\-]'
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','','[^0-9A-Z.vbpi:\\-]'
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','25%',0,0,0,0,'','[^0-9A-Z.vbpi:\\-]',''
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','step 25',0,0,0,1,'','[^a-zA-Z]','[^0-9a-zA-Z.vbpi:\\-]'
|
||||
exec vesp_SearchItemAndChildrenNewByWord '194','','25',0,0,0,0,'','',''
|
||||
*/
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildrenNewByWord] (@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),
|
||||
@ByWordPrefix varchar(64), @ByWordSuffix varchar(64))
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
Set @SearchString = .dbo.vefn_FixSearchStringByWord(@SearchString, @ByWordPrefix, @ByWordSuffix)
|
||||
declare @TextPrefix nvarchar(1)
|
||||
declare @TextSuffix nvarchar(1)
|
||||
set @TextPrefix = ''
|
||||
set @TextSuffix = ''
|
||||
if (@SearchString like '[%]%') set @TextPrefix = '~'
|
||||
if (@SearchString like '%[%]') set @TextSuffix = '~'
|
||||
Declare @SearchStringx nvarchar(200)
|
||||
set @SearchStringx = replace(@SearchString,'\u8209?','-') --JSJ B2016-209 not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?')
|
||||
if (@IncludeLinks + @IncludeRtfFormatting + @IncludeSpecialCharacters = 0)
|
||||
begin
|
||||
if (@CaseSensitive = 0)
|
||||
Begin
|
||||
select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID]
|
||||
,ZZ.[ILastChanged]
|
||||
,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID]
|
||||
,ZZ.[cLastChanged],
|
||||
zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[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]=ZZ.[ContentID]) [DetailCount],
|
||||
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount],
|
||||
(SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount],
|
||||
(SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount],
|
||||
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount],
|
||||
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount],
|
||||
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount],
|
||||
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount],
|
||||
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount]
|
||||
from vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) 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.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
|
||||
order by DvPath
|
||||
end
|
||||
else
|
||||
begin
|
||||
|
||||
select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID]
|
||||
,ZZ.[ILastChanged]
|
||||
,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID]
|
||||
,ZZ.[cLastChanged],
|
||||
zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[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]=ZZ.[ContentID]) [DetailCount],
|
||||
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount],
|
||||
(SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount],
|
||||
(SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount],
|
||||
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount],
|
||||
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount],
|
||||
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount],
|
||||
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount],
|
||||
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount]
|
||||
from vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) 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.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
|
||||
--where zz.text Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or
|
||||
--zz.text Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx or
|
||||
where @TextPrefix+zz.text+@TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or
|
||||
@TextPrefix+zz.text+@TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx or
|
||||
-- docascii are the word sections
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx
|
||||
order by DvPath
|
||||
end
|
||||
end -- no links
|
||||
else
|
||||
begin -- include linked text
|
||||
if (@CaseSensitive = 0)
|
||||
Begin
|
||||
select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID]
|
||||
,ZZ.[ILastChanged]
|
||||
,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID]
|
||||
,ZZ.[cLastChanged],
|
||||
zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[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]=ZZ.[ContentID]) [DetailCount],
|
||||
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount],
|
||||
(SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount],
|
||||
(SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount],
|
||||
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount],
|
||||
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount],
|
||||
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount],
|
||||
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount],
|
||||
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount]
|
||||
from vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) 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.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
|
||||
where .dbo.vefn_RemoveExtraText(@TextPrefix+zz.text+@TextSuffix,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchString or
|
||||
.dbo.vefn_RemoveExtraText(@TextPrefix+zz.text+@TextSuffix,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx or
|
||||
-- docascii are the word sections
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchString or
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx
|
||||
order by DvPath
|
||||
end
|
||||
else -- case sensitive
|
||||
begin
|
||||
select ZZ.DvPath, ZZ.Path, ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID]
|
||||
,ZZ.[ILastChanged]
|
||||
,ZZ.[Number],ZZ.[Text],ZZ.[CType] [Type],ZZ.[CFormatID] [FormatID],ZZ.[CConfig] [Config],ZZ.[CDTS] ,ZZ.[CUserID]
|
||||
,ZZ.[cLastChanged],
|
||||
zz.[pContentID], ZZ.[pDTS],ZZ.[pUserID], ZZ.[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]=ZZ.[ContentID]) [DetailCount],
|
||||
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=ZZ.[ContentID]) [EntryCount],
|
||||
(SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=ZZ.[ContentID]) [GridCount],
|
||||
(SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=ZZ.[ContentID]) [ImageCount],
|
||||
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=ZZ.[ContentID]) [ItemCount],
|
||||
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=ZZ.[ContentID]) [cPartCount],
|
||||
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=ZZ.[ContentID]) [RoUsageCount],
|
||||
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=ZZ.[ContentID]) [TransitionCount],
|
||||
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=ZZ.[ContentID]) [ZContentCount]
|
||||
from vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx,@StepTypeList) 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.Text like @SearchString or zz.text like @SearchStringx-- ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList))
|
||||
--
|
||||
where .dbo.vefn_RemoveExtraText(replace(@TextPrefix+zz.text+@TextSuffix,'\''b0', '\''B0'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like replace(@SearchString,'\''b0', '\''B0') or
|
||||
.dbo.vefn_RemoveExtraText(replace(@TextPrefix+zz.text+@TextSuffix,'\''b0', '\''B0'),@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like replace(@SearchStringx,'\''b0', '\''B0') or
|
||||
-- docascii are the word sections
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString or
|
||||
Replace(zz.DocAscii,nchar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx
|
||||
order by DvPath
|
||||
end
|
||||
end -- include links
|
||||
GO
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Error on Creation'
|
||||
GO
|
||||
|
||||
-----------------------------------------------------------------------------
|
||||
/*
|
||||
@@ -15511,8 +15875,8 @@ BEGIN TRY -- Try Block
|
||||
set nocount on
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
set @RevDate = '01/09/2020 11:00 AM'
|
||||
set @RevDescription = 'Referenced Object data in sql server'
|
||||
set @RevDate = '05/04/2020 10:00 AM'
|
||||
set @RevDescription = 'Allow Search By Word'
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
|
Reference in New Issue
Block a user