From 8e8d3d218f6804ab832cfa7cb18222c5e7f26d3d Mon Sep 17 00:00:00 2001 From: Jorge Rimblas Date: Sun, 20 Jul 2025 01:56:23 -0500 Subject: [PATCH 1/2] Added installation script --- data-audit-util/README.md | 19 ++++++++++++++ data-audit-util/install.sql | 26 +++++++++++++++++++ .../{utl_audit.pkb => util_audit.pkb} | 0 3 files changed, 45 insertions(+) create mode 100644 data-audit-util/install.sql rename data-audit-util/{utl_audit.pkb => util_audit.pkb} (100%) diff --git a/data-audit-util/README.md b/data-audit-util/README.md index 75cda6e..4b7f79e 100644 --- a/data-audit-util/README.md +++ b/data-audit-util/README.md @@ -8,6 +8,25 @@ This package was born out of a need to undestand what happened to a specific row - All triggers that Audit tables will be of the form BUID\_<>\_AUD - ANY Triggers that have the above name signature will be affected by this package +## Installation + +Use the `install.sql` script. + +``` +-- Install all code without failures +@util_audit_control.pks +@util_audit.pks +@util_audit.pkb + +-- create audit table +exec util_audit.create_audit_table(p_action => 'EXECUTE'); + +-- recompile code that is now aware that the audit table exists +@util_audit_control.pks +@util_audit.pks +@util_audit.pkb +``` + ## Limitations DataTypes that can be Audited are: diff --git a/data-audit-util/install.sql b/data-audit-util/install.sql new file mode 100644 index 0000000..7400197 --- /dev/null +++ b/data-audit-util/install.sql @@ -0,0 +1,26 @@ +set feedback off + +PRO Installing data-audit-util + +PRO .. util_audit_control.pks +@util_audit_control.pks + +PRO .. util_audit.pks +@util_audit.pks + +PRO .. util_audit.pkb +@util_audit.pkb + +PRO create audit table +exec util_audit.create_audit_table(p_action => 'EXECUTE'); + + +PRO Recompile code that is now aware that the audit table exists +PRO .. util_audit_control.pks +@util_audit_control.pks + +PRO .. util_audit.pks +@util_audit.pks + +PRO .. util_audit.pkb +@util_audit.pkb diff --git a/data-audit-util/utl_audit.pkb b/data-audit-util/util_audit.pkb similarity index 100% rename from data-audit-util/utl_audit.pkb rename to data-audit-util/util_audit.pkb From d017bf0c8c0a9a7b48dedfb8800ec53016010805 Mon Sep 17 00:00:00 2001 From: Jorge Rimblas Date: Sun, 20 Jul 2025 02:19:27 -0500 Subject: [PATCH 2/2] #3 Add lookup table --- data-audit-util/install.sql | 2 ++ data-audit-util/util_audit.pkb | 48 ++++++++++++++++++++++++++ data-audit-util/util_audit.pks | 46 ++++++++++++++++++++++++ data-audit-util/util_audit_control.pks | 7 ++++ 4 files changed, 103 insertions(+) diff --git a/data-audit-util/install.sql b/data-audit-util/install.sql index 7400197..966ec8c 100644 --- a/data-audit-util/install.sql +++ b/data-audit-util/install.sql @@ -13,6 +13,8 @@ PRO .. util_audit.pkb PRO create audit table exec util_audit.create_audit_table(p_action => 'EXECUTE'); +PRO create lookups table +exec util_audit.create_audit_lookups_table(p_action => 'EXECUTE'); PRO Recompile code that is now aware that the audit table exists diff --git a/data-audit-util/util_audit.pkb b/data-audit-util/util_audit.pkb index 936a513..f168e46 100644 --- a/data-audit-util/util_audit.pkb +++ b/data-audit-util/util_audit.pkb @@ -101,6 +101,31 @@ create or replace PACKAGE BODY util_audit AS WHEN OTHERS THEN raise_application_error(-20001, 'create_audit_table' || ' - ' || dbms_utility.format_error_backtrace, true); END create_audit_table; + -------------------------------------------------------------------------------- + -- CREATE_AUDIT_LOOKUPS_TABLE + -------------------------------------------------------------------------------- + -- Creates the table that will hold information of the lookup (FK) values. + ------------------------------------------------------------------------------------- + PROCEDURE create_audit_lookups_table ( + p_action in varchar2 default 'GENERATE' + ) is + v_sql varchar2(32767); + BEGIN + v_sql := q'{ + create table UTIL_AUDIT_LOOKUPS ( + column_name_return varchar2(255) not null primary key, + table_name varchar2(255) not null, + column_name_pk varchar2(255) not null, + display_expression varchar2(4000) + ) + }'; + + output_sql(p_sql => v_sql, p_action => p_action); + + EXCEPTION + WHEN OTHERS THEN + raise_application_error(-20001, 'create_audit_lookups_table - ' || dbms_utility.format_error_backtrace, true); + END create_audit_lookups_table; -------------------------------------------------------------------------------- -- DROP_AUDIT_TABLE -------------------------------------------------------------------------------- @@ -125,6 +150,29 @@ create or replace PACKAGE BODY util_audit AS END drop_audit_table; -------------------------------------------------------------------------------- +-- DROP_AUDIT_LOOKUPS_TABLE +-------------------------------------------------------------------------------- +-- Drops the central Logging table - USE WITH CAUTION +------------------------------------------------------------------------------------- + PROCEDURE drop_audit_lookups_table ( + p_action IN VARCHAR2 DEFAULT 'GENERATE' + ) IS + v_sql VARCHAR2(32767); + table_does_not_exist EXCEPTION; + PRAGMA exception_init ( table_does_not_exist, -942 ); + BEGIN + v_sql := 'drop table UTIL_AUDIT_LOOKUPS'; + BEGIN + output_sql(p_sql => v_sql, p_action => p_action); + EXCEPTION + WHEN table_does_not_exist THEN + NULL; + WHEN OTHERS THEN + raise_application_error(-20001, 'drop_audit_lookups_table' || ' - ' || dbms_utility.format_error_backtrace, true); + END; + + END drop_audit_lookups_table; +-------------------------------------------------------------------------------- -- ADD_TABLE_AUDIT_TRIG -------------------------------------------------------------------------------- -- Adds a trigger to audit specific columns in a table diff --git a/data-audit-util/util_audit.pks b/data-audit-util/util_audit.pks index 935b41e..2e62465 100644 --- a/data-audit-util/util_audit.pks +++ b/data-audit-util/util_audit.pks @@ -85,6 +85,31 @@ as p_action IN VARCHAR2 DEFAULT 'GENERATE' ); -------------------------------------------------------------------------------- +-- CREATE_AUDIT_LOOKUPS_TABLE +-------------------------------------------------------------------------------- + -- Generates (and optionally executes) a script that will create the lookup reference table + -- + -- Arguments + -- p_action - EXECUTE or GENERATE + -- EXECUTE will execute the script immediately, creating the objects. + -- GENERATE will emit the script to the OWA HTP buffer. + -- + -- + -- Objects Created are + -- UTIL_AUDIT_LOOKUPS - Table that holds lookup information for foreing key values + -- + -- column_name_return varchar2(255) not null primary key, + -- table_name varchar2(255) not null, + -- column_name_pk varchar2(255) not null, + -- display_expression varchar2(4000) + -- + -- example(s): + -- util_audit.create_audit_lookups_table(p_action => 'GENERATE'); + -- + PROCEDURE create_audit_lookups_table ( + p_action IN VARCHAR2 DEFAULT 'GENERATE' + ); +-------------------------------------------------------------------------------- -- DROP_AUDIT_TABLE -------------------------------------------------------------------------------- -- Generates (and optionally executes) a script that will DROP the central logging table @@ -106,6 +131,27 @@ as p_action IN VARCHAR2 DEFAULT 'GENERATE' ); -------------------------------------------------------------------------------- +-- DROP_AUDIT_LOOKUPS_TABLE +-------------------------------------------------------------------------------- + -- Generates (and optionally executes) a script that will DROP the lookups table + -- + -- Arguments + -- p_action - EXECUTE or GENERATE + -- EXECUTE will execute the script immediately, creating the objects. + -- GENERATE will emit the script to the OWA HTP buffer. + -- + -- + -- DROPPED OBJECTS ARE + -- UTIL_AUDIT_LOOKUPS - Table that holds lookup reference values + -- + -- + -- example(s): + -- util_audit.drop_audit_lookups_table(p_action => 'GENERATE'); + -- + PROCEDURE drop_audit_lookups_table ( + p_action IN VARCHAR2 DEFAULT 'GENERATE' + ); +-------------------------------------------------------------------------------- -- ADD_TABLE_AUDIT_TRIG -------------------------------------------------------------------------------- -- Generates (and optionally executes) a script that will CREATE the trigger used to audit a table diff --git a/data-audit-util/util_audit_control.pks b/data-audit-util/util_audit_control.pks index a2c2560..d26692b 100644 --- a/data-audit-util/util_audit_control.pks +++ b/data-audit-util/util_audit_control.pks @@ -24,15 +24,22 @@ declare l_audit_exists varchar2(5); +l_lookups_exists varchar2(5); begin select case when n = 0 then 'false' else 'true' end into l_audit_exists from ( select count(*) n from user_tables where table_name = 'UTIL_AUDIT_RECORDS' ); +select case when n = 0 then 'false' else 'true' end + into l_lookups_exists +from ( + select count(*) n from user_tables where table_name = 'UTIL_AUDIT_LOOKUPS' +); execute immediate ' create or replace package util_audit_control as is_installed constant boolean := ' || l_audit_exists || '; + has_lookups constant boolean := ' || l_lookups_exists || '; end util_audit_control; '; end;