From 1b93858d5923378fe8eb1a1707dad48476741194 Mon Sep 17 00:00:00 2001 From: Nathaniel Brown Date: Mon, 26 Sep 2022 20:55:07 -0400 Subject: [PATCH] Don't create versions that would be identical to previous version --- test/expected/unchanged_version_values.out | 58 ++++++++++++++++++++++ test/runTest.sh | 2 +- test/runTestNochecks.sh | 4 +- test/sql/unchanged_version_values.sql | 42 ++++++++++++++++ versioning_function.sql | 19 +++++-- versioning_function_nochecks.sql | 17 +++++-- 6 files changed, 131 insertions(+), 11 deletions(-) create mode 100644 test/expected/unchanged_version_values.out create mode 100644 test/sql/unchanged_version_values.sql diff --git a/test/expected/unchanged_version_values.out b/test/expected/unchanged_version_values.out new file mode 100644 index 0000000..f8d2db2 --- /dev/null +++ b/test/expected/unchanged_version_values.out @@ -0,0 +1,58 @@ +CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange); +-- Insert some data before versioning is enabled. +INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL)); +CREATE TABLE versioning_history (b bigint, 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, true); +-- Update with no changes that would affect history +BEGIN; +UPDATE versioning SET a = 3; +SELECT a, b FROM versioning ORDER BY a, sys_period; + a | b +---+--- + 3 | 2 +(1 row) + +SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period; + b | ?column? +---+---------- +(0 rows) + +SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b +---+--- +(0 rows) + +COMMIT; +-- Make sure that the next transaction's CURRENT_TIMESTAMP is different. +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- Update with changes that would affect history. +BEGIN; +UPDATE versioning SET b = 3; +SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period; + a | b | ?column? +---+---+---------- + 3 | 3 | t +(1 row) + +SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period; + b | ?column? +---+---------- + 2 | t +(1 row) + +SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + a | b +---+--- + 3 | 3 +(1 row) + +COMMIT; +DROP TABLE versioning; +DROP TABLE versioning_history; diff --git a/test/runTest.sh b/test/runTest.sh index 6e706fa..5e0649f 100644 --- a/test/runTest.sh +++ b/test/runTest.sh @@ -9,7 +9,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 unchanged_version_values" for name in $TESTS; do echo "" diff --git a/test/runTestNochecks.sh b/test/runTestNochecks.sh index d1a11be..bc20e8a 100644 --- a/test/runTestNochecks.sh +++ b/test/runTestNochecks.sh @@ -5,7 +5,9 @@ psql temporal_tables_test -q -f versioning_function_nochecks.sql mkdir -p test/result -TESTS="versioning upper_case structure combinations different_schema unchanged_values" +TESTS=" + versioning upper_case structure combinations different_schema unchanged_values + unchanged_version_values" for name in $TESTS; do echo "" diff --git a/test/sql/unchanged_version_values.sql b/test/sql/unchanged_version_values.sql new file mode 100644 index 0000000..c6caf7e --- /dev/null +++ b/test/sql/unchanged_version_values.sql @@ -0,0 +1,42 @@ +CREATE TABLE versioning (a bigint, b bigint, sys_period tstzrange); + +-- Insert some data before versioning is enabled. +INSERT INTO versioning (a, b, sys_period) VALUES (2, 2, tstzrange('2000-01-01', NULL)); + +CREATE TABLE versioning_history (b bigint, 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, true); + +-- Update with no changes that would affect history +BEGIN; + +UPDATE versioning SET a = 3; + +SELECT a, b FROM versioning ORDER BY a, sys_period; + +SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period; + +SELECT a, 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); + +-- Update with changes that would affect history. +BEGIN; + +UPDATE versioning SET b = 3; + +SELECT a, b, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning ORDER BY a, sys_period; + +SELECT b, upper(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY b, sys_period; + +SELECT a, b FROM versioning WHERE lower(sys_period) = CURRENT_TIMESTAMP ORDER BY a, sys_period; + +COMMIT; + +DROP TABLE versioning; +DROP TABLE versioning_history; \ No newline at end of file diff --git a/versioning_function.sql b/versioning_function.sql index 6c95930..b1a9213 100644 --- a/versioning_function.sql +++ b/versioning_function.sql @@ -13,6 +13,8 @@ DECLARE holder record; holder2 record; pg_version integer; + newVersion record; + oldVersion record; BEGIN -- version 0.4.0 @@ -36,10 +38,6 @@ BEGIN history_table := TG_ARGV[1]; ignore_unchanged_values := TG_ARGV[3]; - IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND NEW IS NOT DISTINCT FROM OLD THEN - RETURN OLD; - END IF; - -- check if sys_period exists on original table SELECT atttypid, attndims INTO holder FROM pg_attribute WHERE attrelid = TG_RELID AND attname = sys_period AND NOT attisdropped; IF NOT FOUND THEN @@ -163,7 +161,18 @@ BEGIN INNER JOIN main ON history.attname = main.attname AND history.attname != sys_period; - + -- skip version if it would be identical to the previous version + IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND array_length(commonColumns, 1) > 0 THEN + EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')' + USING NEW + INTO newVersion; + EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')' + USING OLD + INTO oldVersion; + IF newVersion IS NOT DISTINCT FROM oldVersion THEN + RETURN NEW; + END IF; + END IF; EXECUTE ('INSERT INTO ' || history_table || '(' || diff --git a/versioning_function_nochecks.sql b/versioning_function_nochecks.sql index 9577d20..7d3051c 100644 --- a/versioning_function_nochecks.sql +++ b/versioning_function_nochecks.sql @@ -10,6 +10,8 @@ DECLARE range_lower timestamptz; transaction_info txid_snapshot; existing_range tstzrange; + newVersion record; + oldVersion record; BEGIN -- version 0.4.0 @@ -17,9 +19,6 @@ BEGIN history_table := TG_ARGV[1]; ignore_unchanged_values := TG_ARGV[3]; - IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND NEW IS NOT DISTINCT FROM OLD THEN - RETURN OLD; - END IF; IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN -- Ignore rows already modified in this transaction @@ -60,7 +59,17 @@ BEGIN INNER JOIN main ON history.attname = main.attname AND history.attname != sys_period; - + -- skip version if it would be identical to the previous version + IF ignore_unchanged_values AND TG_OP = 'UPDATE' AND array_length(commonColumns, 1) > 0 THEN EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')' + USING NEW + INTO newVersion; + EXECUTE 'SELECT ROW($1.' || array_to_string(commonColumns , ', $1.') || ')' + USING OLD + INTO oldVersion; + IF newVersion IS NOT DISTINCT FROM oldVersion THEN + RETURN NEW; + END IF; + END IF; EXECUTE ('INSERT INTO ' || history_table || '(' ||