From 2e4d76858a000ef6f08a5cae8c8d9ad72de22d33 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?J=C3=B8rgen=20H=2E=20Fjeld?= Date: Fri, 3 Nov 2023 09:40:02 +0100 Subject: [PATCH] Adjust tests from time_for_series Improve the checking when activating foreign keys for tables with data accordingly. Add the C functions from time_for_keys and periods, for future usage. The `completely_covers` function from time_for_keys is probably a lot faster than the code ported from periods. --- .gitignore | 3 + Makefile | 4 +- completely_covers.c | 189 +++++ completely_covers.h | 0 expected/06_unique_foreign.out | 10 +- expected/09_drop_protection.out | 16 +- expected/10_rename_following.out | 6 +- expected/11_health_checks.out | 2 +- expected/13_issues.out | 2 +- expected/21_init.out | 263 +++++- expected/22_completely_covers_test.out | 62 +- .../23_create_temporal_foreign_key_test.out | 138 +-- expected/24_delete_pk_test.out | 99 ++- expected/25_update_pk_test.out | 110 ++- expected/26_insert_fk_test.out | 118 +-- expected/27_update_fk_test.out | 150 ++-- expected/28_with_exclusion_constraints.out | 258 +++--- periods.c | 788 ++++++++++++++++++ sql/06_unique_foreign.sql | 2 +- sql/09_drop_protection.sql | 4 +- sql/10_rename_following.sql | 6 +- sql/21_init.sql | 98 ++- sql/22_completely_covers_test.sql | 64 +- sql/23_create_temporal_foreign_key_test.sql | 43 +- sql/24_delete_pk_test.sql | 57 +- sql/25_update_pk_test.sql | 83 +- sql/26_insert_fk_test.sql | 53 +- sql/27_update_fk_test.sql | 85 +- sql/28_with_exclusion_constraints.sql | 223 ++--- sql_saga--1.0.sql | 340 ++++---- sql_saga.c | 41 + time_for_keys.c | 40 + 32 files changed, 2445 insertions(+), 912 deletions(-) create mode 100644 completely_covers.c create mode 100644 completely_covers.h create mode 100644 periods.c create mode 100644 sql_saga.c create mode 100644 time_for_keys.c diff --git a/.gitignore b/.gitignore index e6ff307..2dfb599 100644 --- a/.gitignore +++ b/.gitignore @@ -1,5 +1,8 @@ sql_saga.o sql_saga.so +completely_covers.o +periods.o +sql_saga.dylib regression.diffs regression.out results/ diff --git a/Makefile b/Makefile index 44e48d6..1f042ee 100644 --- a/Makefile +++ b/Makefile @@ -1,4 +1,4 @@ -#MODULE_big = sql_saga +MODULE_big = sql_saga EXTENSION = sql_saga EXTENSION_VERSION = 1.0 DATA = $(EXTENSION)--$(EXTENSION_VERSION).sql @@ -11,6 +11,8 @@ SQL_FILES = $(wildcard sql/[0-9]*_*.sql) REGRESS = $(patsubst sql/%.sql,%,$(SQL_FILES)) +OBJS = sql_saga.o periods.o completely_covers.o $(WIN32RES) + PG_CONFIG = pg_config PGXS := $(shell $(PG_CONFIG) --pgxs) include $(PGXS) diff --git a/completely_covers.c b/completely_covers.c new file mode 100644 index 0000000..ac48cf9 --- /dev/null +++ b/completely_covers.c @@ -0,0 +1,189 @@ +/** + * completely_covers.c - + * Provides an aggregate function + * that tells whether a bunch of input ranges competely cover a target range. + */ + +#include +#include +#include +#include +#include +#include +#include +#include + +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include + +#include "completely_covers.h" + +typedef struct completely_covers_state { + TimestampTz covered_to; + TimestampTz target_start; + TimestampTz target_end; + bool target_start_unbounded; + bool target_end_unbounded; + bool answer_is_null; + bool finished; // Used to avoid further processing if we have already succeeded/failed. + bool completely_covered; +} completely_covers_state; + + +Datum completely_covers_transfn(PG_FUNCTION_ARGS); +PG_FUNCTION_INFO_V1(completely_covers_transfn); + +Datum completely_covers_transfn(PG_FUNCTION_ARGS) +{ + MemoryContext aggContext; + completely_covers_state *state; + RangeType *current_range, + *target_range; + RangeBound current_start, current_end, target_start, target_end; + TypeCacheEntry *typcache; + bool current_empty, target_empty; + bool first_time; + + if (!AggCheckCallContext(fcinfo, &aggContext)) { + elog(ERROR, "completely_covers called in non-aggregate context"); + } + + if (PG_ARGISNULL(0)) { + // Need to use MemoryContextAlloc with aggContext, not just palloc0, + // or the state will get cleared in between invocations: + state = (completely_covers_state *)MemoryContextAlloc(aggContext, sizeof(completely_covers_state)); + state->finished = false; + state->completely_covered = false; + first_time = true; + + // Need to find out the target range: + + // TODO: Technically this will fail to detect an inconsistent target + // if only the first row is NULL: + if (PG_ARGISNULL(2)) { + // return NULL from the whole thing + state->answer_is_null = true; + state->finished = true; + PG_RETURN_POINTER(state); + } + state->answer_is_null = false; + + target_range = PG_GETARG_RANGE_P(2); + typcache = range_get_typcache(fcinfo, RangeTypeGetOid(target_range)); + range_deserialize(typcache, target_range, &target_start, &target_end, &target_empty); + + state->target_start_unbounded = target_start.infinite; + state->target_end_unbounded = target_end.infinite; + state->target_start = DatumGetTimestampTz(target_start.val); + state->target_end = DatumGetTimestampTz(target_end.val); + // ereport(NOTICE, (errmsg("STARTING: state is [%ld, %ld) target is [%ld, %ld)", state->target_start, state->target_end, DatumGetTimestampTz(target_start.val), DatumGetTimestampTz(target_end.val)))); + + state->covered_to = 0; + + } else { + // ereport(NOTICE, (errmsg("looking up state...."))); + state = (completely_covers_state *)PG_GETARG_POINTER(0); + + // TODO: Is there any better way to exit an aggregation early? + // Even https://pgxn.org/dist/first_last_agg/ hits all the input rows: + if (state->finished) PG_RETURN_POINTER(state); + + first_time = false; + + // Make sure the second arg is always the same: + if (PG_ARGISNULL(2)) { + ereport(ERROR, (errmsg("completely_covers second argument must be constant across the group"))); + } + target_range = PG_GETARG_RANGE_P(2); + typcache = range_get_typcache(fcinfo, RangeTypeGetOid(target_range)); + range_deserialize(typcache, target_range, &target_start, &target_end, &target_empty); + + // ereport(NOTICE, (errmsg("state is [%ld, %ld) target is [%ld, %ld)", state->target_start, state->target_end, DatumGetTimestampTz(target_start.val), DatumGetTimestampTz(target_end.val)))); + if (DatumGetTimestampTz(target_start.val) != state->target_start || DatumGetTimestampTz(target_end.val) != state->target_end) { + ereport(ERROR, (errmsg("completely_covers second argument must be constant across the group"))); + } + } + + if (PG_ARGISNULL(1)) PG_RETURN_POINTER(state); + current_range = PG_GETARG_RANGE_P(1); + typcache = range_get_typcache(fcinfo, RangeTypeGetOid(current_range)); + range_deserialize(typcache, current_range, ¤t_start, ¤t_end, ¤t_empty); + + // ereport(NOTICE, (errmsg("current is [%ld, %ld)", DatumGetTimestampTz(current_start.val), DatumGetTimestampTz(current_end.val)))); + + if (first_time) { + if (state->target_start_unbounded && !current_start.infinite) { + state->finished = true; + state->completely_covered = false; + PG_RETURN_POINTER(state); + } + if (DatumGetTimestampTz(current_start.val) > state->target_start) { + state->finished = true; + state->completely_covered = false; + PG_RETURN_POINTER(state); + } + + } else { + // If there is a gap then fail: + if (DatumGetTimestampTz(current_start.val) > state->covered_to) { + // ereport(NOTICE, (errmsg("found a gap"))); + state->finished = true; + state->completely_covered = false; + PG_RETURN_POINTER(state); + } + } + + // This check is why we set covered_to to 0 above on the first pass: + // Note this check will not check unsorted inputs in some cases: + // - the inputs cover the target before we hit an out-of-order input. + if (DatumGetTimestampTz(current_start.val) < state->covered_to) { + // Right? Maybe this should be a warning.... + ereport(ERROR, (errmsg("completely_covered first argument should be sorted"))); + // ereport(ERROR, (errmsg("completely_covered first argument should be sorted but got %ld after covering up to %ld", DatumGetTimestampTz(current_start.val), state->covered_to))); + } + + if (current_end.infinite) { + state->completely_covered = true; + state->finished = true; + + } else { + state->covered_to = DatumGetTimestampTz(current_end.val); + + if (!state->target_end_unbounded && state->covered_to >= state->target_end) { + state->completely_covered = true; + state->finished = true; + } + } + + PG_RETURN_POINTER(state); +} + +Datum completely_covers_finalfn(PG_FUNCTION_ARGS); +PG_FUNCTION_INFO_V1(completely_covers_finalfn); + +Datum completely_covers_finalfn(PG_FUNCTION_ARGS) +{ + completely_covers_state *state; + + if (PG_ARGISNULL(0)) PG_RETURN_NULL(); + + state = (completely_covers_state *)PG_GETARG_POINTER(0); + if (state->answer_is_null) { + PG_RETURN_NULL(); + } else { + PG_RETURN_BOOL(state->completely_covered); + } +} diff --git a/completely_covers.h b/completely_covers.h new file mode 100644 index 0000000..e69de29 diff --git a/expected/06_unique_foreign.out b/expected/06_unique_foreign.out index 5d4b6d1..072600a 100644 --- a/expected/06_unique_foreign.out +++ b/expected/06_unique_foreign.out @@ -2,7 +2,7 @@ SET ROLE TO sql_saga_unprivileged_user; -- Unique keys are already pretty much guaranteed by the underlying features of -- PostgreSQL, but test them anyway. -CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e)); +CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e) DEFERRABLE); SELECT sql_saga.add_era('uk', 's', 'e', 'p'); add_era --------- @@ -71,17 +71,17 @@ TABLE sql_saga.foreign_keys; -- INSERT INSERT INTO fk VALUES (0, 100, 0, 1); -- fail ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" -CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM INSERT INTO fk VALUES (0, 100, 0, 10); -- fail ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" -CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM INSERT INTO fk VALUES (0, 100, 1, 11); -- fail ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" -CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM INSERT INTO fk VALUES (1, 100, 1, 3); -- success @@ -89,7 +89,7 @@ INSERT INTO fk VALUES (2, 100, 1, 10); -- success -- UPDATE UPDATE fk SET e = 20 WHERE id = 1; -- fail ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" -CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM UPDATE fk SET e = 6 WHERE id = 1; -- success diff --git a/expected/09_drop_protection.out b/expected/09_drop_protection.out index b9d970d..e0d5131 100644 --- a/expected/09_drop_protection.out +++ b/expected/09_drop_protection.out @@ -44,8 +44,8 @@ SELECT sql_saga.drop_api('dp', 'p'); ALTER TABLE dp DROP CONSTRAINT dp_pkey; /* unique_keys */ ALTER TABLE dp - ADD CONSTRAINT u UNIQUE (id, s, e), - ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&); + ADD CONSTRAINT u UNIQUE (id, s, e) DEFERRABLE, + ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&) DEFERRABLE; SELECT sql_saga.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); add_unique_key ---------------- @@ -53,10 +53,10 @@ SELECT sql_saga.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); (1 row) ALTER TABLE dp DROP CONSTRAINT u; -- fails -ERROR: cannot drop constraint "u" on table "dp" because it is used in period unique key "k" +ERROR: cannot drop constraint "u" on table "dp" because it is used in era unique key "k" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 182 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" +ERROR: cannot drop constraint "x" on table "dp" because it is used in era unique key "k" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 193 at RAISE ALTER TABLE dp DROP CONSTRAINT dp_p_check; -- fails /* foreign_keys */ @@ -74,16 +74,16 @@ SELECT sql_saga.add_foreign_key('dp_ref', ARRAY['id'], 'p', 'k', key_name => 'f' (1 row) 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" +ERROR: cannot drop trigger "f_fk_insert" on table "dp_ref" because it is used in era foreign key "f" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 209 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" +ERROR: cannot drop trigger "f_fk_update" on table "dp_ref" because it is used in era foreign key "f" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 220 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" +ERROR: cannot drop trigger "f_uk_update" on table "dp" because it is used in era foreign key "f" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 232 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" +ERROR: cannot drop trigger "f_uk_delete" on table "dp" because it is used in era foreign key "f" CONTEXT: PL/pgSQL function sql_saga.drop_protection() line 244 at RAISE SELECT sql_saga.drop_foreign_key('dp_ref', 'f'); drop_foreign_key diff --git a/expected/10_rename_following.out b/expected/10_rename_following.out index 83c085d..1acbae7 100644 --- a/expected/10_rename_following.out +++ b/expected/10_rename_following.out @@ -92,9 +92,9 @@ ALTER TABLE rename_test RENAME COLUMN col1 TO "COLUMN1"; ALTER TABLE rename_test RENAME CONSTRAINT "rename_test_col2_col1_col3_s < e_embedded "" symbols_key" TO unconst; ALTER TABLE rename_test RENAME CONSTRAINT rename_test_col2_col1_col3_int4range_excl TO exconst; TABLE sql_saga.unique_keys; - key_name | table_name | column_names | era_name | unique_constraint | exclude_constraint -------------------------------+-------------+---------------------+----------+-------------------+-------------------- - rename_test_col2_col1_col3_p | rename_test | {col2,COLUMN1,col3} | p | unconst | exconst + key_name | table_name | column_names | era_name | unique_constraint | exclude_constraint +------------------------------+-------------+---------------------+----------+-------------------+------------------------------------------- + rename_test_col2_col1_col3_p | rename_test | {col2,COLUMN1,col3} | p | unconst | rename_test_col2_col1_col3_int4range_excl (1 row) /* foreign_keys */ diff --git a/expected/11_health_checks.out b/expected/11_health_checks.out index 5ffaa6b..1df7705 100644 --- a/expected/11_health_checks.out +++ b/expected/11_health_checks.out @@ -13,6 +13,6 @@ SELECT sql_saga.add_era('log', 's', 'e', 'p'); -- passes (1 row) ALTER TABLE log SET UNLOGGED; -- fails -ERROR: table "log" must remain persistent because it has periods +ERROR: table "log" must remain persistent because it has an era CONTEXT: PL/pgSQL function sql_saga.health_checks() line 15 at RAISE DROP TABLE log; diff --git a/expected/13_issues.out b/expected/13_issues.out index d87b9d8..c3cf150 100644 --- a/expected/13_issues.out +++ b/expected/13_issues.out @@ -133,7 +133,7 @@ INSERT INTO uk(id, s, e) VALUES (3, 1, 3), -- Reference over non contiguous time - should fail INSERT INTO fk(id, uk_id, s, e) VALUES (5, 3, 1, 5); ERROR: insert or update on table "fk" violates foreign key constraint "fk_uk_id_q" -CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 130 at RAISE +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- Create overlappig range - should fail diff --git a/expected/21_init.out b/expected/21_init.out index 8aed76d..e657d68 100644 --- a/expected/21_init.out +++ b/expected/21_init.out @@ -1,20 +1,267 @@ -CREATE EXTENSION btree_gist; -- for the GIST exclusion constraints -CREATE EXTENSION time_for_keys; +CREATE EXTENSION sql_saga CASCADE; +NOTICE: installing required extension "btree_gist" CREATE TABLE shifts ( job_id INTEGER, worker_id INTEGER, - valid_at tstzrange, - EXCLUDE USING gist (worker_id WITH =, valid_at WITH &&) + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (job_id, worker_id, valid_from, valid_to) ); CREATE TABLE houses ( id INTEGER, assessment FLOAT, - valid_at tstzrange, - CONSTRAINT tpk_houses_id EXCLUDE USING gist (id WITH =, valid_at WITH &&) DEFERRABLE INITIALLY IMMEDIATE + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (id, valid_from, valid_to) ); CREATE TABLE rooms ( id INTEGER, house_id INTEGER, - valid_at tstzrange, - CONSTRAINT tpk_rooms_id EXCLUDE USING gist (id WITH =, valid_at WITH &&) DEFERRABLE INITIALLY IMMEDIATE + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (id, valid_from, valid_to) ); +-- Before using sql_saga +\d rooms + Table "public.rooms" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + id | integer | | not null | + house_id | integer | | | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "rooms_pkey" PRIMARY KEY, btree (id, valid_from, valid_to) + +\d houses + Table "public.houses" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + id | integer | | not null | + assessment | double precision | | | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "houses_pkey" PRIMARY KEY, btree (id, valid_from, valid_to) + +\d shifts + Table "public.shifts" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + job_id | integer | | not null | + worker_id | integer | | not null | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "shifts_pkey" PRIMARY KEY, btree (job_id, worker_id, valid_from, valid_to) + +-- Verify that enable and disable each work correctly. +SELECT sql_saga.add_era('shifts', 'valid_from', 'valid_to'); + add_era +--------- + t +(1 row) + +SELECT sql_saga.add_era('houses', 'valid_from', 'valid_to', 'valid'); + add_era +--------- + t +(1 row) + +SELECT sql_saga.add_era('rooms', 'valid_from', 'valid_to'); + add_era +--------- + t +(1 row) + +TABLE sql_saga.era; + table_name | era_name | start_column_name | end_column_name | range_type | bounds_check_constraint | audit_table_name +------------+----------+-------------------+-----------------+------------+-------------------------+------------------ + shifts | valid | valid_from | valid_to | tstzrange | shifts_valid_check | + houses | valid | valid_from | valid_to | tstzrange | houses_valid_check | + rooms | valid | valid_from | valid_to | tstzrange | rooms_valid_check | +(3 rows) + +SELECT sql_saga.add_unique_key('shifts', ARRAY['job_id','worker_id'], 'valid'); + add_unique_key +------------------------------- + shifts_job_id_worker_id_valid +(1 row) + +SELECT sql_saga.add_unique_key('houses', ARRAY['id'], 'valid'); + add_unique_key +----------------- + houses_id_valid +(1 row) + +SELECT sql_saga.add_unique_key('rooms', ARRAY['id'], 'valid'); + add_unique_key +---------------- + rooms_id_valid +(1 row) + +TABLE sql_saga.unique_keys; + key_name | table_name | column_names | era_name | unique_constraint | exclude_constraint +-------------------------------+------------+--------------------+----------+-------------------------------------------------+---------------------------------------- + shifts_job_id_worker_id_valid | shifts | {job_id,worker_id} | valid | shifts_job_id_worker_id_valid_from_valid_to_key | shifts_job_id_worker_id_tstzrange_excl + houses_id_valid | houses | {id} | valid | houses_id_valid_from_valid_to_key | houses_id_tstzrange_excl + rooms_id_valid | rooms | {id} | valid | rooms_id_valid_from_valid_to_key | rooms_id_tstzrange_excl +(3 rows) + +SELECT sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid'); + add_foreign_key +---------------------- + rooms_house_id_valid +(1 row) + +TABLE sql_saga.foreign_keys; + key_name | table_name | column_names | era_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger +----------------------+------------+--------------+----------+-----------------+------------+---------------+---------------+--------------------------------+--------------------------------+--------------------------------+-------------------------------- + rooms_house_id_valid | rooms | {house_id} | valid | houses_id_valid | SIMPLE | NO ACTION | NO ACTION | rooms_house_id_valid_fk_insert | rooms_house_id_valid_fk_update | rooms_house_id_valid_uk_update | rooms_house_id_valid_uk_delete +(1 row) + +SELECT sql_saga.drop_foreign_key('rooms', 'rooms_house_id_valid'); + drop_foreign_key +------------------ + t +(1 row) + +TABLE sql_saga.foreign_keys; + key_name | table_name | column_names | era_name | unique_key | match_type | delete_action | update_action | fk_insert_trigger | fk_update_trigger | uk_update_trigger | uk_delete_trigger +----------+------------+--------------+----------+------------+------------+---------------+---------------+-------------------+-------------------+-------------------+------------------- +(0 rows) + +-- While sql_saga is active +\d rooms + Table "public.rooms" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + id | integer | | not null | + house_id | integer | | | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "rooms_pkey" PRIMARY KEY, btree (id, valid_from, valid_to) + "rooms_id_tstzrange_excl" EXCLUDE USING gist (id WITH =, tstzrange(valid_from, valid_to, '[)'::text) WITH &&) DEFERRABLE + "rooms_id_valid_from_valid_to_key" UNIQUE CONSTRAINT, btree (id, valid_from, valid_to) +Check constraints: + "rooms_valid_check" CHECK (valid_from < valid_to) + +\d houses + Table "public.houses" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + id | integer | | not null | + assessment | double precision | | | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "houses_pkey" PRIMARY KEY, btree (id, valid_from, valid_to) + "houses_id_tstzrange_excl" EXCLUDE USING gist (id WITH =, tstzrange(valid_from, valid_to, '[)'::text) WITH &&) DEFERRABLE + "houses_id_valid_from_valid_to_key" UNIQUE CONSTRAINT, btree (id, valid_from, valid_to) +Check constraints: + "houses_valid_check" CHECK (valid_from < valid_to) + +\d shifts + Table "public.shifts" + Column | Type | Collation | Nullable | Default +------------+--------------------------+-----------+----------+--------- + job_id | integer | | not null | + worker_id | integer | | not null | + valid_from | timestamp with time zone | | not null | + valid_to | timestamp with time zone | | not null | +Indexes: + "shifts_pkey" PRIMARY KEY, btree (job_id, worker_id, valid_from, valid_to) + "shifts_job_id_worker_id_tstzrange_excl" EXCLUDE USING gist (job_id WITH =, worker_id WITH =, tstzrange(valid_from, valid_to, '[)'::text) WITH &&) DEFERRABLE + "shifts_job_id_worker_id_valid_from_valid_to_key" UNIQUE CONSTRAINT, btree (job_id, worker_id, valid_from, valid_to) +Check constraints: + "shifts_valid_check" CHECK (valid_from < valid_to) + +SELECT sql_saga.drop_unique_key('rooms', 'rooms_id_valid'); + drop_unique_key +-------------------------------------------------------------------------------------------- + (rooms_id_valid,rooms,{id},valid,rooms_id_valid_from_valid_to_key,rooms_id_tstzrange_excl) +(1 row) + +SELECT sql_saga.drop_unique_key('houses','houses_id_valid'); + drop_unique_key +------------------------------------------------------------------------------------------------ + (houses_id_valid,houses,{id},valid,houses_id_valid_from_valid_to_key,houses_id_tstzrange_excl) +(1 row) + +-- TODO: Simplify this API, to take the same parameters when created. +-- TODO: Detect and raise an error if there is no match in "sql_saga.unique_keys". +SELECT sql_saga.drop_unique_key('shifts', 'shifts_job_id_worker_id_valid'); + drop_unique_key +---------------------------------------------------------------------------------------------------------------------------------------------------------- + (shifts_job_id_worker_id_valid,shifts,"{job_id,worker_id}",valid,shifts_job_id_worker_id_valid_from_valid_to_key,shifts_job_id_worker_id_tstzrange_excl) +(1 row) + +TABLE sql_saga.unique_keys; + key_name | table_name | column_names | era_name | unique_constraint | exclude_constraint +----------+------------+--------------+----------+-------------------+-------------------- +(0 rows) + +SELECT sql_saga.drop_era('rooms'); + drop_era +---------- + t +(1 row) + +SELECT sql_saga.drop_era('houses'); + drop_era +---------- + t +(1 row) + +SELECT sql_saga.drop_era('shifts'); + drop_era +---------- + t +(1 row) + +TABLE sql_saga.era; + table_name | era_name | start_column_name | end_column_name | range_type | bounds_check_constraint | audit_table_name +------------+----------+-------------------+-----------------+------------+-------------------------+------------------ +(0 rows) + +-- Make convenience functions for later tests. +CREATE FUNCTION enable_sql_saga_for_shifts_houses_and_rooms() RETURNS void LANGUAGE plpgsql AS $EOF$ +BEGIN + PERFORM sql_saga.add_era('shifts', 'valid_from', 'valid_to'); + PERFORM sql_saga.add_unique_key('shifts', ARRAY['job_id','worker_id'], 'valid'); + + PERFORM sql_saga.add_era('houses', 'valid_from', 'valid_to', 'valid'); + PERFORM sql_saga.add_unique_key('houses', ARRAY['id'], 'valid'); + + PERFORM sql_saga.add_era('rooms', 'valid_from', 'valid_to'); + PERFORM sql_saga.add_unique_key('rooms', ARRAY['id'], 'valid'); + PERFORM sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid'); +END; +$EOF$; +CREATE FUNCTION disable_sql_saga_for_shifts_houses_and_rooms() RETURNS void LANGUAGE plpgsql AS $EOF$ +BEGIN + PERFORM sql_saga.drop_foreign_key('rooms', 'rooms_house_id_valid'); + + PERFORM sql_saga.drop_unique_key('rooms', 'rooms_id_valid'); + PERFORM sql_saga.drop_unique_key('houses','houses_id_valid'); + PERFORM sql_saga.drop_unique_key('shifts', 'shifts_job_id_worker_id_valid'); + + PERFORM sql_saga.drop_era('rooms'); + PERFORM sql_saga.drop_era('houses'); + PERFORM sql_saga.drop_era('shifts'); +END; +$EOF$; +-- Test the convenience functions. +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- + +(1 row) + +SELECT disable_sql_saga_for_shifts_houses_and_rooms() + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- + +(1 row) + diff --git a/expected/22_completely_covers_test.out b/expected/22_completely_covers_test.out index 64e918d..1f51f59 100644 --- a/expected/22_completely_covers_test.out +++ b/expected/22_completely_covers_test.out @@ -1,16 +1,16 @@ -INSERT INTO shifts VALUES - (1, 1, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (1, 2, tstzrange('2017-11-27 12:00:00', '2017-11-27 17:00:00')), - (2, 3, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (2, 4, tstzrange('2017-11-27 13:00:00', '2017-11-27 17:00:00')), - (3, 5, tstzrange(null, '2017-11-27 12:00:00')), - (3, 5, tstzrange('2017-11-27 12:00:00', '2017-11-27 17:00:00')), - (4, 6, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (4, 7, tstzrange('2017-11-27 12:00:00', null)) +INSERT INTO shifts(job_id, worker_id, valid_from, valid_to) VALUES + (1, 1, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (1, 2, '2017-11-27 12:00:00', '2017-11-27 17:00:00'), + (2, 3, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (2, 4, '2017-11-27 13:00:00', '2017-11-27 17:00:00'), + (3, 5, '-infinity', '2017-11-27 12:00:00'), + (3, 5, '2017-11-27 12:00:00', '2017-11-27 17:00:00'), + (4, 6, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (4, 7, '2017-11-27 12:00:00', 'infinity') ; -- TRUE: -- it covers when the range matches one exactly: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -19,7 +19,7 @@ WHERE job_id = 1; (1 row) -- it covers when the range matches two exactly: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -28,7 +28,7 @@ WHERE job_id = 1; (1 row) -- it covers when the range has extra in front: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 08:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 08:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -37,7 +37,7 @@ WHERE job_id = 1; (1 row) -- it covers when the range has extra behind: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -46,7 +46,7 @@ WHERE job_id = 1; (1 row) -- it covers when the range has extra on both sides: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -55,7 +55,7 @@ WHERE job_id = 1; (1 row) -- an infinite start will cover a finite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 3; completely_covers @@ -73,7 +73,7 @@ WHERE job_id = 3; (1 row) -- an infinite end will cover a finite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 4; completely_covers @@ -82,7 +82,7 @@ WHERE job_id = 4; (1 row) -- an infinite end will cover an infinite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', 'infinity')) FROM shifts WHERE job_id = 4; completely_covers @@ -92,7 +92,7 @@ WHERE job_id = 4; -- FALSE: -- it does not cover when the range is null: -SELECT completely_covers(NULL, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(NULL, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -101,7 +101,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range misses completely: -SELECT completely_covers(valid_at, tstzrange('2017-11-29 08:00:00', '2017-11-29 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-29 08:00:00', '2017-11-29 14:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -110,7 +110,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range has something at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 04:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 04:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -119,7 +119,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range has something at the end: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -128,7 +128,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range has something in the middle: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 2; completely_covers @@ -137,7 +137,7 @@ WHERE job_id = 2; (1 row) -- it does not cover when the range is lower-unbounded: -SELECT completely_covers(valid_at, tstzrange(NULL, '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; completely_covers @@ -146,7 +146,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range is upper-unbounded: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', 'infinity')) FROM shifts WHERE job_id = 1; completely_covers @@ -155,7 +155,7 @@ WHERE job_id = 1; (1 row) -- it does not cover when the range is both-sides-unbounded: -SELECT completely_covers(valid_at, tstzrange(NULL, NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', 'infinity')) FROM shifts WHERE job_id = 1; completely_covers @@ -164,7 +164,7 @@ WHERE job_id = 1; (1 row) -- an infinite start will not cover a finite target if there is uncovered time at the end: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 3; completely_covers @@ -173,7 +173,7 @@ WHERE job_id = 3; (1 row) -- an infinite start will not cover an infinite target if there is uncovered time at the end: -SELECT completely_covers(valid_at, tstzrange(NULL, '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 3; completely_covers @@ -182,7 +182,7 @@ WHERE job_id = 3; (1 row) -- an infinite end will not cover a finite target if there is uncovered time at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 03:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 03:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 4; completely_covers @@ -191,7 +191,7 @@ WHERE job_id = 4; (1 row) -- an infinite end will not cover an infinite target if there is uncovered time at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 03:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 03:00:00', 'infinity')) FROM shifts WHERE job_id = 4; completely_covers @@ -201,7 +201,7 @@ WHERE job_id = 4; -- NULL: -- it is unknown when the target is null: -SELECT completely_covers(valid_at, null) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), null) FROM shifts WHERE job_id = 1; completely_covers @@ -211,7 +211,7 @@ WHERE job_id = 1; -- Errors: -- it fails if the input ranges go backwards: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 13:00:00', '2017-11-27 20:00:00') ORDER BY worker_id DESC) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 13:00:00', '2017-11-27 20:00:00') ORDER BY worker_id DESC) FROM shifts WHERE job_id = 1; ERROR: completely_covered first argument should be sorted diff --git a/expected/23_create_temporal_foreign_key_test.out b/expected/23_create_temporal_foreign_key_test.out index c305cf0..ca8f758 100644 --- a/expected/23_create_temporal_foreign_key_test.out +++ b/expected/23_create_temporal_foreign_key_test.out @@ -1,97 +1,121 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ) ; -- it works on an empty table -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) -- it works on a table with a NULL foreign key -INSERT INTO rooms VALUES (1, NULL, tstzrange('2015-01-01', '2017-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, NULL, '2015-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) DELETE FROM rooms; -- it works on a table with a FK fulfilled by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) DELETE FROM rooms; -- it works on a table with a FK fulfilled by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-06-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) DELETE FROM rooms; -- it fails on a table with a missing foreign key -INSERT INTO rooms VALUES (1, 2, tstzrange('2015-01-01', '2016-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -ERROR: Tried to insert 2 to rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, Fri Jan 01 00:00:00 2016 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -SQL statement "SELECT TRI_FKey_check( - from_table, from_column, from_range_column, - to_table, to_column, to_range_column, - fk_val, from_range, false)" -PL/pgSQL function create_temporal_foreign_key(text,text,text,text,text,text,text) line 92 at PERFORM +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 2, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM rooms;" +PL/pgSQL function sql_saga.add_foreign_key(regclass,name[],name,name,sql_saga.fk_match_types,sql_saga.fk_actions,sql_saga.fk_actions,name,name,name,name,name) line 149 at EXECUTE +SQL statement "SELECT sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid')" +PL/pgSQL function enable_sql_saga_for_shifts_houses_and_rooms() line 11 at PERFORM +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); +NOTICE: period valid not found on table rooms +NOTICE: period valid not found on table houses +NOTICE: period valid not found on table shifts + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- + +(1 row) + DELETE FROM rooms; -- it fails on a table with a completely-uncovered foreign key -INSERT INTO rooms VALUES (1, 1, tstzrange('2010-01-01', '2011-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Fri Jan 01 00:00:00 2010 PST, Sat Jan 01 00:00:00 2011 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -SQL statement "SELECT TRI_FKey_check( - from_table, from_column, from_range_column, - to_table, to_column, to_range_column, - fk_val, from_range, false)" -PL/pgSQL function create_temporal_foreign_key(text,text,text,text,text,text,text) line 92 at PERFORM +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2010-01-01'::TIMESTAMPTZ, '2011-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM rooms;" +PL/pgSQL function sql_saga.add_foreign_key(regclass,name[],name,name,sql_saga.fk_match_types,sql_saga.fk_actions,sql_saga.fk_actions,name,name,name,name,name) line 149 at EXECUTE +SQL statement "SELECT sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid')" +PL/pgSQL function enable_sql_saga_for_shifts_houses_and_rooms() line 11 at PERFORM +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); +NOTICE: period valid not found on table rooms +NOTICE: period valid not found on table houses +NOTICE: period valid not found on table shifts + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- + +(1 row) + DELETE FROM rooms; -- it fails on a table with a partially-covered foreign key -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2018-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, Mon Jan 01 00:00:00 2018 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -SQL statement "SELECT TRI_FKey_check( - from_table, from_column, from_range_column, - to_table, to_column, to_range_column, - fk_val, from_range, false)" -PL/pgSQL function create_temporal_foreign_key(text,text,text,text,text,text,text) line 92 at PERFORM +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2018-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM rooms;" +PL/pgSQL function sql_saga.add_foreign_key(regclass,name[],name,name,sql_saga.fk_match_types,sql_saga.fk_actions,sql_saga.fk_actions,name,name,name,name,name) line 149 at EXECUTE +SQL statement "SELECT sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid')" +PL/pgSQL function enable_sql_saga_for_shifts_houses_and_rooms() line 11 at PERFORM +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); +NOTICE: period valid not found on table rooms +NOTICE: period valid not found on table houses +NOTICE: period valid not found on table shifts + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- + +(1 row) + DELETE FROM rooms; DELETE FROM rooms; DELETE FROM houses; diff --git a/expected/24_delete_pk_test.out b/expected/24_delete_pk_test.out index 90b9243..fb07fbf 100644 --- a/expected/24_delete_pk_test.out +++ b/expected/24_delete_pk_test.out @@ -1,64 +1,75 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)) -; --- ON DELETE RESTRICT -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity') +; -- You can delete a pk with no references DELETE FROM houses WHERE id = 2; -- You can delete a finite pk range with no references -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-06-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2015-06-01'::timestamptz; -INSERT INTO houses VALUES (1, 200000, tstzrange('2015-01-01', '2016-01-01')); +INSERT INTO rooms VALUES (1, 1, '2016-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2015-06-01'::timestamptz; +INSERT INTO houses VALUES (1, 200000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't delete a finite pk range that is partly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; -ERROR: Tried to delete 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- You can't delete a finite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; -ERROR: Tried to delete 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- You can't delete a finite pk range that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; -ERROR: Tried to delete 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- You can delete an infinite pk range with no references -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', '2015-01-01')); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -INSERT INTO houses VALUES (3, 200000, tstzrange('2015-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +INSERT INTO houses VALUES (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can't delete an infinite pk range that is partly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', '2017-01-01')); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to delete 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- You can't delete an infinite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to delete 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- You can't delete an infinite pk range that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to delete 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_del() line 32 at RAISE +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 149 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM DELETE FROM rooms; -- ON DELETE NOACTION -- (same behavior as RESTRICT, but different entry function so it should have separate tests) @@ -71,9 +82,9 @@ DELETE FROM rooms; -- TODO DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) diff --git a/expected/25_update_pk_test.out b/expected/25_update_pk_test.out index e10dfab..612c8d9 100644 --- a/expected/25_update_pk_test.out +++ b/expected/25_update_pk_test.out @@ -1,33 +1,35 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)) -; -- ON UPDATE RESTRICT -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity') +; -- You can update a finite pk id with no references UPDATE houses SET id = 4 WHERE id = 1; UPDATE houses SET id = 1 WHERE id = 4; -- You can update a finite pk range with no references -UPDATE houses SET valid_at = tstzrange('1999-01-01', '2000-01-01') WHERE id = 1 AND valid_at @> '2015-06-01'::timestamptz; -UPDATE houses SET valid_at = tstzrange('2015-01-01', '2016-01-01') WHERE id = 1 AND valid_at @> '1999-06-01'::timestamptz; +UPDATE houses SET valid_from = '1999-01-01'::TIMESTAMPTZ, valid_to = '2000-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2015-06-01'::timestamptz; +UPDATE houses SET valid_from = '2015-01-01'::TIMESTAMPTZ, valid_to = '2016-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '1999-06-01'::timestamptz; -- You can update a finite pk range that is partly covered elsewhere -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); -UPDATE houses SET valid_at = tstzrange('2016-01-01', '2016-09-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; -UPDATE houses SET valid_at = tstzrange('2016-01-01', '2017-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2016-01-01'::TIMESTAMPTZ, valid_to = '2016-09-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; +UPDATE houses SET valid_from = '2016-01-01'::TIMESTAMPTZ, valid_to = '2017-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't update a finite pk id that is partly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); UPDATE houses SET id = 4 WHERE id = 1; -ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 126 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" +PL/pgSQL function sql_saga.uk_update_check() line 23 at PERFORM DELETE FROM rooms; -- You can't update a finite pk range that is partly covered INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); @@ -42,22 +44,30 @@ ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00 CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE DELETE FROM rooms; -- You can't update a finite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2017-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; -ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't update a finite pk id that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM UPDATE houses SET id = 4 WHERE id = 1; ERROR: Tried to update 1 during [Thu Jan 01 00:00:00 2015 PST, Fri Jan 01 00:00:00 2016 PST) from houses but there are overlapping references in rooms.house_id CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE DELETE FROM rooms; -- You can't update a finite pk range that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; -ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can update an infinite pk id with no references INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', '2015-01-01')); @@ -82,28 +92,36 @@ ERROR: Tried to update 3 during [Thu Jan 01 00:00:00 2015 PST, ) from hou CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE DELETE FROM rooms; -- You can't update an infinite pk id that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to update 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to update 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk id that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to update 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk range that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -ERROR: Tried to update 3 during [Thu Jan 01 00:00:00 2015 PST, ) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- ON UPDATE NOACTION -- TODO @@ -115,9 +133,9 @@ DELETE FROM rooms; -- TODO DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) diff --git a/expected/26_insert_fk_test.out b/expected/26_insert_fk_test.out index 118827e..4baa192 100644 --- a/expected/26_insert_fk_test.out +++ b/expected/26_insert_fk_test.out @@ -1,89 +1,97 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)), - (4, 200000, tstzrange(null, '2014-01-01')) -; -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ), + (4, 200000, '-infinity'::TIMESTAMPTZ, '2014-01-01'::TIMESTAMPTZ) +; -- You can insert a NULL fk -INSERT INTO rooms VALUES (1, NULL, tstzrange('2010-01-01', '2011-01-01')); +INSERT INTO rooms VALUES (1, NULL, '2010-01-01'::TIMESTAMPTZ, '2011-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk more than covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2017-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't insert a finite fk id not covered by any row -INSERT INTO rooms VALUES (1, 7, tstzrange('2015-01-01', '2016-01-01')); -ERROR: Tried to insert 7 to rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, Fri Jan 01 00:00:00 2016 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 7, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert a finite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('1999-01-01', '2000-01-01')); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Fri Jan 01 00:00:00 1999 PST, Sat Jan 01 00:00:00 2000 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '1999-01-01'::TIMESTAMPTZ, '2000-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert a finite fk partially covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2014-01-01', '2015-06-01')); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2014 PST, Mon Jun 01 00:00:00 2015 PDT) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2014-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert a finite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2014-01-01', '2016-06-01')); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2014 PST, Wed Jun 01 00:00:00 2016 PDT) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2014-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can insert an infinite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk more than covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't insert an infinite fk id not covered by any row -INSERT INTO rooms VALUES (1, 7, tstzrange('2015-01-01', null)); -ERROR: Tried to insert 7 to rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, ) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 7, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert an infinite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2020-01-01', null)); -ERROR: Tried to insert 1 to rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2020 PST, ) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2020-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert an infinite fk partially covered by one row -INSERT INTO rooms VALUES (1, 4, tstzrange(null, '2020-01-01')); -ERROR: Tried to insert 4 to rooms.house_id but couldn't find it in houses.id for all of [, Wed Jan 01 00:00:00 2020 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 4, '-infinity'::TIMESTAMPTZ, '2020-01-01'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM -- You can't insert an infinite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('1990-01-01', null)); -ERROR: Tried to insert 3 to rooms.house_id but couldn't find it in houses.id for all of [Mon Jan 01 00:00:00 1990 PST, ) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 25 at RAISE -PL/pgSQL function tri_fkey_check_ins() line 25 at IF +INSERT INTO rooms VALUES (1, 3, '1990-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_insert_check() line 20 at PERFORM DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) diff --git a/expected/27_update_fk_test.out b/expected/27_update_fk_test.out index 40da65b..8a81486 100644 --- a/expected/27_update_fk_test.out +++ b/expected/27_update_fk_test.out @@ -1,118 +1,126 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)), - (4, 200000, tstzrange(null, '2014-01-01')) -; -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ), + (4, 200000, '-infinity'::TIMESTAMPTZ, '2014-01-01'::TIMESTAMPTZ) +; -- You can update an fk id to NULL -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = NULL; DELETE FROM rooms; -- You can update the range when the fk is NULL -INSERT INTO rooms VALUES (1, NULL, tstzrange('2015-01-01', '2015-06-01')); -UPDATE rooms SET valid_at = tstzrange('1999-01-01', '2000-01-01'); +INSERT INTO rooms VALUES (1, NULL, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1999-01-01'::TIMESTAMPTZ, '2000-01-01'); DELETE FROM rooms; -- You can update a finite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2016-01-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2016-01-01'); DELETE FROM rooms; -- You can update a finite fk more than covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2015-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2015-06-01'); DELETE FROM rooms; -- You can update a finite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2017-01-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2017-01-01'); DELETE FROM rooms; -- You can update a finite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2016-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2016-06-01'); DELETE FROM rooms; -- You can't update a finite fk id not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = 7; -ERROR: Tried to update to 7 in rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, Sun Feb 01 00:00:00 2015 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update a finite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('1999-01-01', '2000-01-01'); -ERROR: Tried to update to 1 in rooms.house_id but couldn't find it in houses.id for all of [Fri Jan 01 00:00:00 1999 PST, Sat Jan 01 00:00:00 2000 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1999-01-01'::TIMESTAMPTZ, '2000-01-01'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update a finite fk partially covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', '2015-06-01'); -ERROR: Tried to update to 1 in rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2014 PST, Mon Jun 01 00:00:00 2015 PDT) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, '2015-06-01'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update a finite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', '2016-06-01'); -ERROR: Tried to update to 1 in rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2014 PST, Wed Jun 01 00:00:00 2016 PDT) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, '2016-06-01'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can update an infinite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk more than covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2016-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2016-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-06-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-06-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can't update an infinite fk id not covered by any row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = 7; -ERROR: Tried to update to 7 in rooms.house_id but couldn't find it in houses.id for all of [Thu Jan 01 00:00:00 2015 PST, Sun Feb 01 00:00:00 2015 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update an infinite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2020-01-01', null); -ERROR: Tried to update to 1 in rooms.house_id but couldn't find it in houses.id for all of [Wed Jan 01 00:00:00 2020 PST, ) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2020-01-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update an infinite fk partially covered by one row -INSERT INTO rooms VALUES (1, 4, tstzrange(null, '2012-01-01')); -UPDATE rooms SET valid_at = tstzrange(null, '2020-01-01'); -ERROR: Tried to update to 4 in rooms.house_id but couldn't find it in houses.id for all of [, Wed Jan 01 00:00:00 2020 PST) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 4, '-infinity', '2012-01-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('-infinity', '2020-01-01'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; -- You can't update an infinite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('1990-01-01', null); -ERROR: Tried to update to 3 in rooms.house_id but couldn't find it in houses.id for all of [Mon Jan 01 00:00:00 1990 PST, ) -CONTEXT: PL/pgSQL function tri_fkey_check(text,text,text,text,text,text,integer,tstzrange,boolean) line 20 at RAISE -PL/pgSQL function tri_fkey_check_upd() line 25 at IF +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1990-01-01'::TIMESTAMPTZ, 'infinity'); +ERROR: insert or update on table "rooms" violates foreign key constraint "rooms_house_id_valid" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_new_row(name,jsonb) line 133 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew)" +PL/pgSQL function sql_saga.fk_update_check() line 19 at PERFORM DELETE FROM rooms; DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); - drop_temporal_foreign_key ---------------------------- +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); + disable_sql_saga_for_shifts_houses_and_rooms +---------------------------------------------- (1 row) diff --git a/expected/28_with_exclusion_constraints.out b/expected/28_with_exclusion_constraints.out index 332c1ad..c6edbf2 100644 --- a/expected/28_with_exclusion_constraints.out +++ b/expected/28_with_exclusion_constraints.out @@ -1,7 +1,7 @@ -- MOVING THE TIME OF A CHANGE -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - create_temporal_foreign_key ------------------------------ +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + enable_sql_saga_for_shifts_houses_and_rooms +--------------------------------------------- (1 row) @@ -13,18 +13,18 @@ SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'val -- DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; UPDATE houses -SET valid_at = +SET (valid_from, valid_to) = CASE - WHEN lower(valid_at) = '2015-01-01' THEN tstzrange('2015-01-01', '2016-06-01') - WHEN lower(valid_at) = '2016-01-01' THEN tstzrange('2016-06-01', '2017-01-01') + WHEN valid_from = '2015-01-01' THEN ('2015-01-01', '2016-06-01') + WHEN valid_from = '2016-01-01' THEN ('2016-06-01', '2017-01-01') ELSE NULL -- Can't RAISE here but NULL will cause it to fail. END WHERE id = 1 @@ -37,58 +37,60 @@ WHERE id = 1 DELETE FROM rooms; DELETE FROM houses; INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1,'2015-01-01', '2017-01-01') ; --- +-- -- 1.2.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, valid_at)=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; -ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE --- +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 176 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" +PL/pgSQL function sql_saga.uk_update_check() line 23 at PERFORM +-- -- 1.2.2. When the exclusion constraint is checked immediately, -- you can't move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, valid_at)=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; ERROR: current transaction is aborted, commands ignored until end of transaction block COMMIT; --- +-- -- 1.2.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; SET CONSTRAINTS tpk_houses_id DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; COMMIT; -- @@ -98,68 +100,70 @@ COMMIT; -- DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 1.3.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; -ERROR: Tried to update 1 during [Fri Jan 01 00:00:00 2016 PST, Sun Jan 01 00:00:00 2017 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 176 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" +PL/pgSQL function sql_saga.uk_update_check() line 23 at PERFORM UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, valid_at)=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). --- +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Wed Jun 01 00:00:00 2016 PDT")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Fri Jan 01 00:00:00 2016 PST","Sun Jan 01 00:00:00 2017 PST")). +-- -- 1.3.2. When the exclusion constraint is checked immediately, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; --- +-- -- 1.3.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; SET CONSTRAINTS tpk_houses_id DEFERRED; UPDATE houses -SET valid_at = tstzrange('2016-09-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-06-01' +SET (valid_from, valid_to) = ('2016-09-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-06-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-09-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-09-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; -- 2. Small shift to an earlier time -- 2.1 Small shift to an earlier time, moving both ranges at once: DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; UPDATE houses SET valid_at = @@ -173,114 +177,118 @@ WHERE id = 1 -- 2.2 Small shift to an earlier time, moving the earlier range first: DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 2.2.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; -ERROR: Tried to update 1 during [Thu Jan 01 00:00:00 2015 PST, Fri Jan 01 00:00:00 2016 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 176 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" +PL/pgSQL function sql_saga.uk_update_check() line 23 at PERFORM UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). --- +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). +-- -- 2.2.2. When the exclusion constraint is checked immediately, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; COMMIT; --- +-- -- 2.2.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; SET CONSTRAINTS tpk_houses_id DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-03-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-03-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-03-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2015-06-01' +SET (valid_from, valid_to) = ('2015-03-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2015-06-01' ; COMMIT; -- 2.3 Small shift to an earlier time, moving the later range first: DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 2.3.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; -ERROR: Tried to update 1 during [Thu Jan 01 00:00:00 2015 PST, Fri Jan 01 00:00:00 2016 PST) from houses but there are overlapping references in rooms.house_id -CONTEXT: PL/pgSQL function tri_fkey_restrict_upd() line 41 at RAISE --- +ERROR: update or delete on table "houses" violates foreign key constraint "rooms_house_id_valid" on table "rooms" +CONTEXT: PL/pgSQL function sql_saga.validate_foreign_key_old_row(name,jsonb,boolean) line 176 at RAISE +SQL statement "SELECT sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true)" +PL/pgSQL function sql_saga.uk_update_check() line 23 at PERFORM +-- -- 2.3.2. When the exclusion constraint is checked immediately, -- you can't move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; -ERROR: conflicting key value violates exclusion constraint "tpk_houses_id" -DETAIL: Key (id, valid_at)=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, valid_at)=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). +ERROR: conflicting key value violates exclusion constraint "houses_id_tstzrange_excl" +DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Mon Jun 01 00:00:00 2015 PDT","Sun Jan 01 00:00:00 2017 PST")) conflicts with existing key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 00:00:00 2015 PST","Fri Jan 01 00:00:00 2016 PST")). UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; ERROR: current transaction is aborted, commands ignored until end of transaction block COMMIT; --- +-- -- 2.3.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; SET CONSTRAINTS tpk_houses_id DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; -- 3. Large shift to a later time (all the way past the later range) diff --git a/periods.c b/periods.c new file mode 100644 index 0000000..2411c36 --- /dev/null +++ b/periods.c @@ -0,0 +1,788 @@ +#include "postgres.h" +#include "fmgr.h" + +#include "access/htup_details.h" +#include "access/heapam.h" +#if (PG_VERSION_NUM < 120000) +#define table_open(r, l) heap_open(r, l) +#define table_close(r, l) heap_close(r, l) +#else +#include "access/table.h" +#endif +#include "access/tupconvert.h" +#include "access/xact.h" +#include "catalog/pg_type.h" +#include "commands/trigger.h" +#include "datatype/timestamp.h" +#include "executor/spi.h" +#include "funcapi.h" +#include "lib/stringinfo.h" +#include "nodes/bitmapset.h" +#include "utils/builtins.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/hsearch.h" +#include "utils/lsyscache.h" +#include "utils/memutils.h" +#include "utils/rel.h" +#include "utils/timestamp.h" + +PGDLLEXPORT Datum generated_always_as_row_start_end(PG_FUNCTION_ARGS); +PGDLLEXPORT Datum write_history(PG_FUNCTION_ARGS); + +PG_FUNCTION_INFO_V1(generated_always_as_row_start_end); +PG_FUNCTION_INFO_V1(write_history); + +/* Define some SQLSTATEs that might not exist */ +#if (PG_VERSION_NUM < 100000) +#define ERRCODE_GENERATED_ALWAYS MAKE_SQLSTATE('4','2','8','C','9') +#endif +#define ERRCODE_INVALID_ROW_VERSION MAKE_SQLSTATE('2','2','0','1','H') + +/* We use these a lot, so make aliases for them */ +#if (PG_VERSION_NUM < 100000) +#define TRANSACTION_TSTZ TimestampTzGetDatum(GetCurrentTransactionStartTimestamp()) +#define TRANSACTION_TS DirectFunctionCall1(timestamptz_timestamp, TRANSACTION_TSTZ) +#define TRANSACTION_DATE DirectFunctionCall1(timestamptz_date, TRANSACTION_TSTZ) +#else +#define TRANSACTION_TSTZ TimestampTzGetDatum(GetCurrentTransactionStartTimestamp()) +#define TRANSACTION_TS DirectFunctionCall1(timestamptz_timestamp, TRANSACTION_TSTZ) +#define TRANSACTION_DATE DateADTGetDatum(GetSQLCurrentDate()) +#endif + +#define INFINITE_TSTZ TimestampTzGetDatum(DT_NOEND) +#define INFINITE_TS TimestampGetDatum(DT_NOEND) +#define INFINITE_DATE DateADTGetDatum(DATEVAL_NOEND) + +/* Plan caches for inserting into history tables */ +static HTAB *InsertHistoryPlanHash = NULL; + +typedef struct InsertHistoryPlanEntry +{ + Oid history_relid; /* the hash key; must be first */ + char schemaname[NAMEDATALEN]; + char tablename[NAMEDATALEN]; + SPIPlanPtr qplan; +} InsertHistoryPlanEntry; + +static HTAB * +CreateInsertHistoryPlanHash(void) +{ + HASHCTL ctl; + + ctl.keysize = sizeof(Oid); + ctl.entrysize = sizeof(InsertHistoryPlanEntry); + + return hash_create("Insert History Hash", 16, &ctl, HASH_ELEM | HASH_BLOBS); +} + +static void +GetPeriodColumnNames(Relation rel, char *period_name, char **start_name, char **end_name) +{ + int ret; + Datum values[2]; + SPITupleTable *tuptable; + bool is_null; + Datum dat; + MemoryContext mcxt = CurrentMemoryContext; /* The context outside of SPI */ + + const char *sql = + "SELECT p.start_column_name, p.end_column_name " + "FROM periods.periods AS p " + "WHERE (p.table_name, p.period_name) = ($1, $2)"; + static SPIPlanPtr qplan = NULL; + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* + * Query the periods table to get the start and end columns. + * Cache the plan if we haven't already. + */ + if (qplan == NULL) + { + Oid types[2] = {OIDOID, NAMEOID}; + + qplan = SPI_prepare(sql, 2, types); + if (qplan == NULL) + elog(ERROR, "SPI_prepare returned %s for %s", + SPI_result_code_string(SPI_result), sql); + + ret = SPI_keepplan(qplan); + if (ret != 0) + elog(ERROR, "SPI_keepplan returned %s", SPI_result_code_string(ret)); + } + + values[0] = ObjectIdGetDatum(rel->rd_id); + values[1] = CStringGetDatum(period_name); + ret = SPI_execute_plan(qplan, values, NULL, true, 0); + if (ret != SPI_OK_SELECT) + elog(ERROR, "SPI_execute returned %s", SPI_result_code_string(ret)); + + /* Make sure we got one */ + if (SPI_processed == 0) + ereport(ERROR, + (errmsg("period \"%s\" not found on table \"%s\"", + period_name, + RelationGetRelationName(rel)))); + + /* There is a unique constraint so there shouldn't be more than 1 row */ + Assert(SPI_processed == 1); + + /* + * Get the names from the result tuple. We copy them into the original + * context so they don't get wiped out by SPI_finish(). + */ + tuptable = SPI_tuptable; + + dat = SPI_getbinval(tuptable->vals[0], tuptable->tupdesc, 1, &is_null); + *start_name = MemoryContextStrdup(mcxt, NameStr(*(DatumGetName(dat)))); + + dat = SPI_getbinval(tuptable->vals[0], tuptable->tupdesc, 2, &is_null); + *end_name = MemoryContextStrdup(mcxt, NameStr(*(DatumGetName(dat)))); + + /* All done with SPI */ + if (SPI_finish() != SPI_OK_FINISH) + 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; + int i; + Datum values[1]; + TupleDesc tupdesc = RelationGetDescr(rel); + Bitmapset *excluded_attnums = NULL; + MemoryContext mcxt = CurrentMemoryContext; /* The context outside of SPI */ + + 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"; + static SPIPlanPtr qplan = NULL; + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* + * Get the excluded column names. + * Cache the plan if we haven't already. + */ + if (qplan == NULL) + { + Oid types[1] = {OIDOID}; + + qplan = SPI_prepare(sql, 1, types); + if (qplan == NULL) + elog(ERROR, "SPI_prepare returned %s for %s", + SPI_result_code_string(SPI_result), sql); + + ret = SPI_keepplan(qplan); + if (ret != 0) + elog(ERROR, "SPI_keepplan returned %s", SPI_result_code_string(ret)); + } + + values[0] = ObjectIdGetDatum(rel->rd_id); + ret = SPI_execute_plan(qplan, values, NULL, true, 0); + if (ret != SPI_OK_SELECT) + elog(ERROR, "SPI_execute returned %s", SPI_result_code_string(ret)); + + /* Construct a bitmap of excluded attnums */ + if (SPI_processed > 0 && SPI_tuptable != NULL) + { + TupleDesc spitupdesc = SPI_tuptable->tupdesc; + bool isnull; + int i; + + for (i = 0; i < SPI_processed; i++) + { + HeapTuple tuple = SPI_tuptable->vals[i]; + Datum attdatum; + char *attname; + int16 attnum; + + /* Get the attnum from the column name */ + attdatum = SPI_getbinval(tuple, spitupdesc, 1, &isnull); + attname = NameStr(*(DatumGetName(attdatum))); + attnum = SPI_fnumber(tupdesc, attname); + + /* Make sure it's valid (should always be) */ + if (attnum == SPI_ERROR_NOATTRIBUTE) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" does not exist", attname))); + + /* Just ignore system columns (should never happen) */ + if (attnum < 0) + continue; + + /* Add it to the bitmap set */ + excluded_attnums = bms_add_member(excluded_attnums, attnum); + } + + /* + * If we have excluded columns, move the bitmapset out of the SPI + * context. + */ + if (excluded_attnums != NULL) + { + MemoryContext spicontext = MemoryContextSwitchTo(mcxt); + excluded_attnums = bms_copy(excluded_attnums); + MemoryContextSwitchTo(spicontext); + } + } + + /* 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 (excluded_attnums == NULL) + return false; + + for (i = 1; i <= tupdesc->natts; i++) + { + Datum old_datum, new_datum; + bool old_isnull, new_isnull; + int16 typlen; + bool typbyval; + + /* Ignore if deleted column */ + if (TupleDescAttr(tupdesc, i-1)->attisdropped) + continue; + + /* Ignore if excluded column */ + if (bms_is_member(i, excluded_attnums)) + continue; + + 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 */ + typlen = TupleDescAttr(tupdesc, i-1)->attlen; + typbyval = TupleDescAttr(tupdesc, i-1)->attbyval; + 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 + * InvalidOid is returned. + */ +static Oid +GetHistoryTable(Relation rel) +{ + int ret; + Datum values[1]; + Oid result; + SPITupleTable *tuptable; + bool is_null; + + const char *sql = + "SELECT history_table_name::oid " + "FROM periods.system_versioning AS sv " + "WHERE sv.table_name = $1"; + static SPIPlanPtr qplan = NULL; + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + /* + * Check existence in system_versioning table. + * Cache the plan if we haven't already. + */ + if (qplan == NULL) + { + Oid types[1] = {OIDOID}; + + qplan = SPI_prepare(sql, 1, types); + if (qplan == NULL) + elog(ERROR, "SPI_prepare returned %s for %s", + SPI_result_code_string(SPI_result), sql); + + ret = SPI_keepplan(qplan); + if (ret != 0) + elog(ERROR, "SPI_keepplan returned %s", SPI_result_code_string(ret)); + } + + values[0] = ObjectIdGetDatum(rel->rd_id); + ret = SPI_execute_plan(qplan, values, NULL, true, 0); + if (ret != SPI_OK_SELECT) + elog(ERROR, "SPI_execute returned %s", SPI_result_code_string(ret)); + + /* Did we get one? */ + if (SPI_processed == 0) + { + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + return InvalidOid; + } + + /* There is a unique constraint so there shouldn't be more than 1 row */ + Assert(SPI_processed == 1); + + /* Get oid from results */ + tuptable = SPI_tuptable; + result = DatumGetObjectId(SPI_getbinval(tuptable->vals[0], tuptable->tupdesc, 1, &is_null)); + + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); + + return result; +} + +static Datum +GetRowStart(Oid typeid) +{ + switch (typeid) + { + case TIMESTAMPTZOID: + return TRANSACTION_TSTZ; + case TIMESTAMPOID: + return TRANSACTION_TS; + case DATEOID: + return TRANSACTION_DATE; + default: + elog(ERROR, "unexpected type: %d", typeid); + return 0; /* keep compiler quiet */ + } +} + +static Datum +GetRowEnd(Oid typeid) +{ + switch (typeid) + { + case TIMESTAMPTZOID: + return INFINITE_TSTZ; + case TIMESTAMPOID: + return INFINITE_TS; + case DATEOID: + return INFINITE_DATE; + default: + elog(ERROR, "unexpected type: %d", typeid); + return 0; /* keep compiler quiet */ + } +} + +static int +CompareWithCurrentDatum(Oid typeid, Datum value) +{ + switch (typeid) + { + case TIMESTAMPTZOID: + return DatumGetInt32(DirectFunctionCall2(timestamp_cmp, value, TRANSACTION_TSTZ)); + + case TIMESTAMPOID: + return DatumGetInt32(DirectFunctionCall2(timestamp_cmp, value, TRANSACTION_TS)); + + case DATEOID: + return DatumGetInt32(DirectFunctionCall2(date_cmp, value, TRANSACTION_DATE)); + + default: + elog(ERROR, "unexpected type: %d", typeid); + return 0; /* keep compiler quiet */ + } +} + +static int +CompareWithInfiniteDatum(Oid typeid, Datum value) +{ + switch (typeid) + { + case TIMESTAMPTZOID: + return DatumGetInt32(DirectFunctionCall2(timestamp_cmp, value, INFINITE_TSTZ)); + + case TIMESTAMPOID: + return DatumGetInt32(DirectFunctionCall2(timestamp_cmp, value, INFINITE_TS)); + + case DATEOID: + return DatumGetInt32(DirectFunctionCall2(date_cmp, value, INFINITE_DATE)); + + default: + elog(ERROR, "unexpected type: %d", typeid); + return 0; /* keep compiler quiet */ + } +} + +Datum +generated_always_as_row_start_end(PG_FUNCTION_ARGS) +{ + TriggerData *trigdata = castNode(TriggerData, fcinfo->context); + const char *funcname = "generated_always_as_row_start_end"; + Relation rel; + HeapTuple new_row; + TupleDesc new_tupdesc; + Datum values[2]; + bool nulls[2]; + int columns[2]; + char *start_name, *end_name; + int16 start_num, end_num; + Oid typeid; + + /* + * Make sure this is being called as an BEFORE ROW trigger. Note: + * translatable error strings are shared with ri_triggers.c, so resist the + * temptation to fold the function name into them. + */ + if (!CALLED_AS_TRIGGER(fcinfo)) + ereport(ERROR, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + errmsg("function \"%s\" was not called by trigger manager", + funcname))); + + if (!TRIGGER_FIRED_BEFORE(trigdata->tg_event) || + !TRIGGER_FIRED_FOR_ROW(trigdata->tg_event)) + ereport(ERROR, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + 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, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + errmsg("function \"%s\" must be fired for INSERT or UPDATE", + funcname))); + new_row = NULL; /* keep compiler quiet */ + } + + GetPeriodColumnNames(rel, "system_time", &start_name, &end_name); + + /* Get the column numbers and type */ + start_num = SPI_fnumber(new_tupdesc, start_name); + end_num = SPI_fnumber(new_tupdesc, end_name); + typeid = SPI_gettypeid(new_tupdesc, start_num); + + columns[0] = start_num; + values[0] = GetRowStart(typeid); + nulls[0] = false; + columns[1] = end_num; + values[1] = GetRowEnd(typeid); + nulls[1] = false; +#if (PG_VERSION_NUM < 100000) + new_row = SPI_modifytuple(rel, new_row, 2, columns, values, nulls); +#else + new_row = heap_modify_tuple_by_cols(new_row, new_tupdesc, 2, columns, values, nulls); +#endif + + return PointerGetDatum(new_row); +} + +static void +insert_into_history(Relation history_rel, HeapTuple history_tuple) +{ + InsertHistoryPlanEntry *hentry; + bool found; + char *schemaname = SPI_getnspname(history_rel); + char *tablename = SPI_getrelname(history_rel); + Oid history_relid = history_rel->rd_id; + Datum value; + int ret; + + if (SPI_connect() != SPI_OK_CONNECT) + elog(ERROR, "SPI_connect failed"); + + if (!InsertHistoryPlanHash) + InsertHistoryPlanHash = CreateInsertHistoryPlanHash(); + + /* Fetch the cached plan */ + hentry = (InsertHistoryPlanEntry *) hash_search( + InsertHistoryPlanHash, + &history_relid, + HASH_ENTER, + &found); + + /* If we didn't find it or the name changed, re-plan it */ + if (!found || + !strcmp(hentry->schemaname, schemaname) || + !strcmp(hentry->tablename, tablename)) + { + StringInfo buf = makeStringInfo(); + Oid type = HeapTupleHeaderGetTypeId(history_tuple->t_data); + + appendStringInfo(buf, "INSERT INTO %s VALUES (($1).*)", + quote_qualified_identifier(schemaname, tablename)); + + hentry->history_relid = history_relid; + strlcpy(hentry->schemaname, schemaname, sizeof(hentry->schemaname)); + strlcpy(hentry->tablename, tablename, sizeof(hentry->tablename)); + hentry->qplan = SPI_prepare(buf->data, 1, &type); + if (hentry->qplan == NULL) + elog(ERROR, "SPI_prepare returned %s for %s", + SPI_result_code_string(SPI_result), buf->data); + + ret = SPI_keepplan(hentry->qplan); + if (ret != 0) + elog(ERROR, "SPI_keepplan returned %s", SPI_result_code_string(ret)); + } + + /* Do the INSERT */ + value = HeapTupleGetDatum(history_tuple); + ret = SPI_execute_plan(hentry->qplan, &value, NULL, false, 0); + if (ret != SPI_OK_INSERT) + elog(ERROR, "SPI_execute returned %s", SPI_result_code_string(ret)); + + if (SPI_finish() != SPI_OK_FINISH) + elog(ERROR, "SPI_finish failed"); +} + +Datum +write_history(PG_FUNCTION_ARGS) +{ + TriggerData *trigdata = castNode(TriggerData, fcinfo->context); + const char *funcname = "write_history"; + Relation rel; + HeapTuple old_row, new_row; + TupleDesc tupledesc; + char *start_name, *end_name; + int16 start_num, end_num; + Oid typeid; + 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: + * translatable error strings are shared with ri_triggers.c, so resist the + * temptation to fold the function name into them. + */ + if (!CALLED_AS_TRIGGER(fcinfo)) + ereport(ERROR, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + errmsg("function \"%s\" was not called by trigger manager", + funcname))); + + if (!TRIGGER_FIRED_AFTER(trigdata->tg_event) || + !TRIGGER_FIRED_FOR_ROW(trigdata->tg_event)) + ereport(ERROR, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + 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)) + { + old_row = NULL; /* keep compiler quiet */ + new_row = trigdata->tg_trigtuple; + } + else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event)) + { + 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)) + { + old_row = trigdata->tg_trigtuple; + new_row = NULL; /* keep compiler quiet */ + } + else + { + ereport(ERROR, + (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED), + errmsg("function \"%s\" must be fired for INSERT or UPDATE or DELETE", + funcname))); + old_row = NULL; /* keep compiler quiet */ + new_row = NULL; /* keep compiler quiet */ + } + + GetPeriodColumnNames(rel, "system_time", &start_name, &end_name); + + /* Get the column numbers and type */ + start_num = SPI_fnumber(tupledesc, start_name); + end_num = SPI_fnumber(tupledesc, end_name); + typeid = SPI_gettypeid(tupledesc, start_num); + + /* + * 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_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); + + if (CompareWithCurrentDatum(typeid, start_datum) != 0) + ereport(ERROR, + (errcode(ERRCODE_GENERATED_ALWAYS), + errmsg("cannot insert or update column \"%s\"", start_name), + errdetail("Column \"%s\" is GENERATED ALWAYS AS ROW START", start_name))); + + if (CompareWithInfiniteDatum(typeid, end_datum) != 0) + ereport(ERROR, + (errcode(ERRCODE_GENERATED_ALWAYS), + errmsg("cannot insert or update column \"%s\"", end_name), + errdetail("Column \"%s\" is GENERATED ALWAYS AS ROW END", end_name))); + + /* + * If this is an INSERT, then we're done because there is no history to + * write. + */ + if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event)) + 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)); + + /* + * Don't do anything more if the start time is still the same. + * + * DELETE: SQL:2016 13.4 GR 15)a)iii)2) + * UPDATE: SQL:2016 15.13 GR 9)a)iii)2) + */ + if (cmp == 0) + return PointerGetDatum(NULL); + + /* + * There is a weird case in READ UNCOMMITTED and READ COMMITTED where a + * transaction can UPDATE/DELETE a row created by a transaction that + * started later. In effect, system-versioned tables must be run at the + * SERIALIZABLE level and so if we come across such an anomaly, we give an + * invalid row version error, per spec. + * + * DELETE: SQL:2016 13.4 GR 15)a)iii)1) + * UPDATE: SQL:2016 15.13 GR 9)a)iii)1) + */ + if (cmp > 0) + ereport(ERROR, + (errcode(ERRCODE_INVALID_ROW_VERSION), + errmsg("invalid row version"), + errdetail("The row being updated or deleted was created after this transaction started."), + errhint("The transaction might succeed if retried."))); + + /* + * If this table does not have SYSTEM VERSIONING, there is nothing else to + * be done. + */ + history_id = GetHistoryTable(rel); + if (OidIsValid(history_id)) + { + Relation history_rel; + TupleDesc history_tupledesc; + HeapTuple history_tuple; + int16 history_end_num; + TupleConversionMap *map; + Datum *values; + bool *nulls; + + /* Open the history table for inserting */ + history_rel = table_open(history_id, RowExclusiveLock); + history_tupledesc = RelationGetDescr(history_rel); + history_end_num = SPI_fnumber(history_tupledesc, end_name); + + /* + * We may have to convert the tuple structure between the table and the + * history table. + * + * See https://github.com/xocolatl/periods/issues/5 + */ +#if (PG_VERSION_NUM < 130000) + map = convert_tuples_by_name(tupledesc, history_tupledesc, gettext_noop("could not convert row type")); +#else + map = convert_tuples_by_name(tupledesc, history_tupledesc); +#endif + if (map != NULL) + { +#if (PG_VERSION_NUM < 120000) + history_tuple = do_convert_tuple(old_row, map); +#else + history_tuple = execute_attr_map_tuple(old_row, map); +#endif + free_conversion_map(map); + } + else + { + history_tuple = old_row; + + /* + * Use the main table's tupledesc if there is no map so that + * missing attributes are filled in. This corrects for bug #16242 + * which was found by this very problem. + */ + history_tupledesc = tupledesc; + } + + /* Build the new tuple for the history table */ + values = (Datum *) palloc(history_tupledesc->natts * sizeof(Datum)); + nulls = (bool *) palloc(history_tupledesc->natts * sizeof(bool)); + + /* Modify the historical ROW END on the fly */ + heap_deform_tuple(history_tuple, history_tupledesc, values, nulls); + values[history_end_num-1] = GetRowStart(typeid); + nulls[history_end_num-1] = false; + history_tuple = heap_form_tuple(history_tupledesc, values, nulls); + + pfree(values); + pfree(nulls); + + /* INSERT the row */ + insert_into_history(history_rel, history_tuple); + + /* Keep the lock until end of transaction */ + table_close(history_rel, NoLock); + } + + return PointerGetDatum(NULL); +} diff --git a/sql/06_unique_foreign.sql b/sql/06_unique_foreign.sql index 2d7f0c8..5467cb0 100644 --- a/sql/06_unique_foreign.sql +++ b/sql/06_unique_foreign.sql @@ -3,7 +3,7 @@ SET ROLE TO sql_saga_unprivileged_user; -- Unique keys are already pretty much guaranteed by the underlying features of -- PostgreSQL, but test them anyway. -CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e)); +CREATE TABLE uk (id integer, s integer, e integer, CONSTRAINT uk_pkey PRIMARY KEY (id, s, e) DEFERRABLE); SELECT sql_saga.add_era('uk', 's', 'e', 'p'); SELECT sql_saga.add_unique_key('uk', ARRAY['id'], 'p', key_name => 'uk_id_p', unique_constraint => 'uk_pkey'); TABLE sql_saga.unique_keys; diff --git a/sql/09_drop_protection.sql b/sql/09_drop_protection.sql index b7b9994..ac49f0a 100644 --- a/sql/09_drop_protection.sql +++ b/sql/09_drop_protection.sql @@ -26,8 +26,8 @@ ALTER TABLE dp DROP CONSTRAINT dp_pkey; /* unique_keys */ ALTER TABLE dp - ADD CONSTRAINT u UNIQUE (id, s, e), - ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&); + ADD CONSTRAINT u UNIQUE (id, s, e) DEFERRABLE, + ADD CONSTRAINT x EXCLUDE USING gist (id WITH =, integerrange(s, e, '[)') WITH &&) DEFERRABLE; SELECT sql_saga.add_unique_key('dp', ARRAY['id'], 'p', 'k', 'u', 'x'); ALTER TABLE dp DROP CONSTRAINT u; -- fails ALTER TABLE dp DROP CONSTRAINT x; -- fails diff --git a/sql/10_rename_following.sql b/sql/10_rename_following.sql index 1245a04..10d1c83 100644 --- a/sql/10_rename_following.sql +++ b/sql/10_rename_following.sql @@ -48,6 +48,10 @@ ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_fk_update" ON rename_test_ref ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_update" ON rename_test RENAME TO uk_update; ALTER TRIGGER "rename_test_ref_col2_COLUMN1_col3_q_uk_delete" ON rename_test RENAME TO uk_delete; TABLE sql_saga.foreign_keys; -DROP TABLE rename_test_ref; +SELECT sql_saga.drop_foreign_key('rename_test_ref','rename_test_ref_col2_COLUMN1_col3_q'); +SELECT sql_saga.drop_unique_key('rename_test', 'rename_test_col2_col1_col3_p'); DROP TABLE rename_test; + +SELECT sql_saga.drop_era('rename_test_ref','embedded " symbols'); +DROP TABLE rename_test_ref; diff --git a/sql/21_init.sql b/sql/21_init.sql index 8aed76d..68eb127 100644 --- a/sql/21_init.sql +++ b/sql/21_init.sql @@ -1,20 +1,102 @@ -CREATE EXTENSION btree_gist; -- for the GIST exclusion constraints -CREATE EXTENSION time_for_keys; +CREATE EXTENSION sql_saga CASCADE; + CREATE TABLE shifts ( job_id INTEGER, worker_id INTEGER, - valid_at tstzrange, - EXCLUDE USING gist (worker_id WITH =, valid_at WITH &&) + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (job_id, worker_id, valid_from, valid_to) ); + CREATE TABLE houses ( id INTEGER, assessment FLOAT, - valid_at tstzrange, - CONSTRAINT tpk_houses_id EXCLUDE USING gist (id WITH =, valid_at WITH &&) DEFERRABLE INITIALLY IMMEDIATE + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (id, valid_from, valid_to) ); + CREATE TABLE rooms ( id INTEGER, house_id INTEGER, - valid_at tstzrange, - CONSTRAINT tpk_rooms_id EXCLUDE USING gist (id WITH =, valid_at WITH &&) DEFERRABLE INITIALLY IMMEDIATE + valid_from timestamptz, + valid_to timestamptz, + PRIMARY KEY (id, valid_from, valid_to) ); + +-- Before using sql_saga +\d rooms +\d houses +\d shifts + +-- Verify that enable and disable each work correctly. +SELECT sql_saga.add_era('shifts', 'valid_from', 'valid_to'); +SELECT sql_saga.add_era('houses', 'valid_from', 'valid_to', 'valid'); +SELECT sql_saga.add_era('rooms', 'valid_from', 'valid_to'); +TABLE sql_saga.era; + +SELECT sql_saga.add_unique_key('shifts', ARRAY['job_id','worker_id'], 'valid'); +SELECT sql_saga.add_unique_key('houses', ARRAY['id'], 'valid'); +SELECT sql_saga.add_unique_key('rooms', ARRAY['id'], 'valid'); +TABLE sql_saga.unique_keys; + +SELECT sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid'); +TABLE sql_saga.foreign_keys; + +SELECT sql_saga.drop_foreign_key('rooms', 'rooms_house_id_valid'); +TABLE sql_saga.foreign_keys; + +-- While sql_saga is active +\d rooms +\d houses +\d shifts + +SELECT sql_saga.drop_unique_key('rooms', 'rooms_id_valid'); +SELECT sql_saga.drop_unique_key('houses','houses_id_valid'); +-- TODO: Simplify this API, to take the same parameters when created. +-- TODO: Detect and raise an error if there is no match in "sql_saga.unique_keys". +SELECT sql_saga.drop_unique_key('shifts', 'shifts_job_id_worker_id_valid'); +TABLE sql_saga.unique_keys; + +SELECT sql_saga.drop_era('rooms'); +SELECT sql_saga.drop_era('houses'); +SELECT sql_saga.drop_era('shifts'); +TABLE sql_saga.era; + +-- After removing sql_saga, it should be as before. +\d rooms +\d houses +\d shifts + +-- Make convenience functions for later tests. +CREATE FUNCTION enable_sql_saga_for_shifts_houses_and_rooms() RETURNS void LANGUAGE plpgsql AS $EOF$ +BEGIN + PERFORM sql_saga.add_era('shifts', 'valid_from', 'valid_to'); + PERFORM sql_saga.add_unique_key('shifts', ARRAY['job_id','worker_id'], 'valid'); + + PERFORM sql_saga.add_era('houses', 'valid_from', 'valid_to', 'valid'); + PERFORM sql_saga.add_unique_key('houses', ARRAY['id'], 'valid'); + + PERFORM sql_saga.add_era('rooms', 'valid_from', 'valid_to'); + PERFORM sql_saga.add_unique_key('rooms', ARRAY['id'], 'valid'); + PERFORM sql_saga.add_foreign_key('rooms', ARRAY['house_id'], 'valid', 'houses_id_valid'); +END; +$EOF$; + +CREATE FUNCTION disable_sql_saga_for_shifts_houses_and_rooms() RETURNS void LANGUAGE plpgsql AS $EOF$ +BEGIN + PERFORM sql_saga.drop_foreign_key('rooms', 'rooms_house_id_valid'); + + PERFORM sql_saga.drop_unique_key('rooms', 'rooms_id_valid'); + PERFORM sql_saga.drop_unique_key('houses','houses_id_valid'); + PERFORM sql_saga.drop_unique_key('shifts', 'shifts_job_id_worker_id_valid'); + + PERFORM sql_saga.drop_era('rooms'); + PERFORM sql_saga.drop_era('houses'); + PERFORM sql_saga.drop_era('shifts'); +END; +$EOF$; + +-- Test the convenience functions. +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms() diff --git a/sql/22_completely_covers_test.sql b/sql/22_completely_covers_test.sql index b1f3862..f9d9f09 100644 --- a/sql/22_completely_covers_test.sql +++ b/sql/22_completely_covers_test.sql @@ -1,120 +1,120 @@ -INSERT INTO shifts VALUES - (1, 1, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (1, 2, tstzrange('2017-11-27 12:00:00', '2017-11-27 17:00:00')), - (2, 3, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (2, 4, tstzrange('2017-11-27 13:00:00', '2017-11-27 17:00:00')), - (3, 5, tstzrange(null, '2017-11-27 12:00:00')), - (3, 5, tstzrange('2017-11-27 12:00:00', '2017-11-27 17:00:00')), - (4, 6, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')), - (4, 7, tstzrange('2017-11-27 12:00:00', null)) +INSERT INTO shifts(job_id, worker_id, valid_from, valid_to) VALUES + (1, 1, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (1, 2, '2017-11-27 12:00:00', '2017-11-27 17:00:00'), + (2, 3, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (2, 4, '2017-11-27 13:00:00', '2017-11-27 17:00:00'), + (3, 5, '-infinity', '2017-11-27 12:00:00'), + (3, 5, '2017-11-27 12:00:00', '2017-11-27 17:00:00'), + (4, 6, '2017-11-27 06:00:00', '2017-11-27 12:00:00'), + (4, 7, '2017-11-27 12:00:00', 'infinity') ; -- TRUE: -- it covers when the range matches one exactly: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 12:00:00')) FROM shifts WHERE job_id = 1; -- it covers when the range matches two exactly: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; -- it covers when the range has extra in front: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 08:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 08:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; -- it covers when the range has extra behind: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; -- it covers when the range has extra on both sides: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; -- an infinite start will cover a finite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 3; -- an infinite start will cover an infinite target: -SELECT completely_covers(valid_at, tstzrange(NULL, '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 3; -- an infinite end will cover a finite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 4; -- an infinite end will cover an infinite target: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', 'infinity')) FROM shifts WHERE job_id = 4; -- FALSE: -- it does not cover when the range is null: -SELECT completely_covers(NULL, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(NULL, tstzrange('2017-11-27 08:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; -- it does not cover when the range misses completely: -SELECT completely_covers(valid_at, tstzrange('2017-11-29 08:00:00', '2017-11-29 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-29 08:00:00', '2017-11-29 14:00:00')) FROM shifts WHERE job_id = 1; -- it does not cover when the range has something at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 04:00:00', '2017-11-27 14:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 04:00:00', '2017-11-27 14:00:00')) FROM shifts WHERE job_id = 1; -- it does not cover when the range has something at the end: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 1; -- it does not cover when the range has something in the middle: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 2; -- it does not cover when the range is lower-unbounded: -SELECT completely_covers(valid_at, tstzrange(NULL, '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 1; -- it does not cover when the range is upper-unbounded: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', 'infinity')) FROM shifts WHERE job_id = 1; -- it does not cover when the range is both-sides-unbounded: -SELECT completely_covers(valid_at, tstzrange(NULL, NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', 'infinity')) FROM shifts WHERE job_id = 1; -- an infinite start will not cover a finite target if there is uncovered time at the end: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 06:00:00', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 3; -- an infinite start will not cover an infinite target if there is uncovered time at the end: -SELECT completely_covers(valid_at, tstzrange(NULL, '2017-11-27 20:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('-infinity', '2017-11-27 20:00:00')) FROM shifts WHERE job_id = 3; -- an infinite end will not cover a finite target if there is uncovered time at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 03:00:00', '2017-11-27 17:00:00')) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 03:00:00', '2017-11-27 17:00:00')) FROM shifts WHERE job_id = 4; -- an infinite end will not cover an infinite target if there is uncovered time at the beginning: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 03:00:00', NULL)) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 03:00:00', 'infinity')) FROM shifts WHERE job_id = 4; @@ -122,14 +122,14 @@ WHERE job_id = 4; -- NULL: -- it is unknown when the target is null: -SELECT completely_covers(valid_at, null) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), null) FROM shifts WHERE job_id = 1; -- Errors: -- it fails if the input ranges go backwards: -SELECT completely_covers(valid_at, tstzrange('2017-11-27 13:00:00', '2017-11-27 20:00:00') ORDER BY worker_id DESC) +SELECT sql_saga.completely_covers(tstzrange(valid_from,valid_to), tstzrange('2017-11-27 13:00:00', '2017-11-27 20:00:00') ORDER BY worker_id DESC) FROM shifts WHERE job_id = 1; diff --git a/sql/23_create_temporal_foreign_key_test.sql b/sql/23_create_temporal_foreign_key_test.sql index 120be50..91b805c 100644 --- a/sql/23_create_temporal_foreign_key_test.sql +++ b/sql/23_create_temporal_foreign_key_test.sql @@ -1,43 +1,46 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ) ; -- it works on an empty table -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); -- it works on a table with a NULL foreign key -INSERT INTO rooms VALUES (1, NULL, tstzrange('2015-01-01', '2017-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, NULL, '2015-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; -- it works on a table with a FK fulfilled by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; -- it works on a table with a FK fulfilled by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-06-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; -- it fails on a table with a missing foreign key -INSERT INTO rooms VALUES (1, 2, tstzrange('2015-01-01', '2016-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 2, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; -- it fails on a table with a completely-uncovered foreign key -INSERT INTO rooms VALUES (1, 1, tstzrange('2010-01-01', '2011-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2010-01-01'::TIMESTAMPTZ, '2011-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; -- it fails on a table with a partially-covered foreign key -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2018-01-01')); -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); +INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2018-01-01'::TIMESTAMPTZ); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); DELETE FROM rooms; DELETE FROM rooms; diff --git a/sql/24_delete_pk_test.sql b/sql/24_delete_pk_test.sql index f9c78eb..7577db4 100644 --- a/sql/24_delete_pk_test.sql +++ b/sql/24_delete_pk_test.sql @@ -1,59 +1,56 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)) +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity') ; - - --- ON DELETE RESTRICT -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); - -- You can delete a pk with no references DELETE FROM houses WHERE id = 2; -- You can delete a finite pk range with no references -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-06-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2015-06-01'::timestamptz; -INSERT INTO houses VALUES (1, 200000, tstzrange('2015-01-01', '2016-01-01')); +INSERT INTO rooms VALUES (1, 1, '2016-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2015-06-01'::timestamptz; +INSERT INTO houses VALUES (1, 200000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't delete a finite pk range that is partly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't delete a finite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't delete a finite pk range that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); -DELETE FROM houses WHERE id = 1 and valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 1 and tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can delete an infinite pk range with no references -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', '2015-01-01')); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -INSERT INTO houses VALUES (3, 200000, tstzrange('2015-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +INSERT INTO houses VALUES (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can't delete an infinite pk range that is partly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', '2017-01-01')); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't delete an infinite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't delete an infinite pk range that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -DELETE FROM houses WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +DELETE FROM houses WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- ON DELETE NOACTION @@ -71,4 +68,4 @@ DELETE FROM rooms; DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); \ No newline at end of file diff --git a/sql/25_update_pk_test.sql b/sql/25_update_pk_test.sql index 61405c8..0e5a62f 100644 --- a/sql/25_update_pk_test.sql +++ b/sql/25_update_pk_test.sql @@ -1,99 +1,98 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)) -; - - -- ON UPDATE RESTRICT -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity') +; -- You can update a finite pk id with no references UPDATE houses SET id = 4 WHERE id = 1; UPDATE houses SET id = 1 WHERE id = 4; -- You can update a finite pk range with no references -UPDATE houses SET valid_at = tstzrange('1999-01-01', '2000-01-01') WHERE id = 1 AND valid_at @> '2015-06-01'::timestamptz; -UPDATE houses SET valid_at = tstzrange('2015-01-01', '2016-01-01') WHERE id = 1 AND valid_at @> '1999-06-01'::timestamptz; +UPDATE houses SET valid_from = '1999-01-01'::TIMESTAMPTZ, valid_to = '2000-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2015-06-01'::timestamptz; +UPDATE houses SET valid_from = '2015-01-01'::TIMESTAMPTZ, valid_to = '2016-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '1999-06-01'::timestamptz; -- You can update a finite pk range that is partly covered elsewhere -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); -UPDATE houses SET valid_at = tstzrange('2016-01-01', '2016-09-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; -UPDATE houses SET valid_at = tstzrange('2016-01-01', '2017-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2016-01-01'::TIMESTAMPTZ, valid_to = '2016-09-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; +UPDATE houses SET valid_from = '2016-01-01'::TIMESTAMPTZ, valid_to = '2017-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't update a finite pk id that is partly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); UPDATE houses SET id = 4 WHERE id = 1; DELETE FROM rooms; -- You can't update a finite pk range that is partly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2016-06-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't update a finite pk id that is exactly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2017-01-01')); +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); UPDATE houses SET id = 4 WHERE id = 1; DELETE FROM rooms; -- You can't update a finite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2016-01-01', '2017-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can't update a finite pk id that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); UPDATE houses SET id = 4 WHERE id = 1; DELETE FROM rooms; -- You can't update a finite pk range that is more than covered -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-06-01', '2017-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 1 AND valid_at @> '2016-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 1, '2015-06-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 1 AND tstzrange(valid_from, valid_to) @> '2016-06-01'::timestamptz; DELETE FROM rooms; -- You can update an infinite pk id with no references -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', '2015-01-01')); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ); +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; UPDATE houses SET id = 3 WHERE id = 4; DELETE FROM rooms; -- You can update an infinite pk range with no references -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', '2015-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; -UPDATE houses SET valid_at = tstzrange('2015-01-01', null) WHERE id = 3 and valid_at @> '2017-06-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; +UPDATE houses SET valid_from = '2015-01-01'::TIMESTAMPTZ, valid_to = 'infinity' WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2017-06-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk id that is partly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', '2017-01-01')); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk range that is partly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', '2017-01-01')); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk id that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk range that is exactly covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk id that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -UPDATE houses SET id = 4 WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +UPDATE houses SET id = 4 WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- You can't update an infinite pk range that is more than covered -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); -UPDATE houses SET valid_at = tstzrange('2017-01-01', '2018-01-01') WHERE id = 3 and valid_at @> '2016-01-01'::timestamptz; +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'); +UPDATE houses SET valid_from = '2017-01-01'::TIMESTAMPTZ, valid_to = '2018-01-01'::TIMESTAMPTZ WHERE id = 3 and tstzrange(valid_from, valid_to) @> '2016-01-01'::timestamptz; DELETE FROM rooms; -- ON UPDATE NOACTION @@ -110,4 +109,4 @@ DELETE FROM rooms; DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); diff --git a/sql/26_insert_fk_test.sql b/sql/26_insert_fk_test.sql index 3d0fc6d..914b425 100644 --- a/sql/26_insert_fk_test.sql +++ b/sql/26_insert_fk_test.sql @@ -1,74 +1,75 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)), - (4, 200000, tstzrange(null, '2014-01-01')) +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ), + (4, 200000, '-infinity'::TIMESTAMPTZ, '2014-01-01'::TIMESTAMPTZ) ; -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -- You can insert a NULL fk -INSERT INTO rooms VALUES (1, NULL, tstzrange('2010-01-01', '2011-01-01')); +INSERT INTO rooms VALUES (1, NULL, '2010-01-01'::TIMESTAMPTZ, '2011-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk more than covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2017-01-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert a finite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2016-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't insert a finite fk id not covered by any row -INSERT INTO rooms VALUES (1, 7, tstzrange('2015-01-01', '2016-01-01')); +INSERT INTO rooms VALUES (1, 7, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ); -- You can't insert a finite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('1999-01-01', '2000-01-01')); +INSERT INTO rooms VALUES (1, 1, '1999-01-01'::TIMESTAMPTZ, '2000-01-01'::TIMESTAMPTZ); -- You can't insert a finite fk partially covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2014-01-01', '2015-06-01')); +INSERT INTO rooms VALUES (1, 1, '2014-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); -- You can't insert a finite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2014-01-01', '2016-06-01')); +INSERT INTO rooms VALUES (1, 1, '2014-01-01'::TIMESTAMPTZ, '2016-06-01'::TIMESTAMPTZ); -- You can insert an infinite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk more than covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2016-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2016-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can insert an infinite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2014-06-01', null)); +INSERT INTO rooms VALUES (1, 3, '2014-06-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; -- You can't insert an infinite fk id not covered by any row -INSERT INTO rooms VALUES (1, 7, tstzrange('2015-01-01', null)); +INSERT INTO rooms VALUES (1, 7, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); -- You can't insert an infinite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2020-01-01', null)); +INSERT INTO rooms VALUES (1, 1, '2020-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); -- You can't insert an infinite fk partially covered by one row -INSERT INTO rooms VALUES (1, 4, tstzrange(null, '2020-01-01')); +INSERT INTO rooms VALUES (1, 4, '-infinity'::TIMESTAMPTZ, '2020-01-01'::TIMESTAMPTZ); -- You can't insert an infinite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('1990-01-01', null)); +INSERT INTO rooms VALUES (1, 3, '1990-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ); DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); \ No newline at end of file diff --git a/sql/27_update_fk_test.sql b/sql/27_update_fk_test.sql index 2fe6cf8..33d265d 100644 --- a/sql/27_update_fk_test.sql +++ b/sql/27_update_fk_test.sql @@ -1,104 +1,105 @@ -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')), - (2, 300000, tstzrange('2015-01-01', '2016-01-01')), - (3, 100000, tstzrange('2014-01-01', '2015-01-01')), - (3, 200000, tstzrange('2015-01-01', null)), - (4, 200000, tstzrange(null, '2014-01-01')) +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); + +INSERT INTO houses VALUES + (1, 150000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (1, 200000, '2016-01-01'::TIMESTAMPTZ, '2017-01-01'::TIMESTAMPTZ), + (2, 300000, '2015-01-01'::TIMESTAMPTZ, '2016-01-01'::TIMESTAMPTZ), + (3, 100000, '2014-01-01'::TIMESTAMPTZ, '2015-01-01'::TIMESTAMPTZ), + (3, 200000, '2015-01-01'::TIMESTAMPTZ, 'infinity'::TIMESTAMPTZ), + (4, 200000, '-infinity'::TIMESTAMPTZ, '2014-01-01'::TIMESTAMPTZ) ; -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); -- You can update an fk id to NULL -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-06-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = NULL; DELETE FROM rooms; -- You can update the range when the fk is NULL -INSERT INTO rooms VALUES (1, NULL, tstzrange('2015-01-01', '2015-06-01')); -UPDATE rooms SET valid_at = tstzrange('1999-01-01', '2000-01-01'); +INSERT INTO rooms VALUES (1, NULL, '2015-01-01'::TIMESTAMPTZ, '2015-06-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1999-01-01'::TIMESTAMPTZ, '2000-01-01'); DELETE FROM rooms; -- You can update a finite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2016-01-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2016-01-01'); DELETE FROM rooms; -- You can update a finite fk more than covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2015-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2015-06-01'); DELETE FROM rooms; -- You can update a finite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2017-01-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2017-01-01'); DELETE FROM rooms; -- You can update a finite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', '2016-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, '2016-06-01'); DELETE FROM rooms; -- You can't update a finite fk id not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = 7; DELETE FROM rooms; -- You can't update a finite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('1999-01-01', '2000-01-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1999-01-01'::TIMESTAMPTZ, '2000-01-01'); DELETE FROM rooms; -- You can't update a finite fk partially covered by one row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', '2015-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, '2015-06-01'); DELETE FROM rooms; -- You can't update a finite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', '2016-06-01'); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, '2016-06-01'); DELETE FROM rooms; -- You can update an infinite fk exactly covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2015-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2015-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk more than covered by one row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2016-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2016-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk exactly covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can update an infinite fk more than covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2014-06-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2014-06-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can't update an infinite fk id not covered by any row -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); UPDATE rooms SET house_id = 7; DELETE FROM rooms; -- You can't update an infinite fk range not covered by any row -INSERT INTO rooms VALUES (1, 1, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('2020-01-01', null); +INSERT INTO rooms VALUES (1, 1, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('2020-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; -- You can't update an infinite fk partially covered by one row -INSERT INTO rooms VALUES (1, 4, tstzrange(null, '2012-01-01')); -UPDATE rooms SET valid_at = tstzrange(null, '2020-01-01'); +INSERT INTO rooms VALUES (1, 4, '-infinity', '2012-01-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('-infinity', '2020-01-01'); DELETE FROM rooms; -- You can't update an infinite fk partially covered by two rows -INSERT INTO rooms VALUES (1, 3, tstzrange('2015-01-01', '2015-02-01')); -UPDATE rooms SET valid_at = tstzrange('1990-01-01', null); +INSERT INTO rooms VALUES (1, 3, '2015-01-01'::TIMESTAMPTZ, '2015-02-01'::TIMESTAMPTZ); +UPDATE rooms SET (valid_from, valid_to) = ('1990-01-01'::TIMESTAMPTZ, 'infinity'); DELETE FROM rooms; DELETE FROM rooms; DELETE FROM houses; -SELECT drop_temporal_foreign_key('room_has_a_house', 'rooms', 'houses'); +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); diff --git a/sql/28_with_exclusion_constraints.sql b/sql/28_with_exclusion_constraints.sql index 06a24d8..3ed98c9 100644 --- a/sql/28_with_exclusion_constraints.sql +++ b/sql/28_with_exclusion_constraints.sql @@ -1,6 +1,6 @@ -- MOVING THE TIME OF A CHANGE -SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'valid_at', 'houses', 'id', 'valid_at'); +SELECT enable_sql_saga_for_shifts_houses_and_rooms(); -- 1. Small shift to a later time @@ -13,20 +13,20 @@ SELECT create_temporal_foreign_key('room_has_a_house', 'rooms', 'house_id', 'val DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; UPDATE houses -SET valid_at = +SET (valid_from, valid_to) = CASE - WHEN lower(valid_at) = '2015-01-01' THEN tstzrange('2015-01-01', '2016-06-01') - WHEN lower(valid_at) = '2016-01-01' THEN tstzrange('2016-06-01', '2017-01-01') + WHEN valid_from = '2015-01-01' THEN ('2015-01-01', '2016-06-01') + WHEN valid_from = '2016-01-01' THEN ('2016-06-01', '2017-01-01') ELSE NULL -- Can't RAISE here but NULL will cause it to fail. END WHERE id = 1 @@ -42,61 +42,62 @@ DELETE FROM rooms; DELETE FROM houses; INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1,'2015-01-01', '2017-01-01') ; --- +-- -- 1.2.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; --- +-- -- 1.2.2. When the exclusion constraint is checked immediately, -- you can't move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; COMMIT; --- +-- -- 1.2.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id DEFERRED; +\d houses +SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; COMMIT; @@ -109,62 +110,62 @@ COMMIT; DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 1.3.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; --- +-- -- 1.3.2. When the exclusion constraint is checked immediately, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2016-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; --- +-- -- 1.3.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id DEFERRED; +SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; UPDATE houses -SET valid_at = tstzrange('2016-09-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-06-01' +SET (valid_from, valid_to) = ('2016-09-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-06-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2016-09-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2016-09-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; @@ -173,20 +174,20 @@ COMMIT; DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; UPDATE houses -SET valid_at = +SET (valid_from, valid_to) = CASE - WHEN lower(valid_at) = '2015-01-01' THEN tstzrange('2015-01-01', '2015-06-01') - WHEN lower(valid_at) = '2016-01-01' THEN tstzrange('2015-06-01', '2017-01-01') + WHEN valid_from = '2015-01-01' THEN ('2015-01-01', '2015-06-01') + WHEN valid_from = '2016-01-01' THEN ('2015-06-01', '2017-01-01') ELSE NULL -- Can't RAISE here but NULL will cause it to fail. END WHERE id = 1 @@ -196,62 +197,62 @@ WHERE id = 1 DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 2.2.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; --- +-- -- 2.2.2. When the exclusion constraint is checked immediately, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; COMMIT; --- +-- -- 2.2.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id DEFERRED; +SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-03-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-03-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-03-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2015-06-01' +SET (valid_from, valid_to) = ('2015-03-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2015-06-01' ; COMMIT; @@ -259,62 +260,62 @@ COMMIT; DELETE FROM rooms; DELETE FROM houses; -INSERT INTO houses VALUES - (1, 150000, tstzrange('2015-01-01', '2016-01-01')), - (1, 200000, tstzrange('2016-01-01', '2017-01-01')) +INSERT INTO houses VALUES + (1, 150000, '2015-01-01', '2016-01-01'), + (1, 200000, '2016-01-01', '2017-01-01') ; INSERT INTO rooms VALUES - (1, 1, tstzrange('2015-01-01', '2017-01-01')) + (1, 1, '2015-01-01', '2017-01-01') ; --- +-- -- 2.3.1. You can't move the time in two transactions. --- +-- UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; --- +-- -- 2.3.2. When the exclusion constraint is checked immediately, -- you can't move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id IMMEDIATE; +SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; --- +-- -- 2.3.3. When the exclusion constraint is checked deferred, -- you can move the time in one transaction with two statements. --- +-- BEGIN; -SET CONSTRAINTS tpk_houses_id DEFERRED; +SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; UPDATE houses -SET valid_at = tstzrange('2015-06-01', '2017-01-01') -WHERE id = 1 AND lower(valid_at) = '2016-01-01' +SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') +WHERE id = 1 AND valid_from = '2016-01-01' ; UPDATE houses -SET valid_at = tstzrange('2015-01-01', '2015-06-01') -WHERE id = 1 AND lower(valid_at) = '2015-01-01' +SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') +WHERE id = 1 AND valid_from = '2015-01-01' ; COMMIT; @@ -335,3 +336,5 @@ COMMIT; -- TODO -- 5.2. Swap the ranges, later first: -- TODO + +SELECT disable_sql_saga_for_shifts_houses_and_rooms(); \ No newline at end of file diff --git a/sql_saga--1.0.sql b/sql_saga--1.0.sql index cd58aa2..5f5f694 100644 --- a/sql_saga--1.0.sql +++ b/sql_saga--1.0.sql @@ -38,7 +38,8 @@ CREATE TABLE sql_saga.era ( PRIMARY KEY (table_name, era_name), - CHECK (start_column_name <> end_column_name) + CHECK (start_column_name <> end_column_name), + CHECK (era_name <> 'system_time') ); COMMENT ON TABLE sql_saga.era IS 'The main catalog for sql_saga. All "DDL" operations for periods must first take an exclusive lock on this table.'; GRANT SELECT ON TABLE sql_saga.era TO PUBLIC; @@ -118,6 +119,32 @@ CREATE TABLE sql_saga.api_view ( GRANT SELECT ON TABLE sql_saga.api_view TO PUBLIC; SELECT pg_catalog.pg_extension_config_dump('sql_saga.api_view', ''); +/* + * C Helper functions + */ +CREATE OR REPLACE FUNCTION sql_saga.completely_covers_transfn(internal, tstzrange, tstzrange) +RETURNS internal +AS 'sql_saga', 'completely_covers_transfn' +LANGUAGE c; + +CREATE OR REPLACE FUNCTION sql_saga.completely_covers_finalfn(internal, tstzrange, tstzrange) +RETURNS boolean +AS 'sql_saga', 'completely_covers_finalfn' +LANGUAGE c; + +/* + * completely_covers(period tstzrange, target tstzrange) - + * Returns true if the fixed arg `target` + * is completely covered by the sum of the `period` values. + */ +CREATE AGGREGATE sql_saga.completely_covers(tstzrange, tstzrange) ( + sfunc = sql_saga.completely_covers_transfn, + stype = internal, + finalfunc = sql_saga.completely_covers_finalfn, + finalfunc_extra +); + + /* * These function starting with "_" are private to the periods extension and @@ -241,7 +268,7 @@ BEGIN END IF; IF era_name IS NULL THEN - RAISE EXCEPTION 'no period name specified'; + RAISE EXCEPTION 'no era name specified'; END IF; /* Always serialize operations on our catalogs */ @@ -320,7 +347,7 @@ BEGIN END IF; IF start_attnum < 0 THEN - RAISE EXCEPTION 'system columns cannot be used in periods'; + RAISE EXCEPTION 'system columns cannot be used in an era'; END IF; /* Get end column information */ @@ -334,7 +361,7 @@ BEGIN END IF; IF end_attnum < 0 THEN - RAISE EXCEPTION 'system columns cannot be used in periods'; + RAISE EXCEPTION 'system columns cannot be used in an era'; END IF; /* @@ -543,7 +570,7 @@ AS $function$ #variable_conflict use_variable DECLARE - period_row sql_saga.era; + era_row sql_saga.era; portion_view regclass; is_dropped boolean; BEGIN @@ -552,7 +579,7 @@ BEGIN END IF; IF era_name IS NULL THEN - RAISE EXCEPTION 'no period name specified'; + RAISE EXCEPTION 'no era name specified'; END IF; /* Always serialize operations on our catalogs */ @@ -566,12 +593,12 @@ BEGIN is_dropped := NOT EXISTS (SELECT FROM pg_catalog.pg_class AS c WHERE c.oid = table_name); SELECT p.* - INTO period_row + INTO era_row FROM sql_saga.era AS p WHERE (p.table_name, p.era_name) = (table_name, era_name); IF NOT FOUND THEN - RAISE NOTICE 'period % not found on table %', era_name, table_name; + RAISE NOTICE 'era % not found for table %', era_name, table_name; RETURN false; END IF; @@ -581,13 +608,13 @@ BEGIN /* If this is a system_time period, get rid of the triggers */ -- DELETE FROM sql_saga.system_time_periods AS stp -- WHERE stp.table_name = table_name - -- RETURNING stp.* INTO system_time_period_row; + -- RETURNING stp.* INTO system_time_era_row; -- -- IF FOUND AND NOT is_dropped THEN - -- EXECUTE format('ALTER TABLE %s DROP CONSTRAINT %I', table_name, system_time_period_row.infinity_check_constraint); - -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_period_row.generated_always_trigger, table_name); - -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_period_row.write_history_trigger, table_name); - -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_period_row.truncate_trigger, table_name); + -- EXECUTE format('ALTER TABLE %s DROP CONSTRAINT %I', table_name, system_time_era_row.infinity_check_constraint); + -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_era_row.generated_always_trigger, table_name); + -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_era_row.write_history_trigger, table_name); + -- EXECUTE format('DROP TRIGGER %I ON %s', system_time_era_row.truncate_trigger, table_name); -- END IF; IF drop_behavior = 'RESTRICT' THEN @@ -596,7 +623,7 @@ BEGIN SELECT FROM sql_saga.unique_keys AS uk WHERE (uk.table_name, uk.era_name) = (table_name, era_name)) THEN - RAISE EXCEPTION 'period % is part of a UNIQUE or PRIMARY KEY', era_name; + RAISE EXCEPTION 'era % is part of a UNIQUE or PRIMARY KEY', era_name; END IF; /* Check for FOREIGN KEYs */ @@ -604,7 +631,7 @@ BEGIN SELECT FROM sql_saga.foreign_keys AS fk WHERE (fk.table_name, fk.era_name) = (table_name, era_name)) THEN - RAISE EXCEPTION 'period % is part of a FOREIGN KEY', era_name; + RAISE EXCEPTION 'era % is part of a FOREIGN KEY', era_name; END IF; -- /* Check for SYSTEM VERSIONING */ @@ -618,7 +645,7 @@ BEGIN /* Delete bounds check constraint if purging */ IF NOT is_dropped AND purge THEN EXECUTE format('ALTER TABLE %s DROP CONSTRAINT %I', - table_name, period_row.bounds_check_constraint); + table_name, era_row.bounds_check_constraint); END IF; /* Remove from catalog */ @@ -641,7 +668,7 @@ BEGIN /* Delete bounds check constraint if purging */ IF NOT is_dropped AND purge THEN EXECUTE format('ALTER TABLE %s DROP CONSTRAINT %I', - table_name, period_row.bounds_check_constraint); + table_name, era_row.bounds_check_constraint); END IF; /* Remove from catalog */ @@ -743,7 +770,7 @@ BEGIN * If no table is specified but a period is, that doesn't make any sense. */ IF table_name IS NULL AND era_name IS NOT NULL THEN - RAISE EXCEPTION 'cannot specify period name without table name'; + RAISE EXCEPTION 'cannot specify era name without table name'; END IF; /* Always serialize operations on our catalogs */ @@ -811,7 +838,7 @@ BEGIN * If no table is specified but a period is, that doesn't make any sense. */ IF table_name IS NULL AND era_name IS NOT NULL THEN - RAISE EXCEPTION 'cannot specify period name without table name'; + RAISE EXCEPTION 'cannot specify era name without table name'; END IF; /* Always serialize operations on our catalogs */ @@ -928,14 +955,14 @@ BEGIN WHERE fpv.view_name = TG_RELID; IF NOT FOUND THEN - RAISE EXCEPTION 'table and period information not found for view "%"', TG_RELID::regclass; + RAISE EXCEPTION 'table and era information not found for view "%"', TG_RELID::regclass; END IF; - jnew := row_to_json(NEW); + jnew := to_jsonb(NEW); fromval := jnew->info.start_column_name; toval := jnew->info.end_column_name; - jold := row_to_json(OLD); + jold := to_jsonb(OLD); bstartval := jold->info.start_column_name; bendval := jold->info.end_column_name; @@ -1070,9 +1097,9 @@ AS $function$ #variable_conflict use_variable DECLARE - period_row sql_saga.era; + era_row sql_saga.era; column_attnums smallint[]; - period_attnums smallint[]; + era_attnums smallint[]; idx integer; constraint_record record; pass integer; @@ -1091,7 +1118,7 @@ BEGIN PERFORM sql_saga._serialize(table_name); SELECT p.* - INTO period_row + INTO era_row FROM sql_saga.era AS p WHERE (p.table_name, p.era_name) = (table_name, era_name); @@ -1100,9 +1127,9 @@ BEGIN END IF; /* For convenience, put the period's attnums in an array */ - period_attnums := ARRAY[ - (SELECT a.attnum FROM pg_catalog.pg_attribute AS a WHERE (a.attrelid, a.attname) = (period_row.table_name, period_row.start_column_name)), - (SELECT a.attnum FROM pg_catalog.pg_attribute AS a WHERE (a.attrelid, a.attname) = (period_row.table_name, period_row.end_column_name)) + era_attnums := ARRAY[ + (SELECT a.attnum FROM pg_catalog.pg_attribute AS a WHERE (a.attrelid, a.attname) = (era_row.table_name, era_row.start_column_name)), + (SELECT a.attnum FROM pg_catalog.pg_attribute AS a WHERE (a.attrelid, a.attname) = (era_row.table_name, era_row.end_column_name)) ]; /* Get attnums from column names */ @@ -1123,11 +1150,11 @@ BEGIN END IF; /* Make sure the period columns aren't also in the normal columns */ - IF period_row.start_column_name = ANY (column_names) THEN - RAISE EXCEPTION 'column "%" specified twice', period_row.start_column_name; + IF era_row.start_column_name = ANY (column_names) THEN + RAISE EXCEPTION 'column "%" specified twice', era_row.start_column_name; END IF; - IF period_row.end_column_name = ANY (column_names) THEN - RAISE EXCEPTION 'column "%" specified twice', period_row.end_column_name; + IF era_row.end_column_name = ANY (column_names) THEN + RAISE EXCEPTION 'column "%" specified twice', era_row.end_column_name; END IF; /* @@ -1136,19 +1163,19 @@ BEGIN */ IF EXISTS ( SELECT FROM sql_saga.era AS p - WHERE (p.table_name, p.era_name) = (period_row.table_name, 'system_time') + WHERE (p.table_name, p.era_name) = (era_row.table_name, 'system_time') AND ARRAY[p.start_column_name, p.end_column_name] && column_names) THEN - RAISE EXCEPTION 'columns in period for SYSTEM_TIME are not allowed in UNIQUE keys'; + RAISE EXCEPTION 'columns in era for SYSTEM_TIME are not allowed in UNIQUE keys'; END IF; /* If we were given a unique constraint to use, look it up and make sure it matches */ SELECT format('UNIQUE (%s)', string_agg(quote_ident(u.column_name), ', ' ORDER BY u.ordinality)) INTO unique_sql - FROM unnest(column_names || period_row.start_column_name || period_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); + FROM unnest(column_names || era_row.start_column_name || era_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); IF unique_constraint IS NOT NULL THEN - SELECT c.oid, c.contype, c.condeferrable, c.conkey + SELECT c.oid, c.contype, c.condeferrable, c.condeferred, c.conkey INTO constraint_record FROM pg_catalog.pg_constraint AS c WHERE (c.conrelid, c.conname) = (table_name, unique_constraint); @@ -1161,12 +1188,21 @@ BEGIN RAISE EXCEPTION 'constraint "%" is not a PRIMARY KEY or UNIQUE KEY', unique_constraint; END IF; - IF constraint_record.condeferrable THEN - /* SQL:2016 11.8 SR 5 */ - RAISE EXCEPTION 'constraint "%" must not be DEFERRABLE', unique_constraint; + IF NOT constraint_record.condeferrable THEN + /* For restore purposes, constraints may be deferred, + * but everything must be valid at the end fo the transaction + */ + RAISE EXCEPTION 'constraint "%" must be DEFERRABLE', unique_constraint; + END IF; + + IF constraint_record.condeferred THEN + /* By default constraints are NOT deferred, + * and the user receives a timely validation error. + */ + RAISE EXCEPTION 'constraint "%" must be INITIALLY IMMEDIATE', unique_constraint; END IF; - IF NOT constraint_record.conkey = column_attnums || period_attnums THEN + IF NOT constraint_record.conkey = column_attnums || era_attnums THEN RAISE EXCEPTION 'constraint "%" does not match', unique_constraint; END IF; @@ -1190,13 +1226,13 @@ BEGIN FROM unnest(column_names) WITH ORDINALITY AS n (column_name, ordinality); withs := withs || format('%I(%I, %I, ''[)''::text) WITH &&', - period_row.range_type, period_row.start_column_name, period_row.end_column_name); + era_row.range_type, era_row.start_column_name, era_row.end_column_name); - exclude_sql := format('EXCLUDE USING gist (%s)', array_to_string(withs, ', ')); + exclude_sql := format('EXCLUDE USING gist (%s) DEFERRABLE', array_to_string(withs, ', ')); END; IF exclude_constraint IS NOT NULL THEN - SELECT c.oid, c.contype, c.condeferrable, pg_catalog.pg_get_constraintdef(c.oid) AS definition + SELECT c.oid, c.contype, c.condeferrable, c.condeferred, pg_catalog.pg_get_constraintdef(c.oid) AS definition INTO constraint_record FROM pg_catalog.pg_constraint AS c WHERE (c.conrelid, c.conname) = (table_name, exclude_constraint); @@ -1209,9 +1245,18 @@ BEGIN RAISE EXCEPTION 'constraint "%" is not an EXCLUDE constraint', exclude_constraint; END IF; - IF constraint_record.condeferrable THEN - /* SQL:2016 11.8 SR 5 */ - RAISE EXCEPTION 'constraint "%" must not be DEFERRABLE', exclude_constraint; + IF NOT constraint_record.condeferrable THEN + /* For restore purposes, constraints may be deferred, + * but everything must be valid at the end fo the transaction + */ + RAISE EXCEPTION 'constraint "%" must be DEFERRABLE', exclude_constraint; + END IF; + + IF constraint_record.condeferred THEN + /* By default constraints are NOT deferred, + * and the user receives a timely validation error. + */ + RAISE EXCEPTION 'constraint "%" must be INITIALLY IMMEDIATE', exclude_constraint; END IF; IF constraint_record.definition <> exclude_sql THEN @@ -1287,7 +1332,12 @@ BEGIN END; $function$; -CREATE FUNCTION sql_saga.drop_unique_key(table_name regclass, key_name name, drop_behavior sql_saga.drop_behavior DEFAULT 'RESTRICT', purge boolean DEFAULT false) +CREATE FUNCTION sql_saga.drop_unique_key( + table_name regclass, + key_name name, + drop_behavior sql_saga.drop_behavior DEFAULT 'RESTRICT', + purge boolean DEFAULT false + ) RETURNS void LANGUAGE plpgsql SECURITY DEFINER @@ -1337,6 +1387,7 @@ BEGIN unique_key_row.table_name, unique_key_row.unique_constraint, unique_key_row.exclude_constraint); END IF; END LOOP; + END; $function$; @@ -1362,7 +1413,7 @@ BEGIN */ /* Use jsonb to look up values by parameterized names */ - jold := row_to_json(OLD); + jold := to_jsonb(OLD); /* Check the constraint */ PERFORM sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, true); @@ -1392,7 +1443,7 @@ BEGIN */ /* Use jsonb to look up values by parameterized names */ - jold := row_to_json(OLD); + jold := to_jsonb(OLD); /* Check the constraint */ PERFORM sql_saga.validate_foreign_key_old_row(TG_ARGV[0], jold, false); @@ -1425,8 +1476,8 @@ AS $function$ #variable_conflict use_variable DECLARE - period_row sql_saga.era; - ref_period_row sql_saga.era; + era_row sql_saga.era; + ref_era_row sql_saga.era; unique_row sql_saga.unique_keys; column_attnums smallint[]; idx integer; @@ -1445,7 +1496,7 @@ BEGIN /* Get the period involved */ SELECT p.* - INTO period_row + INTO era_row FROM sql_saga.era AS p WHERE (p.table_name, p.era_name) = (table_name, era_name); @@ -1471,11 +1522,11 @@ BEGIN END IF; /* Make sure the period columns aren't also in the normal columns */ - IF period_row.start_column_name = ANY (column_names) THEN - RAISE EXCEPTION 'column "%" specified twice', period_row.start_column_name; + IF era_row.start_column_name = ANY (column_names) THEN + RAISE EXCEPTION 'column "%" specified twice', era_row.start_column_name; END IF; - IF period_row.end_column_name = ANY (column_names) THEN - RAISE EXCEPTION 'column "%" specified twice', period_row.end_column_name; + IF era_row.end_column_name = ANY (column_names) THEN + RAISE EXCEPTION 'column "%" specified twice', era_row.end_column_name; END IF; /* Get the unique key we're linking to */ @@ -1490,13 +1541,13 @@ BEGIN /* Get the unique key's period */ SELECT p.* - INTO ref_period_row + INTO ref_era_row FROM sql_saga.era AS p WHERE (p.table_name, p.era_name) = (unique_row.table_name, unique_row.era_name); - IF period_row.range_type <> ref_period_row.range_type THEN + IF era_row.range_type <> ref_era_row.range_type THEN RAISE EXCEPTION 'period types "%" and "%" are incompatible', - period_row.era_name, ref_period_row.era_name; + era_row.era_name, ref_era_row.era_name; END IF; /* Check that all the columns match */ @@ -1510,7 +1561,7 @@ BEGIN END IF; /* The range types must match, too */ - IF period_row.range_type <> ref_period_row.range_type THEN + IF era_row.range_type <> ref_era_row.range_type THEN RAISE EXCEPTION 'period types do not match'; END IF; @@ -1544,11 +1595,11 @@ BEGIN /* Get the columns that require checking the constraint */ SELECT string_agg(quote_ident(u.column_name), ', ' ORDER BY u.ordinality) INTO foreign_columns - FROM unnest(column_names || period_row.start_column_name || period_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); + FROM unnest(column_names || era_row.start_column_name || era_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); SELECT string_agg(quote_ident(u.column_name), ', ' ORDER BY u.ordinality) INTO unique_columns - FROM unnest(unique_row.column_names || ref_period_row.start_column_name || ref_period_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); + FROM unnest(unique_row.column_names || ref_era_row.start_column_name || ref_era_row.end_column_name) WITH ORDINALITY AS u (column_name, ordinality); /* Time to make the underlying triggers */ fk_insert_trigger := coalesce(fk_insert_trigger, sql_saga._make_name(ARRAY[key_name], 'fk_insert')); @@ -1569,8 +1620,9 @@ BEGIN VALUES (key_name, table_name, column_names, era_name, unique_row.key_name, match_type, update_action, delete_action, fk_insert_trigger, fk_update_trigger, uk_update_trigger, uk_delete_trigger); - /* Validate the constraint on existing data */ - PERFORM sql_saga.validate_foreign_key_new_row(key_name, NULL); + /* Validate the constraint on existing data, iterating over each row. */ + EXECUTE format('SELECT sql_saga.validate_foreign_key_new_row(%1$L, to_jsonb(%2$I.*)) FROM %2$I;', + key_name, table_name); RETURN key_name; END; @@ -1669,7 +1721,7 @@ BEGIN */ /* Use jsonb to look up values by parameterized names */ - jnew := row_to_json(NEW); + jnew := to_jsonb(NEW); /* Check the constraint */ PERFORM sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew); @@ -1696,7 +1748,7 @@ BEGIN */ /* Use jsonb to look up values by parameterized names */ - jnew := row_to_json(NEW); + jnew := to_jsonb(NEW); /* Check the constraint */ PERFORM sql_saga.validate_foreign_key_new_row(TG_ARGV[0], jnew); @@ -1969,75 +2021,79 @@ BEGIN RAISE EXCEPTION 'foreign key "%" not found', foreign_key_name; END IF; + IF row_data IS NULL THEN + RAISE EXCEPTION 'row_data is not provided'; + END IF; + /* * Now that we have all of our names, we can see if there are any nulls in - * the row we were given (if we were given one). + * the row we were given. */ - IF row_data IS NOT NULL THEN - DECLARE - column_name name; - has_nulls boolean; - all_nulls boolean; - cols text[] DEFAULT '{}'; - vals text[] DEFAULT '{}'; - BEGIN - FOREACH column_name IN ARRAY foreign_key_info.fk_column_names LOOP - has_nulls := has_nulls OR row_data->>column_name IS NULL; - all_nulls := all_nulls IS NOT false AND row_data->>column_name IS NULL; - cols := cols || ('fk.' || quote_ident(column_name)); - vals := vals || quote_literal(row_data->>column_name); - END LOOP; - - IF all_nulls THEN - /* - * If there are no values at all, all three types pass. - * - * Period columns are by definition NOT NULL so the FULL MATCH - * type is only concerned with the non-period columns of the - * constraint. SQL:2016 4.23.3.3 - */ - RETURN true; - END IF; + DECLARE + column_name name; + has_nulls boolean; + all_nulls boolean; + cols text[] DEFAULT '{}'; + vals text[] DEFAULT '{}'; + BEGIN + FOREACH column_name IN ARRAY foreign_key_info.fk_column_names LOOP + has_nulls := has_nulls OR row_data->>column_name IS NULL; + all_nulls := all_nulls IS NOT false AND row_data->>column_name IS NULL; + cols := cols || ('fk.' || quote_ident(column_name)); + vals := vals || quote_literal(row_data->>column_name); + END LOOP; - IF has_nulls THEN - CASE foreign_key_info.match_type - WHEN 'SIMPLE' THEN - RETURN true; - WHEN 'PARTIAL' THEN - RAISE EXCEPTION 'partial not implemented'; - WHEN 'FULL' THEN - RAISE EXCEPTION 'foreign key violated (nulls in FULL)'; - END CASE; - END IF; + IF all_nulls THEN + /* + * If there are no values at all, all three types pass. + * + * Period columns are by definition NOT NULL so the FULL MATCH + * type is only concerned with the non-period columns of the + * constraint. SQL:2016 4.23.3.3 + */ + RETURN true; + END IF; - row_clause := format(' (%s) = (%s)', array_to_string(cols, ', '), array_to_string(vals, ', ')); - END; - END IF; - - EXECUTE format(QSQL, foreign_key_info.uk_schema_name, - foreign_key_info.uk_table_name, - foreign_key_info.uk_start_column_name, - foreign_key_info.uk_end_column_name, - foreign_key_info.fk_schema_name, - foreign_key_info.fk_table_name, - foreign_key_info.fk_start_column_name, - foreign_key_info.fk_end_column_name, - (SELECT string_agg(format('%I = %I', ukc, fkc), ' AND ') - FROM unnest(foreign_key_info.uk_column_names, - foreign_key_info.fk_column_names) AS u (ukc, fkc) - ), - row_clause) - INTO violation; + IF has_nulls THEN + CASE foreign_key_info.match_type + WHEN 'SIMPLE' THEN + RETURN true; + WHEN 'PARTIAL' THEN + RAISE EXCEPTION 'partial not implemented'; + WHEN 'FULL' THEN + RAISE EXCEPTION 'foreign key violated (nulls in FULL)'; + END CASE; + END IF; - IF violation THEN - IF row_data IS NULL THEN - RAISE EXCEPTION 'foreign key violated by some row'; - ELSE - RAISE EXCEPTION 'insert or update on table "%" violates foreign key constraint "%"', - foreign_key_info.fk_table_oid::regclass, - foreign_key_name; + row_clause := format(' (%s) = (%s)', array_to_string(cols, ', '), array_to_string(vals, ', ')); + END; + + BEGIN + EXECUTE format(QSQL, foreign_key_info.uk_schema_name, + foreign_key_info.uk_table_name, + foreign_key_info.uk_start_column_name, + foreign_key_info.uk_end_column_name, + foreign_key_info.fk_schema_name, + foreign_key_info.fk_table_name, + foreign_key_info.fk_start_column_name, + foreign_key_info.fk_end_column_name, + (SELECT string_agg(format('%I IS NOT DISTINCT FROM %I', ukc, fkc), ' AND ') + FROM unnest(foreign_key_info.uk_column_names, + foreign_key_info.fk_column_names) AS u (ukc, fkc) + ), + row_clause) + INTO violation; + + IF violation THEN + IF row_data IS NULL THEN + RAISE EXCEPTION 'foreign key violated by some row'; + ELSE + RAISE EXCEPTION 'insert or update on table "%" violates foreign key constraint "%"', + foreign_key_info.fk_table_oid::regclass, + foreign_key_name; + END IF; END IF; - END IF; + END; RETURN true; END; @@ -2066,7 +2122,7 @@ $function$; -- table_owner regrole; -- persistence "char"; -- kind "char"; --- period_row sql_saga.era; +-- era_row sql_saga.era; -- history_table_id oid; -- sql text; -- grantees text; @@ -2122,7 +2178,7 @@ $function$; -- -- /* We need a SYSTEM_TIME period. SQL:2016 11.29 SR 4 */ -- SELECT p.* --- INTO period_row +-- INTO era_row -- FROM sql_saga.era AS p -- WHERE (p.table_name, p.era_name) = (table_class, 'system_time'); -- @@ -2244,7 +2300,7 @@ $function$; -- LANGUAGE sql -- STABLE -- AS 'SELECT * FROM %1$I.%3$I WHERE %4$I <= $1 AND %5$I > $1' --- $$, schema_name, function_as_of_name, view_name, period_row.start_column_name, period_row.end_column_name); +-- $$, schema_name, function_as_of_name, view_name, era_row.start_column_name, era_row.end_column_name); -- EXECUTE format('ALTER FUNCTION %1$I.%2$I(timestamp with time zone) OWNER TO %3$I', -- schema_name, function_as_of_name, table_owner); -- @@ -2255,7 +2311,7 @@ $function$; -- LANGUAGE sql -- STABLE -- AS 'SELECT * FROM %1$I.%3$I WHERE $1 <= $2 AND %5$I > $1 AND %4$I <= $2' --- $$, schema_name, function_between_name, view_name, period_row.start_column_name, period_row.end_column_name); +-- $$, schema_name, function_between_name, view_name, era_row.start_column_name, era_row.end_column_name); -- EXECUTE format('ALTER FUNCTION %1$I.%2$I(timestamp with time zone, timestamp with time zone) OWNER TO %3$I', -- schema_name, function_between_name, table_owner); -- @@ -2266,7 +2322,7 @@ $function$; -- LANGUAGE sql -- STABLE -- AS 'SELECT * FROM %1$I.%3$I WHERE %5$I > least($1, $2) AND %4$I <= greatest($1, $2)' --- $$, schema_name, function_between_symmetric_name, view_name, period_row.start_column_name, period_row.end_column_name); +-- $$, schema_name, function_between_symmetric_name, view_name, era_row.start_column_name, era_row.end_column_name); -- EXECUTE format('ALTER FUNCTION %1$I.%2$I(timestamp with time zone, timestamp with time zone) OWNER TO %3$I', -- schema_name, function_between_symmetric_name, table_owner); -- @@ -2277,7 +2333,7 @@ $function$; -- LANGUAGE sql -- STABLE -- AS 'SELECT * FROM %1$I.%3$I WHERE $1 < $2 AND %5$I > $1 AND %4$I < $2' --- $$, schema_name, function_from_to_name, view_name, period_row.start_column_name, period_row.end_column_name); +-- $$, schema_name, function_from_to_name, view_name, era_row.start_column_name, era_row.end_column_name); -- EXECUTE format('ALTER FUNCTION %1$I.%2$I(timestamp with time zone, timestamp with time zone) OWNER TO %3$I', -- schema_name, function_from_to_name, table_owner); -- @@ -2616,7 +2672,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop constraint "%" on table "%" because it is used in era unique key "%"', r.unique_constraint, r.table_name, r.key_name; END LOOP; @@ -2627,7 +2683,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop constraint "%" on table "%" because it is used in era unique key "%"', r.exclude_constraint, r.table_name, r.key_name; END LOOP; @@ -2643,7 +2699,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in era foreign key "%"', r.fk_insert_trigger, r.table_name, r.key_name; END LOOP; @@ -2654,7 +2710,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in era foreign key "%"', r.fk_update_trigger, r.table_name, r.key_name; END LOOP; @@ -2666,7 +2722,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in era foreign key "%"', r.uk_update_trigger, r.table_name, r.key_name; END LOOP; @@ -2678,7 +2734,7 @@ BEGIN 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 "%"', + RAISE EXCEPTION 'cannot drop trigger "%" on table "%" because it is used in era foreign key "%"', r.uk_delete_trigger, r.table_name, r.key_name; END LOOP; @@ -2999,7 +3055,7 @@ BEGIN JOIN pg_catalog.pg_class AS c ON c.oid = p.table_name WHERE c.relpersistence <> 'p' LOOP - RAISE EXCEPTION 'table "%" must remain persistent because it has periods', + RAISE EXCEPTION 'table "%" must remain persistent because it has an era', r.table_name; END LOOP; @@ -3010,7 +3066,7 @@ BEGIN JOIN pg_catalog.pg_class AS c ON c.oid = sv.audit_table_name WHERE c.relpersistence <> 'p' LOOP - RAISE EXCEPTION 'history table "%" must remain persistent because it has periods', + RAISE EXCEPTION 'history table "%" must remain persistent because it has an era', r.table_name; END LOOP; diff --git a/sql_saga.c b/sql_saga.c new file mode 100644 index 0000000..746983f --- /dev/null +++ b/sql_saga.c @@ -0,0 +1,41 @@ +/** + * sql_saga.c - + * TODO: + * Install a hook so we can get called with a table/column is dropped/renamed, + * so that we can drop/update our constraints as necessary. + */ + +#include +#include +#include +#include +#include + +/* +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +*/ + + +PG_MODULE_MAGIC; + +void _PG_init(void); +void _PG_fini(void); + +void _PG_init(void) { +} + +void _PG_fini(void) { +} + diff --git a/time_for_keys.c b/time_for_keys.c new file mode 100644 index 0000000..1868ed3 --- /dev/null +++ b/time_for_keys.c @@ -0,0 +1,40 @@ +/** + * time_for_keys.c - + * Installs a hook so we can get called with a table/column is dropped/renamed, + * so that we can drop/update our constraints as necessary. + */ + +#include +#include +#include +#include +#include + +/* +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +#include +*/ + + +PG_MODULE_MAGIC; + +void _PG_init(void); +void _PG_fini(void); + +void _PG_init(void) { +} + +void _PG_fini(void) { +} +