B2021-031: Grouping/ordering of items in the Chronology Report is not always correct
B2020-156: When a procedure title is changed, it does not appear in Summary or Chronology of Changes reports
This commit is contained in:
parent
56a231bcd2
commit
7c92953eeb
@ -16273,6 +16273,255 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
|
||||
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [getContentAuditsChronologyByItemID];
|
||||
GO
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemID]
|
||||
(
|
||||
@ProcedureItemID int,
|
||||
@SelectedItemID int,
|
||||
@IncludeDeletedChildren int,
|
||||
@DTS datetime
|
||||
)
|
||||
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
begin
|
||||
select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS)
|
||||
order by OrdinalPath, contentid,auditid -- B2021-031: Grouping/ordering in Chronology Report not always correct
|
||||
-- select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
-- order by OrdinalPath, contentid,auditid--actionwhen
|
||||
RETURN
|
||||
end
|
||||
GO
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChronologyReport]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
|
||||
DROP FUNCTION [vefn_ChronologyReport];
|
||||
GO
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE function [dbo].[vefn_ChronologyReport](@ProcItemID int, @DTS datetime)
|
||||
returns @Report table
|
||||
(
|
||||
src int,
|
||||
AuditID bigint,
|
||||
ContentID int,
|
||||
Number nvarchar(512),
|
||||
Text nvarchar(max),
|
||||
Type int,
|
||||
FormatID int,
|
||||
Config nvarchar(max),
|
||||
DTS datetime,
|
||||
UserID nvarchar(200),
|
||||
DeleteStatus int,
|
||||
ActionDTS datetime,
|
||||
ItemDTS datetime,
|
||||
LastAuditID int,
|
||||
DeletedAuditID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
--added rhm/jcb 20121218i
|
||||
declare @tmpTable table
|
||||
(
|
||||
icontentid int primary key
|
||||
)
|
||||
insert into @tmpTable select icontentid from vefn_tblchilditems(@ProcItemID,@ProcItemID,1)
|
||||
--added jcb 20111122
|
||||
--declare @dts datetime
|
||||
--set @dts = (select dts from items where itemid = @ProcItemID )
|
||||
--set @dts = (SELECT .[dbo].[vefn_GetPreviousRevisionDTSByItemID] (@ProcItemID))
|
||||
--end added jcb 20111122
|
||||
insert into @Report
|
||||
SELECT
|
||||
1 src,
|
||||
[AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
where Number is not null
|
||||
--added jcb 20111028_1827
|
||||
and ca.contentid != (select contentid from items where itemid = @procitemid)
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > @dts)
|
||||
--and ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and ca.dts > @dts
|
||||
--end added jcb 20111122
|
||||
-- UNION
|
||||
-- SELECT
|
||||
--2 src,
|
||||
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
---- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
---- 0 [AuditID]
|
||||
-- ,ca.[ContentID]
|
||||
-- ,[Number]
|
||||
-- ,[Text]
|
||||
-- ,[Type]
|
||||
-- ,[FormatID]
|
||||
-- ,[Config]
|
||||
-- ,ca.[DTS] cadts
|
||||
-- ,ca.[UserID]
|
||||
-- ,ca.[DeleteStatus]
|
||||
-- ,ActionDTS
|
||||
-- ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
-- FROM tblContents ca
|
||||
---- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
--WHERE ca.DeleteStatus = 0 AND
|
||||
----added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
||||
----end added jcb 20111028_1827
|
||||
----ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
----added jcb 20111122
|
||||
----ca.ContentID in (SELECT [ContentID] FROM Contents where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
--ca.ContentID in (SELECT [ContentID] FROM Contents where dts > @dts)
|
||||
----end added jcb 20111122
|
||||
----order by ca.DTS,ActionDTS
|
||||
UNION
|
||||
SELECT
|
||||
3 src,
|
||||
cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
-- 0 [AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM tblContents ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
WHERE ca.DeleteStatus = 0 --AND
|
||||
--added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) -- B2020-156: Procedure not listed in change reports
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and (ca.dts > @dts or ca.actiondts > @dts)
|
||||
--end added jcb 20111122
|
||||
UNION
|
||||
SELECT distinct
|
||||
5 src,
|
||||
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
ca.[AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
WHERE ca.DeleteStatus > 0
|
||||
--added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
and (ca.dts > @dts or ca.actiondts > @dts)
|
||||
--end added jcb 20111122
|
||||
order by ca.DTS,ActionDTS
|
||||
|
||||
insert into @Report
|
||||
SELECT
|
||||
4 src,
|
||||
ca.[AuditID]
|
||||
,ca.[ContentID]
|
||||
,ca.[Number]
|
||||
,ca.[Text]
|
||||
,ca.[Type]
|
||||
,ca.[FormatID]
|
||||
,ca.[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ca.ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
inner join @Report rpt on ca.contentid = rpt.contentid and ca.auditid = rpt.lastauditid
|
||||
where ca.auditid not in (select auditid from @report)
|
||||
and rpt.lastauditid is not null
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
return
|
||||
end
|
||||
go
|
||||
IF (@@Error = 0) PRINT 'TableFunction [vefn_ChronologyReport] Succeeded'
|
||||
ELSE PRINT 'TableFunction [vefn_ChronologyReport] Error on Creation'
|
||||
go
|
||||
|
||||
|
||||
-----------------------------------------------------------------------------
|
||||
/*
|
||||
---------------------------------------------------------------------------
|
||||
@ -16298,8 +16547,8 @@ BEGIN TRY -- Try Block
|
||||
set nocount on
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
set @RevDate = '03/17/2021 9:00 AM'
|
||||
set @RevDescription = 'Limit the RO Inconsistencies in Approved Procedures Inconsistencies Report to procedures in set'
|
||||
set @RevDate = '03/22/2021 11:00 AM'
|
||||
set @RevDescription = 'Include Procedure Changes in History/Change Reports and Fix Ordering of Entries in Chronology Report'
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
|
@ -16273,6 +16273,255 @@ IF (@@Error = 0) PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Succeeded'
|
||||
ELSE PRINT 'ScalarFunction Creation: [vefn_CheckAllXML] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getContentAuditsChronologyByItemID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [getContentAuditsChronologyByItemID];
|
||||
GO
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE PROCEDURE [dbo].[getContentAuditsChronologyByItemID]
|
||||
(
|
||||
@ProcedureItemID int,
|
||||
@SelectedItemID int,
|
||||
@IncludeDeletedChildren int,
|
||||
@DTS datetime
|
||||
)
|
||||
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
begin
|
||||
select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS)
|
||||
order by OrdinalPath, contentid,auditid -- B2021-031: Grouping/ordering in Chronology Report not always correct
|
||||
-- select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
-- order by OrdinalPath, contentid,auditid--actionwhen
|
||||
RETURN
|
||||
end
|
||||
GO
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [getContentAuditsChronologyByItemID] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_ChronologyReport]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1)
|
||||
DROP FUNCTION [vefn_ChronologyReport];
|
||||
GO
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2021 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
CREATE function [dbo].[vefn_ChronologyReport](@ProcItemID int, @DTS datetime)
|
||||
returns @Report table
|
||||
(
|
||||
src int,
|
||||
AuditID bigint,
|
||||
ContentID int,
|
||||
Number nvarchar(512),
|
||||
Text nvarchar(max),
|
||||
Type int,
|
||||
FormatID int,
|
||||
Config nvarchar(max),
|
||||
DTS datetime,
|
||||
UserID nvarchar(200),
|
||||
DeleteStatus int,
|
||||
ActionDTS datetime,
|
||||
ItemDTS datetime,
|
||||
LastAuditID int,
|
||||
DeletedAuditID int
|
||||
)
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN
|
||||
--added rhm/jcb 20121218i
|
||||
declare @tmpTable table
|
||||
(
|
||||
icontentid int primary key
|
||||
)
|
||||
insert into @tmpTable select icontentid from vefn_tblchilditems(@ProcItemID,@ProcItemID,1)
|
||||
--added jcb 20111122
|
||||
--declare @dts datetime
|
||||
--set @dts = (select dts from items where itemid = @ProcItemID )
|
||||
--set @dts = (SELECT .[dbo].[vefn_GetPreviousRevisionDTSByItemID] (@ProcItemID))
|
||||
--end added jcb 20111122
|
||||
insert into @Report
|
||||
SELECT
|
||||
1 src,
|
||||
[AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
where Number is not null
|
||||
--added jcb 20111028_1827
|
||||
and ca.contentid != (select contentid from items where itemid = @procitemid)
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > @dts)
|
||||
--and ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and ca.dts > @dts
|
||||
--end added jcb 20111122
|
||||
-- UNION
|
||||
-- SELECT
|
||||
--2 src,
|
||||
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
---- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
---- 0 [AuditID]
|
||||
-- ,ca.[ContentID]
|
||||
-- ,[Number]
|
||||
-- ,[Text]
|
||||
-- ,[Type]
|
||||
-- ,[FormatID]
|
||||
-- ,[Config]
|
||||
-- ,ca.[DTS] cadts
|
||||
-- ,ca.[UserID]
|
||||
-- ,ca.[DeleteStatus]
|
||||
-- ,ActionDTS
|
||||
-- ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
-- FROM tblContents ca
|
||||
---- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
--WHERE ca.DeleteStatus = 0 AND
|
||||
----added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
||||
----end added jcb 20111028_1827
|
||||
----ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
----added jcb 20111122
|
||||
----ca.ContentID in (SELECT [ContentID] FROM Contents where dts > (select dts from items where itemid = @ProcItemID ))
|
||||
--ca.ContentID in (SELECT [ContentID] FROM Contents where dts > @dts)
|
||||
----end added jcb 20111122
|
||||
----order by ca.DTS,ActionDTS
|
||||
UNION
|
||||
SELECT
|
||||
3 src,
|
||||
cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
-- 0 [AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM tblContents ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
WHERE ca.DeleteStatus = 0 --AND
|
||||
--added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) -- B2020-156: Procedure not listed in change reports
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and (ca.dts > @dts or ca.actiondts > @dts)
|
||||
--end added jcb 20111122
|
||||
UNION
|
||||
SELECT distinct
|
||||
5 src,
|
||||
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
||||
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
||||
ca.[AuditID]
|
||||
,ca.[ContentID]
|
||||
,[Number]
|
||||
,[Text]
|
||||
,[Type]
|
||||
,[FormatID]
|
||||
,[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
WHERE ca.DeleteStatus > 0
|
||||
--added jcb 20111028_1827
|
||||
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
||||
--end added jcb 20111028_1827
|
||||
--added jcb 20111122
|
||||
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
and (ca.dts > @dts or ca.actiondts > @dts)
|
||||
--end added jcb 20111122
|
||||
order by ca.DTS,ActionDTS
|
||||
|
||||
insert into @Report
|
||||
SELECT
|
||||
4 src,
|
||||
ca.[AuditID]
|
||||
,ca.[ContentID]
|
||||
,ca.[Number]
|
||||
,ca.[Text]
|
||||
,ca.[Type]
|
||||
,ca.[FormatID]
|
||||
,ca.[Config]
|
||||
,ca.[DTS] cadts
|
||||
,ca.[UserID]
|
||||
,ca.[DeleteStatus]
|
||||
,ca.ActionDTS
|
||||
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
||||
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
||||
FROM ContentAudits ca
|
||||
-- inner join tblitems ti on ca.contentid = ti.contentid
|
||||
inner join @Report rpt on ca.contentid = rpt.contentid and ca.auditid = rpt.lastauditid
|
||||
where ca.auditid not in (select auditid from @report)
|
||||
and rpt.lastauditid is not null
|
||||
and ca.contentid in (select icontentid from @tmpTable)
|
||||
return
|
||||
end
|
||||
go
|
||||
IF (@@Error = 0) PRINT 'TableFunction [vefn_ChronologyReport] Succeeded'
|
||||
ELSE PRINT 'TableFunction [vefn_ChronologyReport] Error on Creation'
|
||||
go
|
||||
|
||||
|
||||
-----------------------------------------------------------------------------
|
||||
/*
|
||||
---------------------------------------------------------------------------
|
||||
@ -16298,8 +16547,8 @@ BEGIN TRY -- Try Block
|
||||
set nocount on
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
set @RevDate = '03/17/2021 9:00 AM'
|
||||
set @RevDescription = 'Limit the RO Inconsistencies in Approved Procedures Inconsistencies Report to procedures in set'
|
||||
set @RevDate = '03/22/2021 11:00 AM'
|
||||
set @RevDescription = 'Include Procedure Changes in History/Change Reports and Fix Ordering of Entries in Chronology Report'
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
|
Loading…
x
Reference in New Issue
Block a user