Skip to content

Commit

Permalink
Don't create versions that would be identical to previous version (#35)
Browse files Browse the repository at this point in the history
  • Loading branch information
nathanielobrown authored Oct 11, 2022
1 parent 4894907 commit 9255241
Show file tree
Hide file tree
Showing 6 changed files with 131 additions and 11 deletions.
58 changes: 58 additions & 0 deletions test/expected/unchanged_version_values.out
Original file line number Diff line number Diff line change
@@ -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;
2 changes: 1 addition & 1 deletion test/runTest.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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 ""
Expand Down
4 changes: 3 additions & 1 deletion test/runTestNochecks.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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 ""
Expand Down
42 changes: 42 additions & 0 deletions test/sql/unchanged_version_values.sql
Original file line number Diff line number Diff line change
@@ -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;
19 changes: 14 additions & 5 deletions versioning_function.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,8 @@ DECLARE
holder record;
holder2 record;
pg_version integer;
newVersion record;
oldVersion record;
BEGIN

IF TG_WHEN != 'BEFORE' OR TG_LEVEL != 'ROW' THEN
Expand All @@ -37,10 +39,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
Expand Down Expand Up @@ -164,7 +162,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 ||
'(' ||
Expand Down
17 changes: 13 additions & 4 deletions versioning_function_nochecks.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,15 +12,14 @@ DECLARE
range_lower timestamptz;
transaction_info txid_snapshot;
existing_range tstzrange;
newVersion record;
oldVersion record;
BEGIN

sys_period := TG_ARGV[0];
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
Expand Down Expand Up @@ -61,7 +60,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 ||
'(' ||
Expand Down

0 comments on commit 9255241

Please sign in to comment.