From 47353c14647d2950b8cb31024f1f6d30e0f22c5f Mon Sep 17 00:00:00 2001 From: Vik Fearing Date: Wed, 11 Sep 2019 01:52:47 +0200 Subject: [PATCH] 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. --- CHANGELOG.md | 6 + Makefile | 1 + README.md | 16 + expected/drop_protection.out | 38 +- expected/drop_protection_1.out | 7 +- expected/excluded_columns.out | 86 +++ expected/health_checks.out | 2 +- expected/rename_following.out | 27 +- expected/rename_following_1.out | 16 +- expected/system_time_periods.out | 20 +- expected/system_time_periods_1.out | 16 +- expected/system_versioning.out | 33 +- expected/system_versioning_1.out | 33 +- periods--1.0--1.1.sql | 901 +++++++++++++++++++++++++++++ periods.c | 138 ++++- sql/drop_protection.sql | 6 +- sql/excluded_columns.sql | 36 ++ sql/rename_following.sql | 3 +- sql/system_versioning.sql | 14 +- 19 files changed, 1315 insertions(+), 84 deletions(-) create mode 100644 expected/excluded_columns.out create mode 100644 sql/excluded_columns.sql diff --git a/CHANGELOG.md b/CHANGELOG.md index acad496..6b4953d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -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 diff --git a/Makefile b/Makefile index 88d940c..53c6466 100644 --- a/Makefile +++ b/Makefile @@ -9,6 +9,7 @@ REGRESS = install \ periods \ system_time_periods \ system_versioning \ + excluded_columns \ unique_foreign \ for_portion_of \ predicates \ diff --git a/README.md b/README.md index 323bc4a..0338677 100644 --- a/README.md +++ b/README.md @@ -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 diff --git a/expected/drop_protection.out b/expected/drop_protection.out index 9ca5e1f..e70e8e2 100644 --- a/expected/drop_protection.out +++ b/expected/drop_protection.out @@ -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'); @@ -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 @@ -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 ----------------------- @@ -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); @@ -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 ------------------ @@ -133,7 +137,7 @@ 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) @@ -141,19 +145,19 @@ 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 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 ------------------------ diff --git a/expected/drop_protection_1.out b/expected/drop_protection_1.out index 502677a..83b8333 100644 --- a/expected/drop_protection_1.out +++ b/expected/drop_protection_1.out @@ -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'); @@ -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 diff --git a/expected/excluded_columns.out b/expected/excluded_columns.out new file mode 100644 index 0000000..f05925b --- /dev/null +++ b/expected/excluded_columns.out @@ -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; diff --git a/expected/health_checks.out b/expected/health_checks.out index 8219ba5..cfd8b54 100644 --- a/expected/health_checks.out +++ b/expected/health_checks.out @@ -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 diff --git a/expected/rename_following.out b/expected/rename_following.out index 12958cd..b71c017 100644 --- a/expected/rename_following.out +++ b/expected/rename_following.out @@ -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 */ @@ -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 -------------------------------------+-----------------+---------------------+-------------+------------------------------+------------+---------------+---------------+-----------------------------------------------+-----------------------------------------------+-----------------------------------------------+----------------------------------------------- diff --git a/expected/rename_following_1.out b/expected/rename_following_1.out index e67aa92..1ee233a 100644 --- a/expected/rename_following_1.out +++ b/expected/rename_following_1.out @@ -53,26 +53,28 @@ 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 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 */ diff --git a/expected/system_time_periods.out b/expected/system_time_periods.out index 952fb3d..ef5b3c4 100644 --- a/expected/system_time_periods.out +++ b/expected/system_time_periods.out @@ -116,9 +116,9 @@ TABLE periods.periods; (1 row) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------ - sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- + sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {} (1 row) SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); @@ -145,9 +145,9 @@ TABLE periods.periods; (1 row) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ - sysver | system_time | i | g | w | t + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- + sysver | system_time | i | g | w | t | {} (1 row) SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); @@ -169,8 +169,8 @@ TABLE periods.periods; (0 rows) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- (0 rows) /* Forbid UNIQUE keys on system_time columns */ @@ -222,7 +222,7 @@ SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- pa SELECT periods.add_system_time_period('no_unique'); -- fails ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys -CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name) line 46 at RAISE +CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 46 at RAISE SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_start_p'); drop_unique_key ----------------- @@ -278,5 +278,5 @@ SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', ' SELECT periods.add_system_time_period('no_unique_ref'); -- fails ERROR: columns for SYSTEM_TIME must not be part of foreign keys -CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name) line 166 at RAISE +CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 166 at RAISE DROP TABLE no_unique, no_unique_ref; diff --git a/expected/system_time_periods_1.out b/expected/system_time_periods_1.out index ee8d75c..14d462d 100644 --- a/expected/system_time_periods_1.out +++ b/expected/system_time_periods_1.out @@ -116,9 +116,9 @@ TABLE periods.periods; (1 row) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------ - sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+-------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- + sysver | system_time | sysver_endname_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {} (1 row) SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); @@ -145,9 +145,9 @@ TABLE periods.periods; (1 row) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ - sysver | system_time | i | g | w | t + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- + sysver | system_time | i | g | w | t | {} (1 row) SELECT periods.drop_system_time_period('sysver', drop_behavior => 'CASCADE', purge => true); @@ -169,8 +169,8 @@ TABLE periods.periods; (0 rows) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- (0 rows) /* Forbid UNIQUE keys on system_time columns */ diff --git a/expected/system_versioning.out b/expected/system_versioning.out index e090f02..07daa5a 100644 --- a/expected/system_versioning.out +++ b/expected/system_versioning.out @@ -13,17 +13,17 @@ FROM pg_settings WHERE name = 'server_version_num'; (1 row) /* Basic SYSTEM VERSIONING */ -CREATE TABLE sysver (val text); -SELECT periods.add_system_time_period('sysver'); +CREATE TABLE sysver (val text, flap boolean); +SELECT periods.add_system_time_period('sysver', excluded_column_names => ARRAY['flap']); 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 -------------+-------------+---------------------------------------+-------------------------------------+----------------------------------+------------------ - sysver | system_time | sysver_system_time_end_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- + sysver | system_time | sysver_system_time_end_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {flap} (1 row) TABLE periods.system_versioning; @@ -69,7 +69,7 @@ TABLE periods.system_versioning; sysver | system_time | sysver_history | sysver_with_history | sysver__as_of(timestamp with time zone) | sysver__between(timestamp with time zone,timestamp with time zone) | sysver__between_symmetric(timestamp with time zone,timestamp with time zone) | sysver__from_to(timestamp with time zone,timestamp with time zone) (1 row) -INSERT INTO sysver (val) VALUES ('hello'); +INSERT INTO sysver (val, flap) VALUES ('hello', false); SELECT val FROM sysver; val ------- @@ -95,6 +95,23 @@ SELECT val FROM sysver_history ORDER BY system_time_start; hello (1 row) +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +SELECT val FROM sysver; + val +------- + world +(1 row) + +SELECT val FROM sysver_history ORDER BY system_time_start; + val +------- + hello +(1 row) + SELECT transaction_timestamp() AS ts2 \gset DELETE FROM sysver; SELECT val FROM sysver; @@ -268,7 +285,7 @@ TABLE periods.periods; (0 rows) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- (0 rows) diff --git a/expected/system_versioning_1.out b/expected/system_versioning_1.out index cb7cee8..288f80a 100644 --- a/expected/system_versioning_1.out +++ b/expected/system_versioning_1.out @@ -13,17 +13,17 @@ FROM pg_settings WHERE name = 'server_version_num'; (1 row) /* Basic SYSTEM VERSIONING */ -CREATE TABLE sysver (val text); -SELECT periods.add_system_time_period('sysver'); +CREATE TABLE sysver (val text, flap boolean); +SELECT periods.add_system_time_period('sysver', excluded_column_names => ARRAY['flap']); 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 -------------+-------------+---------------------------------------+-------------------------------------+----------------------------------+------------------ - sysver | system_time | sysver_system_time_end_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------------------+-------------------------------------+----------------------------------+------------------+----------------------- + sysver | system_time | sysver_system_time_end_infinity_check | sysver_system_time_generated_always | sysver_system_time_write_history | sysver_truncate | {flap} (1 row) TABLE periods.system_versioning; @@ -69,7 +69,7 @@ TABLE periods.system_versioning; sysver | system_time | sysver_history | sysver_with_history | sysver__as_of(timestamp with time zone) | sysver__between(timestamp with time zone,timestamp with time zone) | sysver__between_symmetric(timestamp with time zone,timestamp with time zone) | sysver__from_to(timestamp with time zone,timestamp with time zone) (1 row) -INSERT INTO sysver (val) VALUES ('hello'); +INSERT INTO sysver (val, flap) VALUES ('hello', false); SELECT val FROM sysver; val ------- @@ -95,6 +95,23 @@ SELECT val FROM sysver_history ORDER BY system_time_start; hello (1 row) +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +SELECT val FROM sysver; + val +------- + world +(1 row) + +SELECT val FROM sysver_history ORDER BY system_time_start; + val +------- + hello +(1 row) + SELECT transaction_timestamp() AS ts2 \gset DELETE FROM sysver; SELECT val FROM sysver; @@ -268,7 +285,7 @@ TABLE periods.periods; (0 rows) TABLE periods.system_time_periods; - table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger -------------+-------------+---------------------------+--------------------------+-----------------------+------------------ + table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names +------------+-------------+---------------------------+--------------------------+-----------------------+------------------+----------------------- (0 rows) diff --git a/periods--1.0--1.1.sql b/periods--1.0--1.1.sql index e69de29..81d280c 100644 --- a/periods--1.0--1.1.sql +++ b/periods--1.0--1.1.sql @@ -0,0 +1,901 @@ +ALTER TABLE periods.system_time_periods + ADD COLUMN excluded_column_names name[] NOT NULL DEFAULT '{}'; + +DROP FUNCTION periods.add_system_time_period(regclass, name, name, name, name, name, name, name); + +CREATE FUNCTION periods.add_system_time_period( + table_class regclass, + start_column_name name DEFAULT 'system_time_start', + end_column_name name DEFAULT 'system_time_end', + bounds_check_constraint name DEFAULT NULL, + infinity_check_constraint name DEFAULT NULL, + generated_always_trigger name DEFAULT NULL, + write_history_trigger name DEFAULT NULL, + truncate_trigger name DEFAULT NULL, + excluded_column_names name[] DEFAULT '{}') + RETURNS boolean + LANGUAGE plpgsql +AS +$function$ +#variable_conflict use_variable +DECLARE + period_name CONSTANT name := 'system_time'; + + schema_name name; + table_name name; + kind "char"; + persistence "char"; + alter_commands text[] DEFAULT '{}'; + + start_attnum smallint; + start_type oid; + start_collation oid; + start_notnull boolean; + + end_attnum smallint; + end_type oid; + end_collation oid; + end_notnull boolean; + + DATE_OID CONSTANT integer := 1082; + TIMESTAMP_OID CONSTANT integer := 1114; + TIMESTAMPTZ_OID CONSTANT integer := 1184; + range_type regtype; +BEGIN + IF table_class IS NULL THEN + RAISE EXCEPTION 'no table name specified'; + END IF; + + /* Always serialize operations on our catalogs */ + PERFORM periods._serialize(table_class); + + /* + * REFERENCES: + * SQL:2016 4.15.2.2 + * SQL:2016 11.7 + * SQL:2016 11.27 + */ + + /* The columns must not be part of UNIQUE keys. SQL:2016 11.7 SR 5)b) */ + IF EXISTS ( + SELECT FROM periods.unique_keys AS uk + WHERE uk.column_names && ARRAY[start_column_name, end_column_name]) + THEN + RAISE EXCEPTION 'columns in period for SYSTEM_TIME are not allowed in UNIQUE keys'; + END IF; + + /* Must be a regular persistent base table. SQL:2016 11.27 SR 2 */ + + SELECT n.nspname, c.relname, c.relpersistence, c.relkind + INTO schema_name, table_name, persistence, kind + FROM pg_catalog.pg_class AS c + JOIN pg_catalog.pg_namespace AS n ON n.oid = c.relnamespace + WHERE c.oid = table_class; + + IF kind <> 'r' THEN + /* + * The main reason partitioned tables aren't supported yet is simply + * beceuase I haven't put any thought into it. + * Maybe it's trivial, maybe not. + */ + IF kind = 'p' THEN + RAISE EXCEPTION 'partitioned tables are not supported yet'; + END IF; + + RAISE EXCEPTION 'relation % is not a table', $1; + END IF; + + IF persistence <> 'p' THEN + /* We could probably accept unlogged tables but what's the point? */ + RAISE EXCEPTION 'table "%" must be persistent', table_class; + END IF; + + /* + * Check if period already exists. + * + * SQL:2016 11.27 SR 4.a + */ + IF EXISTS (SELECT FROM periods.periods AS p WHERE (p.table_name, p.period_name) = (table_class, period_name)) THEN + RAISE EXCEPTION 'period for SYSTEM_TIME already exists on table "%"', table_class; + END IF; + + /* + * Although we are not creating a new object, the SQL standard says that + * periods are in the same namespace as columns, so prevent that. + * + * SQL:2016 11.27 SR 4.b + */ + IF EXISTS (SELECT FROM pg_catalog.pg_attribute AS a WHERE (a.attrelid, a.attname) = (table_class, period_name)) THEN + RAISE EXCEPTION 'a column named system_time already exists for table "%"', table_class; + END IF; + + /* The standard says that the columns must not exist already, but we don't obey that rule for now. */ + + /* Get start column information */ + SELECT a.attnum, a.atttypid, a.attnotnull + INTO start_attnum, start_type, start_notnull + FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (table_class, start_column_name); + + IF NOT FOUND THEN + /* + * First add the column with DEFAULT of -infinity to fill the + * current rows, then replace the DEFAULT with transaction_timestamp() for future + * rows. + * + * The default value is just for self-documentation anyway because + * the trigger will enforce the value. + */ + alter_commands := alter_commands || format('ADD COLUMN %I timestamp with time zone NOT NULL DEFAULT ''-infinity''', start_column_name); + + start_attnum := 0; + start_type := 'timestamp with time zone'::regtype; + start_notnull := true; + END IF; + alter_commands := alter_commands || format('ALTER COLUMN %I SET DEFAULT transaction_timestamp()', start_column_name); + + IF start_attnum < 0 THEN + RAISE EXCEPTION 'system columns cannot be used in periods'; + END IF; + + /* Get end column information */ + SELECT a.attnum, a.atttypid, a.attnotnull + INTO end_attnum, end_type, end_notnull + FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (table_class, end_column_name); + + IF NOT FOUND THEN + alter_commands := alter_commands || format('ADD COLUMN %I timestamp with time zone NOT NULL DEFAULT ''infinity''', end_column_name); + + end_attnum := 0; + end_type := 'timestamp with time zone'::regtype; + end_notnull := true; + ELSE + alter_commands := alter_commands || format('ALTER COLUMN %I SET DEFAULT ''infinity''', end_column_name); + END IF; + + IF end_attnum < 0 THEN + RAISE EXCEPTION 'system columns cannot be used in periods'; + END IF; + + /* Verify compatibility of start/end columns */ + IF start_type::regtype NOT IN ('date', 'timestamp without time zone', 'timestamp with time zone') THEN + RAISE EXCEPTION 'SYSTEM_TIME periods must be of type "date", "timestamp without time zone", or "timestamp with time zone"'; + END IF; + IF start_type <> end_type THEN + RAISE EXCEPTION 'start and end columns must be of same type'; + END IF; + + /* Get appropriate range type */ + CASE start_type + WHEN DATE_OID THEN range_type := 'daterange'; + WHEN TIMESTAMP_OID THEN range_type := 'tsrange'; + WHEN TIMESTAMPTZ_OID THEN range_type := 'tstzrange'; + ELSE + RAISE EXCEPTION 'unexpected data type: "%"', start_type::regtype; + END CASE; + + /* can't be part of a foreign key */ + IF EXISTS ( + SELECT FROM periods.foreign_keys AS fk + WHERE fk.table_name = table_class + AND fk.column_names && ARRAY[start_column_name, end_column_name]) + THEN + RAISE EXCEPTION 'columns for SYSTEM_TIME must not be part of foreign keys'; + END IF; + + /* + * Period columns must not be nullable. + */ + IF NOT start_notnull THEN + alter_commands := alter_commands || format('ALTER COLUMN %I SET NOT NULL', start_column_name); + END IF; + IF NOT end_notnull THEN + alter_commands := alter_commands || format('ALTER COLUMN %I SET NOT NULL', end_column_name); + END IF; + + /* + * Find and appropriate a CHECK constraint to make sure that start < end. + * Create one if necessary. + * + * SQL:2016 11.27 GR 2.b + */ + DECLARE + condef CONSTANT text := format('CHECK ((%I < %I))', start_column_name, end_column_name); + context text; + BEGIN + IF bounds_check_constraint IS NOT NULL THEN + /* We were given a name, does it exist? */ + SELECT pg_catalog.pg_get_constraintdef(c.oid) + INTO context + FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.conname) = (table_class, bounds_check_constraint) + AND c.contype = 'c'; + + IF FOUND THEN + /* Does it match? */ + IF context <> condef THEN + RAISE EXCEPTION 'constraint "%" on table "%" does not match', bounds_check_constraint, table_class; + END IF; + ELSE + /* If it doesn't exist, we'll use the name for the one we create. */ + alter_commands := alter_commands || format('ADD CONSTRAINT %I %s', bounds_check_constraint, condef); + END IF; + ELSE + /* No name given, can we appropriate one? */ + SELECT c.conname + INTO bounds_check_constraint + FROM pg_catalog.pg_constraint AS c + WHERE c.conrelid = table_class + AND c.contype = 'c' + AND pg_catalog.pg_get_constraintdef(c.oid) = condef; + + /* Make our own then */ + IF NOT FOUND THEN + SELECT c.relname + INTO table_name + FROM pg_catalog.pg_class AS c + WHERE c.oid = table_class; + + bounds_check_constraint := periods._choose_name(ARRAY[table_name, period_name], 'check'); + alter_commands := alter_commands || format('ADD CONSTRAINT %I %s', bounds_check_constraint, condef); + END IF; + END IF; + END; + + /* + * Find and appropriate a CHECK constraint to make sure that end = 'infinity'. + * Create one if necessary. + * + * SQL:2016 4.15.2.2 + */ + DECLARE + condef CONSTANT text := format('CHECK ((%I = ''infinity''::timestamp with time zone))', end_column_name); + context text; + BEGIN + IF infinity_check_constraint IS NOT NULL THEN + /* We were given a name, does it exist? */ + SELECT pg_catalog.pg_get_constraintdef(c.oid) + INTO context + FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.conname) = (table_class, infinity_check_constraint) + AND c.contype = 'c'; + + IF FOUND THEN + /* Does it match? */ + IF context <> condef THEN + RAISE EXCEPTION 'constraint "%" on table "%" does not match', infinity_check_constraint, table_class; + END IF; + ELSE + /* If it doesn't exist, we'll use the name for the one we create. */ + alter_commands := alter_commands || format('ADD CONSTRAINT %I %s', infinity_check_constraint, condef); + END IF; + ELSE + /* No name given, can we appropriate one? */ + SELECT c.conname + INTO infinity_check_constraint + FROM pg_catalog.pg_constraint AS c + WHERE c.conrelid = table_class + AND c.contype = 'c' + AND pg_catalog.pg_get_constraintdef(c.oid) = condef; + + /* Make our own then */ + IF NOT FOUND THEN + SELECT c.relname + INTO table_name + FROM pg_catalog.pg_class AS c + WHERE c.oid = table_class; + + infinity_check_constraint := periods._choose_name(ARRAY[table_name, end_column_name], 'infinity_check'); + alter_commands := alter_commands || format('ADD CONSTRAINT %I %s', infinity_check_constraint, condef); + END IF; + END IF; + END; + + /* If we've created any work for ourselves, do it now */ + IF alter_commands <> '{}' THEN + EXECUTE format('ALTER TABLE %I.%I %s', schema_name, table_name, array_to_string(alter_commands, ', ')); + + IF start_attnum = 0 THEN + SELECT a.attnum + INTO start_attnum + FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (table_class, start_column_name); + END IF; + + IF end_attnum = 0 THEN + SELECT a.attnum + INTO end_attnum + FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (table_class, end_column_name); + END IF; + END IF; + + generated_always_trigger := coalesce( + generated_always_trigger, + periods._choose_name(ARRAY[table_name], 'system_time_generated_always')); + EXECUTE format('CREATE TRIGGER %I BEFORE INSERT OR UPDATE ON %s FOR EACH ROW EXECUTE PROCEDURE periods.generated_always_as_row_start_end()', generated_always_trigger, table_class); + + write_history_trigger := coalesce( + write_history_trigger, + periods._choose_name(ARRAY[table_name], 'system_time_write_history')); + EXECUTE format('CREATE TRIGGER %I AFTER INSERT OR UPDATE OR DELETE ON %s FOR EACH ROW EXECUTE PROCEDURE periods.write_history()', write_history_trigger, table_class); + + truncate_trigger := coalesce( + truncate_trigger, + periods._choose_name(ARRAY[table_name], 'truncate')); + EXECUTE format('CREATE TRIGGER %I AFTER TRUNCATE ON %s FOR EACH STATEMENT EXECUTE PROCEDURE periods.truncate_system_versioning()', truncate_trigger, table_class); + + INSERT INTO periods.periods (table_name, period_name, start_column_name, end_column_name, range_type, bounds_check_constraint) + VALUES (table_class, period_name, start_column_name, end_column_name, range_type, bounds_check_constraint); + + INSERT INTO periods.system_time_periods ( + table_name, period_name, infinity_check_constraint, + generated_always_trigger, write_history_trigger, truncate_trigger, + excluded_column_names) + VALUES ( + table_class, period_name, infinity_check_constraint, + generated_always_trigger, write_history_trigger, truncate_trigger, + excluded_column_names); + + RETURN true; +END; +$function$; + +CREATE OR REPLACE FUNCTION periods.drop_protection() + RETURNS event_trigger + LANGUAGE plpgsql +AS +$function$ +#variable_conflict use_variable +DECLARE + r record; + table_name regclass; + period_name name; +BEGIN + /* + * This function is called after the fact, so we have to just look to see + * if anything is missing in the catalogs if we just store the name and not + * a reg* type. + */ + + --- + --- periods + --- + + /* If one of our tables is being dropped, remove references to it */ + FOR table_name, period_name IN + SELECT p.table_name, p.period_name + FROM periods.periods AS p + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = p.table_name + WHERE dobj.object_type = 'table' + ORDER BY dobj.ordinality + LOOP + PERFORM periods.drop_period(table_name, period_name, 'CASCADE', true); + END LOOP; + + /* + * If a column belonging to one of our periods is dropped, we need to reject that. + * SQL:2016 11.23 SR 6 + */ + FOR r IN + SELECT dobj.object_identity, p.period_name + FROM periods.periods AS p + JOIN pg_catalog.pg_attribute AS sa ON (sa.attrelid, sa.attname) = (p.table_name, p.start_column_name) + JOIN pg_catalog.pg_attribute AS ea ON (ea.attrelid, ea.attname) = (p.table_name, p.end_column_name) + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = p.table_name AND dobj.objsubid IN (sa.attnum, ea.attnum) + WHERE dobj.object_type = 'table column' + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop column "%" because it is part of the period "%"', + r.object_identity, r.period_name; + END LOOP; + + /* Also reject dropping the rangetype */ + FOR r IN + SELECT dobj.object_identity, p.table_name, p.period_name + FROM periods.periods AS p + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = p.range_type + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop rangetype "%" because it is used in period "%" on table "%"', + r.object_identity, r.period_name, r.table_name; + END LOOP; + + --- + --- system_time_periods + --- + + /* Complain if the infinity CHECK constraint is missing. */ + FOR r IN + SELECT p.table_name, p.infinity_check_constraint + FROM periods.system_time_periods AS p + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.conname) = (p.table_name, p.infinity_check_constraint)) + LOOP + RAISE EXCEPTION 'cannot drop constraint "%" on table "%" because it is used in SYSTEM_TIME period', + r.infinity_check_constraint, r.table_name; + END LOOP; + + /* Complain if the GENERATED ALWAYS AS ROW START/END trigger is missing. */ + FOR r IN + SELECT p.table_name, p.generated_always_trigger + FROM periods.system_time_periods AS p + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (p.table_name, p.generated_always_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in SYSTEM_TIME period', + r.generated_always_trigger, r.table_name; + END LOOP; + + /* Complain if the write_history trigger is missing. */ + FOR r IN + SELECT p.table_name, p.write_history_trigger + FROM periods.system_time_periods AS p + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (p.table_name, p.write_history_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in SYSTEM_TIME period', + r.write_history_trigger, r.table_name; + END LOOP; + + /* Complain if the TRUNCATE trigger is missing. */ + FOR r IN + SELECT p.table_name, p.truncate_trigger + FROM periods.system_time_periods AS p + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (p.table_name, p.truncate_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in SYSTEM_TIME period', + r.truncate_trigger, r.table_name; + END LOOP; + + /* + * We can't reliably find out what a column was renamed to, so just error + * out in this case. + */ + FOR r IN + SELECT stp.table_name, u.column_name + FROM periods.system_time_periods AS stp + CROSS JOIN LATERAL unnest(stp.excluded_column_names) AS u (column_name) + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (stp.table_name, u.column_name)) + LOOP + RAISE EXCEPTION 'cannot drop or rename column "%" on table "%" because it is excluded from SYSTEM VERSIONING', + r.column_name, r.table_name; + END LOOP; + + --- + --- for_portion_views + --- + + /* Reject dropping the FOR PORTION OF view. */ + FOR r IN + SELECT dobj.object_identity + FROM periods.for_portion_views AS fpv + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = fpv.view_name + WHERE dobj.object_type = 'view' + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop view "%", call "periods.drop_for_portion_view()" instead', + r.object_identity; + END LOOP; + + /* Complain if the FOR PORTION OF trigger is missing. */ + FOR r IN + SELECT fpv.table_name, fpv.period_name, fpv.view_name, fpv.trigger_name + FROM periods.for_portion_views AS fpv + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (fpv.view_name, fpv.trigger_name)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on view "%" because it is used in FOR PORTION OF view for period "%" on table "%"', + r.trigger_name, r.view_name, r.period_name, r.table_name; + END LOOP; + + /* Complain if the table's primary key has been dropped. */ + FOR r IN + SELECT fpv.table_name, fpv.period_name + FROM periods.for_portion_views AS fpv + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.contype) = (fpv.table_name, 'p')) + LOOP + RAISE EXCEPTION 'cannot drop primary key on table "%" because it has a FOR PORTION OF view for period "%"', + r.table_name, r.period_name; + END LOOP; + + --- + --- unique_keys + --- + + /* + * We don't need to protect the individual columns as long as we protect + * the indexes. PostgreSQL will make sure they stick around. + */ + + /* Complain if the indexes implementing our unique indexes are missing. */ + FOR r IN + SELECT uk.key_name, uk.table_name, uk.unique_constraint + FROM periods.unique_keys AS uk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.conname) = (uk.table_name, uk.unique_constraint)) + LOOP + RAISE EXCEPTION 'cannot drop constraint "%" on table "%" because it is used in period unique key "%"', + r.unique_constraint, r.table_name, r.key_name; + END LOOP; + + FOR r IN + SELECT uk.key_name, uk.table_name, uk.exclude_constraint + FROM periods.unique_keys AS uk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_constraint AS c + WHERE (c.conrelid, c.conname) = (uk.table_name, uk.exclude_constraint)) + LOOP + RAISE EXCEPTION 'cannot drop constraint "%" on table "%" because it is used in period unique key "%"', + r.exclude_constraint, r.table_name, r.key_name; + END LOOP; + + --- + --- foreign_keys + --- + + /* Complain if any of the triggers are missing */ + FOR r IN + SELECT fk.key_name, fk.table_name, fk.fk_insert_trigger + FROM periods.foreign_keys AS fk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (fk.table_name, fk.fk_insert_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in period foreign key "%"', + r.fk_insert_trigger, r.table_name, r.key_name; + END LOOP; + + FOR r IN + SELECT fk.key_name, fk.table_name, fk.fk_update_trigger + FROM periods.foreign_keys AS fk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (fk.table_name, fk.fk_update_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in period foreign key "%"', + r.fk_update_trigger, r.table_name, r.key_name; + END LOOP; + + FOR r IN + SELECT fk.key_name, uk.table_name, fk.uk_update_trigger + FROM periods.foreign_keys AS fk + JOIN periods.unique_keys AS uk ON uk.key_name = fk.unique_key + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (uk.table_name, fk.uk_update_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in period foreign key "%"', + r.uk_update_trigger, r.table_name, r.key_name; + END LOOP; + + FOR r IN + SELECT fk.key_name, uk.table_name, fk.uk_delete_trigger + FROM periods.foreign_keys AS fk + JOIN periods.unique_keys AS uk ON uk.key_name = fk.unique_key + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (uk.table_name, fk.uk_delete_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in period foreign key "%"', + r.uk_delete_trigger, r.table_name, r.key_name; + END LOOP; + + --- + --- system_versioning + --- + + FOR r IN + SELECT dobj.object_identity, sv.table_name + FROM periods.system_versioning AS sv + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = sv.history_table_name + WHERE dobj.object_type = 'table' + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop table "%" because it is used in SYSTEM VERSIONING for table "%"', + r.object_identity, r.table_name; + END LOOP; + + FOR r IN + SELECT dobj.object_identity, sv.table_name + FROM periods.system_versioning AS sv + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid = sv.view_name + WHERE dobj.object_type = 'view' + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop view "%" because it is used in SYSTEM VERSIONING for table "%"', + r.object_identity, r.table_name; + END LOOP; + + FOR r IN + SELECT dobj.object_identity, sv.table_name + FROM periods.system_versioning AS sv + JOIN pg_catalog.pg_event_trigger_dropped_objects() WITH ORDINALITY AS dobj + ON dobj.objid IN (sv.func_as_of, sv.func_between, sv.func_between_symmetric, sv.func_from_to) + WHERE dobj.object_type = 'function' + ORDER BY dobj.ordinality + LOOP + RAISE EXCEPTION 'cannot drop function "%" because it is used in SYSTEM VERSIONING for table "%"', + r.object_identity, r.table_name; + END LOOP; +END; +$function$; + +CREATE OR REPLACE FUNCTION periods.rename_following() + RETURNS event_trigger + LANGUAGE plpgsql +AS +$function$ +#variable_conflict use_variable +DECLARE + r record; + sql text; +BEGIN + /* + * Anything that is stored by reg* type will auto-adjust, but anything we + * store by name will need to be updated after a rename. One way to do this + * is to recreate the constraints we have and pull new names out that way. + * If we are unable to do something like that, we must raise an exception. + */ + + --- + --- periods + --- + + /* + * Start and end columns of a period can be found by the bounds check + * constraint. + */ + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.periods SET start_column_name = %L, end_column_name = %L WHERE (table_name, period_name) = (%L::regclass, %L)', + sa.attname, ea.attname, p.table_name, p.period_name) + FROM periods.periods AS p + JOIN pg_catalog.pg_constraint AS c ON (c.conrelid, c.conname) = (p.table_name, p.bounds_check_constraint) + JOIN pg_catalog.pg_attribute AS sa ON sa.attrelid = p.table_name + JOIN pg_catalog.pg_attribute AS ea ON ea.attrelid = p.table_name + WHERE (p.start_column_name, p.end_column_name) <> (sa.attname, ea.attname) + AND pg_catalog.pg_get_constraintdef(c.oid) = format('CHECK ((%I < %I))', sa.attname, ea.attname) + LOOP + EXECUTE sql; + END LOOP; + + /* + * Inversely, the bounds check constraint can be retrieved via the start + * and end columns. + */ + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.periods SET bounds_check_constraint = %L WHERE (table_name, period_name) = (%L::regclass, %L)', + c.conname, p.table_name, p.period_name) + FROM periods.periods AS p + JOIN pg_catalog.pg_constraint AS c ON c.conrelid = p.table_name + JOIN pg_catalog.pg_attribute AS sa ON sa.attrelid = p.table_name + JOIN pg_catalog.pg_attribute AS ea ON ea.attrelid = p.table_name + WHERE p.bounds_check_constraint <> c.conname + AND pg_catalog.pg_get_constraintdef(c.oid) = format('CHECK ((%I < %I))', sa.attname, ea.attname) + AND (p.start_column_name, p.end_column_name) = (sa.attname, ea.attname) + AND NOT EXISTS (SELECT FROM pg_catalog.pg_constraint AS _c WHERE (_c.conrelid, _c.conname) = (p.table_name, p.bounds_check_constraint)) + LOOP + EXECUTE sql; + END LOOP; + + --- + --- system_time_periods + --- + + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.system_time_periods SET infinity_check_constraint = %L WHERE table_name = %L::regclass', + c.conname, p.table_name) + FROM periods.periods AS p + JOIN periods.system_time_periods AS stp ON (stp.table_name, stp.period_name) = (p.table_name, p.period_name) + JOIN pg_catalog.pg_constraint AS c ON c.conrelid = p.table_name + JOIN pg_catalog.pg_attribute AS ea ON ea.attrelid = p.table_name + WHERE stp.infinity_check_constraint <> c.conname + AND pg_catalog.pg_get_constraintdef(c.oid) = format('CHECK ((%I = ''infinity''::%s))', ea.attname, format_type(ea.atttypid, ea.atttypmod)) + AND p.end_column_name = ea.attname + AND NOT EXISTS (SELECT FROM pg_catalog.pg_constraint AS _c WHERE (_c.conrelid, _c.conname) = (stp.table_name, stp.infinity_check_constraint)) + LOOP + EXECUTE sql; + END LOOP; + + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.system_time_periods SET generated_always_trigger = %L WHERE table_name = %L::regclass', + t.tgname, stp.table_name) + FROM periods.system_time_periods AS stp + JOIN pg_catalog.pg_trigger AS t ON t.tgrelid = stp.table_name + WHERE t.tgname <> stp.generated_always_trigger + AND t.tgfoid = 'periods.generated_always_as_row_start_end()'::regprocedure + AND NOT EXISTS (SELECT FROM pg_catalog.pg_trigger AS _t WHERE (_t.tgrelid, _t.tgname) = (stp.table_name, stp.generated_always_trigger)) + LOOP + EXECUTE sql; + END LOOP; + + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.system_time_periods SET write_history_trigger = %L WHERE table_name = %L::regclass', + t.tgname, stp.table_name) + FROM periods.system_time_periods AS stp + JOIN pg_catalog.pg_trigger AS t ON t.tgrelid = stp.table_name + WHERE t.tgname <> stp.write_history_trigger + AND t.tgfoid = 'periods.write_history()'::regprocedure + AND NOT EXISTS (SELECT FROM pg_catalog.pg_trigger AS _t WHERE (_t.tgrelid, _t.tgname) = (stp.table_name, stp.write_history_trigger)) + LOOP + EXECUTE sql; + END LOOP; + + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.system_time_periods SET truncate_trigger = %L WHERE table_name = %L::regclass', + t.tgname, stp.table_name) + FROM periods.system_time_periods AS stp + JOIN pg_catalog.pg_trigger AS t ON t.tgrelid = stp.table_name + WHERE t.tgname <> stp.truncate_trigger + AND t.tgfoid = 'periods.truncate_system_versioning()'::regprocedure + AND NOT EXISTS (SELECT FROM pg_catalog.pg_trigger AS _t WHERE (_t.tgrelid, _t.tgname) = (stp.table_name, stp.truncate_trigger)) + LOOP + EXECUTE sql; + END LOOP; + + /* + * We can't reliably find out what a column was renamed to, so just error + * out in this case. + */ + FOR r IN + SELECT stp.table_name, u.column_name + FROM periods.system_time_periods AS stp + CROSS JOIN LATERAL unnest(stp.excluded_column_names) AS u (column_name) + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (stp.table_name, u.column_name)) + LOOP + RAISE EXCEPTION 'cannot drop or rename column "%" on table "%" because it is excluded from SYSTEM VERSIONING', + r.column_name, r.table_name; + END LOOP; + + --- + --- for_portion_views + --- + + FOR sql IN + SELECT pg_catalog.format('UPDATE periods.for_portion_views SET trigger_name = %L WHERE (table_name, period_name) = (%L::regclass, %L)', + t.tgname, fpv.table_name, fpv.period_name) + FROM periods.for_portion_views AS fpv + JOIN pg_catalog.pg_trigger AS t ON t.tgrelid = fpv.view_name + WHERE t.tgname <> fpv.trigger_name + AND t.tgfoid = 'periods.update_portion_of()'::regprocedure + AND NOT EXISTS (SELECT FROM pg_catalog.pg_trigger AS _t WHERE (_t.tgrelid, _t.tgname) = (fpv.table_name, fpv.trigger_name)) + LOOP + EXECUTE sql; + END LOOP; + + --- + --- unique_keys + --- + + FOR sql IN + SELECT format('UPDATE periods.unique_keys SET column_names = %L WHERE key_name = %L', + a.column_names, uk.key_name) + FROM periods.unique_keys AS uk + JOIN periods.periods AS p ON (p.table_name, p.period_name) = (uk.table_name, uk.period_name) + JOIN pg_catalog.pg_constraint AS c ON (c.conrelid, c.conname) = (uk.table_name, uk.unique_constraint) + JOIN LATERAL ( + SELECT array_agg(a.attname ORDER BY u.ordinality) AS column_names + FROM unnest(c.conkey) WITH ORDINALITY AS u (attnum, ordinality) + JOIN pg_catalog.pg_attribute AS a ON (a.attrelid, a.attnum) = (uk.table_name, u.attnum) + WHERE a.attname NOT IN (p.start_column_name, p.end_column_name) + ) AS a ON true + WHERE uk.column_names <> a.column_names + LOOP + EXECUTE sql; + END LOOP; + + FOR sql IN + SELECT format('UPDATE periods.unique_keys SET unique_constraint = %L WHERE key_name = %L', + c.conname, uk.key_name) + FROM periods.unique_keys AS uk + JOIN periods.periods AS p ON (p.table_name, p.period_name) = (uk.table_name, uk.period_name) + CROSS JOIN LATERAL unnest(uk.column_names || ARRAY[p.start_column_name, p.end_column_name]) WITH ORDINALITY AS u (column_name, ordinality) + JOIN pg_catalog.pg_constraint AS c ON c.conrelid = uk.table_name + WHERE NOT EXISTS (SELECT FROM pg_constraint AS _c WHERE (_c.conrelid, _c.conname) = (uk.table_name, uk.unique_constraint)) + GROUP BY uk.key_name, c.oid, c.conname + HAVING format('UNIQUE (%s)', string_agg(quote_ident(u.column_name), ', ' ORDER BY u.ordinality)) = pg_catalog.pg_get_constraintdef(c.oid) + LOOP + EXECUTE sql; + END LOOP; + + FOR sql IN + SELECT format('UPDATE periods.unique_keys SET exclude_constraint = %L WHERE key_name = %L', + c.conname, uk.key_name) + FROM periods.unique_keys AS uk + JOIN periods.periods AS p ON (p.table_name, p.period_name) = (uk.table_name, uk.period_name) + CROSS JOIN LATERAL unnest(uk.column_names) WITH ORDINALITY AS u (column_name, ordinality) + JOIN pg_catalog.pg_constraint AS c ON c.conrelid = uk.table_name + WHERE NOT EXISTS (SELECT FROM pg_catalog.pg_constraint AS _c WHERE (_c.conrelid, _c.conname) = (uk.table_name, uk.exclude_constraint)) + GROUP BY uk.key_name, c.oid, c.conname, p.range_type, p.start_column_name, p.end_column_name + HAVING format('EXCLUDE USING gist (%s, %I(%I, %I, ''[)''::text) WITH &&)', + string_agg(quote_ident(u.column_name) || ' WITH =', ', ' ORDER BY u.ordinality), + p.range_type, + p.start_column_name, + p.end_column_name) = pg_catalog.pg_get_constraintdef(c.oid) + LOOP + EXECUTE sql; + END LOOP; + + --- + --- foreign_keys + --- + + /* + * We can't reliably find out what a column was renamed to, so just error + * out in this case. + */ + FOR r IN + SELECT fk.key_name, fk.table_name, u.column_name + FROM periods.foreign_keys AS fk + CROSS JOIN LATERAL unnest(fk.column_names) AS u (column_name) + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_attribute AS a + WHERE (a.attrelid, a.attname) = (fk.table_name, u.column_name)) + LOOP + RAISE EXCEPTION 'cannot drop or rename column "%" on table "%" because it is used in period foreign key "%"', + r.column_name, r.table_name, r.key_name; + END LOOP; + + /* + * Since there can be multiple foreign keys, there is no reliable way to + * know which trigger might belong to what, so just error out. + */ + FOR r IN + SELECT fk.key_name, fk.table_name, fk.fk_insert_trigger AS trigger_name + FROM periods.foreign_keys AS fk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (fk.table_name, fk.fk_insert_trigger)) + UNION ALL + SELECT fk.key_name, fk.table_name, fk.fk_update_trigger AS trigger_name + FROM periods.foreign_keys AS fk + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (fk.table_name, fk.fk_update_trigger)) + UNION ALL + SELECT fk.key_name, uk.table_name, fk.uk_update_trigger AS trigger_name + FROM periods.foreign_keys AS fk + JOIN periods.unique_keys AS uk ON uk.key_name = fk.unique_key + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (uk.table_name, fk.uk_update_trigger)) + UNION ALL + SELECT fk.key_name, uk.table_name, fk.uk_delete_trigger AS trigger_name + FROM periods.foreign_keys AS fk + JOIN periods.unique_keys AS uk ON uk.key_name = fk.unique_key + WHERE NOT EXISTS ( + SELECT FROM pg_catalog.pg_trigger AS t + WHERE (t.tgrelid, t.tgname) = (uk.table_name, fk.uk_delete_trigger)) + LOOP + RAISE EXCEPTION 'cannot drop or rename trigger "%" on table "%" because it is used in period foreign key "%"', + r.trigger_name, r.table_name, r.key_name; + END LOOP; + + --- + --- system_versioning + --- + + /* Nothing to do here */ +END; +$function$; + diff --git a/periods.c b/periods.c index 564e75d..97f8aca 100644 --- a/periods.c +++ b/periods.c @@ -14,12 +14,15 @@ #include "commands/trigger.h" #include "datatype/timestamp.h" #include "executor/spi.h" +#include "nodes/bitmapset.h" #include "utils/date.h" +#include "utils/datum.h" #include "utils/elog.h" #if (PG_VERSION_NUM < 100000) #else #include "utils/fmgrprotos.h" #endif +#include "utils/lsyscache.h" #include "utils/memutils.h" #include "utils/rel.h" #include "utils/timestamp.h" @@ -111,6 +114,109 @@ GetPeriodColumnNames(Relation rel, char *period_name, char **start_name, char ** elog(ERROR, "SPI_finish failed"); } +/* + * Check if the only columns changed in an UPDATE are columns that the user is + * excluding from SYSTEM VERSIONING. One possible use case for this is a + * "last_login timestamptz" column on a user table. Arguably, this column + * should be in another table, but users have requested the feature so let's do + * it. + */ +static bool +OnlyExcludedColumnsChanged(Relation rel, HeapTuple old_row, HeapTuple new_row) +{ + int ret; + Oid types[1]; + Datum values[1]; + TupleDesc tupdesc = RelationGetDescr(rel); + Bitmapset *excluded_attnums; + + const char *sql = + "SELECT u.name " + "FROM periods.system_time_periods AS stp " + "CROSS JOIN unnest(stp.excluded_column_names) AS u (name) " + "WHERE stp.table_name = $1"; + + /* Create an empty bitmapset outside of the SPI context */ + excluded_attnums = bms_make_singleton(0); + excluded_attnums = bms_del_member(excluded_attnums, 0); + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* + * XXX: Can we cache this? + */ + types[0] = OIDOID; + values[0] = ObjectIdGetDatum(rel->rd_id); + ret = SPI_execute_with_args(sql, 1, types, values, NULL, true, 0); + if (ret != SPI_OK_SELECT) + elog(ERROR, "SPI_execute failed: %d", ret); + + /* Construct a bitmap of excluded attnums */ + if (SPI_processed > 0 && SPI_tuptable != NULL) + { + TupleDesc spitupdesc = SPI_tuptable->tupdesc; + + for (int i = 0; i < SPI_processed; i++) + { + HeapTuple tuple = SPI_tuptable->vals[i]; + char *attname; + int16 attnum; + + /* Get the attnum from the column name */ + attname = SPI_getvalue(tuple, spitupdesc, 1); + attnum = SPI_fnumber(tupdesc, attname); + pfree(attname); + + excluded_attnums = bms_add_member(excluded_attnums, attnum); + } + } + + /* Don't need SPI anymore */ + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + + /* If there are no excluded columns, then we're done */ + if (bms_is_empty(excluded_attnums)) + return false; + + for (int i = 1; i <= tupdesc->natts; i++) + { + Datum old_datum, new_datum; + bool old_isnull, new_isnull; + Oid typid; + int16 typlen; + bool typbyval; + + /* Ignore if excluded column */ + if (bms_is_member(i, excluded_attnums)) + continue; + + typid = SPI_gettypeid(tupdesc, i); + get_typlenbyval(typid, &typlen, &typbyval); + + old_datum = SPI_getbinval(old_row, tupdesc, i, &old_isnull); + new_datum = SPI_getbinval(new_row, tupdesc, i, &new_isnull); + + /* + * If one value is NULL and other is not, then they are certainly not + * equal. + */ + if (old_isnull != new_isnull) + return false; + + /* If both are NULL, they can be considered equal. */ + if (old_isnull) + continue; + + /* Do a fairly strict binary comparison of the values */ + if (!datumIsEqual(old_datum, new_datum, typbyval, typlen)) + return false; + } + + return true; +} + /* * Get the oid of the history table. If this table does not have a system_time * period an error is raised. If it doesn't have SYSTEM VERSIONING, then @@ -272,11 +378,24 @@ generated_always_as_row_start_end(PG_FUNCTION_ARGS) errmsg("function \"%s\" must be fired BEFORE ROW", funcname))); + /* Get Relation information */ + rel = trigdata->tg_relation; + new_tupdesc = RelationGetDescr(rel); + /* Get the new data that was inserted/updated */ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event)) new_row = trigdata->tg_trigtuple; else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event)) + { + HeapTuple old_row; + + old_row = trigdata->tg_trigtuple; new_row = trigdata->tg_newtuple; + + /* Don't change anything if only excluded columns are being updated. */ + if (OnlyExcludedColumnsChanged(rel, old_row, new_row)) + return PointerGetDatum(new_row); + } else { ereport(ERROR, @@ -285,8 +404,6 @@ generated_always_as_row_start_end(PG_FUNCTION_ARGS) funcname))); new_row = NULL; /* keep compiler quiet */ } - rel = trigdata->tg_relation; - new_tupdesc = RelationGetDescr(rel); GetPeriodColumnNames(rel, "system_time", &start_name, &end_name); @@ -324,6 +441,7 @@ write_history(PG_FUNCTION_ARGS) bool is_null; Oid history_id; int cmp; + bool only_excluded_changed = false; /* * Make sure this is being called as an AFTER ROW trigger. Note: @@ -343,6 +461,10 @@ write_history(PG_FUNCTION_ARGS) errmsg("function \"%s\" must be fired AFTER ROW", funcname))); + /* Get Relation information */ + rel = trigdata->tg_relation; + tupledesc = RelationGetDescr(rel); + /* Get the old data that was updated/deleted */ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event)) { @@ -353,6 +475,9 @@ write_history(PG_FUNCTION_ARGS) { old_row = trigdata->tg_trigtuple; new_row = trigdata->tg_newtuple; + + /* Did only excluded columns change? */ + only_excluded_changed = OnlyExcludedColumnsChanged(rel, old_row, new_row); } else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event)) { @@ -368,8 +493,6 @@ write_history(PG_FUNCTION_ARGS) old_row = NULL; /* keep compiler quiet */ new_row = NULL; /* keep compiler quiet */ } - rel = trigdata->tg_relation; - tupledesc = RelationGetDescr(rel); GetPeriodColumnNames(rel, "system_time", &start_name, &end_name); @@ -382,7 +505,8 @@ write_history(PG_FUNCTION_ARGS) * Validate that the period columns haven't been modified. This can happen * with a trigger executed after generated_always_as_row_start_end(). */ - if (!TRIGGER_FIRED_BY_DELETE(trigdata->tg_event)) + if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event) || + (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event) && !only_excluded_changed)) { Datum start_datum = SPI_getbinval(new_row, tupledesc, start_num, &is_null); Datum end_datum = SPI_getbinval(new_row, tupledesc, end_num, &is_null); @@ -407,6 +531,10 @@ write_history(PG_FUNCTION_ARGS) return PointerGetDatum(NULL); } + /* If only excluded columns have changed, don't write history. */ + if (only_excluded_changed) + return PointerGetDatum(NULL); + /* Compare the OLD row's start with the transaction start */ cmp = CompareWithCurrentDatum(typeid, SPI_getbinval(old_row, tupledesc, start_num, &is_null)); diff --git a/sql/drop_protection.sql b/sql/drop_protection.sql index cc95a69..22b0562 100644 --- a/sql/drop_protection.sql +++ b/sql/drop_protection.sql @@ -7,7 +7,8 @@ CREATE TYPE integerrange AS RANGE (SUBTYPE = integer); CREATE TABLE dp ( id bigint, s integer, - e integer + e integer, + x boolean ); /* periods */ @@ -15,7 +16,8 @@ SELECT periods.add_period('dp', 'p', 's', 'e', 'integerrange'); DROP TYPE integerrange; /* system_time_periods */ -SELECT periods.add_system_time_period('dp'); +SELECT periods.add_system_time_period('dp', excluded_column_names => ARRAY['x']); +ALTER TABLE dp DROP COLUMN x; -- fails ALTER TABLE dp DROP CONSTRAINT dp_system_time_end_infinity_check; -- fails DROP TRIGGER dp_system_time_generated_always ON dp; -- fails DROP TRIGGER dp_system_time_write_history ON dp; -- fails diff --git a/sql/excluded_columns.sql b/sql/excluded_columns.sql new file mode 100644 index 0000000..be8f359 --- /dev/null +++ b/sql/excluded_columns.sql @@ -0,0 +1,36 @@ +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']); +SELECT periods.add_system_versioning('excl'); + +TABLE periods.periods; +TABLE periods.system_time_periods; +TABLE periods.system_versioning; + +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; + +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; + +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; + +UPDATE excl SET null_value = 0; +SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl; + +SELECT periods.drop_system_versioning('excl'); +SELECT periods.drop_system_time_period('excl'); +DROP TABLE excl; diff --git a/sql/rename_following.sql b/sql/rename_following.sql index 3a65c6b..8027dca 100644 --- a/sql/rename_following.sql +++ b/sql/rename_following.sql @@ -21,8 +21,9 @@ ALTER TABLE rename_test RENAME CONSTRAINT rename_test_p_check TO start_before_en TABLE periods.periods; /* system_time_periods */ -SELECT periods.add_system_time_period('rename_test'); +SELECT periods.add_system_time_period('rename_test', excluded_column_names => ARRAY['col3']); TABLE periods.system_time_periods; +ALTER TABLE rename_test RENAME col3 TO "COLUMN3"; 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; diff --git a/sql/system_versioning.sql b/sql/system_versioning.sql index 1057ed6..d9ceb31 100644 --- a/sql/system_versioning.sql +++ b/sql/system_versioning.sql @@ -11,8 +11,8 @@ FROM pg_settings WHERE name = 'server_version_num'; /* Basic SYSTEM VERSIONING */ -CREATE TABLE sysver (val text); -SELECT periods.add_system_time_period('sysver'); +CREATE TABLE sysver (val text, flap boolean); +SELECT periods.add_system_time_period('sysver', excluded_column_names => ARRAY['flap']); TABLE periods.system_time_periods; TABLE periods.system_versioning; SELECT periods.add_system_versioning('sysver', @@ -27,7 +27,7 @@ SELECT periods.drop_system_versioning('sysver', drop_behavior => 'CASCADE'); SELECT periods.add_system_versioning('sysver'); TABLE periods.system_versioning; -INSERT INTO sysver (val) VALUES ('hello'); +INSERT INTO sysver (val, flap) VALUES ('hello', false); SELECT val FROM sysver; SELECT val FROM sysver_history ORDER BY system_time_start; @@ -37,6 +37,14 @@ UPDATE sysver SET val = 'world'; SELECT val FROM sysver; SELECT val FROM sysver_history ORDER BY system_time_start; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +UPDATE sysver SET flap = not flap; +SELECT val FROM sysver; +SELECT val FROM sysver_history ORDER BY system_time_start; + SELECT transaction_timestamp() AS ts2 \gset DELETE FROM sysver;