├── examples
├── jupyter
│ ├── .gitignore
│ ├── Makefile
│ ├── logAndTpl.dot
│ ├── blog_tables.dot
│ └── presentation.ipynb
└── blog.md
├── .gitignore
├── recall.control
├── expected
├── _init.out
├── missing_primarykey.out
├── duplicate_disable.out
├── copy_data.out
├── null_logInterval.out
├── duplicate_enable.out
├── now_issue.out
├── schemas.out
├── cleanup.out
└── crud.out
├── sql
├── missing_primarykey.sql
├── _init.sql
├── duplicate_disable.sql
├── duplicate_enable.sql
├── copy_data.sql
├── null_logInterval.sql
├── schemas.sql
├── now_issue.sql
├── cleanup.sql
└── crud.sql
├── Makefile
├── COPYING
├── recall--0.9--0.9.1.sql
├── CHANGELOG.md
├── recall--0.9.1--0.9.2.sql
├── recall--0.9.5--0.9.6.sql
├── recall--0.9.6.sql
├── README.md
└── recall--0.9.2--0.9.5.sql
/examples/jupyter/.gitignore:
--------------------------------------------------------------------------------
1 | .ipynb_checkpoints/
2 | target/
3 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | results/
2 | regression.diffs
3 | regression.out
4 | .*.swp
5 |
--------------------------------------------------------------------------------
/recall.control:
--------------------------------------------------------------------------------
1 | default_version = '0.9.6'
2 | comment = 'Keeps track of changes to managed tables in a separate _log table'
3 | encoding = 'UTF-8'
4 | requires = 'plpgsql,btree_gist'
5 | schema = 'recall'
6 | superuser = false
7 |
8 |
--------------------------------------------------------------------------------
/expected/_init.out:
--------------------------------------------------------------------------------
1 | --
2 | -- creates some helper functions used by the other tests
3 | --
4 | CREATE FUNCTION pretendToWait(intv INTERVAL) RETURNS VOID AS $$
5 | BEGIN
6 | UPDATE recall.config_log SET _log_time = tstzrange(LOWER(_log_time) - intv, UPPER(_log_time) - intv);
7 | END;
8 | $$ LANGUAGE plpgsql;
9 |
--------------------------------------------------------------------------------
/sql/missing_primarykey.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Tries to enable pg_recall on a table without primary key (which should trigger an exception)
3 | --
4 |
5 | BEGIN;
6 |
7 | CREATE TABLE config (
8 | key VARCHAR(100) NOT NULL,
9 | value TEXT NOT NULL
10 | );
11 |
12 | SELECT recall.enable('config', null);
13 |
14 | COMMIT;
15 |
--------------------------------------------------------------------------------
/sql/_init.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- creates some helper functions used by the other tests
3 | --
4 |
5 | CREATE FUNCTION pretendToWait(intv INTERVAL) RETURNS VOID AS $$
6 | BEGIN
7 | UPDATE recall.config_log SET _log_time = tstzrange(LOWER(_log_time) - intv, UPPER(_log_time) - intv);
8 | END;
9 | $$ LANGUAGE plpgsql;
10 |
11 |
12 |
--------------------------------------------------------------------------------
/Makefile:
--------------------------------------------------------------------------------
1 | MODULES =
2 | EXTENSION = recall
3 | DATA = recall--0.9.6.sql recall--0.9--0.9.1.sql recall--0.9.1--0.9.2.sql recall--0.9.2--0.9.5.sql recall--0.9.5--0.9.6.sql
4 | #DOCS = README.md
5 | REGRESS = _init crud cleanup copy_data duplicate_enable duplicate_disable missing_primarykey now_issue null_logInterval schemas
6 | REGRESS_OPTS = --load-extension btree_gist --load-extension recall
7 |
8 | PG_CONFIG = pg_config
9 | PGXS := $(shell $(PG_CONFIG) --pgxs)
10 | include $(PGXS)
11 |
--------------------------------------------------------------------------------
/sql/duplicate_disable.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple table, enables logging but then disables it twice (which should raise an exception)
3 | --
4 |
5 | BEGIN;
6 |
7 | CREATE TABLE config (
8 | key VARCHAR(100) PRIMARY KEY,
9 | value TEXT
10 | );
11 |
12 | SELECT recall.enable('config', '2 months');
13 |
14 | SELECT recall.disable('config');
15 |
16 | -- ok, everything should have worked as planned so far, but this next call should trigger an exception
17 | SELECT recall.disable('config');
18 |
19 | ROLLBACK;
20 |
--------------------------------------------------------------------------------
/expected/missing_primarykey.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Tries to enable pg_recall on a table without primary key (which should trigger an exception)
3 | --
4 | BEGIN;
5 | CREATE TABLE config (
6 | key VARCHAR(100) NOT NULL,
7 | value TEXT NOT NULL
8 | );
9 | SELECT recall.enable('config', null);
10 | ERROR: You need a primary key on your table if you want to use pg_recall (table: config)!
11 | CONTEXT: SQL statement "SELECT recall.enable(tbl, logInterval, 'recall')"
12 | PL/pgSQL function recall.enable(regclass,interval) line 3 at PERFORM
13 | COMMIT;
14 |
--------------------------------------------------------------------------------
/sql/duplicate_enable.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple table and enables logging twice (the second call should update the interval)
3 | --
4 |
5 | BEGIN;
6 |
7 | CREATE TABLE config (
8 | key VARCHAR(100) PRIMARY KEY,
9 | value TEXT NOT NULL
10 | );
11 |
12 | -- enable logging
13 | SELECT recall.enable('config', '2 months');
14 |
15 | -- run a cleanup to make sure last_cleanup is set
16 | SELECT recall.cleanup_all();
17 |
18 | -- check the config table
19 | SELECT tblid, log_interval, now() - last_cleanup FROM recall._config;
20 |
21 |
22 | -- a new call to recall.enable should trigger a notice, update the interval
23 | -- and reset last_cleanup
24 | SELECT recall.enable('config', '3 months');
25 | SELECT tblid, log_interval, now() - last_cleanup FROM recall._config;
26 |
27 | ROLLBACK;
28 |
--------------------------------------------------------------------------------
/sql/copy_data.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a table, inserts some data and only then calls recall.enable()
3 | -- Then checks if all the data has been copied to the _log table correctly
4 | --
5 |
6 | BEGIN;
7 |
8 | -- create simple table
9 | CREATE TABLE config (
10 | key VARCHAR(100) PRIMARY KEY,
11 | value TEXT
12 | );
13 |
14 | -- fill it with some data
15 | INSERT INTO config VALUES ('key', 'value');
16 | INSERT INTO config VALUES ('hello', 'world');
17 | INSERT INTO config VALUES ('answer', 42);
18 | UPDATE config SET value = 'newValue' WHERE key = 'key';
19 |
20 | -- enable logging
21 | SELECT recall.enable('config', '1 day');
22 |
23 | -- check the data
24 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log;
25 |
26 | ROLLBACK;
27 |
--------------------------------------------------------------------------------
/expected/duplicate_disable.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple table, enables logging but then disables it twice (which should raise an exception)
3 | --
4 | BEGIN;
5 | CREATE TABLE config (
6 | key VARCHAR(100) PRIMARY KEY,
7 | value TEXT
8 | );
9 | SELECT recall.enable('config', '2 months');
10 | enable
11 | --------
12 |
13 | (1 row)
14 |
15 | SELECT recall.disable('config');
16 | NOTICE: view "config_past" does not exist, skipping
17 | CONTEXT: SQL statement "DROP VIEW IF EXISTS config_past"
18 | PL/pgSQL function recall.disable(regclass) line 14 at EXECUTE
19 | disable
20 | ---------
21 |
22 | (1 row)
23 |
24 | -- ok, everything should have worked as planned so far, but this next call should trigger an exception
25 | SELECT recall.disable('config');
26 | ERROR: The table "config" is not managed by pg_recall
27 | ROLLBACK;
28 |
--------------------------------------------------------------------------------
/examples/jupyter/Makefile:
--------------------------------------------------------------------------------
1 |
2 | SVG_FILES=$(patsubst %.dot,target/%.svg,$(wildcard *.dot))
3 | PNG_FILES=$(patsubst %.dot,target/%.png,$(wildcard *.dot))
4 |
5 | all: target/ pics slides
6 |
7 | pics: target/ ${SVG_FILES} ${PNG_FILES}
8 |
9 | slidesToPdf: slides
10 | chromium file://$$PWD/target/presentation.slides.html?print-pdf
11 |
12 | slides: target/presentation.slides.html
13 |
14 | target/:
15 | @mkdir -p target/
16 |
17 | target/%.svg: %.dot
18 | dot -Tsvg -o $@ $<
19 |
20 | target/%.png: %.dot
21 | dot -Tpng -o $@ $<
22 |
23 | target/%.slides.html: %.ipynb
24 | # for some reason subslides are hidden, so let's convert them to proper slides
25 | sed s/subslide/slide/g < $< > target/$<
26 | cd target/; jupyter-nbconvert --to slides $< --reveal-prefix https://cdn.jsdelivr.net/reveal.js/2.6.2
27 | # fix image URLs
28 | sed -i 's| src="target/| src="|g;s/.png/.svg/g' $@
29 |
--------------------------------------------------------------------------------
/sql/null_logInterval.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a managed table with a NULL log interval and makes sure it's not affected
3 | -- by cleanup() calls
4 | --
5 |
6 | BEGIN;
7 |
8 | CREATE TABLE config (
9 | key VARCHAR(100) PRIMARY KEY,
10 | value TEXT NOT NULL
11 | );
12 |
13 | SELECT recall.enable('config', NULL);
14 |
15 |
16 | -- run some statements
17 | INSERT INTO config VALUES ('foo', 'bar');
18 | INSERT INTO config VALUES ('true', false);
19 |
20 | -- 'wait' an hour
21 | SELECT pretendToWait('1 hour');
22 |
23 | -- run some more statements
24 | INSERT INTO config VALUES ('answer', 42);
25 | UPDATE config SET value=true WHERE key='true';
26 |
27 |
28 | -- cleanup (should return 0)
29 | SELECT recall.cleanup('config');
30 |
31 | -- and check the log data (there should be 4 rows)
32 | SELECT key, value, UPPER(_log_time) IS NULL AS is_current FROM recall.config_log;
33 |
34 | ROLLBACK;
35 |
--------------------------------------------------------------------------------
/examples/jupyter/logAndTpl.dot:
--------------------------------------------------------------------------------
1 | digraph g {
2 | node [ shape="none" ]
3 |
4 | account_settings_tpl [label=<
5 |
6 | | account_settings_tpl |
7 |
8 | uid INTEGER
9 | key VARCHAR
10 | value TEXT
11 | |
12 |
>]
13 |
14 | account_settings [label=<
15 |
16 | | account_settings |
17 |
|
18 | PRIMARY KEY (uid, key)
19 | |
20 |
>]
21 |
22 | account_settings_log [label=<
23 |
24 | | account_settings_log |
25 |
26 | _log_time TSTZRANGE,
27 | PRIMARY KEY (uid, key, _log_time)
28 | |
29 |
>]
30 |
31 | account_settings -> account_settings_tpl
32 | account_settings_log -> account_settings_tpl
33 | }
34 |
--------------------------------------------------------------------------------
/COPYING:
--------------------------------------------------------------------------------
1 | Copyright (c) 2016, The pg_recall contributors
2 |
3 | Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies.
4 |
5 | IN NO EVENT SHALL THE PG_RECALL CONTRIBUTORS BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF THE PG_RECALL CONTRIBUTORS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
6 |
7 | THE PG_RECALL CONTRIBUTORS SPECIFICALLY DISCLAIM ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND THE PG_RECALL CONTRIBUTORS HAVE NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
8 |
--------------------------------------------------------------------------------
/expected/copy_data.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a table, inserts some data and only then calls recall.enable()
3 | -- Then checks if all the data has been copied to the _log table correctly
4 | --
5 | BEGIN;
6 | -- create simple table
7 | CREATE TABLE config (
8 | key VARCHAR(100) PRIMARY KEY,
9 | value TEXT
10 | );
11 | -- fill it with some data
12 | INSERT INTO config VALUES ('key', 'value');
13 | INSERT INTO config VALUES ('hello', 'world');
14 | INSERT INTO config VALUES ('answer', 42);
15 | UPDATE config SET value = 'newValue' WHERE key = 'key';
16 | -- enable logging
17 | SELECT recall.enable('config', '1 day');
18 | enable
19 | --------
20 |
21 | (1 row)
22 |
23 | -- check the data
24 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log;
25 | key | value | _start | _end
26 | --------+----------+--------+------
27 | hello | world | |
28 | answer | 42 | |
29 | key | newValue | |
30 | (3 rows)
31 |
32 | ROLLBACK;
33 |
--------------------------------------------------------------------------------
/examples/jupyter/blog_tables.dot:
--------------------------------------------------------------------------------
1 | digraph g {
2 | node [ shape="none" ]
3 |
4 | account [label=<
5 |
6 | | account |
7 |
8 | uid SERIAL
9 | created_at TIMESTAMPTZ
10 | name VARCHAR
11 | login VARCHAR
12 | password VARCHAR
13 | email VARCHAR
14 | |
15 |
>]
16 | account_settings [label=<
17 |
18 | | account_settings |
19 |
20 | uid INTEGER
21 | key VARCHAR
22 | value TEXT
23 | |
24 |
>]
25 | blog_entry [label=<
26 |
27 | | blog_entry |
28 |
29 | entry_id SERIAL
30 | creator INTEGER
31 | created_at TIMESTAMPTZ
32 | title VARCHAR
33 | content TEXT
34 | |
35 |
>]
36 |
37 | blog_entry -> account
38 | account_settings -> account
39 | }
40 |
--------------------------------------------------------------------------------
/expected/null_logInterval.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a managed table with a NULL log interval and makes sure it's not affected
3 | -- by cleanup() calls
4 | --
5 | BEGIN;
6 | CREATE TABLE config (
7 | key VARCHAR(100) PRIMARY KEY,
8 | value TEXT NOT NULL
9 | );
10 | SELECT recall.enable('config', NULL);
11 | enable
12 | --------
13 |
14 | (1 row)
15 |
16 | -- run some statements
17 | INSERT INTO config VALUES ('foo', 'bar');
18 | INSERT INTO config VALUES ('true', false);
19 | -- 'wait' an hour
20 | SELECT pretendToWait('1 hour');
21 | pretendtowait
22 | ---------------
23 |
24 | (1 row)
25 |
26 | -- run some more statements
27 | INSERT INTO config VALUES ('answer', 42);
28 | UPDATE config SET value=true WHERE key='true';
29 | -- cleanup (should return 0)
30 | SELECT recall.cleanup('config');
31 | NOTICE: recall: Cleaning up table config
32 | cleanup
33 | ---------
34 | 0
35 | (1 row)
36 |
37 | -- and check the log data (there should be 4 rows)
38 | SELECT key, value, UPPER(_log_time) IS NULL AS is_current FROM recall.config_log;
39 | key | value | is_current
40 | --------+-------+------------
41 | foo | bar | t
42 | answer | 42 | t
43 | true | false | f
44 | true | true | t
45 | (4 rows)
46 |
47 | ROLLBACK;
48 |
--------------------------------------------------------------------------------
/sql/schemas.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a test schema and a couple of tables, then enables recall on them (some of them locally,
3 | -- some of them in the recall schema) and makes sure they're prefixed correctly
4 | --
5 |
6 | CREATE SCHEMA mySchema;
7 |
8 | CREATE TABLE foo (
9 | id SERIAL PRIMARY KEY
10 | );
11 |
12 | CREATE TABLE hello (
13 | world SERIAL PRIMARY KEY
14 | );
15 |
16 | CREATE TABLE mySchema.bar (
17 | otherId SERIAL PRIMARY KEY
18 | );
19 |
20 | CREATE TABLE mySchema.account (
21 | uid SERIAL PRIMARY KEY
22 | );
23 |
24 | -- The first two log tables will be stored to the 'recall' schema implicitly
25 | SELECT recall.enable('foo', '3 months');
26 | SELECT recall.enable('mySchema.bar', '4 months');
27 |
28 | -- The other two will be stored locally
29 | SELECT recall.enable('hello', '5 months', 'public');
30 | SELECT recall.enable('mySchema.account', '6 months', 'myschema');
31 |
32 | -- expected log table name (same goes for the _tpl table):
33 | -- - foo: recall.foo_log
34 | -- - hello: hello_log
35 | -- - bar: recall.mySchema__bar_log
36 | -- - account: mySchema.account_log
37 | \dt
38 |
39 | \dt mySchema.*
40 |
41 | \dt recall.*
42 |
43 |
44 | -- check the contents of the recall._config table:
45 | SELECT tblid, log_interval, last_cleanup, pkey_cols, tpl_table, log_table FROM recall._config;
46 |
--------------------------------------------------------------------------------
/expected/duplicate_enable.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple table and enables logging twice (the second call should update the interval)
3 | --
4 | BEGIN;
5 | CREATE TABLE config (
6 | key VARCHAR(100) PRIMARY KEY,
7 | value TEXT NOT NULL
8 | );
9 | -- enable logging
10 | SELECT recall.enable('config', '2 months');
11 | enable
12 | --------
13 |
14 | (1 row)
15 |
16 | -- run a cleanup to make sure last_cleanup is set
17 | SELECT recall.cleanup_all();
18 | NOTICE: recall: Cleaning up table config
19 | CONTEXT: SQL statement "SELECT recall.cleanup(tbl)"
20 | PL/pgSQL function recall.cleanup_all() line 7 at PERFORM
21 | cleanup_all
22 | -------------
23 |
24 | (1 row)
25 |
26 | -- check the config table
27 | SELECT tblid, log_interval, now() - last_cleanup FROM recall._config;
28 | tblid | log_interval | ?column?
29 | --------+--------------+----------
30 | config | @ 2 mons | @ 0
31 | (1 row)
32 |
33 | -- a new call to recall.enable should trigger a notice, update the interval
34 | -- and reset last_cleanup
35 | SELECT recall.enable('config', '3 months');
36 | NOTICE: recall.enable(config, @ 3 mons) called on an already managed table. Updating log_interval and pkey_cols, clearing last_cleanup
37 | CONTEXT: SQL statement "SELECT recall.enable(tbl, logInterval, 'recall')"
38 | PL/pgSQL function recall.enable(regclass,interval) line 3 at PERFORM
39 | enable
40 | --------
41 |
42 | (1 row)
43 |
44 | SELECT tblid, log_interval, now() - last_cleanup FROM recall._config;
45 | tblid | log_interval | ?column?
46 | --------+--------------+----------
47 | config | @ 3 mons |
48 | (1 row)
49 |
50 | ROLLBACK;
51 |
--------------------------------------------------------------------------------
/recall--0.9--0.9.1.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Trigger function (added the old=new check)
3 | --
4 | CREATE OR REPLACE FUNCTION recall_trigfn() RETURNS TRIGGER AS $$
5 | DECLARE
6 | pkeyCols TEXT[];
7 | pkeys TEXT[];
8 | cols TEXT[]; -- will be filled with escaped column names (in the same order as the vals below)
9 | vals TEXT[]; -- will contain the equivalent of NEW. for each of the columns in the _tpl table
10 | col TEXT; -- loop variable
11 | BEGIN
12 | if TG_OP = 'UPDATE' AND OLD = NEW THEN
13 | RAISE INFO 'pg_recall: row unchanged, no need to write to log';
14 | RETURN NEW;
15 | END IF;
16 | IF TG_OP IN ('UPDATE', 'DELETE') THEN
17 | -- Get the primary key columns from the config table
18 | SELECT pkey_cols INTO pkeyCols FROM _recall_config WHERE tblid = TG_RELID;
19 |
20 | -- build WHERE clauses in the form of 'pkeyCol = OLD.pkeyCol' for each of the primary key columns
21 | -- (they will later be joined with ' AND ' inbetween)
22 | FOREACH col IN ARRAY pkeyCols
23 | LOOP
24 | pkeys = array_append(pkeys, format('%I = $1.%I', col, col));
25 | END LOOP;
26 |
27 | -- mark old log entries as outdated
28 | EXECUTE format('UPDATE %I SET _log_end = now() WHERE %s AND _log_end IS NULL', TG_TABLE_NAME||'_log', array_to_string(pkeys, ' AND ')) USING OLD;
29 | END IF;
30 | IF TG_OP IN ('INSERT', 'UPDATE') THEN
31 | -- get all columns of the _tpl table and put them into the cols and vals arrays
32 | -- (source: http://dba.stackexchange.com/a/22420/85760 )
33 | FOR col IN SELECT attname FROM pg_attribute WHERE attrelid = (TG_TABLE_NAME||'_tpl')::regclass AND attnum > 0 AND attisdropped = false
34 | LOOP
35 | cols = array_append(cols, format('%I', col));
36 | vals = array_append(vals, format('$1.%I', col));
37 | END LOOP;
38 |
39 | -- create the log entry
40 | EXECUTE format('INSERT INTO %I (%s) VALUES (%s)',
41 | TG_TABLE_NAME||'_log',
42 | array_to_string(cols, ', '),
43 | array_to_string(vals, ', ')) USING NEW;
44 | END IF;
45 | RETURN new;
46 | END;
47 | $$ LANGUAGE plpgsql;
48 |
49 |
50 |
--------------------------------------------------------------------------------
/sql/now_issue.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- This tests if the trigger function works properly in the case of multiple changes to the same record
3 | -- within the same transaction (and therefore with the same timestamp)
4 | --
5 | -- It'll create two records, then do a few kinds of upadte on them and print the results
6 | --
7 |
8 | BEGIN;
9 |
10 | -- create table
11 | CREATE TABLE foo (
12 | id INTEGER NOT NULL PRIMARY KEY,
13 | value TEXT NOT NULL,
14 | enabled BOOLEAN NOT NULL
15 | );
16 |
17 | -- enable logging
18 | SELECT recall.enable('foo', null);
19 |
20 | -- create log view
21 | CREATE VIEW view_foo_log AS
22 | SELECT id, value, enabled, now()-LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.foo_log ORDER BY id, LOWER(_log_time);
23 |
24 |
25 | -- create records
26 | INSERT INTO foo VALUES (1, 'hello', true);
27 | INSERT INTO foo VALUES (2, 'world', false);
28 |
29 | -- check log data
30 | SELECT * FROM view_foo_log;
31 |
32 |
33 | -- update the first record (both columns in one go)
34 | UPDATE foo SET value = 'hallo', enabled = false WHERE id = 1;
35 |
36 | -- check log data (there should still be only one log entry for ID 1)
37 | SELECT * FROM view_foo_log WHERE id = 1;
38 |
39 |
40 | -- update the second record (each column separately)
41 | UPDATE foo SET value = 'welt' WHERE id = 2;
42 | UPDATE foo SET enabled = true WHERE id = 2;
43 |
44 | -- check log data (there should still be only one log entry for ID 2)
45 | SELECT * FROM view_foo_log WHERE id = 2;
46 |
47 |
48 | -- do a global UPDATE
49 | UPDATE foo SET enabled = NOT enabled;
50 |
51 | -- check log data (still only two records, both of them still active)
52 | SELECT * FROM view_foo_log;
53 |
54 |
55 | -- do a key update (in my tests this was run in order and caused no duplicate pkey issues. But if PostgreSQL somehow decided
56 | -- to update oldId=2 before oldId=1, the UPDATE would fail. Let me know if that happens to you - I'll rewrite the test then)
57 | UPDATE foo SET id = id-1;
58 |
59 | -- check log data (we expect the same table as above, but the IDs decremented by one)
60 | SELECT * FROM view_foo_log;
61 |
62 |
63 | ROLLBACK;
64 |
--------------------------------------------------------------------------------
/sql/cleanup.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple data table with the very short log interval of only '2 hours' and performs some CRUD operations on it.
3 | -- Every now and then it'll call 'recall.cleanup_all() and check if only data that's too old
4 | --
5 | -- To have somewhat predictable output, we'll run the whole test inside a transaction (which causes now() to always return the same value).
6 | -- To simulate different batches of changes, log entries will be pushed back by an hour between changes.
7 | --
8 |
9 | -- start transaction
10 | BEGIN;
11 |
12 | -- Create simple key/value table
13 | CREATE TABLE config (
14 | key VARCHAR(100) NOT NULL PRIMARY KEY,
15 | value TEXT NOT NULL
16 | );
17 | SELECT recall.enable('config', '2 hours');
18 |
19 | -- create log view
20 | CREATE VIEW view_config_log AS
21 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log ORDER BY LOWER(_log_time), key;
22 |
23 |
24 | -- query the config table for completeness
25 | SELECT tblid, now() - ts AS ts, log_interval, last_cleanup, pkey_cols from recall._config;
26 |
27 | -- first batch (will end up being now() - 3 hours)
28 | INSERT INTO config (key, value) VALUES ('keyA', 'valA');
29 | INSERT INTO config (key, value) VALUES ('keyB', 'valB');
30 |
31 | -- 'wait' an hour
32 | SELECT pretendToWait('1 hour');
33 |
34 | -- clean up (should't affect the log data yet, so recall.cleanup() should return 0)
35 | SELECT recall.cleanup('config');
36 |
37 | SELECT * FROM view_config_log;
38 |
39 |
40 | -- second batch (will be now() - 2 hours in the end)
41 | INSERT INTO config (key, value) VALUES ('keyC', 'valC');
42 | UPDATE config SET value = 'valueB' WHERE key = 'keyB';
43 |
44 | -- 'wait' another hour
45 | SELECT pretendToWait('1 hour');
46 |
47 | -- clean up again and check the data (should still return 0)
48 | SELECT recall.cleanup('config');
49 |
50 | SELECT * FROM view_config_log;
51 |
52 |
53 | -- third batch (will be now() - 1 hour)
54 | INSERT INTO config (key, value) VALUES ('keyD', 'valD');
55 | DELETE FROM config WHERE key = 'keyC';
56 |
57 | -- 'wait' another hour
58 | SELECT pretendToWait('1 hour');
59 |
60 | -- clean up again and check the data (it's supposed to delete the entries where end_ts is > 2 hours, so even though some are at '2 hours' yet, it should still return 0)
61 | SELECT recall.cleanup('config');
62 | SELECT * FROM view_config_log;
63 |
64 | -- 'wait' just one more minute
65 | SELECT pretendToWait('1 minute');
66 |
67 | -- clean up again and check the data (the log entry for the record changed in the first batch should've been deleted, so we expect a return value of 1 here)
68 | SELECT recall.cleanup('config');
69 | SELECT * FROM view_config_log;
70 |
71 |
72 | -- check if the last_cleanup field was updated correctly (expects to return '@ 0')
73 | SELECT now() - last_cleanup FROM recall._config;
74 |
75 | ROLLBACK;
76 |
--------------------------------------------------------------------------------
/expected/now_issue.out:
--------------------------------------------------------------------------------
1 | --
2 | -- This tests if the trigger function works properly in the case of multiple changes to the same record
3 | -- within the same transaction (and therefore with the same timestamp)
4 | --
5 | -- It'll create two records, then do a few kinds of upadte on them and print the results
6 | --
7 | BEGIN;
8 | -- create table
9 | CREATE TABLE foo (
10 | id INTEGER NOT NULL PRIMARY KEY,
11 | value TEXT NOT NULL,
12 | enabled BOOLEAN NOT NULL
13 | );
14 | -- enable logging
15 | SELECT recall.enable('foo', null);
16 | enable
17 | --------
18 |
19 | (1 row)
20 |
21 | -- create log view
22 | CREATE VIEW view_foo_log AS
23 | SELECT id, value, enabled, now()-LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.foo_log ORDER BY id, LOWER(_log_time);
24 | -- create records
25 | INSERT INTO foo VALUES (1, 'hello', true);
26 | INSERT INTO foo VALUES (2, 'world', false);
27 | -- check log data
28 | SELECT * FROM view_foo_log;
29 | id | value | enabled | _start | _end
30 | ----+-------+---------+--------+------
31 | 1 | hello | t | @ 0 |
32 | 2 | world | f | @ 0 |
33 | (2 rows)
34 |
35 | -- update the first record (both columns in one go)
36 | UPDATE foo SET value = 'hallo', enabled = false WHERE id = 1;
37 | -- check log data (there should still be only one log entry for ID 1)
38 | SELECT * FROM view_foo_log WHERE id = 1;
39 | id | value | enabled | _start | _end
40 | ----+-------+---------+--------+------
41 | 1 | hallo | f | @ 0 |
42 | (1 row)
43 |
44 | -- update the second record (each column separately)
45 | UPDATE foo SET value = 'welt' WHERE id = 2;
46 | UPDATE foo SET enabled = true WHERE id = 2;
47 | -- check log data (there should still be only one log entry for ID 2)
48 | SELECT * FROM view_foo_log WHERE id = 2;
49 | id | value | enabled | _start | _end
50 | ----+-------+---------+--------+------
51 | 2 | welt | t | @ 0 |
52 | (1 row)
53 |
54 | -- do a global UPDATE
55 | UPDATE foo SET enabled = NOT enabled;
56 | -- check log data (still only two records, both of them still active)
57 | SELECT * FROM view_foo_log;
58 | id | value | enabled | _start | _end
59 | ----+-------+---------+--------+------
60 | 1 | hallo | t | @ 0 |
61 | 2 | welt | f | @ 0 |
62 | (2 rows)
63 |
64 | -- do a key update (in my tests this was run in order and caused no duplicate pkey issues. But if PostgreSQL somehow decided
65 | -- to update oldId=2 before oldId=1, the UPDATE would fail. Let me know if that happens to you - I'll rewrite the test then)
66 | UPDATE foo SET id = id-1;
67 | -- check log data (we expect the same table as above, but the IDs decremented by one)
68 | SELECT * FROM view_foo_log;
69 | id | value | enabled | _start | _end
70 | ----+-------+---------+--------+------
71 | 0 | hallo | t | @ 0 |
72 | 1 | welt | f | @ 0 |
73 | (2 rows)
74 |
75 | ROLLBACK;
76 |
--------------------------------------------------------------------------------
/CHANGELOG.md:
--------------------------------------------------------------------------------
1 | Changelog
2 | =========
3 |
4 | 0.9.5
5 | -----
6 |
7 | - version jump to indicate this version will break existing code (I really didn't want to do this, but there are a lot
8 | of advantages. And I've decided to put all the proposed breaking changes into a single version jump to simplify upgrades)
9 | - The upgrade script is able to upgrade all the managed tables and functions, but you'll have to modify your code
10 | - now requires PostgreSQL 9.2 or newer (due to the usage of range types)
11 | - Added schema support:
12 | - The extension itself has been moved to the `recall` schema (and the `recall_` prefix has been removed)
13 | - `_log` and `_tpl` tables will now be placed into the `recall` schema (to help keeping table listings cleaner)
14 | - `recall.enable()` added an optional `tgtSchema` parameter (defaults to `recall`) specifying where the `_log` and `_tpl` tables will be stored.
15 | - `recall.enable()` prepends the data table's schema to the `_tpl` and `_log` table's names unless the data table is in `public` (or matches `tgtSchema`).
16 | So `recall.enable('abc.foo', 'some interval', 'abc')` creates `abc.foo_log`, while `recall.enable('abc.foo', 'some interval')` creates `recall.abc__foo_log')
17 | - The `now()` issue has been fixed (The trigger function is now able to update
18 | - candidate for 1.0
19 |
20 | Under the hood:
21 | - replaced the two `timestamptz` columns in log tables with the single column `_log_time` of type `tstzrange`
22 | - The OIDs of the `_log` and `_tpl` tables are now stored to `recall._config`, so you can move the tables (pg_recall will still find them)
23 | - Added a no-overlap constraint to the `_log` tables. The resulting GiST index replaces the primary key (used up until now).
24 | The GiST index allows fast lookups based on key, timestamps or both (also speeds up the `cleanup()` process)
25 | - Added a CHECK constraint preventing empty interval log entries (which could mess up querying)
26 |
27 | When updating:
28 | - The extension still shows up to be installed into the `public` schema (when listing extensions e.g. using `\dx` in psql)
29 | even though everything's in the `recall` schema (there should be no practical differences between a fresh 0.9.5 installation
30 | and an upgraded one)
31 | - all your `_log` and `_tpl` tables will be moved to the `recall` schema (the update script assumes that they've been in the `public` schema
32 | before as there's no real schema support in previous versions)
33 | - replace all the function calls to any of the extension's functions
34 | - If you rely on the log tables to have private keys (e.g. if you want to reference the log table using a foreign key - for whatever reason), add them yourselve
35 |
36 |
37 | 0.9.2
38 | -----
39 |
40 | - fixed PostgreSQL 9.1 compatibility (by removing a call to 9.4's cardinality() function)
41 | - added recall_at()
42 |
43 | 0.9.1
44 | -----
45 |
46 | - only logging changes (i.e. checking if anything has changed and abort if it hasn't)
47 |
48 | 0.9
49 | ---
50 |
51 | - First upgradable version
52 |
--------------------------------------------------------------------------------
/expected/schemas.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a test schema and a couple of tables, then enables recall on them (some of them locally,
3 | -- some of them in the recall schema) and makes sure they're prefixed correctly
4 | --
5 | CREATE SCHEMA mySchema;
6 | CREATE TABLE foo (
7 | id SERIAL PRIMARY KEY
8 | );
9 | CREATE TABLE hello (
10 | world SERIAL PRIMARY KEY
11 | );
12 | CREATE TABLE mySchema.bar (
13 | otherId SERIAL PRIMARY KEY
14 | );
15 | CREATE TABLE mySchema.account (
16 | uid SERIAL PRIMARY KEY
17 | );
18 | -- The first two log tables will be stored to the 'recall' schema implicitly
19 | SELECT recall.enable('foo', '3 months');
20 | enable
21 | --------
22 |
23 | (1 row)
24 |
25 | SELECT recall.enable('mySchema.bar', '4 months');
26 | enable
27 | --------
28 |
29 | (1 row)
30 |
31 | -- The other two will be stored locally
32 | SELECT recall.enable('hello', '5 months', 'public');
33 | enable
34 | --------
35 |
36 | (1 row)
37 |
38 | SELECT recall.enable('mySchema.account', '6 months', 'myschema');
39 | enable
40 | --------
41 |
42 | (1 row)
43 |
44 | -- expected log table name (same goes for the _tpl table):
45 | -- - foo: recall.foo_log
46 | -- - hello: hello_log
47 | -- - bar: recall.mySchema__bar_log
48 | -- - account: mySchema.account_log
49 | \dt
50 | List of relations
51 | Schema | Name | Type | Owner
52 | --------+-----------+-------+--------
53 | public | foo | table | manuel
54 | public | hello | table | manuel
55 | public | hello_log | table | manuel
56 | public | hello_tpl | table | manuel
57 | (4 rows)
58 |
59 | \dt mySchema.*
60 | List of relations
61 | Schema | Name | Type | Owner
62 | ----------+-------------+-------+--------
63 | myschema | account | table | manuel
64 | myschema | account_log | table | manuel
65 | myschema | account_tpl | table | manuel
66 | myschema | bar | table | manuel
67 | (4 rows)
68 |
69 | \dt recall.*
70 | List of relations
71 | Schema | Name | Type | Owner
72 | --------+-------------------+-------+--------
73 | recall | _config | table | manuel
74 | recall | foo_log | table | manuel
75 | recall | foo_tpl | table | manuel
76 | recall | myschema__bar_log | table | manuel
77 | recall | myschema__bar_tpl | table | manuel
78 | (5 rows)
79 |
80 | -- check the contents of the recall._config table:
81 | SELECT tblid, log_interval, last_cleanup, pkey_cols, tpl_table, log_table FROM recall._config;
82 | tblid | log_interval | last_cleanup | pkey_cols | tpl_table | log_table
83 | ------------------+--------------+--------------+-----------+--------------------------+--------------------------
84 | foo | @ 3 mons | | {id} | recall.foo_tpl | recall.foo_log
85 | myschema.bar | @ 4 mons | | {otherid} | recall.myschema__bar_tpl | recall.myschema__bar_log
86 | hello | @ 5 mons | | {world} | hello_tpl | hello_log
87 | myschema.account | @ 6 mons | | {uid} | myschema.account_tpl | myschema.account_log
88 | (4 rows)
89 |
90 |
--------------------------------------------------------------------------------
/sql/crud.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- This test creates a simple table and performs some INSERT/UPDATE/DELETE statements on it.
3 | -- After each of those statements it checks the contents of the config and the config_log tables
4 | --
5 |
6 | -- we'll do all of this in a transaction to have somewhat predictable now() values
7 | -- whenever we UPDATE values, we'll first move _log_time hour to the past in the log table.
8 | BEGIN;
9 |
10 | -- create a simple key/value table
11 | CREATE TABLE config (
12 | key VARCHAR(100) PRIMARY KEY,
13 | value TEXT NOT NULL
14 | );
15 |
16 | -- enable pg_recall and configure it to store data for three months
17 | SELECT recall.enable('config', '3 months');
18 |
19 | -- create a helper view to query the log table
20 | CREATE VIEW view_config_log AS
21 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log ORDER BY LOWER(_log_time), key;
22 |
23 | -- insert a few values
24 | INSERT INTO config (key, value) VALUES ('enable_something', 'true');
25 | INSERT INTO config (key, value) VALUES ('some_number', '42');
26 |
27 | -- check the data; log table:
28 | -- - there has to be exactly one entry for each data table entry
29 | -- - _start is '@ 0' in both cases
30 | -- - _end is null
31 | SELECT key, value FROM config ORDER BY key;
32 | SELECT * FROM view_config_log;
33 |
34 |
35 | -- update value (to work around the now() issue manually set the log values back one hour)
36 | SELECT pretendToWait('1 hour');
37 | UPDATE config SET value = 'false' WHERE key = 'enable_something';
38 |
39 | -- if we didn't check for duplicates, this would fail (due to the same record being logged twice at the same time)
40 | UPDATE config SET value = 'false' WHERE key = 'enable_something';
41 |
42 | -- check data and log tables. The log table...
43 | -- - now has three entries (two for the 'enable_something' key)
44 | -- - start is '@ 0' for the new log entry and '1 hour' for the others
45 | -- - end is '@ 0' for the old 'enable_something' value and NULL for all the others
46 | SELECT key, value FROM config ORDER BY key;
47 | SELECT * FROM view_config_log;
48 |
49 |
50 | -- do a bulk key update (the equivalent to deleting all entries and creating new ones)
51 | SELECT pretendToWait('1 hour');
52 | UPDATE config SET key = key||'_';
53 |
54 | SELECT key, value FROM config ORDER BY key;
55 | SELECT * FROM view_config_log;
56 |
57 |
58 | -- delete an entry (again after pushing log entries back one hour)
59 | SELECT pretendToWait('1 hour');
60 | DELETE FROM config WHERE key = 'some_number_';
61 |
62 | SELECT key, value FROM config ORDER BY key;
63 | SELECT * FROM view_config_log;
64 |
65 | -- query the log table for the current state (for an easy way to compare it to the data table)
66 | SELECT recall.at('config', now());
67 | SELECT key, value FROM config_past ORDER BY key;
68 | SELECT key, value FROM config ORDER BY key;
69 |
70 | -- query the log table for the state of one hour ago:
71 | SELECT recall.at('config', now() - interval '1 hour');
72 | SELECT key, value FROM config_past ORDER BY key;
73 |
74 | -- query the log table for the state of one hour and one minute ago:
75 | SELECT recall.at('config', now() - interval '61 minutes');
76 | SELECT key, value FROM config_past ORDER BY key;
77 |
78 | -- list all the changes to the 'enable_something' record
79 | SELECT * FROM view_config_log WHERE key = 'enable_something';
80 |
81 | ROLLBACK;
82 |
--------------------------------------------------------------------------------
/recall--0.9.1--0.9.2.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- changes:
3 | -- - fixed PostgreSQL 9.1 compatibility (by replacing cardinality() in recall_enable())
4 | -- - added recall_at() (and corresponding cleanup code in recall_disable()
5 |
6 |
7 | --
8 | -- installer function
9 | --
10 | CREATE OR REPLACE FUNCTION recall_enable(tbl REGCLASS, logInterval INTERVAL) RETURNS VOID AS $$
11 | DECLARE
12 | pkeyCols name[];
13 | pkeysEscaped text[]; -- list of escaped primary key column names (can be joined to a string using array_to_string(pkeysEscaped, ','))
14 | cols text[];
15 | k name;
16 | BEGIN
17 | -- fetch primary keys from the table schema (source: https://wiki.postgresql.org/wiki/Retrieve_primary_key_columns )
18 | SELECT ARRAY(
19 | SELECT a.attname INTO pkeyCols FROM pg_index i JOIN pg_attribute a ON (a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey))
20 | WHERE i.indrelid = tbl AND i.indisprimary
21 | );
22 |
23 | -- raise notice 'foo: %, %', pkeyCols, array_length(pkeyCols, 1);
24 | IF COALESCE(array_ndims(pkeyCols), 0) < 1 THEN
25 | RAISE EXCEPTION 'You need a primary key on your table if you want to use pg_recall (table: %)!', tbl;
26 | END IF;
27 |
28 | -- init pkeysEscaped
29 | FOREACH k IN ARRAY pkeyCols
30 | LOOP
31 | pkeysEscaped = array_append(pkeysEscaped, format('%I', k));
32 | END LOOP;
33 |
34 | -- update existing entry (and return if that was one)
35 | UPDATE _recall_config SET log_interval = logInterval, pkey_cols = pkeyCols, last_cleanup = NULL WHERE tblid = tbl;
36 | IF FOUND THEN
37 | RAISE NOTICE 'recall_enable(%, %) called on an already managed table. Updating log_interval and pkey_cols, clearing last_cleanup', tbl, logInterval;
38 | RETURN;
39 | END IF;
40 |
41 | -- add config table entry
42 | INSERT INTO _recall_config (tblid, log_interval, pkey_cols) VALUES (tbl, logInterval, pkeyCols);
43 |
44 | -- create the _tpl table (without constraints)
45 | EXECUTE format('CREATE TABLE %I (LIKE %I)', tbl||'_tpl', tbl);
46 |
47 | -- create the _log table
48 | EXECUTE format('CREATE TABLE %I (
49 | _log_start TIMESTAMPTZ NOT NULL DEFAULT now(),
50 | _log_end TIMESTAMPTZ,
51 | PRIMARY KEY (%s, _log_start)
52 | ) INHERITS (%I)', tbl||'_log', array_to_string(pkeysEscaped, ', '), tbl||'_tpl');
53 |
54 | -- make the _tpl table the default of the data table
55 | EXECUTE format('ALTER TABLE %I INHERIT %I', tbl, tbl||'_tpl');
56 |
57 | -- set the trigger
58 | EXECUTE format('CREATE TRIGGER trig_recall AFTER INSERT OR UPDATE OR DELETE ON %I
59 | FOR EACH ROW EXECUTE PROCEDURE recall_trigfn()', tbl);
60 |
61 |
62 | -- get list of columns and insert current database state into the log table
63 | SELECT ARRAY(
64 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = (tbl||'_tpl')::regclass AND attnum > 0 AND attisdropped = false
65 | );
66 |
67 | EXECUTE format('INSERT INTO %I (%s) SELECT %s FROM %I',
68 | tbl||'_log',
69 | array_to_string(cols, ', '),
70 | array_to_string(cols, ', '),
71 | tbl);
72 | END;
73 | $$ LANGUAGE plpgsql;
74 |
75 |
76 | --
77 | -- uninstaller function
78 | --
79 | CREATE OR REPLACE FUNCTION recall_disable(tbl REGCLASS) RETURNS VOID AS $$
80 | BEGIN
81 | -- remove config table entry (and raise an exception if there was none)
82 | DELETE FROM _recall_config WHERE tblid = tbl;
83 | IF NOT FOUND THEN
84 | RAISE EXCEPTION 'The table "%" is not managed by pg_recall', tbl;
85 | END IF;
86 |
87 | -- drop temp view created by recall_at (if it exists)
88 | EXECUTE format('DROP VIEW IF EXISTS %I', tbl||'_past');
89 |
90 | -- remove inheritance
91 | EXECUTE format('ALTER TABLE %I NO INHERIT %I', tbl, tbl||'_tpl');
92 |
93 | -- drop extra tables
94 | EXECUTE format('DROP TABLE %I', tbl||'_log');
95 | EXECUTE format('DROP TABLE %I', tbl||'_tpl');
96 |
97 | -- delete trigger
98 | EXECUTE format('DROP TRIGGER trig_recall ON %I', tbl);
99 | END;
100 | $$ LANGUAGE plpgsql;
101 |
102 |
103 | --
104 | -- Query past state
105 | --
106 | CREATE OR REPLACE FUNCTION recall_at(tbl REGCLASS, ts TIMESTAMPTZ) RETURNS REGCLASS AS $$
107 | DECLARE
108 | viewName TEXT;
109 | cols TEXT[];
110 | BEGIN
111 | viewName = tbl||'_past';
112 |
113 | -- get (escaped) list of columns
114 | SELECT ARRAY(
115 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = (tbl||'_tpl')::regclass AND attnum > 0 AND attisdropped = false
116 | );
117 |
118 | EXECUTE format('CREATE OR REPLACE TEMPORARY VIEW %I AS SELECT %s FROM %I WHERE _log_start <= %L AND (_log_end IS NULL OR _log_end > %L)',
119 | viewName,
120 | array_to_string(cols, ', '),
121 | tbl||'_log',
122 | ts, ts
123 | );
124 |
125 | return viewName;
126 | END;
127 | $$ LANGUAGE plpgsql;
128 |
129 |
--------------------------------------------------------------------------------
/expected/cleanup.out:
--------------------------------------------------------------------------------
1 | --
2 | -- Creates a simple data table with the very short log interval of only '2 hours' and performs some CRUD operations on it.
3 | -- Every now and then it'll call 'recall.cleanup_all() and check if only data that's too old
4 | --
5 | -- To have somewhat predictable output, we'll run the whole test inside a transaction (which causes now() to always return the same value).
6 | -- To simulate different batches of changes, log entries will be pushed back by an hour between changes.
7 | --
8 | -- start transaction
9 | BEGIN;
10 | -- Create simple key/value table
11 | CREATE TABLE config (
12 | key VARCHAR(100) NOT NULL PRIMARY KEY,
13 | value TEXT NOT NULL
14 | );
15 | SELECT recall.enable('config', '2 hours');
16 | enable
17 | --------
18 |
19 | (1 row)
20 |
21 | -- create log view
22 | CREATE VIEW view_config_log AS
23 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log ORDER BY LOWER(_log_time), key;
24 | -- query the config table for completeness
25 | SELECT tblid, now() - ts AS ts, log_interval, last_cleanup, pkey_cols from recall._config;
26 | tblid | ts | log_interval | last_cleanup | pkey_cols
27 | --------+-----+--------------+--------------+-----------
28 | config | @ 0 | @ 2 hours | | {key}
29 | (1 row)
30 |
31 | -- first batch (will end up being now() - 3 hours)
32 | INSERT INTO config (key, value) VALUES ('keyA', 'valA');
33 | INSERT INTO config (key, value) VALUES ('keyB', 'valB');
34 | -- 'wait' an hour
35 | SELECT pretendToWait('1 hour');
36 | pretendtowait
37 | ---------------
38 |
39 | (1 row)
40 |
41 | -- clean up (should't affect the log data yet, so recall.cleanup() should return 0)
42 | SELECT recall.cleanup('config');
43 | NOTICE: recall: Cleaning up table config
44 | cleanup
45 | ---------
46 | 0
47 | (1 row)
48 |
49 | SELECT * FROM view_config_log;
50 | key | value | _start | _end
51 | ------+-------+----------+------
52 | keyA | valA | @ 1 hour |
53 | keyB | valB | @ 1 hour |
54 | (2 rows)
55 |
56 | -- second batch (will be now() - 2 hours in the end)
57 | INSERT INTO config (key, value) VALUES ('keyC', 'valC');
58 | UPDATE config SET value = 'valueB' WHERE key = 'keyB';
59 | -- 'wait' another hour
60 | SELECT pretendToWait('1 hour');
61 | pretendtowait
62 | ---------------
63 |
64 | (1 row)
65 |
66 | -- clean up again and check the data (should still return 0)
67 | SELECT recall.cleanup('config');
68 | NOTICE: recall: Cleaning up table config
69 | cleanup
70 | ---------
71 | 0
72 | (1 row)
73 |
74 | SELECT * FROM view_config_log;
75 | key | value | _start | _end
76 | ------+--------+-----------+----------
77 | keyA | valA | @ 2 hours |
78 | keyB | valB | @ 2 hours | @ 1 hour
79 | keyB | valueB | @ 1 hour |
80 | keyC | valC | @ 1 hour |
81 | (4 rows)
82 |
83 | -- third batch (will be now() - 1 hour)
84 | INSERT INTO config (key, value) VALUES ('keyD', 'valD');
85 | DELETE FROM config WHERE key = 'keyC';
86 | -- 'wait' another hour
87 | SELECT pretendToWait('1 hour');
88 | pretendtowait
89 | ---------------
90 |
91 | (1 row)
92 |
93 | -- clean up again and check the data (it's supposed to delete the entries where end_ts is > 2 hours, so even though some are at '2 hours' yet, it should still return 0)
94 | SELECT recall.cleanup('config');
95 | NOTICE: recall: Cleaning up table config
96 | cleanup
97 | ---------
98 | 0
99 | (1 row)
100 |
101 | SELECT * FROM view_config_log;
102 | key | value | _start | _end
103 | ------+--------+-----------+-----------
104 | keyA | valA | @ 3 hours |
105 | keyB | valB | @ 3 hours | @ 2 hours
106 | keyB | valueB | @ 2 hours |
107 | keyC | valC | @ 2 hours | @ 1 hour
108 | keyD | valD | @ 1 hour |
109 | (5 rows)
110 |
111 | -- 'wait' just one more minute
112 | SELECT pretendToWait('1 minute');
113 | pretendtowait
114 | ---------------
115 |
116 | (1 row)
117 |
118 | -- clean up again and check the data (the log entry for the record changed in the first batch should've been deleted, so we expect a return value of 1 here)
119 | SELECT recall.cleanup('config');
120 | NOTICE: recall: Cleaning up table config
121 | cleanup
122 | ---------
123 | 1
124 | (1 row)
125 |
126 | SELECT * FROM view_config_log;
127 | key | value | _start | _end
128 | ------+--------+-----------------+----------------
129 | keyA | valA | @ 3 hours 1 min |
130 | keyB | valueB | @ 2 hours 1 min |
131 | keyC | valC | @ 2 hours 1 min | @ 1 hour 1 min
132 | keyD | valD | @ 1 hour 1 min |
133 | (4 rows)
134 |
135 | -- check if the last_cleanup field was updated correctly (expects to return '@ 0')
136 | SELECT now() - last_cleanup FROM recall._config;
137 | ?column?
138 | ----------
139 | @ 0
140 | (1 row)
141 |
142 | ROLLBACK;
143 |
--------------------------------------------------------------------------------
/expected/crud.out:
--------------------------------------------------------------------------------
1 | --
2 | -- This test creates a simple table and performs some INSERT/UPDATE/DELETE statements on it.
3 | -- After each of those statements it checks the contents of the config and the config_log tables
4 | --
5 | -- we'll do all of this in a transaction to have somewhat predictable now() values
6 | -- whenever we UPDATE values, we'll first move _log_time hour to the past in the log table.
7 | BEGIN;
8 | -- create a simple key/value table
9 | CREATE TABLE config (
10 | key VARCHAR(100) PRIMARY KEY,
11 | value TEXT NOT NULL
12 | );
13 | -- enable pg_recall and configure it to store data for three months
14 | SELECT recall.enable('config', '3 months');
15 | enable
16 | --------
17 |
18 | (1 row)
19 |
20 | -- create a helper view to query the log table
21 | CREATE VIEW view_config_log AS
22 | SELECT key, value, now() - LOWER(_log_time) AS _start, now() - UPPER(_log_time) AS _end FROM recall.config_log ORDER BY LOWER(_log_time), key;
23 | -- insert a few values
24 | INSERT INTO config (key, value) VALUES ('enable_something', 'true');
25 | INSERT INTO config (key, value) VALUES ('some_number', '42');
26 | -- check the data; log table:
27 | -- - there has to be exactly one entry for each data table entry
28 | -- - _start is '@ 0' in both cases
29 | -- - _end is null
30 | SELECT key, value FROM config ORDER BY key;
31 | key | value
32 | ------------------+-------
33 | enable_something | true
34 | some_number | 42
35 | (2 rows)
36 |
37 | SELECT * FROM view_config_log;
38 | key | value | _start | _end
39 | ------------------+-------+--------+------
40 | enable_something | true | @ 0 |
41 | some_number | 42 | @ 0 |
42 | (2 rows)
43 |
44 | -- update value (to work around the now() issue manually set the log values back one hour)
45 | SELECT pretendToWait('1 hour');
46 | pretendtowait
47 | ---------------
48 |
49 | (1 row)
50 |
51 | UPDATE config SET value = 'false' WHERE key = 'enable_something';
52 | -- if we didn't check for duplicates, this would fail (due to the same record being logged twice at the same time)
53 | UPDATE config SET value = 'false' WHERE key = 'enable_something';
54 | INFO: pg_recall: row unchanged, no need to write to log
55 | -- check data and log tables. The log table...
56 | -- - now has three entries (two for the 'enable_something' key)
57 | -- - start is '@ 0' for the new log entry and '1 hour' for the others
58 | -- - end is '@ 0' for the old 'enable_something' value and NULL for all the others
59 | SELECT key, value FROM config ORDER BY key;
60 | key | value
61 | ------------------+-------
62 | enable_something | false
63 | some_number | 42
64 | (2 rows)
65 |
66 | SELECT * FROM view_config_log;
67 | key | value | _start | _end
68 | ------------------+-------+----------+------
69 | enable_something | true | @ 1 hour | @ 0
70 | some_number | 42 | @ 1 hour |
71 | enable_something | false | @ 0 |
72 | (3 rows)
73 |
74 | -- do a bulk key update (the equivalent to deleting all entries and creating new ones)
75 | SELECT pretendToWait('1 hour');
76 | pretendtowait
77 | ---------------
78 |
79 | (1 row)
80 |
81 | UPDATE config SET key = key||'_';
82 | SELECT key, value FROM config ORDER BY key;
83 | key | value
84 | -------------------+-------
85 | enable_something_ | false
86 | some_number_ | 42
87 | (2 rows)
88 |
89 | SELECT * FROM view_config_log;
90 | key | value | _start | _end
91 | -------------------+-------+-----------+----------
92 | enable_something | true | @ 2 hours | @ 1 hour
93 | some_number | 42 | @ 2 hours | @ 0
94 | enable_something | false | @ 1 hour | @ 0
95 | enable_something_ | false | @ 0 |
96 | some_number_ | 42 | @ 0 |
97 | (5 rows)
98 |
99 | -- delete an entry (again after pushing log entries back one hour)
100 | SELECT pretendToWait('1 hour');
101 | pretendtowait
102 | ---------------
103 |
104 | (1 row)
105 |
106 | DELETE FROM config WHERE key = 'some_number_';
107 | SELECT key, value FROM config ORDER BY key;
108 | key | value
109 | -------------------+-------
110 | enable_something_ | false
111 | (1 row)
112 |
113 | SELECT * FROM view_config_log;
114 | key | value | _start | _end
115 | -------------------+-------+-----------+-----------
116 | enable_something | true | @ 3 hours | @ 2 hours
117 | some_number | 42 | @ 3 hours | @ 1 hour
118 | enable_something | false | @ 2 hours | @ 1 hour
119 | enable_something_ | false | @ 1 hour |
120 | some_number_ | 42 | @ 1 hour | @ 0
121 | (5 rows)
122 |
123 | -- query the log table for the current state (for an easy way to compare it to the data table)
124 | SELECT recall.at('config', now());
125 | at
126 | -------------
127 | config_past
128 | (1 row)
129 |
130 | SELECT key, value FROM config_past ORDER BY key;
131 | key | value
132 | -------------------+-------
133 | enable_something_ | false
134 | (1 row)
135 |
136 | SELECT key, value FROM config ORDER BY key;
137 | key | value
138 | -------------------+-------
139 | enable_something_ | false
140 | (1 row)
141 |
142 | -- query the log table for the state of one hour ago:
143 | SELECT recall.at('config', now() - interval '1 hour');
144 | at
145 | -------------
146 | config_past
147 | (1 row)
148 |
149 | SELECT key, value FROM config_past ORDER BY key;
150 | key | value
151 | -------------------+-------
152 | enable_something_ | false
153 | some_number_ | 42
154 | (2 rows)
155 |
156 | -- query the log table for the state of one hour and one minute ago:
157 | SELECT recall.at('config', now() - interval '61 minutes');
158 | at
159 | -------------
160 | config_past
161 | (1 row)
162 |
163 | SELECT key, value FROM config_past ORDER BY key;
164 | key | value
165 | ------------------+-------
166 | enable_something | false
167 | some_number | 42
168 | (2 rows)
169 |
170 | -- list all the changes to the 'enable_something' record
171 | SELECT * FROM view_config_log WHERE key = 'enable_something';
172 | key | value | _start | _end
173 | ------------------+-------+-----------+-----------
174 | enable_something | true | @ 3 hours | @ 2 hours
175 | enable_something | false | @ 2 hours | @ 1 hour
176 | (2 rows)
177 |
178 | ROLLBACK;
179 |
--------------------------------------------------------------------------------
/examples/blog.md:
--------------------------------------------------------------------------------
1 | Example: Blog
2 | =============
3 |
4 | This example should demonstrate a few use cases for pg_recall.
5 | It's written in markdoen with inline SQL (all the executed statements are indented by four spaces, so you can actually run it and play around with it yourself:
6 |
7 | ```
8 | grep '^ ' blog.md | psql
9 | ```
10 |
11 | ### But now down to business:
12 | We'll create three tables, two of which will be managed by pg_recall.
13 | Between the INSERTs/UPDATEs I've added `pg_sleep()` calls to artificially slow down the execution and to make the resulting timestamps a little more meaningful.
14 |
15 | CREATE EXTENSION IF NOT EXISTS recall WITH VERSION '0.9.5';
16 |
17 | CREATE TABLE account (
18 | uid SERIAL PRIMARY KEY,
19 | created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
20 |
21 | name VARCHAR(200) NOT NULL,
22 | login VARCHAR(100) NOT NULL,
23 | password VARCHAR(200) NOT NULL,
24 | email VARCHAR(200) NOT NULL
25 | );
26 | CREATE UNIQUE INDEX idx_account_login ON account(lower(login));
27 |
28 | CREATE TABLE account_settings (
29 | uid INTEGER NOT NULL,
30 | key VARCHAR(100) NOT NULL,
31 | value TEXT NOT NULL,
32 |
33 | PRIMARY KEY (uid, key),
34 | FOREIGN KEY (uid) REFERENCES account(uid)
35 | );
36 |
37 | CREATE TABLE blog_entry (
38 | entry_id SERIAL PRIMARY KEY,
39 | creator INTEGER NOT NULL,
40 | created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
41 |
42 | title VARCHAR(200) NOT NULL,
43 | content TEXT NOT NULL,
44 |
45 | FOREIGN KEY (creator) REFERENCES account(uid)
46 | );
47 |
48 | For blog entries, we want users to be able to have a look at the canges (and revert them if needed)
49 |
50 | SELECT recall.enable('blog_entry', '6 months');
51 |
52 | For account settings we use pg_recall to allow support agents to see
53 | which settings were changed when to simplify the support process.
54 |
55 | SELECT recall.enable('account_settings', '1 year');
56 |
57 |
58 | ### Ok, let's pretend to be a new user who registers and creates some content (for simplicity we set the ID values explicitly here):
59 |
60 | INSERT INTO account (uid, name, login, password, email)
61 | VALUES (12, 'John Doe', 'jdoe', 'very secure password', 'jdoe@example.com')
62 | RETURNING uid;
63 |
64 | INSERT INTO account_settings (uid, key, value) VALUES
65 | (12, 'get_newsletter', true),
66 | (12, 'enable_spellcheck', false);
67 |
68 |
69 | INSERT INTO blog_entry (entry_id, creator, title, content) VALUES
70 | (123, 12, 'Welcome to my new bog', 'This is sooooo super exciting!'),
71 | (124, 12, 'House warming party', 'I want to invite you all to my house warming party next tuesday at 123 Some Place')
72 | RETURNING entry_id;
73 |
74 | SELECT pg_sleep(2);
75 |
76 | argh, typo...
77 |
78 | UPDATE blog_entry SET title = 'Welcome to my new blog' WHERE entry_id = 123;
79 | SELECT pg_sleep(2);
80 |
81 | spell check would've helped me there...
82 |
83 | UPDATE account_settings SET value = true WHERE uid = 12 AND key = 'enable_spellcheck';
84 | SELECT pg_sleep(2);
85 |
86 | Maybe not the best idea to invite the whole internet, let's forget about it...
87 |
88 | DELETE FROM blog_entry WHERE entry_id = 124;
89 | SELECT pg_sleep(2);
90 |
91 |
92 | ### By now we've gathered some data. Let's have a look at the tables and their contents:
93 |
94 |
95 | SELECT * FROM account;
96 |
97 | | uid | created_at | name | login | password | email
98 | |-----|-------------------------------|----------|-------|----------------------|------------------
99 | | 12 | 2016-03-14 16:16:18.765388+01 | John Doe | jdoe | very secure password | jdoe@example.com
100 |
101 |
102 | SELECT * FROM account_settings;
103 |
104 | | uid | key | value
105 | |-----|-------------------|-------
106 | | 12 | get_newsletter | true
107 | | 12 | enable_spellcheck | true
108 |
109 |
110 | SELECT * FROM blog_entry;
111 |
112 | | entry_id | creator | created_at | title | content
113 | |----------|---------|-------------------------------|------------------------|--------------------------------
114 | | 123 | 12 | 2016-03-14 16:16:18.771485+01 | Welcome to my new blog | This is sooooo super exciting!
115 |
116 | ### And now for the fun stuff:
117 |
118 | SELECT * FROM recall.account_settings_log;
119 |
120 | | uid | key | value | _log_time
121 | |-----|-------------------|-------|-------------------------------------------------------------------
122 | | 12 | get_newsletter | true | ["2016-03-14 16:16:18.766717+01",)
123 | | 12 | enable_spellcheck | false | ["2016-03-14 16:16:18.766717+01","2016-03-14 16:16:22.780649+01")
124 | | 12 | enable_spellcheck | true | ["2016-03-14 16:16:22.780649+01",)
125 |
126 | You can see that the enable_spellcheck setting has changed roughly four seconds after it was created.
127 |
128 | All the log entries where the range end is unset are still active, all the others have been replaced by newer ones (or deleted, as we can see in the `blog_entry` log)
129 |
130 |
131 | SELECT * FROM recall.blog_entry_log;
132 |
133 | | entry_id | creator | created_at | title | content | _log_time
134 | |----------|---------|-------------------------------|------------------------|-----------------------------------------------------------------------------------|-------------------------------------------------------------------
135 | | 123 | 12 | 2016-03-14 16:16:18.771485+01 | Welcome to my new bog | This is sooooo super exciting! | ["2016-03-14 16:16:18.771485+01","2016-03-14 16:16:20.77742+01")
136 | | 123 | 12 | 2016-03-14 16:16:18.771485+01 | Welcome to my new blog | This is sooooo super exciting! | ["2016-03-14 16:16:20.77742+01",)
137 | | 124 | 12 | 2016-03-14 16:16:18.771485+01 | House warming party | I want to invite you all to my house warming party next tuesday at 123 Some Place | ["2016-03-14 16:16:18.771485+01","2016-03-14 16:16:24.785018+01")
138 |
139 |
140 | So far so good, but let's have a look at the `blog_entry` table as it was four seconds ago (right after we fixed the typo):
141 |
142 | SELECT recall.at('blog_entry', now() - interval '4 seconds');
143 |
144 | | at
145 | |-----------------
146 | | blog_entry_past
147 |
148 | SELECT * FROM blog_entry_past;
149 |
150 | | entry_id | creator | created_at | title | content
151 | |----------|---------|-------------------------------|------------------------|-----------------------------------------------------------------------------------
152 | | 123 | 12 | 2016-03-14 16:16:18.771485+01 | Welcome to my new blog | This is sooooo super exciting!
153 | | 124 | 12 | 2016-03-14 16:16:18.771485+01 | House warming party | I want to invite you all to my house warming party next tuesday at 123 Some Place
154 |
155 | Using `recall.at()` is a two step process (I haven't found a cleaner way to do it).
156 | First you call the function (which returns the name of the temporary view it creates, but that's always going to be `_past` - without schema). All that function does is to create the view (no actual data is accessed).
157 |
158 | Then you can query the temporary view any way you want to (PostgreSQL will even use the GiST index on the log table - or any other indexes you define yourself)
159 |
160 |
161 | ### The `recall._config` table keeps track of the managed tables:
162 |
163 | select * from recall._config;
164 |
165 | | tblid | ts | log_interval | last_cleanup | pkey_cols | tpl_table | log_table
166 | |------------------|-------------------------------|--------------|--------------|------------|-----------------------------|-----------------------------
167 | | blog_entry | 2016-03-14 16:16:18.738986+01 | 6 mons | | {entry_id} | recall.blog_entry_tpl | recall.blog_entry_log
168 | | account_settings | 2016-03-14 16:16:18.757334+01 | 1 year | | {uid,key} | recall.account_settings_tpl | recall.account_settings_log
169 |
170 |
171 | - `tblid` defines the database table in question
172 | - `ts` is the time when `recall.enable()` was called first
173 | - `log_interval` defines how long log entries are kept after they've been replaced by newer ones (`recall.cleanup()` will delete all of them where `UPPER(_log_time) < now() - log_interval`).
174 | In essence this defines how far back in time you can go.
175 | - `last_cleanup` is set by each call to `recall.cleanup()` and helps you keep track of when each table was cleaned up.
176 | - `pkey_cols` caches the table's primary key column names so that they don't have to be queried each time the trigger function runs.
177 | In the unlikely case that you change the primary key on a table, a call to `recall.enable()` will update this (but you're pretty much on yourself if you try that. It hasn't been tested!)
178 | - `tpl_table` and `log_table` are references to the two tables created by pg_recall (when calling `recall.enable()`. These references help the extension to find the tables even if they're renamed or moved to another schema
179 |
180 |
181 | You shouldn't need to edit that table yourself. The contents of `log_interval`, `last_cleanup` and `pkey_cols` are updated automatically every time you call `recall.enable()` on them (which can also be used to update the log interval).
182 |
183 | Cleanup
184 | -------
185 |
186 | To clean up after you've run this example, issue the following commands:
187 |
188 | ```sql
189 | SELECT recall.disable('account_settings'); SELECT recall.disable('blog_entry');
190 | DROP TABLE account_settings, blog_entry, account;
191 | DROP EXTENSION recall;
192 | ```
193 |
--------------------------------------------------------------------------------
/recall--0.9.5--0.9.6.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- installer function
3 | --
4 | CREATE OR REPLACE FUNCTION enable(tbl REGCLASS, logInterval INTERVAL, tgtSchema NAME) RETURNS VOID AS $$
5 | DECLARE
6 | pkeyCols NAME[];
7 | overlapPkeys TEXT[]; -- list of pkey checks (in the form of 'colName WITH =') to be used in the EXCLUDE constraint of the log table
8 | cols TEXT[];
9 | k NAME;
10 |
11 | tblSchema NAME; tblName NAME;
12 | prefix NAME;
13 | tplTable REGCLASS;
14 | logTable REGCLASS;
15 | BEGIN
16 | -- get the schema and local table name for tbl (and construct tplTable and logTable from them)
17 | SELECT schema, name INTO tblSchema, tblName FROM @extschema@._tablemapping WHERE id = tbl;
18 | IF tblSchema = 'public' OR tblSchema = tgtSchema THEN
19 | prefix := tblName;
20 | ELSE
21 | prefix := tblSchema||'__'||tblName;
22 | END IF;
23 |
24 | -- fetch the table's primary key columns (source: https://wiki.postgresql.org/wiki/Retrieve_primary_key_columns )
25 | SELECT ARRAY(
26 | SELECT a.attname INTO pkeyCols FROM pg_index i JOIN pg_attribute a ON (a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey))
27 | WHERE i.indrelid = tbl AND i.indisprimary
28 | );
29 | IF COALESCE(array_ndims(pkeyCols), 0) < 1 THEN
30 | RAISE EXCEPTION 'You need a primary key on your table if you want to use pg_recall (table: %)!', tbl;
31 | END IF;
32 |
33 | -- update existing entry if exists (and return in that case)
34 | UPDATE @extschema@._config SET log_interval = logInterval, pkey_cols = pkeyCols, last_cleanup = NULL WHERE tblid = tbl;
35 | IF FOUND THEN
36 | RAISE NOTICE '@extschema@.enable(%, %) called on an already managed table. Updating log_interval and pkey_cols, clearing last_cleanup', tbl, logInterval;
37 | RETURN;
38 | END IF;
39 |
40 | -- init overlapPkeys
41 | FOREACH k IN ARRAY pkeyCols
42 | LOOP
43 | overlapPkeys = array_append(overlapPkeys, format('%I WITH =', k));
44 | END LOOP;
45 |
46 | -- create the _tpl table (without constraints)
47 | EXECUTE format('CREATE TABLE %I.%I (LIKE %s)', tgtSchema, prefix||'_tpl', tbl);
48 | tplTable := format('%I.%I', tgtSchema, prefix||'_tpl');
49 |
50 | -- create the _log table
51 | EXECUTE format('CREATE TABLE %I.%I (
52 | _log_time TSTZRANGE NOT NULL DEFAULT tstzrange(now(), NULL),
53 | EXCLUDE USING gist (%s, _log_time WITH &&),
54 | CHECK (NOT isempty(_log_time))
55 | ) INHERITS (%s)',
56 | tgtSchema, prefix||'_log',
57 | array_to_string(overlapPkeys, ', '),
58 | tplTable
59 | );
60 | logTable := format('%I.%I', tgtSchema, prefix||'_log');
61 |
62 | -- make the _tpl table the parent of the data table
63 | EXECUTE format('ALTER TABLE %s INHERIT %s', tbl, tplTable);
64 |
65 | -- set the trigger
66 | EXECUTE format('CREATE TRIGGER trig_recall AFTER INSERT OR UPDATE OR DELETE ON %s
67 | FOR EACH ROW EXECUTE PROCEDURE @extschema@._trigfn()', tbl);
68 |
69 | -- add config table entry
70 | INSERT INTO @extschema@._config (tblid, log_interval, pkey_cols, tpl_table, log_table) VALUES (tbl, logInterval, pkeyCols, tplTable, logTable);
71 |
72 | -- get list of columns and insert current database state into the log table
73 | SELECT ARRAY(
74 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
75 | );
76 |
77 | EXECUTE format('INSERT INTO %s (%s, _log_time) SELECT %s, tstzrange(null,null) FROM %s',
78 | logTable,
79 | array_to_string(cols, ', '),
80 | array_to_string(cols, ', '),
81 | tbl);
82 | END;
83 | $$ LANGUAGE plpgsql;
84 |
85 | --
86 | -- uninstaller function
87 | --
88 | CREATE OR REPLACE FUNCTION disable(tbl REGCLASS) RETURNS VOID AS $$
89 | DECLARE
90 | tplTable REGCLASS;
91 | logTable REGCLASS;
92 |
93 | BEGIN
94 | -- remove config table entry (and raise an exception if there was none)
95 | DELETE FROM @extschema@._config WHERE tblid = tbl RETURNING tpl_table, log_table INTO tplTable, logTable;
96 | IF NOT FOUND THEN
97 | RAISE EXCEPTION 'The table "%" is not managed by pg_recall', tbl;
98 | END IF;
99 |
100 | -- drop temp view created by @extschema@.at (if it exists)
101 | EXECUTE format('DROP VIEW IF EXISTS %I', tbl||'_past');
102 |
103 | -- remove inheritance
104 | EXECUTE format('ALTER TABLE %s NO INHERIT %s', tbl, tplTable);
105 |
106 | -- drop extra tables
107 | EXECUTE format('DROP TABLE %s', logTable);
108 | EXECUTE format('DROP TABLE %s', tplTable);
109 |
110 | -- delete trigger
111 | EXECUTE format('DROP TRIGGER trig_recall ON %I', tbl);
112 | END;
113 | $$ LANGUAGE plpgsql;
114 |
115 |
116 | --
117 | -- Trigger function
118 | --
119 | CREATE OR REPLACE FUNCTION _trigfn() RETURNS TRIGGER AS $$
120 | DECLARE
121 | tplTable REGCLASS;
122 | logTable REGCLASS;
123 |
124 | pkeyCols TEXT[];
125 | pkeyChecks TEXT[]; -- array of 'colName = $1.colName' strings
126 | assignments TEXT[]; -- array of 'colname = $2.colName' strings (for the UPDATE statement)
127 | cols TEXT[]; -- will be filled with escaped column names (in the same order as the vals below)
128 | vals TEXT[]; -- will contain the equivalent of NEW. for each of the columns in the _tpl table
129 | col TEXT; -- loop variable
130 | rowCount INTEGER;
131 | startTs TIMESTAMPTZ; -- contains the timestamp that marks the end of the old as well as the start of the new log entry; will be now() if possible or clock_timestamp() if newer log entries already exist (see #19)
132 | BEGIN
133 | startTs := now();
134 |
135 | if TG_OP = 'UPDATE' AND OLD = NEW THEN
136 | RAISE INFO 'pg_recall: row unchanged, no need to write to log';
137 | RETURN NEW;
138 | END IF;
139 |
140 | -- Fetch the table's config
141 | SELECT pkey_cols, tpl_table, log_table INTO pkeyCols, tplTable, logTable FROM @extschema@._config WHERE tblid = TG_RELID;
142 |
143 | IF TG_OP IN ('UPDATE', 'DELETE') THEN
144 | -- build WHERE clauses in the form of 'pkeyCol = OLD.pkeyCol' for each of the primary key columns
145 | -- (they will later be joined with ' AND ' inbetween)
146 | FOREACH col IN ARRAY pkeyCols
147 | LOOP
148 | pkeyChecks = array_append(pkeyChecks, format('%I = $1.%I', col, col));
149 | END LOOP;
150 |
151 | -- mark old log entries as outdated
152 | EXECUTE format('UPDATE %s SET _log_time = tstzrange(LOWER(_log_time), now()) WHERE %s AND upper_inf(_log_time) AND LOWER(_log_time) < now()',
153 | logTable, array_to_string(pkeyChecks, ' AND ')) USING OLD;
154 | GET DIAGNOSTICS rowCount = ROW_COUNT;
155 | IF rowCount = 0 THEN
156 | -- in rare cases LOWER(_log_time) of existing entries is greater than this transaction's now() (see #19)
157 | -- That's why I've added the less-than check above. If no entries have been updated above, run the same statement again but use clock_timestamp() instead of now()
158 | -- special case: LOWER(_log_time) = now(), which indicates multiple updates within the same transaction. In that case we don't want an update here (hence the > in the above and the < in the below statement)
159 | startTs := clock_timestamp();
160 | EXECUTE format('UPDATE %s SET _log_time = tstzrange(LOWER(_log_time), $2) WHERE %s AND upper_inf(_log_time) AND LOWER(_log_time) > now()',
161 | logTable, array_to_string(pkeyChecks, ' AND ')) USING OLD, startTs;
162 | GET DIAGNOSTICS rowCount = ROW_COUNT;
163 | IF rowCount = 0 THEN
164 | -- ok, false alarm. no need to use clock_timestamp() for this log entry. Revert back to now()
165 | startTs := now();
166 | END IF;
167 | END IF;
168 | END IF;
169 | IF TG_OP IN ('INSERT', 'UPDATE') THEN
170 | -- get all columns of the _tpl table and put them into the cols and vals arrays
171 | -- (source: http://dba.stackexchange.com/a/22420/85760 )
172 | FOR col IN SELECT attname FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
173 | LOOP
174 | -- for the INSERT
175 | cols = array_append(cols, format('%I', col));
176 | vals = array_append(vals, format('$1.%I', col));
177 |
178 | -- for the UPDATE
179 | assignments = array_append(assignments, format('%I = $2.%I', col, col));
180 | END LOOP;
181 |
182 | rowCount := 0;
183 | IF TG_OP = 'UPDATE' THEN
184 | -- We might already have created a log entry for the current transaction. In that case, update the existing one (see #16)
185 | EXECUTE format('UPDATE %s SET %s WHERE %s AND LOWER(_log_time) = now()',
186 | logTable,
187 | array_to_string(assignments, ', '),
188 | array_to_string(pkeyChecks, ' AND ')
189 | ) USING OLD, NEW;
190 | GET DIAGNOSTICS rowCount = ROW_COUNT;
191 | END IF;
192 |
193 | IF rowCount = 0 THEN
194 | -- create the log entry (as there was nothing to update)
195 | EXECUTE format('INSERT INTO %s (%s, _log_time) VALUES (%s, tstzrange($2,NULL))',
196 | logTable,
197 | array_to_string(cols, ', '),
198 | array_to_string(vals, ', ')
199 | ) USING NEW, startTs;
200 | END IF;
201 |
202 | END IF;
203 | RETURN new;
204 | END;
205 | $$ LANGUAGE plpgsql;
206 |
207 |
208 | --
209 | -- Cleanup functions (return the number of deleted rows)
210 | --
211 | CREATE OR REPLACE FUNCTION cleanup(tbl REGCLASS) RETURNS INTEGER AS $$
212 | DECLARE
213 | logInterval INTERVAL;
214 | rc INTEGER;
215 |
216 | logTable REGCLASS;
217 | BEGIN
218 | -- get the log table and interval (and update last_cleanup while we're at it)
219 | UPDATE @extschema@._config SET last_cleanup = now() WHERE tblId = tbl RETURNING log_interval, log_table INTO logInterval, logTable;
220 |
221 | RAISE NOTICE 'recall: Cleaning up table %', tbl;
222 | -- Remove old entries
223 | EXECUTE format('DELETE FROM %s WHERE UPPER(_log_time) < now() - $1', logTable) USING logInterval;
224 |
225 | GET DIAGNOSTICS rc = ROW_COUNT;
226 | RETURN rc;
227 | END;
228 | $$ LANGUAGE plpgsql;
229 |
230 | --
231 | -- Query past state
232 | --
233 | CREATE OR REPLACE FUNCTION at(tbl REGCLASS, ts TIMESTAMPTZ) RETURNS REGCLASS AS $$
234 | DECLARE
235 | tblName TEXT;
236 | tplTable REGCLASS;
237 | logTable REGCLASS;
238 |
239 | viewName NAME;
240 | cols TEXT[]; -- escaped list
241 | BEGIN
242 | -- initialize vars
243 | SELECT tpl_table, log_table INTO tplTable, logTable FROM @extschema@._config WHERE tblid = tbl;
244 | SELECT name INTO tblName FROM @extschema@._tablemapping WHERE id = tbl;
245 |
246 | viewName := tblName||'_past';
247 |
248 | -- get (escaped) list of columns
249 | SELECT ARRAY(
250 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
251 | );
252 |
253 | EXECUTE format('CREATE OR REPLACE TEMPORARY VIEW %I AS SELECT %s FROM %s WHERE _log_time @> %L::timestamptz',
254 | viewName,
255 | array_to_string(cols, ', '),
256 | logTable,
257 | ts
258 | );
259 |
260 | return viewName;
261 | END;
262 | $$ LANGUAGE plpgsql;
263 |
264 |
--------------------------------------------------------------------------------
/recall--0.9.6.sql:
--------------------------------------------------------------------------------
1 | -- for each managed table, this will contain an entry specifying when the table was added to pg_recall and the amount of time outdated log entries are kept
2 | CREATE TABLE _config (
3 | tblid REGCLASS NOT NULL PRIMARY KEY,
4 | ts TIMESTAMPTZ NOT NULL DEFAULT NOW(),
5 | log_interval INTERVAL,
6 | last_cleanup TIMESTAMPTZ,
7 | pkey_cols name[] NOT NULL,
8 | tpl_table REGCLASS NOT NULL,
9 | log_table REGCLASS NOT NULL
10 | );
11 |
12 | -- define it as config table (to include its data in pg_dump)
13 | SELECT pg_catalog.pg_extension_config_dump('_config', '');
14 |
15 | --
16 | -- helper functions (and views)
17 | --
18 | CREATE VIEW @extschema@._tablemapping AS
19 | SELECT t.oid AS id, n.nspname AS schema, t.relname AS name
20 | FROM pg_class t INNER JOIN pg_namespace n ON (t.relnamespace = n.oid);
21 |
22 | --
23 | -- installer function
24 | --
25 | CREATE FUNCTION enable(tbl REGCLASS, logInterval INTERVAL, tgtSchema NAME) RETURNS VOID AS $$
26 | DECLARE
27 | pkeyCols NAME[];
28 | overlapPkeys TEXT[]; -- list of pkey checks (in the form of 'colName WITH =') to be used in the EXCLUDE constraint of the log table
29 | cols TEXT[];
30 | k NAME;
31 |
32 | tblSchema NAME; tblName NAME;
33 | prefix NAME;
34 | tplTable REGCLASS;
35 | logTable REGCLASS;
36 | BEGIN
37 | -- get the schema and local table name for tbl (and construct tplTable and logTable from them)
38 | SELECT schema, name INTO tblSchema, tblName FROM @extschema@._tablemapping WHERE id = tbl;
39 | IF tblSchema = 'public' OR tblSchema = tgtSchema THEN
40 | prefix := tblName;
41 | ELSE
42 | prefix := tblSchema||'__'||tblName;
43 | END IF;
44 |
45 | -- fetch the table's primary key columns (source: https://wiki.postgresql.org/wiki/Retrieve_primary_key_columns )
46 | SELECT ARRAY(
47 | SELECT a.attname INTO pkeyCols FROM pg_index i JOIN pg_attribute a ON (a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey))
48 | WHERE i.indrelid = tbl AND i.indisprimary
49 | );
50 | IF COALESCE(array_ndims(pkeyCols), 0) < 1 THEN
51 | RAISE EXCEPTION 'You need a primary key on your table if you want to use pg_recall (table: %)!', tbl;
52 | END IF;
53 |
54 | -- update existing entry if exists (and return in that case)
55 | UPDATE @extschema@._config SET log_interval = logInterval, pkey_cols = pkeyCols, last_cleanup = NULL WHERE tblid = tbl;
56 | IF FOUND THEN
57 | RAISE NOTICE '@extschema@.enable(%, %) called on an already managed table. Updating log_interval and pkey_cols, clearing last_cleanup', tbl, logInterval;
58 | RETURN;
59 | END IF;
60 |
61 | -- init overlapPkeys
62 | FOREACH k IN ARRAY pkeyCols
63 | LOOP
64 | overlapPkeys = array_append(overlapPkeys, format('%I WITH =', k));
65 | END LOOP;
66 |
67 | -- create the _tpl table (without constraints)
68 | EXECUTE format('CREATE TABLE %I.%I (LIKE %s)', tgtSchema, prefix||'_tpl', tbl);
69 | tplTable := format('%I.%I', tgtSchema, prefix||'_tpl');
70 |
71 | -- create the _log table
72 | EXECUTE format('CREATE TABLE %I.%I (
73 | _log_time TSTZRANGE NOT NULL DEFAULT tstzrange(now(), NULL),
74 | EXCLUDE USING gist (%s, _log_time WITH &&),
75 | CHECK (NOT isempty(_log_time))
76 | ) INHERITS (%s)',
77 | tgtSchema, prefix||'_log',
78 | array_to_string(overlapPkeys, ', '),
79 | tplTable
80 | );
81 | logTable := format('%I.%I', tgtSchema, prefix||'_log');
82 |
83 | -- make the _tpl table the parent of the data table
84 | EXECUTE format('ALTER TABLE %s INHERIT %s', tbl, tplTable);
85 |
86 | -- set the trigger
87 | EXECUTE format('CREATE TRIGGER trig_recall AFTER INSERT OR UPDATE OR DELETE ON %s
88 | FOR EACH ROW EXECUTE PROCEDURE @extschema@._trigfn()', tbl);
89 |
90 | -- add config table entry
91 | INSERT INTO @extschema@._config (tblid, log_interval, pkey_cols, tpl_table, log_table) VALUES (tbl, logInterval, pkeyCols, tplTable, logTable);
92 |
93 | -- get list of columns and insert current database state into the log table
94 | SELECT ARRAY(
95 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
96 | );
97 |
98 | EXECUTE format('INSERT INTO %s (%s, _log_time) SELECT %s, tstzrange(null,null) FROM %s',
99 | logTable,
100 | array_to_string(cols, ', '),
101 | array_to_string(cols, ', '),
102 | tbl);
103 | END;
104 | $$ LANGUAGE plpgsql;
105 |
106 | CREATE FUNCTION enable(tbl REGCLASS, logInterval INTERVAL) RETURNS VOID AS $$
107 | BEGIN
108 | PERFORM @extschema@.enable(tbl, logInterval, '@extschema@');
109 | END;
110 | $$ LANGUAGE plpgsql;
111 |
112 | --
113 | -- uninstaller function
114 | --
115 | CREATE FUNCTION disable(tbl REGCLASS) RETURNS VOID AS $$
116 | DECLARE
117 | tplTable REGCLASS;
118 | logTable REGCLASS;
119 |
120 | BEGIN
121 | -- remove config table entry (and raise an exception if there was none)
122 | DELETE FROM @extschema@._config WHERE tblid = tbl RETURNING tpl_table, log_table INTO tplTable, logTable;
123 | IF NOT FOUND THEN
124 | RAISE EXCEPTION 'The table "%" is not managed by pg_recall', tbl;
125 | END IF;
126 |
127 | -- drop temp view created by @extschema@.at (if it exists)
128 | EXECUTE format('DROP VIEW IF EXISTS %I', tbl||'_past');
129 |
130 | -- remove inheritance
131 | EXECUTE format('ALTER TABLE %s NO INHERIT %s', tbl, tplTable);
132 |
133 | -- drop extra tables
134 | EXECUTE format('DROP TABLE %s', logTable);
135 | EXECUTE format('DROP TABLE %s', tplTable);
136 |
137 | -- delete trigger
138 | EXECUTE format('DROP TRIGGER trig_recall ON %I', tbl);
139 | END;
140 | $$ LANGUAGE plpgsql;
141 |
142 |
143 | --
144 | -- Trigger function
145 | --
146 | CREATE FUNCTION _trigfn() RETURNS TRIGGER AS $$
147 | DECLARE
148 | tplTable REGCLASS;
149 | logTable REGCLASS;
150 |
151 | pkeyCols TEXT[];
152 | pkeyChecks TEXT[]; -- array of 'colName = $1.colName' strings
153 | assignments TEXT[]; -- array of 'colname = $2.colName' strings (for the UPDATE statement)
154 | cols TEXT[]; -- will be filled with escaped column names (in the same order as the vals below)
155 | vals TEXT[]; -- will contain the equivalent of NEW. for each of the columns in the _tpl table
156 | col TEXT; -- loop variable
157 | rowCount INTEGER;
158 | startTs TIMESTAMPTZ; -- contains the timestamp that marks the end of the old as well as the start of the new log entry; will be now() if possible or clock_timestamp() if newer log entries already exist (see #19)
159 | BEGIN
160 | startTs := now();
161 |
162 | if TG_OP = 'UPDATE' AND OLD = NEW THEN
163 | RAISE INFO 'pg_recall: row unchanged, no need to write to log';
164 | RETURN NEW;
165 | END IF;
166 |
167 | -- Fetch the table's config
168 | SELECT pkey_cols, tpl_table, log_table INTO pkeyCols, tplTable, logTable FROM @extschema@._config WHERE tblid = TG_RELID;
169 |
170 | IF TG_OP IN ('UPDATE', 'DELETE') THEN
171 | -- build WHERE clauses in the form of 'pkeyCol = OLD.pkeyCol' for each of the primary key columns
172 | -- (they will later be joined with ' AND ' inbetween)
173 | FOREACH col IN ARRAY pkeyCols
174 | LOOP
175 | pkeyChecks = array_append(pkeyChecks, format('%I = $1.%I', col, col));
176 | END LOOP;
177 |
178 | -- mark old log entries as outdated
179 | EXECUTE format('UPDATE %s SET _log_time = tstzrange(LOWER(_log_time), now()) WHERE %s AND upper_inf(_log_time) AND LOWER(_log_time) < now()',
180 | logTable, array_to_string(pkeyChecks, ' AND ')) USING OLD;
181 | GET DIAGNOSTICS rowCount = ROW_COUNT;
182 | IF rowCount = 0 THEN
183 | -- in rare cases LOWER(_log_time) of existing entries is greater than this transaction's now() (see #19)
184 | -- That's why I've added the less-than check above. If no entries have been updated above, run the same statement again but use clock_timestamp() instead of now()
185 | -- special case: LOWER(_log_time) = now(), which indicates multiple updates within the same transaction. In that case we don't want an update here (hence the > in the above and the < in the below statement)
186 | startTs := clock_timestamp();
187 | EXECUTE format('UPDATE %s SET _log_time = tstzrange(LOWER(_log_time), $2) WHERE %s AND upper_inf(_log_time) AND LOWER(_log_time) > now()',
188 | logTable, array_to_string(pkeyChecks, ' AND ')) USING OLD, startTs;
189 | GET DIAGNOSTICS rowCount = ROW_COUNT;
190 | IF rowCount = 0 THEN
191 | -- ok, false alarm. no need to use clock_timestamp() for this log entry. Revert back to now()
192 | startTs := now();
193 | END IF;
194 | END IF;
195 | END IF;
196 | IF TG_OP IN ('INSERT', 'UPDATE') THEN
197 | -- get all columns of the _tpl table and put them into the cols and vals arrays
198 | -- (source: http://dba.stackexchange.com/a/22420/85760 )
199 | FOR col IN SELECT attname FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
200 | LOOP
201 | -- for the INSERT
202 | cols = array_append(cols, format('%I', col));
203 | vals = array_append(vals, format('$1.%I', col));
204 |
205 | -- for the UPDATE
206 | assignments = array_append(assignments, format('%I = $2.%I', col, col));
207 | END LOOP;
208 |
209 | rowCount := 0;
210 | IF TG_OP = 'UPDATE' THEN
211 | -- We might already have created a log entry for the current transaction. In that case, update the existing one (see #16)
212 | EXECUTE format('UPDATE %s SET %s WHERE %s AND LOWER(_log_time) = now()',
213 | logTable,
214 | array_to_string(assignments, ', '),
215 | array_to_string(pkeyChecks, ' AND ')
216 | ) USING OLD, NEW;
217 | GET DIAGNOSTICS rowCount = ROW_COUNT;
218 | END IF;
219 |
220 | IF rowCount = 0 THEN
221 | -- create the log entry (as there was nothing to update)
222 | EXECUTE format('INSERT INTO %s (%s, _log_time) VALUES (%s, tstzrange($2,NULL))',
223 | logTable,
224 | array_to_string(cols, ', '),
225 | array_to_string(vals, ', ')
226 | ) USING NEW, startTs;
227 | END IF;
228 |
229 | END IF;
230 | RETURN new;
231 | END;
232 | $$ LANGUAGE plpgsql;
233 |
234 |
235 | --
236 | -- Cleanup functions (return the number of deleted rows)
237 | --
238 | CREATE FUNCTION cleanup(tbl REGCLASS) RETURNS INTEGER AS $$
239 | DECLARE
240 | logInterval INTERVAL;
241 | rc INTEGER;
242 |
243 | logTable REGCLASS;
244 | BEGIN
245 | -- get the log table and interval (and update last_cleanup while we're at it)
246 | UPDATE @extschema@._config SET last_cleanup = now() WHERE tblId = tbl RETURNING log_interval, log_table INTO logInterval, logTable;
247 |
248 | RAISE NOTICE 'recall: Cleaning up table %', tbl;
249 | -- Remove old entries
250 | EXECUTE format('DELETE FROM %s WHERE UPPER(_log_time) < now() - $1', logTable) USING logInterval;
251 |
252 | GET DIAGNOSTICS rc = ROW_COUNT;
253 | RETURN rc;
254 | END;
255 | $$ LANGUAGE plpgsql;
256 |
257 | -- convenience cleanup function
258 | CREATE FUNCTION cleanup_all() RETURNS VOID AS $$
259 | DECLARE
260 | tbl REGCLASS;
261 | BEGIN
262 | FOR tbl in SELECT tblid FROM @extschema@._config
263 | LOOP
264 | PERFORM @extschema@.cleanup(tbl);
265 | END LOOP;
266 | END;
267 | $$ LANGUAGE plpgsql;
268 |
269 | --
270 | -- Query past state
271 | --
272 | CREATE FUNCTION at(tbl REGCLASS, ts TIMESTAMPTZ) RETURNS REGCLASS AS $$
273 | DECLARE
274 | tblName TEXT;
275 | tplTable REGCLASS;
276 | logTable REGCLASS;
277 |
278 | viewName NAME;
279 | cols TEXT[]; -- escaped list
280 | BEGIN
281 | -- initialize vars
282 | SELECT tpl_table, log_table INTO tplTable, logTable FROM @extschema@._config WHERE tblid = tbl;
283 | SELECT name INTO tblName FROM @extschema@._tablemapping WHERE id = tbl;
284 |
285 | viewName := tblName||'_past';
286 |
287 | -- get (escaped) list of columns
288 | SELECT ARRAY(
289 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
290 | );
291 |
292 | EXECUTE format('CREATE OR REPLACE TEMPORARY VIEW %I AS SELECT %s FROM %s WHERE _log_time @> %L::timestamptz',
293 | viewName,
294 | array_to_string(cols, ', '),
295 | logTable,
296 | ts
297 | );
298 |
299 | return viewName;
300 | END;
301 | $$ LANGUAGE plpgsql;
302 |
303 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | pg_recall
2 | =========
3 |
4 | `pg_recall` is a PostgreSQL extension that keeps track of changes in a separate `_log` table (one `_log` table for each managed data table).
5 |
6 | For CRUD queries (`SELECT`, `INSERT`, `UPDATE` and `DELETE`) this works transparently. DDL changes have to be adapted though.
7 |
8 | To see it in action, have a look at the [`examples/`][5] directory.
9 |
10 |
11 | What it was designed for
12 | --------
13 |
14 | The main goal of `pg_recall` is to provide a quick and transparent way to keep track of changes to user-edited data (to eliminate the risk of accidential deletion or modification and to provide a safe way for them to try out different settings while being able to revert to the old state if necessary).
15 |
16 | It allows to query the individual table rows or the entire table for arbitrary timestamps (within the `logInterval` you specify for each table).
17 |
18 | You could think of it as kind of a safety net for you and your customers (but NOT as a replacement for backups)
19 |
20 | I'd love to see ports for other databases.
21 |
22 | Installation and Usage
23 | ----------------------
24 |
25 | ### Requirements
26 |
27 | - PostgreSQL (9.2 or newer, as it uses range data types)
28 | - the `btree_gist` extension (that one requires superuser database access!)
29 |
30 | The code is pretty standard pl/pgsql code so it should be platform independent.
31 |
32 | ### Installation
33 |
34 | The extension can be installed by issuing `make install` (you'll have to run that as root in most cases).
35 |
36 | After that the extension has to be enabled for each database you want to use it on:
37 |
38 | ```sql
39 | CREATE EXTENSION IF NOT EXISTS recall WITH VERSION '0.9.5';
40 | ```
41 |
42 | I recommend specifying the version (if you don't, the most recent version will be installed), especially before we hit 1.0 or if you're using database migration software,
43 |
44 | ### Activation
45 |
46 | As there are some resource impacts to using `pg_recall`, you have to enable it for each table you want to use it on:
47 |
48 | SELECT recall.enable('tableName', 'log_interval', 'targetSchema');
49 | SELECT recall.enable('tableName', 'log_interval'); -- targetSchema defaults to 'recall'
50 |
51 | so for example
52 |
53 | SELECT recall.enable('accounts', '6 months');
54 |
55 | After that a trigger has been added to your `accounts` table and all changes will be logged to the automatically created `recall.accounts_log` table.
56 |
57 | You can work with your data as you did before, no changes to the CRUD queries are necessary.
58 |
59 | And if you want to change the log interval later on, simply invoke `recall.enable()` again (with the new interval of course). This will also update the cached primary key columns for that table and will reset the `last_cleanup` field to NULL.
60 |
61 | #### What happens behind the scenes?
62 |
63 | `recall.enable()` creates a `*_tpl` and a `*_log` table for each of the tables you call it for (`*` being the name of the original data table).
64 | Those two tables will be stored in `targetSchema` (defaults to `recall`)
65 |
66 | The `_tpl` table serves as parent table for both the `_log` table and the original data table (See [PostgreSQL's Inheritance Documentation][1] for details).
67 | It's created without constraints and won't contain any data (it only serves as the one table you have to apply schema changes to).
68 |
69 | The `_log` table looks like this:
70 |
71 | ```SQL
72 | CREATE TABLE _log (
73 | _log_time TSTZRANGE NOT NULL DEFAULT tstzrange(now(), null),
74 | EXCLUDE USING gist (id WITH =, _log_time WITH &&) -- automatically includes all your pkey columns and prevents overlaps in your log data
75 | CHECK (NOT isempty(_log_time))
76 | ) INHERITS _tpl;
77 | ```
78 |
79 | Other than the GiST index that checks for overlaps no index constraints are defined for the `_log` table (no foreign keys and no unique or check constraints).
80 |
81 | The GiST index will be used for all pkey- and/or timestamp related queries, so they'll be reasonably fast, but if you plan on querying based on non-primary key columns, you'll have to add your own indexes.
82 |
83 | Not having any foreign keys also means it won't stop you from deleting previously referenced data (let's say you have an `account` and a `contract` table (and each contract references the account that created it). If you enable `pg_recall` on contract but not on account (or the log interval in account is shorter than that in contract), it's possible you have references to account IDs in contract_log that point to data that's been deleted from account and are therefore not restorable).
84 |
85 | ### Querying historic data
86 |
87 | As mentioned before, you don't have to change any queries for current data, but if you want to have a look at past records (within the `logInterval` of course), you have to query the corresponding `_log` table.
88 |
89 | There currently is one convenience function, `recall.at()`. It creates a temporary view resembling the data table at any given time in the past.
90 |
91 | But if you want to do something not covered by that function, you'll have to query the `_log` table yourself (`:ts` being the timestamp you want to query for):
92 |
93 | ... AND _log_time @> :ts
94 |
95 | See PostgreSQL's [range operators][12] for details on how to query based on time.
96 |
97 | In the following examples, `my_table` is the name of the original data table.
98 |
99 | #### Querying past data
100 |
101 | pg_recall provides a convenience function for querying log data from a certain moment in time: `recall.at(tblName, timestamp)`.
102 |
103 | It'll create a temporary view with the suffix `_past` added to your data table's name that you can query exactly like the original data table.
104 |
105 | SELECT recall.at('my_table', now() - interval '2 months');
106 | SELECT * FROM my_table_past WHERE ...;
107 |
108 | As mentioned before, the `_past` view is temporary, so it'll only be visible from the current database session (which allows you to use `recall.at()` simultaneously on the same table from different sessions).
109 |
110 | Also, as it just creates a view, using `recall.at()` should perform roughly the same as if you were querying the `_log` table yourself.
111 |
112 | `recall.at()` returns the name of the temporary view.
113 |
114 | ##### Querying for a key in the past
115 |
116 | SELECT recall.at('my_table', now() - interval '1 minute');
117 | SELECT * FROM my_table_past WHERE id = 5;
118 |
119 | or alternatively (also includes the `_log_time` column)
120 |
121 | SELECT * FROM my_table_log WHERE id = 5 AND _log_time @> now() - interval '1 minute';
122 |
123 |
124 | #### Listing all the changes to one key (ordered by the time they occured)
125 |
126 | SELECT * FROM my_table_log WHERE some_key = 'some value' ORDER BY LOWER(_log_time) DESC;
127 |
128 | ### Cleanup
129 |
130 | Every now and then you should run `recall.cleanup('tableName')` or the more convenient
131 |
132 | SELECT recall.cleanup_all();
133 |
134 | It will cycle through all managed log tables and remove all outdated log entries (with `UPPER(_log_time) < now() - logInterval` - logInterval is the interval you specified as second parameter of `recall.enable()`).
135 |
136 | It is up to you how you want to run this cleanup job. If you don't run it, the log tables will simply keep growing. Depending on your application a simple background task might do the trick. Alternatively you could write a cron job.
137 |
138 | ### Deactivation
139 |
140 | To disable logging for a table, simply call
141 |
142 | SELECT recall.disable('tableName');
143 |
144 | Note: This will restore the original state of that table and drop the `*_log` table, so **all the log data for that table will be lost!**
145 |
146 |
147 | Caveats
148 | -------
149 |
150 | - It adds two extra tables for each data table you enable it on. Subsequent DDL changes (i.e. `ALTER TABLE`s that add/modify or delete columns) have to be done on the `_tpl` table.
151 | - The log table doesn't inherit the constraints (and foreign keys). So make sure you also enable recall on all referenced tables (with at least the same log interval) to avoid ending up with log entries pointing to nothing.
152 | - The cleanup function has to be run manually (e.g. using a background task in your app or a cronjob)
153 | - It creates copies of the whole record every time it changes, so you might not want to use it on tables that have a high churn rate or contain large BLOB data.
154 | However:
155 | - The trigger function detects unchanged records (`UPDATE ... SET value = value`), so feel free to bulk-update larger quantities of records without filtering out unchanged ones beforehand.
156 | - The main issue when using pg_recall on those tables is storage. If you're ok with the storage implications, there's no reason not to use pg_recall on those tables.
157 | - It doesn't protect the log table, so it won't protect you from accidentally (or an adversary from intentionally) tampering with the log tables.
158 | - You might wanna think twice before changing the primary key of a table (changing their value should work, but adding/removing columns from/to the primary key is untested and will most likely break things).
159 | - **`pg_recall` does NOT replace database backups, but that should go without saying.**
160 | It can however be a reasonable simple tool to allow you or your users to view and manage changes to pretty much arbitrary data.
161 |
162 |
163 | Wanna help?
164 | -----------
165 |
166 | Have a look at the [github issues page][2] and feel free to issue pull requests.
167 |
168 | Note that I'm running the regression tests (`make installcheck`) on a 9.5 server (other versions may trigger different notices (9.1 for example prints implicit primary key creation notices))
169 |
170 | If you plan on porting recall to another database/framework, let me know.
171 |
172 | ### Project structure
173 |
174 | `pg_recall` tries to follow the generic structure of PostgreSQL Extensions.
175 | Read the [Extension manual][3] and the [Extension Build Infrastructure][4] for further details.
176 |
177 | - `expected/*`: contains the expected output of the regression tests
178 | - `sql/*`: contains the regression tests
179 | - `examples/`: example projects
180 | - `recall--0.9.5.sql`: the actual implementation
181 | - `recall--0.9*--0.9*.sql`: update script(s)
182 | - `recall.control`: extension control file
183 | - `Makefile`: PGXS make file (noteworthy targets: `make install` and `make installcheck` to run the regression tests)
184 | - `README.md`: this file
185 | - `COPYING`: license file
186 |
187 | License
188 | -------
189 |
190 | This project is licensed under the terms of the PostgreSQL license (which is similar to the MIT license; see the COPYING file for details).
191 |
192 | Related
193 | -------
194 |
195 | This is a list of other projects I found doing similar things.
196 | Keep in mind though that for most of these I only had a quick look at how they're implemented/used, so don't count on any of the following facts to be objective or true :)
197 |
198 | ### PostgreSQL
199 |
200 | - [TimeTravel for PostgreSQL][6] (GNU GPLv3): Similar project, everything's in the `tt` database schema, seems to store the log data a little differently though (can't really say much more about them because I've just skimmed through their documentation PDF)
201 | - [A PL/pgSQL Trigger Procedure For Auditing][7] in the PostgreSQL docs
202 |
203 | ### Others
204 |
205 | - Temporal queries in SQL:2011
206 | - [Oracle FlashBack][8]
207 | - [CouchDB's Revisions][9] Revision support is a first class citicen of CouchDB land. Revisions are identified by sequential IDs, old data can be cleaned up by "compaction"
208 | - [EclipseLink JPA History][10]: Higher level implementation in EclipseLink (but using a lot of the same ideas).
209 |
210 | - ...
211 |
212 | Contact
213 | -------
214 |
215 | Create GitHub issues/merge requests where appropriate.
216 |
217 | For everything else contact me on [Twitter][11] or per mail (first name @ last name .net)
218 |
219 |
220 | [1]: http://www.postgresql.org/docs/current/static/ddl-inherit.html
221 | [2]: https://github.com/mreithub/pg_recall/issues
222 | [3]: http://www.postgresql.org/docs/9.4/static/extend-extensions.html
223 | [4]: http://www.postgresql.org/docs/9.1/static/extend-pgxs.html
224 | [5]: examples/
225 | [6]: http://www.databtech.com/eng/index_timetravel.htm
226 | [7]: http://www.postgresql.org/docs/current/static/plpgsql-trigger.html#PLPGSQL-TRIGGER-AUDIT-EXAMPLE
227 | [8]: https://docs.oracle.com/cd/B28359_01/appdev.111/b28424/adfns_flashback.htm
228 | [9]: http://docs.couchdb.org/en/1.6.1/intro/api.html#revisions
229 | [10]: https://wiki.eclipse.org/EclipseLink/Examples/JPA/History
230 | [11]: https://twitter.com/mreithub
231 | [12]: http://www.postgresql.org/docs/9.2/static/functions-range.html#RANGE-OPERATORS-TABLE
232 |
--------------------------------------------------------------------------------
/recall--0.9.2--0.9.5.sql:
--------------------------------------------------------------------------------
1 |
2 | -- create schema
3 | CREATE SCHEMA IF NOT EXISTS recall;
4 |
5 | --
6 | -- update the config table
7 | --
8 | ALTER TABLE _recall_config ADD tpl_table REGCLASS;
9 | ALTER TABLE _recall_config ADD log_table REGCLASS;
10 |
11 | -- fetch the table OIDs
12 | UPDATE _recall_config SET tpl_table = oid FROM pg_class l WHERE relname = tblid||'_tpl';
13 | UPDATE _recall_config SET log_table = oid FROM pg_class l WHERE relname = tblid||'_log';
14 |
15 | -- set new columns non-null
16 | ALTER TABLE _recall_config ALTER tpl_table SET NOT NULL;
17 | ALTER TABLE _recall_config ALTER log_table SET NOT NULL;
18 |
19 | -- move it to the recall schema
20 | ALTER TABLE _recall_config SET SCHEMA recall;
21 | ALTER TABLE recall._recall_config RENAME TO _config;
22 |
23 | -- TODO move log and tpl tables
24 | CREATE FUNCTION recall.__migrate_tables() RETURNS VOID AS $$
25 | DECLARE
26 | tbl REGCLASS;
27 | overlapPkeys TEXT[];
28 | k NAME;
29 | BEGIN
30 | FOR tbl IN SELECT tblid FROM recall._config
31 | LOOP
32 | EXECUTE format('ALTER TABLE %I SET SCHEMA recall', tbl||'_log');
33 | EXECUTE format('ALTER TABLE %I SET SCHEMA recall', tbl||'_tpl');
34 |
35 | -- init overlapPkeys
36 | overlapPkeys = ARRAY[]::TEXT[];
37 | FOR k IN SELECT unnest(pkey_cols) FROM recall._config WHERE tblid = tbl
38 | LOOP
39 | overlapPkeys = array_append(overlapPkeys, format('%I WITH =', k));
40 | END LOOP;
41 |
42 | -- drop primary key
43 | EXECUTE format('ALTER TABLE recall.%I DROP CONSTRAINT %I', tbl||'_log', tbl||'_log_pkey');
44 |
45 | -- replace timestamp columns
46 | EXECUTE format('ALTER TABLE recall.%I ADD _log_time TSTZRANGE DEFAULT tstzrange(now(), NULL)', tbl||'_log');
47 | EXECUTE format('UPDATE recall.%I SET _log_time = tstzrange(_log_start, _log_end)', tbl||'_log');
48 | EXECUTE format('ALTER TABLE recall.%I DROP COLUMN _log_start', tbl||'_log');
49 | EXECUTE format('ALTER TABLE recall.%I DROP COLUMN _log_end', tbl||'_log');
50 | EXECUTE format('ALTER TABLE recall.%I ALTER _log_time SET NOT NULL', tbl||'_log');
51 |
52 | -- add EXCLUDE and CHECK constraints to the log tables
53 | EXECUTE format('ALTER TABLE recall.%I ADD CONSTRAINT %I EXCLUDE USING gist (%s, _log_time WITH &&)',
54 | tbl||'_log',
55 | tbl||'_log_no_overlays',
56 | array_to_string(overlapPkeys, ', '));
57 | EXECUTE format('ALTER TABLE recall.%I ADD CONSTRAINT %I CHECK (NOT isempty(_log_time))',
58 | tbl||'_log',
59 | tbl||'_log_not_empty');
60 |
61 | END LOOP;
62 | END;
63 | $$ LANGUAGE plpgsql;
64 | SELECT recall.__migrate_tables();
65 | DROP FUNCTION recall.__migrate_tables();
66 |
67 | --
68 | -- move and rename the functions (we're moving them to make sure
69 | --
70 |
71 | -- move the functions to the 'recall' schema
72 | ALTER FUNCTION recall_enable(REGCLASS, INTERVAL) SET SCHEMA recall;
73 | ALTER FUNCTION recall_disable(REGCLASS) SET SCHEMA recall;
74 | ALTER FUNCTION recall_trigfn() SET SCHEMA recall;
75 | ALTER FUNCTION recall_cleanup(REGCLASS) SET SCHEMA recall;
76 | ALTER FUNCTION recall_cleanup_all() SET SCHEMA recall;
77 | ALTER FUNCTION recall_at(REGCLASS,TIMESTAMPTZ) SET SCHEMA recall;
78 |
79 | -- remove the table prefixes
80 | ALTER FUNCTION recall.recall_enable(tbl REGCLASS, logInterval INTERVAL) RENAME TO enable;
81 | ALTER FUNCTION recall.recall_disable(REGCLASS) RENAME TO disable;
82 | ALTER FUNCTION recall.recall_trigfn() RENAME TO _trigfn;
83 | ALTER FUNCTION recall.recall_cleanup(REGCLASS) RENAME TO cleanup;
84 | ALTER FUNCTION recall.recall_cleanup_all() RENAME TO cleanup_all;
85 | ALTER FUNCTION recall.recall_at(REGCLASS,TIMESTAMPTZ) RENAME TO at;
86 |
87 | --
88 | -- helper view (translates table OIDs to their name + schema (and back))
89 | --
90 | CREATE VIEW recall._tablemapping AS
91 | SELECT t.oid AS id, n.nspname AS schema, t.relname AS name
92 | FROM pg_class t INNER JOIN pg_namespace n ON (t.relnamespace = n.oid);
93 |
94 |
95 | --
96 | -- installer function
97 | --
98 | CREATE FUNCTION recall.enable(tbl REGCLASS, logInterval INTERVAL, tgtSchema NAME) RETURNS VOID AS $$
99 | DECLARE
100 | pkeyCols NAME[];
101 | overlapPkeys TEXT[]; -- list of pkey checks (in the form of 'colName WITH =') to be used in the EXCLUDE constraint of the log table
102 | cols TEXT[];
103 | k NAME;
104 |
105 | tblSchema NAME; tblName NAME;
106 | prefix NAME;
107 | tplTable REGCLASS;
108 | logTable REGCLASS;
109 | BEGIN
110 | -- get the schema and local table name for tbl (and construct tplTable and logTable from them)
111 | SELECT schema, name INTO tblSchema, tblName FROM recall._tablemapping WHERE id = tbl;
112 | IF tblSchema = 'public' OR tblSchema = tgtSchema THEN
113 | prefix := tblName;
114 | ELSE
115 | prefix := tblSchema||'__'||tblName;
116 | END IF;
117 |
118 | -- fetch the table's primary key columns (source: https://wiki.postgresql.org/wiki/Retrieve_primary_key_columns )
119 | SELECT ARRAY(
120 | SELECT a.attname INTO pkeyCols FROM pg_index i JOIN pg_attribute a ON (a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey))
121 | WHERE i.indrelid = tbl AND i.indisprimary
122 | );
123 | IF COALESCE(array_ndims(pkeyCols), 0) < 1 THEN
124 | RAISE EXCEPTION 'You need a primary key on your table if you want to use pg_recall (table: %)!', tbl;
125 | END IF;
126 |
127 | -- update existing entry if exists (and return in that case)
128 | UPDATE recall._config SET log_interval = logInterval, pkey_cols = pkeyCols, last_cleanup = NULL WHERE tblid = tbl;
129 | IF FOUND THEN
130 | RAISE NOTICE 'recall.enable(%, %) called on an already managed table. Updating log_interval and pkey_cols, clearing last_cleanup', tbl, logInterval;
131 | RETURN;
132 | END IF;
133 |
134 | -- init overlapPkeys
135 | FOREACH k IN ARRAY pkeyCols
136 | LOOP
137 | overlapPkeys = array_append(overlapPkeys, format('%I WITH =', k));
138 | END LOOP;
139 |
140 | -- create the _tpl table (without constraints)
141 | EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I)', tgtSchema, prefix||'_tpl', tblSchema, tblName);
142 |
143 | -- create the _log table
144 | EXECUTE format('CREATE TABLE %I.%I (
145 | _log_time TSTZRANGE NOT NULL DEFAULT tstzrange(now(), NULL),
146 | EXCLUDE USING gist (%s, _log_time WITH &&),
147 | CHECK (NOT isempty(_log_time))
148 | ) INHERITS (%I.%I)',
149 | tgtSchema, prefix||'_log',
150 | array_to_string(overlapPkeys, ', '),
151 | tgtSchema, prefix||'_tpl'
152 | );
153 |
154 | -- make the _tpl table the parent of the data table
155 | EXECUTE format('ALTER TABLE %I.%I INHERIT %I.%I', tblSchema, tblName, tgtSchema, prefix||'_tpl');
156 |
157 | -- set the trigger
158 | EXECUTE format('CREATE TRIGGER trig_recall AFTER INSERT OR UPDATE OR DELETE ON %I.%I
159 | FOR EACH ROW EXECUTE PROCEDURE recall._trigfn()', tblSchema, tblName);
160 |
161 | -- add config table entry
162 | tplTable = format('%I.%I', tgtSchema, prefix||'_tpl');
163 | logTable = format('%I.%I', tgtSchema, prefix||'_log');
164 | INSERT INTO recall._config (tblid, log_interval, pkey_cols, tpl_table, log_table) VALUES (tbl, logInterval, pkeyCols, tplTable, logTable);
165 |
166 | -- get list of columns and insert current database state into the log table
167 | SELECT ARRAY(
168 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
169 | );
170 |
171 | EXECUTE format('INSERT INTO %I.%I (%s) SELECT %s FROM %I.%I',
172 | tgtSchema, prefix||'_log',
173 | array_to_string(cols, ', '),
174 | array_to_string(cols, ', '),
175 | tblSchema, tblName);
176 | END;
177 | $$ LANGUAGE plpgsql;
178 |
179 |
180 |
181 | CREATE OR REPLACE FUNCTION recall.enable(tbl REGCLASS, logInterval INTERVAL) RETURNS VOID AS $$
182 | BEGIN
183 | PERFORM recall.enable(tbl, logInterval, 'recall');
184 | END;
185 | $$ LANGUAGE plpgsql;
186 |
187 | --
188 | -- uninstaller function
189 | --
190 | CREATE OR REPLACE FUNCTION recall.disable(tbl REGCLASS) RETURNS VOID AS $$
191 | DECLARE
192 | tplTable REGCLASS;
193 | logTable REGCLASS;
194 |
195 | tblSchema NAME; tblName NAME;
196 | tplSchema NAME; tplName NAME;
197 | logSchema NAME; logName NAME;
198 | BEGIN
199 | -- remove config table entry (and raise an exception if there was none)
200 | DELETE FROM recall._config WHERE tblid = tbl RETURNING tpl_table, log_table INTO tplTable, logTable;
201 | IF NOT FOUND THEN
202 | RAISE EXCEPTION 'The table "%" is not managed by pg_recall', tbl;
203 | END IF;
204 |
205 | -- get schema and table names
206 | SELECT schema, name INTO tblSchema, tblName FROM recall._tablemapping WHERE id = tbl;
207 | SELECT schema, name INTO tplSchema, tplName FROM recall._tablemapping WHERE id = tplTable;
208 | SELECT schema, name INTO logSchema, logName FROM recall._tablemapping WHERE id = logTable;
209 |
210 | -- drop temp view created by recall.at (if it exists)
211 | EXECUTE format('DROP VIEW IF EXISTS %I', tbl||'_past');
212 |
213 | -- remove inheritance
214 | EXECUTE format('ALTER TABLE %I.%I NO INHERIT %I.%I', tblSchema, tblName, tplSchema, tplName);
215 |
216 | -- drop extra tables
217 | EXECUTE format('DROP TABLE %I.%I', logSchema, logName);
218 | EXECUTE format('DROP TABLE %I.%I', tplSchema, tplName);
219 |
220 | -- delete trigger
221 | EXECUTE format('DROP TRIGGER trig_recall ON %I', tbl);
222 | END;
223 | $$ LANGUAGE plpgsql;
224 |
225 |
226 | --
227 | -- Trigger function
228 | --
229 | CREATE OR REPLACE FUNCTION recall._trigfn() RETURNS TRIGGER AS $$
230 | DECLARE
231 | tplTable REGCLASS;
232 | logTable REGCLASS;
233 |
234 | tblSchema NAME; tblName NAME;
235 | logSchema NAME; logName NAME;
236 |
237 | pkeyCols TEXT[];
238 | pkeyChecks TEXT[]; -- array of 'colName = $1.colName' strings
239 | assignments TEXT[]; -- array of 'colname = $2.colName' strings (for the UPDATE statement)
240 | cols TEXT[]; -- will be filled with escaped column names (in the same order as the vals below)
241 | vals TEXT[]; -- will contain the equivalent of NEW. for each of the columns in the _tpl table
242 | col TEXT; -- loop variable
243 | updateCount INTEGER;
244 | BEGIN
245 | if TG_OP = 'UPDATE' AND OLD = NEW THEN
246 | RAISE INFO 'pg_recall: row unchanged, no need to write to log';
247 | RETURN NEW;
248 | END IF;
249 |
250 | -- Fetch the table's config
251 | SELECT pkey_cols, tpl_table, log_table INTO pkeyCols, tplTable, logTable FROM recall._config WHERE tblid = TG_RELID;
252 |
253 | -- fetch table schema and names
254 | SELECT schema, name INTO tblSchema, tblName FROM recall._tablemapping WHERE id = TG_RELID;
255 | SELECT schema, name INTO logSchema, logName FROM recall._tablemapping WHERE id = logTable;
256 |
257 | IF TG_OP IN ('UPDATE', 'DELETE') THEN
258 | -- build WHERE clauses in the form of 'pkeyCol = OLD.pkeyCol' for each of the primary key columns
259 | -- (they will later be joined with ' AND ' inbetween)
260 | FOREACH col IN ARRAY pkeyCols
261 | LOOP
262 | pkeyChecks = array_append(pkeyChecks, format('%I = $1.%I', col, col));
263 | END LOOP;
264 |
265 | -- mark old log entries as outdated
266 | EXECUTE format('UPDATE %I.%I SET _log_time = tstzrange(LOWER(_log_time), now()) WHERE %s AND upper_inf(_log_time) AND LOWER(_log_time) != now()',
267 | logSchema, logName,
268 | array_to_string(pkeyChecks, ' AND ')) USING OLD;
269 | END IF;
270 | IF TG_OP IN ('INSERT', 'UPDATE') THEN
271 | -- get all columns of the _tpl table and put them into the cols and vals arrays
272 | -- (source: http://dba.stackexchange.com/a/22420/85760 )
273 | FOR col IN SELECT attname FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
274 | LOOP
275 | -- for the INSERT
276 | cols = array_append(cols, format('%I', col));
277 | vals = array_append(vals, format('$1.%I', col));
278 |
279 | -- for the UPDATE
280 | assignments = array_append(assignments, format('%I = $2.%I', col, col));
281 | END LOOP;
282 |
283 | -- for UPDATE statements, check if the value's been changed before (see #16)
284 | updateCount := 0;
285 | IF TG_OP = 'UPDATE' THEN
286 | -- we can reuse pkeyChecks here
287 | EXECUTE format('UPDATE %I.%I SET %s WHERE %s AND LOWER(_log_time) = now()',
288 | logSchema, logName,
289 | array_to_string(assignments, ', '),
290 | array_to_string(pkeyChecks, ' AND ')
291 | ) USING OLD, NEW;
292 | GET DIAGNOSTICS updateCount = ROW_COUNT;
293 | END IF;
294 |
295 | IF updateCount = 0 THEN
296 | -- create the log entry (as there was nothing to update)
297 | EXECUTE format('INSERT INTO %I.%I (%s) VALUES (%s)',
298 | logSchema, logName,
299 | array_to_string(cols, ', '),
300 | array_to_string(vals, ', ')
301 | ) USING NEW;
302 | END IF;
303 |
304 | END IF;
305 | RETURN new;
306 | END;
307 | $$ LANGUAGE plpgsql;
308 |
309 |
310 | --
311 | -- Cleanup functions (return the number of deleted rows)
312 | --
313 | CREATE OR REPLACE FUNCTION recall.cleanup(tbl REGCLASS) RETURNS INTEGER AS $$
314 | DECLARE
315 | logInterval INTERVAL;
316 | rc INTEGER;
317 |
318 | logTable REGCLASS;
319 | logSchema NAME;
320 | logName NAME;
321 | BEGIN
322 | -- get the log table and interval (and update last_cleanup while we're at it)
323 | UPDATE recall._config SET last_cleanup = now() WHERE tblId = tbl RETURNING log_interval, log_table INTO logInterval, logTable;
324 |
325 | -- resolve the log table's schema and name
326 | SELECT schema, name INTO logSchema, logName FROM recall._tablemapping WHERE id = logTable;
327 |
328 | RAISE NOTICE 'recall: Cleaning up table %', tbl;
329 | -- Remove old entries
330 | EXECUTE format('DELETE FROM %I.%I WHERE UPPER(_log_time) < now() - $1', logSchema, logName) USING logInterval;
331 |
332 | GET DIAGNOSTICS rc = ROW_COUNT;
333 | RETURN rc;
334 | END;
335 | $$ LANGUAGE plpgsql;
336 |
337 | -- convenience cleanup function
338 | CREATE OR REPLACE FUNCTION recall.cleanup_all() RETURNS VOID AS $$
339 | DECLARE
340 | tbl REGCLASS;
341 | BEGIN
342 | FOR tbl in SELECT tblid FROM recall._config
343 | LOOP
344 | PERFORM recall.cleanup(tbl);
345 | END LOOP;
346 | END;
347 | $$ LANGUAGE plpgsql;
348 |
349 | --
350 | -- Query past state
351 | --
352 | CREATE OR REPLACE FUNCTION recall.at(tbl REGCLASS, ts TIMESTAMPTZ) RETURNS REGCLASS AS $$
353 | DECLARE
354 | tplTable REGCLASS;
355 | logTable REGCLASS;
356 |
357 | tblSchema NAME; tblName NAME;
358 | logSchema NAME; logName NAME;
359 |
360 | viewName NAME;
361 | cols TEXT[];
362 | BEGIN
363 | -- initialize vars
364 | SELECT tpl_table, log_table INTO tplTable, logTable FROM recall._config WHERE tblid = tbl;
365 |
366 | SELECT schema, name INTO tblSchema, tblName FROM recall._tablemapping WHERE id = tbl;
367 | SELECT schema, name INTO logSchema, logName FROM recall._tablemapping WHERE id = logTable;
368 | viewName := tblName||'_past';
369 |
370 | -- get (escaped) list of columns
371 | SELECT ARRAY(
372 | SELECT format('%I', attname) INTO cols FROM pg_attribute WHERE attrelid = tplTable AND attnum > 0 AND attisdropped = false
373 | );
374 |
375 | EXECUTE format('CREATE OR REPLACE TEMPORARY VIEW %I AS SELECT %s FROM %I.%I WHERE _log_time @> %L::timestamptz',
376 | viewName,
377 | array_to_string(cols, ', '),
378 | logSchema, logName,
379 | ts
380 | );
381 |
382 | return viewName;
383 | END;
384 | $$ LANGUAGE plpgsql;
385 |
386 |
--------------------------------------------------------------------------------
/examples/jupyter/presentation.ipynb:
--------------------------------------------------------------------------------
1 | {
2 | "cells": [
3 | {
4 | "cell_type": "markdown",
5 | "metadata": {
6 | "slideshow": {
7 | "slide_type": "slide"
8 | }
9 | },
10 | "source": [
11 | "# pg_recall\n",
12 | "\n",
13 | "a time machine for your PostgreSQL data\n",
14 | "\n",
15 | "
\n",
16 | "\n",
17 | "https://github.com/mreithub/pg_recall/"
18 | ]
19 | },
20 | {
21 | "cell_type": "code",
22 | "execution_count": 2,
23 | "metadata": {
24 | "collapsed": false,
25 | "slideshow": {
26 | "slide_type": "fragment"
27 | }
28 | },
29 | "outputs": [
30 | {
31 | "name": "stdout",
32 | "output_type": "stream",
33 | "text": [
34 | "ok"
35 | ]
36 | }
37 | ],
38 | "source": [
39 | "\\connect host=localhost user=manuel database=postgres nopassword"
40 | ]
41 | },
42 | {
43 | "cell_type": "markdown",
44 | "metadata": {
45 | "slideshow": {
46 | "slide_type": "slide"
47 | }
48 | },
49 | "source": [
50 | "## what it's for"
51 | ]
52 | },
53 | {
54 | "cell_type": "markdown",
55 | "metadata": {
56 | "slideshow": {
57 | "slide_type": "subslide"
58 | }
59 | },
60 | "source": [
61 | "keeps track of data changes to your tables"
62 | ]
63 | },
64 | {
65 | "cell_type": "markdown",
66 | "metadata": {
67 | "slideshow": {
68 | "slide_type": "fragment"
69 | }
70 | },
71 | "source": [
72 | "- look at past states of your tables"
73 | ]
74 | },
75 | {
76 | "cell_type": "markdown",
77 | "metadata": {
78 | "slideshow": {
79 | "slide_type": "fragment"
80 | }
81 | },
82 | "source": [
83 | "- list changes for individual keys"
84 | ]
85 | },
86 | {
87 | "cell_type": "markdown",
88 | "metadata": {
89 | "slideshow": {
90 | "slide_type": "fragment"
91 | }
92 | },
93 | "source": [
94 | "- allows you to implement tools to automate that\n",
95 | " - undo/redo buttons\n",
96 | " - Revision history page\n",
97 | " - a backend for customer service where they can see what the user did\n",
98 | " - look for data/users that behave oddly"
99 | ]
100 | },
101 | {
102 | "cell_type": "markdown",
103 | "metadata": {
104 | "slideshow": {
105 | "slide_type": "subslide"
106 | }
107 | },
108 | "source": [
109 | "for...\n",
110 | "- user data \n",
111 | "- logging metrics"
112 | ]
113 | },
114 | {
115 | "cell_type": "markdown",
116 | "metadata": {
117 | "slideshow": {
118 | "slide_type": "fragment"
119 | }
120 | },
121 | "source": [
122 | "... data that doesn't change *too often*"
123 | ]
124 | },
125 | {
126 | "cell_type": "markdown",
127 | "metadata": {
128 | "slideshow": {
129 | "slide_type": "slide"
130 | }
131 | },
132 | "source": [
133 | "## design goals"
134 | ]
135 | },
136 | {
137 | "cell_type": "markdown",
138 | "metadata": {
139 | "slideshow": {
140 | "slide_type": "subslide"
141 | }
142 | },
143 | "source": [
144 | "CRUD transparency"
145 | ]
146 | },
147 | {
148 | "cell_type": "markdown",
149 | "metadata": {
150 | "slideshow": {
151 | "slide_type": "subslide"
152 | }
153 | },
154 | "source": [
155 | "simplicity"
156 | ]
157 | },
158 | {
159 | "cell_type": "markdown",
160 | "metadata": {
161 | "slideshow": {
162 | "slide_type": "subslide"
163 | }
164 | },
165 | "source": [
166 | "flexibility"
167 | ]
168 | },
169 | {
170 | "cell_type": "markdown",
171 | "metadata": {
172 | "slideshow": {
173 | "slide_type": "subslide"
174 | }
175 | },
176 | "source": [
177 | "little overhead"
178 | ]
179 | },
180 | {
181 | "cell_type": "markdown",
182 | "metadata": {
183 | "slideshow": {
184 | "slide_type": "slide"
185 | }
186 | },
187 | "source": [
188 | "## Demo"
189 | ]
190 | },
191 | {
192 | "cell_type": "markdown",
193 | "metadata": {
194 | "slideshow": {
195 | "slide_type": "fragment"
196 | }
197 | },
198 | "source": [
199 | ""
200 | ]
201 | },
202 | {
203 | "cell_type": "code",
204 | "execution_count": 35,
205 | "metadata": {
206 | "collapsed": false
207 | },
208 | "outputs": [
209 | {
210 | "name": "stdout",
211 | "output_type": "stream",
212 | "text": [
213 | "ok (took 0.00ms)"
214 | ]
215 | }
216 | ],
217 | "source": [
218 | "BEGIN; -- run all this in a transaction (for predictable timing) "
219 | ]
220 | },
221 | {
222 | "cell_type": "code",
223 | "execution_count": 36,
224 | "metadata": {
225 | "collapsed": false,
226 | "slideshow": {
227 | "slide_type": "subslide"
228 | }
229 | },
230 | "outputs": [
231 | {
232 | "name": "stdout",
233 | "output_type": "stream",
234 | "text": [
235 | "ok (took 0.00ms)"
236 | ]
237 | }
238 | ],
239 | "source": [
240 | "CREATE TABLE IF NOT EXISTS account (\n",
241 | " uid SERIAL PRIMARY KEY,\n",
242 | " created_at TIMESTAMPTZ NOT NULL DEFAULT now(),\n",
243 | "\n",
244 | " name VARCHAR(200) NOT NULL,\n",
245 | " login VARCHAR(100) NOT NULL,\n",
246 | " password VARCHAR(200) NOT NULL,\n",
247 | " email VARCHAR(200) NOT NULL\n",
248 | ");\n",
249 | "CREATE UNIQUE INDEX IF NOT EXISTS idx_account_login ON account(lower(login));\n",
250 | "\n",
251 | "CREATE TABLE IF NOT EXISTS account_settings (\n",
252 | " uid INTEGER NOT NULL,\n",
253 | " key VARCHAR(100) NOT NULL,\n",
254 | " value TEXT NOT NULL,\n",
255 | "\n",
256 | " PRIMARY KEY (uid, key),\n",
257 | " FOREIGN KEY (uid) REFERENCES account(uid)\n",
258 | ");\n",
259 | " §\n",
260 | "CREATE TABLE IF NOT EXISTS blog_entry (\n",
261 | " entry_id SERIAL PRIMARY KEY,\n",
262 | " creator INTEGER NOT NULL,\n",
263 | " created_at TIMESTAMPTZ NOT NULL DEFAULT now(),\n",
264 | "\n",
265 | " title VARCHAR(200) NOT NULL,\n",
266 | " content TEXT NOT NULL,\n",
267 | "\n",
268 | " FOREIGN KEY (creator) REFERENCES account(uid)\n",
269 | "); "
270 | ]
271 | },
272 | {
273 | "cell_type": "markdown",
274 | "metadata": {
275 | "slideshow": {
276 | "slide_type": "subslide"
277 | }
278 | },
279 | "source": [
280 | "Installation\n",
281 | "------------\n",
282 | "\n",
283 | "run `make install` in the source directory"
284 | ]
285 | },
286 | {
287 | "cell_type": "code",
288 | "execution_count": 37,
289 | "metadata": {
290 | "collapsed": false,
291 | "slideshow": {
292 | "slide_type": "fragment"
293 | }
294 | },
295 | "outputs": [
296 | {
297 | "data": {
298 | "text/html": [
299 | ""
300 | ]
301 | },
302 | "metadata": {},
303 | "output_type": "display_data"
304 | },
305 | {
306 | "name": "stdout",
307 | "output_type": "stream",
308 | "text": [
309 | "1 rows (took 0.00ms)"
310 | ]
311 | }
312 | ],
313 | "source": [
314 | "CREATE EXTENSION IF NOT EXISTS btree_gist;\n",
315 | "CREATE EXTENSION IF NOT EXISTS recall WITH VERSION '0.9.5';\n",
316 | "\n",
317 | "SELECT recall.enable('account_settings', '3 months');\n",
318 | "SELECT recall.enable('blog_entry', '6 months');"
319 | ]
320 | },
321 | {
322 | "cell_type": "code",
323 | "execution_count": 38,
324 | "metadata": {
325 | "collapsed": false,
326 | "slideshow": {
327 | "slide_type": "fragment"
328 | }
329 | },
330 | "outputs": [
331 | {
332 | "name": "stdout",
333 | "output_type": "stream",
334 | "text": [
335 | "ok (took 0.00ms)"
336 | ]
337 | }
338 | ],
339 | "source": [
340 | "-- cheating a little\n",
341 | "CREATE OR REPLACE FUNCTION pretendToWait(t INTERVAL) RETURNS void AS $$\n",
342 | " UPDATE recall.account_settings_log SET _log_time = tstzrange(LOWER(_log_time)-t, UPPER(_log_time)-t);\n",
343 | " UPDATE recall.blog_entry_log SET _log_time = tstzrange(LOWER(_log_time)-t, UPPER(_log_time)-t);\n",
344 | "$$ LANGUAGE sql;"
345 | ]
346 | },
347 | {
348 | "cell_type": "markdown",
349 | "metadata": {
350 | "slideshow": {
351 | "slide_type": "subslide"
352 | }
353 | },
354 | "source": [
355 | "### Table inheritance\n",
356 | ""
357 | ]
358 | },
359 | {
360 | "cell_type": "code",
361 | "execution_count": 7,
362 | "metadata": {
363 | "collapsed": false,
364 | "slideshow": {
365 | "slide_type": "subslide"
366 | }
367 | },
368 | "outputs": [
369 | {
370 | "data": {
371 | "text/html": [
372 | "| Schema | Name | Type | Owner |
|---|
| public | account | table | manuel |
| public | account_settings | table | manuel |
| public | blog_entry | table | manuel |
"
373 | ]
374 | },
375 | "metadata": {},
376 | "output_type": "display_data"
377 | },
378 | {
379 | "name": "stdout",
380 | "output_type": "stream",
381 | "text": [
382 | "3 rows (took 0.00ms)"
383 | ]
384 | }
385 | ],
386 | "source": [
387 | "\\dt"
388 | ]
389 | },
390 | {
391 | "cell_type": "code",
392 | "execution_count": 8,
393 | "metadata": {
394 | "collapsed": false,
395 | "slideshow": {
396 | "slide_type": "subslide"
397 | }
398 | },
399 | "outputs": [
400 | {
401 | "data": {
402 | "text/html": [
403 | "| Schema | Name | Type | Owner |
|---|
| recall | _config | table | manuel |
| recall | account_settings_log | table | manuel |
| recall | account_settings_tpl | table | manuel |
| recall | blog_entry_log | table | manuel |
| recall | blog_entry_tpl | table | manuel |
"
404 | ]
405 | },
406 | "metadata": {},
407 | "output_type": "display_data"
408 | },
409 | {
410 | "name": "stdout",
411 | "output_type": "stream",
412 | "text": [
413 | "5 rows (took 0.00ms)"
414 | ]
415 | }
416 | ],
417 | "source": [
418 | "\\dt recall"
419 | ]
420 | },
421 | {
422 | "cell_type": "markdown",
423 | "metadata": {
424 | "slideshow": {
425 | "slide_type": "subslide"
426 | }
427 | },
428 | "source": [
429 | "### Some data..."
430 | ]
431 | },
432 | {
433 | "cell_type": "code",
434 | "execution_count": 39,
435 | "metadata": {
436 | "collapsed": false,
437 | "slideshow": {
438 | "slide_type": "fragment"
439 | }
440 | },
441 | "outputs": [
442 | {
443 | "data": {
444 | "text/html": [
445 | ""
446 | ]
447 | },
448 | "metadata": {},
449 | "output_type": "display_data"
450 | },
451 | {
452 | "name": "stdout",
453 | "output_type": "stream",
454 | "text": [
455 | "1 rows (took 0.00ms)"
456 | ]
457 | }
458 | ],
459 | "source": [
460 | "INSERT INTO account (uid, name, login, password, email)\n",
461 | "VALUES (12, 'John Doe', 'jdoe', 'very secure password', 'jdoe@example.com')\n",
462 | "RETURNING uid;"
463 | ]
464 | },
465 | {
466 | "cell_type": "code",
467 | "execution_count": 40,
468 | "metadata": {
469 | "collapsed": false,
470 | "slideshow": {
471 | "slide_type": "fragment"
472 | }
473 | },
474 | "outputs": [
475 | {
476 | "name": "stdout",
477 | "output_type": "stream",
478 | "text": [
479 | "2 rows (took 0.00ms)"
480 | ]
481 | }
482 | ],
483 | "source": [
484 | "INSERT INTO account_settings (uid, key, value) VALUES\n",
485 | "(12, 'get_newsletter', true),\n",
486 | "(12, 'enable_spellcheck', false);"
487 | ]
488 | },
489 | {
490 | "cell_type": "code",
491 | "execution_count": 41,
492 | "metadata": {
493 | "collapsed": false,
494 | "slideshow": {
495 | "slide_type": "fragment"
496 | }
497 | },
498 | "outputs": [
499 | {
500 | "data": {
501 | "text/html": [
502 | ""
503 | ]
504 | },
505 | "metadata": {},
506 | "output_type": "display_data"
507 | },
508 | {
509 | "name": "stdout",
510 | "output_type": "stream",
511 | "text": [
512 | "2 rows (took 0.00ms)"
513 | ]
514 | }
515 | ],
516 | "source": [
517 | "INSERT INTO blog_entry (entry_id, creator, title, content) VALUES\n",
518 | "(123 , 12, 'Welcome to my new bog', 'This is sooooo super exciting!'),\n",
519 | "(124, 12, 'House warming party', 'I want to invite you all to my house warming party next tuesday at 123 Some Place')\n",
520 | "RETURNING entry_id;"
521 | ]
522 | },
523 | {
524 | "cell_type": "markdown",
525 | "metadata": {
526 | "slideshow": {
527 | "slide_type": "subslide"
528 | }
529 | },
530 | "source": [
531 | "### Changes"
532 | ]
533 | },
534 | {
535 | "cell_type": "code",
536 | "execution_count": 42,
537 | "metadata": {
538 | "collapsed": false,
539 | "slideshow": {
540 | "slide_type": "fragment"
541 | }
542 | },
543 | "outputs": [
544 | {
545 | "name": "stdout",
546 | "output_type": "stream",
547 | "text": [
548 | "1 rows (took 0.00ms)"
549 | ]
550 | }
551 | ],
552 | "source": [
553 | "-- fix a typo\n",
554 | "SELECT pretendToWait('5 minutes');\n",
555 | "UPDATE blog_entry SET title = 'Welcome to my new blog'\n",
556 | " WHERE entry_id = 123;"
557 | ]
558 | },
559 | {
560 | "cell_type": "code",
561 | "execution_count": 43,
562 | "metadata": {
563 | "collapsed": false,
564 | "slideshow": {
565 | "slide_type": "fragment"
566 | }
567 | },
568 | "outputs": [
569 | {
570 | "name": "stdout",
571 | "output_type": "stream",
572 | "text": [
573 | "1 rows (took 0.00ms)"
574 | ]
575 | }
576 | ],
577 | "source": [
578 | "-- enable spell check to prevent typos in the future\n",
579 | "SELECT pretendToWait('5 minutes');\n",
580 | "UPDATE account_settings SET value = true\n",
581 | " WHERE uid = 12 AND key = 'enable_spellcheck';"
582 | ]
583 | },
584 | {
585 | "cell_type": "code",
586 | "execution_count": 44,
587 | "metadata": {
588 | "collapsed": false,
589 | "slideshow": {
590 | "slide_type": "fragment"
591 | }
592 | },
593 | "outputs": [
594 | {
595 | "name": "stdout",
596 | "output_type": "stream",
597 | "text": [
598 | "1 rows (took 0.00ms)"
599 | ]
600 | }
601 | ],
602 | "source": [
603 | "-- remove the second blog entry\n",
604 | "SELECT pretendToWait('5 minutes');\n",
605 | "DELETE FROM blog_entry WHERE entry_id = 124;"
606 | ]
607 | },
608 | {
609 | "cell_type": "markdown",
610 | "metadata": {
611 | "slideshow": {
612 | "slide_type": "subslide"
613 | }
614 | },
615 | "source": [
616 | "### Let's have a look"
617 | ]
618 | },
619 | {
620 | "cell_type": "code",
621 | "execution_count": 15,
622 | "metadata": {
623 | "collapsed": false,
624 | "slideshow": {
625 | "slide_type": "fragment"
626 | }
627 | },
628 | "outputs": [
629 | {
630 | "data": {
631 | "text/html": [
632 | "| uid | created_at | name | login | password | email |
|---|
| 12 | 2016-04-04 20:52:30.577405+02:00 | John Doe | jdoe | very secure password | jdoe@example.com |
"
633 | ]
634 | },
635 | "metadata": {},
636 | "output_type": "display_data"
637 | },
638 | {
639 | "name": "stdout",
640 | "output_type": "stream",
641 | "text": [
642 | "1 rows (took 0.00ms)"
643 | ]
644 | }
645 | ],
646 | "source": [
647 | "SELECT * FROM account;"
648 | ]
649 | },
650 | {
651 | "cell_type": "code",
652 | "execution_count": 16,
653 | "metadata": {
654 | "collapsed": false,
655 | "slideshow": {
656 | "slide_type": "fragment"
657 | }
658 | },
659 | "outputs": [
660 | {
661 | "data": {
662 | "text/html": [
663 | "| uid | key | value |
|---|
| 12 | get_newsletter | true |
| 12 | enable_spellcheck | true |
"
664 | ]
665 | },
666 | "metadata": {},
667 | "output_type": "display_data"
668 | },
669 | {
670 | "name": "stdout",
671 | "output_type": "stream",
672 | "text": [
673 | "2 rows (took 0.00ms)"
674 | ]
675 | }
676 | ],
677 | "source": [
678 | "SELECT * FROM account_settings;"
679 | ]
680 | },
681 | {
682 | "cell_type": "code",
683 | "execution_count": 17,
684 | "metadata": {
685 | "collapsed": false,
686 | "slideshow": {
687 | "slide_type": "subslide"
688 | }
689 | },
690 | "outputs": [
691 | {
692 | "data": {
693 | "text/html": [
694 | "| entry_id | creator | created_at | title | content |
|---|
| 123 | 12 | 2016-04-04 20:52:30.577405+02:00 | Welcome to my new blog | This is sooooo super exciting! |
"
695 | ]
696 | },
697 | "metadata": {},
698 | "output_type": "display_data"
699 | },
700 | {
701 | "name": "stdout",
702 | "output_type": "stream",
703 | "text": [
704 | "1 rows (took 0.00ms)"
705 | ]
706 | }
707 | ],
708 | "source": [
709 | "SELECT * FROM blog_entry;"
710 | ]
711 | },
712 | {
713 | "cell_type": "markdown",
714 | "metadata": {
715 | "slideshow": {
716 | "slide_type": "subslide"
717 | }
718 | },
719 | "source": [
720 | "### Going back in time"
721 | ]
722 | },
723 | {
724 | "cell_type": "code",
725 | "execution_count": 46,
726 | "metadata": {
727 | "collapsed": false,
728 | "slideshow": {
729 | "slide_type": "fragment"
730 | }
731 | },
732 | "outputs": [
733 | {
734 | "data": {
735 | "text/html": [
736 | "| entry_id | creator | created_at | title | content |
|---|
| 123 | 12 | 2016-04-04 21:16:47.405329+02:00 | Welcome to my new blog | This is sooooo super exciting! |
| 124 | 12 | 2016-04-04 21:16:47.405329+02:00 | House warming party | I want to invite you all to my house warming party next tuesday at 123 Some Place |
"
737 | ]
738 | },
739 | "metadata": {},
740 | "output_type": "display_data"
741 | },
742 | {
743 | "name": "stdout",
744 | "output_type": "stream",
745 | "text": [
746 | "2 rows (took 0.00ms)"
747 | ]
748 | }
749 | ],
750 | "source": [
751 | "SELECT recall.at('blog_entry', now() - interval '10 minutes');\n",
752 | "SELECT * FROM blog_entry_past;"
753 | ]
754 | },
755 | {
756 | "cell_type": "markdown",
757 | "metadata": {
758 | "slideshow": {
759 | "slide_type": "subslide"
760 | }
761 | },
762 | "source": [
763 | "### Behind the scenes"
764 | ]
765 | },
766 | {
767 | "cell_type": "code",
768 | "execution_count": 19,
769 | "metadata": {
770 | "collapsed": false,
771 | "slideshow": {
772 | "slide_type": "fragment"
773 | }
774 | },
775 | "outputs": [
776 | {
777 | "data": {
778 | "text/html": [
779 | "| uid | key | value | _log_time |
|---|
| 12 | get_newsletter | true | [\"2016-04-04 20:37:30.577405+02\",) |
| 12 | enable_spellcheck | false | [\"2016-04-04 20:37:30.577405+02\",\"2016-04-04 20:47:30.577405+02\") |
| 12 | enable_spellcheck | true | [\"2016-04-04 20:47:30.577405+02\",) |
"
780 | ]
781 | },
782 | "metadata": {},
783 | "output_type": "display_data"
784 | },
785 | {
786 | "name": "stdout",
787 | "output_type": "stream",
788 | "text": [
789 | "3 rows (took 0.00ms)"
790 | ]
791 | }
792 | ],
793 | "source": [
794 | "SELECT uid, key, value, _log_time::text FROM recall.account_settings_log;"
795 | ]
796 | },
797 | {
798 | "cell_type": "code",
799 | "execution_count": 20,
800 | "metadata": {
801 | "collapsed": false,
802 | "slideshow": {
803 | "slide_type": "subslide"
804 | }
805 | },
806 | "outputs": [
807 | {
808 | "data": {
809 | "text/html": [
810 | "| entry_id | creator | created_at | title | content | _log_time |
|---|
| 123 | 12 | 2016-04-04 20:52:30.577405+02:00 | Welcome to my new bog | This is sooooo super exciting! | [\"2016-04-04 20:37:30.577405+02\",\"2016-04-04 20:42:30.577405+02\") |
| 123 | 12 | 2016-04-04 20:52:30.577405+02:00 | Welcome to my new blog | This is sooooo super exciting! | [\"2016-04-04 20:42:30.577405+02\",) |
| 124 | 12 | 2016-04-04 20:52:30.577405+02:00 | House warming party | I want to invite you all to my house warming party next tuesday at 123 Some Place | [\"2016-04-04 20:37:30.577405+02\",\"2016-04-04 20:52:30.577405+02\") |
"
811 | ]
812 | },
813 | "metadata": {},
814 | "output_type": "display_data"
815 | },
816 | {
817 | "name": "stdout",
818 | "output_type": "stream",
819 | "text": [
820 | "3 rows (took 0.00ms)"
821 | ]
822 | }
823 | ],
824 | "source": [
825 | "SELECT entry_id, creator, created_at, title, content, _log_time::text\n",
826 | "FROM recall.blog_entry_log;"
827 | ]
828 | },
829 | {
830 | "cell_type": "code",
831 | "execution_count": 21,
832 | "metadata": {
833 | "collapsed": false,
834 | "slideshow": {
835 | "slide_type": "subslide"
836 | }
837 | },
838 | "outputs": [
839 | {
840 | "data": {
841 | "text/html": [
842 | "| tblid | ts | log_interval | last_cleanup | pkey_cols | tpl_table | log_table |
|---|
| account_settings | 2016-04-04 20:52:30.577405+02:00 | 90 days, 0:00:00 | None | ['uid', 'key'] | recall.account_settings_tpl | recall.account_settings_log |
| blog_entry | 2016-04-04 20:52:30.577405+02:00 | 180 days, 0:00:00 | None | ['entry_id'] | recall.blog_entry_tpl | recall.blog_entry_log |
"
843 | ]
844 | },
845 | "metadata": {},
846 | "output_type": "display_data"
847 | },
848 | {
849 | "name": "stdout",
850 | "output_type": "stream",
851 | "text": [
852 | "2 rows (took 0.00ms)"
853 | ]
854 | }
855 | ],
856 | "source": [
857 | "SELECT * FROM recall._config;"
858 | ]
859 | },
860 | {
861 | "cell_type": "code",
862 | "execution_count": 22,
863 | "metadata": {
864 | "collapsed": false,
865 | "slideshow": {
866 | "slide_type": "fragment"
867 | }
868 | },
869 | "outputs": [
870 | {
871 | "name": "stdout",
872 | "output_type": "stream",
873 | "text": [
874 | "ok (took 0.00ms)"
875 | ]
876 | }
877 | ],
878 | "source": [
879 | "ROLLBACK; "
880 | ]
881 | },
882 | {
883 | "cell_type": "markdown",
884 | "metadata": {
885 | "slideshow": {
886 | "slide_type": "slide"
887 | }
888 | },
889 | "source": [
890 | "## design choices"
891 | ]
892 | },
893 | {
894 | "cell_type": "markdown",
895 | "metadata": {
896 | "slideshow": {
897 | "slide_type": "subslide"
898 | }
899 | },
900 | "source": [
901 | "storage is (relatively) cheap\n",
902 | "- logs rows, not individual fields\n",
903 | "- detects unchanged rows\n",
904 | "- each table has a retention interval"
905 | ]
906 | },
907 | {
908 | "cell_type": "markdown",
909 | "metadata": {
910 | "slideshow": {
911 | "slide_type": "subslide"
912 | }
913 | },
914 | "source": [
915 | "separate log tables"
916 | ]
917 | },
918 | {
919 | "cell_type": "markdown",
920 | "metadata": {
921 | "slideshow": {
922 | "slide_type": "subslide"
923 | }
924 | },
925 | "source": [
926 | "timestamps identify revisions"
927 | ]
928 | },
929 | {
930 | "cell_type": "code",
931 | "execution_count": 23,
932 | "metadata": {
933 | "collapsed": false,
934 | "slideshow": {
935 | "slide_type": "fragment"
936 | }
937 | },
938 | "outputs": [
939 | {
940 | "data": {
941 | "text/html": [
942 | "| now |
|---|
| 2016-04-04 21:05:00.405573+02:00 |
"
943 | ]
944 | },
945 | "metadata": {},
946 | "output_type": "display_data"
947 | },
948 | {
949 | "name": "stdout",
950 | "output_type": "stream",
951 | "text": [
952 | "1 rows (took 0.00ms)"
953 | ]
954 | }
955 | ],
956 | "source": [
957 | "BEGIN;\n",
958 | "SELECT now();"
959 | ]
960 | },
961 | {
962 | "cell_type": "code",
963 | "execution_count": 31,
964 | "metadata": {
965 | "collapsed": false,
966 | "slideshow": {
967 | "slide_type": "fragment"
968 | }
969 | },
970 | "outputs": [
971 | {
972 | "data": {
973 | "text/html": [
974 | "| now |
|---|
| 2016-04-04 21:05:00.405573+02:00 |
"
975 | ]
976 | },
977 | "metadata": {},
978 | "output_type": "display_data"
979 | },
980 | {
981 | "name": "stdout",
982 | "output_type": "stream",
983 | "text": [
984 | "1 rows (took 0.00ms)"
985 | ]
986 | }
987 | ],
988 | "source": [
989 | "SELECT now(); "
990 | ]
991 | },
992 | {
993 | "cell_type": "code",
994 | "execution_count": 32,
995 | "metadata": {
996 | "collapsed": false,
997 | "slideshow": {
998 | "slide_type": "fragment"
999 | }
1000 | },
1001 | "outputs": [
1002 | {
1003 | "name": "stdout",
1004 | "output_type": "stream",
1005 | "text": [
1006 | "ok (took 0.00ms)"
1007 | ]
1008 | }
1009 | ],
1010 | "source": [
1011 | "ROLLBACK;"
1012 | ]
1013 | },
1014 | {
1015 | "cell_type": "markdown",
1016 | "metadata": {
1017 | "slideshow": {
1018 | "slide_type": "subslide"
1019 | }
1020 | },
1021 | "source": [
1022 | "`tstzrange` as revision identifier"
1023 | ]
1024 | },
1025 | {
1026 | "cell_type": "code",
1027 | "execution_count": 34,
1028 | "metadata": {
1029 | "collapsed": false,
1030 | "slideshow": {
1031 | "slide_type": "fragment"
1032 | }
1033 | },
1034 | "outputs": [
1035 | {
1036 | "data": {
1037 | "text/html": [
1038 | ""
1039 | ]
1040 | },
1041 | "metadata": {},
1042 | "output_type": "display_data"
1043 | },
1044 | {
1045 | "name": "stdout",
1046 | "output_type": "stream",
1047 | "text": [
1048 | "1 rows (took 0.00ms)"
1049 | ]
1050 | }
1051 | ],
1052 | "source": [
1053 | "SELECT '[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp"
1054 | ]
1055 | },
1056 | {
1057 | "cell_type": "markdown",
1058 | "metadata": {
1059 | "slideshow": {
1060 | "slide_type": "subslide"
1061 | }
1062 | },
1063 | "source": [
1064 | "no constraints in the log table"
1065 | ]
1066 | },
1067 | {
1068 | "cell_type": "markdown",
1069 | "metadata": {
1070 | "slideshow": {
1071 | "slide_type": "slide"
1072 | }
1073 | },
1074 | "source": [
1075 | "## Restrictions"
1076 | ]
1077 | },
1078 | {
1079 | "cell_type": "markdown",
1080 | "metadata": {
1081 | "slideshow": {
1082 | "slide_type": "subslide"
1083 | }
1084 | },
1085 | "source": [
1086 | "it protects user data, not schema changes"
1087 | ]
1088 | },
1089 | {
1090 | "cell_type": "markdown",
1091 | "metadata": {
1092 | "slideshow": {
1093 | "slide_type": "subslide"
1094 | }
1095 | },
1096 | "source": [
1097 | "manual cleanup"
1098 | ]
1099 | },
1100 | {
1101 | "cell_type": "markdown",
1102 | "metadata": {
1103 | "slideshow": {
1104 | "slide_type": "subslide"
1105 | }
1106 | },
1107 | "source": [
1108 | "storage overhead"
1109 | ]
1110 | },
1111 | {
1112 | "cell_type": "markdown",
1113 | "metadata": {
1114 | "slideshow": {
1115 | "slide_type": "subslide"
1116 | }
1117 | },
1118 | "source": [
1119 | "depends on `btree_gist`"
1120 | ]
1121 | },
1122 | {
1123 | "cell_type": "markdown",
1124 | "metadata": {
1125 | "slideshow": {
1126 | "slide_type": "slide"
1127 | }
1128 | },
1129 | "source": [
1130 | "## PostgreSQL features"
1131 | ]
1132 | },
1133 | {
1134 | "cell_type": "markdown",
1135 | "metadata": {
1136 | "slideshow": {
1137 | "slide_type": "subslide"
1138 | }
1139 | },
1140 | "source": [
1141 | "extension support"
1142 | ]
1143 | },
1144 | {
1145 | "cell_type": "markdown",
1146 | "metadata": {
1147 | "slideshow": {
1148 | "slide_type": "subslide"
1149 | }
1150 | },
1151 | "source": [
1152 | "range types"
1153 | ]
1154 | },
1155 | {
1156 | "cell_type": "markdown",
1157 | "metadata": {
1158 | "slideshow": {
1159 | "slide_type": "fragment"
1160 | }
1161 | },
1162 | "source": [
1163 | "- no-overlap"
1164 | ]
1165 | },
1166 | {
1167 | "cell_type": "markdown",
1168 | "metadata": {
1169 | "slideshow": {
1170 | "slide_type": "fragment"
1171 | }
1172 | },
1173 | "source": [
1174 | "- non-empty"
1175 | ]
1176 | },
1177 | {
1178 | "cell_type": "markdown",
1179 | "metadata": {
1180 | "slideshow": {
1181 | "slide_type": "subslide"
1182 | }
1183 | },
1184 | "source": [
1185 | "GiST¹ indexes\n",
1186 | "\n",
1187 | "¹ Generalized Search Tree"
1188 | ]
1189 | },
1190 | {
1191 | "cell_type": "markdown",
1192 | "metadata": {
1193 | "slideshow": {
1194 | "slide_type": "fragment"
1195 | }
1196 | },
1197 | "source": [
1198 | "the `btree_gist` extension contains GiST index implementations for built in types"
1199 | ]
1200 | },
1201 | {
1202 | "cell_type": "markdown",
1203 | "metadata": {
1204 | "slideshow": {
1205 | "slide_type": "subslide"
1206 | }
1207 | },
1208 | "source": [
1209 | "table inheritance"
1210 | ]
1211 | },
1212 | {
1213 | "cell_type": "markdown",
1214 | "metadata": {
1215 | "slideshow": {
1216 | "slide_type": "subslide"
1217 | }
1218 | },
1219 | "source": [
1220 | "`pl/pgsql`"
1221 | ]
1222 | },
1223 | {
1224 | "cell_type": "markdown",
1225 | "metadata": {
1226 | "slideshow": {
1227 | "slide_type": "slide"
1228 | }
1229 | },
1230 | "source": [
1231 | "## Future"
1232 | ]
1233 | },
1234 | {
1235 | "cell_type": "markdown",
1236 | "metadata": {
1237 | "slideshow": {
1238 | "slide_type": "fragment"
1239 | }
1240 | },
1241 | "source": [
1242 | "- automatic partitioning\n",
1243 | "- website\n",
1244 | "- ports?\n",
1245 | "- ..."
1246 | ]
1247 | },
1248 | {
1249 | "cell_type": "markdown",
1250 | "metadata": {
1251 | "slideshow": {
1252 | "slide_type": "slide"
1253 | }
1254 | },
1255 | "source": [
1256 | "## Similar projects\n",
1257 | "\n",
1258 | "### PostgreSQL\n",
1259 | "\n",
1260 | "- [TimeTravel for PostgreSQL][6] (GNU GPLv3)\n",
1261 | "- [A PL/pgSQL Trigger Procedure For Auditing][7] in the PostgreSQL docs\n",
1262 | "\n",
1263 | "### Others\n",
1264 | "\n",
1265 | "- Temporal queries in SQL:2011\n",
1266 | "- [Oracle FlashBack][8]\n",
1267 | "- [CouchDB's Document Revisions][9]\n",
1268 | "- [EclipseLink JPA History][10]\n",
1269 | "\n",
1270 | "[6]: http://www.databtech.com/eng/index_timetravel.htm\n",
1271 | "[7]: http://www.postgresql.org/docs/current/static/plpgsql-trigger.html#PLPGSQL-TRIGGER-AUDIT-EXAMPLE\n",
1272 | "[8]: https://docs.oracle.com/cd/B28359_01/appdev.111/b28424/adfns_flashback.htm\n",
1273 | "[9]: http://docs.couchdb.org/en/1.6.1/intro/api.html#revisions\n",
1274 | "[10]: https://wiki.eclipse.org/EclipseLink/Examples/JPA/History"
1275 | ]
1276 | },
1277 | {
1278 | "cell_type": "markdown",
1279 | "metadata": {
1280 | "slideshow": {
1281 | "slide_type": "slide"
1282 | }
1283 | },
1284 | "source": [
1285 | "## Questions?\n",
1286 | "\n",
1287 | "feel free to talk to me afterwards, tweet me at [@mreithub][1] or send an email to [manuel@reithuber.net][2] .\n",
1288 | "\n",
1289 | "The project's open source and can be found at:\n",
1290 | "https://github.com/mreithub/pg_recall/\n",
1291 | "\n",
1292 | "
\n",
1293 | "\n",
1294 | "These slides were written using [jupyter.org][3] (extended by [RISE][4] as well as my own [postgres_kernel][5])\n",
1295 | "\n",
1296 | "[1]: https://twitter.com/mreithub\n",
1297 | "[2]: mailto:manuel@reithuber.net?subject=pg_recall\n",
1298 | "[3]: https://jupyter.org\n",
1299 | "[4]: https://github.com/damianavila/RISE/\n",
1300 | "[5]: https://github.com/mreithub/postgres_kernel"
1301 | ]
1302 | },
1303 | {
1304 | "cell_type": "markdown",
1305 | "metadata": {
1306 | "slideshow": {
1307 | "slide_type": "slide"
1308 | }
1309 | },
1310 | "source": [
1311 | "## Cleanup"
1312 | ]
1313 | },
1314 | {
1315 | "cell_type": "code",
1316 | "execution_count": null,
1317 | "metadata": {
1318 | "collapsed": false,
1319 | "slideshow": {
1320 | "slide_type": "fragment"
1321 | }
1322 | },
1323 | "outputs": [],
1324 | "source": [
1325 | "-- cleanup\n",
1326 | "SELECT recall.disable('account_settings');\n",
1327 | "SELECT recall.disable('blog_entry');"
1328 | ]
1329 | },
1330 | {
1331 | "cell_type": "code",
1332 | "execution_count": null,
1333 | "metadata": {
1334 | "collapsed": false,
1335 | "slideshow": {
1336 | "slide_type": "fragment"
1337 | }
1338 | },
1339 | "outputs": [],
1340 | "source": [
1341 | "DROP TABLE blog_entry, account_settings, account;"
1342 | ]
1343 | }
1344 | ],
1345 | "metadata": {
1346 | "celltoolbar": "Slideshow",
1347 | "kernelspec": {
1348 | "display_name": "PostgreSQL",
1349 | "language": "",
1350 | "name": "postgres"
1351 | },
1352 | "language_info": {
1353 | "mimetype": "text/x-postgresql",
1354 | "name": "sql"
1355 | }
1356 | },
1357 | "nbformat": 4,
1358 | "nbformat_minor": 0
1359 | }
1360 |
--------------------------------------------------------------------------------