B2021-025: Limit RO items in Approved Procedures Inconsistencies Report
This commit is contained in:
parent
acb9bc903e
commit
2868362fe2
@ -16179,6 +16179,100 @@ IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Succee
|
|||||||
ELSE PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Error on Creation'
|
ELSE PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Error on Creation'
|
||||||
GO
|
GO
|
||||||
|
|
||||||
|
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CheckAllXML]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
|
||||||
|
DROP FUNCTION [vefn_CheckAllXML];
|
||||||
|
GO
|
||||||
|
/*****************************************************************************
|
||||||
|
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||||
|
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||||
|
*****************************************************************************/
|
||||||
|
CREATE FUNCTION [dbo].[vefn_CheckAllXML](@DocVersionID int)
|
||||||
|
returns xml
|
||||||
|
begin
|
||||||
|
--temp table for sibling itemid
|
||||||
|
declare @tItems table (ItemID int)
|
||||||
|
insert into @tItems
|
||||||
|
select itemid from vefn_siblingitems((select itemid from docversions where versionid = @docversionid),0)
|
||||||
|
--temp table for max checkid
|
||||||
|
declare @tChecks table (CheckID int)
|
||||||
|
insert into @tChecks
|
||||||
|
select max(cc.checkid) checkid from checks cc
|
||||||
|
inner join stages ss on cc.stageid = ss.stageid
|
||||||
|
inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
inner join @tItems ii on rr.itemid = ii.itemid -- B2021-025: get only items in procedures in this docversion
|
||||||
|
where ss.isapproved = 1 group by rr.itemid
|
||||||
|
--temp table for multi valued roids
|
||||||
|
declare @mvROIDS table (ROID varchar(max))
|
||||||
|
insert into @mvROIDS
|
||||||
|
select roid from (select distinct r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue
|
||||||
|
from checks cc join @tchecks tc on cc.checkid = tc.checkid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)) t1 group by roid having count(*) > 1
|
||||||
|
--temp table for multi valued transitionids
|
||||||
|
declare @mvTransitions table (TransitionID int)
|
||||||
|
insert into @mvTransitions
|
||||||
|
select transitionid from (select distinct r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue
|
||||||
|
from checks cc cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)) t1 group by transitionid having count(*) > 1
|
||||||
|
--temp table for multi valued docids
|
||||||
|
declare @mvLibDocs table (DocID int)
|
||||||
|
insert into @mvLibDocs
|
||||||
|
select docid from (select distinct r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate
|
||||||
|
from checks cc cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)) t1 group by docid having count(*) > 1
|
||||||
|
--temp table for roids
|
||||||
|
declare @tROIDS table (ItemID int,ROID varchar(max),ROValue varchar(max),CheckID int)
|
||||||
|
insert into @tROIDS
|
||||||
|
select rr.itemid,r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue, cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)
|
||||||
|
--temp table for transitions
|
||||||
|
declare @tTransitions table (ItemID int,TransitionID int,TransitionValue varchar(max),CheckID int)
|
||||||
|
insert into @tTransitions
|
||||||
|
select rr.itemid,r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue,cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)
|
||||||
|
--temp table for libdocs
|
||||||
|
declare @tLibDocs table (ItemID int, DocID int, DocDate datetime,CheckID int)
|
||||||
|
insert into @tLibDocs
|
||||||
|
select rr.itemid,r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate,cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)
|
||||||
|
|
||||||
|
--get all inconsitencies accross set
|
||||||
|
declare @ChkXML xml
|
||||||
|
set @ChkXML =
|
||||||
|
(
|
||||||
|
select
|
||||||
|
(--ro inconsistencies accross set
|
||||||
|
select ROCheck.ItemID,ROCheck.ROID,ROCheck.ROValue from @tROIDS ROCheck
|
||||||
|
inner join @tChecks tc on ROCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on ROCheck.itemid = ti.itemid
|
||||||
|
inner join @mvROIDS mv on ROCheck.roid = mv.roid
|
||||||
|
order by ROCheck.itemid
|
||||||
|
for xml auto,root('ROChecks'),type
|
||||||
|
),
|
||||||
|
(--transition inconsistencies accross set
|
||||||
|
select TransitionCheck.ItemID,TransitionCheck.TransitionID,TransitionCheck.TransitionValue from @tTransitions TransitionCheck
|
||||||
|
inner join @tChecks tc on TransitionCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on TransitionCheck.itemid = ti.itemid
|
||||||
|
inner join @mvTransitions mv on TransitionCheck.TransitionID = mv.TransitionID
|
||||||
|
order by TransitionCheck.itemid
|
||||||
|
for xml auto,root('TransitionChecks'),type
|
||||||
|
),
|
||||||
|
(--libdoc inconsistencies accross set
|
||||||
|
select LibDocCheck.ItemID,LibDocCheck.DocID,LibDocCheck.DocDate from @tLibDocs LibDocCheck
|
||||||
|
inner join @tChecks tc on LibDocCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on LibDocCheck.itemid = ti.itemid
|
||||||
|
inner join @mvLibDocs mv on LibDocCheck.docid = mv.docid
|
||||||
|
order by LibDocCheck.itemid
|
||||||
|
for xml auto,root('LibDocChecks'),type
|
||||||
|
)
|
||||||
|
for xml path(''),ROOT ('ConsistencyChecks'),type
|
||||||
|
)
|
||||||
|
return @ChkXML
|
||||||
|
end
|
||||||
|
GO
|
||||||
|
IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
|
||||||
|
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
|
||||||
|
GO
|
||||||
|
|
||||||
-----------------------------------------------------------------------------
|
-----------------------------------------------------------------------------
|
||||||
/*
|
/*
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
@ -16193,7 +16287,7 @@ GO
|
|||||||
|
|
||||||
/*****************************************************************************
|
/*****************************************************************************
|
||||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||||
Copyright 2019 - Volian Enterprises, Inc. All rights reserved.
|
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||||
*****************************************************************************/
|
*****************************************************************************/
|
||||||
CREATE PROCEDURE [dbo].[vesp_GetSQLCodeRevision]
|
CREATE PROCEDURE [dbo].[vesp_GetSQLCodeRevision]
|
||||||
WITH EXECUTE AS OWNER
|
WITH EXECUTE AS OWNER
|
||||||
@ -16204,8 +16298,8 @@ BEGIN TRY -- Try Block
|
|||||||
set nocount on
|
set nocount on
|
||||||
DECLARE @RevDate varchar(255)
|
DECLARE @RevDate varchar(255)
|
||||||
DECLARE @RevDescription varchar(255)
|
DECLARE @RevDescription varchar(255)
|
||||||
set @RevDate = '07/30/2020 10:00 AM'
|
set @RevDate = '03/17/2021 9:00 AM'
|
||||||
set @RevDescription = 'Only allow one user to access properties for Folders and DocVersions'
|
set @RevDescription = 'Limit the RO Inconsistencies in Approved Procedures Inconsistencies Report to procedures in set'
|
||||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||||
|
@ -16179,6 +16179,100 @@ IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Succee
|
|||||||
ELSE PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Error on Creation'
|
ELSE PRINT 'Procedure Creation: [vesp_SessionCanCheckOutItem] Error on Creation'
|
||||||
GO
|
GO
|
||||||
|
|
||||||
|
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_CheckAllXML]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1)
|
||||||
|
DROP FUNCTION [vefn_CheckAllXML];
|
||||||
|
GO
|
||||||
|
/*****************************************************************************
|
||||||
|
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||||
|
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||||
|
*****************************************************************************/
|
||||||
|
CREATE FUNCTION [dbo].[vefn_CheckAllXML](@DocVersionID int)
|
||||||
|
returns xml
|
||||||
|
begin
|
||||||
|
--temp table for sibling itemid
|
||||||
|
declare @tItems table (ItemID int)
|
||||||
|
insert into @tItems
|
||||||
|
select itemid from vefn_siblingitems((select itemid from docversions where versionid = @docversionid),0)
|
||||||
|
--temp table for max checkid
|
||||||
|
declare @tChecks table (CheckID int)
|
||||||
|
insert into @tChecks
|
||||||
|
select max(cc.checkid) checkid from checks cc
|
||||||
|
inner join stages ss on cc.stageid = ss.stageid
|
||||||
|
inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
inner join @tItems ii on rr.itemid = ii.itemid -- B2021-025: get only items in procedures in this docversion
|
||||||
|
where ss.isapproved = 1 group by rr.itemid
|
||||||
|
--temp table for multi valued roids
|
||||||
|
declare @mvROIDS table (ROID varchar(max))
|
||||||
|
insert into @mvROIDS
|
||||||
|
select roid from (select distinct r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue
|
||||||
|
from checks cc join @tchecks tc on cc.checkid = tc.checkid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)) t1 group by roid having count(*) > 1
|
||||||
|
--temp table for multi valued transitionids
|
||||||
|
declare @mvTransitions table (TransitionID int)
|
||||||
|
insert into @mvTransitions
|
||||||
|
select transitionid from (select distinct r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue
|
||||||
|
from checks cc cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)) t1 group by transitionid having count(*) > 1
|
||||||
|
--temp table for multi valued docids
|
||||||
|
declare @mvLibDocs table (DocID int)
|
||||||
|
insert into @mvLibDocs
|
||||||
|
select docid from (select distinct r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate
|
||||||
|
from checks cc cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)) t1 group by docid having count(*) > 1
|
||||||
|
--temp table for roids
|
||||||
|
declare @tROIDS table (ItemID int,ROID varchar(max),ROValue varchar(max),CheckID int)
|
||||||
|
insert into @tROIDS
|
||||||
|
select rr.itemid,r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue, cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)
|
||||||
|
--temp table for transitions
|
||||||
|
declare @tTransitions table (ItemID int,TransitionID int,TransitionValue varchar(max),CheckID int)
|
||||||
|
insert into @tTransitions
|
||||||
|
select rr.itemid,r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue,cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)
|
||||||
|
--temp table for libdocs
|
||||||
|
declare @tLibDocs table (ItemID int, DocID int, DocDate datetime,CheckID int)
|
||||||
|
insert into @tLibDocs
|
||||||
|
select rr.itemid,r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate,cc.checkid
|
||||||
|
from checks cc inner join revisions rr on cc.revisionid = rr.revisionid
|
||||||
|
cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)
|
||||||
|
|
||||||
|
--get all inconsitencies accross set
|
||||||
|
declare @ChkXML xml
|
||||||
|
set @ChkXML =
|
||||||
|
(
|
||||||
|
select
|
||||||
|
(--ro inconsistencies accross set
|
||||||
|
select ROCheck.ItemID,ROCheck.ROID,ROCheck.ROValue from @tROIDS ROCheck
|
||||||
|
inner join @tChecks tc on ROCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on ROCheck.itemid = ti.itemid
|
||||||
|
inner join @mvROIDS mv on ROCheck.roid = mv.roid
|
||||||
|
order by ROCheck.itemid
|
||||||
|
for xml auto,root('ROChecks'),type
|
||||||
|
),
|
||||||
|
(--transition inconsistencies accross set
|
||||||
|
select TransitionCheck.ItemID,TransitionCheck.TransitionID,TransitionCheck.TransitionValue from @tTransitions TransitionCheck
|
||||||
|
inner join @tChecks tc on TransitionCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on TransitionCheck.itemid = ti.itemid
|
||||||
|
inner join @mvTransitions mv on TransitionCheck.TransitionID = mv.TransitionID
|
||||||
|
order by TransitionCheck.itemid
|
||||||
|
for xml auto,root('TransitionChecks'),type
|
||||||
|
),
|
||||||
|
(--libdoc inconsistencies accross set
|
||||||
|
select LibDocCheck.ItemID,LibDocCheck.DocID,LibDocCheck.DocDate from @tLibDocs LibDocCheck
|
||||||
|
inner join @tChecks tc on LibDocCheck.checkid = tc.checkid
|
||||||
|
inner join @tItems ti on LibDocCheck.itemid = ti.itemid
|
||||||
|
inner join @mvLibDocs mv on LibDocCheck.docid = mv.docid
|
||||||
|
order by LibDocCheck.itemid
|
||||||
|
for xml auto,root('LibDocChecks'),type
|
||||||
|
)
|
||||||
|
for xml path(''),ROOT ('ConsistencyChecks'),type
|
||||||
|
)
|
||||||
|
return @ChkXML
|
||||||
|
end
|
||||||
|
GO
|
||||||
|
IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
|
||||||
|
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
|
||||||
|
GO
|
||||||
|
|
||||||
-----------------------------------------------------------------------------
|
-----------------------------------------------------------------------------
|
||||||
/*
|
/*
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
@ -16193,7 +16287,7 @@ GO
|
|||||||
|
|
||||||
/*****************************************************************************
|
/*****************************************************************************
|
||||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||||
Copyright 2019 - Volian Enterprises, Inc. All rights reserved.
|
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||||
*****************************************************************************/
|
*****************************************************************************/
|
||||||
CREATE PROCEDURE [dbo].[vesp_GetSQLCodeRevision]
|
CREATE PROCEDURE [dbo].[vesp_GetSQLCodeRevision]
|
||||||
WITH EXECUTE AS OWNER
|
WITH EXECUTE AS OWNER
|
||||||
@ -16204,8 +16298,8 @@ BEGIN TRY -- Try Block
|
|||||||
set nocount on
|
set nocount on
|
||||||
DECLARE @RevDate varchar(255)
|
DECLARE @RevDate varchar(255)
|
||||||
DECLARE @RevDescription varchar(255)
|
DECLARE @RevDescription varchar(255)
|
||||||
set @RevDate = '07/30/2020 10:00 AM'
|
set @RevDate = '03/17/2021 9:00 AM'
|
||||||
set @RevDescription = 'Only allow one user to access properties for Folders and DocVersions'
|
set @RevDescription = 'Limit the RO Inconsistencies in Approved Procedures Inconsistencies Report to procedures in set'
|
||||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||||
|
Loading…
x
Reference in New Issue
Block a user