141 lines
7.4 KiB
Transact-SQL
141 lines
7.4 KiB
Transact-SQL
|
|
/****** Object: StoredProcedure [vesp_SearchItemAndChildren] ******/
|
|
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
|
DROP PROCEDURE [vesp_SearchItemAndChildren];
|
|
GO
|
|
|
|
/*
|
|
exec vesp_SearchItemAndChildren '1,2,4','20007','%#Link:Transition%',1,0,0,0
|
|
exec vesp_SearchItemAndChildren '1,2,4','20007','%#Link:Transition%',1,1,0,0
|
|
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 '4','','%WATER%',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
|
|
*/
|
|
CREATE PROCEDURE [dbo].[vesp_SearchItemAndChildren] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX),
|
|
@SearchString varchar(MAX), @CaseSensitive as int, @IncludeLinks as int, @IncludeRtfFormatting as int, @IncludeSpecialCharacters as int) WITH EXECUTE AS OWNER
|
|
AS
|
|
BEGIN
|
|
Declare @Delim char(1)
|
|
Set @Delim=char(7)
|
|
Declare @DelimNumber char(1)
|
|
Set @DelimNumber=char(17)
|
|
Declare @DelimStep char(1)
|
|
Set @DelimStep='.'
|
|
Set @SearchString = .dbo.vefn_FixSearchString(@SearchString)
|
|
begin
|
|
with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID],
|
|
[pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath) as (
|
|
Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged]
|
|
,0 as [pContentID],[I].[DTS] As [pDTS], [I].[UserID] As [pUserID], [I].[LastChanged] As [pLastChanged],
|
|
Cast('' as nvarchar(max)) PPath,
|
|
Cast(Case when C.Type < 20000 then @Delim + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path,
|
|
0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath
|
|
FROM [Items] I
|
|
Join Contents C on C.ContentID=I.ContentID
|
|
JOIN vefn_DocVersionSplit(@DocVersionList) DV
|
|
ON I.[ItemID] = DV.[ItemID]
|
|
Union All
|
|
-- Children
|
|
select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
|
|
,P.[ContentID] as [pContentID],P.[DTS] As [pDTS],P.[UserID] As [pUserID],P.[LastChanged] As [pLastChanged]
|
|
,PATH + --''
|
|
case C.Type/10000
|
|
when 2 then
|
|
case P.FromType
|
|
when 3 then @DelimStep + 'Caution'
|
|
when 4 then @DelimStep + 'Note'
|
|
else '' end
|
|
else '' end
|
|
PPath,
|
|
Path + case C.Type/10000
|
|
when 0 then @Delim +C.Number + @DelimNumber + C.Text
|
|
when 1 then @Delim +C.Number + @DelimNumber + C.Text
|
|
else
|
|
case P.FromType
|
|
--when 1 then 'PRC' + @Delim + cast(1 as varchar(3))
|
|
--when 2 then 'SEC' + @Delim + cast(1 as varchar(3))
|
|
when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3))
|
|
when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3))
|
|
when 5 then @DelimStep +'RNO' + @DelimStep
|
|
when 7 then @DelimStep +'Table' + @DelimStep
|
|
else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3))
|
|
end end Path,
|
|
case when P.FromType = 5 then -1 else 0 end IsRNO,
|
|
OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' ,
|
|
OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001'
|
|
from Itemz Z
|
|
join Parts P on P.ContentID = Z.ContentID
|
|
join Items I on I.ItemID = P.ItemID
|
|
join Contents C on C.ContentID = I.ContentID
|
|
Union All
|
|
-- Siblings
|
|
select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged]
|
|
,null,null,null,null
|
|
,PPath,
|
|
--'1' +
|
|
PPath + case C.Type/10000
|
|
when 0 then @Delim + C.Number + @DelimNumber + C.Text
|
|
when 1 then @Delim + C.Number + @DelimNumber + C.Text
|
|
else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3))
|
|
end Path, 0,
|
|
POrdinalPath,
|
|
POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4)
|
|
from Itemz Z
|
|
join Items I on I.PreviousID = Z.ItemID
|
|
join Contents C on C.ContentID = I.ContentID
|
|
--where Z.[Level] > 0
|
|
)
|
|
select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged],
|
|
C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] As [cDTS],C.[UserID] As [cUserID],C.[LastChanged] As [cLastChanged],
|
|
[pContentID],[pDTS],[pUserID],[pLastChanged],
|
|
(SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount],
|
|
(SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount],
|
|
(SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount],
|
|
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount],
|
|
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount],
|
|
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount],
|
|
(SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount],
|
|
(SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount],
|
|
(SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount],
|
|
(SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount],
|
|
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount],
|
|
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount],
|
|
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount]
|
|
from ItemZ I
|
|
join Contents C on C.ContentID = I.ContentID
|
|
left join Entries E on C.ContentID = E.ContentID
|
|
left join Documents D on E.DocID = D.DocID
|
|
where
|
|
(isnull(@SearchString,'')=''
|
|
OR (@CaseSensitive = 1 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CS_AS)
|
|
OR (@CaseSensitive = 0 AND .dbo.vefn_RemoveExtraText(C.Text,@IncludeLinks, @IncludeRtfFormatting, @IncludeSpecialCharacters) like @SearchString Collate SQL_Latin1_General_CP1_CI_AS)
|
|
OR (@CaseSensitive = 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
|