Added stored procedures and function to support transition report functionality
This commit is contained in:
parent
ca0d2d3843
commit
746ac8f35d
@ -9088,3 +9088,427 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: vefn_FixROData Succeeded'
|
||||
ELSE PRINT 'ScalarFunction Creation: vefn_FixROData Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: UserDefinedFunction [dbo].[vefn_GetVersionProcedureItems] Script Date: 1/5/2015 3:58:49 PM ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionProcedureItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
|
||||
DROP FUNCTION [vefn_GetVersionProcedureItems];
|
||||
GO
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
/*
|
||||
Select * from vefn_GetVersionProcedureItems('') where procid = 63589
|
||||
Select * from vefn_GetVersionProcedureItems('1') where procid = 63589
|
||||
Select * from vefn_GetVersionProcedureItems('4') where procid = 63589
|
||||
*/
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2013 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE FUNCTION [dbo].[vefn_GetVersionProcedureItems](@DocVersionList varchar(MAX))
|
||||
RETURNS @VersionItems TABLE
|
||||
(
|
||||
VersionID int,
|
||||
ProcID int,
|
||||
ItemID int primary key,
|
||||
ContentID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
BEGIN
|
||||
with Itemz([VersionID], ProcID, [ItemID], [ContentID]) as
|
||||
(Select DV.VersionID, DV.ItemID ProcID, [I].[ItemID], [I].[ContentID]
|
||||
FROM [Items] I
|
||||
JOIN vefn_DocVersionSplit(@DocVersionList) DV
|
||||
ON I.[ItemID] = DV.[ItemID]
|
||||
Union All
|
||||
-- Children
|
||||
select Z.VersionID, Z.ProcID, I.[ItemID], I.[ContentID]
|
||||
from Itemz Z
|
||||
join Parts P on P.ContentID = Z.ContentID
|
||||
join Items I on I.ItemID = P.ItemID
|
||||
Union All
|
||||
-- Siblings
|
||||
select Z.VersionID, case when z.ProcID = z.ItemID then I.ItemID else Z.ProcID end ProcID, I.[ItemID], I.[ContentID]
|
||||
from Itemz Z
|
||||
join Items I on I.PreviousID = Z.ItemID
|
||||
)
|
||||
insert into @VersionItems
|
||||
select VersionID, ProcID, [ItemID], [ContentID]
|
||||
from ItemZ I
|
||||
--Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ)
|
||||
OPTION (MAXRECURSION 10000)
|
||||
END
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
IF (@@Error = 0) PRINT 'TableFunction vefn_GetVersionProcedureItems Succeeded'
|
||||
ELSE PRINT 'TableFunction vefn_GetVersionProcedureItems Error on Creation'
|
||||
|
||||
/****** Object: StoredProcedure [getTransitionSearchResults] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_SearchTransitions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [dbo].[vesp_SearchTransitions];
|
||||
GO
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
/****** Object: StoredProcedure [dbo].[vesp_SearchTransitions] Script Date: 1/7/2015 6:15:17 PM ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[vesp_SearchTransitions]
|
||||
(
|
||||
@DocVersionList varchar(max),
|
||||
@TranType int,
|
||||
@TranCategory varchar(20)
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
declare @itmp table
|
||||
(
|
||||
vid int,
|
||||
pid int,
|
||||
iid int primary key,
|
||||
cid int
|
||||
)
|
||||
declare @ctmp table
|
||||
(
|
||||
vid int,
|
||||
pid int,
|
||||
iid int,
|
||||
cid int primary key
|
||||
)
|
||||
declare @ttmp table
|
||||
(
|
||||
itemid int,
|
||||
dvpath varchar(max)
|
||||
)
|
||||
insert into @itmp select * from vefn_getversionprocedureitems(@DocVersionList)
|
||||
insert into @ctmp select * from @itmp
|
||||
if @TranType = -1 and @TranCategory = '' begin
|
||||
insert into @ttmp
|
||||
select ii.ItemID,dv.DVPath
|
||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||
join @ctmp ct on dv.VersionID = ct.vid
|
||||
join Items ii on ct.cid = ii.ContentID
|
||||
join Transitions tt on ii.ContentID = tt.FromID
|
||||
end else if @TranType > -1 and @TranCategory = '' begin
|
||||
insert into @ttmp
|
||||
select ii.ItemID,dv.DVPath
|
||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||
join @ctmp ct on dv.VersionID = ct.vid
|
||||
join Items ii on ct.cid = ii.ContentID
|
||||
join Transitions tt on ii.ContentID = tt.FromID
|
||||
where tt.TranType = @TranType
|
||||
end else if @TranType = -1 and @TranCategory != '' begin
|
||||
insert into @ttmp
|
||||
select ii.ItemID,dv.DVPath
|
||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||
join @ctmp ct on dv.VersionID = ct.vid
|
||||
join Items ii on ct.cid = ii.ContentID
|
||||
join Transitions tt on ii.ContentID = tt.FromID
|
||||
join @itmp it on tt.ToID = it.iid
|
||||
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
|
||||
insert into @ttmp
|
||||
select ii.ItemID,dv.DVPath
|
||||
from vefn_DocVersionSplit(@DocVersionList) dv
|
||||
join @ctmp ct on dv.VersionID = ct.vid
|
||||
join Items ii on ct.cid = ii.ContentID
|
||||
join Transitions tt on ii.ContentID = tt.FromID
|
||||
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
|
||||
end
|
||||
SELECT
|
||||
tt.dvpath,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],
|
||||
(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 [Items] I
|
||||
join @ttmp tt on I.ItemID = tt.itemid
|
||||
join Contents C on C.ContentID = I.ContentID
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_SearchTransitions Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: vesp_SearchTransitions Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: TableFunction [vefn_GetVersionFormatSections] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionFormatSections]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
|
||||
DROP FUNCTION [vefn_GetVersionFormatSections];
|
||||
GO
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE FUNCTION [dbo].[vefn_GetVersionFormatSections](@DocVersionList varchar(MAX))
|
||||
RETURNS @VersionItems TABLE
|
||||
(
|
||||
VersionID int,
|
||||
ItemID int,
|
||||
ContentID int primary key,
|
||||
FormatID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
BEGIN
|
||||
with Itemz([VersionID], [ItemID], [ContentID], [FormatID], [ParentFormatID]) as
|
||||
(Select DV.VersionID, [I].[ItemID], [I].[ContentID],
|
||||
isnull(C.[FormatID],isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID]))),
|
||||
isnull(DV2.[FormatID],isnull(F.[FormatID],P.[FormatID]))
|
||||
FROM [Items] I
|
||||
JOIN vefn_DocVersionSplit(@DocVersionList) DV ON I.[ItemID] = DV.[ItemID]
|
||||
join docversions DV2 on DV.[VersionID] = DV2.[VersionID]
|
||||
join folders F on DV2.[FolderID] = F.[FolderID]
|
||||
join folders P on P.[FolderID] = F.[ParentID]
|
||||
join Contents C on I.ContentID = C.ContentID
|
||||
|
||||
Union All
|
||||
-- Children
|
||||
select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[FormatID]), Z.[FormatID]
|
||||
from Itemz Z
|
||||
join Parts P on P.ContentID = Z.ContentID
|
||||
join Items I on I.ItemID = P.ItemID
|
||||
join Contents C on I.ContentID = C.ContentID
|
||||
where c.Type < 20000
|
||||
Union All
|
||||
-- Siblings
|
||||
select Z.VersionID, I.[ItemID], I.[ContentID], isnull(C.[FormatID],Z.[ParentFormatID]), Z.[ParentFormatID]
|
||||
from Itemz Z
|
||||
join Items I on I.PreviousID = Z.ItemID
|
||||
join Contents C on I.ContentID = C.ContentID
|
||||
)
|
||||
insert into @VersionItems
|
||||
select VersionID, [ItemID], [ContentID], [FormatID]
|
||||
from ItemZ I
|
||||
--Select * From rousages RU Where RU.ContentID in (Select ContentID from ItemZ)
|
||||
OPTION (MAXRECURSION 10000)
|
||||
END
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
-- Display the status of func creation
|
||||
IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_GetVersionFormatSections Succeeded'
|
||||
ELSE PRINT 'TableFunction Creation: vefn_GetVersionFormatSections Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [vesp_GetFormatVersions] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetFormatVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [dbo].[vesp_GetFormatVersions];
|
||||
GO
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
/****** Object: StoredProcedure [dbo].[vesp_GetFormatVersions] Script Date: 1/7/2015 6:15:17 PM ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
CREATE PROCEDURE vesp_GetFormatVersions
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
select ff.Name + ' - ' + ff.Description Title,vfi.FormatID,vn.VersionID
|
||||
from vefn_GetVersionNames() vn
|
||||
join vefn_GetVersionFormatSections('') vfi on vn.VersionID = vfi.VersionID
|
||||
join Formats ff on vfi.FormatID = ff.FormatID
|
||||
group by ff.Name + ' - ' + ff.Description,vfi.formatid,vn.VersionID
|
||||
return
|
||||
END
|
||||
GO
|
||||
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetFormatVersions Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: vesp_GetFormatVersions Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [vesp_GetTranTypesByFormatID] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetTranTypesByFormatID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [dbo].[vesp_GetTranTypesByFormatID];
|
||||
GO
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
/****** Object: StoredProcedure [dbo].[vesp_GetTranTypesByFormatID] Script Date: 1/7/2015 6:15:17 PM ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
/*
|
||||
vesp_GetTranTypesByFormatID 102
|
||||
*/
|
||||
CREATE PROCEDURE vesp_GetTranTypesByFormatID
|
||||
(
|
||||
@FormatID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
declare @t1 table
|
||||
(
|
||||
formatid int,
|
||||
transindex int,
|
||||
transmenu varchar(max)
|
||||
)
|
||||
declare @t2 table
|
||||
(
|
||||
transindex int,
|
||||
formatid int
|
||||
)
|
||||
insert into @t1
|
||||
select ff.formatid,r1.value('@Index','int') transindex, r1.value('@TransMenu','varchar(max)') transmenu
|
||||
from Formats ff
|
||||
cross apply ff.Data.nodes('//TransTypes') t1(r1)
|
||||
where ff.FormatID = @FormatID
|
||||
union
|
||||
select ff.formatid,r1.value('@Index','int') transindex, r1.value('@TransMenu','varchar(max)') transmenu
|
||||
from Formats ff
|
||||
cross apply ff.Data.nodes('//TransTypes') t1(r1)
|
||||
where ff.FormatID = 1
|
||||
insert into @t2
|
||||
select transindex,max(formatid) formatid from @t1 group by transindex
|
||||
select t1.transindex,t1.transmenu
|
||||
from @t1 t1
|
||||
join @t2 t2 on t1.formatid = t2.formatid and t1.transindex = t2.transindex
|
||||
order by t1.transindex
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetTranTypesByFormatID Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: vesp_GetTranTypesByFormatID Error on Creation'
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [vesp_GetTransitionReportData] ******/
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetTransitionReportData]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [dbo].[vesp_GetTransitionReportData];
|
||||
GO
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2012 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
/****** Object: StoredProcedure [dbo].[vesp_GetTransitionReportData] Script Date: 1/7/2015 6:15:17 PM ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
/*
|
||||
vesp_GetTransitionReportData 1,1
|
||||
*/
|
||||
CREATE PROCEDURE vesp_GetTransitionReportData
|
||||
(
|
||||
@VersionID int,
|
||||
@ProcedureID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
declare @itmp table
|
||||
(
|
||||
vid int,
|
||||
pid int,
|
||||
iid int primary key,
|
||||
cid int
|
||||
)
|
||||
declare @ctmp table
|
||||
(
|
||||
vid int,
|
||||
pid int,
|
||||
iid int,
|
||||
cid int primary key
|
||||
)
|
||||
declare @ttmp table
|
||||
(
|
||||
tid int primary key
|
||||
)
|
||||
insert into @itmp select * from vefn_getversionprocedureitems(@VersionID)
|
||||
insert into @ctmp select * from @itmp
|
||||
insert into @ttmp select tt.TransitionID from Transitions tt join @ctmp ct on tt.FromID = ct.cid join @itmp it on tt.ToID = it.iid
|
||||
--internal
|
||||
select 1 level,tt.*,
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount]
|
||||
from Transitions tt
|
||||
join @ttmp tp on tt.TransitionID = tp.tid
|
||||
join @ctmp ct on tt.FromID = ct.cid
|
||||
join @itmp it on tt.ToID = it.iid
|
||||
where ct.vid = it.vid and ct.pid = @ProcedureID and it.pid = @ProcedureID
|
||||
--external from
|
||||
union
|
||||
select 2 level,tt.*,
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount]
|
||||
from Transitions tt
|
||||
join @ttmp tp on tt.TransitionID = tp.tid
|
||||
join @ctmp ct on tt.FromID = ct.cid
|
||||
join @itmp it on tt.ToID = it.iid
|
||||
where ct.pid = @ProcedureID and it.pid != @ProcedureID
|
||||
--external to
|
||||
union
|
||||
select 3 level,tt.*,
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount]
|
||||
from Transitions tt
|
||||
join @ttmp tp on tt.TransitionID = tp.tid
|
||||
join @ctmp ct on tt.FromID = ct.cid
|
||||
join @itmp it on tt.ToID = it.iid
|
||||
where ct.pid != @ProcedureID and it.pid = @ProcedureID
|
||||
--outside from
|
||||
union
|
||||
select 4 level,tt.*,
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount]
|
||||
from Transitions tt
|
||||
join @ttmp tp on tt.TransitionID = tp.tid
|
||||
join @ctmp ct on tt.FromID = ct.cid
|
||||
join Items ii on tt.ToID = ii.ItemID
|
||||
where ct.pid = @ProcedureID and ii.ItemID not in (select iid from @itmp)
|
||||
--outside to
|
||||
union
|
||||
select 5 level,tt.*,
|
||||
(SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=tt.[TransitionID]) [ZTransitionCount]
|
||||
from Transitions tt
|
||||
join @ttmp tp on tt.TransitionID = tp.tid
|
||||
join @itmp it on tt.ToID = it.iid
|
||||
join Items ii on tt.FromID = ii.ContentID
|
||||
where it.pid = @ProcedureID and ii.ContentID not in (select cid from @ctmp)
|
||||
RETURN
|
||||
END
|
||||
GO
|
||||
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: vesp_GetTransitionReportData Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: vesp_GetTransitionReportData Error on Creation'
|
||||
GO
|
||||
|
Loading…
x
Reference in New Issue
Block a user