-
Notifications
You must be signed in to change notification settings - Fork 78
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* 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
- Loading branch information
Showing
14 changed files
with
324 additions
and
19 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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(); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
Oops, something went wrong.