diff --git a/.unreleased/fix_6339 b/.unreleased/fix_6339 new file mode 100644 index 00000000000..b4f4290cb34 --- /dev/null +++ b/.unreleased/fix_6339 @@ -0,0 +1,2 @@ +Fixes: #6339 Fix tablespace with constraints +Thanks: @lyp-bobi for reporting the issue diff --git a/sql/chunk_constraint.sql b/sql/chunk_constraint.sql index 0b0a815870d..1d205b236fe 100644 --- a/sql/chunk_constraint.sql +++ b/sql/chunk_constraint.sql @@ -40,10 +40,6 @@ BEGIN def := pg_get_constraintdef(constraint_oid); - IF indx_tablespace IS NOT NULL THEN - def := format('%s USING INDEX TABLESPACE %I', def, indx_tablespace); - END IF; - ELSIF constraint_type = 't' THEN -- constraint triggers are copied separately with normal triggers def := NULL; @@ -63,6 +59,18 @@ BEGIN $$ ALTER TABLE %I.%I ADD CONSTRAINT %I %s $$, chunk_row.schema_name, chunk_row.table_name, chunk_constraint_row.constraint_name, def ); + + -- if constraint (primary or unique) needs a tablespace then add it + -- via a separate ALTER INDEX SET TABLESPACE command. We cannot append it + -- to the "def" string above since it leads to a SYNTAX error when + -- "DEFERRABLE" or "INITIALLY DEFERRED" are used in the constraint + IF indx_tablespace IS NOT NULL THEN + EXECUTE pg_catalog.format( + $$ ALTER INDEX %I.%I SET TABLESPACE %I $$, + chunk_row.schema_name, chunk_constraint_row.constraint_name, indx_tablespace + ); + END IF; + END IF; END $BODY$ SET search_path TO pg_catalog, pg_temp; diff --git a/sql/updates/reverse-dev.sql b/sql/updates/reverse-dev.sql index 7f33372ef99..123d39f252c 100644 --- a/sql/updates/reverse-dev.sql +++ b/sql/updates/reverse-dev.sql @@ -333,3 +333,72 @@ BEGIN END LOOP; END; $$ LANGUAGE PLPGSQL; + +DROP FUNCTION _timescaledb_functions.chunk_constraint_add_table_constraint( + chunk_constraint_row _timescaledb_catalog.chunk_constraint +); + +CREATE FUNCTION _timescaledb_functions.chunk_constraint_add_table_constraint( + chunk_constraint_row _timescaledb_catalog.chunk_constraint +) + RETURNS VOID LANGUAGE PLPGSQL AS +$BODY$ +DECLARE + chunk_row _timescaledb_catalog.chunk; + hypertable_row _timescaledb_catalog.hypertable; + constraint_oid OID; + constraint_type CHAR; + check_sql TEXT; + def TEXT; + indx_tablespace NAME; + tablespace_def TEXT; +BEGIN + SELECT * INTO STRICT chunk_row FROM _timescaledb_catalog.chunk c WHERE c.id = chunk_constraint_row.chunk_id; + SELECT * INTO STRICT hypertable_row FROM _timescaledb_catalog.hypertable h WHERE h.id = chunk_row.hypertable_id; + + IF chunk_constraint_row.dimension_slice_id IS NOT NULL THEN + RAISE 'cannot create dimension constraint %', chunk_constraint_row; + ELSIF chunk_constraint_row.hypertable_constraint_name IS NOT NULL THEN + + SELECT oid, contype INTO STRICT constraint_oid, constraint_type FROM pg_constraint + WHERE conname=chunk_constraint_row.hypertable_constraint_name AND + conrelid = format('%I.%I', hypertable_row.schema_name, hypertable_row.table_name)::regclass::oid; + + IF constraint_type IN ('p','u') THEN + -- since primary keys and unique constraints are backed by an index + -- they might have an index tablespace assigned + -- the tablspace is not part of the constraint definition so + -- we have to append it explicitly to preserve it + SELECT T.spcname INTO indx_tablespace + FROM pg_constraint C, pg_class I, pg_tablespace T + WHERE C.oid = constraint_oid AND C.contype IN ('p', 'u') AND I.oid = C.conindid AND I.reltablespace = T.oid; + + def := pg_get_constraintdef(constraint_oid); + + IF indx_tablespace IS NOT NULL THEN + def := format('%s USING INDEX TABLESPACE %I', def, indx_tablespace); + END IF; + + ELSIF constraint_type = 't' THEN + -- constraint triggers are copied separately with normal triggers + def := NULL; + ELSE + def := pg_get_constraintdef(constraint_oid); + END IF; + + ELSE + RAISE 'unknown constraint type'; + END IF; + + IF def IS NOT NULL THEN + -- to allow for custom types with operators outside of pg_catalog + -- we set search_path to @extschema@ + SET LOCAL search_path TO @extschema@, pg_temp; + EXECUTE pg_catalog.format( + $$ ALTER TABLE %I.%I ADD CONSTRAINT %I %s $$, + chunk_row.schema_name, chunk_row.table_name, chunk_constraint_row.constraint_name, def + ); + + END IF; +END +$BODY$ SET search_path TO pg_catalog, pg_temp; diff --git a/test/expected/constraint.out b/test/expected/constraint.out index ec7e953f7aa..b22baab9360 100644 --- a/test/expected/constraint.out +++ b/test/expected/constraint.out @@ -812,7 +812,7 @@ CREATE TABLE tbl ( fk_id int, id int, time timestamp, -CONSTRAINT pk PRIMARY KEY (time, id) USING INDEX TABLESPACE tablespace1); +CONSTRAINT pk PRIMARY KEY (time, id) USING INDEX TABLESPACE tablespace1 DEFERRABLE INITIALLY DEFERRED); SELECT create_hypertable('tbl', 'time'); WARNING: column type "timestamp without time zone" used for "time" does not follow best practices create_hypertable diff --git a/test/sql/constraint.sql b/test/sql/constraint.sql index 1603422f0b2..9861b798e9c 100644 --- a/test/sql/constraint.sql +++ b/test/sql/constraint.sql @@ -612,7 +612,7 @@ CREATE TABLE tbl ( fk_id int, id int, time timestamp, -CONSTRAINT pk PRIMARY KEY (time, id) USING INDEX TABLESPACE tablespace1); +CONSTRAINT pk PRIMARY KEY (time, id) USING INDEX TABLESPACE tablespace1 DEFERRABLE INITIALLY DEFERRED); SELECT create_hypertable('tbl', 'time');