diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql
index 5693daee..ce6d0c7f 100644
--- a/PROMS/DataLoader/PROMSFixes.Sql
+++ b/PROMS/DataLoader/PROMSFixes.Sql
@@ -1,3 +1,5 @@
+
+
if db_name() in('master','model','msdn','tempdb')
begin
DECLARE @ErrorMsg varchar(255)
@@ -1454,204 +1456,453 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemI
ELSE PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemID Error on Creation'
GO
-IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
- DROP FUNCTION [vefn_GetUnitPrefix];
+
+
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[ve_GetFolderPath]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
+ DROP FUNCTION [dbo].[ve_GetFolderPath];
+
GO
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
/*
-select 'DocVersions' Type, VersionID, Config, .dbo.vefn_GetUnitPrefix(config) UnitPrefix from DocVersions
-UNION select 'Blank' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'Null' Type, 0 VersionID, null Config, .dbo.vefn_GetUnitPrefix(null) UnitPrefix
-UNION select 'XML with' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'XML without' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'XML empty' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-*/
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns the Folder Path for a specified Document Version using recursion
+ 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement
+
+ Parameters: @VersionID Document Version ID
+
+ Examples: Select VersionID,Name,dbo.ve_GetFolderPath(VersionID) from DocVersions order by VersionID;
+==========================================================================================================
+ */
+Create Function [dbo].[ve_GetFolderPath] (@VersionID int)
+Returns VarChar(Max)
+With Execute as Owner
+as
+Begin
+
+ Declare @Path VarChar(Max);
+
+ With zFolders ([Level], FolderID, [Path])
+ as (
+
+ Select 1 as 'Level',
+ dv.FolderID as 'FolderID',
+ Cast(dv.[Name] as VarChar(Max)) as 'Path'
+ From DocVersions dv with (NoLock)
+ Where dv.VersionID = @VersionID
+
+ Union All
+
+ Select f.ParentID - (Select ParentID from Folders where FolderID = f.ParentID) as 'Level',
+ f.ParentID as 'FolderID',
+ Cast(f.[Name] + char(7) + zf.[Path] as VarChar(Max)) as 'Path'
+ From Folders f with (NoLock)
+ inner join zFolders zf on f.FolderID = zf.FolderID
+ Where f.FolderID <> f.ParentID
+
+ )
+ Select @Path = zf.[Path]
+ From zFolders zf
+ Where zf.[Level] = 0;
+
+ return @Path;
+
+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'[dbo].[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_GetUnitPrefix];
+GO
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE function [dbo].[vefn_GetUnitPrefix](@config varchar(MAX))
-returns varchar(MAX)
-begin
- declare @Xml xml
- set @Xml = cast(@config as xml)
- declare @UnitPrefix varchar(MAX)
- set @UnitPrefix = (select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') UnitPrefix from @XML.nodes('//Unit') as tmpXml(v))
- return isnull(@UnitPrefix,'')
-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('')
-*/
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns the Unit Prefix from the specified Xml Configuration Data
+ 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement
+
+ Parameters: @Config Xml Configuration Data
+
+ Examples: Select 'DocVersions' Type, VersionID, Config, .dbo.vefn_GetUnitPrefix(config) UnitPrefix from DocVersions
+ UNION select 'Blank' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'Null' Type, 0 VersionID, null Config, .dbo.vefn_GetUnitPrefix(null) UnitPrefix
+ UNION select 'XML with' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'XML without' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'XML empty' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_GetUnitPrefix](@Config varchar(MAX))
+Returns VarChar(Max)
+With Execute as Owner
+as
+Begin
+
+ Declare @Xml xml;
+ Declare @UnitPrefix VarChar(Max);
+
+ Set @Xml = Cast(@Config as xml)
+
+ Set @UnitPrefix = (Select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') as 'UnitPrefix' From @XML.nodes('//Unit') as tmpXml(v))
+
+ Return IsNull(@UnitPrefix,'');
+
+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'[dbo].[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_DocVersionSplit];
+
+GO
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE FUNCTION [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
-RETURNS @IDs TABLE
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns a table of document version info from a comma delimited list of specified document version IDs
+ 08/20/2021 Jake Ropar: Add with (NoLock) statements to prevent table locking
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs (pass '' or null to retrieve all versions)
+
+ Examples: select * from vefn_DocVersionSplit('1,4');
+ select * from vefn_DocVersionSplit(null);
+ select * from vefn_DocVersionSplit('');
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
+Returns @IDs Table
(
- VersionID int PRIMARY KEY,
- ItemID int,
- DVPath varchar(MAX),
- UnitPrefix varchar(MAX)
+ VersionID Int Primary Key,
+ ItemID Int,
+ DVPath VarChar(Max),
+ UnitPrefix VarChar(MAX)
)
-WITH EXECUTE AS OWNER
-AS
-BEGIN
-IF(isnull(@DocVersionList,'') = '')
- Insert into @IDs
- Select VersionID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config)
- from DocVersions where ItemID is not null
-else
- Insert into @IDs
- Select ID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config)
- from vefn_SplitInt(@DocVersionList,',') as T
- join DocVersions DV on VersionID = T.ID
-RETURN
-END
+With Execute as Owner
+as
+Begin
-GO
+ If(IsNull(@DocVersionList,'') = '')
+ Insert into @IDs
+ Select dv.VersionID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), dbo.vefn_GetUnitPrefix(dv.Config)
+ From DocVersions dv with (NoLock) Where dv.ItemID is not null;
+ Else
+ Insert into @IDs
+ Select t.ID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), .dbo.vefn_GetUnitPrefix(dv.config)
+ From dbo.vefn_SplitInt(@DocVersionList,',') as t
+ inner join DocVersions dv with (NoLock) on dv.VersionID = t.ID;
+
+ 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];
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vefn_SiblingAndChildrenItemsNewByWord]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_SiblingAndChildrenItemsNewByWord];
GO
-/*
-select * from vefn_SiblingAndChildrenItems('146','')
-*/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
- Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+ Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(MAX),@UnitPrefix varchar(MAX))
-RETURNS @SiblingAndChildren TABLE
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2021
+ Description: Returns all items mathcing the specified search critera, filtered by a list of specified document versions
+ 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions)
+ @UnitPrefix The unit prefix to use when building the item path
+ @SearchString Search string criteria
+ @SearchStringx Alternate search string criteria
+ @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections)
+
+ Examples: 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:\\-]%','');
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_SiblingAndChildrenItemsNewByWord](@DocVersionList VarChar(Max), @UnitPrefix VarChar(Max), @SearchString VarChar(Max),
+ @SearchStringx VarChar(Max), @StepTypeList VarChar(Max))
+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)
+ 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='.'
-BEGIN
-with Itemz([ItemID], [DVPath], [Level], [ParentID], [Ordinal], [PreviousID], [FromType], [ContentID], [DTS], [UserID],[pContentID],
- [pDTS],[pUserID],PPath, [Path], [IsRNO], [POrdinalPath], [OrdinalPath], [UnitPrefix]) as (
- Select [I].[ItemID], DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID]
- ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID],
- Cast('' as nvarchar(max)) [PPath],
- Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(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 I.[ItemID], DVPath, [Level] + 1,Z.ItemID,0, I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],
- P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID]
- ,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,
- 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
- 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,
- 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', 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 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 + 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, 0,
- POrdinalPath,
- POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), UnitPrefix
- from Itemz Z
- join Items I on I.PreviousID = Z.ItemID
- join Contents C on C.ContentID = I.ContentID
- --where Z.[Level] > 0
+With Execute as Owner
+as
+Begin
-)
-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
+ -- Declare Local Variables
+ Declare @Delim Char(1);
+ Declare @DelimNumber Char(1);
+ Declare @DelimStep Char(1);
+ declare @TextPrefix nVarChar(1);
+ declare @TextSuffix nVarChar(1);
+
+ -- Set Default Values
+ Set @Delim = Char(7);
+ Set @DelimNumber = Char(17);
+ Set @DelimStep = '.';
+ Set @TextPrefix = '';
+ Set @TextSuffix = '';
+
+ -- Check Input Parameters
+ If (@SearchString Like '[%]%') Set @TextPrefix = '~';
+ if (@SearchString Like '%[%]') Set @TextSuffix = '~';
+
+
+ With zItems (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 (
+
+ -- Parent Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ dv.VersionID as 'VersionID',
+ Cast((Case When (c.[Type] < 20000) Then @Delim + @UnitPrefix + IsNull(c.Number,'') + @DelimNumber + IsNull(c.[Text],'') Else '1' End) as nVarChar(Max)) as 'Path',
+ 0 as 'FromType',
+ 0 as 'Ordinal',
+ 0 as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ 0 as 'pContentID',
+ i.DTS as 'pDTS',
+ i.UserID as 'pUserID',
+ 0 as 'IsRNO',
+ c.[Text] as 'Text',
+ c.Number as 'Number',
+ Cast('' as nVarChar(Max)) as 'PPath',
+ c.Type as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as VarBinary(8)) as 'CLastChanged',
+ Cast(0 as VarBinary(8)) as 'PLastChanged'
+ From Items i with (NoLock)
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+ join dbo.vefn_DocVersionSplit(@DocVersionList) dv on i.ItemID = dv.ItemID
+
+ Union All
+
+ -- Children Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ zi.VersionID as 'VersionID',
+ zi.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 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 (zi.FromType < 3) Then @Delim Else @DelimStep End + Cast(1 as varchar(4))
+ End
+ End as 'Path',
+ p.FromType as 'FromType',
+ 0 as 'Ordinal',
+ zi.ItemID as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ p.ContentID as 'pContentID',
+ p.DTS as 'pDTS',
+ p.UserID as 'pUserID',
+ Case When (p.FromType = 5) Then -1 Else 0 End as 'IsRNO',
+ c.Text as 'Text',
+ c.Number as 'Number',
+ zi.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 as 'PPath',
+ c.[Type] as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as varbinary(8)) as 'CLastChanged',
+ Cast(p.LastChanged as varbinary(8)) as 'PLastChanged'
+ From zItems zi
+ join Parts p with (NoLock) on p.ContentID = zi.ContentID
+ join Items i with (NoLock) on i.ItemID = p.ItemID
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+
+ Union All
+
+ -- Sibling Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ zi.VersionID as 'VersionID',
+ zi.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(zi.Path) = '.') Then @DelimStep Else @Delim End + Cast(zi.Ordinal + 2 as varchar(4))
+ End as 'Path',
+ zi.FromType as 'FromType',
+ zi.Ordinal + 1 as 'Ordinal',
+ zi.ParentID as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ Null as 'pContentID',
+ Null as 'pDTS',
+ Null as 'pUserID',
+ 0 as 'IsRNO',
+ c.[text] as 'Text',
+ c.Number as 'Number',
+ zi.PPath as 'PPath',
+ c.[Type] as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as varbinary(8)) as 'CLastChanged',
+ Cast(0 as varbinary(8)) as 'PLastChanged'
+ From zItems zi
+ join Items i with (NoLock) on i.PreviousID = zi.ItemID
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+
+ )
+ Insert Into @SiblingAndChildren
+ Select zi.ILastChanged,
+ zi.ItemID,
+ dv.DVPath,
+ zi.Path,
+ zi.FromType,
+ zi.Ordinal,
+ zi.ParentID,
+ zi.PreviousID,
+ zi.ContentID,
+ zi.DTS,
+ zi.UserID,
+ zi.pContentID,
+ zi.pDTS,
+ zi.pUserID,
+ zi.IsRNO,
+ zi.Text,
+ d.DocAscii,
+ zi.Number,
+ zi.CType,
+ zi.CFormatID,
+ zi.CConfig,
+ zi.DTS,
+ zi.CUserID,
+ zi.CLastChanged,
+ zi.PLastChanged
+ From zItems zi
+ join dbo.vefn_DocVersionSplit(@DocVersionList) dv on dv.VersionID = zi.VersionID
+ left join Entries e with (NoLock) on e.ContentID = zi.ContentID
+ left join Documents d with (NoLock) on d.DocID = e.DocID
+ Where (@TextPrefix + zi.[Text] + @TextSuffix like @SearchString Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchString
+ Or @TextPrefix + zi.[Text] + @TextSuffix like @SearchStringx Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchStringx)
+ And (IsNull(@StepTypeList,'') = '' or (dbo.vefn_AllSections(zi.CType) in (Select ID from dbo.vefn_SplitInt(@StepTypeList,','))))
+ Option (Recompile, MaxRecursion 10000);
+
+ 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];
@@ -15584,325 +15835,306 @@ 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
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
+ DROP Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord];
GO
-IF (@@Error = 0) PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Succeeded'
-ELSE PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Error on Creation'
+SET ANSI_NULLS ON
GO
-
-IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
-DROP PROCEDURE [vesp_SearchItemAndChildrenNewByWord];
+SET QUOTED_IDENTIFIER ON
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)
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2020
+ Description: Returns all items mathcing the specified search critera, filtered by a list of specified Document Versions and Step Types
+ 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace, also changed all
+ Select (*) statements to Select (1) for performace reasons
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions)
+ @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections)
+ @SearchString Search string criteria
+ @CaseSensitive Indicator for Case Sensitive Search (0 = False, 1 = True)
+ @IncludeLinks Indicator to include Links in results (0 = False, 1 = True)
+ @IncludeRtfFormatting Indicator to include RTF Formatting in results (0 = False, 1 = True)
+ @IncludeSpecialCharacters Indicator to include Special Characters in results (0 = False, 1 = True)
+ @UnitPrefix Specified Unit Prefix if any
+ @ByWordPrefix Word Prefix for the specified search string criteria
+ @ByWordSuffix Word Suffix for the specified search string criteria
+
+
+ Examples: 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,'','','';
+==========================================================================================================
+ */
+Create Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord] (@DocVersionList VarChar(Max), @StepTypeList VarChar(Max), @SearchString VarChar(Max), @CaseSensitive Int,
+ @IncludeLinks Int, @IncludeRtfFormatting Int, @IncludeSpecialCharacters Int, @UnitPrefix VarChar(Max),
+ @ByWordPrefix VarChar(64), @ByWordSuffix VarChar(64))
+With Execute As Owner
+As
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
+
+ Set NoCount On;
+
+ -- Declare Local Variables
+ Declare @TextPrefix nVarChar(1);
+ Declare @TextSuffix nVarChar(1);
+ Declare @SearchStringx nVarChar(200);
+
+ -- Set Default Values
+ Set @TextPrefix = '';
+ Set @TextSuffix = '';
+
+ Set @SearchString = dbo.vefn_FixSearchStringByWord(@SearchString, @ByWordPrefix, @ByWordSuffix);
+ If (@SearchString like '[%]%') Set @TextPrefix = '~';
+ If (@SearchString like '%[%]') Set @TextSuffix = '~';
+ Set @SearchStringx = Replace(@SearchString,'\u8209?','-') -- [John Jenko] B2016-209: not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?')
+
+
+ If (@IncludeLinks + @IncludeRtfFormatting + @IncludeSpecialCharacters = 0)
+ Begin
+
+ If (@CaseSensitive = 0)
+ Begin
+
+ --Select 'Case #1: No Links/RtfFormatting/SpecialCharacters & Not Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+ Else
+ Begin
+
+ --Select 'Case #2: No Links/RtfFormatting/SpecialCharacters & Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (@TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ or @TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx
+ or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ End -- no links
+
+ Else
+
+ Begin -- include linked text
+
+ If (@CaseSensitive = 0)
+ Begin
+
+ --Select 'Case #3: Include Links/RtfFormatting/SpecialCharacters & Not Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchString
+ Or dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx
+ Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchString
+ Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ Else -- case sensitive
+
+ Begin
+
+ --Select 'Case #4: Include Links/RtfFormatting/SpecialCharacters & Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (dbo.vefn_RemoveExtraText(Replace(@TextPrefix + z.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 + z.Text + @TextSuffix,'\''b0', '\''B0'), @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like Replace(@SearchStringx,'\''b0', '\''B0')
+ Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ End -- include links
+
+End
+Go
+
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Succeeded'
ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Error on Creation'
GO
+
+
+
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[DeleteItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [DeleteItemAndChildren];
GO
@@ -16670,6 +16902,458 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
GO
+
+
+
+
+If Exists(Select * From sys.views Where Name = N'vwSysInfo_IndexFragmentation')
+ Drop View [dbo].[vwSysInfo_IndexFragmentation];
+Go
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: (System Info) Master View for Table Index Fragmentation
+==========================================================================================================
+*/
+Create View [dbo].[vwSysInfo_IndexFragmentation]
+As
+
+ Select s.[name] as 'SchemaName',
+ t.[name] as 'TableName',
+ i.[name] as 'IndexName',
+ i.is_primary_key as 'IsPrimaryKey',
+ i.fill_factor as 'FillFactor',
+ ips.[avg_fragmentation_in_percent] as 'AvgFragmentation',
+ ips.[page_count] as 'PageCount',
+ ips.index_level as 'IndexLevel',
+ ips.index_depth as 'IndexDepth',
+ Case When (ips.[avg_fragmentation_in_percent] > 30) Then 'Rebuild'
+ When (ips.[avg_fragmentation_in_percent] > 5) Then 'Reorganize'
+ Else 'None'
+ End as 'SuggestedAction'
+ From sys.[dm_db_index_physical_stats] (DB_ID(), NULL, NULL, NULL, NULL) as ips
+ inner join sys.[tables] t With (NoLock) on t.[object_id] = ips.[object_id]
+ inner join sys.[schemas] s With (NoLock) on t.[schema_id] = s.[schema_id]
+ inner join sys.[indexes] i With (NoLock) on i.[object_id] = ips.[object_id] And i.[index_id] = ips.[index_id]
+ Where ips.[database_id] = DB_ID()
+ and not i.[name] is null;
+
+Go
+
+IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Succeeded'
+ELSE PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Error on Creation'
+GO
+
+
+
+If Exists(Select * From sys.views Where Name = N'vwSysInfo_UserTables')
+ Drop View [dbo].[vwSysInfo_UserTables];
+Go
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: (System Info) Master View for User Tables with Columns
+==========================================================================================================
+*/
+Create View [dbo].[vwSysInfo_UserTables]
+As
+
+ Select OBJECT_SCHEMA_NAME(t.[object_id],DB_ID()) as 'SchemaName',
+ t.[name] as 'TableName',
+ ac.[name] as 'ColumnName',
+ ac.[column_id]as 'ColumnOrder',
+ ty.[name] as 'DataType',
+ ac.[max_length] as 'MaxLength',
+ ac.[precision] as 'Precision',
+ ac.[scale] as 'Scale',
+ ac.[is_nullable] as 'IsNullable',
+ ac.[is_ansi_padded] as 'IsAnsiPadded',
+ ac.[is_identity] as 'IsIdentity',
+ object_definition(ac.[default_object_id]) as 'DefaultValue'
+ From sys.[tables] t With (NoLock)
+ inner join sys.[all_columns] ac With (NoLock) on t.[object_id] = ac.[object_id]
+ inner join sys.[types] ty With (NoLock) on ac.[system_type_id] = ty.[system_type_id] and ac.[user_type_id] = ty.[user_type_id]
+ Where t.[is_ms_shipped] = 0; -- Indicates if table is from Microsoft or User Created
+
+GO
+
+IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_UserTables] Succeeded'
+ELSE PRINT 'View Creation: [vwSysInfo_UserTables] Error on Creation'
+GO
+
+
+
+
+IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_UtilityCheckIndexes]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
+ DROP Procedure [dbo].[vesp_UtilityCheckIndexes];
+GO
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: Rebuild / Reorganize all Indexes in the database based on their current average fragmentation
+ Note** @LowerFragCutoff value should always be less than the @UpperFragCutoff value,
+ if not then @@LowerFragCutoff value witll be automatically set to the @UpperFragCutoff value
+
+ Parameters: @UpperFragCutoff Fragmentation Cutoff Value for Rebuild vs Reorganize (30.0 Recommended)
+ @LowerFragCutoff Average Fragmentation Cutoff Value for Initial Index Selection (10.0 Recommended)
+ @IsPrint Print the Commands Indicator (1 = Print Commands, 0 = Dont Print Commands)
+ @IsExecute Execute the Commands Indicator (1 = Execute Commands, 0 = Dont Execute Commands)
+
+Examples: exec [dbo].[vesp_UtilityCheckIndexes] null, null, null, null; -- Use default values and only execute the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] null, null, 1, 0; -- Use the Upper Cutoff and Lower Cutoff default values and only print the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] null, null, 0, 1; -- Use the Upper Cutoff and Lower Cutoff default values and only execute the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] 30.0, null, 1, 0; -- Override Upper Cutoff, use the Lower Cutoff default value and print and execute the commands
+==========================================================================================================
+ */
+Create Procedure [dbo].[vesp_UtilityCheckIndexes] (@UpperFragCutoff float = null, @LowerFragCutoff float = null,
+ @IsPrint Bit = null, @IsExecute Bit = null)
+With Execute As Owner
+As
+Begin
+
+ Set NoCount On;
+
+ -- Declare Local Variables
+ Declare @ObjectID int;
+ Declare @IndexID int;
+ Declare @PartitionCount bigint;
+ Declare @SchemaName nvarchar(130);
+ Declare @ObjectName nvarchar(130);
+ Declare @IndexName nvarchar(130);
+ Declare @PartitionNum bigint;
+ Declare @IndexAvgFrag float;
+ Declare @Command nvarchar(4000);
+
+ -- Set Default Values
+ If (@UpperFragCutoff is null) Set @UpperFragCutoff = 10.0;
+ If (@LowerFragCutoff is null) Set @LowerFragCutoff = 2.0;
+ If (@IsPrint is null) Set @IsPrint = 0;
+ If (@IsExecute is null) Set @IsExecute = 1;
+
+ -- Check if Lower Cutoff is greater than Upper Cutoff
+ If (@LowerFragCutoff > @UpperFragCutoff) Set @LowerFragCutoff = @UpperFragCutoff;
+
+
+ -- Conditionally select tables and indexes from the sys.dm_db_index_physical_stats function
+ -- and convert object and index IDs to names.
+
+ Select object_id as 'ObjectID',
+ index_id as 'IndexID',
+ partition_number as 'PartitionNum',
+ avg_fragmentation_in_percent as 'AvgFrag'
+ Into #work_to_do
+ From sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
+ Where avg_fragmentation_in_percent > @LowerFragCutoff AND index_id > 0;
+
+ -- Declare the cursor for the list of partitions to be processed.
+ Declare cursor_Partitions Cursor For
+ Select ObjectID, IndexID, PartitionNum, AvgFrag
+ From #work_to_do;
+
+ -- Open the cursor.
+ Open cursor_Partitions;
+
+ -- Loop through the partitions.
+ While (1=1)
+
+ Begin;
+
+ Fetch Next From cursor_Partitions Into @ObjectID, @IndexID, @PartitionNum, @IndexAvgFrag;
+
+ IF (@@FETCH_STATUS < 0) Break;
+
+ Select @ObjectName = QUOTENAME(o.name), @SchemaName = QUOTENAME(s.name)
+ From sys.objects as o
+ join sys.schemas as s on s.schema_id = o.schema_id
+ Where o.object_id = @ObjectID;
+
+ Select @IndexName = QUOTENAME(name)
+ From sys.indexes
+ Where object_id = @ObjectID AND index_id = @IndexID;
+
+ Select @PartitionCount = Count(*)
+ From sys.partitions
+ Where object_id = @ObjectID AND index_id = @IndexID;
+
+ Set @Command = '';
+
+ -- Determine whether to rebuild or reorganize
+ IF (@IndexAvgFrag < @UpperFragCutoff)
+ Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REORGANIZE;';
+
+ IF (@IndexAvgFrag >= @UpperFragCutoff)
+ Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REBUILD;';
+
+ IF (@PartitionCount > 1)
+ Set @Command = @Command + N' PARTITION=' + Cast(@PartitionNum AS nvarchar(10));
+
+ -- Print command if enabled
+ If (@IsPrint = 1) Print @Command;
+
+ -- Execute command if enabled
+ If (@IsExecute = 1) Exec (@Command);
+
+ End;
+
+ -- Close and deallocate the cursor
+ Close cursor_Partitions;
+ Deallocate cursor_Partitions;
+
+ -- Drop the temporary table
+ Drop Table #work_to_do;
+
+ Return;
+End
+Go
+
+IF (@@Error = 0) PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Succeeded'
+ELSE PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblEntriesDeleteStatusDocID')
+ Drop Index [IX_tblEntriesDeleteStatusDocID] on [dbo].[tblEntries]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblEntriesDeleteStatusDocID]
+ON [dbo].[tblEntries] ([DeleteStatus] ASC)
+INCLUDE ([DocID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblEntriesDeleteStatusDocID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblEntriesDeleteStatusDocID] Error on Creation'
+GO
+
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblAnnotationsDeleteStatusAnnotationID')
+ Drop Index [IX_tblAnnotationsDeleteStatusAnnotationID] on [dbo].[tblAnnotations]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblAnnotationsDeleteStatusAnnotationID]
+ON [dbo].[tblAnnotations] ([DeleteStatus] ASC)
+INCLUDE ([AnnotationID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblAnnotationsDeleteStatusAnnotationID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblAnnotationsDeleteStatusAnnotationID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblContentsDeleteStatusContentID')
+ Drop Index [IX_tblContentsDeleteStatusContentID] on [dbo].[tblContents]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblContentsDeleteStatusContentID]
+ON [dbo].[tblContents] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblContentsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblContentsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblDocumentsDeleteStatusDocID')
+ Drop Index [IX_tblDocumentsDeleteStatusDocID] on [dbo].[tblDocuments]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblDocumentsDeleteStatusDocID]
+ON [dbo].[tblDocuments] ([DeleteStatus] ASC)
+INCLUDE ([DocID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblDocumentsDeleteStatusDocID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblDocumentsDeleteStatusDocID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblGridsDeleteStatusContentID')
+ Drop Index [IX_tblGridsDeleteStatusContentID] on [dbo].[tblGrids]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblGridsDeleteStatusContentID]
+ON [dbo].[tblGrids] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblGridsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblGridsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblImagesDeleteStatusContentID')
+ Drop Index [IX_tblImagesDeleteStatusContentID] on [dbo].[tblImages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblImagesDeleteStatusContentID]
+ON [dbo].[tblImages] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblImagesDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblImagesDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblItemsDeleteStatusItemID')
+ Drop Index [IX_tblItemsDeleteStatusItemID] on [dbo].[tblItems]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblItemsDeleteStatusItemID]
+ON [dbo].[tblItems] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblItemsDeleteStatusItemID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblItemsDeleteStatusItemID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemIDContentID')
+ Drop Index [IX_tblPartsDeleteStatusItemIDContentID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemIDContentID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ItemID], [ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemIDContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemIDContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemID')
+ Drop Index [IX_tblPartsDeleteStatusItemID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ItemID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusContentID')
+ Drop Index [IX_tblPartsDeleteStatusContentID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusContentID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusContentID')
+ Drop Index [IX_tblROUsagesDeleteStatusContentID] on [dbo].[tblROUsages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusContentID]
+ON [dbo].[tblROUsages] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusRODbID')
+ Drop Index [IX_tblROUsagesDeleteStatusRODbID] on [dbo].[tblROUsages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusRODbID]
+ON [dbo].[tblROUsages] ([DeleteStatus] ASC)
+INCLUDE (RODbID)
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusRODbID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusRODbID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblTransitionsDeleteStatusTransitionID')
+ Drop Index [IX_tblTransitionsDeleteStatusTransitionID] on [dbo].[tblTransitions]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblTransitionsDeleteStatusTransitionID]
+ON [dbo].[tblTransitions] ([DeleteStatus] ASC)
+INCLUDE (TransitionID)
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblTransitionsDeleteStatusTransitionID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblTransitionsDeleteStatusTransitionID] Error on Creation'
+GO
+
+
+
+
+-- Rebuild / Reorganize All Indexes
+exec [dbo].[vesp_UtilityCheckIndexes];
+
+
+IF (@@Error = 0) PRINT 'Running vesp_UtilityCheckIndexes Succeeded'
+ELSE PRINT 'Running vesp_UtilityCheckIndexes Failed to Execute'
+GO
+
+
+
+
+
-----------------------------------------------------------------------------
/*
---------------------------------------------------------------------------
@@ -16695,8 +17379,10 @@ BEGIN TRY -- Try Block
set nocount on
DECLARE @RevDate varchar(255)
DECLARE @RevDescription varchar(255)
- set @RevDate = '07/06/2021 12:16 PM'
- set @RevDescription = 'Added vesp_RemoveUnUsedFormat'
+
+ set @RevDate = '08/26/2021 12:12 PM'
+ set @RevDescription = 'Improved search performace and removed locking / Added views & Procs to rebuild / reorganize fragmented indexes'
+
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
IF( @@TRANCOUNT > 0 ) COMMIT
@@ -16711,4 +17397,5 @@ GO
IF (@@Error = 0) PRINT 'StoredProcedure [vesp_GetSQLCodeRevision] Succeeded'
ELSE PRINT 'StoredProcedure [vesp_GetSQLCodeRevision] Error on Creation'
go
-vesp_GetSQLCodeRevision
+
+Exec vesp_GetSQLCodeRevision;
diff --git a/PROMS/VEPROMS User Interface/PROMSFixes.Sql b/PROMS/VEPROMS User Interface/PROMSFixes.Sql
index 5693daee..ce6d0c7f 100644
--- a/PROMS/VEPROMS User Interface/PROMSFixes.Sql
+++ b/PROMS/VEPROMS User Interface/PROMSFixes.Sql
@@ -1,3 +1,5 @@
+
+
if db_name() in('master','model','msdn','tempdb')
begin
DECLARE @ErrorMsg varchar(255)
@@ -1454,204 +1456,453 @@ IF (@@Error = 0) PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemI
ELSE PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemID Error on Creation'
GO
-IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
- DROP FUNCTION [vefn_GetUnitPrefix];
+
+
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[ve_GetFolderPath]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
+ DROP FUNCTION [dbo].[ve_GetFolderPath];
+
GO
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
/*
-select 'DocVersions' Type, VersionID, Config, .dbo.vefn_GetUnitPrefix(config) UnitPrefix from DocVersions
-UNION select 'Blank' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'Null' Type, 0 VersionID, null Config, .dbo.vefn_GetUnitPrefix(null) UnitPrefix
-UNION select 'XML with' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'XML without' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-UNION select 'XML empty' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
-*/
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns the Folder Path for a specified Document Version using recursion
+ 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement
+
+ Parameters: @VersionID Document Version ID
+
+ Examples: Select VersionID,Name,dbo.ve_GetFolderPath(VersionID) from DocVersions order by VersionID;
+==========================================================================================================
+ */
+Create Function [dbo].[ve_GetFolderPath] (@VersionID int)
+Returns VarChar(Max)
+With Execute as Owner
+as
+Begin
+
+ Declare @Path VarChar(Max);
+
+ With zFolders ([Level], FolderID, [Path])
+ as (
+
+ Select 1 as 'Level',
+ dv.FolderID as 'FolderID',
+ Cast(dv.[Name] as VarChar(Max)) as 'Path'
+ From DocVersions dv with (NoLock)
+ Where dv.VersionID = @VersionID
+
+ Union All
+
+ Select f.ParentID - (Select ParentID from Folders where FolderID = f.ParentID) as 'Level',
+ f.ParentID as 'FolderID',
+ Cast(f.[Name] + char(7) + zf.[Path] as VarChar(Max)) as 'Path'
+ From Folders f with (NoLock)
+ inner join zFolders zf on f.FolderID = zf.FolderID
+ Where f.FolderID <> f.ParentID
+
+ )
+ Select @Path = zf.[Path]
+ From zFolders zf
+ Where zf.[Level] = 0;
+
+ return @Path;
+
+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'[dbo].[vefn_GetUnitPrefix]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_GetUnitPrefix];
+GO
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE function [dbo].[vefn_GetUnitPrefix](@config varchar(MAX))
-returns varchar(MAX)
-begin
- declare @Xml xml
- set @Xml = cast(@config as xml)
- declare @UnitPrefix varchar(MAX)
- set @UnitPrefix = (select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') UnitPrefix from @XML.nodes('//Unit') as tmpXml(v))
- return isnull(@UnitPrefix,'')
-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('')
-*/
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns the Unit Prefix from the specified Xml Configuration Data
+ 08/20/2021 Jake Ropar: Reformatted and added With Execute as Owner statement
+
+ Parameters: @Config Xml Configuration Data
+
+ Examples: Select 'DocVersions' Type, VersionID, Config, .dbo.vefn_GetUnitPrefix(config) UnitPrefix from DocVersions
+ UNION select 'Blank' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'Null' Type, 0 VersionID, null Config, .dbo.vefn_GetUnitPrefix(null) UnitPrefix
+ UNION select 'XML with' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'XML without' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+ UNION select 'XML empty' Type, 0 VersionID, '' Config, .dbo.vefn_GetUnitPrefix('') UnitPrefix
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_GetUnitPrefix](@Config varchar(MAX))
+Returns VarChar(Max)
+With Execute as Owner
+as
+Begin
+
+ Declare @Xml xml;
+ Declare @UnitPrefix VarChar(Max);
+
+ Set @Xml = Cast(@Config as xml)
+
+ Set @UnitPrefix = (Select Replace(v.value('@ProcedureNumber', 'nvarchar(100)'),'#','') as 'UnitPrefix' From @XML.nodes('//Unit') as tmpXml(v))
+
+ Return IsNull(@UnitPrefix,'');
+
+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'[dbo].[vefn_DocVersionSplit]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_DocVersionSplit];
+
+GO
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE FUNCTION [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
-RETURNS @IDs TABLE
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2012
+ Description: Returns a table of document version info from a comma delimited list of specified document version IDs
+ 08/20/2021 Jake Ropar: Add with (NoLock) statements to prevent table locking
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs (pass '' or null to retrieve all versions)
+
+ Examples: select * from vefn_DocVersionSplit('1,4');
+ select * from vefn_DocVersionSplit(null);
+ select * from vefn_DocVersionSplit('');
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX))
+Returns @IDs Table
(
- VersionID int PRIMARY KEY,
- ItemID int,
- DVPath varchar(MAX),
- UnitPrefix varchar(MAX)
+ VersionID Int Primary Key,
+ ItemID Int,
+ DVPath VarChar(Max),
+ UnitPrefix VarChar(MAX)
)
-WITH EXECUTE AS OWNER
-AS
-BEGIN
-IF(isnull(@DocVersionList,'') = '')
- Insert into @IDs
- Select VersionID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config)
- from DocVersions where ItemID is not null
-else
- Insert into @IDs
- Select ID, ItemID, dbo.ve_GetFolderPath(VersionID), .dbo.vefn_GetUnitPrefix(config)
- from vefn_SplitInt(@DocVersionList,',') as T
- join DocVersions DV on VersionID = T.ID
-RETURN
-END
+With Execute as Owner
+as
+Begin
-GO
+ If(IsNull(@DocVersionList,'') = '')
+ Insert into @IDs
+ Select dv.VersionID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), dbo.vefn_GetUnitPrefix(dv.Config)
+ From DocVersions dv with (NoLock) Where dv.ItemID is not null;
+ Else
+ Insert into @IDs
+ Select t.ID, dv.ItemID, dbo.ve_GetFolderPath(dv.VersionID), .dbo.vefn_GetUnitPrefix(dv.config)
+ From dbo.vefn_SplitInt(@DocVersionList,',') as t
+ inner join DocVersions dv with (NoLock) on dv.VersionID = t.ID;
+
+ 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];
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vefn_SiblingAndChildrenItemsNewByWord]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
+ DROP FUNCTION [dbo].[vefn_SiblingAndChildrenItemsNewByWord];
GO
-/*
-select * from vefn_SiblingAndChildrenItems('146','')
-*/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
- Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+ Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
-CREATE FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(MAX),@UnitPrefix varchar(MAX))
-RETURNS @SiblingAndChildren TABLE
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2021
+ Description: Returns all items mathcing the specified search critera, filtered by a list of specified document versions
+ 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions)
+ @UnitPrefix The unit prefix to use when building the item path
+ @SearchString Search string criteria
+ @SearchStringx Alternate search string criteria
+ @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections)
+
+ Examples: 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:\\-]%','');
+==========================================================================================================
+ */
+Create Function [dbo].[vefn_SiblingAndChildrenItemsNewByWord](@DocVersionList VarChar(Max), @UnitPrefix VarChar(Max), @SearchString VarChar(Max),
+ @SearchStringx VarChar(Max), @StepTypeList VarChar(Max))
+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)
+ 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='.'
-BEGIN
-with Itemz([ItemID], [DVPath], [Level], [ParentID], [Ordinal], [PreviousID], [FromType], [ContentID], [DTS], [UserID],[pContentID],
- [pDTS],[pUserID],PPath, [Path], [IsRNO], [POrdinalPath], [OrdinalPath], [UnitPrefix]) as (
- Select [I].[ItemID], DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID]
- ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID],
- Cast('' as nvarchar(max)) [PPath],
- Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + Isnull(C.Number,'') + @DelimNumber + Isnull(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 I.[ItemID], DVPath, [Level] + 1,Z.ItemID,0, I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],
- P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID]
- ,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,
- 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
- 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,
- 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', 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 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 + 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, 0,
- POrdinalPath,
- POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), UnitPrefix
- from Itemz Z
- join Items I on I.PreviousID = Z.ItemID
- join Contents C on C.ContentID = I.ContentID
- --where Z.[Level] > 0
+With Execute as Owner
+as
+Begin
-)
-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
+ -- Declare Local Variables
+ Declare @Delim Char(1);
+ Declare @DelimNumber Char(1);
+ Declare @DelimStep Char(1);
+ declare @TextPrefix nVarChar(1);
+ declare @TextSuffix nVarChar(1);
+
+ -- Set Default Values
+ Set @Delim = Char(7);
+ Set @DelimNumber = Char(17);
+ Set @DelimStep = '.';
+ Set @TextPrefix = '';
+ Set @TextSuffix = '';
+
+ -- Check Input Parameters
+ If (@SearchString Like '[%]%') Set @TextPrefix = '~';
+ if (@SearchString Like '%[%]') Set @TextSuffix = '~';
+
+
+ With zItems (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 (
+
+ -- Parent Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ dv.VersionID as 'VersionID',
+ Cast((Case When (c.[Type] < 20000) Then @Delim + @UnitPrefix + IsNull(c.Number,'') + @DelimNumber + IsNull(c.[Text],'') Else '1' End) as nVarChar(Max)) as 'Path',
+ 0 as 'FromType',
+ 0 as 'Ordinal',
+ 0 as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ 0 as 'pContentID',
+ i.DTS as 'pDTS',
+ i.UserID as 'pUserID',
+ 0 as 'IsRNO',
+ c.[Text] as 'Text',
+ c.Number as 'Number',
+ Cast('' as nVarChar(Max)) as 'PPath',
+ c.Type as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as VarBinary(8)) as 'CLastChanged',
+ Cast(0 as VarBinary(8)) as 'PLastChanged'
+ From Items i with (NoLock)
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+ join dbo.vefn_DocVersionSplit(@DocVersionList) dv on i.ItemID = dv.ItemID
+
+ Union All
+
+ -- Children Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ zi.VersionID as 'VersionID',
+ zi.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 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 (zi.FromType < 3) Then @Delim Else @DelimStep End + Cast(1 as varchar(4))
+ End
+ End as 'Path',
+ p.FromType as 'FromType',
+ 0 as 'Ordinal',
+ zi.ItemID as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ p.ContentID as 'pContentID',
+ p.DTS as 'pDTS',
+ p.UserID as 'pUserID',
+ Case When (p.FromType = 5) Then -1 Else 0 End as 'IsRNO',
+ c.Text as 'Text',
+ c.Number as 'Number',
+ zi.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 as 'PPath',
+ c.[Type] as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as varbinary(8)) as 'CLastChanged',
+ Cast(p.LastChanged as varbinary(8)) as 'PLastChanged'
+ From zItems zi
+ join Parts p with (NoLock) on p.ContentID = zi.ContentID
+ join Items i with (NoLock) on i.ItemID = p.ItemID
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+
+ Union All
+
+ -- Sibling Records
+ Select Cast(i.LastChanged as varbinary(8)) as 'ILastChanged',
+ i.ItemID as 'ItemID',
+ zi.VersionID as 'VersionID',
+ zi.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(zi.Path) = '.') Then @DelimStep Else @Delim End + Cast(zi.Ordinal + 2 as varchar(4))
+ End as 'Path',
+ zi.FromType as 'FromType',
+ zi.Ordinal + 1 as 'Ordinal',
+ zi.ParentID as 'ParentID',
+ i.PreviousID as 'PreviousID',
+ i.ContentID as 'ContentID',
+ i.DTS as 'DTS',
+ i.UserID as 'UserID',
+ Null as 'pContentID',
+ Null as 'pDTS',
+ Null as 'pUserID',
+ 0 as 'IsRNO',
+ c.[text] as 'Text',
+ c.Number as 'Number',
+ zi.PPath as 'PPath',
+ c.[Type] as 'CType',
+ c.FormatID as 'CFormatID',
+ c.Config as 'CConfig',
+ c.DTS as 'CDTS',
+ c.UserID as 'CUserID',
+ Cast(c.LastChanged as varbinary(8)) as 'CLastChanged',
+ Cast(0 as varbinary(8)) as 'PLastChanged'
+ From zItems zi
+ join Items i with (NoLock) on i.PreviousID = zi.ItemID
+ join Contents c with (NoLock) on c.ContentID = i.ContentID
+
+ )
+ Insert Into @SiblingAndChildren
+ Select zi.ILastChanged,
+ zi.ItemID,
+ dv.DVPath,
+ zi.Path,
+ zi.FromType,
+ zi.Ordinal,
+ zi.ParentID,
+ zi.PreviousID,
+ zi.ContentID,
+ zi.DTS,
+ zi.UserID,
+ zi.pContentID,
+ zi.pDTS,
+ zi.pUserID,
+ zi.IsRNO,
+ zi.Text,
+ d.DocAscii,
+ zi.Number,
+ zi.CType,
+ zi.CFormatID,
+ zi.CConfig,
+ zi.DTS,
+ zi.CUserID,
+ zi.CLastChanged,
+ zi.PLastChanged
+ From zItems zi
+ join dbo.vefn_DocVersionSplit(@DocVersionList) dv on dv.VersionID = zi.VersionID
+ left join Entries e with (NoLock) on e.ContentID = zi.ContentID
+ left join Documents d with (NoLock) on d.DocID = e.DocID
+ Where (@TextPrefix + zi.[Text] + @TextSuffix like @SearchString Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchString
+ Or @TextPrefix + zi.[Text] + @TextSuffix like @SearchStringx Or Replace(d.DocAscii, nChar(176), '\''B0') like @SearchStringx)
+ And (IsNull(@StepTypeList,'') = '' or (dbo.vefn_AllSections(zi.CType) in (Select ID from dbo.vefn_SplitInt(@StepTypeList,','))))
+ Option (Recompile, MaxRecursion 10000);
+
+ 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];
@@ -15584,325 +15835,306 @@ 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
+
+
+
+IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
+ DROP Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord];
GO
-IF (@@Error = 0) PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Succeeded'
-ELSE PRINT 'Function: vefn_SiblingAndChildrenItemsNewByWord Error on Creation'
+SET ANSI_NULLS ON
GO
-
-IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildrenNewByWord]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
-DROP PROCEDURE [vesp_SearchItemAndChildrenNewByWord];
+SET QUOTED_IDENTIFIER ON
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)
+/*
+==========================================================================================================
+ Author: Rich Mark
+ Create Date: 01/01/2020
+ Description: Returns all items mathcing the specified search critera, filtered by a list of specified Document Versions and Step Types
+ 08/20/2021 Jake Ropar: Add with (NoLock) and Option (Recompile) statements to eliminate UI locking and improve performace, also changed all
+ Select (*) statements to Select (1) for performace reasons
+
+ Parameters: @DocVersionList Comma delimited list of document version IDs used to filter search results (pass '' or null to include all versions)
+ @StepTypeList Comma delimited list of of step types used to filter search results (pass '' or null to include all step type sections)
+ @SearchString Search string criteria
+ @CaseSensitive Indicator for Case Sensitive Search (0 = False, 1 = True)
+ @IncludeLinks Indicator to include Links in results (0 = False, 1 = True)
+ @IncludeRtfFormatting Indicator to include RTF Formatting in results (0 = False, 1 = True)
+ @IncludeSpecialCharacters Indicator to include Special Characters in results (0 = False, 1 = True)
+ @UnitPrefix Specified Unit Prefix if any
+ @ByWordPrefix Word Prefix for the specified search string criteria
+ @ByWordSuffix Word Suffix for the specified search string criteria
+
+
+ Examples: 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,'','','';
+==========================================================================================================
+ */
+Create Procedure [dbo].[vesp_SearchItemAndChildrenNewByWord] (@DocVersionList VarChar(Max), @StepTypeList VarChar(Max), @SearchString VarChar(Max), @CaseSensitive Int,
+ @IncludeLinks Int, @IncludeRtfFormatting Int, @IncludeSpecialCharacters Int, @UnitPrefix VarChar(Max),
+ @ByWordPrefix VarChar(64), @ByWordSuffix VarChar(64))
+With Execute As Owner
+As
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
+
+ Set NoCount On;
+
+ -- Declare Local Variables
+ Declare @TextPrefix nVarChar(1);
+ Declare @TextSuffix nVarChar(1);
+ Declare @SearchStringx nVarChar(200);
+
+ -- Set Default Values
+ Set @TextPrefix = '';
+ Set @TextSuffix = '';
+
+ Set @SearchString = dbo.vefn_FixSearchStringByWord(@SearchString, @ByWordPrefix, @ByWordSuffix);
+ If (@SearchString like '[%]%') Set @TextPrefix = '~';
+ If (@SearchString like '%[%]') Set @TextSuffix = '~';
+ Set @SearchStringx = Replace(@SearchString,'\u8209?','-') -- [John Jenko] B2016-209: not finding dashes in Word sections (FixSearchString converts '-' to '\u8209?')
+
+
+ If (@IncludeLinks + @IncludeRtfFormatting + @IncludeSpecialCharacters = 0)
+ Begin
+
+ If (@CaseSensitive = 0)
+ Begin
+
+ --Select 'Case #1: No Links/RtfFormatting/SpecialCharacters & Not Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+ Else
+ Begin
+
+ --Select 'Case #2: No Links/RtfFormatting/SpecialCharacters & Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (@TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ or @TextPrefix + z.Text + @TextSuffix Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx
+ or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ End -- no links
+
+ Else
+
+ Begin -- include linked text
+
+ If (@CaseSensitive = 0)
+ Begin
+
+ --Select 'Case #3: Include Links/RtfFormatting/SpecialCharacters & Not Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchString
+ Or dbo.vefn_RemoveExtraText(@TextPrefix + z.Text + @TextSuffix, @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx
+ Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchString
+ Or Replace(z.DocAscii, nChar(176), '\''B0') Collate SQL_Latin1_General_CP1_CI_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ Else -- case sensitive
+
+ Begin
+
+ --Select 'Case #4: Include Links/RtfFormatting/SpecialCharacters & Case Sensitive';
+
+ Select z.DvPath as 'DvPath',
+ z.[Path] as 'Path',
+ z.FromType as 'FromType',
+ z.Ordinal as 'Ordinal',
+ z.ParentID as 'ParentID',
+ z.ItemID as 'ItemID',
+ z.PreviousID as 'PreviousID',
+ z.ContentID as 'ContentID',
+ z.DTS as 'DTS',
+ z.UserID as 'UserID',
+ z.ILastChanged as 'ILastChanged',
+ z.Number as 'Number',
+ z.[Text] as 'Text',
+ z.CType as 'Type',
+ z.CFormatID as 'FormatID',
+ z.CConfig as 'Config',
+ z.CDTS as 'CDTS',
+ z.CUserID as 'CUserID',
+ z.CLastChanged as 'cLastChanged',
+ z.pContentID as 'pContentID',
+ z.pDTS as 'pDTS',
+ z.pUserID as 'pUserID',
+ z.PLastChanged as 'pLastChanged',
+ (Select Count(1) From Annotations a with (NoLock) Where a.ItemID = z.ItemID) as 'AnnotationCount',
+ (Select Count(1) From DocVersions dv with (NoLock) Where dv.ItemID = z.ItemID) as 'DocVersionCount',
+ (Select Count(1) From Items i with (NoLock) Where i.PreviousID = z.ItemID) as 'NextCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ItemID = z.ItemID) as 'PartCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.RangeID = z.ItemID) as 'Transition_RangeIDCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.ToID = z.ItemID) as 'Transition_ToIDCount',
+ (Select Count(1) From Details d with (NoLock) Where d.ContentID = z.ContentID) as 'DetailCount',
+ (Select Count(1) From Entries e with (NoLock) Where e.ContentID = z.ContentID) as 'EntryCount',
+ (Select Count(1) From Grids g with (NoLock) Where g.ContentID = z.ContentID) as 'GridCount',
+ (Select Count(1) From Images i with (NoLock) Where i.ContentID = z.ContentID) as 'ImageCount',
+ (Select Count(1) From Items i with (NoLock) Where i.ContentID = z.ContentID) as 'ItemCount',
+ (Select Count(1) From Parts p with (NoLock) Where p.ContentID = z.ContentID) as 'cPartCount',
+ (Select Count(1) From RoUsages ru with (NoLock) Where ru.ContentID = z.ContentID) as 'RoUsageCount',
+ (Select Count(1) From Transitions t with (NoLock) Where t.FromID = z.ContentID) as 'TransitionCount',
+ (Select Count(1) From ZContents zc with (NoLock) Where zc.ContentID = z.ContentID) as 'ZContentCount'
+ From dbo.vefn_SiblingAndChildrenItemsNewByWord(@DocVersionList, @UnitPrefix, @SearchString, @SearchStringx, @StepTypeList) z
+ Where (dbo.vefn_RemoveExtraText(Replace(@TextPrefix + z.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 + z.Text + @TextSuffix,'\''b0', '\''B0'), @IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) Collate SQL_Latin1_General_CP1_CS_AS like Replace(@SearchStringx,'\''b0', '\''B0')
+ Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchString
+ Or Replace(z.DocAscii,nChar(176),'\''B0') Collate SQL_Latin1_General_CP1_CS_AS like @SearchStringx)
+ Order By z.DvPath Asc
+ Option (Recompile);
+
+ End
+
+ End -- include links
+
+End
+Go
+
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Succeeded'
ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildrenNewByWord Error on Creation'
GO
+
+
+
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[DeleteItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [DeleteItemAndChildren];
GO
@@ -16670,6 +16902,458 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
GO
+
+
+
+
+If Exists(Select * From sys.views Where Name = N'vwSysInfo_IndexFragmentation')
+ Drop View [dbo].[vwSysInfo_IndexFragmentation];
+Go
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: (System Info) Master View for Table Index Fragmentation
+==========================================================================================================
+*/
+Create View [dbo].[vwSysInfo_IndexFragmentation]
+As
+
+ Select s.[name] as 'SchemaName',
+ t.[name] as 'TableName',
+ i.[name] as 'IndexName',
+ i.is_primary_key as 'IsPrimaryKey',
+ i.fill_factor as 'FillFactor',
+ ips.[avg_fragmentation_in_percent] as 'AvgFragmentation',
+ ips.[page_count] as 'PageCount',
+ ips.index_level as 'IndexLevel',
+ ips.index_depth as 'IndexDepth',
+ Case When (ips.[avg_fragmentation_in_percent] > 30) Then 'Rebuild'
+ When (ips.[avg_fragmentation_in_percent] > 5) Then 'Reorganize'
+ Else 'None'
+ End as 'SuggestedAction'
+ From sys.[dm_db_index_physical_stats] (DB_ID(), NULL, NULL, NULL, NULL) as ips
+ inner join sys.[tables] t With (NoLock) on t.[object_id] = ips.[object_id]
+ inner join sys.[schemas] s With (NoLock) on t.[schema_id] = s.[schema_id]
+ inner join sys.[indexes] i With (NoLock) on i.[object_id] = ips.[object_id] And i.[index_id] = ips.[index_id]
+ Where ips.[database_id] = DB_ID()
+ and not i.[name] is null;
+
+Go
+
+IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Succeeded'
+ELSE PRINT 'View Creation: [vwSysInfo_IndexFragmentation] Error on Creation'
+GO
+
+
+
+If Exists(Select * From sys.views Where Name = N'vwSysInfo_UserTables')
+ Drop View [dbo].[vwSysInfo_UserTables];
+Go
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: (System Info) Master View for User Tables with Columns
+==========================================================================================================
+*/
+Create View [dbo].[vwSysInfo_UserTables]
+As
+
+ Select OBJECT_SCHEMA_NAME(t.[object_id],DB_ID()) as 'SchemaName',
+ t.[name] as 'TableName',
+ ac.[name] as 'ColumnName',
+ ac.[column_id]as 'ColumnOrder',
+ ty.[name] as 'DataType',
+ ac.[max_length] as 'MaxLength',
+ ac.[precision] as 'Precision',
+ ac.[scale] as 'Scale',
+ ac.[is_nullable] as 'IsNullable',
+ ac.[is_ansi_padded] as 'IsAnsiPadded',
+ ac.[is_identity] as 'IsIdentity',
+ object_definition(ac.[default_object_id]) as 'DefaultValue'
+ From sys.[tables] t With (NoLock)
+ inner join sys.[all_columns] ac With (NoLock) on t.[object_id] = ac.[object_id]
+ inner join sys.[types] ty With (NoLock) on ac.[system_type_id] = ty.[system_type_id] and ac.[user_type_id] = ty.[user_type_id]
+ Where t.[is_ms_shipped] = 0; -- Indicates if table is from Microsoft or User Created
+
+GO
+
+IF (@@Error = 0) PRINT 'View Creation: [vwSysInfo_UserTables] Succeeded'
+ELSE PRINT 'View Creation: [vwSysInfo_UserTables] Error on Creation'
+GO
+
+
+
+
+IF EXISTS (Select * From dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[vesp_UtilityCheckIndexes]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
+ DROP Procedure [dbo].[vesp_UtilityCheckIndexes];
+GO
+
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+
+/*****************************************************************************
+ Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
+ Copyright 2020 - Volian Enterprises, Inc. All rights reserved.
+*****************************************************************************/
+/*
+==========================================================================================================
+ Author: Jake Ropar
+ Create Date: 08/23/2021
+ Description: Rebuild / Reorganize all Indexes in the database based on their current average fragmentation
+ Note** @LowerFragCutoff value should always be less than the @UpperFragCutoff value,
+ if not then @@LowerFragCutoff value witll be automatically set to the @UpperFragCutoff value
+
+ Parameters: @UpperFragCutoff Fragmentation Cutoff Value for Rebuild vs Reorganize (30.0 Recommended)
+ @LowerFragCutoff Average Fragmentation Cutoff Value for Initial Index Selection (10.0 Recommended)
+ @IsPrint Print the Commands Indicator (1 = Print Commands, 0 = Dont Print Commands)
+ @IsExecute Execute the Commands Indicator (1 = Execute Commands, 0 = Dont Execute Commands)
+
+Examples: exec [dbo].[vesp_UtilityCheckIndexes] null, null, null, null; -- Use default values and only execute the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] null, null, 1, 0; -- Use the Upper Cutoff and Lower Cutoff default values and only print the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] null, null, 0, 1; -- Use the Upper Cutoff and Lower Cutoff default values and only execute the commands
+ exec [dbo].[vesp_UtilityCheckIndexes] 30.0, null, 1, 0; -- Override Upper Cutoff, use the Lower Cutoff default value and print and execute the commands
+==========================================================================================================
+ */
+Create Procedure [dbo].[vesp_UtilityCheckIndexes] (@UpperFragCutoff float = null, @LowerFragCutoff float = null,
+ @IsPrint Bit = null, @IsExecute Bit = null)
+With Execute As Owner
+As
+Begin
+
+ Set NoCount On;
+
+ -- Declare Local Variables
+ Declare @ObjectID int;
+ Declare @IndexID int;
+ Declare @PartitionCount bigint;
+ Declare @SchemaName nvarchar(130);
+ Declare @ObjectName nvarchar(130);
+ Declare @IndexName nvarchar(130);
+ Declare @PartitionNum bigint;
+ Declare @IndexAvgFrag float;
+ Declare @Command nvarchar(4000);
+
+ -- Set Default Values
+ If (@UpperFragCutoff is null) Set @UpperFragCutoff = 10.0;
+ If (@LowerFragCutoff is null) Set @LowerFragCutoff = 2.0;
+ If (@IsPrint is null) Set @IsPrint = 0;
+ If (@IsExecute is null) Set @IsExecute = 1;
+
+ -- Check if Lower Cutoff is greater than Upper Cutoff
+ If (@LowerFragCutoff > @UpperFragCutoff) Set @LowerFragCutoff = @UpperFragCutoff;
+
+
+ -- Conditionally select tables and indexes from the sys.dm_db_index_physical_stats function
+ -- and convert object and index IDs to names.
+
+ Select object_id as 'ObjectID',
+ index_id as 'IndexID',
+ partition_number as 'PartitionNum',
+ avg_fragmentation_in_percent as 'AvgFrag'
+ Into #work_to_do
+ From sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
+ Where avg_fragmentation_in_percent > @LowerFragCutoff AND index_id > 0;
+
+ -- Declare the cursor for the list of partitions to be processed.
+ Declare cursor_Partitions Cursor For
+ Select ObjectID, IndexID, PartitionNum, AvgFrag
+ From #work_to_do;
+
+ -- Open the cursor.
+ Open cursor_Partitions;
+
+ -- Loop through the partitions.
+ While (1=1)
+
+ Begin;
+
+ Fetch Next From cursor_Partitions Into @ObjectID, @IndexID, @PartitionNum, @IndexAvgFrag;
+
+ IF (@@FETCH_STATUS < 0) Break;
+
+ Select @ObjectName = QUOTENAME(o.name), @SchemaName = QUOTENAME(s.name)
+ From sys.objects as o
+ join sys.schemas as s on s.schema_id = o.schema_id
+ Where o.object_id = @ObjectID;
+
+ Select @IndexName = QUOTENAME(name)
+ From sys.indexes
+ Where object_id = @ObjectID AND index_id = @IndexID;
+
+ Select @PartitionCount = Count(*)
+ From sys.partitions
+ Where object_id = @ObjectID AND index_id = @IndexID;
+
+ Set @Command = '';
+
+ -- Determine whether to rebuild or reorganize
+ IF (@IndexAvgFrag < @UpperFragCutoff)
+ Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REORGANIZE;';
+
+ IF (@IndexAvgFrag >= @UpperFragCutoff)
+ Set @Command = N'ALTER INDEX ' + @IndexName + N' ON ' + @SchemaName + N'.' + @ObjectName + N' REBUILD;';
+
+ IF (@PartitionCount > 1)
+ Set @Command = @Command + N' PARTITION=' + Cast(@PartitionNum AS nvarchar(10));
+
+ -- Print command if enabled
+ If (@IsPrint = 1) Print @Command;
+
+ -- Execute command if enabled
+ If (@IsExecute = 1) Exec (@Command);
+
+ End;
+
+ -- Close and deallocate the cursor
+ Close cursor_Partitions;
+ Deallocate cursor_Partitions;
+
+ -- Drop the temporary table
+ Drop Table #work_to_do;
+
+ Return;
+End
+Go
+
+IF (@@Error = 0) PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Succeeded'
+ELSE PRINT 'StoredProcedure Creation: [vesp_UtilityCheckIndexes] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblEntriesDeleteStatusDocID')
+ Drop Index [IX_tblEntriesDeleteStatusDocID] on [dbo].[tblEntries]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblEntriesDeleteStatusDocID]
+ON [dbo].[tblEntries] ([DeleteStatus] ASC)
+INCLUDE ([DocID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblEntriesDeleteStatusDocID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblEntriesDeleteStatusDocID] Error on Creation'
+GO
+
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblAnnotationsDeleteStatusAnnotationID')
+ Drop Index [IX_tblAnnotationsDeleteStatusAnnotationID] on [dbo].[tblAnnotations]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblAnnotationsDeleteStatusAnnotationID]
+ON [dbo].[tblAnnotations] ([DeleteStatus] ASC)
+INCLUDE ([AnnotationID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblAnnotationsDeleteStatusAnnotationID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblAnnotationsDeleteStatusAnnotationID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblContentsDeleteStatusContentID')
+ Drop Index [IX_tblContentsDeleteStatusContentID] on [dbo].[tblContents]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblContentsDeleteStatusContentID]
+ON [dbo].[tblContents] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblContentsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblContentsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblDocumentsDeleteStatusDocID')
+ Drop Index [IX_tblDocumentsDeleteStatusDocID] on [dbo].[tblDocuments]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblDocumentsDeleteStatusDocID]
+ON [dbo].[tblDocuments] ([DeleteStatus] ASC)
+INCLUDE ([DocID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblDocumentsDeleteStatusDocID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblDocumentsDeleteStatusDocID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblGridsDeleteStatusContentID')
+ Drop Index [IX_tblGridsDeleteStatusContentID] on [dbo].[tblGrids]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblGridsDeleteStatusContentID]
+ON [dbo].[tblGrids] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblGridsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblGridsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblImagesDeleteStatusContentID')
+ Drop Index [IX_tblImagesDeleteStatusContentID] on [dbo].[tblImages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblImagesDeleteStatusContentID]
+ON [dbo].[tblImages] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblImagesDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblImagesDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblItemsDeleteStatusItemID')
+ Drop Index [IX_tblItemsDeleteStatusItemID] on [dbo].[tblItems]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblItemsDeleteStatusItemID]
+ON [dbo].[tblItems] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblItemsDeleteStatusItemID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblItemsDeleteStatusItemID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemIDContentID')
+ Drop Index [IX_tblPartsDeleteStatusItemIDContentID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemIDContentID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ItemID], [ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemIDContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemIDContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusItemID')
+ Drop Index [IX_tblPartsDeleteStatusItemID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusItemID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ItemID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusItemID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusItemID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblPartsDeleteStatusContentID')
+ Drop Index [IX_tblPartsDeleteStatusContentID] on [dbo].[tblParts]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblPartsDeleteStatusContentID]
+ON [dbo].[tblParts] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblPartsDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblPartsDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusContentID')
+ Drop Index [IX_tblROUsagesDeleteStatusContentID] on [dbo].[tblROUsages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusContentID]
+ON [dbo].[tblROUsages] ([DeleteStatus] ASC)
+INCLUDE ([ContentID])
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusContentID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusContentID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblROUsagesDeleteStatusRODbID')
+ Drop Index [IX_tblROUsagesDeleteStatusRODbID] on [dbo].[tblROUsages]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblROUsagesDeleteStatusRODbID]
+ON [dbo].[tblROUsages] ([DeleteStatus] ASC)
+INCLUDE (RODbID)
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblROUsagesDeleteStatusRODbID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblROUsagesDeleteStatusRODbID] Error on Creation'
+GO
+
+
+If Exists (Select * From sys.Indexes Where Name = N'IX_tblTransitionsDeleteStatusTransitionID')
+ Drop Index [IX_tblTransitionsDeleteStatusTransitionID] on [dbo].[tblTransitions]
+Go
+
+CREATE NONCLUSTERED INDEX [IX_tblTransitionsDeleteStatusTransitionID]
+ON [dbo].[tblTransitions] ([DeleteStatus] ASC)
+INCLUDE (TransitionID)
+WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
+GO
+
+IF (@@Error = 0) PRINT 'Index Creation: [IX_tblTransitionsDeleteStatusTransitionID] Succeeded'
+ELSE PRINT 'Index Creation:[IX_tblTransitionsDeleteStatusTransitionID] Error on Creation'
+GO
+
+
+
+
+-- Rebuild / Reorganize All Indexes
+exec [dbo].[vesp_UtilityCheckIndexes];
+
+
+IF (@@Error = 0) PRINT 'Running vesp_UtilityCheckIndexes Succeeded'
+ELSE PRINT 'Running vesp_UtilityCheckIndexes Failed to Execute'
+GO
+
+
+
+
+
-----------------------------------------------------------------------------
/*
---------------------------------------------------------------------------
@@ -16695,8 +17379,10 @@ BEGIN TRY -- Try Block
set nocount on
DECLARE @RevDate varchar(255)
DECLARE @RevDescription varchar(255)
- set @RevDate = '07/06/2021 12:16 PM'
- set @RevDescription = 'Added vesp_RemoveUnUsedFormat'
+
+ set @RevDate = '08/26/2021 12:12 PM'
+ set @RevDescription = 'Improved search performace and removed locking / Added views & Procs to rebuild / reorganize fragmented indexes'
+
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
IF( @@TRANCOUNT > 0 ) COMMIT
@@ -16711,4 +17397,5 @@ GO
IF (@@Error = 0) PRINT 'StoredProcedure [vesp_GetSQLCodeRevision] Succeeded'
ELSE PRINT 'StoredProcedure [vesp_GetSQLCodeRevision] Error on Creation'
go
-vesp_GetSQLCodeRevision
+
+Exec vesp_GetSQLCodeRevision;