├── AUTHORS ├── COPYRIGHT ├── README.md └── audit.sql /AUTHORS: -------------------------------------------------------------------------------- 1 | Craig Ringer 2 | github: 3 | 4 | with contributions including: 5 | 6 | github: 3nids 7 | github: ADTC 8 | github: asenyshyn 9 | github: jhm713 10 | github: paulovieira 11 | github: nineinchnick 12 | -------------------------------------------------------------------------------- /COPYRIGHT: -------------------------------------------------------------------------------- 1 | The following is "The PostgreSQL License", effectively equivalent to the BSD 2 | license. 3 | 4 | I, Craig Ringer, cede any copyright on this work to the PostgreSQL Global 5 | Development Group. 6 | 7 | ------ 8 | 9 | PostgreSQL Audit Trigger Example 10 | Copyright (c) 2013, PostgreSQL Global Development Group 11 | 12 | Permission to use, copy, modify, and distribute this software and its 13 | documentation for any purpose, without fee, and without a written agreement 14 | is hereby granted, provided that the above copyright notice and this 15 | paragraph and the following two paragraphs appear in all copies. 16 | 17 | IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR 18 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 19 | LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS 20 | DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE 21 | POSSIBILITY OF SUCH DAMAGE. 22 | 23 | THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES, 24 | INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY 25 | AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS 26 | ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO 27 | PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 28 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | A simple, customisable table audit system for PostgreSQL implemented using triggers. 2 | 3 | This is based off https://github.com/2ndQuadrant/audit-trigger with the following changes 4 | 5 | 1. The row data is stored in `jsonb`. 6 | 2. Logs user information from hasura's graphql-engine (accessible by `current_setting('hasura.user')`). 7 | 8 | ## Installation 9 | 10 | Load `audit.sql` into the database where you want to set up auditing. You can do this via psql or any other tool that lets you execute sql on the database. 11 | 12 | ```bash 13 | psql -h -p -U -d -f audit.sql --single-transaction 14 | ``` 15 | 16 | ## Setting up triggers 17 | 18 | Run the following sql to setup audit on a table 19 | 20 | ```sql 21 | select audit.audit_table('author'); 22 | ``` 23 | 24 | For a table in a different schema name as follows: 25 | 26 | ```sql 27 | select audit.audit_table('shipping.delivery'); 28 | ``` 29 | 30 | This sets up triggers on the given table which logs any change (insert/update/delete) into the table `audit.logged_actions`. 31 | 32 | ```sql 33 | select * from audit.logged_actions 34 | ``` 35 | 36 | ## Available options 37 | 38 | The function `audit.audit_table` takes the following arguments: 39 | 40 | | argument | description | 41 | | --- | --- | 42 | | `target_table` | Table name, schema qualified if not on search_path | 43 | | `audit_rows` | Record each row change, or only audit at a statement level | 44 | | `audit_query_text` | Record the text of the client query that triggered the audit event? | 45 | | `ignored_cols` | Columns to exclude from update diffs, ignore updates that change only ignored cols. | 46 | 47 | ### Examples 48 | 49 | Do not log changes for every row 50 | 51 | ```sql 52 | select audit.audit_table('author', false); 53 | ``` 54 | 55 | Log changes for every row but don't log the sql statement 56 | 57 | ```sql 58 | select audit.audit_table('author', true, false); 59 | ``` 60 | 61 | Log changes for every row, log the sql statement, but don't log the data of the columns `email` and `phone_number` 62 | 63 | ```sql 64 | select audit.audit_table('author', true, true, '{email,phone_number}'); 65 | ``` 66 | -------------------------------------------------------------------------------- /audit.sql: -------------------------------------------------------------------------------- 1 | -- This is based on 2ndQuadrant/audit-trigger. 2 | -- 3 | -- Few changes from the original 4 | -- 1. Requires postgres >= 10 5 | -- 2. Row data is stored in jsonb 6 | 7 | -- The following are comments preserved from the original file: 8 | 9 | --> -- An audit history is important on most tables. Provide an audit trigger that logs to 10 | --> -- a dedicated audit table for the major relations. 11 | --> -- 12 | --> -- This file should be generic and not depend on application roles or structures, 13 | --> -- as it's being listed here: 14 | --> -- 15 | --> -- This trigger was originally based on 16 | --> -- http://wiki.postgresql.org/wiki/Audit_trigger 17 | --> -- but has been completely rewritten. 18 | --> -- 19 | 20 | CREATE SCHEMA audit; 21 | REVOKE ALL ON SCHEMA audit FROM public; 22 | 23 | COMMENT ON SCHEMA audit IS 'Out-of-table audit/history logging tables and trigger functions'; 24 | 25 | -- 26 | -- Audited data. Lots of information is available, it's just a matter of how much 27 | -- you really want to record. See: 28 | -- 29 | -- http://www.postgresql.org/docs/9.1/static/functions-info.html 30 | -- 31 | -- Remember, every column you add takes up more audit table space and slows audit 32 | -- inserts. 33 | -- 34 | -- Every index you add has a big impact too, so avoid adding indexes to the 35 | -- audit table unless you REALLY need them. 36 | -- 37 | -- It is sometimes worth copying the audit table, or a coarse subset of it that 38 | -- you're interested in, into a temporary table where you CREATE any useful 39 | -- indexes and do your analysis. 40 | -- 41 | CREATE TABLE audit.logged_actions ( 42 | event_id bigserial primary key, 43 | 44 | schema_name text not null, 45 | table_name text not null, 46 | relid oid not null, 47 | 48 | session_user_name text, 49 | hasura_user jsonb, 50 | 51 | action_tstamp_tx TIMESTAMP WITH TIME ZONE NOT NULL, 52 | action_tstamp_stm TIMESTAMP WITH TIME ZONE NOT NULL, 53 | action_tstamp_clk TIMESTAMP WITH TIME ZONE NOT NULL, 54 | transaction_id bigint, 55 | 56 | application_name text, 57 | client_addr inet, 58 | client_port integer, 59 | 60 | client_query text, 61 | action TEXT NOT NULL CHECK (action IN ('I','D','U', 'T')), 62 | row_data jsonb, 63 | changed_fields jsonb, 64 | statement_only boolean not null 65 | ); 66 | 67 | REVOKE ALL ON audit.logged_actions FROM public; 68 | 69 | COMMENT ON TABLE audit.logged_actions IS 'History of auditable actions on audited tables, from audit.if_modified_func()'; 70 | COMMENT ON COLUMN audit.logged_actions.event_id IS 'Unique identifier for each auditable event'; 71 | COMMENT ON COLUMN audit.logged_actions.schema_name IS 'Database schema audited table for this event is in'; 72 | COMMENT ON COLUMN audit.logged_actions.table_name IS 'Non-schema-qualified table name of table event occured in'; 73 | COMMENT ON COLUMN audit.logged_actions.relid IS 'Table OID. Changes with drop/create. Get with ''tablename''::regclass'; 74 | COMMENT ON COLUMN audit.logged_actions.session_user_name IS 'Login / session user whose statement caused the audited event'; 75 | COMMENT ON COLUMN audit.logged_actions.action_tstamp_tx IS 'Transaction start timestamp for tx in which audited event occurred'; 76 | COMMENT ON COLUMN audit.logged_actions.action_tstamp_stm IS 'Statement start timestamp for tx in which audited event occurred'; 77 | COMMENT ON COLUMN audit.logged_actions.action_tstamp_clk IS 'Wall clock time at which audited event''s trigger call occurred'; 78 | COMMENT ON COLUMN audit.logged_actions.transaction_id IS 'Identifier of transaction that made the change. May wrap, but unique paired with action_tstamp_tx.'; 79 | COMMENT ON COLUMN audit.logged_actions.client_addr IS 'IP address of client that issued query. Null for unix domain socket.'; 80 | COMMENT ON COLUMN audit.logged_actions.client_port IS 'Remote peer IP port address of client that issued query. Undefined for unix socket.'; 81 | COMMENT ON COLUMN audit.logged_actions.client_query IS 'Top-level query that caused this auditable event. May be more than one statement.'; 82 | COMMENT ON COLUMN audit.logged_actions.application_name IS 'Application name set when this audit event occurred. Can be changed in-session by client.'; 83 | COMMENT ON COLUMN audit.logged_actions.action IS 'Action type; I = insert, D = delete, U = update, T = truncate'; 84 | COMMENT ON COLUMN audit.logged_actions.row_data IS 'Record value. Null for statement-level trigger. For INSERT this is the new tuple. For DELETE and UPDATE it is the old tuple.'; 85 | COMMENT ON COLUMN audit.logged_actions.changed_fields IS 'New values of fields changed by UPDATE. Null except for row-level UPDATE events.'; 86 | COMMENT ON COLUMN audit.logged_actions.statement_only IS '''t'' if audit event is from an FOR EACH STATEMENT trigger, ''f'' for FOR EACH ROW'; 87 | 88 | CREATE INDEX logged_actions_relid_idx ON audit.logged_actions(relid); 89 | CREATE INDEX logged_actions_action_tstamp_tx_stm_idx ON audit.logged_actions(action_tstamp_stm); 90 | CREATE INDEX logged_actions_action_idx ON audit.logged_actions(action); 91 | 92 | CREATE OR REPLACE FUNCTION audit.if_modified_func() RETURNS TRIGGER AS $body$ 93 | DECLARE 94 | audit_row audit.logged_actions; 95 | excluded_cols text[] = ARRAY[]::text[]; 96 | new_r jsonb; 97 | old_r jsonb; 98 | BEGIN 99 | IF TG_WHEN <> 'AFTER' THEN 100 | RAISE EXCEPTION 'audit.if_modified_func() may only run as an AFTER trigger'; 101 | END IF; 102 | 103 | audit_row = ROW( 104 | nextval('audit.logged_actions_event_id_seq'), -- event_id 105 | TG_TABLE_SCHEMA::text, -- schema_name 106 | TG_TABLE_NAME::text, -- table_name 107 | TG_RELID, -- relation OID for much quicker searches 108 | session_user::text, -- session_user_name 109 | current_setting('hasura.user', 't')::jsonb, -- user information from hasura graphql engine 110 | current_timestamp, -- action_tstamp_tx 111 | statement_timestamp(), -- action_tstamp_stm 112 | clock_timestamp(), -- action_tstamp_clk 113 | txid_current(), -- transaction ID 114 | current_setting('application_name'), -- client application 115 | inet_client_addr(), -- client_addr 116 | inet_client_port(), -- client_port 117 | current_query(), -- top-level query or queries (if multistatement) from client 118 | substring(TG_OP,1,1), -- action 119 | NULL, NULL, -- row_data, changed_fields 120 | 'f' -- statement_only 121 | ); 122 | 123 | IF NOT TG_ARGV[0]::boolean IS DISTINCT FROM 'f'::boolean THEN 124 | audit_row.client_query = NULL; 125 | END IF; 126 | 127 | IF TG_ARGV[1] IS NOT NULL THEN 128 | excluded_cols = TG_ARGV[1]::text[]; 129 | END IF; 130 | 131 | IF (TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW') THEN 132 | old_r = to_jsonb(OLD); 133 | new_r = to_jsonb(NEW); 134 | audit_row.row_data = old_r - excluded_cols; 135 | SELECT 136 | jsonb_object_agg(new_t.key, new_t.value) - excluded_cols 137 | INTO 138 | audit_row.changed_fields 139 | FROM jsonb_each(old_r) as old_t 140 | JOIN jsonb_each(new_r) as new_t 141 | ON (old_t.key = new_t.key AND old_t.value <> new_t.value); 142 | ELSIF (TG_OP = 'DELETE' AND TG_LEVEL = 'ROW') THEN 143 | audit_row.row_data = to_jsonb(OLD) - excluded_cols; 144 | ELSIF (TG_OP = 'INSERT' AND TG_LEVEL = 'ROW') THEN 145 | audit_row.row_data = to_jsonb(NEW) - excluded_cols; 146 | ELSIF (TG_LEVEL = 'STATEMENT' AND TG_OP IN ('INSERT','UPDATE','DELETE','TRUNCATE')) THEN 147 | audit_row.statement_only = 't'; 148 | ELSE 149 | RAISE EXCEPTION '[audit.if_modified_func] - Trigger func added as trigger for unhandled case: %, %',TG_OP, TG_LEVEL; 150 | RETURN NULL; 151 | END IF; 152 | INSERT INTO audit.logged_actions VALUES (audit_row.*); 153 | RETURN NULL; 154 | END; 155 | $body$ 156 | LANGUAGE plpgsql 157 | SECURITY DEFINER 158 | SET search_path = pg_catalog, public; 159 | 160 | 161 | COMMENT ON FUNCTION audit.if_modified_func() IS $body$ 162 | Track changes to a table at the statement and/or row level. 163 | 164 | Optional parameters to trigger in CREATE TRIGGER call: 165 | 166 | param 0: boolean, whether to log the query text. Default 't'. 167 | 168 | param 1: text[], columns to ignore in updates. Default []. 169 | 170 | Updates to ignored cols are omitted from changed_fields. 171 | 172 | Updates with only ignored cols changed are not inserted 173 | into the audit log. 174 | 175 | Almost all the processing work is still done for updates 176 | that ignored. If you need to save the load, you need to use 177 | WHEN clause on the trigger instead. 178 | 179 | No warning or error is issued if ignored_cols contains columns 180 | that do not exist in the target table. This lets you specify 181 | a standard set of ignored columns. 182 | 183 | There is no parameter to disable logging of values. Add this trigger as 184 | a 'FOR EACH STATEMENT' rather than 'FOR EACH ROW' trigger if you do not 185 | want to log row values. 186 | 187 | Note that the user name logged is the login role for the session. The audit trigger 188 | cannot obtain the active role because it is reset by the SECURITY DEFINER invocation 189 | of the audit trigger its self. 190 | $body$; 191 | 192 | 193 | 194 | CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass, audit_rows boolean, audit_query_text boolean, ignored_cols text[]) RETURNS void AS $body$ 195 | DECLARE 196 | stm_targets text = 'INSERT OR UPDATE OR DELETE OR TRUNCATE'; 197 | _q_txt text; 198 | _ignored_cols_snip text = ''; 199 | BEGIN 200 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_row ON ' || target_table; 201 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_stm ON ' || target_table; 202 | 203 | IF audit_rows THEN 204 | IF array_length(ignored_cols,1) > 0 THEN 205 | _ignored_cols_snip = ', ' || quote_literal(ignored_cols); 206 | END IF; 207 | _q_txt = 'CREATE TRIGGER audit_trigger_row AFTER INSERT OR UPDATE OR DELETE ON ' || 208 | target_table || 209 | ' FOR EACH ROW EXECUTE PROCEDURE audit.if_modified_func(' || 210 | quote_literal(audit_query_text) || _ignored_cols_snip || ');'; 211 | RAISE NOTICE '%',_q_txt; 212 | EXECUTE _q_txt; 213 | stm_targets = 'TRUNCATE'; 214 | ELSE 215 | END IF; 216 | 217 | _q_txt = 'CREATE TRIGGER audit_trigger_stm AFTER ' || stm_targets || ' ON ' || 218 | target_table || 219 | ' FOR EACH STATEMENT EXECUTE PROCEDURE audit.if_modified_func('|| 220 | quote_literal(audit_query_text) || ');'; 221 | RAISE NOTICE '%',_q_txt; 222 | EXECUTE _q_txt; 223 | 224 | END; 225 | $body$ 226 | language 'plpgsql'; 227 | 228 | COMMENT ON FUNCTION audit.audit_table(regclass, boolean, boolean, text[]) IS $body$ 229 | Add auditing support to a table. 230 | 231 | Arguments: 232 | target_table: Table name, schema qualified if not on search_path 233 | audit_rows: Record each row change, or only audit at a statement level 234 | audit_query_text: Record the text of the client query that triggered the audit event? 235 | ignored_cols: Columns to exclude from update diffs, ignore updates that change only ignored cols. 236 | $body$; 237 | 238 | -- Pg doesn't allow variadic calls with 0 params, so provide a wrapper 239 | CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass, audit_rows boolean, audit_query_text boolean) RETURNS void AS $body$ 240 | SELECT audit.audit_table($1, $2, $3, ARRAY[]::text[]); 241 | $body$ LANGUAGE SQL; 242 | 243 | -- And provide a convenience call wrapper for the simplest case 244 | -- of row-level logging with no excluded cols and query logging enabled. 245 | -- 246 | CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass) RETURNS void AS $body$ 247 | SELECT audit.audit_table($1, BOOLEAN 't', BOOLEAN 't'); 248 | $body$ LANGUAGE 'sql'; 249 | 250 | COMMENT ON FUNCTION audit.audit_table(regclass) IS $body$ 251 | Add auditing support to the given table. Row-level changes will be logged with full client query text. No cols are ignored. 252 | $body$; 253 | --------------------------------------------------------------------------------