C2026-010 Add Audit History to Setting Change Bars
This commit is contained in:
@@ -24578,6 +24578,161 @@ IF (@@Error = 0) PRINT 'Procedure Creation: [GetCurrentApprovedRevisions] Succee
|
||||
ELSE PRINT 'Procedure Creation: [GetCurrentApprovedRevisions] Error on Creation'
|
||||
GO
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================================================
|
||||
-- Begin: C2026-010 Add Audit Ability for ChangeBars
|
||||
-- Author: Matthew Schill
|
||||
-- Create date: 02/17/2026
|
||||
==========================================================================================================
|
||||
*/
|
||||
/*
|
||||
----------------------------------------------------------------------------------
|
||||
Tables:
|
||||
----------------------------------------------------------------------------------
|
||||
[ChangeBarAudits]
|
||||
|
||||
----------------------------------------------------------------------------------
|
||||
Indexes:
|
||||
----------------------------------------------------------------------------------
|
||||
[IX_ChangeBarAudits_ItemID] on [dbo].[ChangeBarAudits]
|
||||
|
||||
|
||||
|
||||
*/
|
||||
|
||||
|
||||
IF Not Exists(SELECT * FROM sys.objects Where name = 'ChangeBarAudits' AND type in (N'U'))
|
||||
Begin
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
|
||||
/****** Create Table to hold Audit Information ******/
|
||||
CREATE TABLE [dbo].[ChangeBarAudits](
|
||||
[AuditID] [bigint] IDENTITY(1,1) NOT NULL,
|
||||
[ItemID] [bigint] NOT NULL,
|
||||
[Text] [nvarchar](max) NULL,
|
||||
[DTS] [datetime] NOT NULL,
|
||||
[UserID] [nvarchar](100) NOT NULL,
|
||||
[UnitIndex] [int] NULL,
|
||||
CONSTRAINT [PK_ChangeBarAudits] PRIMARY KEY CLUSTERED
|
||||
(
|
||||
[AuditID] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
|
||||
|
||||
IF (@@Error = 0) PRINT 'Table Creation: [ChangeBarAudits] Succeeded'
|
||||
ELSE PRINT 'Table Creation: [ChangeBarAudits] Error on Creation'
|
||||
|
||||
/****** Table was not previously created - so intially populate with info from Approvals ******/
|
||||
INSERT into ChangeBarAudits([ItemID],[Text],[DTS],[UserID],[UnitIndex])
|
||||
select --rr.RevisionID,
|
||||
rr.ItemID,
|
||||
Text = CASE WHEN r1.value('@Index','int') <> 0 AND UnitName IS NOT NULL THEN
|
||||
'(Unit ' + UnitName + ') '
|
||||
ELSE
|
||||
''
|
||||
END +
|
||||
'Approved by (' + rr.UserID + ') on (' +
|
||||
CAST(rr.DTS AS VARCHAR) + ')',
|
||||
rr.DTS,
|
||||
rr.UserID,
|
||||
UnitIndex = r1.value('@Index','int')
|
||||
-- , UnitName
|
||||
from revisions rr
|
||||
inner join versions vv on rr.revisionid = vv.revisionid
|
||||
inner join stages ss on vv.stageid = ss.stageid
|
||||
outer apply rr.config.nodes('Config/Applicability') t1(r1)
|
||||
outer apply
|
||||
( Select r2.value('@Name','varchar') UnitName
|
||||
FROM
|
||||
(select DocVerSions.ItemID, cast(config as xml) xconfig from DocVersions
|
||||
inner join
|
||||
vefn_AllSiblingItems(rr.ItemID) Sib ON DocVerSions.ItemID = Sib.ItemID) SDV
|
||||
cross apply
|
||||
xconfig.nodes('Config/Slaves/Slave') t2(r2)
|
||||
WHERE r2.value('@index','varchar') = r1.value('@Index','int')
|
||||
) UN
|
||||
where ss.isapproved = 1
|
||||
order by rr.ItemID, rr.RevisionID desc
|
||||
|
||||
IF (@@Error = 0) PRINT '[ChangeBarAudits] Initial Population Succeeded'
|
||||
ELSE PRINT '[ChangeBarAudits] Initial Population Error'
|
||||
|
||||
/****** Create Index to get ChangeBar Audit Information for Item (ItemID = ProcedureID) ******/
|
||||
CREATE NONCLUSTERED INDEX [IX_ChangeBarAudits_ItemID] ON [dbo].[ChangeBarAudits]
|
||||
(
|
||||
[ItemID] ASC
|
||||
)
|
||||
INCLUDE ([AuditID], [Text], [DTS], [UnitIndex])
|
||||
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
|
||||
IF (@@Error = 0) PRINT 'Index Creation: [IX_ChangeBarAudits_ItemID] Succeeded'
|
||||
ELSE PRINT 'Index Creation: [IX_ChangeBarAudits_ItemID] Error on Creation'
|
||||
|
||||
End
|
||||
|
||||
-- =============================================
|
||||
-- Description: Gets ChangeBar Audit History by item
|
||||
-- =============================================
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[GetChangeBarAuditHistoryByItem]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [GetChangeBarAuditHistoryByItem];
|
||||
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[GetChangeBarAuditHistoryByItem]
|
||||
(
|
||||
@ItemID AS bigint
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
Select * FROM ChangeBarAudits where ItemID = @ItemID
|
||||
order by DTS desc
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [GetChangeBarAuditHistoryByItem] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [GetChangeBarAuditHistoryByItem] Error on Creation'
|
||||
GO
|
||||
|
||||
-- =============================================
|
||||
-- Description: Adds ChangeBar Audit History
|
||||
-- =============================================
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[AddChangeBarAuditHistory]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [AddChangeBarAuditHistory];
|
||||
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[AddChangeBarAuditHistory]
|
||||
(
|
||||
@ItemID AS bigint,
|
||||
@Description As nvarchar(max),
|
||||
@DTS AS Datetime,
|
||||
@UserID As nvarchar(100),
|
||||
@UnitIndex AS bigint = NULL
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
INSERT into ChangeBarAudits([ItemID],[Text],[DTS],[UserID],[UnitIndex])
|
||||
VALUES (@ItemID, @Description, @DTS, @UserID, @UnitIndex)
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [AddChangeBarAuditHistory] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [AddChangeBarAuditHistory] Error on Creation'
|
||||
GO
|
||||
|
||||
/*
|
||||
==========================================================================================================
|
||||
-- End: C2026-010 Add Audit Ability for ChangeBars
|
||||
==========================================================================================================
|
||||
*/
|
||||
|
||||
|
||||
/*
|
||||
---------------------------------------------------------------------------
|
||||
| ADD New Code Before this Block |
|
||||
@@ -24611,8 +24766,8 @@ BEGIN TRY -- Try Block
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
|
||||
set @RevDate = '02/09/2026 7:00 AM'
|
||||
set @RevDescription = 'Added procedure for getting current revisions'
|
||||
set @RevDate = '02/18/2026 7:00 AM'
|
||||
set @RevDescription = 'Added Audit Ability for ChangeBars'
|
||||
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
|
||||
Reference in New Issue
Block a user