Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add set_system_time function #32

Merged
merged 10 commits into from
Sep 20, 2023
2 changes: 2 additions & 0 deletions Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -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"
Expand All @@ -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"
Expand Down
62 changes: 58 additions & 4 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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:
Expand All @@ -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:

```
Expand Down Expand Up @@ -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;
Expand All @@ -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:
Expand All @@ -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") |

<a name="system-time"></a>
## 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")


<a name="additional-features"></a>

## Additional features
Expand Down
2 changes: 1 addition & 1 deletion scripts/update-version.js
Original file line number Diff line number Diff line change
Expand Up @@ -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`, {
Expand Down
27 changes: 27 additions & 0 deletions system_time_function.sql
Original file line number Diff line number Diff line change
@@ -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;
31 changes: 31 additions & 0 deletions test/expected/invalid_set_system_time.out
Original file line number Diff line number Diff line change
@@ -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.
10 changes: 5 additions & 5 deletions test/expected/non_equality_types.out
Original file line number Diff line number Diff line change
@@ -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;
11 changes: 5 additions & 6 deletions test/expected/non_equality_types_unchanged_values.out
Original file line number Diff line number Diff line change
@@ -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
78 changes: 78 additions & 0 deletions test/expected/set_system_time.out
Original file line number Diff line number Diff line change
@@ -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;
5 changes: 4 additions & 1 deletion test/runTest.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand All @@ -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 ""
Expand Down
1 change: 1 addition & 0 deletions test/runTestNochecks.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand Down
16 changes: 16 additions & 0 deletions test/sql/invalid_set_system_time.sql
Original file line number Diff line number Diff line change
@@ -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();
64 changes: 64 additions & 0 deletions test/sql/set_system_time.sql
Original file line number Diff line number Diff line change
@@ -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;
Loading
Loading