Revised vesp_SearchTransitions to include step path field
This commit is contained in:
parent
0e50de5f44
commit
ea8c38cd28
@ -9163,6 +9163,9 @@ GO
|
|||||||
|
|
||||||
SET QUOTED_IDENTIFIER ON
|
SET QUOTED_IDENTIFIER ON
|
||||||
GO
|
GO
|
||||||
|
/*
|
||||||
|
exec vesp_searchtransitions '1,2,4,6,7,11,12',6,''
|
||||||
|
*/
|
||||||
|
|
||||||
CREATE PROCEDURE [dbo].[vesp_SearchTransitions]
|
CREATE PROCEDURE [dbo].[vesp_SearchTransitions]
|
||||||
(
|
(
|
||||||
@ -9173,6 +9176,12 @@ CREATE PROCEDURE [dbo].[vesp_SearchTransitions]
|
|||||||
WITH EXECUTE AS OWNER
|
WITH EXECUTE AS OWNER
|
||||||
AS
|
AS
|
||||||
BEGIN
|
BEGIN
|
||||||
|
Declare @Delim char(1)
|
||||||
|
Set @Delim=char(7)
|
||||||
|
Declare @DelimNumber char(1)
|
||||||
|
Set @DelimNumber=char(17)
|
||||||
|
Declare @DelimStep char(1)
|
||||||
|
Set @DelimStep='.'
|
||||||
declare @itmp table
|
declare @itmp table
|
||||||
(
|
(
|
||||||
vid int,
|
vid int,
|
||||||
@ -9190,20 +9199,21 @@ BEGIN
|
|||||||
declare @ttmp table
|
declare @ttmp table
|
||||||
(
|
(
|
||||||
itemid int,
|
itemid int,
|
||||||
dvpath varchar(max)
|
dvpath varchar(max),
|
||||||
|
UnitPrefix varchar(MAX)
|
||||||
)
|
)
|
||||||
insert into @itmp select * from vefn_getversionprocedureitems(@DocVersionList)
|
insert into @itmp select * from vefn_getversionprocedureitems(@DocVersionList)
|
||||||
insert into @ctmp select * from @itmp
|
insert into @ctmp select * from @itmp
|
||||||
if @TranType = -1 and @TranCategory = '' begin
|
if @TranType = -1 and @TranCategory = '' begin
|
||||||
insert into @ttmp
|
insert into @ttmp
|
||||||
select ii.ItemID,dv.DVPath
|
select ii.ItemID,dv.DVPath,dv.UnitPrefix
|
||||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||||
join @ctmp ct on dv.VersionID = ct.vid
|
join @ctmp ct on dv.VersionID = ct.vid
|
||||||
join Items ii on ct.cid = ii.ContentID
|
join Items ii on ct.cid = ii.ContentID
|
||||||
join Transitions tt on ii.ContentID = tt.FromID
|
join Transitions tt on ii.ContentID = tt.FromID
|
||||||
end else if @TranType > -1 and @TranCategory = '' begin
|
end else if @TranType > -1 and @TranCategory = '' begin
|
||||||
insert into @ttmp
|
insert into @ttmp
|
||||||
select ii.ItemID,dv.DVPath
|
select ii.ItemID,dv.DVPath,dv.UnitPrefix
|
||||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||||
join @ctmp ct on dv.VersionID = ct.vid
|
join @ctmp ct on dv.VersionID = ct.vid
|
||||||
join Items ii on ct.cid = ii.ContentID
|
join Items ii on ct.cid = ii.ContentID
|
||||||
@ -9211,7 +9221,7 @@ BEGIN
|
|||||||
where tt.TranType = @TranType
|
where tt.TranType = @TranType
|
||||||
end else if @TranType = -1 and @TranCategory != '' begin
|
end else if @TranType = -1 and @TranCategory != '' begin
|
||||||
insert into @ttmp
|
insert into @ttmp
|
||||||
select ii.ItemID,dv.DVPath
|
select ii.ItemID,dv.DVPath,dv.UnitPrefix
|
||||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||||
join @ctmp ct on dv.VersionID = ct.vid
|
join @ctmp ct on dv.VersionID = ct.vid
|
||||||
join Items ii on ct.cid = ii.ContentID
|
join Items ii on ct.cid = ii.ContentID
|
||||||
@ -9220,7 +9230,7 @@ BEGIN
|
|||||||
where case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory
|
where case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory
|
||||||
end else begin
|
end else begin
|
||||||
insert into @ttmp
|
insert into @ttmp
|
||||||
select ii.ItemID,dv.DVPath
|
select ii.ItemID,dv.DVPath,dv.UnitPrefix
|
||||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||||
join @ctmp ct on dv.VersionID = ct.vid
|
join @ctmp ct on dv.VersionID = ct.vid
|
||||||
join Items ii on ct.cid = ii.ContentID
|
join Items ii on ct.cid = ii.ContentID
|
||||||
@ -9228,8 +9238,71 @@ BEGIN
|
|||||||
join @itmp it on tt.ToID = it.iid
|
join @itmp it on tt.ToID = it.iid
|
||||||
where tt.TranType = @TranType and case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory
|
where tt.TranType = @TranType and case when it.vid = ct.vid then case when it.pid = ct.pid then 'Internal' else 'External' end else 'Outside' end = @TranCategory
|
||||||
end
|
end
|
||||||
|
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 + 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 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 + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'')
|
||||||
|
when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(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 + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'')
|
||||||
|
when 1 then @Delim + Isnull(C.Number,'') + @DelimNumber + Isnull(C.Text,'')
|
||||||
|
else case when .dbo.vefn_GetLastDelim(Path) = '.' 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
|
||||||
|
)
|
||||||
SELECT
|
SELECT
|
||||||
tt.dvpath,I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged],
|
tt.dvpath,Z.Path,
|
||||||
|
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],
|
C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged],
|
||||||
(SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount],
|
(SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount],
|
||||||
(SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount],
|
(SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount],
|
||||||
@ -9246,10 +9319,13 @@ BEGIN
|
|||||||
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount],
|
(SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount],
|
||||||
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount],
|
(SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount],
|
||||||
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount]
|
(SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount]
|
||||||
FROM [Items] I
|
FROM Itemz Z
|
||||||
join @ttmp tt on I.ItemID = tt.itemid
|
join [Items] I on Z.ItemID = I.ItemID
|
||||||
join Contents C on C.ContentID = I.ContentID
|
join @ttmp tt on I.ItemID = tt.itemid
|
||||||
RETURN
|
join Contents C on C.ContentID = I.ContentID
|
||||||
|
left join Parts P on i.ItemID = P.ItemID
|
||||||
|
RETURN
|
||||||
|
END
|
||||||
END
|
END
|
||||||
GO
|
GO
|
||||||
|
|
||||||
|
Loading…
x
Reference in New Issue
Block a user