Skip to content

Instantly share code, notes, and snippets.

@micimize
Forked from myitcv/time_travel_trigger.sql
Last active October 3, 2019 22:37
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save micimize/81af2f5829af4a07aa1bc8777eebb33d to your computer and use it in GitHub Desktop.
Save micimize/81af2f5829af4a07aa1bc8777eebb33d to your computer and use it in GitHub Desktop.
Trigger-based equivalent of old PostgreSQL time travel module - see http://blog.myitcv.org.uk/2014/02/25/row-level-version-control-with-postgresql.html for more details
/*
original contained the following, has since been modified
Copyright (c) 2015 Paul Jolly <paul@myitcv.org.uk)
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in
all copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
THE SOFTWARE.
*/
CREATE OR REPLACE FUNCTION process_timetravel_before() RETURNS TRIGGER AS $timetravel_before$
DECLARE
relation REGCLASS;
temp_row RECORD; -- a temporary variable used on updates/deletes
time_now TIMESTAMP; -- get the time now just once.... for consistency's sake
BEGIN
-- use of TG_TABLE_* keeps this generic and non-table specific
-- see http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN
relation = (TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME)::regclass;
time_now = now();
IF (TG_OP = 'UPDATE') THEN
-- updating deleted rows invalid
IF (OLD.valid_until != 'infinity') THEN
RAISE EXCEPTION 'Cannot % old row', TG_OP;
END IF;
EXECUTE 'SELECT * FROM ' || relation || ' WHERE ctid = $1 FOR UPDATE'
USING OLD.ctid;
NEW.valid_from := time_now;
IF (NOT isfinite(NEW.valid_until)) THEN
NEW.valid_until := 'infinity';
END IF;
-- allow the update to continue
-- correct number of rows will be reported affected
RETURN NEW;
ELSIF (TG_OP = 'DELETE') THEN
-- deleting deleted rows invalid
IF (OLD.valid_until != 'infinity') THEN
RAISE EXCEPTION 'Cannot % old row', TG_OP;
END IF;
EXECUTE 'UPDATE ' || relation || ' SET valid_until = $1 WHERE ctid = $2'
USING time_now, OLD.ctid;
-- cancel the delete
-- unfortunately, correct row counts will not be reported
RETURN NULL;
ELSIF (TG_OP = 'INSERT') THEN
IF NEW.valid_until is null THEN
NEW.valid_until := 'infinity';
END IF;
IF NEW.valid_from is null THEN
NEW.valid_from := time_now;
END IF;
-- continue the insert
RETURN NEW;
END IF;
RETURN NULL; -- won't get here if we only create the trigger for insert, update and delete
END;
$timetravel_before$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION process_timetravel_after() RETURNS TRIGGER AS $timetravel_after$
DECLARE
relation REGCLASS;
temp_row RECORD; -- a temporary variable used on updates/deletes
BEGIN
IF (TG_OP = 'UPDATE' AND NEW.valid_until = 'infinity') THEN
relation = (TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME)::regclass;
-- not sure whether this is strictly required... could we modify OLD without side effects?
temp_row := OLD;
temp_row.valid_until := NEW.valid_from;
EXECUTE 'INSERT INTO ' || relation || ' SELECT $1.*'
USING temp_row;
END IF;
-- return value doesn't matter in after
RETURN NULL;
END;
$timetravel_after$ LANGUAGE plpgsql;
@micimize
Copy link
Author

micimize commented Oct 3, 2019

-- manages valid_from and valid_until,
-- transforms deletions into updates
create trigger mytable_before
  before insert or update or delete on myschema}.mytable
  for each row execute procedure process_timetravel_before();

-- insert historical records after user updates,
-- i.e. when (pg_trigger_depth() = 0)
-- this also protects against historical insertions on cascade triggers
create trigger mytable_after
  after update on myschema.mytable
  for each row
  when (pg_trigger_depth() = 0)
  execute procedure process_timetravel_after();

@micimize
Copy link
Author

micimize commented Oct 3, 2019

tried to strip the app-specific logic here - hopefully didn't break it in the process

@micimize
Copy link
Author

micimize commented Oct 3, 2019

Final piece of the puzzle for me for postgraphile integration was a deletion rewrite rule.

-- rewrite deletes into updates,
-- returning * for postgraphile
CREATE OR REPLACE RULE mytable_archive AS
ON DELETE TO myschema.mytable
-- WHERE OLD.valid_until = 'infinity'
DO INSTEAD
  UPDATE myschema.mytable
  SET valid_until = NOW()
  WHERE ctid = OLD.ctid
RETURNING *;

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment