First of all, I think the way to approach "rogue administrators" is with a combination of Oracle's audit trail and Database Vault features.
That said, here's what I might try:
1) Create a custom ODCI aggregate function to compute a hash of multiple rows as an aggregate.
2) Create a VIRTUAL NOT NULL
column on the table that was an SHA hash of all the columns in the table -- or all the one's you care about protecting. You'd keep this around all the time -- basically trading away some insert/update/delete
performance in exchange to be able to compute hashes more quickly.
3) Create a non-unique index on that virtual column
4) SELECT my_aggregate_hash_function(virtual_hash_column) FROM my_table
to get the results.
Here's code:
Create an aggregate function to compute a SHA hash over a bunch of rows
CREATE OR REPLACE TYPE matt_hash_aggregate_impl AS OBJECT
(
hash_value RAW(32000),
CONSTRUCTOR FUNCTION matt_hash_aggregate_impl(SELF IN OUT NOCOPY matt_hash_aggregate_impl ) RETURN SELF AS RESULT,
-- Called to initialize a new aggregation context
-- For analytic functions, the aggregation context of the *previous* window is passed in, so we only need to adjust as needed instead
-- of creating the new aggregation context from scratch
STATIC FUNCTION ODCIAggregateInitialize (sctx IN OUT matt_hash_aggregate_impl) RETURN NUMBER,
-- Called when a new data point is added to an aggregation context
MEMBER FUNCTION ODCIAggregateIterate (self IN OUT matt_hash_aggregate_impl, value IN raw ) RETURN NUMBER,
-- Called to return the computed aggragate from an aggregation context
MEMBER FUNCTION ODCIAggregateTerminate (self IN matt_hash_aggregate_impl, returnValue OUT raw, flags IN NUMBER) RETURN NUMBER,
-- Called to merge to two aggregation contexts into one (e.g., merging results of parallel slaves)
MEMBER FUNCTION ODCIAggregateMerge (self IN OUT matt_hash_aggregate_impl, ctx2 IN matt_hash_aggregate_impl) RETURN NUMBER,
-- ODCIAggregateDelete
MEMBER FUNCTION ODCIAggregateDelete(self IN OUT matt_hash_aggregate_impl, value raw) RETURN NUMBER
);
/
CREATE OR REPLACE TYPE BODY matt_hash_aggregate_impl IS
CONSTRUCTOR FUNCTION matt_hash_aggregate_impl(SELF IN OUT NOCOPY matt_hash_aggregate_impl ) RETURN SELF AS RESULT IS
BEGIN
SELF.hash_value := null;
RETURN;
END;
STATIC FUNCTION ODCIAggregateInitialize (sctx IN OUT matt_hash_aggregate_impl) RETURN NUMBER IS
BEGIN
sctx := matt_hash_aggregate_impl ();
RETURN ODCIConst.Success;
END;
MEMBER FUNCTION ODCIAggregateIterate (self IN OUT matt_hash_aggregate_impl, value IN raw ) RETURN NUMBER IS
BEGIN
IF self.hash_value IS NULL THEN
self.hash_value := dbms_crypto.hash(value, dbms_crypto.hash_sh1);
ELSE
self.hash_value := dbms_crypto.hash(self.hash_value || value, dbms_crypto.hash_sh1);
END IF;
RETURN ODCIConst.Success;
END;
MEMBER FUNCTION ODCIAggregateTerminate (self IN matt_hash_aggregate_impl, returnValue OUT raw, flags IN NUMBER) RETURN NUMBER IS
BEGIN
returnValue := dbms_crypto.hash(self.hash_value,dbms_crypto.hash_sh1);
RETURN ODCIConst.Success;
END;
MEMBER FUNCTION ODCIAggregateMerge (self IN OUT matt_hash_aggregate_impl, ctx2 IN matt_hash_aggregate_impl) RETURN NUMBER IS
BEGIN
self.hash_value := dbms_crypto.hash(self.hash_value || ctx2.hash_value, dbms_crypto.hash_sh1);
RETURN ODCIConst.Success;
END;
-- ODCIAggregateDelete
MEMBER FUNCTION ODCIAggregateDelete(self IN OUT matt_hash_aggregate_impl, value raw) RETURN NUMBER IS
BEGIN
raise_application_error(-20001, 'Invalid operation -- hash aggregate function does not support windowing!');
END;
END;
/
CREATE OR REPLACE FUNCTION matt_hash_aggregate ( input raw) RETURN raw
PARALLEL_ENABLE AGGREGATE USING matt_hash_aggregate_impl;
/
Create a test table to work with (you skip this since you have your real table)
create table mattmsi as select * from mtl_system_items where rownum <= 200000;
Create a virtual column hash of each row's data. Make sure it is NOT NULL
alter table mattmsi add compliance_hash generated always as ( dbms_crypto.hash(to_clob(inventory_item_id || segment1 || last_update_date || created_by || description), 3 /*dbms_crypto.hash_sh1*/) ) VIRTUAL not null ;
Create an index on the virtual column; this way you can compute your hash with an full scan of the narrow index instead of a full scan of the fat table
create index msi_compliance_hash_n1 on mattmsi (compliance_hash);
Put it all together to compute your hash
SELECT matt_hash_aggregate(compliance_hash) from (select compliance_hash from mattmsi order by compliance_hash);
A few comments:
- I think it is important to use a hash to compute the aggregate
(rather than merely doing a
SUM()
over the row-level hashes,
because an attacker could forge the correct sum very easily.
- I don't think you can (easily?) use parallel query because it is
important that the rows be fed to the aggregate function in a
consistent order, or else the hash value will change.