2 -- Glyn Astill 28/08/2015
4 -- Attempt at pl/pgsql drop-in replacement for table_log C extenstion AKA
5 -- pg Table Audit / PostgreSQL Table Log / tablelog by Andreas Scherbaum
6 -- http://www.postgresql.org/ftp/projects/pgFoundry/tablelog/tablelog/
7 -- http://github.com/andreasscherbaum/table_log
9 -- A slightly more up to date version of the original C extension can
10 -- also be found here:
11 -- https://github.com/glynastill/pg_table_audit
13 -- There are now many better ways to audit DML, using json types or
14 -- advanced extensions like pgaudit (below), however if for some reason
15 -- you're stuck with table_log this may help.
17 -- http://8kb.co.uk/blog/2015/01/19/copying-pavel-stehules-simple-history-table-but-with-the-jsonb-type/
18 -- https://github.com/2ndQuadrant/pgaudit
22 DROP FUNCTION IF EXISTS table_log_pl (); -- ignore any error (but do not CASCADE)
23 DROP FUNCTION IF EXISTS table_log_restore_table_pl(varchar, varchar, char, char, char, timestamptz, char, int, int, varchar, varchar);
25 -- Table_log plpgsql function; there's better ways to do this, but this is a drop in replacement for table_log C functions.
26 CREATE OR REPLACE FUNCTION table_log_pl() RETURNS TRIGGER AS
30 v_loguser boolean := false;
34 v_col_trig text := '';
35 v_val_trig text := '';
39 v_enable_cache boolean := true;
40 v_enable_prepare boolean := true;
50 -- - The trigger_id comes off sequence, this function is oblivious
51 -- - 3 columns means don't log trigger_user or trigger_id
52 -- - 4 columns means don't log trigger_user
53 -- - 5 columns means log both
54 -- - To use the column data caching on server versions prior to
55 -- 9.6 add custom var "table_log.column_cache = ''" to postgresql.conf
57 IF (TG_NARGS > 2) THEN
58 v_nspname := TG_ARGV[2];
60 v_nspname := TG_TABLE_SCHEMA;
63 IF (TG_NARGS > 1 AND TG_ARGV[1]::int = 1) THEN
67 IF (TG_NARGS > 0) THEN
68 v_tabname := TG_ARGV[0];
70 v_tabname := TG_TABLE_NAME || '_log';
73 -- Retrieve custom variable used as a poor mans cache for multirow statements
74 IF (v_enable_cache) THEN
75 IF (current_setting('server_version_num')::int >= 90600) THEN
76 v_col_cache := current_setting('table_log.column_cache', true);
78 v_col_cache := current_setting('table_log.column_cache');
82 -- If column caching is enabled and previous call in this transaction
83 -- was for the same relation we can retrieve column detail.
84 IF (v_enable_cache AND left(v_col_cache, length(TG_RELID::text)+1) = (TG_RELID::text || ':')) THEN
85 v_cols := right(v_col_cache, (length(TG_RELID::text)+1)*-1);
86 v_cols_nam := ('{' || right(v_col_cache, (length(TG_RELID::text)+1)*-1) || '}')::text[];
87 ELSE -- Otherwise fetch the column detail
88 IF (TG_WHEN != 'AFTER') THEN
89 RAISE EXCEPTION 'table_log: must be fired after event';
91 IF (TG_LEVEL = 'STATEMENT') THEN
92 RAISE EXCEPTION 'table_log: can''t process STATEMENT events';
95 SELECT count(*), string_agg(quote_ident(attname),','), string_agg(format_type(atttypid, atttypmod),','), array_agg(quote_ident(attname))
96 INTO STRICT v_num_col, v_cols, v_cols_typ, v_cols_nam
97 FROM pg_catalog.pg_attribute
98 WHERE attrelid = TG_RELID
100 AND NOT attisdropped;
102 IF (v_num_col < 1) THEN
103 RAISE EXCEPTION 'table_log: number of columns in table is < 1, can this happen?';
106 SELECT count(*) INTO STRICT v_num_col_log
107 FROM pg_catalog.pg_attribute
108 WHERE attrelid = (v_nspname || '.' || v_tabname)::regclass
110 AND NOT attisdropped;
112 IF (v_num_col_log < 1) THEN
113 RAISE EXCEPTION 'could not get number columns in relation %.%', v_nspname, v_tabname;
116 -- This is the way the original checks column count regardless of trigger_id is presence
117 IF (v_num_col_log != (v_num_col + 3 + v_loguser::int)) AND (v_num_col_log != (v_num_col + 4 + v_loguser::int)) THEN
118 RAISE EXCEPTION 'number colums in relation %.%(%) does not match columns in %.%(%)', TG_TABLE_SCHEMA, TG_TABLE_NAME, v_num_col, v_nspname, v_tabname, v_num_col_log;
121 -- Set custom variable for use as a poor mans cache for multirow statements
122 IF (v_enable_cache) THEN
123 v_col_cache := (TG_RELID::text || ':' || v_cols);
124 PERFORM set_config('table_log.column_cache', v_col_cache, true);
127 -- Create a prepared statement for the current table, deallocating
128 -- any old statements we may have prepared.
129 IF (v_enable_prepare) THEN
130 FOR v_tmp IN (SELECT name FROM pg_catalog.pg_prepared_statements WHERE name ~ '^table_log_pl_') LOOP
131 EXECUTE format('DEALLOCATE %I', v_tmp);
134 SELECT '$' || string_agg(a::text, ', $') INTO v_col_trig FROM generate_series(1,v_num_col+3+v_loguser::int) a;
137 v_sql := format('PREPARE table_log_pl_%s(%s, text, text, timestamptz, text) AS INSERT INTO %I.%I (%s, "trigger_user", "trigger_mode", "trigger_changed", "trigger_tuple") VALUES (%s)', TG_RELID, v_cols_typ, v_nspname, v_tabname, v_cols, v_col_trig);
139 v_sql := format('PREPARE table_log_pl_%s(%s, text, timestamptz, text) AS INSERT INTO %I.%I (%s, "trigger_mode", "trigger_changed", "trigger_tuple") VALUES (%s)', TG_RELID, v_cols_typ, v_nspname, v_tabname, v_cols, v_col_trig);
145 -- If prepared statement method is enabled, construct strings for
146 -- variable parameters and execute.
147 IF (v_enable_prepare) THEN
148 FOR v_i IN 1..array_upper(v_cols_nam, 1) LOOP
149 IF (TG_OP != 'INSERT') THEN
150 EXECUTE 'SELECT ($1).' || v_cols_nam[v_i] || '::text' INTO v_tmp USING OLD;
151 v_vals_old := v_vals_old || quote_nullable(v_tmp) || ',';
153 IF (TG_OP != 'DELETE') THEN
154 EXECUTE 'SELECT ($1).' || v_cols_nam[v_i] || '::text' INTO v_tmp USING NEW;
155 v_vals_new := v_vals_new || quote_nullable(v_tmp) || ',';
160 v_vals_new := v_vals_new || quote_literal(session_user) || ',';
161 v_vals_old := v_vals_old || quote_literal(session_user) || ',';
164 IF (TG_OP != 'INSERT') THEN
165 v_sql := format('EXECUTE table_log_pl_%s(%s%L, %L, %L)', TG_RELID, v_vals_old, TG_OP, current_timestamp, 'old');
168 IF (TG_OP != 'DELETE') THEN
169 v_sql := format('EXECUTE table_log_pl_%s(%s%L, %L, %L)', TG_RELID, v_vals_new, TG_OP, current_timestamp, 'new');
175 ELSE -- Otherwise we can do the inserts dynamically.
177 v_col_trig := v_col_trig || ', "trigger_user"';
178 v_val_trig := format('%L, ', session_user);
180 v_col_trig := v_col_trig || ', "trigger_mode", "trigger_changed", "trigger_tuple"';
181 v_val_trig := format('%s%L, %L', v_val_trig, TG_OP, current_timestamp);
183 IF (TG_OP != 'INSERT') THEN
184 v_sql := format('INSERT INTO %I.%I (%s%s) SELECT %s, %s, ''old'' FROM (SELECT ($1::text::%I).*) t', v_nspname, v_tabname, v_cols, v_col_trig, v_cols, v_val_trig, TG_RELID::regclass);
185 EXECUTE v_sql USING OLD;
187 IF (TG_OP != 'DELETE') THEN
188 v_sql := format('INSERT INTO %I.%I (%s%s) SELECT %s, %s, ''new'' FROM (SELECT ($1::text::%I).*) t', v_nspname, v_tabname, v_cols, v_col_trig, v_cols, v_val_trig, TG_RELID::regclass);
189 EXECUTE v_sql USING NEW;
198 LANGUAGE plpgsql VOLATILE;
200 CREATE OR REPLACE FUNCTION table_log_restore_table_pl (origtab varchar, origtab_pk varchar, logtab char, logtab_pk char, restoretab char, to_timestamp timestamptz, search_pk char DEFAULT NULL, method int DEFAULT 0, not_temporarly int DEFAULT 0, origtab_schema varchar DEFAULT NULL, logtab_schema varchar DEFAULT NULL) RETURNS varchar AS
205 v_restoretab_cols int;
217 -- The original implimentation doesn't allow fully qualified table
218 -- references in table_log_restore_table; You can get some milage
219 -- out of search_path if required there. For this reason the plpgsql
220 -- version adds the following two optional parameters to those below:
222 -- - original table schema
223 -- - logging table schema
225 -- Comments from C implimentation:
227 -- restore a complete table based on the logging table
230 -- - original table name
231 -- - name of primary key in original table
233 -- - name of primary key in logging table
234 -- - restore table name
235 -- - timestamp for restoring data
236 -- - primary key to restore (only this key will be restored) (optional)
238 -- 0: restore from blank table (default)
239 -- needs a complete logging table
240 -- 1: restore from actual table backwards
241 -- - dont create table temporarly
242 -- 0: create restore table temporarly (default)
243 -- 1: create restore table not temporarly
247 IF origtab IS NULL THEN
248 RAISE NOTICE 'table_log_restore_table: missing original table name';
250 IF origtab_pk IS NULL THEN
251 RAISE NOTICE 'table_log_restore_table: missing primary key name for original table';
253 IF logtab IS NULL THEN
254 RAISE NOTICE 'table_log_restore_table: missing log table name';
256 IF logtab_pk IS NULL THEN
257 RAISE NOTICE 'table_log_restore_table: missing primary key name for log table';
259 IF restoretab IS NULL THEN
260 RAISE NOTICE 'table_log_restore_table: missing copy table name';
262 IF to_timestamp IS NULL THEN
263 RAISE NOTICE 'table_log_restore_table: missing timestamp';
265 IF (search_pk IS NOT NULL) THEN
266 RAISE NOTICE 'table_log_restore_table: will restore a single key';
269 IF origtab_pk = logtab_pk THEN
270 RAISE EXCEPTION 'pkey of logging table cannot be the pkey of the original table: % <-> %', origtab_pk, logtab_pk;
273 v_origtab_fqn := coalesce(quote_ident(origtab_schema) || '.','') || quote_ident(origtab);
274 v_logtab_fqn := coalesce(quote_ident(logtab_schema) || '.','') || quote_ident(logtab);
276 -- Check original table and get column list
277 SELECT string_agg(quote_ident(attname), ','), count(*), count(*) filter (where attname=origtab_pk)
278 INTO v_cols, v_origtab_cols, v_pk_count
279 FROM pg_catalog.pg_class c
280 JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid
281 JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
282 WHERE c.relname = origtab AND c.relkind='r' AND a.attnum > 0
283 AND (origtab_schema IS NULL OR n.nspname = origtab_schema)
284 AND NOT attisdropped;
286 IF v_origtab_cols = 0 OR v_cols IS NULL THEN
287 RAISE EXCEPTION 'could not check relation: % (columns = %)', v_origtab_fqn, v_origtab_cols;
288 ELSIF v_pk_count != 1 THEN
289 RAISE EXCEPTION 'could not check relation: (missing pkey) % in table %', origtab_pk, v_origtab_fqn;
291 RAISE NOTICE 'original table: OK (% columns)', v_origtab_cols;
295 SELECT count(*), count(*) filter (where attname=logtab_pk)
296 INTO v_logtab_cols, v_pk_count
297 FROM pg_catalog.pg_class c
298 JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid
299 JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
300 WHERE c.relname = logtab AND c.relkind='r' AND a.attnum > 0
301 AND (logtab_schema IS NULL OR n.nspname = logtab_schema)
302 AND NOT attisdropped;
304 IF v_logtab_cols = 0 THEN
305 RAISE EXCEPTION 'could not check relation: % (columns = %)', v_logtab_fqn, v_logtab_cols;
306 ELSIF v_pk_count != 1 THEN
307 RAISE EXCEPTION 'could not check relation: (missing pkey) % in table %', logtab_pk, v_logtab_fqn;
309 RAISE NOTICE 'log table: OK (% columns)', v_logtab_cols;
312 -- Check restore table
313 IF EXISTS(SELECT 1 FROM pg_catalog.pg_class
314 WHERE relname=restoretab AND relkind='r') THEN
315 RAISE EXCEPTION 'restore table already exists: %', restoretab;
317 RAISE NOTICE 'restore table: OK (doesnt exists)';
320 -- create restore table
322 IF not_temporarly = 0 THEN
323 v_sql := v_sql || ' TEMPORARY';
325 v_sql := v_sql || format(' TABLE %I AS SELECT * FROM %s', restoretab, v_origtab_fqn);
326 IF search_pk IS NOT NULL THEN
327 v_sql := v_sql || format(' WHERE %I = %L', origtab_pk, search_pk);
330 RAISE NOTICE 'need logs from start to timestamp: %', to_timestamp;
331 v_sql := v_sql || ' LIMIT 0'; -- Create blank table to roll forward into (need all logs)
333 RAISE NOTICE 'need logs from end to timestamp: %', to_timestamp;
336 -- RAISE NOTICE 'DDL: %', v_sql;
339 -- now build query for getting logs
340 v_sql := format('SELECT * FROM %s WHERE ', v_logtab_fqn);
342 v_sql := v_sql || format('trigger_changed <= %L', to_timestamp); -- ROLL FORWARD
344 v_sql := v_sql || format('trigger_changed >= %L', to_timestamp); -- ROLL BACK
347 IF search_pk IS NOT NULL THEN
348 v_sql := v_sql || format(' AND %I = %L', origtab_pk, search_pk);
352 v_sql := v_sql || format(' ORDER BY %I ASC', logtab_pk);
354 v_sql := v_sql || format(' ORDER BY %I DESC', logtab_pk);
357 -- RAISE NOTICE 'SQL: %', v_sql;
359 FOR v_rec IN EXECUTE v_sql
361 IF v_rec.trigger_mode = 'UPDATE' AND ((method = 0 AND v_rec.trigger_tuple = 'old') OR (method = 1 AND v_rec.trigger_tuple = 'new')) THEN
362 -- For previous update row versions we needn't apply anything;
363 -- we just note the pk value for the quals when applying the
364 -- next row change, i.e when rolling forward the old pk value,
365 -- when rolling back the new pk value
366 EXECUTE format('SELECT ($1::text::%s).%I', v_logtab_fqn, origtab_pk) INTO v_old_pk_str USING v_rec;
368 -- Apply the row changes from the log table, the following is
369 -- a mass of substitutions, but essentially we're selecting
370 -- data out of the log table record and casting it into the
373 IF v_rec.trigger_mode = 'UPDATE' THEN
374 v_sql := format('UPDATE %I SET (%s) = (SELECT %s FROM (SELECT ($1::text::%s).*) t) WHERE %I = %L',
375 restoretab, v_cols, v_cols, v_logtab_fqn, origtab_pk, v_old_pk_str);
376 ELSIF (v_rec.trigger_mode = 'INSERT' AND method = 0) OR (v_rec.trigger_mode = 'DELETE' AND method != 0) THEN
377 v_sql := format('INSERT INTO %I (%s) SELECT %s FROM (SELECT ($1::text::%s).*) t',
378 restoretab, v_cols, v_cols, v_logtab_fqn);
379 ELSIF (v_rec.trigger_mode = 'INSERT' AND method != 0) OR (v_rec.trigger_mode = 'DELETE' AND method = 0) THEN
380 v_sql := format('DELETE FROM %I WHERE %I = ($1::text::%s).%I',
381 restoretab, origtab_pk, v_logtab_fqn, origtab_pk);
383 RAISE EXCEPTION 'unknown trigger_mode: %', trigger_mode;
386 -- RAISE NOTICE 'DML: %', v_sql;
387 EXECUTE v_sql USING v_rec;
392 RETURN quote_ident(restoretab);
395 LANGUAGE plpgsql VOLATILE;