|
| 1 | +-- An audit history is important on most tables. Provide an audit trigger that logs to |
| 2 | +-- a dedicated audit table for the major relations. |
| 3 | +-- |
| 4 | +-- This file should be generic and not depend on application roles or structures, |
| 5 | +-- as it's being listed here: |
| 6 | +-- |
| 7 | +-- https://wiki.postgresql.org/wiki/Audit_trigger_91plus |
| 8 | +-- |
| 9 | +-- This trigger was originally based on |
| 10 | +-- http://wiki.postgresql.org/wiki/Audit_trigger |
| 11 | +-- but has been completely rewritten. |
| 12 | + |
| 13 | +CREATE EXTENSION IF NOT EXISTS hstore; |
| 14 | + |
| 15 | +CREATE SCHEMA audit; |
| 16 | +REVOKE ALL ON SCHEMA audit FROM public; |
| 17 | + |
| 18 | +COMMENT ON SCHEMA audit IS 'Out-of-table audit/history logging tables and trigger functions'; |
| 19 | + |
| 20 | +-- |
| 21 | +-- Audited data. Lots of information is available, it's just a matter of how much |
| 22 | +-- you really want to record. See: |
| 23 | +-- |
| 24 | +-- http://www.postgresql.org/docs/9.1/static/functions-info.html |
| 25 | +-- |
| 26 | +-- Remember, every column you add takes up more audit table space and slows audit |
| 27 | +-- inserts. |
| 28 | +-- |
| 29 | +-- Every index you add has a big impact too, so avoid adding indexes to the |
| 30 | +-- audit table unless you REALLY need them. The hstore GIST indexes are |
| 31 | +-- particularly expensive. |
| 32 | +-- |
| 33 | +-- It is sometimes worth copying the audit table, or a coarse subset of it that |
| 34 | +-- you're interested in, into a temporary table where you CREATE any useful |
| 35 | +-- indexes and do your analysis. |
| 36 | +-- |
| 37 | +CREATE TABLE audit.logged_actions ( |
| 38 | + event_id bigserial primary key, |
| 39 | + schema_name text not null, |
| 40 | + table_name text not null, |
| 41 | + relid oid not null, |
| 42 | + session_user_name text, |
| 43 | + action_tstamp_tx TIMESTAMP WITH TIME ZONE NOT NULL, |
| 44 | + action_tstamp_stm TIMESTAMP WITH TIME ZONE NOT NULL, |
| 45 | + action_tstamp_clk TIMESTAMP WITH TIME ZONE NOT NULL, |
| 46 | + transaction_id bigint, |
| 47 | + application_name text, |
| 48 | + client_addr inet, |
| 49 | + client_port integer, |
| 50 | + client_query text not null, |
| 51 | + action TEXT NOT NULL CHECK (action IN ('I','D','U', 'T')), |
| 52 | + row_data hstore, |
| 53 | + changed_fields hstore, |
| 54 | + statement_only boolean not null |
| 55 | +); |
| 56 | + |
| 57 | +REVOKE ALL ON audit.logged_actions FROM public; |
| 58 | + |
| 59 | +COMMENT ON TABLE audit.logged_actions IS 'History of auditable actions on audited tables, from audit.if_modified_func()'; |
| 60 | +COMMENT ON COLUMN audit.logged_actions.event_id IS 'Unique identifier for each auditable event'; |
| 61 | +COMMENT ON COLUMN audit.logged_actions.schema_name IS 'Database schema audited table for this event is in'; |
| 62 | +COMMENT ON COLUMN audit.logged_actions.table_name IS 'Non-schema-qualified table name of table event occured in'; |
| 63 | +COMMENT ON COLUMN audit.logged_actions.relid IS 'Table OID. Changes with drop/create. Get with ''tablename''::regclass'; |
| 64 | +COMMENT ON COLUMN audit.logged_actions.session_user_name IS 'Login / session user whose statement caused the audited event'; |
| 65 | +COMMENT ON COLUMN audit.logged_actions.action_tstamp_tx IS 'Transaction start timestamp for tx in which audited event occurred'; |
| 66 | +COMMENT ON COLUMN audit.logged_actions.action_tstamp_stm IS 'Statement start timestamp for tx in which audited event occurred'; |
| 67 | +COMMENT ON COLUMN audit.logged_actions.action_tstamp_clk IS 'Wall clock time at which audited event''s trigger call occurred'; |
| 68 | +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.'; |
| 69 | +COMMENT ON COLUMN audit.logged_actions.client_addr IS 'IP address of client that issued query. Null for unix ___domain socket.'; |
| 70 | +COMMENT ON COLUMN audit.logged_actions.client_port IS 'Remote peer IP port address of client that issued query. Undefined for unix socket.'; |
| 71 | +COMMENT ON COLUMN audit.logged_actions.client_query IS 'Top-level query that caused this auditable event. May be more than one statement.'; |
| 72 | +COMMENT ON COLUMN audit.logged_actions.application_name IS 'Application name set when this audit event occurred. Can be changed in-session by client.'; |
| 73 | +COMMENT ON COLUMN audit.logged_actions.action IS 'Action type; I = insert, D = delete, U = update, T = truncate'; |
| 74 | +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.'; |
| 75 | +COMMENT ON COLUMN audit.logged_actions.changed_fields IS 'New values of fields changed by UPDATE. Null except for row-level UPDATE events.'; |
| 76 | +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'; |
| 77 | + |
| 78 | +CREATE INDEX logged_actions_relid_idx ON audit.logged_actions(relid); |
| 79 | +CREATE INDEX logged_actions_action_tstamp_tx_stm_idx ON audit.logged_actions(action_tstamp_stm); |
| 80 | +CREATE INDEX logged_actions_action_idx ON audit.logged_actions(action); |
| 81 | + |
| 82 | +CREATE OR REPLACE FUNCTION audit.if_modified_func() RETURNS TRIGGER AS $body$ |
| 83 | +DECLARE |
| 84 | + audit_row audit.logged_actions; |
| 85 | + include_values boolean; |
| 86 | + log_diffs boolean; |
| 87 | + h_old hstore; |
| 88 | + h_new hstore; |
| 89 | + excluded_cols text[] = ARRAY[]::text[]; |
| 90 | +BEGIN |
| 91 | + IF TG_WHEN <> 'AFTER' THEN |
| 92 | + RAISE EXCEPTION 'audit.if_modified_func() may only run as an AFTER trigger'; |
| 93 | + END IF; |
| 94 | + |
| 95 | + audit_row = ROW( |
| 96 | + nextval('audit.logged_actions_event_id_seq'), -- event_id |
| 97 | + TG_TABLE_SCHEMA::text, -- schema_name |
| 98 | + TG_TABLE_NAME::text, -- table_name |
| 99 | + TG_RELID, -- relation OID for much quicker searches |
| 100 | + session_user::text, -- session_user_name |
| 101 | + current_timestamp, -- action_tstamp_tx |
| 102 | + statement_timestamp(), -- action_tstamp_stm |
| 103 | + clock_timestamp(), -- action_tstamp_clk |
| 104 | + txid_current(), -- transaction ID |
| 105 | + (SELECT setting FROM pg_settings WHERE name = 'application_name'), |
| 106 | + inet_client_addr(), -- client_addr |
| 107 | + inet_client_port(), -- client_port |
| 108 | + current_query(), -- top-level query or queries (if multistatement) from client |
| 109 | + substring(TG_OP,1,1), -- action |
| 110 | + NULL, NULL, -- row_data, changed_fields |
| 111 | + 'f' -- statement_only |
| 112 | + ); |
| 113 | + |
| 114 | + IF NOT TG_ARGV[0]::boolean IS DISTINCT FROM 'f'::boolean THEN |
| 115 | + audit_row.client_query = NULL; |
| 116 | + END IF; |
| 117 | + |
| 118 | + IF TG_ARGV[1] IS NOT NULL THEN |
| 119 | + excluded_cols = TG_ARGV[1]::text[]; |
| 120 | + END IF; |
| 121 | + |
| 122 | + IF (TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW') THEN |
| 123 | + audit_row.row_data = hstore(OLD.*); |
| 124 | + audit_row.changed_fields = (hstore(NEW.*) - audit_row.row_data) - excluded_cols; |
| 125 | + IF audit_row.changed_fields = hstore('') THEN |
| 126 | + -- All changed fields are ignored. Skip this update. |
| 127 | + RETURN NULL; |
| 128 | + END IF; |
| 129 | + ELSIF (TG_OP = 'DELETE' AND TG_LEVEL = 'ROW') THEN |
| 130 | + audit_row.row_data = hstore(OLD.*) - excluded_cols; |
| 131 | + ELSIF (TG_OP = 'INSERT' AND TG_LEVEL = 'ROW') THEN |
| 132 | + audit_row.row_data = hstore(NEW.*) - excluded_cols; |
| 133 | + ELSIF (TG_LEVEL = 'STATEMENT' AND TG_OP IN ('INSERT','UPDATE','DELETE','TRUNCATE')) THEN |
| 134 | + audit_row.statement_only = 't'; |
| 135 | + ELSE |
| 136 | + RAISE EXCEPTION '[audit.if_modified_func] - Trigger func added as trigger for unhandled case: %, %',TG_OP, TG_LEVEL; |
| 137 | + RETURN NULL; |
| 138 | + END IF; |
| 139 | + INSERT INTO audit.logged_actions VALUES (audit_row.*); |
| 140 | + RETURN NULL; |
| 141 | +END; |
| 142 | +$body$ |
| 143 | +LANGUAGE plpgsql |
| 144 | +SECURITY DEFINER |
| 145 | +SET search_path = pg_catalog, public; |
| 146 | + |
| 147 | + |
| 148 | +COMMENT ON FUNCTION audit.if_modified_func() IS $body$ |
| 149 | +Track changes to a table at the statement and/or row level. |
| 150 | + |
| 151 | +Optional parameters to trigger in CREATE TRIGGER call: |
| 152 | + |
| 153 | +param 0: boolean, whether to log the query text. Default 't'. |
| 154 | + |
| 155 | +param 1: text[], columns to ignore in updates. Default []. |
| 156 | + |
| 157 | + Updates to ignored cols are omitted from changed_fields. |
| 158 | + |
| 159 | + Updates with only ignored cols changed are not inserted |
| 160 | + into the audit log. |
| 161 | + |
| 162 | + Almost all the processing work is still done for updates |
| 163 | + that ignored. If you need to save the load, you need to use |
| 164 | + WHEN clause on the trigger instead. |
| 165 | + |
| 166 | + No warning or error is issued if ignored_cols contains columns |
| 167 | + that do not exist in the target table. This lets you specify |
| 168 | + a standard set of ignored columns. |
| 169 | + |
| 170 | +There is no parameter to disable logging of values. Add this trigger as |
| 171 | +a 'FOR EACH STATEMENT' rather than 'FOR EACH ROW' trigger if you do not |
| 172 | +want to log row values. |
| 173 | + |
| 174 | +Note that the user name logged is the login role for the session. The audit trigger |
| 175 | +cannot obtain the active role because it is reset by the SECURITY DEFINER invocation |
| 176 | +of the audit trigger its self. |
| 177 | +$body$; |
| 178 | + |
| 179 | + |
| 180 | + |
| 181 | +CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass, audit_rows boolean, audit_query_text boolean, ignored_cols text[]) RETURNS void AS $body$ |
| 182 | +DECLARE |
| 183 | + stm_targets text = 'INSERT OR UPDATE OR DELETE OR TRUNCATE'; |
| 184 | + _q_txt text; |
| 185 | + _ignored_cols_snip text = ''; |
| 186 | +BEGIN |
| 187 | + EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_row ON ' || quote_ident(target_table::text); |
| 188 | + EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_stm ON ' || quote_ident(target_table::text); |
| 189 | + |
| 190 | + IF audit_rows THEN |
| 191 | + IF array_length(ignored_cols,1) > 0 THEN |
| 192 | + _ignored_cols_snip = ', ' || quote_literal(ignored_cols); |
| 193 | + END IF; |
| 194 | + _q_txt = 'CREATE TRIGGER audit_trigger_row AFTER INSERT OR UPDATE OR DELETE ON ' || |
| 195 | + quote_ident(target_table::text) || |
| 196 | + ' FOR EACH ROW EXECUTE PROCEDURE audit.if_modified_func(' || |
| 197 | + quote_literal(audit_query_text) || _ignored_cols_snip || ');'; |
| 198 | + RAISE NOTICE '%',_q_txt; |
| 199 | + EXECUTE _q_txt; |
| 200 | + stm_targets = 'TRUNCATE'; |
| 201 | + ELSE |
| 202 | + END IF; |
| 203 | + |
| 204 | + _q_txt = 'CREATE TRIGGER audit_trigger_stm AFTER ' || stm_targets || ' ON ' || |
| 205 | + quote_ident(target_table::text) || |
| 206 | + ' FOR EACH STATEMENT EXECUTE PROCEDURE audit.if_modified_func('|| |
| 207 | + quote_literal(audit_query_text) || ');'; |
| 208 | + RAISE NOTICE '%',_q_txt; |
| 209 | + EXECUTE _q_txt; |
| 210 | + |
| 211 | +END; |
| 212 | +$body$ |
| 213 | +language 'plpgsql'; |
| 214 | + |
| 215 | +COMMENT ON FUNCTION audit.audit_table(regclass, boolean, boolean, text[]) IS $body$ |
| 216 | +Add auditing support to a table. |
| 217 | + |
| 218 | +Arguments: |
| 219 | + target_table: Table name, schema qualified if not on search_path |
| 220 | + audit_rows: Record each row change, or only audit at a statement level |
| 221 | + audit_query_text: Record the text of the client query that triggered the audit event? |
| 222 | + ignored_cols: Columns to exclude from update diffs, ignore updates that change only ignored cols. |
| 223 | +$body$; |
| 224 | + |
| 225 | +-- Pg doesn't allow variadic calls with 0 params, so provide a wrapper |
| 226 | +CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass, audit_rows boolean, audit_query_text boolean) RETURNS void AS $body$ |
| 227 | +SELECT audit.audit_table($1, $2, $3, ARRAY[]::text[]); |
| 228 | +$body$ LANGUAGE SQL; |
| 229 | + |
| 230 | +-- And provide a convenience call wrapper for the simplest case |
| 231 | +-- of row-level logging with no excluded cols and query logging enabled. |
| 232 | +-- |
| 233 | +CREATE OR REPLACE FUNCTION audit.audit_table(target_table regclass) RETURNS void AS $$ |
| 234 | +SELECT audit.audit_table($1, BOOLEAN 't', BOOLEAN 't'); |
| 235 | +$$ LANGUAGE 'sql'; |
| 236 | + |
| 237 | +COMMENT ON FUNCTION audit.audit_table(regclass) IS $body$ |
| 238 | +Add auditing support to the given table. Row-level changes will be logged with full client query text. No cols are ignored. |
| 239 | +$body$; |
0 commit comments