-
Notifications
You must be signed in to change notification settings - Fork 899
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Fix FK constraints for compressed chunks
When foreign key support for compressed chunks was added we moved the FK constraint from the uncompressed chunk to the compressed chunk as part of compress_chunk and moved it back as part of decompress_chunk. With the addition of partially compressed chunks in 2.10.x this approach was no longer sufficient and the FK constraint needs to be present on both the uncompressed and the compressed chunk. While this patch will fix future compressed chunks a migration has to be run after upgrading timescaledb to migrate existing chunks affected by this. The following code will fix any affected hypertables: ``` CREATE OR REPLACE FUNCTION pg_temp.constraint_columns(regclass, int2[]) RETURNS text[] AS $$ SELECT array_agg(attname) FROM unnest($2) un(attnum) LEFT JOIN pg_attribute att ON att.attrelid=$1 AND att.attnum = un.attnum; $$ LANGUAGE SQL SET search_path TO pg_catalog, pg_temp; DO $$ DECLARE ht_id int; ht regclass; chunk regclass; con_oid oid; con_frelid regclass; con_name text; con_columns text[]; chunk_id int; BEGIN -- iterate over all hypertables that have foreign key constraints FOR ht_id, ht in SELECT ht.id, format('%I.%I',ht.schema_name,ht.table_name)::regclass FROM _timescaledb_catalog.hypertable ht WHERE EXISTS ( SELECT FROM pg_constraint con WHERE con.contype='f' AND con.conrelid=format('%I.%I',ht.schema_name,ht.table_name)::regclass ) LOOP RAISE NOTICE 'Hypertable % has foreign key constraint', ht; -- iterate over all foreign key constraints on the hypertable -- and check that they are present on every chunk FOR con_oid, con_frelid, con_name, con_columns IN SELECT con.oid, con.confrelid, con.conname, pg_temp.constraint_columns(con.conrelid,con.conkey) FROM pg_constraint con WHERE con.contype='f' AND con.conrelid=ht LOOP RAISE NOTICE 'Checking constraint % %', con_name, con_columns; -- check that the foreign key constraint is present on the chunk FOR chunk_id, chunk IN SELECT ch.id, format('%I.%I',ch.schema_name,ch.table_name)::regclass FROM _timescaledb_catalog.chunk ch WHERE ch.hypertable_id=ht_id LOOP RAISE NOTICE 'Checking chunk %', chunk; IF NOT EXISTS ( SELECT FROM pg_constraint con WHERE con.contype='f' AND con.conrelid=chunk AND con.confrelid=con_frelid AND pg_temp.constraint_columns(con.conrelid,con.conkey) = con_columns ) THEN RAISE WARNING 'Restoring constraint % on chunk %', con_name, chunk; PERFORM _timescaledb_functions.constraint_clone(con_oid, chunk); INSERT INTO _timescaledb_catalog.chunk_constraint(chunk_id, dimension_slice_id, constraint_name, hypertable_constraint_name) VALUES (chunk_id, NULL, con_name, con_name); END IF; END LOOP; END LOOP; END LOOP; END $$; DROP FUNCTION pg_temp.constraint_columns(regclass, int2[]); ```
- Loading branch information
Showing
7 changed files
with
82 additions
and
68 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
Fixes: #6797 Fix foreign key constraint handling on compressed hypertables |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,45 @@ | ||
-- This file and its contents are licensed under the Timescale License. | ||
-- Please see the included NOTICE for copyright information and | ||
-- LICENSE-TIMESCALE for a copy of the license. | ||
-- test foreign key constraints with compression | ||
CREATE TABLE keys(time timestamptz unique); | ||
CREATE TABLE ht_with_fk(time timestamptz); | ||
SELECT create_hypertable('ht_with_fk','time'); | ||
NOTICE: adding not-null constraint to column "time" | ||
create_hypertable | ||
------------------------- | ||
(1,public,ht_with_fk,t) | ||
(1 row) | ||
|
||
ALTER TABLE ht_with_fk ADD CONSTRAINT keys FOREIGN KEY (time) REFERENCES keys(time) ON DELETE CASCADE; | ||
ALTER TABLE ht_with_fk SET (timescaledb.compress,timescaledb.compress_segmentby='time'); | ||
-- no keys added yet so any insert into ht_with_fk should fail | ||
\set ON_ERROR_STOP 0 | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
ERROR: insert or update on table "_hyper_1_1_chunk" violates foreign key constraint "1_1_keys" | ||
\set ON_ERROR_STOP 1 | ||
-- create a key in the referenced table | ||
INSERT INTO keys SELECT '2000-01-01'; | ||
-- now the insert should succeed | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
SELECT compress_chunk(ch) FROM show_chunks('ht_with_fk') ch; | ||
compress_chunk | ||
---------------------------------------- | ||
_timescaledb_internal._hyper_1_2_chunk | ||
(1 row) | ||
|
||
-- insert should still succeed after compression | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
-- inserting key not present in keys should fail | ||
\set ON_ERROR_STOP 0 | ||
INSERT INTO ht_with_fk SELECT '2000-01-01 0:00:01'; | ||
ERROR: insert or update on table "_hyper_1_2_chunk" violates foreign key constraint "2_2_keys" | ||
\set ON_ERROR_STOP 1 | ||
SELECT conrelid::regclass,conname,confrelid::regclass FROM pg_constraint WHERE contype = 'f' AND confrelid = 'keys'::regclass ORDER BY conrelid::regclass::text,conname; | ||
conrelid | conname | confrelid | ||
------------------------------------------------+----------+----------- | ||
ht_with_fk | keys | keys | ||
_timescaledb_internal.compress_hyper_2_3_chunk | keys | keys | ||
_timescaledb_internal._hyper_1_2_chunk | 2_2_keys | keys | ||
(3 rows) | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,35 @@ | ||
-- This file and its contents are licensed under the Timescale License. | ||
-- Please see the included NOTICE for copyright information and | ||
-- LICENSE-TIMESCALE for a copy of the license. | ||
|
||
-- test foreign key constraints with compression | ||
CREATE TABLE keys(time timestamptz unique); | ||
CREATE TABLE ht_with_fk(time timestamptz); | ||
SELECT create_hypertable('ht_with_fk','time'); | ||
|
||
ALTER TABLE ht_with_fk ADD CONSTRAINT keys FOREIGN KEY (time) REFERENCES keys(time) ON DELETE CASCADE; | ||
ALTER TABLE ht_with_fk SET (timescaledb.compress,timescaledb.compress_segmentby='time'); | ||
|
||
-- no keys added yet so any insert into ht_with_fk should fail | ||
\set ON_ERROR_STOP 0 | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
\set ON_ERROR_STOP 1 | ||
|
||
-- create a key in the referenced table | ||
INSERT INTO keys SELECT '2000-01-01'; | ||
|
||
-- now the insert should succeed | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
|
||
SELECT compress_chunk(ch) FROM show_chunks('ht_with_fk') ch; | ||
|
||
-- insert should still succeed after compression | ||
INSERT INTO ht_with_fk SELECT '2000-01-01'; | ||
|
||
-- inserting key not present in keys should fail | ||
\set ON_ERROR_STOP 0 | ||
INSERT INTO ht_with_fk SELECT '2000-01-01 0:00:01'; | ||
\set ON_ERROR_STOP 1 | ||
|
||
SELECT conrelid::regclass,conname,confrelid::regclass FROM pg_constraint WHERE contype = 'f' AND confrelid = 'keys'::regclass ORDER BY conrelid::regclass::text,conname; | ||
|