From 27b59c107c58b280c8c8b37aeddb59062895296b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?J=C3=B8rgen=20H=2E=20Fjeld?= Date: Wed, 15 Nov 2023 00:18:45 +0100 Subject: [PATCH] Add schema handling And an appropriate test. Also adjust deferrable logic, such that all feedback is immediate, unless explicitly deferred. --- expected/21_init.out | 4 +- .../23_create_temporal_foreign_key_test.out | 12 +- expected/28_with_exclusion_constraints.out | 6 + expected/41_with_schema_test.out | 261 ++++++++++++++++++ sql/28_with_exclusion_constraints.sql | 12 + sql/41_with_schema_test.sql | 98 +++++++ sql_saga--1.0.sql | 48 ++-- 7 files changed, 417 insertions(+), 24 deletions(-) create mode 100644 expected/41_with_schema_test.out create mode 100644 sql/41_with_schema_test.sql diff --git a/expected/21_init.out b/expected/21_init.out index cb71834..8434e21 100644 --- a/expected/21_init.out +++ b/expected/21_init.out @@ -143,8 +143,8 @@ Indexes: Check constraints: "houses_valid_check" CHECK (valid_from < valid_to) Triggers: - rooms_house_id_valid_uk_delete AFTER DELETE ON houses FROM rooms DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_delete_check('rooms_house_id_valid') - rooms_house_id_valid_uk_update AFTER UPDATE OF id, valid_from, valid_to ON houses FROM rooms DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_update_check('rooms_house_id_valid') + rooms_house_id_valid_uk_delete AFTER DELETE ON houses FROM rooms DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_delete_check('rooms_house_id_valid') + rooms_house_id_valid_uk_update AFTER UPDATE OF id, valid_from, valid_to ON houses FROM rooms DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_update_check('rooms_house_id_valid') \d shifts Table "public.shifts" diff --git a/expected/23_create_temporal_foreign_key_test.out b/expected/23_create_temporal_foreign_key_test.out index a2899e0..9350c78 100644 --- a/expected/23_create_temporal_foreign_key_test.out +++ b/expected/23_create_temporal_foreign_key_test.out @@ -65,8 +65,8 @@ INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 2, '2015-01-01'::T 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.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM public.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 165 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(); @@ -84,8 +84,8 @@ INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2010-01-01'::T 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.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM public.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 165 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(); @@ -103,8 +103,8 @@ INSERT INTO rooms(id,house_id,valid_from,valid_to) VALUES (1, 1, '2015-01-01'::T 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.validate_foreign_key_new_row('rooms_house_id_valid', to_jsonb(rooms.*)) FROM public.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 165 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(); diff --git a/expected/28_with_exclusion_constraints.out b/expected/28_with_exclusion_constraints.out index d67c6a0..ab1d6a0 100644 --- a/expected/28_with_exclusion_constraints.out +++ b/expected/28_with_exclusion_constraints.out @@ -88,6 +88,7 @@ COMMIT; -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -134,6 +135,7 @@ DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Thu Jan 01 -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-01-01' @@ -149,6 +151,7 @@ COMMIT; -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2016-09-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-06-01' @@ -215,6 +218,7 @@ DETAIL: Key (id, tstzrange(valid_from, valid_to, '[)'::text))=(1, ["Mon Jun 01 -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -230,6 +234,7 @@ COMMIT; -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2015-03-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -290,6 +295,7 @@ COMMIT; -- BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; UPDATE houses SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-01-01' diff --git a/expected/41_with_schema_test.out b/expected/41_with_schema_test.out new file mode 100644 index 0000000..8bdc513 --- /dev/null +++ b/expected/41_with_schema_test.out @@ -0,0 +1,261 @@ +-- Use a blank search path, so every table must +-- be prefixed with a schema +SELECT pg_catalog.set_config('search_path', '', false); + set_config +------------ + +(1 row) + + +CREATE EXTENSION sql_saga CASCADE; +ERROR: extension "sql_saga" already exists + +CREATE SCHEMA exposed; +CREATE SCHEMA hidden; + +CREATE TABLE exposed.employees ( + id INTEGER, + valid_from date, + valid_to date, + name varchar NOT NULL, + role varchar NOT NULL +); + +CREATE TABLE hidden.staff ( + id INTEGER, + valid_from date, + valid_to date, + salary FLOAT, + employee_id INTEGER +); + +-- Before using sql_saga +\d exposed.employees + Table "exposed.employees" + Column | Type | Collation | Nullable | Default +------------+-------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | | + valid_to | date | | | + name | character varying | | not null | + role | character varying | | not null | + +\d hidden.staff + Table "hidden.staff" + Column | Type | Collation | Nullable | Default +-------------+------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | | + valid_to | date | | | + salary | double precision | | | + employee_id | integer | | | + + +-- Verify that enable and disable each work correctly. +SELECT sql_saga.add_era('exposed.employees', 'valid_from', 'valid_to'); + add_era +--------- + t +(1 row) + +SELECT sql_saga.add_era('hidden.staff', '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 +-------------------+----------+-------------------+-----------------+------------+-------------------------+------------------ + exposed.employees | valid | valid_from | valid_to | daterange | employees_valid_check | + hidden.staff | valid | valid_from | valid_to | daterange | staff_valid_check | +(2 rows) + + +SELECT sql_saga.add_unique_key('exposed.employees', ARRAY['id'], 'valid'); + add_unique_key +-------------------- + employees_id_valid +(1 row) + +SELECT sql_saga.add_unique_key('hidden.staff', ARRAY['id'], 'valid'); + add_unique_key +---------------- + staff_id_valid +(1 row) + +TABLE sql_saga.unique_keys; + key_name | table_name | column_names | era_name | unique_constraint | exclude_constraint +--------------------+-------------------+--------------+----------+--------------------------------------+----------------------------- + employees_id_valid | exposed.employees | {id} | valid | employees_id_valid_from_valid_to_key | employees_id_daterange_excl + staff_id_valid | hidden.staff | {id} | valid | staff_id_valid_from_valid_to_key | staff_id_daterange_excl +(2 rows) + + +SELECT sql_saga.add_foreign_key('hidden.staff', ARRAY['employee_id'], 'valid', 'employees_id_valid'); + add_foreign_key +------------------------- + staff_employee_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 +-------------------------+--------------+---------------+----------+--------------------+------------+---------------+---------------+-----------------------------------+-----------------------------------+-----------------------------------+----------------------------------- + staff_employee_id_valid | hidden.staff | {employee_id} | valid | employees_id_valid | SIMPLE | NO ACTION | NO ACTION | staff_employee_id_valid_fk_insert | staff_employee_id_valid_fk_update | staff_employee_id_valid_uk_update | staff_employee_id_valid_uk_delete +(1 row) + + +-- While sql_saga is active +\d exposed.employees + Table "exposed.employees" + Column | Type | Collation | Nullable | Default +------------+-------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | not null | + valid_to | date | | not null | + name | character varying | | not null | + role | character varying | | not null | +Indexes: + "employees_id_daterange_excl" EXCLUDE USING gist (id WITH =, daterange(valid_from, valid_to, '[)'::text) WITH &&) DEFERRABLE + "employees_id_valid_from_valid_to_key" UNIQUE CONSTRAINT, btree (id, valid_from, valid_to) DEFERRABLE +Check constraints: + "employees_valid_check" CHECK (valid_from < valid_to) +Triggers: + staff_employee_id_valid_uk_delete AFTER DELETE ON exposed.employees FROM hidden.staff DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_delete_check('staff_employee_id_valid') + staff_employee_id_valid_uk_update AFTER UPDATE OF id, valid_from, valid_to ON exposed.employees FROM hidden.staff DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.uk_update_check('staff_employee_id_valid') + +\d hidden.staff + Table "hidden.staff" + Column | Type | Collation | Nullable | Default +-------------+------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | not null | + valid_to | date | | not null | + salary | double precision | | | + employee_id | integer | | | +Indexes: + "staff_id_daterange_excl" EXCLUDE USING gist (id WITH =, daterange(valid_from, valid_to, '[)'::text) WITH &&) DEFERRABLE + "staff_id_valid_from_valid_to_key" UNIQUE CONSTRAINT, btree (id, valid_from, valid_to) DEFERRABLE +Check constraints: + "staff_valid_check" CHECK (valid_from < valid_to) +Triggers: + staff_employee_id_valid_fk_insert AFTER INSERT ON hidden.staff FROM exposed.employees DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.fk_insert_check('staff_employee_id_valid') + staff_employee_id_valid_fk_update AFTER UPDATE OF employee_id, valid_from, valid_to ON hidden.staff FROM exposed.employees DEFERRABLE INITIALLY IMMEDIATE FOR EACH ROW EXECUTE FUNCTION sql_saga.fk_update_check('staff_employee_id_valid') + + +-- Test data. +INSERT INTO exposed.employees (id, valid_from, valid_to, name, role) VALUES +(101, '2022-01-01', '2022-06-30', 'Alice Johnson', 'Junior Manager'), +(101, '2022-07-01', '2023-12-31', 'Alice Johnson', 'Senior Manager'), +(102, '2022-01-01', '2022-08-31', 'Bob Smith', 'Junior Engineer'), +(102, '2022-09-01', '2023-12-31', 'Bob Smith', 'Senior Engineer'), +(103, '2022-01-01', '2022-12-31', 'Charlie Brown', 'Designer'), +(104, '2022-01-01', '2022-05-31', 'Diana Prince', 'Junior Analyst'), +(104, '2022-06-01', '2023-12-31', 'Diana Prince', 'Senior Analyst'); + +INSERT INTO hidden.staff (id, valid_from, valid_to, employee_id, salary) VALUES +(201, '2022-01-01', '2022-06-30',101 , 50000.00), +(201, '2022-08-01', '2023-12-31',101 , 60000.00), -- Salary increase in August, a month after role change in July +(202, '2022-01-01', '2022-08-31',102 , 55000.00), +(202, '2022-10-01', '2023-12-31',102 , 70000.00), -- Salary increase in October, a month after role change in September +(203, '2022-01-01', '2022-12-31',103 , 48000.00), +(204, '2022-01-01', '2022-05-31',104 , 45000.00), +(204, '2022-07-01', '2023-12-31',104 , 55000.00); -- Salary increase in July, a month after role change in June + + +-- Fail +DELETE FROM exposed.employees WHERE id = 101; +ERROR: update or delete on table "exposed.employees" violates foreign key constraint "staff_employee_id_valid" on table "hidden.staff" +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, false)" +PL/pgSQL function sql_saga.uk_delete_check() line 22 at PERFORM + +-- Success +DELETE FROM hidden.staff WHERE employee_id = 101; +DELETE FROM exposed.employees WHERE id = 101; + +-- Fail +UPDATE hidden.staff SET valid_to = 'infinity' WHERE employee_id = 103; +ERROR: insert or update on table "hidden.staff" violates foreign key constraint "staff_employee_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 + +-- Success +UPDATE exposed.employees SET valid_to = 'infinity' WHERE id = 103; +UPDATE hidden.staff SET valid_to = 'infinity' WHERE employee_id = 103; + +-- Teardown + +SELECT sql_saga.drop_foreign_key('hidden.staff', 'staff_employee_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) + + +SELECT sql_saga.drop_unique_key('exposed.employees', 'employees_id_valid'); + drop_unique_key +----------------- + +(1 row) + +SELECT sql_saga.drop_unique_key('hidden.staff','staff_id_valid'); + drop_unique_key +----------------- + +(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('exposed.employees'); + drop_era +---------- + t +(1 row) + +SELECT sql_saga.drop_era('hidden.staff'); + 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) + + +-- After removing sql_saga, it should be as before. +\d exposed.employees + Table "exposed.employees" + Column | Type | Collation | Nullable | Default +------------+-------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | not null | + valid_to | date | | not null | + name | character varying | | not null | + role | character varying | | not null | + +\d hidden.staff + Table "hidden.staff" + Column | Type | Collation | Nullable | Default +-------------+------------------+-----------+----------+--------- + id | integer | | | + valid_from | date | | not null | + valid_to | date | | not null | + salary | double precision | | | + employee_id | integer | | | + + +DROP EXTENSION sql_saga; +DROP EXTENSION btree_gist; diff --git a/sql/28_with_exclusion_constraints.sql b/sql/28_with_exclusion_constraints.sql index 11f3715..36da63e 100644 --- a/sql/28_with_exclusion_constraints.sql +++ b/sql/28_with_exclusion_constraints.sql @@ -92,6 +92,8 @@ COMMIT; BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2016-06-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -142,6 +144,8 @@ WHERE id = 1 AND valid_from = '2015-01-01' BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2016-06-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-01-01' @@ -160,6 +164,8 @@ COMMIT; BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2016-09-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-06-01' @@ -234,6 +240,8 @@ WHERE id = 1 AND valid_from = '2016-01-01' BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl IMMEDIATE; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2015-06-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -252,6 +260,8 @@ COMMIT; BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2015-01-01', '2015-03-01') WHERE id = 1 AND valid_from = '2015-01-01' @@ -315,6 +325,8 @@ COMMIT; BEGIN; SET CONSTRAINTS houses_id_tstzrange_excl DEFERRED; +SET CONSTRAINTS rooms_house_id_valid_uk_update DEFERRED; + UPDATE houses SET (valid_from, valid_to) = ('2015-06-01', '2017-01-01') WHERE id = 1 AND valid_from = '2016-01-01' diff --git a/sql/41_with_schema_test.sql b/sql/41_with_schema_test.sql new file mode 100644 index 0000000..c4a1d52 --- /dev/null +++ b/sql/41_with_schema_test.sql @@ -0,0 +1,98 @@ +-- Use a blank search path, so every table must +-- be prefixed with a schema +SELECT pg_catalog.set_config('search_path', '', false); + +CREATE EXTENSION sql_saga CASCADE; + +CREATE SCHEMA exposed; +CREATE SCHEMA hidden; + +CREATE TABLE exposed.employees ( + id INTEGER, + valid_from date, + valid_to date, + name varchar NOT NULL, + role varchar NOT NULL +); + +CREATE TABLE hidden.staff ( + id INTEGER, + valid_from date, + valid_to date, + salary FLOAT, + employee_id INTEGER +); + +-- Before using sql_saga +\d exposed.employees +\d hidden.staff + +-- Verify that enable and disable each work correctly. +SELECT sql_saga.add_era('exposed.employees', 'valid_from', 'valid_to'); +SELECT sql_saga.add_era('hidden.staff', 'valid_from', 'valid_to'); +TABLE sql_saga.era; + +SELECT sql_saga.add_unique_key('exposed.employees', ARRAY['id'], 'valid'); +SELECT sql_saga.add_unique_key('hidden.staff', ARRAY['id'], 'valid'); +TABLE sql_saga.unique_keys; + +SELECT sql_saga.add_foreign_key('hidden.staff', ARRAY['employee_id'], 'valid', 'employees_id_valid'); +TABLE sql_saga.foreign_keys; + +-- While sql_saga is active +\d exposed.employees +\d hidden.staff + +-- Test data. +INSERT INTO exposed.employees (id, valid_from, valid_to, name, role) VALUES +(101, '2022-01-01', '2022-06-30', 'Alice Johnson', 'Junior Manager'), +(101, '2022-07-01', '2023-12-31', 'Alice Johnson', 'Senior Manager'), +(102, '2022-01-01', '2022-08-31', 'Bob Smith', 'Junior Engineer'), +(102, '2022-09-01', '2023-12-31', 'Bob Smith', 'Senior Engineer'), +(103, '2022-01-01', '2022-12-31', 'Charlie Brown', 'Designer'), +(104, '2022-01-01', '2022-05-31', 'Diana Prince', 'Junior Analyst'), +(104, '2022-06-01', '2023-12-31', 'Diana Prince', 'Senior Analyst'); + +INSERT INTO hidden.staff (id, valid_from, valid_to, employee_id, salary) VALUES +(201, '2022-01-01', '2022-06-30',101 , 50000.00), +(201, '2022-08-01', '2023-12-31',101 , 60000.00), -- Salary increase in August, a month after role change in July +(202, '2022-01-01', '2022-08-31',102 , 55000.00), +(202, '2022-10-01', '2023-12-31',102 , 70000.00), -- Salary increase in October, a month after role change in September +(203, '2022-01-01', '2022-12-31',103 , 48000.00), +(204, '2022-01-01', '2022-05-31',104 , 45000.00), +(204, '2022-07-01', '2023-12-31',104 , 55000.00); -- Salary increase in July, a month after role change in June + + +-- Fail +DELETE FROM exposed.employees WHERE id = 101; + +-- Success +DELETE FROM hidden.staff WHERE employee_id = 101; +DELETE FROM exposed.employees WHERE id = 101; + +-- Fail +UPDATE hidden.staff SET valid_to = 'infinity' WHERE employee_id = 103; + +-- Success +UPDATE exposed.employees SET valid_to = 'infinity' WHERE id = 103; +UPDATE hidden.staff SET valid_to = 'infinity' WHERE employee_id = 103; + +-- Teardown + +SELECT sql_saga.drop_foreign_key('hidden.staff', 'staff_employee_id_valid'); +TABLE sql_saga.foreign_keys; + +SELECT sql_saga.drop_unique_key('exposed.employees', 'employees_id_valid'); +SELECT sql_saga.drop_unique_key('hidden.staff','staff_id_valid'); +TABLE sql_saga.unique_keys; + +SELECT sql_saga.drop_era('exposed.employees'); +SELECT sql_saga.drop_era('hidden.staff'); +TABLE sql_saga.era; + +-- After removing sql_saga, it should be as before. +\d exposed.employees +\d hidden.staff + +DROP EXTENSION sql_saga; +DROP EXTENSION btree_gist; \ No newline at end of file diff --git a/sql_saga--1.0.sql b/sql_saga--1.0.sql index 0c74411..c879217 100644 --- a/sql_saga--1.0.sql +++ b/sql_saga--1.0.sql @@ -1479,6 +1479,10 @@ DECLARE era_row sql_saga.era; ref_era_row sql_saga.era; unique_row sql_saga.unique_keys; + schema_name_str text; + table_name_str text; + unique_row_schema_name_str text; + unique_row_table_name_str text; column_attnums smallint[]; idx integer; pass integer; @@ -1494,6 +1498,11 @@ BEGIN /* Always serialize operations on our catalogs */ PERFORM sql_saga._serialize(table_name); + SELECT n.nspname, c.relname INTO schema_name_str, table_name_str + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = table_name; + /* Get the period involved */ SELECT p.* INTO era_row @@ -1550,6 +1559,11 @@ BEGIN era_row.era_name, ref_era_row.era_name; END IF; + SELECT n.nspname, c.relname INTO unique_row_schema_name_str, unique_row_table_name_str + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = unique_row.table_name; + /* Check that all the columns match */ IF EXISTS ( SELECT FROM unnest(column_names, unique_row.column_names) AS u (fk_attname, uk_attname) @@ -1584,13 +1598,15 @@ BEGIN END LOOP; key_name := key_name || CASE WHEN pass > 0 THEN '_' || pass::text ELSE '' END; + -- TODO: Consider how update_action should be handled, it seems + -- clear it should affect the timing of the trigger. /* See if we're deferring the constraints or not */ - IF update_action = 'NO ACTION' THEN - upd_action := ' DEFERRABLE INITIALLY DEFERRED'; - END IF; - IF delete_action = 'NO ACTION' THEN - del_action := ' DEFERRABLE INITIALLY DEFERRED'; - END IF; + -- IF update_action = 'NO ACTION' THEN + -- upd_action := ' DEFERRABLE INITIALLY DEFERRED'; + -- END IF; + -- IF delete_action = 'NO ACTION' THEN + -- del_action := ' DEFERRABLE INITIALLY DEFERRED'; + -- END IF; /* Get the columns that require checking the constraint */ SELECT string_agg(quote_ident(u.column_name), ', ' ORDER BY u.ordinality) @@ -1603,17 +1619,17 @@ BEGIN /* Time to make the underlying triggers */ fk_insert_trigger := coalesce(fk_insert_trigger, sql_saga._make_name(ARRAY[key_name], 'fk_insert')); - EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER INSERT ON %s FROM %s DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.fk_insert_check(%L)', - fk_insert_trigger, table_name, unique_row.table_name, key_name); + EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER INSERT ON %I.%I FROM %I.%I DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.fk_insert_check(%L)', + fk_insert_trigger, schema_name_str, table_name_str, unique_row_schema_name_str ,unique_row_table_name_str, key_name); fk_update_trigger := coalesce(fk_update_trigger, sql_saga._make_name(ARRAY[key_name], 'fk_update')); - EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER UPDATE OF %s ON %s FROM %s DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.fk_update_check(%L)', - fk_update_trigger, foreign_columns, table_name, unique_row.table_name, key_name); + EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER UPDATE OF ' || foreign_columns || ' ON %I.%I FROM %I.%I DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.fk_update_check(%L)', + fk_update_trigger, schema_name_str, table_name_str, unique_row_schema_name_str ,unique_row_table_name_str, key_name); uk_update_trigger := coalesce(uk_update_trigger, sql_saga._make_name(ARRAY[key_name], 'uk_update')); - EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER UPDATE OF %s ON %s FROM %s%s DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.uk_update_check(%L)', - uk_update_trigger, unique_columns, unique_row.table_name, table_name, upd_action, key_name); + EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER UPDATE OF ' || unique_columns || ' ON %I.%I FROM %I.%I DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.uk_update_check(%L)', + uk_update_trigger, unique_row_schema_name_str ,unique_row_table_name_str, schema_name_str, table_name_str, key_name); uk_delete_trigger := coalesce(uk_delete_trigger, sql_saga._make_name(ARRAY[key_name], 'uk_delete')); - EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER DELETE ON %s FROM %s%s DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.uk_delete_check(%L)', - uk_delete_trigger, unique_row.table_name, table_name, del_action, key_name); + EXECUTE format('CREATE CONSTRAINT TRIGGER %I AFTER DELETE ON %I.%I FROM %I.%I DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE sql_saga.uk_delete_check(%L)', + uk_delete_trigger, unique_row_schema_name_str ,unique_row_table_name_str, schema_name_str, table_name_str, key_name); INSERT INTO sql_saga.foreign_keys (key_name, table_name, column_names, era_name, unique_key, match_type, update_action, delete_action, fk_insert_trigger, fk_update_trigger, uk_update_trigger, uk_delete_trigger) @@ -1621,8 +1637,8 @@ BEGIN fk_insert_trigger, fk_update_trigger, uk_update_trigger, uk_delete_trigger); /* 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); + EXECUTE format('SELECT sql_saga.validate_foreign_key_new_row(%1$L, to_jsonb(%3$I.*)) FROM %2$I.%3$I;', + key_name, schema_name_str, table_name_str); RETURN key_name; END;