├── .gitignore
├── test
├── performance
│ ├── teardown.sql
│ ├── delete.sql
│ ├── update.sql
│ ├── insert.sql
│ └── setup.sql
├── expected
│ ├── non_equality_types.out
│ ├── non_equality_types_unchanged_values.out
│ ├── noop_update.out
│ ├── versioning_rollback_include_current_version_in_history.out
│ ├── unchanged_version_values.out
│ ├── unchanged_values.out
│ ├── invalid_set_system_time.out
│ ├── increment_version.out
│ ├── increment_version_with_include_current_version_in_history.out
│ ├── migration_mode.out
│ ├── set_system_time.out
│ ├── upper_case.out
│ ├── different_schema.out
│ └── versioning_including_current_version_in_history.out
├── sql
│ ├── non_equality_types.sql
│ ├── non_equality_types_unchanged_values.sql
│ ├── noop_update.sql
│ ├── versioning_rollback_include_current_version_in_history.sql
│ ├── unchanged_version_values.sql
│ ├── unchanged_values.sql
│ ├── increment_version.sql
│ ├── set_system_time.sql
│ ├── increment_version_with_include_current_version_in_history.sql
│ ├── upper_case.sql
│ ├── versioning_including_current_version_in_history.sql
│ ├── different_schema.sql
│ └── migration_mode.sql
├── runTestNochecks.sh
├── runTest.sh
└── runRemoteTests.sh
├── .github
├── dependabot.yml
└── workflows
│ ├── release.yml
│ └── ci.yml
├── docker-compose.yml
├── system_time_function.sql
├── scripts
└── update-version.js
├── package.json
├── LICENSE
├── Makefile
├── versioning_function_nochecks.sql
├── versioning_function.sql
└── README.md
/.gitignore:
--------------------------------------------------------------------------------
1 | *.tmp
2 | .DS_Store
3 | test/result
4 | .env
5 | .envrc
6 | test/remote_expected
7 | test/remote_sql
8 | test/remote_result
9 |
--------------------------------------------------------------------------------
/test/performance/teardown.sql:
--------------------------------------------------------------------------------
1 | \timing off
2 |
3 | DROP TABLE subscriptions;
4 | DROP TABLE subscriptions_history;
5 | DROP FUNCTION versioning();
--------------------------------------------------------------------------------
/test/performance/delete.sql:
--------------------------------------------------------------------------------
1 | \timing on
2 |
3 | -- rows already created by performance-insert.sql
4 |
5 | UPDATE subscriptions SET state = 'updated';
--------------------------------------------------------------------------------
/test/performance/update.sql:
--------------------------------------------------------------------------------
1 | \timing on
2 |
3 | -- rows already created by performance-insert.sql
4 |
5 | UPDATE subscriptions SET state = 'updated';
--------------------------------------------------------------------------------
/test/performance/insert.sql:
--------------------------------------------------------------------------------
1 | \timing on
2 |
3 | INSERT INTO subscriptions(name, state) SELECT 'test' || g, 'inserted' FROM generate_series (1,100000) AS t(g);
--------------------------------------------------------------------------------
/.github/dependabot.yml:
--------------------------------------------------------------------------------
1 | version: 2
2 | updates:
3 | - package-ecosystem: npm
4 | directory: /
5 | schedule:
6 | interval: weekly
7 | - package-ecosystem: github-actions
8 | directory: /
9 | schedule:
10 | interval: weekly
11 |
--------------------------------------------------------------------------------
/docker-compose.yml:
--------------------------------------------------------------------------------
1 | version: '3.9'
2 |
3 | services:
4 |
5 | db:
6 | image: postgres:latest
7 | container_name: temporal-tables-test
8 | restart: always
9 | environment:
10 | POSTGRES_PASSWORD: password
11 | POSTGRES_USER: postgres
12 | ports:
13 | - 5432:5432
--------------------------------------------------------------------------------
/test/expected/non_equality_types.out:
--------------------------------------------------------------------------------
1 | SET client_min_messages TO error;
2 | CREATE TABLE non_equality_types (json json, sys_period tstzrange);
3 | CREATE TRIGGER versioning_trigger
4 | BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types
5 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types', false);
6 | INSERT INTO non_equality_types VALUES ('{"a":1}'::json);
7 | UPDATE non_equality_types SET json = '{"a":2}'::json WHERE 1=1;
8 |
--------------------------------------------------------------------------------
/test/sql/non_equality_types.sql:
--------------------------------------------------------------------------------
1 | SET client_min_messages TO error;
2 |
3 | CREATE TABLE non_equality_types (json json, sys_period tstzrange);
4 |
5 | CREATE TRIGGER versioning_trigger
6 | BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types
7 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types', false);
8 |
9 | INSERT INTO non_equality_types VALUES ('{"a":1}'::json);
10 |
11 | UPDATE non_equality_types SET json = '{"a":2}'::json WHERE 1=1;
12 |
--------------------------------------------------------------------------------
/test/performance/setup.sql:
--------------------------------------------------------------------------------
1 | \timing off
2 |
3 | CREATE TABLE subscriptions
4 | (
5 | name text NOT NULL,
6 | state text NOT NULL,
7 | sys_period tstzrange NOT NULL DEFAULT tstzrange(current_timestamp, null)
8 | );
9 |
10 | CREATE TABLE subscriptions_history (LIKE subscriptions);
11 |
12 | CREATE TRIGGER versioning_trigger
13 | BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
14 | FOR EACH ROW EXECUTE PROCEDURE versioning(
15 | 'sys_period', 'subscriptions_history', true
16 | );
17 |
18 |
--------------------------------------------------------------------------------
/system_time_function.sql:
--------------------------------------------------------------------------------
1 | -- version 1.2.1
2 |
3 | CREATE OR REPLACE FUNCTION set_system_time(user_timestamp timestamptz)
4 | RETURNS void AS $$
5 | DECLARE
6 | custom_system_time text;
7 | BEGIN
8 | IF user_timestamp IS NULL THEN
9 | custom_system_time := null;
10 | ELSE
11 | custom_system_time := TO_CHAR(user_timestamp, 'YYYY-MM-DD HH24:MI:SS');
12 | END IF;
13 |
14 | PERFORM set_config('user_defined.system_time', custom_system_time, false);
15 |
16 | END;
17 | $$ LANGUAGE plpgsql;
18 |
--------------------------------------------------------------------------------
/test/sql/non_equality_types_unchanged_values.sql:
--------------------------------------------------------------------------------
1 | SET client_min_messages TO error;
2 |
3 | CREATE TABLE non_equality_types_unchanged_values (json json, sys_period tstzrange);
4 |
5 | CREATE TRIGGER versioning_trigger
6 | BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types_unchanged_values
7 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types_unchanged_values', false, true);
8 |
9 | INSERT INTO non_equality_types_unchanged_values VALUES ('{"a":1}'::json);
10 |
11 | UPDATE non_equality_types_unchanged_values SET json = '{"a":2}'::json WHERE 1=1;
12 |
--------------------------------------------------------------------------------
/test/expected/non_equality_types_unchanged_values.out:
--------------------------------------------------------------------------------
1 | SET client_min_messages TO error;
2 | CREATE TABLE non_equality_types_unchanged_values (json json, sys_period tstzrange);
3 | CREATE TRIGGER versioning_trigger
4 | BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types_unchanged_values
5 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types_unchanged_values', false, true);
6 | INSERT INTO non_equality_types_unchanged_values VALUES ('{"a":1}'::json);
7 | UPDATE non_equality_types_unchanged_values SET json = '{"a":2}'::json WHERE 1=1;
8 | ERROR: could not identify an equality operator for type json
9 |
--------------------------------------------------------------------------------
/scripts/update-version.js:
--------------------------------------------------------------------------------
1 | var { readFileSync, writeFileSync } = require("fs");
2 |
3 | console.log("UPDATING VERSION ...");
4 |
5 | const packageJson = require("../package.json");
6 | const newVersion = packageJson.version;
7 | const files = ["versioning_function", "versioning_function_nochecks", "system_time_function"];
8 |
9 | files.forEach((fileName) => {
10 | const data = readFileSync(__dirname + `/../${fileName}.sql`, {
11 | encoding: "utf8",
12 | });
13 |
14 | const updated = data.replace(
15 | /-- version \d+.\d+.\d+/g,
16 | `-- version ${newVersion}`
17 | );
18 |
19 | writeFileSync(__dirname + `/../${fileName}.sql`, updated, {
20 | encoding: "utf8",
21 | });
22 | });
23 |
24 | console.log("VERSION UPDATED!");
25 |
--------------------------------------------------------------------------------
/package.json:
--------------------------------------------------------------------------------
1 | {
2 | "name": "temporal_tables",
3 | "version": "1.2.1",
4 | "description": "A postgresql temporal_tables extension in PL/pgSQL",
5 | "repository": {
6 | "type": "git",
7 | "url": "git+https://github.com/nearform/temporal_tables.git"
8 | },
9 | "scripts": {
10 | "db:start": "docker compose up -d",
11 | "db:stop": "docker compose down",
12 | "update-version": "node ./scripts/update-version.js",
13 | "test": "PGHOST=localhost PGPORT=5432 PGUSER=postgres PGPASSWORD=password make run_test"
14 | },
15 | "keywords": [],
16 | "author": "",
17 | "license": "ISC",
18 | "bugs": {
19 | "url": "https://github.com/nearform/temporal_tables/issues"
20 | },
21 | "homepage": "https://github.com/nearform/temporal_tables#readme"
22 | }
23 |
--------------------------------------------------------------------------------
/.github/workflows/release.yml:
--------------------------------------------------------------------------------
1 | name: release
2 | on:
3 | workflow_dispatch:
4 | inputs:
5 | semver:
6 | description: The semver to use
7 | required: true
8 | default: patch
9 | type: choice
10 | options:
11 | - patch
12 | - minor
13 | - major
14 | pull_request:
15 | types: [closed]
16 |
17 | jobs:
18 | release:
19 | permissions:
20 | contents: write
21 | issues: write
22 | pull-requests: write
23 | runs-on: ubuntu-latest
24 | steps:
25 | - uses: nearform-actions/optic-release-automation-action@v4
26 | with:
27 | semver: ${{ github.event.inputs.semver }}
28 | commit-message: 'chore: release {version}'
29 | build-command: |
30 | npm run update-version
31 |
--------------------------------------------------------------------------------
/test/sql/noop_update.sql:
--------------------------------------------------------------------------------
1 | -- No-op Update Test
2 | CREATE TABLE versioning_noop (a bigint, "b b" date, sys_period tstzrange);
3 |
4 | -- Insert initial data.
5 | INSERT INTO versioning_noop (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE versioning_noop_history (a bigint, "b b" date, sys_period tstzrange);
8 |
9 | CREATE TRIGGER versioning_noop_trigger
10 | BEFORE INSERT OR UPDATE OR DELETE ON versioning_noop
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_noop_history', false, true, true);
12 |
13 | -- Test no-op update (the row is updated without any value changes).
14 | BEGIN;
15 |
16 | UPDATE versioning_noop SET a = 1, "b b" = '2020-01-01' WHERE a = 1;
17 |
18 | -- Check that no history record was created.
19 | SELECT * FROM versioning_noop_history; -- Expecting 0 rows in history.
20 |
21 | COMMIT;
22 |
23 | -- Cleanup
24 | DROP TABLE versioning_noop;
25 | DROP TABLE versioning_noop_history;
26 |
--------------------------------------------------------------------------------
/test/expected/noop_update.out:
--------------------------------------------------------------------------------
1 | -- No-op Update Test
2 | CREATE TABLE versioning_noop (a bigint, "b b" date, sys_period tstzrange);
3 | -- Insert initial data.
4 | INSERT INTO versioning_noop (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
5 | CREATE TABLE versioning_noop_history (a bigint, "b b" date, sys_period tstzrange);
6 | CREATE TRIGGER versioning_noop_trigger
7 | BEFORE INSERT OR UPDATE OR DELETE ON versioning_noop
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_noop_history', false, true, true);
9 | -- Test no-op update (the row is updated without any value changes).
10 | BEGIN;
11 | UPDATE versioning_noop SET a = 1, "b b" = '2020-01-01' WHERE a = 1;
12 | -- Check that no history record was created.
13 | SELECT * FROM versioning_noop_history; -- Expecting 0 rows in history.
14 | a | b b | sys_period
15 | ---+-----+------------
16 | (0 rows)
17 |
18 | COMMIT;
19 | -- Cleanup
20 | DROP TABLE versioning_noop;
21 | DROP TABLE versioning_noop_history;
22 |
--------------------------------------------------------------------------------
/test/sql/versioning_rollback_include_current_version_in_history.sql:
--------------------------------------------------------------------------------
1 | -- Rollback Behavior Test
2 | CREATE TABLE versioning_rollback (a bigint, "b b" date, sys_period tstzrange);
3 |
4 | -- Insert initial data.
5 | INSERT INTO versioning_rollback (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE versioning_rollback_history (a bigint, "b b" date, sys_period tstzrange);
8 |
9 | CREATE TRIGGER versioning_rollback_trigger
10 | BEFORE INSERT OR UPDATE OR DELETE ON versioning_rollback
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_rollback_history', false, false, true);
12 |
13 | -- Test rollback during update.
14 | BEGIN;
15 |
16 | UPDATE versioning_rollback SET a = 2 WHERE a = 1;
17 |
18 | -- Rollback the transaction.
19 | ROLLBACK;
20 |
21 | -- Ensure no history record was created.
22 | SELECT * FROM versioning_rollback_history; -- Expecting 0 rows in history.
23 |
24 | -- Ensure original data is unchanged.
25 | SELECT * FROM versioning_rollback; -- Expecting original value a = 1.
26 |
27 | -- Cleanup
28 | DROP TABLE versioning_rollback;
29 | DROP TABLE versioning_rollback_history;
30 |
--------------------------------------------------------------------------------
/.github/workflows/ci.yml:
--------------------------------------------------------------------------------
1 | name: ci
2 |
3 | on: [push, pull_request]
4 |
5 | env:
6 | CI: true
7 | PGHOST: localhost
8 | PGPORT: 5432
9 | PGUSER: postgres
10 | PGPASSWORD: postgres
11 |
12 | jobs:
13 | test:
14 | runs-on: ubuntu-latest
15 |
16 | services:
17 | postgres:
18 | image: ${{ matrix.pg }}
19 | env:
20 | POSTGRES_PASSWORD: postgres
21 | # Set health checks to wait until postgres has started
22 | options: >-
23 | --health-cmd pg_isready
24 | --health-interval 10s
25 | --health-timeout 5s
26 | --health-retries 5
27 | ports:
28 | - 5432:5432
29 |
30 | strategy:
31 | matrix:
32 | pg: ["postgres:9.5-alpine", "postgres:9.6-alpine", "postgres:10-alpine", "postgres:11-alpine", "postgres:12-alpine", "postgres:13-alpine", "postgres:14-alpine", "postgres:15-alpine", "postgres:16-alpine", "postgres:17-alpine"]
33 |
34 | steps:
35 | - uses: actions/checkout@v5
36 |
37 | - name: Run tests
38 | run: |
39 | make run_test
40 |
41 | - name: Run tests no check
42 | run: |
43 | make run_test_nochecks
44 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Copyright (c) 2016-2017 Nearform and contributors
4 |
5 | Contributors listed at https://github.com/nearform/temporal_tables#the-team and in
6 | the README file.
7 |
8 | Permission is hereby granted, free of charge, to any person obtaining a copy
9 | of this software and associated documentation files (the "Software"), to deal
10 | in the Software without restriction, including without limitation the rights
11 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
12 | copies of the Software, and to permit persons to whom the Software is
13 | furnished to do so, subject to the following conditions:
14 |
15 | The above copyright notice and this permission notice shall be included in all
16 | copies or substantial portions of the Software.
17 |
18 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
19 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
20 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
21 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
22 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
23 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
24 | SOFTWARE.
25 |
--------------------------------------------------------------------------------
/test/expected/versioning_rollback_include_current_version_in_history.out:
--------------------------------------------------------------------------------
1 | -- Rollback Behavior Test
2 | CREATE TABLE versioning_rollback (a bigint, "b b" date, sys_period tstzrange);
3 | -- Insert initial data.
4 | INSERT INTO versioning_rollback (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
5 | CREATE TABLE versioning_rollback_history (a bigint, "b b" date, sys_period tstzrange);
6 | CREATE TRIGGER versioning_rollback_trigger
7 | BEFORE INSERT OR UPDATE OR DELETE ON versioning_rollback
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_rollback_history', false, false, true);
9 | -- Test rollback during update.
10 | BEGIN;
11 | UPDATE versioning_rollback SET a = 2 WHERE a = 1;
12 | -- Rollback the transaction.
13 | ROLLBACK;
14 | -- Ensure no history record was created.
15 | SELECT * FROM versioning_rollback_history; -- Expecting 0 rows in history.
16 | a | b b | sys_period
17 | ---+-----+------------
18 | (0 rows)
19 |
20 | -- Ensure original data is unchanged.
21 | SELECT * FROM versioning_rollback; -- Expecting original value a = 1.
22 | a | b b | sys_period
23 | ---+------------+-----------------------------------
24 | 1 | 01-01-2020 | ["Sat Jan 01 00:00:00 2000 UTC",)
25 | (1 row)
26 |
27 | -- Cleanup
28 | DROP TABLE versioning_rollback;
29 | DROP TABLE versioning_rollback_history;
30 |
--------------------------------------------------------------------------------
/test/sql/unchanged_version_values.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange);
2 |
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
5 |
6 | CREATE TABLE versioning_history (b bigint, sys_period tstzrange);
7 |
8 | CREATE TRIGGER versioning_trigger
9 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
10 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false, true);
11 |
12 | -- Update with no changes that would affect history
13 | BEGIN;
14 |
15 | UPDATE versioning SET a = 3;
16 |
17 | SELECT a, b FROM versioning ORDER BY a, sys_period;
18 |
19 | SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period;
20 |
21 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
22 |
23 | COMMIT;
24 |
25 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
26 | SELECT pg_sleep(0.1);
27 |
28 | -- Update with changes that would affect history.
29 | BEGIN;
30 |
31 | UPDATE versioning SET b = 3;
32 |
33 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
34 |
35 | SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period;
36 |
37 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
38 |
39 | COMMIT;
40 |
41 | DROP TABLE versioning;
42 | DROP TABLE versioning_history;
--------------------------------------------------------------------------------
/test/sql/unchanged_values.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange);
2 |
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO versioning (a, b, sys_period) VALUES (1, 1, tstzrange('-infinity', NULL));
5 | INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE versioning_history (a bigint, b bigint, sys_period tstzrange);
8 |
9 | CREATE TRIGGER versioning_trigger
10 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false, true);
12 |
13 | -- Update with no changes.
14 | BEGIN;
15 |
16 | UPDATE versioning SET b = 2 WHERE a = 2;
17 |
18 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
19 |
20 | SELECT a, b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
21 |
22 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
23 |
24 | COMMIT;
25 |
26 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
27 | SELECT pg_sleep(0.1);
28 |
29 | -- Update with actual changes.
30 | BEGIN;
31 |
32 | UPDATE versioning SET b = 3 WHERE a = 2;
33 |
34 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
35 |
36 | SELECT a, b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
37 |
38 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
39 |
40 | COMMIT;
41 |
42 | DROP TABLE versioning;
43 | DROP TABLE versioning_history;
--------------------------------------------------------------------------------
/test/runTestNochecks.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 |
3 | export PGDATESTYLE="Postgres, MDY";
4 |
5 | createdb temporal_tables_test
6 | psql temporal_tables_test -q -c "ALTER DATABASE temporal_tables_test SET timezone TO 'UTC';"
7 | psql temporal_tables_test -q -f versioning_function_nochecks.sql
8 | psql temporal_tables_test -q -f system_time_function.sql
9 |
10 | mkdir -p test/result
11 |
12 | FILES_DIFFERENT=false
13 |
14 | REMOTE_TESTS="
15 | combinations structure versioning
16 | versioning_custom_system_time
17 | "
18 |
19 | ./test/runRemoteTests.sh "$REMOTE_TESTS"
20 | REMOTE_TESTS_RESULT=$?
21 |
22 | if [ "$REMOTE_TESTS_RESULT" -eq 1 ]; then
23 | # Atleast one of the remote tests failed.
24 | FILES_DIFFERENT=true
25 | fi
26 |
27 | TESTS="
28 | upper_case different_schema unchanged_values unchanged_version_values
29 | non_equality_types non_equality_types_unchanged_values
30 | set_system_time versioning_including_current_version_in_history
31 | versioning_rollback_include_current_version_in_history noop_update
32 | migration_mode increment_version increment_version_with_include_current_version_in_history
33 | "
34 |
35 | for name in $TESTS; do
36 | echo ""
37 | echo $name
38 | echo ""
39 | psql temporal_tables_test -X -a -q --set=SHOW_CONTEXT=never < test/sql/$name.sql > test/result/$name.out 2>&1
40 | DIFF_OUTPUT=$(diff -b test/expected/$name.out test/result/$name.out)
41 | echo "$DIFF_OUTPUT"
42 |
43 | if [ -n "$DIFF_OUTPUT" ]; then
44 | # Expected and actual files are different.
45 | FILES_DIFFERENT=true
46 | fi
47 | done
48 |
49 | psql -q -c "drop database temporal_tables_test;"
50 |
51 | # Exit with 1 if any of the test case failed.
52 | if [ "$FILES_DIFFERENT" = true ]; then
53 | exit 1
54 | fi
55 |
--------------------------------------------------------------------------------
/test/expected/unchanged_version_values.out:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange);
2 | -- Insert some data before versioning is enabled.
3 | INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
4 | CREATE TABLE versioning_history (b bigint, sys_period tstzrange);
5 | CREATE TRIGGER versioning_trigger
6 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
7 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false, true);
8 | -- Update with no changes that would affect history
9 | BEGIN;
10 | UPDATE versioning SET a = 3;
11 | SELECT a, b FROM versioning ORDER BY a, sys_period;
12 | a | b
13 | ---+---
14 | 3 | 2
15 | (1 row)
16 |
17 | SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period;
18 | b | ?column?
19 | ---+----------
20 | (0 rows)
21 |
22 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
23 | a | b
24 | ---+---
25 | (0 rows)
26 |
27 | COMMIT;
28 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
29 | SELECT pg_sleep(0.1);
30 | pg_sleep
31 | ----------
32 |
33 | (1 row)
34 |
35 | -- Update with changes that would affect history.
36 | BEGIN;
37 | UPDATE versioning SET b = 3;
38 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
39 | a | b | ?column?
40 | ---+---+----------
41 | 3 | 3 | t
42 | (1 row)
43 |
44 | SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period;
45 | b | ?column?
46 | ---+----------
47 | 2 | t
48 | (1 row)
49 |
50 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
51 | a | b
52 | ---+---
53 | 3 | 3
54 | (1 row)
55 |
56 | COMMIT;
57 | DROP TABLE versioning;
58 | DROP TABLE versioning_history;
59 |
--------------------------------------------------------------------------------
/test/runTest.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 |
3 | export PGDATESTYLE="Postgres, MDY";
4 |
5 | createdb temporal_tables_test
6 | psql temporal_tables_test -q -c "ALTER DATABASE temporal_tables_test SET timezone TO 'UTC';"
7 | psql temporal_tables_test -q -f versioning_function.sql
8 | psql temporal_tables_test -q -f system_time_function.sql
9 |
10 | mkdir -p test/result
11 |
12 | FILES_DIFFERENT=false
13 |
14 | REMOTE_TESTS="
15 | combinations structure versioning
16 | invalid_system_period invalid_system_period_values invalid_types
17 | no_history_system_period no_history_table no_system_period
18 | versioning_custom_system_time
19 | "
20 |
21 | ./test/runRemoteTests.sh "$REMOTE_TESTS"
22 | REMOTE_TESTS_RESULT=$?
23 |
24 | if [ "$REMOTE_TESTS_RESULT" -eq 1 ]; then
25 | # Atleast one of the remote tests failed.
26 | FILES_DIFFERENT=true
27 | fi
28 |
29 | TESTS="
30 | upper_case different_schema unchanged_values unchanged_version_values
31 | non_equality_types non_equality_types_unchanged_values
32 | set_system_time versioning_including_current_version_in_history
33 | versioning_rollback_include_current_version_in_history noop_update
34 | migration_mode increment_version increment_version_with_include_current_version_in_history
35 | "
36 |
37 | for name in $TESTS; do
38 | echo ""
39 | echo $name
40 | echo ""
41 | psql temporal_tables_test -X -a -q --set=SHOW_CONTEXT=never < test/sql/$name.sql > test/result/$name.out 2>&1
42 | DIFF_OUTPUT=$(diff -b test/expected/$name.out test/result/$name.out)
43 | echo "$DIFF_OUTPUT"
44 |
45 | if [ -n "$DIFF_OUTPUT" ]; then
46 | # Expected and actual files are different.
47 | FILES_DIFFERENT=true
48 | fi
49 | done
50 |
51 | psql -q -c "drop database temporal_tables_test;"
52 |
53 | # Exit with 1 if any of the test case failed.
54 | if [ "$FILES_DIFFERENT" = true ]; then
55 | exit 1
56 | fi
57 |
--------------------------------------------------------------------------------
/test/runRemoteTests.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 |
3 | echo "Downloading remote files"
4 |
5 | REMOTE_BASE_PATH="https://raw.githubusercontent.com/arkhipov/temporal_tables/refs/heads/master/"
6 | REMOTE_SQL_FILE_URL="${REMOTE_BASE_PATH}sql/"
7 | LOCAL_SQL_PATH="test/remote_sql/"
8 | REMOTE_OUT_FILE_URL="${REMOTE_BASE_PATH}expected/"
9 | LOCAL_OUT_PATH="test/remote_expected/"
10 | LOCAL_RESULT_PATH="test/remote_result/"
11 | FILES_DIFFERENT=false
12 |
13 | # Create test folders if not available.
14 | mkdir -p $LOCAL_SQL_PATH
15 | mkdir -p $LOCAL_OUT_PATH
16 | mkdir -p $LOCAL_RESULT_PATH
17 |
18 | # Download the remote test files.
19 | REMOTE_TESTS="$1"
20 | REMOTE_FILES_TO_TEST=" "
21 | for name in $REMOTE_TESTS; do
22 | curl -f -o ${LOCAL_SQL_PATH}${name}.sql ${REMOTE_SQL_FILE_URL}${name}.sql
23 | SQL_STATUS=$?
24 |
25 | curl -f -o ${LOCAL_OUT_PATH}${name}.out ${REMOTE_OUT_FILE_URL}${name}.out
26 | OUT_STATUS=$?
27 |
28 | if [ "$SQL_STATUS" -eq 0 ] && [ "$OUT_STATUS" -eq 0 ]; then
29 | echo "Remote files downloaded successfully for ${name}"
30 | REMOTE_FILES_TO_TEST="${REMOTE_FILES_TO_TEST}${name} "
31 | else
32 | echo "Remote files download failed for ${name}"
33 | fi
34 | done
35 |
36 | echo $REMOTE_FILES_TO_TEST
37 |
38 | # Run the tests for the downloaded files.
39 | for name in $REMOTE_FILES_TO_TEST; do
40 | echo ""
41 | echo $name
42 | echo ""
43 | psql temporal_tables_test -X -a -q --set=SHOW_CONTEXT=never < test/remote_sql/$name.sql > test/remote_result/$name.out 2>&1
44 | DIFF_OUTPUT=$(diff -b test/remote_expected/$name.out test/remote_result/$name.out)
45 | echo "$DIFF_OUTPUT"
46 |
47 | if [ -n "$DIFF_OUTPUT" ]; then
48 | # Expected and actual files are different.
49 | FILES_DIFFERENT=true
50 | fi
51 | done
52 |
53 | # Exit with 1 if any of the test case failed.
54 | if [ "$FILES_DIFFERENT" = true ]; then
55 | exit 1
56 | fi
57 |
--------------------------------------------------------------------------------
/test/sql/increment_version.sql:
--------------------------------------------------------------------------------
1 | -- Test for the increment_version feature
2 |
3 | CREATE TABLE increment_version_test (
4 | id serial primary key,
5 | data text,
6 | version integer,
7 | sys_period tstzrange
8 | );
9 |
10 | CREATE TABLE increment_version_test_history (
11 | id integer,
12 | data text,
13 | version integer,
14 | sys_period tstzrange
15 | );
16 |
17 | -- Enable the versioning trigger with increment_version set to true
18 | CREATE TRIGGER versioning_trigger
19 | BEFORE INSERT OR UPDATE OR DELETE ON increment_version_test
20 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'increment_version_test_history', 'false', 'false', 'false', 'false', 'true', 'version');
21 |
22 | -- Test INSERT
23 | BEGIN;
24 | INSERT INTO increment_version_test (data) VALUES ('initial version');
25 | SELECT data, version FROM increment_version_test;
26 | SELECT data, version FROM increment_version_test_history;
27 | COMMIT;
28 |
29 | -- Test UPDATE
30 | BEGIN;
31 | UPDATE increment_version_test SET data = 'second version' WHERE id = 1;
32 | SELECT data, version FROM increment_version_test;
33 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history;
34 | COMMIT;
35 |
36 | -- Test another UPDATE
37 | BEGIN;
38 | UPDATE increment_version_test SET data = 'third version' WHERE id = 1;
39 | SELECT data, version FROM increment_version_test;
40 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history ORDER BY version;
41 | COMMIT;
42 |
43 | -- Test DELETE
44 | BEGIN;
45 | DELETE FROM increment_version_test WHERE id = 1;
46 | SELECT * FROM increment_version_test;
47 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history ORDER BY version;
48 | COMMIT;
49 |
50 | DROP TABLE increment_version_test;
51 | DROP TABLE increment_version_test_history;
52 |
--------------------------------------------------------------------------------
/test/sql/set_system_time.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
2 |
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
5 | INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
8 |
9 | CREATE TRIGGER versioning_trigger
10 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false);
12 |
13 | -- Insert.
14 | BEGIN;
15 |
16 | SELECT set_system_time('2001-01-01 22:59:59');
17 |
18 | INSERT INTO versioning (a) VALUES (3);
19 |
20 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
21 |
22 | SELECT * FROM versioning_history ORDER BY a, sys_period;
23 |
24 | COMMIT;
25 | -- Update.
26 | BEGIN;
27 |
28 | SELECT set_system_time('2001-02-01 22:59:59');
29 |
30 | UPDATE versioning SET a = 4 WHERE a = 3;
31 |
32 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
33 |
34 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
35 |
36 | COMMIT;
37 | BEGIN;
38 |
39 | SELECT set_system_time('2001-03-01 22:59:59');
40 |
41 | UPDATE versioning SET a = 5 WHERE a = 4;
42 | UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
43 |
44 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
45 |
46 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
47 |
48 | COMMIT;
49 |
50 | -- Delete.
51 | BEGIN;
52 |
53 | SELECT set_system_time('2001-04-01 22:59:59');
54 |
55 | DELETE FROM versioning WHERE a = 4;
56 |
57 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
58 |
59 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
60 |
61 | COMMIT;
62 |
63 | DROP TABLE versioning;
64 | DROP TABLE versioning_history;
65 |
--------------------------------------------------------------------------------
/test/expected/unchanged_values.out:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange);
2 | -- Insert some data before versioning is enabled.
3 | INSERT INTO versioning (a, b, sys_period) VALUES (1, 1, tstzrange('-infinity', NULL));
4 | INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
5 | CREATE TABLE versioning_history (a bigint, b bigint, sys_period tstzrange);
6 | CREATE TRIGGER versioning_trigger
7 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false, true);
9 | -- Update with no changes.
10 | BEGIN;
11 | UPDATE versioning SET b = 2 WHERE a = 2;
12 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
13 | a | b | ?column?
14 | ---+---+----------
15 | 1 | 1 | f
16 | 2 | 2 | f
17 | (2 rows)
18 |
19 | SELECT a, b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
20 | a | b | ?column?
21 | ---+---+----------
22 | (0 rows)
23 |
24 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
25 | a | b
26 | ---+---
27 | (0 rows)
28 |
29 | COMMIT;
30 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
31 | SELECT pg_sleep(0.1);
32 | pg_sleep
33 | ----------
34 |
35 | (1 row)
36 |
37 | -- Update with actual changes.
38 | BEGIN;
39 | UPDATE versioning SET b = 3 WHERE a = 2;
40 | SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
41 | a | b | ?column?
42 | ---+---+----------
43 | 1 | 1 | f
44 | 2 | 3 | t
45 | (2 rows)
46 |
47 | SELECT a, b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
48 | a | b | ?column?
49 | ---+---+----------
50 | 2 | 2 | t
51 | (1 row)
52 |
53 | SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
54 | a | b
55 | ---+---
56 | 2 | 3
57 | (1 row)
58 |
59 | COMMIT;
60 | DROP TABLE versioning;
61 | DROP TABLE versioning_history;
--------------------------------------------------------------------------------
/test/sql/increment_version_with_include_current_version_in_history.sql:
--------------------------------------------------------------------------------
1 | -- Test for the increment_version feature with include_current_version_in_history=true
2 |
3 | CREATE TABLE increment_version_with_history_test (
4 | id serial primary key,
5 | data text,
6 | version integer,
7 | sys_period tstzrange
8 | );
9 |
10 | CREATE TABLE increment_version_with_history_test_history (
11 | id integer,
12 | data text,
13 | version integer,
14 | sys_period tstzrange
15 | );
16 |
17 | -- Enable the versioning trigger with increment_version and include_current_version_in_history set to true
18 | CREATE TRIGGER versioning_trigger
19 | BEFORE INSERT OR UPDATE OR DELETE ON increment_version_with_history_test
20 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'increment_version_with_history_test_history', 'false', 'false', 'true', 'false', 'true', 'version');
21 |
22 | -- Test INSERT
23 | BEGIN;
24 | INSERT INTO increment_version_with_history_test (data) VALUES ('initial version');
25 | SELECT data, version FROM increment_version_with_history_test;
26 | SELECT data, version FROM increment_version_with_history_test_history;
27 | COMMIT;
28 |
29 | -- Test UPDATE
30 | BEGIN;
31 | UPDATE increment_version_with_history_test SET data = 'second version' WHERE id = 1;
32 | SELECT data, version FROM increment_version_with_history_test;
33 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
34 | COMMIT;
35 |
36 | -- Test another UPDATE
37 | BEGIN;
38 | UPDATE increment_version_with_history_test SET data = 'third version' WHERE id = 1;
39 | SELECT data, version FROM increment_version_with_history_test;
40 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
41 | COMMIT;
42 |
43 | -- Test DELETE
44 | BEGIN;
45 | DELETE FROM increment_version_with_history_test WHERE id = 1;
46 | SELECT * FROM increment_version_with_history_test;
47 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
48 | COMMIT;
49 |
50 | DROP TABLE increment_version_with_history_test;
51 | DROP TABLE increment_version_with_history_test_history;
52 |
--------------------------------------------------------------------------------
/Makefile:
--------------------------------------------------------------------------------
1 | run_test:
2 | @echo "\nRunning Tests\n"
3 | @sh test/runTest.sh
4 |
5 | run_test_nochecks:
6 | @echo "\nRunning Tests - No Check\n"
7 | @sh test/runTestNochecks.sh
8 |
9 |
10 | performance_test:
11 | @echo "\nDB Setup\n"
12 | @createdb temporal_tables_test
13 | @psql temporal_tables_test -q -f versioning_function.sql
14 | @psql temporal_tables_test -q -f system_time_function.sql
15 | @psql temporal_tables_test -q -f test/performance/setup.sql
16 |
17 | @echo "\nRun Test\n"
18 |
19 | @echo "Insert"
20 | @psql temporal_tables_test -q -f test/performance/insert.sql
21 |
22 | @echo "Update"
23 | @psql temporal_tables_test -q -f test/performance/update.sql
24 |
25 | @echo "Delete"
26 | @psql temporal_tables_test -q -f test/performance/delete.sql
27 |
28 | @echo "\nDB teardown\n"
29 | @psql temporal_tables_test -q -f test/performance/teardown.sql
30 | @psql -q -c "drop database temporal_tables_test;"
31 |
32 | performance_test_nochecks:
33 | @echo "\nDB Setup\n"
34 | @createdb temporal_tables_test
35 | @psql temporal_tables_test -q -f versioning_function_nochecks.sql
36 | @psql temporal_tables_test -q -f system_time_function.sql
37 | @psql temporal_tables_test -q -f test/performance/setup.sql
38 |
39 | @echo "\nRun Test for NOCHECKS version\n"
40 |
41 | @echo "Insert"
42 | @psql temporal_tables_test -q -f test/performance/insert.sql
43 |
44 | @echo "Update"
45 | @psql temporal_tables_test -q -f test/performance/update.sql
46 |
47 | @echo "Delete"
48 | @psql temporal_tables_test -q -f test/performance/delete.sql
49 |
50 | @echo "\nDB teardown\n"
51 | @psql temporal_tables_test -q -f test/performance/teardown.sql
52 | @psql -q -c "drop database temporal_tables_test;"
53 |
54 |
55 | performance_test_original:
56 | @echo "\nDB Setup\n"
57 | @createdb temporal_tables_test
58 | @psql temporal_tables_test -q -c "create extension temporal_tables"
59 | @psql temporal_tables_test -q -f test/performance/setup.sql
60 |
61 | @echo "\nRun Test for ORIGINAL version\n"
62 |
63 | @echo "Insert"
64 | @psql temporal_tables_test -q -f test/performance/insert.sql
65 |
66 | @echo "Update"
67 | @psql temporal_tables_test -q -f test/performance/update.sql
68 |
69 | @echo "Delete"
70 | @psql temporal_tables_test -q -f test/performance/delete.sql
71 |
72 | @echo "\nDB teardown\n"
73 | @psql -q -c "drop database temporal_tables_test;"
74 |
--------------------------------------------------------------------------------
/test/expected/invalid_set_system_time.out:
--------------------------------------------------------------------------------
1 | -- Invalid dates
2 | SELECT set_system_time('2022-13-01 22:59:59');
3 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
4 | SELECT set_system_time('22-13-01 22:59:59');
5 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
6 | SELECT set_system_time('2022-12-99 22:59:59');
7 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
8 | -- Invalid time
9 | SELECT set_system_time('2022-01-11 99:59:59');
10 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
11 | SELECT set_system_time('2022-01-11 22:99:59');
12 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
13 | SELECT set_system_time('2022-01-11 22:59:99');
14 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
15 | SELECT set_system_time('2022-01-11 22:59');
16 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
17 | SELECT set_system_time('2022-01-11 22');
18 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
19 | -- Invalid values
20 | SELECT set_system_time('Invalid string value');
21 | ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH24:MI:SS.MS.US (hours are in 24-hour format 00-23, MS and US are optional)
22 | SELECT set_system_time(123);
23 | ERROR: function set_system_time(integer) does not exist
24 | LINE 1: SELECT set_system_time(123);
25 | ^
26 | HINT: No function matches the given name and argument types. You might need to add explicit type casts.
27 | SELECT set_system_time();
28 | ERROR: function set_system_time() does not exist
29 | LINE 1: SELECT set_system_time();
30 | ^
31 | HINT: No function matches the given name and argument types. You might need to add explicit type casts.
32 |
--------------------------------------------------------------------------------
/test/expected/increment_version.out:
--------------------------------------------------------------------------------
1 | -- Test for the increment_version feature
2 | CREATE TABLE increment_version_test (
3 | id serial primary key,
4 | data text,
5 | version integer,
6 | sys_period tstzrange
7 | );
8 | CREATE TABLE increment_version_test_history (
9 | id integer,
10 | data text,
11 | version integer,
12 | sys_period tstzrange
13 | );
14 | -- Enable the versioning trigger with increment_version set to true
15 | CREATE TRIGGER versioning_trigger
16 | BEFORE INSERT OR UPDATE OR DELETE ON increment_version_test
17 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'increment_version_test_history', 'false', 'false', 'false', 'false', 'true', 'version');
18 | -- Test INSERT
19 | BEGIN;
20 | INSERT INTO increment_version_test (data) VALUES ('initial version');
21 | SELECT data, version FROM increment_version_test;
22 | data | version
23 | -----------------+---------
24 | initial version | 1
25 | (1 row)
26 |
27 | SELECT data, version FROM increment_version_test_history;
28 | data | version
29 | ------+---------
30 | (0 rows)
31 |
32 | COMMIT;
33 | -- Test UPDATE
34 | BEGIN;
35 | UPDATE increment_version_test SET data = 'second version' WHERE id = 1;
36 | SELECT data, version FROM increment_version_test;
37 | data | version
38 | ----------------+---------
39 | second version | 2
40 | (1 row)
41 |
42 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history;
43 | data | version | history_ended
44 | -----------------+---------+---------------
45 | initial version | 1 | t
46 | (1 row)
47 |
48 | COMMIT;
49 | -- Test another UPDATE
50 | BEGIN;
51 | UPDATE increment_version_test SET data = 'third version' WHERE id = 1;
52 | SELECT data, version FROM increment_version_test;
53 | data | version
54 | ---------------+---------
55 | third version | 3
56 | (1 row)
57 |
58 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history ORDER BY version;
59 | data | version | history_ended
60 | -----------------+---------+---------------
61 | initial version | 1 | t
62 | second version | 2 | t
63 | (2 rows)
64 |
65 | COMMIT;
66 | -- Test DELETE
67 | BEGIN;
68 | DELETE FROM increment_version_test WHERE id = 1;
69 | SELECT * FROM increment_version_test;
70 | id | data | version | sys_period
71 | ----+------+---------+------------
72 | (0 rows)
73 |
74 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_test_history ORDER BY version;
75 | data | version | history_ended
76 | -----------------+---------+---------------
77 | initial version | 1 | t
78 | second version | 2 | t
79 | third version | 3 | t
80 | (3 rows)
81 |
82 | COMMIT;
83 | DROP TABLE increment_version_test;
84 | DROP TABLE increment_version_test_history;
--------------------------------------------------------------------------------
/test/sql/upper_case.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE "Versioning" (a bigint, "b b" date, sys_period tstzrange);
2 |
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO "Versioning" (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
5 | INSERT INTO "Versioning" (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE "VersioningHistory" (a bigint, c date, sys_period tstzrange);
8 |
9 | CREATE TRIGGER "VersioningTrigger"
10 | BEFORE INSERT OR UPDATE OR DELETE ON "Versioning"
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', '"VersioningHistory"', false);
12 |
13 | -- Insert.
14 | BEGIN;
15 |
16 | INSERT INTO "Versioning" (a) VALUES (3);
17 |
18 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
19 |
20 | SELECT * FROM "VersioningHistory" ORDER BY a, sys_period;
21 |
22 | COMMIT;
23 |
24 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
25 | SELECT pg_sleep(0.1);
26 |
27 | -- Update.
28 | BEGIN;
29 |
30 | UPDATE "Versioning" SET a = 4 WHERE a = 3;
31 |
32 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
33 |
34 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
35 |
36 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
37 |
38 | COMMIT;
39 |
40 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
41 | SELECT pg_sleep(0.1);
42 |
43 | -- Multiple updates.
44 | BEGIN;
45 |
46 | UPDATE "Versioning" SET a = 5 WHERE a = 4;
47 | UPDATE "Versioning" SET "b b" = '2012-01-01' WHERE a = 5;
48 |
49 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
50 |
51 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
52 |
53 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
54 |
55 | COMMIT;
56 |
57 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
58 | SELECT pg_sleep(0.1);
59 |
60 | -- Delete.
61 | BEGIN;
62 |
63 | DELETE FROM "Versioning" WHERE a = 4;
64 |
65 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
66 |
67 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
68 |
69 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
70 |
71 | END;
72 |
73 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
74 | SELECT pg_sleep(0.1);
75 |
76 | -- Delete.
77 | BEGIN;
78 |
79 | DELETE FROM "Versioning";
80 |
81 | SELECT * FROM "Versioning";
82 |
83 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
84 |
85 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
86 |
87 | END;
88 |
89 | DROP TABLE "Versioning";
90 | DROP TABLE "VersioningHistory";
--------------------------------------------------------------------------------
/test/expected/increment_version_with_include_current_version_in_history.out:
--------------------------------------------------------------------------------
1 | -- Test for the increment_version feature with include_current_version_in_history=true
2 | CREATE TABLE increment_version_with_history_test (
3 | id serial primary key,
4 | data text,
5 | version integer,
6 | sys_period tstzrange
7 | );
8 | CREATE TABLE increment_version_with_history_test_history (
9 | id integer,
10 | data text,
11 | version integer,
12 | sys_period tstzrange
13 | );
14 | -- Enable the versioning trigger with increment_version and include_current_version_in_history set to true
15 | CREATE TRIGGER versioning_trigger
16 | BEFORE INSERT OR UPDATE OR DELETE ON increment_version_with_history_test
17 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'increment_version_with_history_test_history', 'false', 'false', 'true', 'false', 'true', 'version');
18 | -- Test INSERT
19 | BEGIN;
20 | INSERT INTO increment_version_with_history_test (data) VALUES ('initial version');
21 | SELECT data, version FROM increment_version_with_history_test;
22 | data | version
23 | -----------------+---------
24 | initial version | 1
25 | (1 row)
26 |
27 | SELECT data, version FROM increment_version_with_history_test_history;
28 | data | version
29 | -----------------+---------
30 | initial version | 1
31 | (1 row)
32 |
33 | COMMIT;
34 | -- Test UPDATE
35 | BEGIN;
36 | UPDATE increment_version_with_history_test SET data = 'second version' WHERE id = 1;
37 | SELECT data, version FROM increment_version_with_history_test;
38 | data | version
39 | ----------------+---------
40 | second version | 2
41 | (1 row)
42 |
43 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
44 | data | version | history_ended
45 | -----------------+---------+---------------
46 | initial version | 1 | t
47 | second version | 2 | f
48 | (2 rows)
49 |
50 | COMMIT;
51 | -- Test another UPDATE
52 | BEGIN;
53 | UPDATE increment_version_with_history_test SET data = 'third version' WHERE id = 1;
54 | SELECT data, version FROM increment_version_with_history_test;
55 | data | version
56 | ---------------+---------
57 | third version | 3
58 | (1 row)
59 |
60 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
61 | data | version | history_ended
62 | -----------------+---------+---------------
63 | initial version | 1 | t
64 | second version | 2 | t
65 | third version | 3 | f
66 | (3 rows)
67 |
68 | COMMIT;
69 | -- Test DELETE
70 | BEGIN;
71 | DELETE FROM increment_version_with_history_test WHERE id = 1;
72 | SELECT * FROM increment_version_with_history_test;
73 | id | data | version | sys_period
74 | ----+------+---------+------------
75 | (0 rows)
76 |
77 | SELECT data, version, upper(sys_period) IS NOT NULL as history_ended FROM increment_version_with_history_test_history ORDER BY version;
78 | data | version | history_ended
79 | -----------------+---------+---------------
80 | initial version | 1 | t
81 | second version | 2 | t
82 | third version | 3 | t
83 | (3 rows)
84 |
85 | COMMIT;
86 | DROP TABLE increment_version_with_history_test;
87 | DROP TABLE increment_version_with_history_test_history;
88 |
--------------------------------------------------------------------------------
/test/sql/versioning_including_current_version_in_history.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, x bigint, "b b" date, sys_period tstzrange);
2 |
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO versioning (a, x, sys_period) VALUES (1, 1, tstzrange('-infinity', NULL));
5 | INSERT INTO versioning (a, x, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
6 |
7 | CREATE TABLE versioning_history (a bigint, x bigint, c date, sys_period tstzrange);
8 |
9 | CREATE TRIGGER versioning_trigger
10 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
11 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', true, false, true);
12 |
13 | -- Insert.
14 | BEGIN;
15 |
16 | INSERT INTO versioning (a) VALUES (3);
17 |
18 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
19 |
20 | SELECT a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
21 |
22 | COMMIT;
23 |
24 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
25 | SELECT pg_sleep(0.1);
26 |
27 | -- Update.
28 | BEGIN;
29 |
30 | UPDATE versioning SET a = 4, x = 4 WHERE a = 3;
31 |
32 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
33 |
34 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
35 |
36 | SELECT a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
37 |
38 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
39 |
40 | SELECT a, c, lower(sys_period) IS NOT NULL FROM versioning_history ORDER BY a, sys_period;
41 |
42 | COMMIT;
43 |
44 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
45 | SELECT pg_sleep(0.1);
46 |
47 | -- Multiple updates.
48 | BEGIN;
49 |
50 | UPDATE versioning SET a = 5 WHERE a = 4;
51 | UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
52 |
53 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' FROM versioning ORDER BY a, sys_period;
54 |
55 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
56 |
57 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' FROM versioning_history ORDER BY a, sys_period;
58 |
59 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' ORDER BY a, sys_period;
60 |
61 | COMMIT;
62 |
63 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
64 | SELECT pg_sleep(0.1);
65 |
66 | -- Delete.
67 | BEGIN;
68 |
69 | DELETE FROM versioning WHERE a = 4;
70 |
71 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
72 |
73 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
74 |
75 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
76 |
77 | END;
78 |
79 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
80 | SELECT pg_sleep(0.1);
81 |
82 | -- Delete.
83 | BEGIN;
84 |
85 | DELETE FROM versioning;
86 |
87 | SELECT * FROM versioning;
88 |
89 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
90 |
91 | END;
92 |
93 | DROP TABLE versioning;
94 | DROP TABLE versioning_history;
95 |
--------------------------------------------------------------------------------
/test/sql/different_schema.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA IF NOT EXISTS other_schema;
2 |
3 | CREATE TABLE other_schema.versioning (a bigint, "b b" date, sys_period tstzrange);
4 |
5 | -- Insert some data before versioning is enabled.
6 | INSERT INTO other_schema.versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
7 | INSERT INTO other_schema.versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
8 |
9 | CREATE TABLE other_schema.versioning_history (a bigint, c date, sys_period tstzrange);
10 |
11 | CREATE TRIGGER versioning_trigger
12 | BEFORE INSERT OR UPDATE OR DELETE ON other_schema.versioning
13 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'other_schema.versioning_history', false);
14 |
15 | -- Insert.
16 | BEGIN;
17 |
18 | INSERT INTO other_schema.versioning (a) VALUES (3);
19 |
20 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
21 |
22 | SELECT * FROM other_schema.versioning_history ORDER BY a, sys_period;
23 |
24 | COMMIT;
25 |
26 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
27 | SELECT pg_sleep(0.1);
28 |
29 | -- Update.
30 | BEGIN;
31 |
32 | UPDATE other_schema.versioning SET a = 4 WHERE a = 3;
33 |
34 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
35 |
36 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
37 |
38 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
39 |
40 | COMMIT;
41 |
42 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
43 | SELECT pg_sleep(0.1);
44 |
45 | -- Multiple updates.
46 | BEGIN;
47 |
48 | UPDATE other_schema.versioning SET a = 5 WHERE a = 4;
49 | UPDATE other_schema.versioning SET "b b" = '2012-01-01' WHERE a = 5;
50 |
51 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
52 |
53 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
54 |
55 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
56 |
57 | COMMIT;
58 |
59 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
60 | SELECT pg_sleep(0.1);
61 |
62 | -- Delete.
63 | BEGIN;
64 |
65 | DELETE FROM other_schema.versioning WHERE a = 4;
66 |
67 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
68 |
69 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
70 |
71 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
72 |
73 | END;
74 |
75 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
76 | SELECT pg_sleep(0.1);
77 |
78 | -- Delete.
79 | BEGIN;
80 |
81 | DELETE FROM other_schema.versioning;
82 |
83 | SELECT * FROM other_schema.versioning;
84 |
85 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
86 |
87 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
88 |
89 | END;
90 |
91 | DROP TABLE other_schema.versioning;
92 | DROP TABLE other_schema.versioning_history;
93 | DROP SCHEMA other_schema;
--------------------------------------------------------------------------------
/test/sql/migration_mode.sql:
--------------------------------------------------------------------------------
1 | CREATE EXTENSION IF NOT EXISTS pgcrypto;
2 |
3 | -- Create the table with various columns
4 | CREATE TABLE versioned_table (
5 | id SERIAL PRIMARY KEY,
6 | createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
7 | updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
8 | name TEXT,
9 | price NUMERIC(10, 2),
10 | is_active BOOLEAN DEFAULT true,
11 | event_date DATE,
12 | metadata JSONB,
13 | unique_key UUID DEFAULT gen_random_uuid(),
14 | sys_period tstzrange NOT NULL DEFAULT tstzrange(current_timestamp, null)
15 | );
16 |
17 | -- create history table
18 | CREATE TABLE versioned_table_history (LIKE versioned_table);
19 |
20 | -- create trigger for versioning without include current and migration
21 | CREATE TRIGGER versioned_table_versioning BEFORE
22 | INSERT
23 | OR
24 | UPDATE
25 | OR DELETE ON versioned_table FOR EACH ROW EXECUTE PROCEDURE versioning(
26 | 'sys_period',
27 | 'versioned_table_history',
28 | true
29 | );
30 |
31 | --insert 10 records into the table
32 | INSERT INTO
33 | versioned_table (
34 | createdAt,
35 | updatedAt,
36 | name,
37 | price,
38 | is_active,
39 | event_date,
40 | metadata
41 | )
42 | SELECT
43 | CURRENT_TIMESTAMP,
44 | CURRENT_TIMESTAMP,
45 | 'Item ' || gs,
46 | round((random() * 100) :: numeric, 2),
47 | (random() < 0.5),
48 | CURRENT_DATE + (gs % 30),
49 | jsonb_build_object(
50 | 'generated_id',
51 | gs,
52 | 'random_val',
53 | round((random() * 100) :: numeric, 2)
54 | )
55 | FROM
56 | generate_series(1, 10) AS gs;
57 |
58 | -- should return count of 0
59 | SELECT
60 | count(*)
61 | FROM
62 | versioned_table_history;
63 |
64 | -- update a column for all rows
65 | UPDATE
66 | versioned_table
67 | SET
68 | price = round((random() * 100) :: numeric, 2);
69 |
70 | -- should return count of 10
71 | SELECT
72 | count(*)
73 | FROM
74 | versioned_table_history;
75 |
76 | -- drop versioning trigger
77 | DROP TRIGGER IF EXISTS versioned_table_versioning ON versioned_table;
78 |
79 | -- Create trigger with auto_migrate and include_current_version_in_history enabled
80 | CREATE TRIGGER versioned_table_versioning BEFORE
81 | INSERT
82 | OR
83 | UPDATE
84 | OR DELETE ON versioned_table FOR EACH ROW EXECUTE PROCEDURE versioning(
85 | 'sys_period',
86 | 'versioned_table_history',
87 | true,
88 | false,
89 | true,
90 | true
91 | );
92 |
93 | -- update a column for all rows
94 | UPDATE
95 | versioned_table
96 | SET
97 | price = round((random() * 100) :: numeric, 2);
98 |
99 | -- should return count of 30 as the missing history and the current record should now be in the history table
100 | SELECT
101 | count(*)
102 | FROM
103 | versioned_table_history;
104 |
105 | -- should not return any records
106 | SELECT
107 | count(*),
108 | id
109 | FROM
110 | versioned_table_history
111 | GROUP BY
112 | id
113 | HAVING
114 | count(*) != 3;
115 |
116 | -- should return count of 10 for the current record of all 10 rows
117 | SELECT
118 | count(*)
119 | FROM
120 | versioned_table_history
121 | WHERE
122 | upper(sys_period) IS NULL;
123 |
124 | DROP TABLE IF EXISTS versioned_table;
125 |
126 | DROP TABLE IF EXISTS versioned_table_history;
127 |
128 | DROP EXTENSION IF EXISTS pgcrypto;
129 |
--------------------------------------------------------------------------------
/test/expected/migration_mode.out:
--------------------------------------------------------------------------------
1 | CREATE EXTENSION IF NOT EXISTS pgcrypto;
2 | -- Create the table with various columns
3 | CREATE TABLE versioned_table (
4 | id SERIAL PRIMARY KEY,
5 | createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
6 | updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
7 | name TEXT,
8 | price NUMERIC(10, 2),
9 | is_active BOOLEAN DEFAULT true,
10 | event_date DATE,
11 | metadata JSONB,
12 | unique_key UUID DEFAULT gen_random_uuid(),
13 | sys_period tstzrange NOT NULL DEFAULT tstzrange(current_timestamp, null)
14 | );
15 | -- create history table
16 | CREATE TABLE versioned_table_history (LIKE versioned_table);
17 | -- create trigger for versioning without include current and migration
18 | CREATE TRIGGER versioned_table_versioning BEFORE
19 | INSERT
20 | OR
21 | UPDATE
22 | OR DELETE ON versioned_table FOR EACH ROW EXECUTE PROCEDURE versioning(
23 | 'sys_period',
24 | 'versioned_table_history',
25 | true
26 | );
27 | --insert 10 records into the table
28 | INSERT INTO
29 | versioned_table (
30 | createdAt,
31 | updatedAt,
32 | name,
33 | price,
34 | is_active,
35 | event_date,
36 | metadata
37 | )
38 | SELECT
39 | CURRENT_TIMESTAMP,
40 | CURRENT_TIMESTAMP,
41 | 'Item ' || gs,
42 | round((random() * 100) :: numeric, 2),
43 | (random() < 0.5),
44 | CURRENT_DATE + (gs % 30),
45 | jsonb_build_object(
46 | 'generated_id',
47 | gs,
48 | 'random_val',
49 | round((random() * 100) :: numeric, 2)
50 | )
51 | FROM
52 | generate_series(1, 10) AS gs;
53 | -- should return count of 0
54 | SELECT
55 | count(*)
56 | FROM
57 | versioned_table_history;
58 | count
59 | -------
60 | 0
61 | (1 row)
62 |
63 | -- update a column for all rows
64 | UPDATE
65 | versioned_table
66 | SET
67 | price = round((random() * 100) :: numeric, 2);
68 | -- should return count of 10
69 | SELECT
70 | count(*)
71 | FROM
72 | versioned_table_history;
73 | count
74 | -------
75 | 10
76 | (1 row)
77 |
78 | -- drop versioning trigger
79 | DROP TRIGGER IF EXISTS versioned_table_versioning ON versioned_table;
80 | -- Create trigger with auto_migrate and include_current_version_in_history enabled
81 | CREATE TRIGGER versioned_table_versioning BEFORE
82 | INSERT
83 | OR
84 | UPDATE
85 | OR DELETE ON versioned_table FOR EACH ROW EXECUTE PROCEDURE versioning(
86 | 'sys_period',
87 | 'versioned_table_history',
88 | true,
89 | false,
90 | true,
91 | true
92 | );
93 | -- update a column for all rows
94 | UPDATE
95 | versioned_table
96 | SET
97 | price = round((random() * 100) :: numeric, 2);
98 | -- should return count of 30 as the missing history and the current record should now be in the history table
99 | SELECT
100 | count(*)
101 | FROM
102 | versioned_table_history;
103 | count
104 | -------
105 | 30
106 | (1 row)
107 |
108 | -- should not return any records
109 | SELECT
110 | count(*),
111 | id
112 | FROM
113 | versioned_table_history
114 | GROUP BY
115 | id
116 | HAVING
117 | count(*) != 3;
118 | count | id
119 | -------+----
120 | (0 rows)
121 |
122 | -- should return count of 10 for the current record of all 10 rows
123 | SELECT
124 | count(*)
125 | FROM
126 | versioned_table_history
127 | WHERE
128 | upper(sys_period) IS NULL;
129 | count
130 | -------
131 | 10
132 | (1 row)
133 |
134 | DROP TABLE IF EXISTS versioned_table;
135 | DROP TABLE IF EXISTS versioned_table_history;
136 | DROP EXTENSION IF EXISTS pgcrypto;
137 |
--------------------------------------------------------------------------------
/test/expected/set_system_time.out:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
2 | -- Insert some data before versioning is enabled.
3 | INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
4 | INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
5 | CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
6 | CREATE TRIGGER versioning_trigger
7 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false);
9 | -- Insert.
10 | BEGIN;
11 | SELECT set_system_time('2001-01-01 22:59:59');
12 | set_system_time
13 | -----------------
14 |
15 | (1 row)
16 |
17 | INSERT INTO versioning (a) VALUES (3);
18 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
19 | a | b b | sys_period
20 | ---+-----+-----------------------------------
21 | 1 | | [-infinity,)
22 | 2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
23 | 3 | | ["Mon Jan 01 22:59:59 2001 UTC",)
24 | (3 rows)
25 |
26 | SELECT * FROM versioning_history ORDER BY a, sys_period;
27 | a | c | sys_period
28 | ---+---+------------
29 | (0 rows)
30 |
31 | COMMIT;
32 | -- Update.
33 | BEGIN;
34 | SELECT set_system_time('2001-02-01 22:59:59');
35 | set_system_time
36 | -----------------
37 |
38 | (1 row)
39 |
40 | UPDATE versioning SET a = 4 WHERE a = 3;
41 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
42 | a | b b | sys_period
43 | ---+-----+-----------------------------------
44 | 1 | | [-infinity,)
45 | 2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
46 | 4 | | ["Thu Feb 01 22:59:59 2001 UTC",)
47 | (3 rows)
48 |
49 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
50 | a | c | sys_period
51 | ---+---+-----------------------------------------------------------------
52 | 3 | | ["Mon Jan 01 22:59:59 2001 UTC","Thu Feb 01 22:59:59 2001 UTC")
53 | (1 row)
54 |
55 | COMMIT;
56 | BEGIN;
57 | SELECT set_system_time('2001-03-01 22:59:59');
58 | set_system_time
59 | -----------------
60 |
61 | (1 row)
62 |
63 | UPDATE versioning SET a = 5 WHERE a = 4;
64 | UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
65 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
66 | a | b b | sys_period
67 | ---+------------+-----------------------------------
68 | 1 | | [-infinity,)
69 | 2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
70 | 5 | 01-01-2012 | ["Thu Mar 01 22:59:59 2001 UTC",)
71 | (3 rows)
72 |
73 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
74 | a | c | sys_period
75 | ---+---+-----------------------------------------------------------------
76 | 3 | | ["Mon Jan 01 22:59:59 2001 UTC","Thu Feb 01 22:59:59 2001 UTC")
77 | 4 | | ["Thu Feb 01 22:59:59 2001 UTC","Thu Mar 01 22:59:59 2001 UTC")
78 | (2 rows)
79 |
80 | COMMIT;
81 | -- Delete.
82 | BEGIN;
83 | SELECT set_system_time('2001-04-01 22:59:59');
84 | set_system_time
85 | -----------------
86 |
87 | (1 row)
88 |
89 | DELETE FROM versioning WHERE a = 4;
90 | SELECT a, "b b", sys_period FROM versioning ORDER BY a, sys_period;
91 | a | b b | sys_period
92 | ---+------------+-----------------------------------
93 | 1 | | [-infinity,)
94 | 2 | | ["Sat Jan 01 00:00:00 2000 UTC",)
95 | 5 | 01-01-2012 | ["Thu Mar 01 22:59:59 2001 UTC",)
96 | (3 rows)
97 |
98 | SELECT a, c, sys_period FROM versioning_history ORDER BY a, sys_period;
99 | a | c | sys_period
100 | ---+---+-----------------------------------------------------------------
101 | 3 | | ["Mon Jan 01 22:59:59 2001 UTC","Thu Feb 01 22:59:59 2001 UTC")
102 | 4 | | ["Thu Feb 01 22:59:59 2001 UTC","Thu Mar 01 22:59:59 2001 UTC")
103 | (2 rows)
104 |
105 | COMMIT;
106 | DROP TABLE versioning;
107 | DROP TABLE versioning_history;
108 |
--------------------------------------------------------------------------------
/test/expected/upper_case.out:
--------------------------------------------------------------------------------
1 | CREATE TABLE "Versioning" (a bigint, "b b" date, sys_period tstzrange);
2 | -- Insert some data before versioning is enabled.
3 | INSERT INTO "Versioning" (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
4 | INSERT INTO "Versioning" (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
5 | CREATE TABLE "VersioningHistory" (a bigint, c date, sys_period tstzrange);
6 | CREATE TRIGGER "VersioningTrigger"
7 | BEFORE INSERT OR UPDATE OR DELETE ON "Versioning"
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', '"VersioningHistory"', false);
9 | -- Insert.
10 | BEGIN;
11 | INSERT INTO "Versioning" (a) VALUES (3);
12 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
13 | a | b b | ?column?
14 | ---+-----+----------
15 | 1 | | f
16 | 2 | | f
17 | 3 | | t
18 | (3 rows)
19 |
20 | SELECT * FROM "VersioningHistory" ORDER BY a, sys_period;
21 | a | c | sys_period
22 | ---+---+------------
23 | (0 rows)
24 |
25 | COMMIT;
26 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
27 | SELECT pg_sleep(0.1);
28 | pg_sleep
29 | ----------
30 |
31 | (1 row)
32 |
33 | -- Update.
34 | BEGIN;
35 | UPDATE "Versioning" SET a = 4 WHERE a = 3;
36 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
37 | a | b b | ?column?
38 | ---+-----+----------
39 | 1 | | f
40 | 2 | | f
41 | 4 | | t
42 | (3 rows)
43 |
44 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
45 | a | c | ?column?
46 | ---+---+----------
47 | 3 | | t
48 | (1 row)
49 |
50 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
51 | a | b b
52 | ---+-----
53 | 4 |
54 | (1 row)
55 |
56 | COMMIT;
57 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
58 | SELECT pg_sleep(0.1);
59 | pg_sleep
60 | ----------
61 |
62 | (1 row)
63 |
64 | -- Multiple updates.
65 | BEGIN;
66 | UPDATE "Versioning" SET a = 5 WHERE a = 4;
67 | UPDATE "Versioning" SET "b b" = '2012-01-01' WHERE a = 5;
68 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
69 | a | b b | ?column?
70 | ---+------------+----------
71 | 1 | | f
72 | 2 | | f
73 | 5 | 01-01-2012 | t
74 | (3 rows)
75 |
76 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
77 | a | c | ?column?
78 | ---+---+----------
79 | 3 | | f
80 | 4 | | t
81 | (2 rows)
82 |
83 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
84 | a | b b
85 | ---+------------
86 | 5 | 01-01-2012
87 | (1 row)
88 |
89 | COMMIT;
90 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
91 | SELECT pg_sleep(0.1);
92 | pg_sleep
93 | ----------
94 |
95 | (1 row)
96 |
97 | -- Delete.
98 | BEGIN;
99 | DELETE FROM "Versioning" WHERE a = 4;
100 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period;
101 | a | b b | ?column?
102 | ---+------------+----------
103 | 1 | | f
104 | 2 | | f
105 | 5 | 01-01-2012 | f
106 | (3 rows)
107 |
108 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
109 | a | c | ?column?
110 | ---+---+----------
111 | 3 | | f
112 | 4 | | f
113 | (2 rows)
114 |
115 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
116 | a | b b
117 | ---+-----
118 | (0 rows)
119 |
120 | END;
121 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
122 | SELECT pg_sleep(0.1);
123 | pg_sleep
124 | ----------
125 |
126 | (1 row)
127 |
128 | -- Delete.
129 | BEGIN;
130 | DELETE FROM "Versioning";
131 | SELECT * FROM "Versioning";
132 | a | b b | sys_period
133 | ---+-----+------------
134 | (0 rows)
135 |
136 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period;
137 | a | c | ?column?
138 | ---+---+----------
139 | 1 | | t
140 | 2 | | t
141 | 3 | | f
142 | 4 | | f
143 | 5 | | t
144 | (5 rows)
145 |
146 | SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
147 | a | b b
148 | ---+-----
149 | (0 rows)
150 |
151 | END;
152 | DROP TABLE "Versioning";
153 | DROP TABLE "VersioningHistory";
154 |
--------------------------------------------------------------------------------
/test/expected/different_schema.out:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA IF NOT EXISTS other_schema;
2 | CREATE TABLE other_schema.versioning (a bigint, "b b" date, sys_period tstzrange);
3 | -- Insert some data before versioning is enabled.
4 | INSERT INTO other_schema.versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
5 | INSERT INTO other_schema.versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
6 | CREATE TABLE other_schema.versioning_history (a bigint, c date, sys_period tstzrange);
7 | CREATE TRIGGER versioning_trigger
8 | BEFORE INSERT OR UPDATE OR DELETE ON other_schema.versioning
9 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'other_schema.versioning_history', false);
10 | -- Insert.
11 | BEGIN;
12 | INSERT INTO other_schema.versioning (a) VALUES (3);
13 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
14 | a | b b | ?column?
15 | ---+-----+----------
16 | 1 | | f
17 | 2 | | f
18 | 3 | | t
19 | (3 rows)
20 |
21 | SELECT * FROM other_schema.versioning_history ORDER BY a, sys_period;
22 | a | c | sys_period
23 | ---+---+------------
24 | (0 rows)
25 |
26 | COMMIT;
27 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
28 | SELECT pg_sleep(0.1);
29 | pg_sleep
30 | ----------
31 |
32 | (1 row)
33 |
34 | -- Update.
35 | BEGIN;
36 | UPDATE other_schema.versioning SET a = 4 WHERE a = 3;
37 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
38 | a | b b | ?column?
39 | ---+-----+----------
40 | 1 | | f
41 | 2 | | f
42 | 4 | | t
43 | (3 rows)
44 |
45 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
46 | a | c | ?column?
47 | ---+---+----------
48 | 3 | | t
49 | (1 row)
50 |
51 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
52 | a | b b
53 | ---+-----
54 | 4 |
55 | (1 row)
56 |
57 | COMMIT;
58 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
59 | SELECT pg_sleep(0.1);
60 | pg_sleep
61 | ----------
62 |
63 | (1 row)
64 |
65 | -- Multiple updates.
66 | BEGIN;
67 | UPDATE other_schema.versioning SET a = 5 WHERE a = 4;
68 | UPDATE other_schema.versioning SET "b b" = '2012-01-01' WHERE a = 5;
69 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
70 | a | b b | ?column?
71 | ---+------------+----------
72 | 1 | | f
73 | 2 | | f
74 | 5 | 01-01-2012 | t
75 | (3 rows)
76 |
77 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
78 | a | c | ?column?
79 | ---+---+----------
80 | 3 | | f
81 | 4 | | t
82 | (2 rows)
83 |
84 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
85 | a | b b
86 | ---+------------
87 | 5 | 01-01-2012
88 | (1 row)
89 |
90 | COMMIT;
91 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
92 | SELECT pg_sleep(0.1);
93 | pg_sleep
94 | ----------
95 |
96 | (1 row)
97 |
98 | -- Delete.
99 | BEGIN;
100 | DELETE FROM other_schema.versioning WHERE a = 4;
101 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning ORDER BY a, sys_period;
102 | a | b b | ?column?
103 | ---+------------+----------
104 | 1 | | f
105 | 2 | | f
106 | 5 | 01-01-2012 | f
107 | (3 rows)
108 |
109 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
110 | a | c | ?column?
111 | ---+---+----------
112 | 3 | | f
113 | 4 | | f
114 | (2 rows)
115 |
116 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
117 | a | b b
118 | ---+-----
119 | (0 rows)
120 |
121 | END;
122 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
123 | SELECT pg_sleep(0.1);
124 | pg_sleep
125 | ----------
126 |
127 | (1 row)
128 |
129 | -- Delete.
130 | BEGIN;
131 | DELETE FROM other_schema.versioning;
132 | SELECT * FROM other_schema.versioning;
133 | a | b b | sys_period
134 | ---+-----+------------
135 | (0 rows)
136 |
137 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM other_schema.versioning_history ORDER BY a, sys_period;
138 | a | c | ?column?
139 | ---+---+----------
140 | 1 | | t
141 | 2 | | t
142 | 3 | | f
143 | 4 | | f
144 | 5 | | t
145 | (5 rows)
146 |
147 | SELECT a, "b b" FROM other_schema.versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
148 | a | b b
149 | ---+-----
150 | (0 rows)
151 |
152 | END;
153 | DROP TABLE other_schema.versioning;
154 | DROP TABLE other_schema.versioning_history;
155 | DROP SCHEMA other_schema;
--------------------------------------------------------------------------------
/test/expected/versioning_including_current_version_in_history.out:
--------------------------------------------------------------------------------
1 | CREATE TABLE versioning (a bigint, x bigint, "b b" date, sys_period tstzrange);
2 | -- Insert some data before versioning is enabled.
3 | INSERT INTO versioning (a, x, sys_period) VALUES (1, 1, tstzrange('-infinity', NULL));
4 | INSERT INTO versioning (a, x, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL));
5 | CREATE TABLE versioning_history (a bigint, x bigint, c date, sys_period tstzrange);
6 | CREATE TRIGGER versioning_trigger
7 | BEFORE INSERT OR UPDATE OR DELETE ON versioning
8 | FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', true, false, true);
9 | -- Insert.
10 | BEGIN;
11 | INSERT INTO versioning (a) VALUES (3);
12 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
13 | a | b b | ?column?
14 | ---+-----+----------
15 | 1 | | f
16 | 2 | | f
17 | 3 | | t
18 | (3 rows)
19 |
20 | SELECT a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
21 | a | c | ?column?
22 | ---+---+----------
23 | 3 | | t
24 | (1 row)
25 |
26 | COMMIT;
27 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
28 | SELECT pg_sleep(0.1);
29 | pg_sleep
30 | ----------
31 |
32 | (1 row)
33 |
34 | -- Update.
35 | BEGIN;
36 | UPDATE versioning SET a = 4, x = 4 WHERE a = 3;
37 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
38 | a | b b | ?column?
39 | ---+-----+----------
40 | 1 | | f
41 | 2 | | f
42 | 4 | | t
43 | (3 rows)
44 |
45 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
46 | a | c | ?column?
47 | ---+---+----------
48 | 3 | | t
49 | 4 | |
50 | (2 rows)
51 |
52 | SELECT a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
53 | a | c | ?column?
54 | ---+---+----------
55 | 3 | | f
56 | 4 | | t
57 | (2 rows)
58 |
59 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
60 | a | b b
61 | ---+-----
62 | 4 |
63 | (1 row)
64 |
65 | SELECT a, c, lower(sys_period) IS NOT NULL FROM versioning_history ORDER BY a, sys_period;
66 | a | c | ?column?
67 | ---+---+----------
68 | 3 | | t
69 | 4 | | t
70 | (2 rows)
71 |
72 | COMMIT;
73 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
74 | SELECT pg_sleep(0.1);
75 | pg_sleep
76 | ----------
77 |
78 | (1 row)
79 |
80 | -- Multiple updates.
81 | BEGIN;
82 | UPDATE versioning SET a = 5 WHERE a = 4;
83 | UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
84 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' FROM versioning ORDER BY a, sys_period;
85 | a | b b | ?column?
86 | ---+------------+----------
87 | 1 | | f
88 | 2 | | f
89 | 5 | 01-01-2012 | t
90 | (3 rows)
91 |
92 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
93 | a | c | ?column?
94 | ---+---+----------
95 | 3 | | f
96 | 4 | | t
97 | 5 | | f
98 | 5 | |
99 | (4 rows)
100 |
101 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' FROM versioning_history ORDER BY a, sys_period;
102 | a | c | ?column?
103 | ---+---+----------
104 | 3 | | f
105 | 4 | | f
106 | 5 | | t
107 | 5 | |
108 | (4 rows)
109 |
110 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP + interval '1 microseconds' ORDER BY a, sys_period;
111 | a | b b
112 | ---+------------
113 | 5 | 01-01-2012
114 | (1 row)
115 |
116 | COMMIT;
117 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
118 | SELECT pg_sleep(0.1);
119 | pg_sleep
120 | ----------
121 |
122 | (1 row)
123 |
124 | -- Delete.
125 | BEGIN;
126 | DELETE FROM versioning WHERE a = 4;
127 | SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period;
128 | a | b b | ?column?
129 | ---+------------+----------
130 | 1 | | f
131 | 2 | | f
132 | 5 | 01-01-2012 | f
133 | (3 rows)
134 |
135 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
136 | a | c | ?column?
137 | ---+---+----------
138 | 3 | | f
139 | 4 | | f
140 | 5 | | f
141 | 5 | |
142 | (4 rows)
143 |
144 | SELECT a, "b b" FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period;
145 | a | b b
146 | ---+-----
147 | (0 rows)
148 |
149 | END;
150 | -- Make sure that the next transaction's CURRENT_TIMESTAMP is different.
151 | SELECT pg_sleep(0.1);
152 | pg_sleep
153 | ----------
154 |
155 | (1 row)
156 |
157 | -- Delete.
158 | BEGIN;
159 | DELETE FROM versioning;
160 | SELECT * FROM versioning;
161 | a | x | b b | sys_period
162 | ---+---+-----+------------
163 | (0 rows)
164 |
165 | SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
166 | a | c | ?column?
167 | ---+---+----------
168 | 3 | | f
169 | 4 | | f
170 | 5 | | f
171 | 5 | | t
172 | (4 rows)
173 |
174 | END;
175 | DROP TABLE versioning;
176 | DROP TABLE versioning_history;
177 |
--------------------------------------------------------------------------------
/versioning_function_nochecks.sql:
--------------------------------------------------------------------------------
1 | -- version 1.2.1
2 |
3 | CREATE OR REPLACE FUNCTION versioning()
4 | RETURNS TRIGGER AS $$
5 | DECLARE
6 | sys_period text;
7 | history_table text;
8 | manipulate jsonb;
9 | mitigate_update_conflicts text;
10 | ignore_unchanged_values bool;
11 | include_current_version_in_history bool;
12 | enable_migration_mode bool;
13 | increment_version bool;
14 | version_column_name text;
15 | commonColumns text[];
16 | time_stamp_to_use timestamptz;
17 | range_lower timestamptz;
18 | existing_range tstzrange;
19 | existing_version integer;
20 | newVersion record;
21 | oldVersion record;
22 | user_defined_system_time text;
23 | record_exists bool;
24 | BEGIN
25 | -- set custom system time if exists
26 | BEGIN
27 | SELECT current_setting('user_defined.system_time') INTO user_defined_system_time;
28 | IF NOT FOUND OR (user_defined_system_time <> '') IS NOT TRUE THEN
29 | time_stamp_to_use := CURRENT_TIMESTAMP;
30 | ELSE
31 | SELECT TO_TIMESTAMP(
32 | user_defined_system_time,
33 | 'YYYY-MM-DD HH24:MI:SS.MS.US'
34 | ) INTO time_stamp_to_use;
35 | END IF;
36 | EXCEPTION WHEN OTHERS THEN
37 | time_stamp_to_use := CURRENT_TIMESTAMP;
38 | END;
39 |
40 | sys_period := TG_ARGV[0];
41 | history_table := TG_ARGV[1];
42 | mitigate_update_conflicts := TG_ARGV[2];
43 | ignore_unchanged_values := COALESCE(TG_ARGV[3],'false');
44 | include_current_version_in_history := COALESCE(TG_ARGV[4],'false');
45 | enable_migration_mode := COALESCE(TG_ARGV[5],'false');
46 | increment_version := COALESCE(TG_ARGV[6],'false');
47 | version_column_name := COALESCE(TG_ARGV[7],'version');
48 |
49 | IF ignore_unchanged_values AND TG_OP = 'UPDATE' THEN
50 | IF NEW IS NOT DISTINCT FROM OLD THEN
51 | RETURN OLD;
52 | END IF;
53 | END IF;
54 |
55 | IF increment_version = 'true' THEN
56 | IF TG_OP = 'INSERT' THEN
57 | existing_version := 0;
58 | END IF;
59 | END IF;
60 |
61 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' OR (include_current_version_in_history = 'true' AND TG_OP = 'INSERT') THEN
62 | IF include_current_version_in_history <> 'true' THEN
63 | -- Ignore rows already modified in the current transaction
64 | IF OLD.xmin::text = (txid_current() % (2^32)::bigint)::text THEN
65 | IF TG_OP = 'DELETE' THEN
66 | RETURN OLD;
67 | END IF;
68 | RETURN NEW;
69 | END IF;
70 | END IF;
71 |
72 | -- If we we are performing an update or delete we might want to optionally mitigate update conflicts
73 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
74 | EXECUTE format('SELECT $1.%I', sys_period) USING OLD INTO existing_range;
75 |
76 | range_lower := lower(existing_range);
77 |
78 | IF mitigate_update_conflicts = 'true' THEN
79 | -- mitigate update conflicts
80 | IF range_lower >= time_stamp_to_use THEN
81 | time_stamp_to_use := range_lower + interval '1 microseconds';
82 | END IF;
83 | END IF;
84 |
85 | IF increment_version = 'true' THEN
86 | EXECUTE format('SELECT $1.%I', version_column_name) USING OLD INTO existing_version;
87 | END IF;
88 | END IF;
89 |
90 | WITH history AS
91 | (SELECT attname
92 | FROM pg_attribute
93 | WHERE attrelid = history_table::regclass
94 | AND attnum > 0
95 | AND NOT attisdropped),
96 | main AS
97 | (SELECT attname
98 | FROM pg_attribute
99 | WHERE attrelid = TG_RELID
100 | AND attnum > 0
101 | AND NOT attisdropped)
102 | SELECT array_agg(quote_ident(history.attname)) INTO commonColumns
103 | FROM history
104 | INNER JOIN main
105 | ON history.attname = main.attname
106 | AND history.attname != sys_period;
107 |
108 | IF increment_version = 'true' THEN
109 | commonColumns := array_remove(commonColumns, quote_ident(version_column_name));
110 | END IF;
111 |
112 | -- Check if record exists in history table for migration mode
113 | IF enable_migration_mode = 'true' AND include_current_version_in_history = 'true' AND (TG_OP = 'UPDATE' OR TG_OP = 'DELETE') THEN
114 | EXECUTE 'SELECT EXISTS (
115 | SELECT 1 FROM ' || history_table || ' WHERE ROW(' ||
116 | array_to_string(commonColumns, ',') ||
117 | ') IS NOT DISTINCT FROM ROW($1.' ||
118 | array_to_string(commonColumns, ',$1.') ||
119 | '))'
120 | USING OLD INTO record_exists;
121 |
122 | IF NOT record_exists THEN
123 | -- Insert current record into history table with its original range
124 | IF increment_version = 'true' THEN
125 | EXECUTE 'INSERT INTO ' ||
126 | history_table ||
127 | '(' ||
128 | array_to_string(commonColumns, ',') ||
129 | ',' ||
130 | quote_ident(sys_period) ||
131 | ',' ||
132 | quote_ident(version_column_name) ||
133 | ') VALUES ($1.' ||
134 | array_to_string(commonColumns, ',$1.') ||
135 | ',tstzrange($2, $3, ''[)''), $4)'
136 | USING OLD, range_lower, time_stamp_to_use, existing_version;
137 | ELSE
138 | EXECUTE 'INSERT INTO ' ||
139 | history_table ||
140 | '(' ||
141 | array_to_string(commonColumns, ',') ||
142 | ',' ||
143 | quote_ident(sys_period) ||
144 | ') VALUES ($1.' ||
145 | array_to_string(commonColumns, ',$1.') ||
146 | ',tstzrange($2, $3, ''[)''))'
147 | USING OLD, range_lower, time_stamp_to_use;
148 | END IF;
149 | END IF;
150 | END IF;
151 |
152 | -- skip version if it would be identical to the previous version
153 | IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND array_length(commonColumns, 1) > 0 THEN
154 | EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')'
155 | USING NEW
156 | INTO newVersion;
157 | EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')'
158 | USING OLD
159 | INTO oldVersion;
160 | IF newVersion IS NOT DISTINCT FROM oldVersion THEN
161 | RETURN NEW;
162 | END IF;
163 | END IF;
164 |
165 | -- If we are including the current version in the history and the operation is an update or delete, we need to update the previous version in the history table
166 | IF include_current_version_in_history = 'true' THEN
167 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
168 | EXECUTE (
169 | 'UPDATE ' ||
170 | history_table ||
171 | ' SET ' ||
172 | quote_ident(sys_period) ||
173 | ' = tstzrange($2, $3, ''[)'')' ||
174 | ' WHERE (' ||
175 | array_to_string(commonColumns , ',') ||
176 | ') IS NOT DISTINCT FROM ($1.' ||
177 | array_to_string(commonColumns, ',$1.') ||
178 | ') AND ' ||
179 | quote_ident(sys_period) ||
180 | ' = $1.' ||
181 | quote_ident(sys_period)
182 | )
183 | USING OLD, range_lower, time_stamp_to_use;
184 | END IF;
185 | -- If we are including the current version in the history and the operation is an insert or update, we need to insert the current version in the history table
186 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN
187 | IF increment_version = 'true' THEN
188 | EXECUTE ('INSERT INTO ' ||
189 | history_table ||
190 | '(' ||
191 | array_to_string(commonColumns , ',') ||
192 | ',' ||
193 | quote_ident(sys_period) ||
194 | ',' ||
195 | quote_ident(version_column_name) ||
196 | ') VALUES ($1.' ||
197 | array_to_string(commonColumns, ',$1.') ||
198 | ',tstzrange($2, NULL, ''[)''), $3)')
199 | USING NEW, time_stamp_to_use, existing_version + 1;
200 | ELSE
201 | EXECUTE ('INSERT INTO ' ||
202 | history_table ||
203 | '(' ||
204 | array_to_string(commonColumns , ',') ||
205 | ',' ||
206 | quote_ident(sys_period) ||
207 | ') VALUES ($1.' ||
208 | array_to_string(commonColumns, ',$1.') ||
209 | ',tstzrange($2, NULL, ''[)''))')
210 | USING NEW, time_stamp_to_use;
211 | END IF;
212 | END IF;
213 | ELSE
214 | IF increment_version = 'true' THEN
215 | EXECUTE ('INSERT INTO ' ||
216 | history_table ||
217 | '(' ||
218 | array_to_string(commonColumns , ',') ||
219 | ',' ||
220 | quote_ident(sys_period) ||
221 | ',' ||
222 | quote_ident(version_column_name) ||
223 | ') VALUES ($1.' ||
224 | array_to_string(commonColumns, ',$1.') ||
225 | ',tstzrange($2, $3, ''[)''), $4)')
226 | USING OLD, range_lower, time_stamp_to_use, existing_version;
227 | ELSE
228 | EXECUTE ('INSERT INTO ' ||
229 | history_table ||
230 | '(' ||
231 | array_to_string(commonColumns , ',') ||
232 | ',' ||
233 | quote_ident(sys_period) ||
234 | ') VALUES ($1.' ||
235 | array_to_string(commonColumns, ',$1.') ||
236 | ',tstzrange($2, $3, ''[)''))')
237 | USING OLD, range_lower, time_stamp_to_use;
238 | END IF;
239 | END IF;
240 |
241 | END IF;
242 |
243 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN
244 | manipulate := jsonb_set('{}'::jsonb, ('{' || sys_period || '}')::text[], to_jsonb(tstzrange(time_stamp_to_use, null, '[)')));
245 |
246 | IF increment_version = 'true' THEN
247 | manipulate := jsonb_set(manipulate, ('{' || version_column_name || '}')::text[], to_jsonb(existing_version + 1));
248 | END IF;
249 |
250 | RETURN jsonb_populate_record(NEW, manipulate);
251 | END IF;
252 |
253 | RETURN OLD;
254 | END;
255 | $$ LANGUAGE plpgsql;
256 |
--------------------------------------------------------------------------------
/versioning_function.sql:
--------------------------------------------------------------------------------
1 | -- version 1.2.1
2 |
3 | CREATE OR REPLACE FUNCTION versioning()
4 | RETURNS TRIGGER AS $$
5 | DECLARE
6 | sys_period text;
7 | history_table text;
8 | manipulate jsonb;
9 | mitigate_update_conflicts text;
10 | ignore_unchanged_values bool;
11 | include_current_version_in_history bool;
12 | enable_migration_mode bool;
13 | increment_version bool;
14 | version_column_name text;
15 | commonColumns text[];
16 | time_stamp_to_use timestamptz;
17 | range_lower timestamptz;
18 | existing_range tstzrange;
19 | existing_version integer;
20 | holder record;
21 | holder2 record;
22 | pg_version integer;
23 | newVersion record;
24 | oldVersion record;
25 | user_defined_system_time text;
26 | record_exists bool;
27 | BEGIN
28 | -- set custom system time if exists
29 | BEGIN
30 | SELECT current_setting('user_defined.system_time') INTO user_defined_system_time;
31 | IF NOT FOUND OR (user_defined_system_time <> '') IS NOT TRUE THEN
32 | time_stamp_to_use := CURRENT_TIMESTAMP;
33 | ELSE
34 | SELECT TO_TIMESTAMP(
35 | user_defined_system_time,
36 | 'YYYY-MM-DD HH24:MI:SS.MS.US'
37 | ) INTO time_stamp_to_use;
38 | END IF;
39 | EXCEPTION WHEN OTHERS THEN
40 | time_stamp_to_use := CURRENT_TIMESTAMP;
41 | END;
42 |
43 | IF TG_WHEN != 'BEFORE' OR TG_LEVEL != 'ROW' THEN
44 | RAISE TRIGGER_PROTOCOL_VIOLATED USING
45 | MESSAGE = 'function "versioning" must be fired BEFORE ROW';
46 | END IF;
47 |
48 | IF TG_OP != 'INSERT' AND TG_OP != 'UPDATE' AND TG_OP != 'DELETE' THEN
49 | RAISE TRIGGER_PROTOCOL_VIOLATED USING
50 | MESSAGE = 'function "versioning" must be fired for INSERT or UPDATE or DELETE';
51 | END IF;
52 |
53 | IF TG_NARGS not between 3 and 8 THEN
54 | RAISE INVALID_PARAMETER_VALUE USING
55 | MESSAGE = 'wrong number of parameters for function "versioning"',
56 | HINT = 'expected 3 to 8 parameters but got ' || TG_NARGS;
57 | END IF;
58 |
59 | sys_period := TG_ARGV[0];
60 | history_table := TG_ARGV[1];
61 | mitigate_update_conflicts := TG_ARGV[2];
62 | ignore_unchanged_values := COALESCE(TG_ARGV[3],'false');
63 | include_current_version_in_history := COALESCE(TG_ARGV[4],'false');
64 | enable_migration_mode := COALESCE(TG_ARGV[5],'false');
65 | increment_version := COALESCE(TG_ARGV[6],'false');
66 | version_column_name := COALESCE(TG_ARGV[7],'version');
67 |
68 | IF ignore_unchanged_values AND TG_OP = 'UPDATE' THEN
69 | IF NEW IS NOT DISTINCT FROM OLD THEN
70 | RETURN OLD;
71 | END IF;
72 | END IF;
73 |
74 | -- check if sys_period exists on original table
75 | SELECT atttypid, attndims INTO holder FROM pg_attribute WHERE attrelid = TG_RELID AND attname = sys_period AND NOT attisdropped;
76 | IF NOT FOUND THEN
77 | RAISE 'column "%" of relation "%" does not exist', sys_period, TG_TABLE_NAME USING
78 | ERRCODE = 'undefined_column';
79 | END IF;
80 | IF holder.atttypid != to_regtype('tstzrange') THEN
81 | IF holder.attndims > 0 THEN
82 | RAISE 'system period column "%" of relation "%" is not a range but an array', sys_period, TG_TABLE_NAME USING
83 | ERRCODE = 'datatype_mismatch';
84 | END IF;
85 |
86 | SELECT rngsubtype INTO holder2 FROM pg_range WHERE rngtypid = holder.atttypid;
87 | IF FOUND THEN
88 | RAISE 'system period column "%" of relation "%" is not a range of timestamp with timezone but of type %', sys_period, TG_TABLE_NAME, format_type(holder2.rngsubtype, null) USING
89 | ERRCODE = 'datatype_mismatch';
90 | END IF;
91 |
92 | RAISE 'system period column "%" of relation "%" is not a range but type %', sys_period, TG_TABLE_NAME, format_type(holder.atttypid, null) USING
93 | ERRCODE = 'datatype_mismatch';
94 | END IF;
95 |
96 | -- check version column
97 | IF increment_version = 'true' THEN
98 | SELECT atttypid INTO holder FROM pg_attribute WHERE attrelid = TG_RELID AND attname = version_column_name AND NOT attisdropped;
99 | IF NOT FOUND THEN
100 | RAISE 'relation "%" does not contain version column "%"', TG_TABLE_NAME, version_column_name USING
101 | ERRCODE = 'undefined_column';
102 | END IF;
103 | IF holder.atttypid != to_regtype('integer') THEN
104 | RAISE 'version column "%" of relation "%" is not an integer', version_column_name, TG_TABLE_NAME USING
105 | ERRCODE = 'datatype_mismatch';
106 | END IF;
107 | IF TG_OP = 'INSERT' THEN
108 | existing_version := 0;
109 | END IF;
110 | END IF;
111 |
112 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' OR (include_current_version_in_history = 'true' AND TG_OP = 'INSERT') THEN
113 | IF include_current_version_in_history <> 'true' THEN
114 | -- Ignore rows already modified in the current transaction
115 | IF OLD.xmin::text = (txid_current() % (2^32)::bigint)::text THEN
116 | IF TG_OP = 'DELETE' THEN
117 | RETURN OLD;
118 | END IF;
119 | RETURN NEW;
120 | END IF;
121 | END IF;
122 |
123 | SELECT current_setting('server_version_num')::integer
124 | INTO pg_version;
125 |
126 | -- to support postgres < 9.6
127 | IF pg_version < 90600 THEN
128 | -- check if history table exits
129 | IF to_regclass(history_table::cstring) IS NULL THEN
130 | RAISE 'relation "%" does not exist', history_table;
131 | END IF;
132 | ELSE
133 | IF to_regclass(history_table) IS NULL THEN
134 | RAISE 'relation "%" does not exist', history_table;
135 | END IF;
136 | END IF;
137 |
138 | -- check if history table has sys_period
139 | IF NOT EXISTS(SELECT * FROM pg_attribute WHERE attrelid = history_table::regclass AND attname = sys_period AND NOT attisdropped) THEN
140 | RAISE 'history relation "%" does not contain system period column "%"', history_table, sys_period USING
141 | HINT = 'history relation must contain system period column with the same name and data type as the versioned one';
142 | END IF;
143 |
144 | -- check if history table has version column
145 | IF increment_version = 'true' THEN
146 | IF NOT EXISTS(SELECT * FROM pg_attribute WHERE attrelid = history_table::regclass AND attname = version_column_name AND NOT attisdropped) THEN
147 | RAISE 'history relation "%" does not contain version column "%"', history_table, version_column_name USING
148 | HINT = 'history relation must contain version column with the same name and data type as the versioned one';
149 | END IF;
150 | END IF;
151 |
152 | -- If we we are performing an update or delete, we need to check if the current version is valid and optionally mitigate update conflicts
153 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
154 | EXECUTE format('SELECT $1.%I', sys_period) USING OLD INTO existing_range;
155 |
156 | IF existing_range IS NULL THEN
157 | RAISE 'system period column "%" of relation "%" must not be null', sys_period, TG_TABLE_NAME USING
158 | ERRCODE = 'null_value_not_allowed';
159 | END IF;
160 |
161 | IF isempty(existing_range) OR NOT upper_inf(existing_range) THEN
162 | RAISE 'system period column "%" of relation "%" contains invalid value', sys_period, TG_TABLE_NAME USING
163 | ERRCODE = 'data_exception',
164 | DETAIL = 'valid ranges must be non-empty and unbounded on the high side';
165 | END IF;
166 |
167 | range_lower := lower(existing_range);
168 |
169 | IF mitigate_update_conflicts = 'true' THEN
170 | -- mitigate update conflicts
171 | IF range_lower >= time_stamp_to_use THEN
172 | time_stamp_to_use := range_lower + interval '1 microseconds';
173 | END IF;
174 | END IF;
175 | IF range_lower >= time_stamp_to_use THEN
176 | RAISE 'system period value of relation "%" cannot be set to a valid period because a row that is attempted to modify was also modified by another transaction', TG_TABLE_NAME USING
177 | ERRCODE = 'data_exception',
178 | DETAIL = 'the start time of the system period is the greater than or equal to the time of the current transaction ';
179 | END IF;
180 |
181 | IF increment_version = 'true' THEN
182 | EXECUTE format('SELECT $1.%I', version_column_name) USING OLD INTO existing_version;
183 | IF existing_version IS NULL THEN
184 | RAISE 'version column "%" of relation "%" must not be null', version_column_name, TG_TABLE_NAME USING
185 | ERRCODE = 'null_value_not_allowed';
186 | END IF;
187 | END IF;
188 | END IF;
189 |
190 | WITH history AS
191 | (SELECT attname, atttypid
192 | FROM pg_attribute
193 | WHERE attrelid = history_table::regclass
194 | AND attnum > 0
195 | AND NOT attisdropped),
196 | main AS
197 | (SELECT attname, atttypid
198 | FROM pg_attribute
199 | WHERE attrelid = TG_RELID
200 | AND attnum > 0
201 | AND NOT attisdropped)
202 | SELECT
203 | history.attname AS history_name,
204 | main.attname AS main_name,
205 | history.atttypid AS history_type,
206 | main.atttypid AS main_type
207 | INTO holder
208 | FROM history
209 | INNER JOIN main
210 | ON history.attname = main.attname
211 | WHERE
212 | history.atttypid != main.atttypid;
213 |
214 | IF FOUND THEN
215 | RAISE 'column "%" of relation "%" is of type % but column "%" of history relation "%" is of type %',
216 | holder.main_name, TG_TABLE_NAME, format_type(holder.main_type, null), holder.history_name, history_table, format_type(holder.history_type, null)
217 | USING ERRCODE = 'datatype_mismatch';
218 | END IF;
219 |
220 | WITH history AS
221 | (SELECT attname
222 | FROM pg_attribute
223 | WHERE attrelid = history_table::regclass
224 | AND attnum > 0
225 | AND NOT attisdropped),
226 | main AS
227 | (SELECT attname
228 | FROM pg_attribute
229 | WHERE attrelid = TG_RELID
230 | AND attnum > 0
231 | AND NOT attisdropped)
232 | SELECT array_agg(quote_ident(history.attname)) INTO commonColumns
233 | FROM history
234 | INNER JOIN main
235 | ON history.attname = main.attname
236 | AND history.attname != sys_period;
237 |
238 | IF increment_version = 'true' THEN
239 | commonColumns := array_remove(commonColumns, quote_ident(version_column_name));
240 | END IF;
241 |
242 | -- Check if record exists in history table for migration mode
243 | IF enable_migration_mode = 'true' AND include_current_version_in_history = 'true' AND (TG_OP = 'UPDATE' OR TG_OP = 'DELETE') THEN
244 | EXECUTE 'SELECT EXISTS (
245 | SELECT 1 FROM ' || history_table || ' WHERE ROW(' ||
246 | array_to_string(commonColumns, ',') ||
247 | ') IS NOT DISTINCT FROM ROW($1.' ||
248 | array_to_string(commonColumns, ',$1.') ||
249 | '))'
250 | USING OLD INTO record_exists;
251 |
252 | IF NOT record_exists THEN
253 | -- Insert current record into history table with its original range
254 | IF increment_version = 'true' THEN
255 | EXECUTE 'INSERT INTO ' ||
256 | history_table ||
257 | '(' ||
258 | array_to_string(commonColumns, ',') ||
259 | ',' ||
260 | quote_ident(sys_period) ||
261 | ',' ||
262 | quote_ident(version_column_name) ||
263 | ') VALUES ($1.' ||
264 | array_to_string(commonColumns, ',$1.') ||
265 | ',tstzrange($2, $3, ''[)''), $4)'
266 | USING OLD, range_lower, time_stamp_to_use, existing_version;
267 | ELSE
268 | EXECUTE 'INSERT INTO ' ||
269 | history_table ||
270 | '(' ||
271 | array_to_string(commonColumns, ',') ||
272 | ',' ||
273 | quote_ident(sys_period) ||
274 | ') VALUES ($1.' ||
275 | array_to_string(commonColumns, ',$1.') ||
276 | ',tstzrange($2, $3, ''[)''))'
277 | USING OLD, range_lower, time_stamp_to_use;
278 | END IF;
279 | END IF;
280 | END IF;
281 |
282 | -- skip version if it would be identical to the previous version
283 | IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND array_length(commonColumns, 1) > 0 THEN
284 | EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')'
285 | USING NEW
286 | INTO newVersion;
287 | EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')'
288 | USING OLD
289 | INTO oldVersion;
290 | IF newVersion IS NOT DISTINCT FROM oldVersion THEN
291 | RETURN NEW;
292 | END IF;
293 | END IF;
294 |
295 | -- If we are including the current version in the history and the operation is an update or delete, we need to update the previous version in the history table
296 | IF include_current_version_in_history = 'true' THEN
297 | IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
298 | EXECUTE (
299 | 'UPDATE ' ||
300 | history_table ||
301 | ' SET ' ||
302 | quote_ident(sys_period) ||
303 | ' = tstzrange($2, $3, ''[)'')' ||
304 | ' WHERE (' ||
305 | array_to_string(commonColumns , ',') ||
306 | ') IS NOT DISTINCT FROM ($1.' ||
307 | array_to_string(commonColumns, ',$1.') ||
308 | ') AND ' ||
309 | quote_ident(sys_period) ||
310 | ' = $1.' ||
311 | quote_ident(sys_period)
312 | )
313 | USING OLD, range_lower, time_stamp_to_use;
314 | END IF;
315 | -- If we are including the current version in the history and the operation is an insert or update, we need to insert the current version in the history table
316 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN
317 | IF increment_version = 'true' THEN
318 | EXECUTE ('INSERT INTO ' ||
319 | history_table ||
320 | '(' ||
321 | array_to_string(commonColumns , ',') ||
322 | ',' ||
323 | quote_ident(sys_period) ||
324 | ',' ||
325 | quote_ident(version_column_name) ||
326 | ') VALUES ($1.' ||
327 | array_to_string(commonColumns, ',$1.') ||
328 | ',tstzrange($2, NULL, ''[)''), $3)')
329 | USING NEW, time_stamp_to_use, existing_version + 1;
330 | ELSE
331 | EXECUTE ('INSERT INTO ' ||
332 | history_table ||
333 | '(' ||
334 | array_to_string(commonColumns , ',') ||
335 | ',' ||
336 | quote_ident(sys_period) ||
337 | ') VALUES ($1.' ||
338 | array_to_string(commonColumns, ',$1.') ||
339 | ',tstzrange($2, NULL, ''[)''))')
340 | USING NEW, time_stamp_to_use;
341 | END IF;
342 | END IF;
343 | ELSE
344 | IF increment_version = 'true' THEN
345 | EXECUTE ('INSERT INTO ' ||
346 | history_table ||
347 | '(' ||
348 | array_to_string(commonColumns , ',') ||
349 | ',' ||
350 | quote_ident(sys_period) ||
351 | ',' ||
352 | quote_ident(version_column_name) ||
353 | ') VALUES ($1.' ||
354 | array_to_string(commonColumns, ',$1.') ||
355 | ',tstzrange($2, $3, ''[)''), $4)')
356 | USING OLD, range_lower, time_stamp_to_use, existing_version;
357 | ELSE
358 | EXECUTE ('INSERT INTO ' ||
359 | history_table ||
360 | '(' ||
361 | array_to_string(commonColumns , ',') ||
362 | ',' ||
363 | quote_ident(sys_period) ||
364 | ') VALUES ($1.' ||
365 | array_to_string(commonColumns, ',$1.') ||
366 | ',tstzrange($2, $3, ''[)''))')
367 | USING OLD, range_lower, time_stamp_to_use;
368 | END IF;
369 | END IF;
370 |
371 | END IF;
372 |
373 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN
374 | manipulate := jsonb_set('{}'::jsonb, ('{' || sys_period || '}')::text[], to_jsonb(tstzrange(time_stamp_to_use, null, '[)')));
375 |
376 | IF increment_version = 'true' THEN
377 | manipulate := jsonb_set(manipulate, ('{' || version_column_name || '}')::text[], to_jsonb(existing_version + 1));
378 | END IF;
379 |
380 | RETURN jsonb_populate_record(NEW, manipulate);
381 | END IF;
382 |
383 | RETURN OLD;
384 | END;
385 | $$ LANGUAGE plpgsql;
386 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Temporal Tables
2 |
3 | [](https://github.com/nearform/temporal_tables/actions/workflows/ci.yml)
4 |
5 | This rewrite aims to provide a temporal tables solution in PL/pgSQL, targeting AWS RDS, Google Cloud SQL, and Azure Database for PostgreSQL where custom C extensions aren't permitted.
6 |
7 | The script in `versioning_function.sql` serves as a direct substitute.
8 |
9 | For a speedier but riskier option, `versioning_function_nochecks.sql` is 2x faster due to the absence of validation checks.
10 |
11 | Over time, new features have been introduced while maintaining backward compatibility:
12 |
13 | - [Ignore updates with no actual changes](#ignore-unchanged-values)
14 | - [Include the current version in history](#include-current-version-in-history)
15 | - [Autoincrementing version number support](#autoincrementing-version-number)
16 |
17 |
18 |
19 | ## Usage
20 |
21 | Create a database and the versioning function:
22 |
23 | ```sh
24 | createdb temporal_test
25 | psql temporal_test < versioning_function.sql
26 | ```
27 |
28 | If you would like to have `set_system_time` function available (more details [below](#system-time)) you should run the following as well:
29 |
30 | ```sh
31 | psql temporal_test < system_time_function.sql
32 | ```
33 |
34 | Connect to the db:
35 |
36 | ```
37 | psql temporal_test
38 | ```
39 |
40 | Create the table to version, in this example it will be a "subscription" table:
41 |
42 | ```sql
43 | CREATE TABLE subscriptions
44 | (
45 | name text NOT NULL,
46 | state text NOT NULL
47 | );
48 | ```
49 |
50 | Add the system period column:
51 |
52 | ```sql
53 | ALTER TABLE subscriptions
54 | ADD COLUMN sys_period tstzrange NOT NULL DEFAULT tstzrange(current_timestamp, null);
55 | ```
56 |
57 | Create the history table:
58 |
59 | ```sql
60 | CREATE TABLE subscriptions_history (LIKE subscriptions);
61 | ```
62 |
63 | To improve performance of the trigger at runtime, include some indexes on the history table:
64 |
65 | ```sql
66 | CREATE INDEX ON subscriptions_history (sys_period);
67 |
68 | -- If your table has a unique identity column include that as well for indexing
69 | -- CREATE INDEX ON subscriptions_history (id);
70 | ```
71 |
72 | Finally, create the trigger:
73 |
74 | ```sql
75 | CREATE TRIGGER versioning_trigger
76 | BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
77 | FOR EACH ROW EXECUTE PROCEDURE versioning(
78 | 'sys_period', 'subscriptions_history', true
79 | );
80 | ```
81 |
82 | A note on the history table name. Previous versions of this extension quoted and escaped it before usage.
83 | Starting version 0.4.0 we are not escaping it anymore and users need to provide the escaped version as a parameter to the trigger.
84 |
85 | This is consistent with the C version, simplifies the extension code and fixes an issue with upper case names that weren't properly supported.
86 |
87 | Now test with some data:
88 |
89 | ```sql
90 | INSERT INTO subscriptions (name, state) VALUES ('test1', 'inserted');
91 | UPDATE subscriptions SET state = 'updated' WHERE name = 'test1';
92 | UPDATE subscriptions SET state = 'updated twice' WHERE name = 'test1';
93 | DELETE FROM subscriptions WHERE name = 'test1';
94 | ```
95 |
96 | Take some time between a query and the following, otherwise the difference in the time periods won't be noticeable.
97 |
98 | After all the queries are completed, you should check the tables content.
99 |
100 | ```sql
101 | SELECT * FROM subscriptions;
102 | ```
103 |
104 | Should return 0 rows
105 |
106 | ```sql
107 | SELECT * FROM subscriptions_history;
108 | ```
109 |
110 | Should return something similar to:
111 |
112 | | name | state | sys_period |
113 | | ----- | ------------- | ----------------------------------------------------------------- |
114 | | test1 | inserted | ["2017-08-01 16:09:45.542983+02","2017-08-01 16:09:54.984179+02") |
115 | | test1 | updated | ["2017-08-01 16:09:54.984179+02","2017-08-01 16:10:08.880571+02") |
116 | | test1 | updated twice | ["2017-08-01 16:10:08.880571+02","2017-08-01 16:10:17.33659+02") |
117 |
118 |
119 |
120 | ## Setting custom system time
121 |
122 | If you want to take advantage of setting a custom system time you can use the `set_system_time` function. It is a port of the original [set_system_time](https://github.com/arkhipov/temporal_tables#advanced-usage).
123 | The function accepts a timestamp as input. It also accepts string representation of a timestamp in the following formats.
124 |
125 | - `YYYY-MM-DD HH:MI:SS`
126 | - `YYYY-MM-DD`
127 |
128 | Same as the original function, calling it with `null` will reset to default setting (using the CURRENT_TIMESTAMP):
129 |
130 | ```sql
131 | SELECT set_system_time(null);
132 | ```
133 |
134 | Below is an example on how to use this function (continues using the example from above):
135 |
136 | Create the set_system_time function:
137 |
138 | ```sh
139 | psql temporal_test < system_time_function.sql
140 | ```
141 |
142 | Set a custom value for the system time:
143 |
144 | ```sql
145 | SELECT set_system_time('1999-12-31 23:59:59'::timestamptz);
146 | ```
147 |
148 | Now test with some data:
149 |
150 | ```sql
151 | INSERT INTO subscriptions (name, state) VALUES ('test2', 'inserted');
152 | UPDATE subscriptions SET state = 'updated' WHERE name = 'test2';
153 | UPDATE subscriptions SET state = 'updated twice' WHERE name = 'test2';
154 | DELETE FROM subscriptions WHERE name = 'test2';
155 | ```
156 |
157 | Take some time between a query and the following, otherwise the difference in the time periods won't be noticeable.
158 |
159 | After all the queries are completed, you should check the `subscriptions_history` table content:
160 |
161 | ```sql
162 | SELECT * FROM subscriptions_history;
163 | ```
164 |
165 | Should return something similar to:
166 |
167 | | name | state | sys_period |
168 | | ----- | ------------- | ----------------------------------------------------------------- |
169 | | test1 | inserted | ["2017-08-01 16:09:45.542983+02","2017-08-01 16:09:54.984179+02") |
170 | | test1 | updated | ["2017-08-01 16:09:54.984179+02","2017-08-01 16:10:08.880571+02") |
171 | | test1 | updated twice | ["2017-08-01 16:10:08.880571+02","2017-08-01 16:10:17.33659+02") |
172 | | test2 | inserted | ["1999-12-31 23:59:59+01","1999-12-31 23:59:59.000001+01") |
173 | | test2 | updated | ["1999-12-31 23:59:59.000001+01","1999-12-31 23:59:59.000002+01") |
174 | | test2 | updated twice | ["1999-12-31 23:59:59.000002+01","1999-12-31 23:59:59.000003+01") |
175 |
176 |
177 |
178 | ## Additional features
179 |
180 |
181 |
182 | ### Ignore updates without actual change
183 |
184 | **NOTE: This feature does not work for tables with columns with types that does not support equality operator (e.g. PostGIS types, JSON types, etc.).**
185 |
186 | By default this extension creates a record in the history table for every update that occurs in the versioned table, regardless of any change actually happening.
187 |
188 | We added a fourth parameter to the trigger to change this behaviour and only record updates that result in an actual change.
189 |
190 | It is worth mentioning that before making the change, a check is performed on the source table against the history table, in such a way that if the history table has only a subset of the columns of the source table, and you are performing an update in a column that is not present in this subset (this means the column does not exist in the history table), this extension will NOT add a new record to the history. Then you can have columns in the source table that create no new versions if modified by not including those columns in the history table.
191 |
192 | The parameter is set by default to `false`, set it to `true` to stop tracking updates without actual changes:
193 |
194 | ```sql
195 | CREATE TRIGGER versioning_trigger
196 | BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
197 | FOR EACH ROW EXECUTE PROCEDURE versioning(
198 | 'sys_period', 'subscriptions_history', true, true
199 | );
200 | ```
201 |
202 |
203 |
204 | ### Include the current version in history
205 |
206 | By default this extension only creates a record in the history table for historical records. This feature enables users to also store the details of the current record in the history table. Simplifying cases when you want a consolidated view of both the current and historical states.
207 |
208 | e.g
209 |
210 | ```sql
211 | SELECT * FROM t_history WHERE x <@ sys_period;
212 | ```
213 |
214 | when `include_current_version_in_history` is true
215 |
216 | as opposed to
217 |
218 | ```sql
219 | SELECT * FROM t WHERE x <@ sys_period
220 | UNION
221 | SELECT * FROM t_history WHERE x <@ sys_period;
222 | ```
223 |
224 | when `include_current_version_in_history` is false (or unset)
225 |
226 | This is a fifth parameter in the extension so all previous parameters need to be specified when using this.
227 |
228 | The parameter is set by default to false, set it to true to include current version of records in the history table.
229 |
230 | ```sql
231 | CREATE TRIGGER versioning_trigger
232 | BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
233 | FOR EACH ROW EXECUTE PROCEDURE versioning(
234 | 'sys_period', 'subscriptions_history', true, false, true
235 | );
236 | ```
237 |
238 |
239 |
240 | ### Migrating to include_current_version_in_history
241 |
242 | If you're already using temporal tables and want to adopt the `include_current_version_in_history` feature, follow these steps to safely migrate your existing tables without losing historical data.
243 |
244 | #### Prerequisites
245 |
246 | 1. **Maintenance Window**: Schedule a maintenance window when no applications are writing to the tables.
247 | 2. **Backup**: Create a backup of your database before proceeding.
248 | 3. **Latest Version**: Ensure you're running the latest version of the temporal tables functions:
249 | ```sql
250 | -- Update the versioning function
251 | \i versioning_function.sql
252 | ```
253 |
254 | #### Migration Steps
255 |
256 | 1. **Identify Versioned Tables**
257 | First, identify all your versioned tables:
258 |
259 | ```sql
260 | SELECT DISTINCT trigger_schema, event_object_table
261 | FROM information_schema.triggers
262 | WHERE trigger_name = 'versioning_trigger'; -- Replace trigger name with the name of the version trigger
263 | ```
264 |
265 | 2. **Copy Current Records**
266 | For each versioned table, copy current records to the history table:
267 |
268 | ```sql
269 | -- Replace table_name with your actual table name
270 | INSERT INTO table_name_history
271 | SELECT *, tstzrange(LOWER(sys_period), NULL)
272 | FROM table_name
273 | WHERE NOT EXISTS (
274 | SELECT 1
275 | FROM table_name_history
276 | WHERE table_name_history.primary_key = table_name.primary_key
277 | AND UPPER(table_name_history.sys_period) IS NULL
278 | );
279 | ```
280 |
281 | 3. **Update Triggers**
282 | Recreate the versioning trigger with the new parameter:
283 |
284 | ```sql
285 | -- Drop existing trigger
286 | DROP TRIGGER IF EXISTS versioning_trigger ON table_name;
287 |
288 | -- Create new trigger with include_current_version_in_history
289 | CREATE TRIGGER versioning_trigger
290 | BEFORE INSERT OR UPDATE OR DELETE ON table_name
291 | FOR EACH ROW EXECUTE PROCEDURE versioning(
292 | 'sys_period',
293 | 'table_name_history',
294 | true, -- enforce timestamps
295 | false, -- ignore unchanged values (adjust as needed)
296 | true -- include current version in history
297 | );
298 | ```
299 |
300 | #### Verification
301 |
302 | After migration, verify the setup:
303 |
304 | ```sql
305 | -- Check if current records exist in history
306 | SELECT t.*, h.*
307 | FROM table_name t
308 | LEFT JOIN table_name_history h ON t.primary_key = h.primary_key
309 | WHERE UPPER(h.sys_period) IS NULL;
310 | ```
311 |
312 | #### Rollback Plan
313 |
314 | If issues occur, you can revert to the previous state:
315 |
316 | ```sql
317 | -- Recreate trigger without include_current_version_in_history
318 | CREATE OR REPLACE TRIGGER versioning_trigger
319 | BEFORE INSERT OR UPDATE OR DELETE ON table_name
320 | FOR EACH ROW EXECUTE PROCEDURE versioning(
321 | 'sys_period',
322 | 'table_name_history',
323 | true, -- enforce timestamps
324 | false -- ignore unchanged values (adjust as needed)
325 | );
326 |
327 | -- Remove current versions from history
328 | DELETE FROM table_name_history
329 | WHERE UPPER(sys_period) IS NULL;
330 | ```
331 |
332 | #### Notes
333 |
334 | - The migration process ensures no historical data is lost
335 | - Existing queries that use UNION to combine current and historical records will continue to work
336 | - New queries can benefit from simplified syntax by querying just the history table
337 | - Consider updating application queries to use the new consolidated history view
338 |
339 | ### Automatic Migration Mode
340 |
341 | When adopting the `include_current_version_in_history` feature for existing tables, you can use the automatic gradual migration mode to seamlessly populate the history table with current records.
342 |
343 | The migration mode is enabled by adding a sixth parameter to the versioning trigger:
344 |
345 | ```sql
346 | CREATE TRIGGER versioning_trigger
347 | BEFORE INSERT OR UPDATE OR DELETE ON your_table
348 | FOR EACH ROW EXECUTE PROCEDURE versioning(
349 | 'sys_period', 'your_table_history', true, false, true, true
350 | );
351 | ```
352 |
353 | When migration mode is enabled:
354 |
355 | - On the first `UPDATE` or `DELETE` operation for each record, the trigger checks if the current version exists in the history table
356 | - If the current version is missing, it's automatically inserted into the history table before proceeding with the update/delete
357 | - This ensures a complete history is maintained without requiring manual data migration
358 |
359 | #### Usage Guidelines
360 |
361 | 1. **When to Use**: Enable migration mode when you want to adopt `include_current_version_in_history` for existing tables that already have data.
362 |
363 | 2. **How to Use**:
364 |
365 | ```sql
366 | -- Update your existing trigger to include migration mode
367 | DROP TRIGGER IF EXISTS versioning_trigger ON your_table;
368 | CREATE TRIGGER versioning_trigger
369 | BEFORE INSERT OR UPDATE OR DELETE ON your_table
370 | FOR EACH ROW EXECUTE PROCEDURE versioning(
371 | 'sys_period', 'your_table_history', true, false, true, true
372 | );
373 | ```
374 |
375 | 3. **Limitations**:
376 |
377 | - Migration mode only works for `UPDATE` and `DELETE` operations
378 | - It only migrates records that are actually modified or deleted
379 | - Once a record has been migrated, subsequent operations will follow normal versioning behavior
380 |
381 | 4. **Best Practices**:
382 | - Enable migration mode only when you're ready to adopt `include_current_version_in_history`
383 | - Consider running a test migration on a copy of your data first to determine any performance impacts
384 | - Monitor the size of your history table during migration
385 | - You can disable migration mode after all records have been migrated
386 |
387 | **Note:** The automatic migration happens gradually, filling in missing history only when existing records are updated or deleted. As a result, records that rarely change will still require manual migration using the [method described above](#migration-to-include-current-version-in-history). However, since the most active records will be automatically migrated, the risk of missing important data is greatly reduced, eliminating the need for a dedicated maintenance window.
388 |
389 |
390 |
391 | ### Autoincrementing version number
392 |
393 | There is support for autoincrementing a version number whenever values of a row get updated. This may be useful for a few reasons:
394 |
395 | * Easier to see how many updates have been made to a row
396 | * Adding primary keys to the history table. E.g. if the main table has a primary key 'id', it will allow adding a primary key 'id', 'version' to the history table. A lot of ORMs expect a primary key
397 |
398 | To achieve this:
399 | * Add an `int` `version` column (or any other name you prefer) to the base table, e.g.
400 | ```sql
401 | ALTER TABLE subscriptions ADD COLUMN version int NOT NULL DEFAULT 1
402 | ```
403 | * Add the same to the history table
404 | ```sql
405 | ALTER TABLE subscriptions_history ADD COLUMN version int NOT NULL
406 | ```
407 | * Create the trigger to use the feature
408 | ```sql
409 | DROP TRIGGER IF EXISTS versioning_trigger ON subscriptions;
410 | CREATE TRIGGER versioning_trigger
411 | BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
412 | FOR EACH ROW EXECUTE PROCEDURE versioning(
413 | 'sys_period', 'subscriptions_history', false, false, false, false,
414 | true, -- turn on increment_version
415 | 'version' -- version_column_name
416 | );
417 | ```
418 |
419 | After this, if you insert a new row
420 | ```sql
421 | INSERT INTO subscriptions (name, state) VALUES ('test1', 'inserted')
422 | ```
423 | the table will start with the row having the initial version `name=test1, state=inserted, version=1`.
424 |
425 | If then, the row gets updated with
426 | ```sql
427 | UPDATE subscriptions SET state='updated' WHERE name='test1'
428 | ```
429 | then the table will reflect incremented version `name=test1, state=updated, version=2`. And correspondingly the history table will have the old version `name=test1, state=inserted, version=1` (or both versions if `include_current_version_in_history` is turned on).
430 |
431 |
432 |
433 |
434 | ## Migrations
435 |
436 | During the life of an application is may be necessary to change the schema of a table. In order for temporal_tables to continue to work properly the same migrations should be applied to the history table as well.
437 |
438 | ### What happens if a column is added to the original table but not to the history table?
439 |
440 | The new column will be ignored, meaning that the updated row is transferred to the history table, but without the value of the new column. This means that you will lose that specific data.
441 |
442 | There are valid use cases for this, for example when you are not interested in storing the historic values of that column.
443 |
444 | **Beware that temporal_tables won't raise an error**
445 |
446 | ### What should I do if I need to remove a column from the original table but want to keep the historic values for it?
447 |
448 | You remove the column in the original table, but keep it in the history table - provided it accepts null values.
449 |
450 | From that point on the old column in the history table will be ignored and will get null values.
451 |
452 | If the column doesn't accept null values you'll need to modify it to allow for null values, otherwise temporal_tables won't be able to create new rows and all operations on the original table will fail
453 |
454 |
455 |
456 | ## Test
457 |
458 | Ensure you have a postgres database available. A database container can be started by running:
459 |
460 | ```sh
461 | npm run db:start
462 | ```
463 |
464 | In order to run tests
465 |
466 | ```sh
467 | npm test
468 | ```
469 |
470 | or
471 |
472 | ```sh
473 | make run_test
474 | ```
475 |
476 | The test suite will run the queries in test/sql and store the output in test/result, and will then diff the output from test/result with the prerecorded output in test/expected.
477 |
478 | A test suite is also available for the nochecks alternative:
479 |
480 | ```sh
481 | make run_test_nochecks
482 | ```
483 |
484 | Obviously, this suite won't run the tests about the error reporting.
485 |
486 | **Note:** When running the tests using `make` ensure that the expected environment variables are available
487 |
488 | ```sh
489 | PGHOST=localhost
490 | PGPORT=5432
491 | PGUSER=postgres
492 | PGPASSWORD=password
493 | ```
494 |
495 |
496 |
497 | ## Performance tests
498 |
499 | For performance tests run:
500 |
501 | ```sh
502 | make performance_test
503 | ```
504 |
505 | This will create the temporal_tables_test database, add all necessary tables, run test tests and drop the database.
506 |
507 | Is it also possible to test against the nochecks version:
508 |
509 | ```sh
510 | make performance_test_nochecks
511 | ```
512 |
513 | or the original c extension run:
514 |
515 | ```sh
516 | make performance_test_original
517 | ```
518 |
519 | This required the original extensions to be installed, but will automatically add it to the database.
520 |
521 | On the test machine (my laptop) the complete version is 2x slower than the nochecks versions and 16x slower than the original version.
522 |
523 | Two comments about those results:
524 |
525 | - original c version makes some use of caching (i.e to share an execution plan), whilst this version doesn't. This is probably accounting for a good chunk of the performance difference. At the moment there's not plan of implementing such caching in this version.
526 | - The trigger still executes in under 1ms and in production environments the the network latency should be more relevant than the trigger itself.
527 |
528 |
529 |
530 | ## The team
531 |
532 | ### Paolo Chiodi
533 |
534 | [https://github.com/paolochiodi](https://github.com/paolochiodi)
535 |
536 | [https://twitter.com/paolochiodi](https://twitter.com/paolochiodi)
537 |
538 |
539 |
540 | ## Acknowledgements
541 |
542 | This project was kindly sponsored by [nearForm](http://nearform.com).
543 |
544 | ## License
545 |
546 | Licensed under [MIT](./LICENSE).
547 |
548 | The test scenarios in test/sql and test/expected have been copied over from the original temporal_tables extension, whose license is [BSD 2-clause](https://github.com/arkhipov/temporal_tables/blob/master/LICENSE)
549 |
550 | [](https://www.nearform.com/contact/?utm_source=open-source&utm_medium=banner&utm_campaign=os-project-pages)
551 |
--------------------------------------------------------------------------------