Skip to content

Commit

Permalink
Add a way to set the system time that is used by versioned triggers.
Browse files Browse the repository at this point in the history
  • Loading branch information
arkhipov committed Dec 15, 2015
1 parent f6f0f0f commit 65af4b1
Show file tree
Hide file tree
Showing 13 changed files with 680 additions and 19 deletions.
6 changes: 3 additions & 3 deletions META.json
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,7 @@
"name": "temporal_tables",
"abstract": "Temporal Tables Extension",
"description": "This extension provides support for temporal tables. System-period data versioning (also known as transaction time or system time) allows you to specify that old rows are archived into another table (that is called the history table).",
"version": "1.0.2",
"version": "1.1.0",
"release_status": "stable",
"maintainer": [
"Vladislav Arkhipov <[email protected]>"
Expand All @@ -11,9 +11,9 @@
"provides": {
"temporal_tables": {
"abstract": "Temporal Tables Extension",
"file": "temporal_tables--1.0.2.sql",
"file": "temporal_tables--1.1.0.sql",
"docfile": "README.md",
"version": "1.0.2"
"version": "1.1.0"
}
},
"prereqs": {
Expand Down
11 changes: 7 additions & 4 deletions Makefile
Original file line number Diff line number Diff line change
@@ -1,17 +1,20 @@
# versioning/Makefile

MODULE_big = temporal_tables
OBJS = versioning.o
OBJS = temporal_tables.o versioning.o

EXTENSION = temporal_tables
DATA = temporal_tables--1.0.2.sql \
DATA = temporal_tables--1.1.0.sql \
temporal_tables--1.0.0--1.0.1.sql \
temporal_tables--1.0.1--1.0.2.sql
temporal_tables--1.0.1--1.0.2.sql \
temporal_tables--1.0.2--1.1.0.sql
DOCS = README.md

REGRESS = install no_system_period invalid_system_period \
no_history_table no_history_system_period invalid_types \
invalid_system_period_values versioning structure uninstall
invalid_system_period_values \
versioning versioning_custom_system_time \
structure uninstall

PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
Expand Down
22 changes: 22 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -318,6 +318,28 @@ The history table employees_history now looks like this:
Bernard Marx | Hatchery and Conditioning Centre | 10000 | [2006-08-08, 2007-02-27)
Helmholtz Watson | College of Emotional Engineering | 18500 | [2006-08-08, 2012-12-24)

Advanced usage
==============

Instead of using CURRENT_TIMESTAMP, you may want to set a custom system time for
versioning triggers. It is useful for creating a data warehouse from a system
that recorded a system time and you want to use that time instead.

```SQL
SELECT set_system_time('1985-08-08 06:42:00+08');
```

To revert it back to the default behaviour, call the function with `NULL` as its
argument.

```SQL
SELECT set_system_time(NULL);
```

If the `set_system_time` function is issued within a transaction that is later
aborted, all the changes are undone. If the transaction is committed, the
changes will persist until the end of the session.

Examples and hints
=====================

Expand Down
2 changes: 2 additions & 0 deletions expected/versioning.out
Original file line number Diff line number Diff line change
Expand Up @@ -121,3 +121,5 @@ SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDE
(0 rows)

END;
DROP TABLE versioning;
DROP TABLE versioning_history;
206 changes: 206 additions & 0 deletions expected/versioning_custom_system_time.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,206 @@
SET client_min_messages TO NOTICE;
SET TIME ZONE 'UTC';
CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
-- Insert some data before versioning is enabled.
INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
CREATE TRIGGER versioning_trigger
BEFORE INSERT OR UPDATE OR DELETE ON versioning
FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false);
-- Insert.
BEGIN;
SELECT set_system_time('2001-01-01'::timestamptz);
set_system_time
-----------------

(1 row)

INSERT INTO versioning (a) VALUES (3);
SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
a | b b | sys_period
---+-----+-----------------------------------
1 | | [-infinity,)
2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
3 | | ["Mon Jan 01 00:00:00 2001 UTC",)
(3 rows)

SELECT * FROM versioning_history ORDER BY a, sys_period;
a | c | sys_period
---+---+------------
(0 rows)

COMMIT;
-- Update.
BEGIN;
SELECT set_system_time('2001-02-01');
set_system_time
-----------------

(1 row)

UPDATE versioning SET a = 4 WHERE a = 3;
SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
a | b b | sys_period
---+-----+-----------------------------------
1 | | [-infinity,)
2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
4 | | ["Thu Feb 01 00:00:00 2001 UTC",)
(3 rows)

SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
a | c | sys_period
---+---+-----------------------------------------------------------------
3 | | ["Mon Jan 01 00:00:00 2001 UTC","Thu Feb 01 00:00:00 2001 UTC")
(1 row)

COMMIT;
-- Multiple updates.
BEGIN;
SELECT set_system_time('2001-03-01');
set_system_time
-----------------

(1 row)

UPDATE versioning SET a = 5 WHERE a = 4;
UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
a | b b | sys_period
---+------------+-----------------------------------
1 | | [-infinity,)
2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
5 | 01-01-2012 | ["Thu Mar 01 00:00:00 2001 UTC",)
(3 rows)

SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
a | c | sys_period
---+---+-----------------------------------------------------------------
3 | | ["Mon Jan 01 00:00:00 2001 UTC","Thu Feb 01 00:00:00 2001 UTC")
4 | | ["Thu Feb 01 00:00:00 2001 UTC","Thu Mar 01 00:00:00 2001 UTC")
(2 rows)

COMMIT;
-- Delete.
BEGIN;
SELECT set_system_time('2001-04-01');
set_system_time
-----------------

(1 row)

DELETE FROM versioning WHERE a = 4;
SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
a | b b | sys_period
---+------------+-----------------------------------
1 | | [-infinity,)
2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
5 | 01-01-2012 | ["Thu Mar 01 00:00:00 2001 UTC",)
(3 rows)

SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
a | c | sys_period
---+---+-----------------------------------------------------------------
3 | | ["Mon Jan 01 00:00:00 2001 UTC","Thu Feb 01 00:00:00 2001 UTC")
4 | | ["Thu Feb 01 00:00:00 2001 UTC","Thu Mar 01 00:00:00 2001 UTC")
(2 rows)

COMMIT;
-- Persist on commit.
BEGIN;
DELETE FROM versioning WHERE a = 4;
SELECT * FROM versioning WHERE a = 4;
a | b b | sys_period
---+-----+------------
(0 rows)

SELECT * FROM versioning_history WHERE a = 4;
a | c | sys_period
---+---+-----------------------------------------------------------------
4 | | ["Thu Feb 01 00:00:00 2001 UTC","Thu Mar 01 00:00:00 2001 UTC")
(1 row)

ROLLBACK;
-- Reset on rollback.
BEGIN;
SELECT set_system_time(NULL);
set_system_time
-----------------

(1 row)

ROLLBACK;
BEGIN;
DELETE FROM versioning WHERE a = 4;
SELECT * FROM versioning WHERE a = 4;
a | b b | sys_period
---+-----+------------
(0 rows)

SELECT * FROM versioning_history WHERE a = 4;
a | c | sys_period
---+---+-----------------------------------------------------------------
4 | | ["Thu Feb 01 00:00:00 2001 UTC","Thu Mar 01 00:00:00 2001 UTC")
(1 row)

COMMIT;
-- Savepoints.
BEGIN;
SELECT set_system_time(NULL);
set_system_time
-----------------

(1 row)

SAVEPOINT p0;
SELECT set_system_time('2002-01-01');
set_system_time
-----------------

(1 row)

SAVEPOINT p1;
SELECT set_system_time('2002-02-01');
set_system_time
-----------------

(1 row)

INSERT INTO versioning (a) VALUES (6);
SELECT * FROM versioning WHERE a = 6;
a | b b | sys_period
---+-----+-----------------------------------
6 | | ["Fri Feb 01 00:00:00 2002 UTC",)
(1 row)

SAVEPOINT p2;
SELECT set_system_time('2002-03-01');
set_system_time
-----------------

(1 row)

INSERT INTO versioning (a) VALUES (7);
SELECT * FROM versioning WHERE a = 7;
a | b b | sys_period
---+-----+-----------------------------------
7 | | ["Fri Mar 01 00:00:00 2002 UTC",)
(1 row)

ROLLBACK TO SAVEPOINT p2;
INSERT INTO versioning (a) VALUES (7);
SELECT * FROM versioning WHERE a = 7;
a | b b | sys_period
---+-----+-----------------------------------
7 | | ["Fri Feb 01 00:00:00 2002 UTC",)
(1 row)

ROLLBACK TO SAVEPOINT p0;
INSERT INTO versioning (a) VALUES (6);
SELECT upper(sys_period) FROM versioning WHERE a = 6 AND lower(sys_period) = CURRENT_TIMESTAMP;
upper
-------

(1 row)

END;
3 changes: 3 additions & 0 deletions sql/versioning.sql
Original file line number Diff line number Diff line change
Expand Up @@ -73,3 +73,6 @@ SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER
SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;

END;

DROP TABLE versioning;
DROP TABLE versioning_history;
Loading

0 comments on commit 65af4b1

Please sign in to comment.