Skip to content

Commit

Permalink
Add support for excluded columns.
Browse files Browse the repository at this point in the history
These are columns for which updates do not cause `GENERATED ALWAYS AS
ROW START` to change, and historical rows will not be generated.

This is not in the standard, but was requested by several people.
  • Loading branch information
Vik Fearing committed Sep 12, 2019
1 parent a658893 commit 47353c1
Show file tree
Hide file tree
Showing 19 changed files with 1,315 additions and 84 deletions.
6 changes: 6 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,12 @@ The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/).

## [Unreleased]

- Add support for excluded columns. These are columns for which
updates do not cause `GENERATED ALWAYS AS ROW START` to change, and
historical rows will not be generated.

This is not in the standard, but was requested by several people.

## [1.0] – 2019-08-25

### Added
Expand Down
1 change: 1 addition & 0 deletions Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@ REGRESS = install \
periods \
system_time_periods \
system_versioning \
excluded_columns \
unique_foreign \
for_portion_of \
predicates \
Expand Down
16 changes: 16 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -238,6 +238,22 @@ created both by the SQL standard and by this extension. A special
function is provided as a convenience, but `add_period` can also be
called.

### Excluding columns

It might be desirable to prevent some columns from updating the
`SYSTEM_TIME` values. For example, perhaps your `users` table has a
column `last_login` which gets updated all the time and you don’t want
to generate a new historical row (see below) for just that. Ideally such
a column would be in its own table, but if not then it can be excluded
with an optional parameter:

``` sql
SELECT periods.add_system_time_period('example',
excluded_column_names => ARRAY['foo', 'bar']);
```

This functionality is not present in the SQL standard.

## `WITH SYSTEM VERSIONING`

This special `SYSTEM_TIME` period can be used to keep track of changes
Expand Down
38 changes: 21 additions & 17 deletions expected/drop_protection.out
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,8 @@ CREATE TYPE integerrange AS RANGE (SUBTYPE = integer);
CREATE TABLE dp (
id bigint,
s integer,
e integer
e integer,
x boolean
);
/* periods */
SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange');
Expand All @@ -23,12 +24,15 @@ DROP TYPE integerrange;
ERROR: cannot drop rangetype "public.integerrange" because it is used in period "p" on table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 56 at RAISE
/* system_time_periods */
SELECT periods.add_system_time_period('dp');
SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']);
add_system_time_period
------------------------
t
(1 row)

ALTER TABLE dp DROP COLUMN x; -- fails
ERROR: cannot drop or rename column "x" on table "dp" because it is excluded from SYSTEM VERSIONING
CONTEXT: PL/pgSQL function periods.drop_protection() line 124 at RAISE
ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails
ERROR: cannot drop constraint "dp_system_time_end_infinity_check" on table "dp" because it is used in SYSTEM_TIME period
CONTEXT: PL/pgSQL function periods.drop_protection() line 72 at RAISE
Expand All @@ -51,13 +55,13 @@ SELECT periods.add_for_portion_view('dp', 'p');

DROP VIEW dp__for_portion_of_p;
ERROR: cannot drop view "public.dp__for_portion_of_p", call "periods.drop_for_portion_view()" instead
CONTEXT: PL/pgSQL function periods.drop_protection() line 125 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 141 at RAISE
DROP TRIGGER for_portion_of_p ON dp__for_portion_of_p;
ERROR: cannot drop trigger "for_portion_of_p" on view "dp__for_portion_of_p" because it is used in FOR PORTION OF view for period "p" on table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 137 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 153 at RAISE
ALTER TABLE dp DROP CONSTRAINT dp_pkey;
ERROR: cannot drop primary key on table "dp" because it has a FOR PORTION OF view for period "p"
CONTEXT: PL/pgSQL function periods.drop_protection() line 149 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 165 at RAISE
SELECT periods.drop_for_portion_view('dp', 'p');
drop_for_portion_view
-----------------------
Expand All @@ -77,10 +81,10 @@ SELECT periods.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x');

ALTER TABLE dp DROP CONSTRAINT u; -- fails
ERROR: cannot drop constraint "u" on table "dp" because it is used in period unique key "k"
CONTEXT: PL/pgSQL function periods.drop_protection() line 170 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 186 at RAISE
ALTER TABLE dp DROP CONSTRAINT x; -- fails
ERROR: cannot drop constraint "x" on table "dp" because it is used in period unique key "k"
CONTEXT: PL/pgSQL function periods.drop_protection() line 181 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 197 at RAISE
ALTER TABLE dp DROP CONSTRAINT dp_p_check; -- fails
/* foreign_keys */
CREATE TABLE dp_ref (LIKE dp);
Expand All @@ -98,16 +102,16 @@ SELECT periods.add_foreign_key('dp_ref', ARRAY['id'], 'p', 'k', key_name => 'f')

DROP TRIGGER f_fk_insert ON dp_ref; -- fails
ERROR: cannot drop trigger "f_fk_insert" on table "dp_ref" because it is used in period foreign key "f"
CONTEXT: PL/pgSQL function periods.drop_protection() line 197 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 213 at RAISE
DROP TRIGGER f_fk_update ON dp_ref; -- fails
ERROR: cannot drop trigger "f_fk_update" on table "dp_ref" because it is used in period foreign key "f"
CONTEXT: PL/pgSQL function periods.drop_protection() line 208 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 224 at RAISE
DROP TRIGGER f_uk_update ON dp; -- fails
ERROR: cannot drop trigger "f_uk_update" on table "dp" because it is used in period foreign key "f"
CONTEXT: PL/pgSQL function periods.drop_protection() line 220 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 236 at RAISE
DROP TRIGGER f_uk_delete ON dp; -- fails
ERROR: cannot drop trigger "f_uk_delete" on table "dp" because it is used in period foreign key "f"
CONTEXT: PL/pgSQL function periods.drop_protection() line 232 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 248 at RAISE
SELECT periods.drop_foreign_key('dp_ref', 'f');
drop_foreign_key
------------------
Expand All @@ -133,27 +137,27 @@ drop cascades to function dp__between(timestamp with time zone,timestamp with ti
drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone)
drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone)
ERROR: cannot drop table "public.dp_history" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 248 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 264 at RAISE
DROP VIEW dp_with_history CASCADE;
NOTICE: drop cascades to 4 other objects
DETAIL: drop cascades to function dp__as_of(timestamp with time zone)
drop cascades to function dp__between(timestamp with time zone,timestamp with time zone)
drop cascades to function dp__between_symmetric(timestamp with time zone,timestamp with time zone)
drop cascades to function dp__from_to(timestamp with time zone,timestamp with time zone)
ERROR: cannot drop view "public.dp_with_history" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 260 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 276 at RAISE
DROP FUNCTION dp__as_of(timestamp with time zone);
ERROR: cannot drop function "public.dp__as_of(timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 272 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE
DROP FUNCTION dp__between(timestamp with time zone,timestamp with time zone);
ERROR: cannot drop function "public.dp__between(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 272 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE
DROP FUNCTION dp__between_symmetric(timestamp with time zone,timestamp with time zone);
ERROR: cannot drop function "public.dp__between_symmetric(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 272 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE
DROP FUNCTION dp__from_to(timestamp with time zone,timestamp with time zone);
ERROR: cannot drop function "public.dp__from_to(timestamp with time zone,timestamp with time zone)" because it is used in SYSTEM VERSIONING for table "dp"
CONTEXT: PL/pgSQL function periods.drop_protection() line 272 at RAISE
CONTEXT: PL/pgSQL function periods.drop_protection() line 288 at RAISE
SELECT periods.drop_system_versioning('dp', purge => true);
drop_system_versioning
------------------------
Expand Down
7 changes: 5 additions & 2 deletions expected/drop_protection_1.out
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,8 @@ CREATE TYPE integerrange AS RANGE (SUBTYPE = integer);
CREATE TABLE dp (
id bigint,
s integer,
e integer
e integer,
x boolean
);
/* periods */
SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange');
Expand All @@ -22,12 +23,14 @@ SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange');
DROP TYPE integerrange;
ERROR: cannot drop rangetype "public.integerrange" because it is used in period "p" on table "dp"
/* system_time_periods */
SELECT periods.add_system_time_period('dp');
SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']);
add_system_time_period
------------------------
t
(1 row)

ALTER TABLE dp DROP COLUMN x; -- fails
ERROR: cannot drop or rename column "x" on table "dp" because it is excluded from SYSTEM VERSIONING
ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails
ERROR: cannot drop constraint "dp_system_time_end_infinity_check" on table "dp" because it is used in SYSTEM_TIME period
DROP TRIGGER dp_system_time_generated_always ON dp; -- fails
Expand Down
86 changes: 86 additions & 0 deletions expected/excluded_columns.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,86 @@
CREATE TABLE excl (
value text NOT NULL,
null_value integer,
flap text NOT NULL
);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']);
add_system_time_period
------------------------
t
(1 row)

SELECT periods.add_system_versioning('excl');
NOTICE: history table "excl_history" created for "excl", be sure to index it properly
add_system_versioning
-----------------------

(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-------------------------
excl | system_time | system_time_start | system_time_end | tstzrange | excl_system_time_check
(1 row)

TABLE periods.system_time_periods;
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names
------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+-----------------------
excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap}
(1 row)

TABLE periods.system_versioning;
table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to
------------+-------------+--------------------+-------------------+---------------------------------------+------------------------------------------------------------------+----------------------------------------------------------------------------+------------------------------------------------------------------
excl | system_time | excl_history | excl_with_history | excl__as_of(timestamp with time zone) | excl__between(timestamp with time zone,timestamp with time zone) | excl__between_symmetric(timestamp with time zone,timestamp with time zone) | excl__from_to(timestamp with time zone,timestamp with time zone)
(1 row)

BEGIN;
SELECT CURRENT_TIMESTAMP AS now \gset
INSERT INTO excl (value, flap) VALUES ('hello world', 'off');
COMMIT;
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
-------------+------------+------+---------
hello world | | off | f
(1 row)

UPDATE excl SET flap = 'off';
UPDATE excl SET flap = 'on';
UPDATE excl SET flap = 'off';
UPDATE excl SET flap = 'on';
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
-------------+------------+------+---------
hello world | | on | f
(1 row)

BEGIN;
SELECT CURRENT_TIMESTAMP AS now2 \gset
UPDATE excl SET value = 'howdy folks!';
COMMIT;
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
--------------+------------+------+---------
howdy folks! | | on | t
(1 row)

UPDATE excl SET null_value = 0;
SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl;
value | null_value | flap | changed
--------------+------------+------+---------
howdy folks! | 0 | on | t
(1 row)

SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
t
(1 row)

SELECT periods.drop_system_time_period('excl');
drop_system_time_period
-------------------------
t
(1 row)

DROP TABLE excl;
2 changes: 1 addition & 1 deletion expected/health_checks.out
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ ERROR: table "log" must be persistent
CONTEXT: PL/pgSQL function periods.add_period(regclass,name,name,name,regtype,name) line 72 at RAISE
SELECT periods.add_system_time_period('log'); -- fails
ERROR: table "log" must be persistent
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name) line 72 at RAISE
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 72 at RAISE
ALTER TABLE log SET LOGGED;
SELECT periods.add_period('log', 'p', 's', 'e'); -- passes
add_period
Expand Down
27 changes: 15 additions & 12 deletions expected/rename_following.out
Original file line number Diff line number Diff line change
Expand Up @@ -53,26 +53,29 @@ TABLE periods.periods;
(1 row)

/* system_time_periods */
SELECT periods.add_system_time_period('rename_test');
SELECT periods.add_system_time_period('rename_test', excluded_column_names => ARRAY['col3']);
add_system_time_period
------------------------
t
(1 row)

TABLE periods.system_time_periods;
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger
-------------+-------------+--------------------------------------------+------------------------------------------+---------------------------------------+----------------------
rename_test | system_time | rename_test_system_time_end_infinity_check | rename_test_system_time_generated_always | rename_test_system_time_write_history | rename_test_truncate
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names
-------------+-------------+--------------------------------------------+------------------------------------------+---------------------------------------+----------------------+-----------------------
rename_test | system_time | rename_test_system_time_end_infinity_check | rename_test_system_time_generated_always | rename_test_system_time_write_history | rename_test_truncate | {col3}
(1 row)

ALTER TABLE rename_test RENAME col3 TO "COLUMN3";
ERROR: cannot drop or rename column "col3" on table "rename_test" because it is excluded from SYSTEM VERSIONING
CONTEXT: PL/pgSQL function periods.rename_following() line 121 at RAISE
ALTER TABLE rename_test RENAME CONSTRAINT rename_test_system_time_end_infinity_check TO inf_check;
ALTER TRIGGER rename_test_system_time_generated_always ON rename_test RENAME TO generated_always;
ALTER TRIGGER rename_test_system_time_write_history ON rename_test RENAME TO write_history;
ALTER TRIGGER rename_test_truncate ON rename_test RENAME TO trunc;
TABLE periods.system_time_periods;
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger
-------------+-------------+---------------------------+--------------------------+-----------------------+------------------
rename_test | system_time | inf_check | generated_always | write_history | trunc
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names
-------------+-------------+---------------------------+--------------------------+-----------------------+------------------+-----------------------
rename_test | system_time | inf_check | generated_always | write_history | trunc | {col3}
(1 row)

/* for_portion_views */
Expand Down Expand Up @@ -147,19 +150,19 @@ TABLE periods.foreign_keys;

ALTER TABLE rename_test_ref RENAME COLUMN "COLUMN1" TO col1; -- fails
ERROR: cannot drop or rename column "COLUMN1" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q"
CONTEXT: PL/pgSQL function periods.rename_following() line 194 at RAISE
CONTEXT: PL/pgSQL function periods.rename_following() line 210 at RAISE
ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" ON rename_test_ref RENAME TO fk_insert;
ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_insert" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q"
CONTEXT: PL/pgSQL function periods.rename_following() line 229 at RAISE
CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE
ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_update" ON rename_test_ref RENAME TO fk_update;
ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_fk_update" on table "rename_test_ref" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q"
CONTEXT: PL/pgSQL function periods.rename_following() line 229 at RAISE
CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE
ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_update" ON rename_test RENAME TO uk_update;
ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_update" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q"
CONTEXT: PL/pgSQL function periods.rename_following() line 229 at RAISE
CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE
ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" ON rename_test RENAME TO uk_delete;
ERROR: cannot drop or rename trigger "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" on table "rename_test" because it is used in period foreign key "rename_test_ref_col2_COLUMN1_col3_q"
CONTEXT: PL/pgSQL function periods.rename_following() line 229 at RAISE
CONTEXT: PL/pgSQL function periods.rename_following() line 245 at RAISE
TABLE periods.foreign_keys;
key_name | table_name | column_names | period_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger
-------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------
Expand Down
Loading

0 comments on commit 47353c1

Please sign in to comment.