Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
19 changes: 19 additions & 0 deletions data-audit-util/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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\_<<TABLE_NAME>>\_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:
Expand Down
28 changes: 28 additions & 0 deletions data-audit-util/install.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
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 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
PRO .. util_audit_control.pks
@util_audit_control.pks

PRO .. util_audit.pks
@util_audit.pks

PRO .. util_audit.pkb
@util_audit.pkb
48 changes: 48 additions & 0 deletions data-audit-util/utl_audit.pkb → data-audit-util/util_audit.pkb
Original file line number Diff line number Diff line change
Expand Up @@ -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
--------------------------------------------------------------------------------
Expand All @@ -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
Expand Down
46 changes: 46 additions & 0 deletions data-audit-util/util_audit.pks
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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
Expand Down
7 changes: 7 additions & 0 deletions data-audit-util/util_audit_control.pks
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down