From bcc0cfca480a9b3456b0e31b408ed8d59fe4358c Mon Sep 17 00:00:00 2001 From: Rich Date: Thu, 19 Apr 2012 18:23:39 +0000 Subject: [PATCH] Use the UnitPrefix directly from the DocVersion Config for searches --- PROMS/DataLoader/PROMSFixes.Sql | 624 ++++++++++++++++++++++++++++++++ 1 file changed, 624 insertions(+) diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index 72a360b7..8277d667 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -1048,3 +1048,627 @@ GO IF (@@Error = 0) PRINT 'Procedure Creation: getAnnotationAuditsChronologyByItemID Succeeded' 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]; +GO +/* +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) +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 + +/* +select * from vefn_DocVersionSplit('1,4') +select * from vefn_DocVersionSplit(null) +select * from vefn_DocVersionSplit('') +*/ +ALTER FUNCTION [dbo].[vefn_DocVersionSplit](@DocVersionList varchar(MAX)) +RETURNS @IDs TABLE +( + 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 + +GO +/* +select * from vefn_SiblingAndChildrenItems('','3-') +*/ + +ALTER FUNCTION [dbo].[vefn_SiblingAndChildrenItems](@DocVersionList varchar(10),@UnitPrefix 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) +) +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 + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) [Path], + 0 IsRNO, Cast('' as nvarchar(max)) [POrdinalPath], Cast('0001' as nvarchar(max)) [OrdinalPath], UnitPrefix + FROM [Items] I + Join Contents C on C.ContentID=I.ContentID + JOIN vefn_DocVersionSplit(@DocVersionList) DV + ON I.[ItemID] = DV.[ItemID] +Union All +-- Children + select 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' + else '' end + else '' end + PPath, + Path + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text -- Procedure + when 1 then @Delim + C.Number + @DelimNumber + C.Text -- Section + else + case P.FromType + --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) + --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) + when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) + when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) + when 5 then @DelimStep +'RNO' + @DelimStep + when 7 then @DelimStep +'Table' + @DelimStep + else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) + end end Path, + case when P.FromType = 5 then -1 else 0 end IsRNO, + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001', 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 + C.Number + @DelimNumber + C.Text -- Procedure + when 1 then @Delim + C.Number + @DelimNumber + C.Text -- Section + else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) + end Path, 0, + POrdinalPath, + POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), UnitPrefix + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + join Contents C on C.ContentID = I.ContentID + --where Z.[Level] > 0 + +) +insert into @SiblingAndChildren +select I.[ItemID], [DvPath], [Path], I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID], + [pContentID],[pDTS],[pUserID],[IsRNO]/*,[PPath],[POrdinalPath]*/,[OrdinalPath] + from ItemZ I +OPTION (MAXRECURSION 10000) +END +RETURN +END +GO + +/* +exec vesp_SearchAnnotationItemAndChildren Null,Null,'1',Null,0,"3-" +exec vesp_SearchAnnotationItemAndChildren Null,Null,'2',Null,0 +exec vesp_SearchAnnotationItemAndChildren Null,Null,'3',Null,0 +exec vesp_SearchAnnotationItemAndChildren Null,Null,'4',Null,0 +exec vesp_SearchAnnotationItemAndChildren Null,Null,'5',Null,0 +exec vesp_SearchAnnotationItemAndChildren Null,Null,'',Null,0 +*/ +ALTER PROCEDURE [dbo].[vesp_SearchAnnotationItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @AnnotationTypeList varchar(MAX), @SearchString nvarchar(MAX), @CaseSensitive as int, @UnitPrefix nvarchar(MAX)) +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='.' +Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) +begin +with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], + [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( + Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] + ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], + Cast('' as nvarchar(max)) PPath, + Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, + 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix + FROM [Items] I + Join Contents C on C.ContentID=I.ContentID + JOIN vefn_DocVersionSplit(@DocVersionList) DV + ON I.[ItemID] = DV.[ItemID] +Union All +-- Children + select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] + ,PATH + --'' + case C.Type/10000 + when 2 then + case P.FromType + when 3 then @DelimStep + 'Caution' + when 4 then @DelimStep + 'Note' + else '' end + else '' end + PPath, + Path + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else + case P.FromType + --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) + --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) + when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) + when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) + when 5 then @DelimStep +'RNO' + @DelimStep + when 7 then @DelimStep +'Table' + @DelimStep + else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) + end end Path, + case when P.FromType = 5 then -1 else 0 end IsRNO, + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix + from Itemz Z + join Parts P on P.ContentID = Z.ContentID + join Items I on I.ItemID = P.ItemID + join Contents C on C.ContentID = I.ContentID +Union All +-- Siblings + select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,null,null,null,null + ,PPath, + --'1' + + PPath + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) + end Path, 0, + POrdinalPath, + POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + join Contents C on C.ContentID = I.ContentID + --where Z.[Level] > 0 +) +select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], + C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], + [pContentID],[pDTS],[pUserID],[pLastChanged],AnnotationID SearchAnnotationID, SearchText, TT.Name AnnotationType, + (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], + (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], + (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], + (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], + (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], + (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], + (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], + (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], + (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], + (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] + from ItemZ I + join Contents C on C.ContentID = I.ContentID + left join Entries E on C.ContentID = E.ContentID + left join Documents D on E.DocID = D.DocID + join Annotations A on A.ItemID = I.ItemID + join vefn_AnnotationTypeSplit(@AnnotationTypeList) TT on TT.TypeID=A.TypeID +where + (isnull(@SearchString,'')='' + OR (@CaseSensitive = 1 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) + OR (@CaseSensitive = 0 AND A.SearchText like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)) + AND + ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) + or + ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) + or + (@StepTypeList like '%20040%' AND IsRNO = -1))) + order by DvPath,OrdinalPath +OPTION (MAXRECURSION 10000) +END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren Succeeded' +ELSE PRINT 'Procedure Creation: vesp_SearchAnnotationItemAndChildren Error on Creation' +GO + +/* +exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,0,0,0 +exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,1,0,0 +exec vesp_SearchItemAndChildren '1,2,4','20007','#Link:Transition',1,2,0,0 +exec vesp_SearchItemAndChildren '4','','#Link:Refer',1,2,0,0 +exec vesp_SearchItemAndChildren '4','','200`F',0,1,0,0 +exec vesp_SearchItemAndChildren '4','10000','',0,0,0,0 +exec vesp_SearchItemAndChildren '4','','[0-9]`F',0,1,0,0 +exec vesp_SearchItemAndChildren '','','RCP',0,0,0,0 +exec vesp_SearchItemAndChildren '','','%',0,0,0,0 +exec vesp_SearchItemAndChildren '','20040','',0,0,0,0 +exec vesp_SearchItemAndChildren '','10000','XYZZY',0,0,0,0 +exec vesp_SearchItemAndChildren '','10000','XYZZY',1,0,0,0 +exec vesp_SearchItemAndChildren '','','%IF%',0,0,0,0 +exec vesp_SearchItemAndChildren '','','%IF%',1,0,0,0 +exec vesp_SearchItemAndChildren '','','%47%',1,0,0,0 +exec vesp_SearchItemAndChildren '','','%47%',1,0,0,1 +exec vesp_SearchItemAndChildren '','','condenser not av',0,0,0,0 +exec vesp_SearchItemAndChildren '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 +exec vesp_SearchItemAndChildren '','','DISPATCH NEAR SG',2,0,0,0 +exec vesp_SearchItemAndChildren '','','PORV NEAR SG',2,0,0,0 +exec vesp_SearchItemAndChildren '','','CHECK NORMAL',0,0,0,0 +exec vesp_SearchItemAndChildren '','','turbine-driven',0,0,0,0 +*/ +ALTER PROCEDURE [dbo].[vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), +@SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX)) +WITH EXECUTE AS OWNER +AS +BEGIN +Declare @Delim char(1) +Set @Delim=char(7) +Declare @DelimNumber char(1) +Set @DelimNumber=char(17) +Declare @DelimStep char(1) +Set @DelimStep='.' +Set @SearchString = .dbo.vefn_FixSearchString(@SearchString) +begin +with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], + [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( + Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] + ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], + Cast('' as nvarchar(max)) PPath, + Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, + 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix + FROM [Items] I + Join Contents C on C.ContentID=I.ContentID + JOIN vefn_DocVersionSplit(@DocVersionList) DV + ON I.[ItemID] = DV.[ItemID] +Union All +-- Children + select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] + ,PATH + --'' + case C.Type/10000 + when 2 then + case P.FromType + when 3 then @DelimStep + 'Caution' + when 4 then @DelimStep + 'Note' + else '' end + else '' end + PPath, + Path + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else + case P.FromType + --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) + --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) + when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) + when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) + when 5 then @DelimStep +'RNO' + @DelimStep + when 7 then @DelimStep +'Table' + @DelimStep + else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) + end end Path, + case when P.FromType = 5 then -1 else 0 end IsRNO, + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix + from Itemz Z + join Parts P on P.ContentID = Z.ContentID + join Items I on I.ItemID = P.ItemID + join Contents C on C.ContentID = I.ContentID +Union All +-- Siblings + select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,null,null,null,null + ,PPath, + --'1' + + PPath + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) + end Path, 0, + POrdinalPath, + POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + join Contents C on C.ContentID = I.ContentID + --where Z.[Level] > 0 +) +select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], + C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], + [pContentID],[pDTS],[pUserID],[pLastChanged], + (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], + (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], + (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], + (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], + (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], + (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], + (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], + (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], + (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], + (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] + from ItemZ I + join Contents C on C.ContentID = I.ContentID + left join Entries E on C.ContentID = E.ContentID + left join Documents D on E.DocID = D.DocID + where + (isnull(@SearchString,'')='' + OR (@CaseSensitive = 1 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) + OR (@CaseSensitive = 0 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) + OR (@CaseSensitive = 1 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CS_AS) + OR (@CaseSensitive = 0 AND D.DocAscii like @SearchString Collate SQL_Latin1_General_CP1_CI_AS) + ) + AND + ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) + or + ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) + or + (@StepTypeList like '%20040%' AND IsRNO = -1))) + order by DvPath,OrdinalPath +OPTION (MAXRECURSION 10000) +END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchItemAndChildren Succeeded' +ELSE PRINT 'Procedure Creation: vesp_SearchItemAndChildren Error on Creation' +GO + +/* +exec vesp_SearchROItemAndChildren '1,2,4','20007','1:00010000019C,0001000002AE' +exec vesp_SearchROItemAndChildren '1,2,4','','1:00010000019C,0001000002AE' +exec vesp_SearchROItemAndChildren '1,2,4','20007','1:0001' +exec vesp_SearchROItemAndChildren '1,2,4','20006','1' +exec vesp_SearchROItemAndChildren '1,2,4','20006','' +exec vesp_SearchROItemAndChildren '',Null,Null,'XXX-' +*/ +ALTER PROCEDURE [dbo].[vesp_SearchROItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX)) +WITH EXECUTE AS OWNER +AS +BEGIN +Declare @Delim char(1) +Set @Delim=char(7) +Declare @DelimNumber char(1) +Set @DelimNumber=char(17) +Declare @DelimStep char(1) +Set @DelimStep='.' +begin +with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], + [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, UnitPrefix) as ( + Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] + ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], + Cast('' as nvarchar(max)) PPath, + Cast(Case when C.Type < 20000 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, + 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, UnitPrefix + + FROM [Items] I + Join Contents C on C.ContentID=I.ContentID + JOIN vefn_DocVersionSplit(@DocVersionList) DV + ON I.[ItemID] = DV.[ItemID] +Union All +-- Children + select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] + ,PATH + --'' + case C.Type/10000 + when 2 then + case P.FromType + when 3 then @DelimStep + 'Caution' + when 4 then @DelimStep + 'Note' + else '' end + else '' end + PPath, + --Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000 + Path + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else + case P.FromType + --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) + --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) + when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) + when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) + when 5 then @DelimStep +'RNO' + @DelimStep + when 7 then @DelimStep +'Table' + @DelimStep + else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) + end end Path, + case when P.FromType = 5 then -1 else 0 end IsRNO, + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', UnitPrefix + from Itemz Z + join Parts P on P.ContentID = Z.ContentID + join Items I on I.ItemID = P.ItemID + join Contents C on C.ContentID = I.ContentID +Union All +-- Siblings + select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,null,null,null,null + ,PPath, + --'1' + + PPath + case C.Type/10000 + when 0 then @Delim + UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) + end Path, 0, + POrdinalPath, + POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), UnitPrefix + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + join Contents C on C.ContentID = I.ContentID + --where Z.[Level] > 0 +) +select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], + C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], + [pContentID],[pDTS],[pUserID],[pLastChanged], + (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], + (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], + (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], + (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], + (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], + (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], + (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], + (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], + (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], + (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount] + from ItemZ I + join Contents C on C.ContentID = I.ContentID + left join Entries E on C.ContentID = E.ContentID + left join Documents D on E.DocID = D.DocID + where + I.ContentID in(select ContentID from ROUsages RU + join vefn_SplitROSearch(@ROSearchString) RR + ON RR.RODBID = RU.RODBID and + RU.ROID like RR.ROID + '%' Collate SQL_Latin1_General_CP1_CI_AS +UNION +select Distinct ContentID from Entries EE + Join DROUsages RU on RU.DocID = EE.DocID + join vefn_SplitROSearch(@ROSearchString) RR + ON RR.RODBID = RU.RODBID and + RU.ROID = RR.ROID) + AND + ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) + or + ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) + or + (@StepTypeList like '%20040%' AND IsRNO = -1))) + order by DvPath,OrdinalPath +OPTION (MAXRECURSION 10000) +END +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Succeeded' +ELSE PRINT 'Procedure Creation: vesp_SearchROItemAndChildren Error on Creation' +GO + + +/* +exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,0,0,0 +exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,1,0,0 +exec vesp_SearchItemAndChildrenNew '1,2,4','20007','#Link:Transition',1,2,0,0 +exec vesp_SearchItemAndChildrenNew '4','','#Link:Refer',1,2,0,0 +exec vesp_SearchItemAndChildrenNew '4','','200`F',0,1,0,0 +exec vesp_SearchItemAndChildrenNew '4','10000','',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '4','','[0-9]`F',0,1,0,0 +exec vesp_SearchItemAndChildrenNew '1','','"RCP"',2,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','"RCP"',2,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','20040','',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','10000','XYZZY',1,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%IF%',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%IF%',1,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%47%',1,0,0,1 +exec vesp_SearchItemAndChildrenNew '','','condenser not av',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','(SG OR LHSI) AND DISPATCH',2,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','DISPATCH NEAR SG',2,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','PORV NEAR SG',2,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','CHECK NORMAL',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','(Resolved Transition Text)',0,0,0,0 +exec vesp_SearchItemAndChildrenNew '','','%turbine-driven%',0,0,0,0 +*/ + +CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildrenNew] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), +@SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int, @UnitPrefix as varchar(MAX)) +WITH EXECUTE AS OWNER +AS +select ZZ.DvPath, ZZ.Path, ZZ.[Level],ZZ.[FromType],ZZ.[Ordinal], ZZ.[ParentID], ZZ.[ItemID],ZZ.[PreviousID],ZZ.[ContentID],ZZ.[DTS],ZZ.[UserID] + ,II.[LastChanged] + ,CC.[Number],CC.[Text],CC.[Type],CC.[FormatID],CC.[Config],CC.[DTS] [cDTS],CC.[UserID] [cUserID] + ,CC.[LastChanged] [cLastChanged], + PP.[ContentID] [pContentID], PP.[DTS] [pDTS],PP.[UserID] [pUserID], PP.[LastChanged] [pLastChanged], + (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=ZZ.[ItemID]) [AnnotationCount], + (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=ZZ.[ItemID]) [DocVersionCount], + (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=ZZ.[ItemID]) [NextCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=ZZ.[ItemID]) [PartCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=ZZ.[ItemID]) [Transition_RangeIDCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=ZZ.[ItemID]) [Transition_ToIDCount], + (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=CC.[ContentID]) [DetailCount], + (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=CC.[ContentID]) [EntryCount], + (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=CC.[ContentID]) [GridCount], + (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=CC.[ContentID]) [ImageCount], + (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=CC.[ContentID]) [ItemCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=CC.[ContentID]) [cPartCount], + (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=CC.[ContentID]) [RoUsageCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=CC.[ContentID]) [TransitionCount], + (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=CC.[ContentID]) [ZContentCount] +from vefn_SiblingAndChildrenItems(@DocVersionList, @UnitPrefix) ZZ + Join Items II on ZZ.ItemID=II.ItemID + Left Join Parts PP on ZZ.PContentID=PP.ContentID and ZZ.FromType = PP.FromType + Join Contents CC on CC.ContentID=ZZ.ContentID +where ZZ.ContentID in (select ContentID from vefn_FindText(@DocVersionList,@SearchString,@CaseSensitive,@IncludeLinks,@IncludeRtfFormatting,@IncludeSpecialCharacters,@StepTypeList)) + order by DvPath,OrdinalPath + GO \ No newline at end of file