From 59577ef3dd457ad9f0fca14184640085cd545dbf Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Fri, 7 Jan 2022 16:37:52 +0100 Subject: [PATCH 1/9] Created set_system_time function --- system_time_function.sql | 21 +++++++++++++++++++++ 1 file changed, 21 insertions(+) create mode 100644 system_time_function.sql diff --git a/system_time_function.sql b/system_time_function.sql new file mode 100644 index 0000000..187e426 --- /dev/null +++ b/system_time_function.sql @@ -0,0 +1,21 @@ +CREATE OR REPLACE FUNCTION set_system_time(custom_system_time text) +RETURNS timestamptz AS $$ +DECLARE + custom_system_timestamptz timestamptz; +BEGIN + + IF custom_system_time IS NULL THEN + custom_system_timestamptz = CURRENT_TIMESTAMP; + ELSE + SELECT TO_TIMESTAMP( + custom_system_time, + 'YYYY-MM-DD HH24:MI:SS' + ) INTO custom_system_timestamptz; + END IF; + + SET user_defined.system_time = custom_system_timestamptz; + + return custom_system_timestamptz; + +END; +$$ LANGUAGE plpgsql; From 52c8051ef32ca8cae612f67bd6b22e0979831f8b Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Mon, 10 Jan 2022 16:04:08 +0100 Subject: [PATCH 2/9] Updated versioning function to check for custom system time; Updated README --- README.md | 65 +++++++++++++++++++++++++++++--- system_time_function.sql | 30 ++++++++------- versioning_function.sql | 14 ++++++- versioning_function_nochecks.sql | 14 ++++++- 4 files changed, 102 insertions(+), 21 deletions(-) diff --git a/README.md b/README.md index 3087f14..c865cda 100644 --- a/README.md +++ b/README.md @@ -3,16 +3,12 @@ ![](https://github.com/nearform/temporal_tables/workflows/ci/badge.svg) -_Version: 0.4.0_ - This is an attempt to rewrite the postgresql [temporal_tables](https://github.com/arkhipov/temporal_tables) extension in PL/pgSQL, without the need for external c extension. The goal is to be able to use it on AWS RDS and other hosted solutions, where using custom extensions or c functions is not an option. 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 +23,12 @@ Create a database and the versioning function: ```sh createdb temporal_test psql temporal_test < versioning_function.sql +psql temporal_test < system_time_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: @@ -84,7 +86,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; @@ -93,7 +95,7 @@ SELECT * FROM subscriptions; Should return 0 rows ```sql -SELECT * FROM subscriptions_history +SELECT * FROM subscriptions_history; ``` Should return something similar to: @@ -105,6 +107,57 @@ name | state | sys_period 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` (hours are in 24-hour format 00-23). +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/system_time_function.sql b/system_time_function.sql index 187e426..54b962d 100644 --- a/system_time_function.sql +++ b/system_time_function.sql @@ -1,21 +1,25 @@ -CREATE OR REPLACE FUNCTION set_system_time(custom_system_time text) -RETURNS timestamptz AS $$ +CREATE OR REPLACE FUNCTION set_system_time(user_timestamp text) +RETURNS text AS $$ DECLARE - custom_system_timestamptz timestamptz; + custom_system_time text; BEGIN - - IF custom_system_time IS NULL THEN - custom_system_timestamptz = CURRENT_TIMESTAMP; + IF user_timestamp IS NULL THEN + custom_system_time := null; ELSE - SELECT TO_TIMESTAMP( - custom_system_time, - 'YYYY-MM-DD HH24:MI:SS' - ) INTO custom_system_timestamptz; + PERFORM + REGEXP_MATCHES(user_timestamp, + '([0-9]){4}-(0[1-9]|1[0-2])-(0[1-9]|[1-2][0-9]|3[0-1]) ([0-1][0-9]|2[0-3]):[0-5][0-9]:[0-5][0-9]', + 'g'); + IF NOT FOUND THEN + RAISE 'You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23)'; + ELSE + custom_system_time := user_timestamp; + END IF; END IF; + + PERFORM set_config('user_defined.system_time', custom_system_time, false); - SET user_defined.system_time = custom_system_timestamptz; - - return custom_system_timestamptz; + return custom_system_time; END; $$ LANGUAGE plpgsql; diff --git a/versioning_function.sql b/versioning_function.sql index 6c95930..7894e2b 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -6,14 +6,26 @@ DECLARE manipulate jsonb; ignore_unchanged_values bool; commonColumns text[]; - time_stamp_to_use timestamptz := current_timestamp; + time_stamp_to_use timestamptz; range_lower timestamptz; transaction_info txid_snapshot; existing_range tstzrange; holder record; holder2 record; pg_version integer; + user_defined_system_time text; BEGIN + -- set custom system time if exists + 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' + ) INTO time_stamp_to_use; + END IF; + -- version 0.4.0 IF TG_WHEN != 'BEFORE' OR TG_LEVEL != 'ROW' THEN diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index 9577d20..bcf3453 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -6,11 +6,23 @@ DECLARE manipulate jsonb; ignore_unchanged_values bool; commonColumns text[]; - time_stamp_to_use timestamptz := current_timestamp; + time_stamp_to_use timestamptz; range_lower timestamptz; transaction_info txid_snapshot; existing_range tstzrange; + user_defined_system_time text; BEGIN + -- set custom system time if exists + 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' + ) INTO time_stamp_to_use; + END IF; + -- version 0.4.0 sys_period := TG_ARGV[0]; From bca7168450a1e1f2e07bce7a5aea03c72da7be30 Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Mon, 10 Jan 2022 17:09:42 +0100 Subject: [PATCH 3/9] Fixed test setup --- Makefile | 2 ++ test/runTest.sh | 1 + test/runTestNochecks.sh | 1 + 3 files changed, 4 insertions(+) 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/test/runTest.sh b/test/runTest.sh index 6e706fa..7d02ab1 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 diff --git a/test/runTestNochecks.sh b/test/runTestNochecks.sh index d1a11be..7113757 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 From 10955b6c0ceb34ae1022316d2c270f64bff2ee18 Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Tue, 11 Jan 2022 11:24:06 +0100 Subject: [PATCH 4/9] Fixed failing unit tests --- versioning_function.sql | 22 +++++++++++++--------- versioning_function_nochecks.sql | 22 +++++++++++++--------- 2 files changed, 26 insertions(+), 18 deletions(-) diff --git a/versioning_function.sql b/versioning_function.sql index 7894e2b..2a3d14b 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -16,15 +16,19 @@ DECLARE user_defined_system_time text; BEGIN -- set custom system time if exists - 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' - ) INTO time_stamp_to_use; - END IF; + 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' + ) INTO time_stamp_to_use; + END IF; + EXCEPTION WHEN OTHERS THEN + time_stamp_to_use := CURRENT_TIMESTAMP; + END; -- version 0.4.0 diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index bcf3453..aa24f2e 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -13,15 +13,19 @@ DECLARE user_defined_system_time text; BEGIN -- set custom system time if exists - 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' - ) INTO time_stamp_to_use; - END IF; + 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' + ) INTO time_stamp_to_use; + END IF; + EXCEPTION WHEN OTHERS THEN + time_stamp_to_use := CURRENT_TIMESTAMP; + END; -- version 0.4.0 From b6f91a9b1d45f7f4239ac5b05551b8f324e82632 Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Tue, 11 Jan 2022 14:48:08 +0100 Subject: [PATCH 5/9] Added unit tests --- test/expected/invalid_set_system_time.out | 31 +++++++++ test/expected/set_system_time.out | 78 +++++++++++++++++++++++ test/runTest.sh | 2 +- test/sql/invalid_set_system_time.sql | 16 +++++ test/sql/set_system_time.sql | 64 +++++++++++++++++++ 5 files changed, 190 insertions(+), 1 deletion(-) 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/test/expected/invalid_set_system_time.out b/test/expected/invalid_set_system_time.out new file mode 100644 index 0000000..8b4abc2 --- /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 HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('22-13-01 22:59:59'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('2022-12-99 22:59:59'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +-- 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 HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('2022-01-11 22:99:59'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('2022-01-11 22:59:99'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('2022-01-11 22:59'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +SELECT set_system_time('2022-01-11 22'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +-- Invalid values +SELECT set_system_time('Invalid string value'); +ERROR: You must enter a timestamp in the following format: YYYY-MM-DD HH:MI:SS (hours are in 24-hour format 00-23) +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/set_system_time.out b/test/expected/set_system_time.out new file mode 100644 index 0000000..cd8edad --- /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'); + set_system_time +--------------------- + 2001-01-01 22:59:59 +(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+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+01") + 4 | | (,"2001-01-01 22:59:59+01") +(2 rows) + +COMMIT; +-- Delete. +BEGIN; +SELECT set_system_time('2022-01-11 12:00:00'); + set_system_time +--------------------- + 2022-01-11 12:00:00 +(1 row) + +DELETE FROM versioning WHERE a = 4; +SELECT * FROM versioning_history; + a | c | sys_period +---+---+----------------------------- + 3 | | (,"2001-01-01 22:59:59+01") + 4 | | (,"2001-01-01 22:59:59+01") +(2 rows) + +END; +-- Delete. +BEGIN; +DELETE FROM versioning; +SELECT * FROM versioning_history; + a | c | sys_period +---+---+----------------------------- + 3 | | (,"2001-01-01 22:59:59+01") + 4 | | (,"2001-01-01 22:59:59+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 7d02ab1..b6630d8 100644 --- a/test/runTest.sh +++ b/test/runTest.sh @@ -10,7 +10,7 @@ TESTS=" no_history_table no_history_system_period no_system_period invalid_system_period_values invalid_system_period invalid_types versioning upper_case structure combinations - different_schema unchanged_values" + different_schema unchanged_values set_system_time invalid_set_system_time" for name in $TESTS; do echo "" 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..338f761 --- /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'); + +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'); + +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; \ No newline at end of file From 3b3a6df8f3c780390353504f0bab4080c813949f Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Wed, 20 Sep 2023 12:27:33 +0200 Subject: [PATCH 6/9] feat: added support for MS(milliseconds) and US(microseconds) --- README.md | 2 +- system_time_function.sql | 4 +-- test/expected/invalid_set_system_time.out | 18 ++++++------ test/expected/set_system_time.out | 34 +++++++++++------------ test/sql/set_system_time.sql | 6 ++-- versioning_function.sql | 2 +- versioning_function_nochecks.sql | 4 +-- 7 files changed, 35 insertions(+), 35 deletions(-) diff --git a/README.md b/README.md index c865cda..aa6dc0c 100644 --- a/README.md +++ b/README.md @@ -110,7 +110,7 @@ name | state | sys_period ## 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` (hours are in 24-hour format 00-23). +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 diff --git a/system_time_function.sql b/system_time_function.sql index 54b962d..82322a7 100644 --- a/system_time_function.sql +++ b/system_time_function.sql @@ -8,10 +8,10 @@ BEGIN ELSE PERFORM REGEXP_MATCHES(user_timestamp, - '([0-9]){4}-(0[1-9]|1[0-2])-(0[1-9]|[1-2][0-9]|3[0-1]) ([0-1][0-9]|2[0-3]):[0-5][0-9]:[0-5][0-9]', + '(\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 HH:MI:SS (hours are in 24-hour format 00-23)'; + 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; diff --git a/test/expected/invalid_set_system_time.out b/test/expected/invalid_set_system_time.out index 8b4abc2..43aa78a 100644 --- a/test/expected/invalid_set_system_time.out +++ b/test/expected/invalid_set_system_time.out @@ -1,24 +1,24 @@ -- 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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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 HH:MI:SS (hours are in 24-hour format 00-23) +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); diff --git a/test/expected/set_system_time.out b/test/expected/set_system_time.out index cd8edad..5112c21 100644 --- a/test/expected/set_system_time.out +++ b/test/expected/set_system_time.out @@ -8,10 +8,10 @@ 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'); +SELECT set_system_time('2001-01-01 22:59:59.001.000234'); set_system_time ---------------------- - 2001-01-01 22:59:59 +-------------------------------- + 2001-01-01 22:59:59.001.000234 (1 row) INSERT INTO versioning (a) VALUES (3); @@ -26,8 +26,8 @@ BEGIN; UPDATE versioning SET a = 4 WHERE a = 3; SELECT * FROM versioning_history; a | c | sys_period ----+---+----------------------------- - 3 | | (,"2001-01-01 22:59:59+01") +---+---+------------------------------------ + 3 | | (,"2001-01-01 22:59:59.001234+01") (1 row) COMMIT; @@ -37,26 +37,26 @@ 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+01") - 4 | | (,"2001-01-01 22:59:59+01") +---+---+------------------------------------ + 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'); +SELECT set_system_time('2022-01-11 12:00:00.000.000000'); set_system_time ---------------------- - 2022-01-11 12:00:00 +-------------------------------- + 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+01") - 4 | | (,"2001-01-01 22:59:59+01") +---+---+------------------------------------ + 3 | | (,"2001-01-01 22:59:59.001234+01") + 4 | | (,"2001-01-01 22:59:59.001234+01") (2 rows) END; @@ -65,9 +65,9 @@ BEGIN; DELETE FROM versioning; SELECT * FROM versioning_history; a | c | sys_period ----+---+----------------------------- - 3 | | (,"2001-01-01 22:59:59+01") - 4 | | (,"2001-01-01 22:59:59+01") +---+---+------------------------------------ + 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") diff --git a/test/sql/set_system_time.sql b/test/sql/set_system_time.sql index 338f761..b81d18b 100644 --- a/test/sql/set_system_time.sql +++ b/test/sql/set_system_time.sql @@ -13,7 +13,7 @@ FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_history', fa -- Insert. BEGIN; -SELECT set_system_time('2001-01-01 22:59:59'); +SELECT set_system_time('2001-01-01 22:59:59.001.000234'); INSERT INTO versioning (a) VALUES (3); @@ -43,7 +43,7 @@ COMMIT; -- Delete. BEGIN; -SELECT set_system_time('2022-01-11 12:00:00'); +SELECT set_system_time('2022-01-11 12:00:00.000.000000'); DELETE FROM versioning WHERE a = 4; @@ -61,4 +61,4 @@ SELECT * FROM versioning_history; END; DROP TABLE versioning; -DROP TABLE versioning_history; \ No newline at end of file +DROP TABLE versioning_history; diff --git a/versioning_function.sql b/versioning_function.sql index 2a3d14b..6263247 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -23,7 +23,7 @@ BEGIN ELSE SELECT TO_TIMESTAMP( user_defined_system_time, - 'YYYY-MM-DD HH24:MI:SS' + 'YYYY-MM-DD HH24:MI:SS.MS.US' ) INTO time_stamp_to_use; END IF; EXCEPTION WHEN OTHERS THEN diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index aa24f2e..0785b91 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -20,7 +20,7 @@ BEGIN ELSE SELECT TO_TIMESTAMP( user_defined_system_time, - 'YYYY-MM-DD HH24:MI:SS' + 'YYYY-MM-DD HH24:MI:SS.MS.US' ) INTO time_stamp_to_use; END IF; EXCEPTION WHEN OTHERS THEN @@ -97,4 +97,4 @@ BEGIN RETURN OLD; END; -$$ LANGUAGE plpgsql; \ No newline at end of file +$$ LANGUAGE plpgsql; From 3d9b60172c1593c34a17d9ffd6e6cc3098e9724e Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Wed, 20 Sep 2023 12:36:56 +0200 Subject: [PATCH 7/9] chore: bump package version to 0.6.0 --- package.json | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/package.json b/package.json index c941128..ab25d9c 100644 --- a/package.json +++ b/package.json @@ -1,6 +1,6 @@ { "name": "temporal_tables", - "version": "0.5.0", + "version": "0.6.0", "description": "A postgresql temporal_tables extension in PL/pgSQL", "repository": { "type": "git", From 568825dd99d7af203c395ec27e842b3a1096719b Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Wed, 20 Sep 2023 13:01:07 +0200 Subject: [PATCH 8/9] chore: reverted version back to 0.5.0 and updated the script to include the new file --- package.json | 2 +- scripts/update-version.js | 2 +- system_time_function.sql | 2 ++ versioning_function.sql | 2 +- versioning_function_nochecks.sql | 2 +- 5 files changed, 6 insertions(+), 4 deletions(-) diff --git a/package.json b/package.json index ab25d9c..c941128 100644 --- a/package.json +++ b/package.json @@ -1,6 +1,6 @@ { "name": "temporal_tables", - "version": "0.6.0", + "version": "0.5.0", "description": "A postgresql temporal_tables extension in PL/pgSQL", "repository": { "type": "git", 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 index 82322a7..a100ac3 100644 --- a/system_time_function.sql +++ b/system_time_function.sql @@ -1,3 +1,5 @@ +-- version 0.5.0 + CREATE OR REPLACE FUNCTION set_system_time(user_timestamp text) RETURNS text AS $$ DECLARE diff --git a/versioning_function.sql b/versioning_function.sql index 19e439a..f3bb1a2 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -1,4 +1,4 @@ --- version 0.6.0 +-- version 0.5.0 CREATE OR REPLACE FUNCTION versioning() RETURNS TRIGGER AS $$ diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index 611767f..1163c6e 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -1,4 +1,4 @@ --- version 0.6.0 +-- version 0.5.0 CREATE OR REPLACE FUNCTION versioning() RETURNS TRIGGER AS $$ From 4ba930f2bace3730c8c39fc00b92c32a7c88ca20 Mon Sep 17 00:00:00 2001 From: Radomir Drndarski Date: Wed, 20 Sep 2023 15:25:10 +0200 Subject: [PATCH 9/9] docs: removed unnecessary line --- README.md | 1 - 1 file changed, 1 deletion(-) diff --git a/README.md b/README.md index 0e78510..07bca56 100644 --- a/README.md +++ b/README.md @@ -23,7 +23,6 @@ Create a database and the versioning function: ```sh createdb temporal_test psql temporal_test < versioning_function.sql -psql temporal_test < system_time_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: