From 1dac089bdadbcb0671996826a639d17638b40e64 Mon Sep 17 00:00:00 2001
From: Radomir Drndarski <90759187+radomird@users.noreply.github.com>
Date: Wed, 20 Sep 2023 15:26:15 +0200
Subject: [PATCH] Add set_system_time function (#32)
* Created set_system_time function
* Updated versioning function to check for custom system time;
Updated README
* Fixed test setup
* Fixed failing unit tests
* Added unit tests
* feat: added support for MS(milliseconds) and US(microseconds)
* chore: bump package version to 0.6.0
* chore: reverted version back to 0.5.0 and updated the script to include the new file
* docs: removed unnecessary line
---
Makefile | 2 +
README.md | 62 ++++++++++++++-
scripts/update-version.js | 2 +-
system_time_function.sql | 27 +++++++
test/expected/invalid_set_system_time.out | 31 ++++++++
test/expected/non_equality_types.out | 10 +--
.../non_equality_types_unchanged_values.out | 11 ++-
test/expected/set_system_time.out | 78 +++++++++++++++++++
test/runTest.sh | 5 +-
test/runTestNochecks.sh | 1 +
test/sql/invalid_set_system_time.sql | 16 ++++
test/sql/set_system_time.sql | 64 +++++++++++++++
versioning_function.sql | 17 +++-
versioning_function_nochecks.sql | 17 +++-
14 files changed, 324 insertions(+), 19 deletions(-)
create mode 100644 system_time_function.sql
create mode 100644 test/expected/invalid_set_system_time.out
create mode 100644 test/expected/set_system_time.out
create mode 100644 test/sql/invalid_set_system_time.sql
create mode 100644 test/sql/set_system_time.sql
diff --git a/Makefile b/Makefile
index 339c32b..2262150 100644
--- a/Makefile
+++ b/Makefile
@@ -11,6 +11,7 @@ performance_test:
@echo "\nDB Setup\n"
@createdb temporal_tables_test
@psql temporal_tables_test -q -f versioning_function.sql
+ @psql temporal_tables_test -q -f system_time_function.sql
@psql temporal_tables_test -q -f test/performance/setup.sql
@echo "\nRun Test\n"
@@ -32,6 +33,7 @@ performance_test_nochecks:
@echo "\nDB Setup\n"
@createdb temporal_tables_test
@psql temporal_tables_test -q -f versioning_function_nochecks.sql
+ @psql temporal_tables_test -q -f system_time_function.sql
@psql temporal_tables_test -q -f test/performance/setup.sql
@echo "\nRun Test for NOCHECKS version\n"
diff --git a/README.md b/README.md
index 394c2bf..07bca56 100644
--- a/README.md
+++ b/README.md
@@ -8,8 +8,6 @@ The goal is to be able to use it on AWS RDS and other hosted solutions, where us
The version provided in `versioning_function.sql` is a drop-in replacement.
-It works exactly the same way, but lacks the [set_system_time](https://github.com/arkhipov/temporal_tables#advanced-usage) function to work with the current time.
-
The version in `versioning_function_nochecks.sql` is similar to the previous one, but all validation checks have been removed. This version is 2x faster than the normal one, but more dangerous and prone to errors.
With time, added some new functionality diverging from the original implementations. New functionalities are however still retro-compatible:
@@ -27,6 +25,11 @@ createdb temporal_test
psql temporal_test < versioning_function.sql
```
+If you would like to have `set_system_time` function available (more details [below](#system-time)) you should run the following as well:
+```sh
+psql temporal_test < system_time_function.sql
+```
+
Connect to the db:
```
@@ -82,7 +85,7 @@ DELETE FROM subscriptions WHERE name = 'test1';
Take some time between a query and the following, otherwise the difference in the time periods won't be noticeable.
-After all the query are completed, you should check the tables content.
+After all the queries are completed, you should check the tables content.
```sql
SELECT * FROM subscriptions;
@@ -91,7 +94,7 @@ SELECT * FROM subscriptions;
Should return 0 rows
```sql
-SELECT * FROM subscriptions_history
+SELECT * FROM subscriptions_history;
```
Should return something similar to:
@@ -102,6 +105,57 @@ Should return something similar to:
| test1 | updated | ["2017-08-01 16:09:54.984179+02","2017-08-01 16:10:08.880571+02") |
| test1 | updated twice | ["2017-08-01 16:10:08.880571+02","2017-08-01 16:10:17.33659+02") |
+
+## Setting custom system time
+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).
+The function accepts string representation of timestamp in the following format: `YYYY-MM-DD HH:MI:SS.MS.US` - where hours are in 24-hour format 00-23 and the MS (milliseconds) and US (microseconds) portions are optional.
+Same as the original function, calling it with `null` will reset to default setting (using the CURRENT_TIMESTAMP):
+
+```sql
+SELECT set_system_time(null);
+```
+Below is an example on how to use this function (continues using the example from above):
+
+Create the set_system_time function:
+
+```sh
+psql temporal_test < system_time_function.sql
+```
+
+Set a custom value for the system time:
+```sql
+SELECT set_system_time('1999-12-31 23:59:59');
+```
+
+Now test with some data:
+
+```sql
+INSERT INTO subscriptions (name, state) VALUES ('test2', 'inserted');
+UPDATE subscriptions SET state = 'updated' WHERE name = 'test2';
+UPDATE subscriptions SET state = 'updated twice' WHERE name = 'test2';
+DELETE FROM subscriptions WHERE name = 'test2';
+```
+
+Take some time between a query and the following, otherwise the difference in the time periods won't be noticeable.
+
+After all the queries are completed, you should check the `subscriptions_history` table content:
+
+```sql
+SELECT * FROM subscriptions_history;
+```
+
+Should return something similar to:
+
+name | state | sys_period
+----- | ------------- | -------------------------------------------------------------------
+ test1 | inserted | ["2017-08-01 16:09:45.542983+02","2017-08-01 16:09:54.984179+02")
+ test1 | updated | ["2017-08-01 16:09:54.984179+02","2017-08-01 16:10:08.880571+02")
+ test1 | updated twice | ["2017-08-01 16:10:08.880571+02","2017-08-01 16:10:17.33659+02")
+ test2 | inserted | ["1999-12-31 23:59:59+01","1999-12-31 23:59:59.000001+01")
+ test2 | updated | ["1999-12-31 23:59:59.000001+01","1999-12-31 23:59:59.000002+01")
+ test2 | updated twice | ["1999-12-31 23:59:59.000002+01","1999-12-31 23:59:59.000003+01")
+
+
## Additional features
diff --git a/scripts/update-version.js b/scripts/update-version.js
index 95ac054..4e1f6f3 100644
--- a/scripts/update-version.js
+++ b/scripts/update-version.js
@@ -4,7 +4,7 @@ console.log("UPDATING VERSION ...");
const packageJson = require("../package.json");
const newVersion = packageJson.version;
-const files = ["versioning_function", "versioning_function_nochecks"];
+const files = ["versioning_function", "versioning_function_nochecks", "system_time_function"];
files.forEach((fileName) => {
const data = readFileSync(__dirname + `/../${fileName}.sql`, {
diff --git a/system_time_function.sql b/system_time_function.sql
new file mode 100644
index 0000000..a100ac3
--- /dev/null
+++ b/system_time_function.sql
@@ -0,0 +1,27 @@
+-- version 0.5.0
+
+CREATE OR REPLACE FUNCTION set_system_time(user_timestamp text)
+RETURNS text AS $$
+DECLARE
+ custom_system_time text;
+BEGIN
+ IF user_timestamp IS NULL THEN
+ custom_system_time := null;
+ ELSE
+ PERFORM
+ REGEXP_MATCHES(user_timestamp,
+ '(\d){4}-(0[1-9]|1[0-2])-(0[1-9]|[1-2]\d|3[0-1]) ([0-1]\d|2[0-3]):[0-5]\d:[0-5]\d(\.\d{1,3})?(\.\d{1,6})?',
+ 'g');
+ IF NOT FOUND THEN
+ RAISE '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)';
+ ELSE
+ custom_system_time := user_timestamp;
+ END IF;
+ END IF;
+
+ PERFORM set_config('user_defined.system_time', custom_system_time, false);
+
+ return custom_system_time;
+
+END;
+$$ LANGUAGE plpgsql;
diff --git a/test/expected/invalid_set_system_time.out b/test/expected/invalid_set_system_time.out
new file mode 100644
index 0000000..43aa78a
--- /dev/null
+++ b/test/expected/invalid_set_system_time.out
@@ -0,0 +1,31 @@
+-- Invalid dates
+SELECT set_system_time('2022-13-01 22:59:59');
+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)
+SELECT set_system_time('22-13-01 22:59:59');
+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)
+SELECT set_system_time('2022-12-99 22:59:59');
+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)
+-- Invalid time
+SELECT set_system_time('2022-01-11 99:59:59');
+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)
+SELECT set_system_time('2022-01-11 22:99:59');
+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)
+SELECT set_system_time('2022-01-11 22:59:99');
+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)
+SELECT set_system_time('2022-01-11 22:59');
+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)
+SELECT set_system_time('2022-01-11 22');
+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)
+-- Invalid values
+SELECT set_system_time('Invalid string value');
+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)
+SELECT set_system_time(123);
+ERROR: function set_system_time(integer) does not exist
+LINE 1: SELECT set_system_time(123);
+ ^
+HINT: No function matches the given name and argument types. You might need to add explicit type casts.
+SELECT set_system_time();
+ERROR: function set_system_time() does not exist
+LINE 1: SELECT set_system_time();
+ ^
+HINT: No function matches the given name and argument types. You might need to add explicit type casts.
diff --git a/test/expected/non_equality_types.out b/test/expected/non_equality_types.out
index 03bc934..60dec3b 100644
--- a/test/expected/non_equality_types.out
+++ b/test/expected/non_equality_types.out
@@ -1,7 +1,7 @@
-SET client_min_messages TO error
-CREATE TABLE non_equality_types (json json, sys_period tstzrange)
+SET client_min_messages TO error;
+CREATE TABLE non_equality_types (json json, sys_period tstzrange);
CREATE TRIGGER versioning_trigger
BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types
-FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types', false)
-INSERT INTO non_equality_types VALUES ('{"a":1}'::json)
-UPDATE non_equality_types SET json = '{"a":2}'::json WHERE 1=1
+FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types', false);
+INSERT INTO non_equality_types VALUES ('{"a":1}'::json);
+UPDATE non_equality_types SET json = '{"a":2}'::json WHERE 1=1;
diff --git a/test/expected/non_equality_types_unchanged_values.out b/test/expected/non_equality_types_unchanged_values.out
index f8d6519..5b86891 100644
--- a/test/expected/non_equality_types_unchanged_values.out
+++ b/test/expected/non_equality_types_unchanged_values.out
@@ -1,9 +1,8 @@
-SET client_min_messages TO error
-CREATE TABLE non_equality_types_unchanged_values (json json, sys_period tstzrange)
+SET client_min_messages TO error;
+CREATE TABLE non_equality_types_unchanged_values (json json, sys_period tstzrange);
CREATE TRIGGER versioning_trigger
BEFORE INSERT OR UPDATE OR DELETE ON non_equality_types_unchanged_values
-FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types_unchanged_values', false, true)
-INSERT INTO non_equality_types_unchanged_values VALUES ('{"a":1}'::json)
-UPDATE non_equality_types_unchanged_values SET json = '{"a":2}'::json WHERE 1=1
+FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'non_equality_types_unchanged_values', false, true);
+INSERT INTO non_equality_types_unchanged_values VALUES ('{"a":1}'::json);
+UPDATE non_equality_types_unchanged_values SET json = '{"a":2}'::json WHERE 1=1;
ERROR: could not identify an equality operator for type json
-CONTEXT: PL/pgSQL function versioning() line 39 at IF
diff --git a/test/expected/set_system_time.out b/test/expected/set_system_time.out
new file mode 100644
index 0000000..5112c21
--- /dev/null
+++ b/test/expected/set_system_time.out
@@ -0,0 +1,78 @@
+CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
+-- Insert some data before versioning is enabled.
+INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
+INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
+CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
+CREATE TRIGGER versioning_trigger
+BEFORE INSERT OR UPDATE OR DELETE ON versioning
+FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false);
+-- Insert.
+BEGIN;
+SELECT set_system_time('2001-01-01 22:59:59.001.000234');
+ set_system_time
+--------------------------------
+ 2001-01-01 22:59:59.001.000234
+(1 row)
+
+INSERT INTO versioning (a) VALUES (3);
+SELECT * FROM versioning_history;
+ a | c | sys_period
+---+---+------------
+(0 rows)
+
+COMMIT;
+-- Update.
+BEGIN;
+UPDATE versioning SET a = 4 WHERE a = 3;
+SELECT * FROM versioning_history;
+ a | c | sys_period
+---+---+------------------------------------
+ 3 | | (,"2001-01-01 22:59:59.001234+01")
+(1 row)
+
+COMMIT;
+-- Reset system time and do multiple updates.
+BEGIN;
+UPDATE versioning SET a = 5 WHERE a = 4;
+UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
+SELECT * FROM versioning_history;
+ a | c | sys_period
+---+---+------------------------------------
+ 3 | | (,"2001-01-01 22:59:59.001234+01")
+ 4 | | (,"2001-01-01 22:59:59.001234+01")
+(2 rows)
+
+COMMIT;
+-- Delete.
+BEGIN;
+SELECT set_system_time('2022-01-11 12:00:00.000.000000');
+ set_system_time
+--------------------------------
+ 2022-01-11 12:00:00.000.000000
+(1 row)
+
+DELETE FROM versioning WHERE a = 4;
+SELECT * FROM versioning_history;
+ a | c | sys_period
+---+---+------------------------------------
+ 3 | | (,"2001-01-01 22:59:59.001234+01")
+ 4 | | (,"2001-01-01 22:59:59.001234+01")
+(2 rows)
+
+END;
+-- Delete.
+BEGIN;
+DELETE FROM versioning;
+SELECT * FROM versioning_history;
+ a | c | sys_period
+---+---+------------------------------------
+ 3 | | (,"2001-01-01 22:59:59.001234+01")
+ 4 | | (,"2001-01-01 22:59:59.001234+01")
+ 1 | | (,"2022-01-11 12:00:00+01")
+ 2 | | (,"2022-01-11 12:00:00+01")
+ 5 | | (,"2022-01-11 12:00:00+01")
+(5 rows)
+
+END;
+DROP TABLE versioning;
+DROP TABLE versioning_history;
diff --git a/test/runTest.sh b/test/runTest.sh
index 9178945..d1bcb1e 100644
--- a/test/runTest.sh
+++ b/test/runTest.sh
@@ -2,6 +2,7 @@
createdb temporal_tables_test
psql temporal_tables_test -q -f versioning_function.sql
+psql temporal_tables_test -q -f system_time_function.sql
mkdir -p test/result
@@ -10,7 +11,9 @@ TESTS="
invalid_system_period_values invalid_system_period invalid_types
versioning upper_case structure combinations
different_schema unchanged_values unchanged_version_values
- non_equality_types non_equality_types_unchanged_values"
+ non_equality_types non_equality_types_unchanged_values
+ set_system_time invalid_set_system_time
+ "
for name in $TESTS; do
echo ""
diff --git a/test/runTestNochecks.sh b/test/runTestNochecks.sh
index 76a5b96..f29ac0c 100644
--- a/test/runTestNochecks.sh
+++ b/test/runTestNochecks.sh
@@ -2,6 +2,7 @@
createdb temporal_tables_test
psql temporal_tables_test -q -f versioning_function_nochecks.sql
+psql temporal_tables_test -q -f system_time_function.sql
mkdir -p test/result
diff --git a/test/sql/invalid_set_system_time.sql b/test/sql/invalid_set_system_time.sql
new file mode 100644
index 0000000..5d93688
--- /dev/null
+++ b/test/sql/invalid_set_system_time.sql
@@ -0,0 +1,16 @@
+-- Invalid dates
+SELECT set_system_time('2022-13-01 22:59:59');
+SELECT set_system_time('22-13-01 22:59:59');
+SELECT set_system_time('2022-12-99 22:59:59');
+
+-- Invalid time
+SELECT set_system_time('2022-01-11 99:59:59');
+SELECT set_system_time('2022-01-11 22:99:59');
+SELECT set_system_time('2022-01-11 22:59:99');
+SELECT set_system_time('2022-01-11 22:59');
+SELECT set_system_time('2022-01-11 22');
+
+-- Invalid values
+SELECT set_system_time('Invalid string value');
+SELECT set_system_time(123);
+SELECT set_system_time();
diff --git a/test/sql/set_system_time.sql b/test/sql/set_system_time.sql
new file mode 100644
index 0000000..b81d18b
--- /dev/null
+++ b/test/sql/set_system_time.sql
@@ -0,0 +1,64 @@
+CREATE TABLE versioning (a bigint, "b b" date, sys_period tstzrange);
+
+-- Insert some data before versioning is enabled.
+INSERT INTO versioning (a, sys_period) VALUES (1, tstzrange('-infinity', NULL));
+INSERT INTO versioning (a, sys_period) VALUES (2, tstzrange('2000-01-01', NULL));
+
+CREATE TABLE versioning_history (a bigint, c date, sys_period tstzrange);
+
+CREATE TRIGGER versioning_trigger
+BEFORE INSERT OR UPDATE OR DELETE ON versioning
+FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', false);
+
+-- Insert.
+BEGIN;
+
+SELECT set_system_time('2001-01-01 22:59:59.001.000234');
+
+INSERT INTO versioning (a) VALUES (3);
+
+SELECT * FROM versioning_history;
+
+COMMIT;
+
+-- Update.
+BEGIN;
+
+UPDATE versioning SET a = 4 WHERE a = 3;
+
+SELECT * FROM versioning_history;
+
+COMMIT;
+
+-- Reset system time and do multiple updates.
+BEGIN;
+
+UPDATE versioning SET a = 5 WHERE a = 4;
+UPDATE versioning SET "b b" = '2012-01-01' WHERE a = 5;
+
+SELECT * FROM versioning_history;
+
+COMMIT;
+
+-- Delete.
+BEGIN;
+
+SELECT set_system_time('2022-01-11 12:00:00.000.000000');
+
+DELETE FROM versioning WHERE a = 4;
+
+SELECT * FROM versioning_history;
+
+END;
+
+-- Delete.
+BEGIN;
+
+DELETE FROM versioning;
+
+SELECT * FROM versioning_history;
+
+END;
+
+DROP TABLE versioning;
+DROP TABLE versioning_history;
diff --git a/versioning_function.sql b/versioning_function.sql
index ea46678..f3bb1a2 100644
--- a/versioning_function.sql
+++ b/versioning_function.sql
@@ -8,7 +8,7 @@ DECLARE
manipulate jsonb;
ignore_unchanged_values bool;
commonColumns text[];
- time_stamp_to_use timestamptz := current_timestamp;
+ time_stamp_to_use timestamptz;
range_lower timestamptz;
existing_range tstzrange;
holder record;
@@ -16,7 +16,22 @@ DECLARE
pg_version integer;
newVersion record;
oldVersion record;
+ user_defined_system_time text;
BEGIN
+ -- set custom system time if exists
+ BEGIN
+ SELECT current_setting('user_defined.system_time') INTO user_defined_system_time;
+ IF NOT FOUND OR (user_defined_system_time <> '') IS NOT TRUE THEN
+ time_stamp_to_use := CURRENT_TIMESTAMP;
+ ELSE
+ SELECT TO_TIMESTAMP(
+ user_defined_system_time,
+ 'YYYY-MM-DD HH24:MI:SS.MS.US'
+ ) INTO time_stamp_to_use;
+ END IF;
+ EXCEPTION WHEN OTHERS THEN
+ time_stamp_to_use := CURRENT_TIMESTAMP;
+ END;
IF TG_WHEN != 'BEFORE' OR TG_LEVEL != 'ROW' THEN
RAISE TRIGGER_PROTOCOL_VIOLATED USING
diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql
index 82d31e2..1163c6e 100644
--- a/versioning_function_nochecks.sql
+++ b/versioning_function_nochecks.sql
@@ -8,12 +8,27 @@ DECLARE
manipulate jsonb;
ignore_unchanged_values bool;
commonColumns text[];
- time_stamp_to_use timestamptz := current_timestamp;
+ time_stamp_to_use timestamptz;
range_lower timestamptz;
existing_range tstzrange;
newVersion record;
oldVersion record;
+ user_defined_system_time text;
BEGIN
+ -- set custom system time if exists
+ BEGIN
+ SELECT current_setting('user_defined.system_time') INTO user_defined_system_time;
+ IF NOT FOUND OR (user_defined_system_time <> '') IS NOT TRUE THEN
+ time_stamp_to_use := CURRENT_TIMESTAMP;
+ ELSE
+ SELECT TO_TIMESTAMP(
+ user_defined_system_time,
+ 'YYYY-MM-DD HH24:MI:SS.MS.US'
+ ) INTO time_stamp_to_use;
+ END IF;
+ EXCEPTION WHEN OTHERS THEN
+ time_stamp_to_use := CURRENT_TIMESTAMP;
+ END;
sys_period := TG_ARGV[0];
history_table := TG_ARGV[1];