diff --git a/HISTORY.md b/HISTORY.md index 5533056..2550df8 100644 --- a/HISTORY.md +++ b/HISTORY.md @@ -1,4 +1,8 @@ +# 0.4.0 - 2020/7/14 + +- Breaking change: the versioning function is not quoting and escaping the name of the history table. Any name that needs quoting (upper case, special chars) should be provided as parameters already quoted and escaped. + # 0.3.0 - 2020/7/14 - Add parameter to ignore updates without actual changes diff --git a/README.md b/README.md index 2483c42..cb88436 100644 --- a/README.md +++ b/README.md @@ -1,7 +1,7 @@ # Temporal Tables -_Version: 0.3.0_ +_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. @@ -66,6 +66,11 @@ FOR EACH ROW EXECUTE PROCEDURE versioning( ); ``` +A note on the history table name. Previous versions of this extension quoted and escaped it before usage. +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. + +This is consistent with the c version, simplifies the extension code and fixes an issue with upper case names that weren't properly supported. + Now test with some data: ```sql diff --git a/test/expected/upper_case.out b/test/expected/upper_case.out new file mode 100644 index 0000000..854c6f7 --- /dev/null +++ b/test/expected/upper_case.out @@ -0,0 +1,153 @@ +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 "VersioningHistory" (a bigint, c date, sys_period tstzrange); +CREATE TRIGGER "VersioningTrigger" +BEFORE INSERT OR UPDATE OR DELETE ON "Versioning" +FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', '"VersioningHistory"', false); +-- Insert. +BEGIN; +INSERT INTO "Versioning" (a) VALUES (3); +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + a | b b | ?column? +---+-----+---------- + 1 | | f + 2 | | f + 3 | | t +(3 rows) + +SELECT * FROM "VersioningHistory" ORDER BY a, sys_period; + a | c | sys_period +---+---+------------ +(0 rows) + +COMMIT; +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- Update. +BEGIN; +UPDATE "Versioning" SET a = 4 WHERE a = 3; +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + a | b b | ?column? +---+-----+---------- + 1 | | f + 2 | | f + 4 | | t +(3 rows) + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + a | c | ?column? +---+---+---------- + 3 | | t +(1 row) + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b b +---+----- + 4 | +(1 row) + +COMMIT; +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- Multiple updates. +BEGIN; +UPDATE "Versioning" SET a = 5 WHERE a = 4; +UPDATE "Versioning" SET "b b" = '2012-01-01' WHERE a = 5; +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + a | b b | ?column? +---+------------+---------- + 1 | | f + 2 | | f + 5 | 2012-01-01 | t +(3 rows) + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + a | c | ?column? +---+---+---------- + 3 | | f + 4 | | t +(2 rows) + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b b +---+------------ + 5 | 2012-01-01 +(1 row) + +COMMIT; +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- Delete. +BEGIN; +DELETE FROM "Versioning" WHERE a = 4; +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + a | b b | ?column? +---+------------+---------- + 1 | | f + 2 | | f + 5 | 2012-01-01 | f +(3 rows) + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + a | c | ?column? +---+---+---------- + 3 | | f + 4 | | f +(2 rows) + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b b +---+----- +(0 rows) + +END; +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- Delete. +BEGIN; +DELETE FROM "Versioning"; +SELECT * FROM "Versioning"; + a | b b | sys_period +---+-----+------------ +(0 rows) + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + a | c | ?column? +---+---+---------- + 1 | | t + 2 | | t + 3 | | f + 4 | | f + 5 | | t +(5 rows) + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b b +---+----- +(0 rows) + +END; +DROP TABLE "Versioning"; +DROP TABLE "VersioningHistory"; diff --git a/test/runTest.sh b/test/runTest.sh index 9768582..6e706fa 100644 --- a/test/runTest.sh +++ b/test/runTest.sh @@ -8,7 +8,8 @@ mkdir -p test/result TESTS=" no_history_table no_history_system_period no_system_period invalid_system_period_values invalid_system_period invalid_types - versioning structure combinations different_schema unchanged_values" + versioning upper_case structure combinations + different_schema unchanged_values" for name in $TESTS; do echo "" diff --git a/test/runTestNochecks.sh b/test/runTestNochecks.sh index 7cf0354..d1a11be 100644 --- a/test/runTestNochecks.sh +++ b/test/runTestNochecks.sh @@ -5,7 +5,7 @@ psql temporal_tables_test -q -f versioning_function_nochecks.sql mkdir -p test/result -TESTS="versioning structure combinations different_schema unchanged_values" +TESTS="versioning upper_case structure combinations different_schema unchanged_values" for name in $TESTS; do echo "" diff --git a/test/sql/upper_case.sql b/test/sql/upper_case.sql new file mode 100644 index 0000000..0f1fbe6 --- /dev/null +++ b/test/sql/upper_case.sql @@ -0,0 +1,90 @@ +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 "VersioningHistory" (a bigint, c date, sys_period tstzrange); + +CREATE TRIGGER "VersioningTrigger" +BEFORE INSERT OR UPDATE OR DELETE ON "Versioning" +FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', '"VersioningHistory"', false); + +-- Insert. +BEGIN; + +INSERT INTO "Versioning" (a) VALUES (3); + +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + +SELECT * FROM "VersioningHistory" ORDER BY a, sys_period; + +COMMIT; + +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + +-- Update. +BEGIN; + +UPDATE "Versioning" SET a = 4 WHERE a = 3; + +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + +COMMIT; + +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + +-- Multiple updates. +BEGIN; + +UPDATE "Versioning" SET a = 5 WHERE a = 4; +UPDATE "Versioning" SET "b b" = '2012-01-01' WHERE a = 5; + +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + +COMMIT; + +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + +-- Delete. +BEGIN; + +DELETE FROM "Versioning" WHERE a = 4; + +SELECT a, "b b", lower(sys_period) = CURRENT_TIMESTAMP FROM "Versioning" ORDER BY a, sys_period; + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + +END; + +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + +-- Delete. +BEGIN; + +DELETE FROM "Versioning"; + +SELECT * FROM "Versioning"; + +SELECT a, c, upper(sys_period) = CURRENT_TIMESTAMP FROM "VersioningHistory" ORDER BY a, sys_period; + +SELECT a, "b b" FROM "Versioning" WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + +END; + +DROP TABLE "Versioning"; +DROP TABLE "VersioningHistory"; \ No newline at end of file diff --git a/versioning_function.sql b/versioning_function.sql index 37ec2c8..6c95930 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -14,7 +14,7 @@ DECLARE holder2 record; pg_version integer; BEGIN - -- version 0.3.0 + -- version 0.4.0 IF TG_WHEN != 'BEFORE' OR TG_LEVEL != 'ROW' THEN RAISE TRIGGER_PROTOCOL_VIOLATED USING @@ -165,12 +165,7 @@ BEGIN AND history.attname != sys_period; EXECUTE ('INSERT INTO ' || - CASE split_part(history_table, '.', 2) - WHEN '' THEN - quote_ident(history_table) - ELSE - quote_ident(split_part(history_table, '.', 1)) || '.' || quote_ident(split_part(history_table, '.', 2)) - END || + history_table || '(' || array_to_string(commonColumns , ',') || ',' || diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index 97ea4fc..9577d20 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -11,7 +11,7 @@ DECLARE transaction_info txid_snapshot; existing_range tstzrange; BEGIN - -- version 0.3.0 + -- version 0.4.0 sys_period := TG_ARGV[0]; history_table := TG_ARGV[1]; @@ -62,12 +62,7 @@ BEGIN AND history.attname != sys_period; EXECUTE ('INSERT INTO ' || - CASE split_part(history_table, '.', 2) - WHEN '' THEN - quote_ident(history_table) - ELSE - quote_ident(split_part(history_table, '.', 1)) || '.' || quote_ident(split_part(history_table, '.', 2)) - END || + history_table || '(' || array_to_string(commonColumns , ',') || ',' ||