Skip to content

Commit

Permalink
Feature - Current version history (#71)
Browse files Browse the repository at this point in the history
* Adds a new feature to the extension that enables the current versions of records to also be stored in the history table
* adding some friendly comments
* Added an additional test to check current row ranges are set correctly doing an update and removed a redundant delete test

Co-authored-by: Marcos César de Oliveira <[email protected]>
Co-authored-by: Levente A <[email protected]>
Co-authored-by: Simone Busoli <[email protected]>
  • Loading branch information
4 people authored Nov 1, 2024
1 parent 9abf823 commit 1b512f9
Show file tree
Hide file tree
Showing 13 changed files with 525 additions and 48 deletions.
4 changes: 3 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
*.tmp
.DS_Store
test/result
test/result
.env
.envrc
38 changes: 38 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ For a speedier but riskier option, `versioning_function_nochecks.sql` is 2x fast
Over time, new features have been introduced while maintaining backward compatibility:

- [Ignore updates with no actual changes](#ignore-unchanged-values)
- [Include the current version in history](#include-current-version-in-history)

<a name="usage"></a>

Expand Down Expand Up @@ -184,6 +185,43 @@ FOR EACH ROW EXECUTE PROCEDURE versioning(
);
```


<a name="include-current-version-in-history"></a>

### Include the current version in history

By default this extension only creates a record in the history table for historical records. This feature enables users to also store the details of the current record in the history table. Simplifying cases when you want a consolidated view of both the current and historical states.

e.g

```sql
SELECT * FROM t_history WHERE x <@ sys_period;
```
when `include_current_version_in_history` is true

as opposed to

``` sql
SELECT * FROM t WHERE x <@ sys_period
UNION
SELECT * FROM t_history WHERE x <@ sys_period;
```
when `include_current_version_in_history` is false (or unset)

This is a fith parameter in the extension so all previous parameters need to be specified when using this.

The parameter is set by default to false, set it to true to include current version of records in the history table.

``` sql
CREATE TRIGGER versioning_trigger
BEFORE INSERT OR UPDATE OR DELETE ON subscriptions
FOR EACH ROW EXECUTE PROCEDURE versioning(
'sys_period', 'subscriptions_history', true, false, true
);
```



<a name="migrations"></a>

## Migrations
Expand Down
21 changes: 21 additions & 0 deletions test/expected/noop_update.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
-- No-op Update Test
CREATE TABLE versioning_noop (a bigint, "b b" date, sys_period tstzrange);
-- Insert initial data.
INSERT INTO versioning_noop (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
CREATE TABLE versioning_noop_history (a bigint, "b b" date, sys_period tstzrange);
CREATE TRIGGER versioning_noop_trigger
BEFORE INSERT OR UPDATE OR DELETE ON versioning_noop
FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_noop_history', false, true, true);
-- Test no-op update (the row is updated without any value changes).
BEGIN;
UPDATE versioning_noop SET a = 1, "b b" = '2020-01-01' WHERE a = 1;
-- Check that no history record was created.
SELECT * FROM versioning_noop_history; -- Expecting 0 rows in history.
a | b b | sys_period
---+-----+------------
(0 rows)

COMMIT;
-- Cleanup
DROP TABLE versioning_noop;
DROP TABLE versioning_noop_history;
20 changes: 10 additions & 10 deletions test/expected/set_system_time.out
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,7 @@ 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")
3 | | (,"2001-01-01 22:59:59.001234+00")
(1 row)

COMMIT;
Expand All @@ -38,8 +38,8 @@ 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")
3 | | (,"2001-01-01 22:59:59.001234+00")
4 | | (,"2001-01-01 22:59:59.001234+00")
(2 rows)

COMMIT;
Expand All @@ -55,8 +55,8 @@ 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")
3 | | (,"2001-01-01 22:59:59.001234+00")
4 | | (,"2001-01-01 22:59:59.001234+00")
(2 rows)

END;
Expand All @@ -66,11 +66,11 @@ 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")
3 | | (,"2001-01-01 22:59:59.001234+00")
4 | | (,"2001-01-01 22:59:59.001234+00")
1 | | (,"2022-01-11 12:00:00+00")
2 | | (,"2022-01-11 12:00:00+00")
5 | | (,"2022-01-11 12:00:00+00")
(5 rows)

END;
Expand Down
160 changes: 160 additions & 0 deletions test/expected/versioning_including_current_version_in_history.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,160 @@
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, false, true);
-- 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 a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | | t
(1 row)

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 versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | | t
4 | |
(2 rows)

SELECT a, c, lower(sys_period) = CURRENT_TIMESTAMP FROM versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | |
4 | | t
(2 rows)

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 versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | | f
4 | | t
5 | | t
5 | |
(4 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 versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | | f
4 | | f
5 | | f
5 | |
(4 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 versioning_history ORDER BY a, sys_period;
a | c | ?column?
---+---+----------
3 | | f
4 | | f
5 | | f
5 | | t
(4 rows)

END;
DROP TABLE versioning;
DROP TABLE versioning_history;
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
-- Rollback Behavior Test
CREATE TABLE versioning_rollback (a bigint, "b b" date, sys_period tstzrange);
-- Insert initial data.
INSERT INTO versioning_rollback (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));
CREATE TABLE versioning_rollback_history (a bigint, "b b" date, sys_period tstzrange);
CREATE TRIGGER versioning_rollback_trigger
BEFORE INSERT OR UPDATE OR DELETE ON versioning_rollback
FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_rollback_history', false, false, true);
-- Test rollback during update.
BEGIN;
UPDATE versioning_rollback SET a = 2 WHERE a = 1;
-- Rollback the transaction.
ROLLBACK;
-- Ensure no history record was created.
SELECT * FROM versioning_rollback_history; -- Expecting 0 rows in history.
a | b b | sys_period
---+-----+------------
(0 rows)

-- Ensure original data is unchanged.
SELECT * FROM versioning_rollback; -- Expecting original value a = 1.
a | b b | sys_period
---+------------+-----------------------------
1 | 2020-01-01 | ["2000-01-01 00:00:00+00",)
(1 row)

-- Cleanup
DROP TABLE versioning_rollback;
DROP TABLE versioning_rollback_history;
3 changes: 2 additions & 1 deletion test/runTest.sh
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,8 @@ TESTS="
versioning upper_case structure combinations
different_schema unchanged_values unchanged_version_values
non_equality_types non_equality_types_unchanged_values
set_system_time invalid_set_system_time
set_system_time invalid_set_system_time versioning_including_current_version_in_history
versioning_rollback_include_current_version_in_history noop_update
"

for name in $TESTS; do
Expand Down
3 changes: 2 additions & 1 deletion test/runTestNochecks.sh
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,8 @@ mkdir -p test/result
TESTS="
versioning upper_case structure combinations different_schema unchanged_values
non_equality_types non_equality_types_unchanged_values
unchanged_version_values
unchanged_version_values versioning_including_current_version_in_history
versioning_rollback_include_current_version_in_history noop_update
"

for name in $TESTS; do
Expand Down
25 changes: 25 additions & 0 deletions test/sql/noop_update.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- No-op Update Test
CREATE TABLE versioning_noop (a bigint, "b b" date, sys_period tstzrange);

-- Insert initial data.
INSERT INTO versioning_noop (a, "b b", sys_period) VALUES (1, '2020-01-01', tstzrange('2000-01-01', NULL));

CREATE TABLE versioning_noop_history (a bigint, "b b" date, sys_period tstzrange);

CREATE TRIGGER versioning_noop_trigger
BEFORE INSERT OR UPDATE OR DELETE ON versioning_noop
FOR EACH ROW EXECUTE PROCEDURE versioning('sys_period', 'versioning_noop_history', false, true, true);

-- Test no-op update (the row is updated without any value changes).
BEGIN;

UPDATE versioning_noop SET a = 1, "b b" = '2020-01-01' WHERE a = 1;

-- Check that no history record was created.
SELECT * FROM versioning_noop_history; -- Expecting 0 rows in history.

COMMIT;

-- Cleanup
DROP TABLE versioning_noop;
DROP TABLE versioning_noop_history;
Loading

0 comments on commit 1b512f9

Please sign in to comment.