Disallow cascade_via_foreign_keys if any partition rel has non-inherited fkeys (#4487)

pull/4490/head
Onur Tirtir 2021-01-11 21:50:09 +03:00 committed by GitHub
parent 7b05777682
commit dd55ab394e
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 349 additions and 0 deletions

View File

@ -68,6 +68,15 @@ CascadeOperationForConnectedRelations(Oid relationId, LOCKMODE lockMode,
List *fKeyConnectedRelationIdList = GetForeignKeyConnectedRelationIdList(relationId);
LockRelationsWithLockMode(fKeyConnectedRelationIdList, lockMode);
/*
* Before removing any partition relations, we should error out here if any
* of connected relations is a partition table involved in a foreign key that
* is not inherited from its parent table.
* We should handle this case here as we remove partition relations in this
* function before ExecuteCascadeOperationForRelationIdList.
*/
ErrorIfAnyPartitionRelationInvolvedInNonInheritedFKey(fKeyConnectedRelationIdList);
/*
* We shouldn't cascade through foreign keys on partition tables as citus
* table functions already have their own logics to handle partition relations.
@ -116,6 +125,40 @@ LockRelationsWithLockMode(List *relationIdList, LOCKMODE lockMode)
}
/*
* ErrorIfAnyPartitionRelationInvolvedInNonInheritedFKey searches given
* relationIdList for a partition relation involved in a foreign key relationship
* that is not inherited from its parent and errors out if such a partition
* relation exists.
*/
void
ErrorIfAnyPartitionRelationInvolvedInNonInheritedFKey(List *relationIdList)
{
Oid relationId = InvalidOid;
foreach_oid(relationId, relationIdList)
{
if (!PartitionTable(relationId))
{
continue;
}
if (!RelationInvolvedInAnyNonInheritedForeignKeys(relationId))
{
continue;
}
char *partitionRelationQualifiedName =
generate_qualified_relation_name(relationId);
ereport(ERROR, (errmsg("cannot cascade operation via foreign keys as "
"partition table %s involved in a foreign key "
"relationship that is not inherited from it's "
"parent table", partitionRelationQualifiedName),
errhint("Remove non-inherited foreign keys from %s and "
"try operation again", partitionRelationQualifiedName)));
}
}
/*
* RemovePartitionRelationIds returns a list of relation id's by removing
* partition relation id's from given relationIdList.

View File

@ -1656,6 +1656,16 @@ UndistributeTable(Oid relationId, bool cascadeViaForeignKeys)
ereport(NOTICE, (errmsg("undistributing the partitions of %s",
quote_qualified_identifier(schemaName, relationName))));
List *partitionList = PartitionList(relationId);
/*
* This is a less common pattern where foreing key is directly from/to
* the partition relation as we already handled inherited foreign keys
* on partitions either by erroring out or cascading via foreign keys.
* It seems an acceptable limitation for now to ask users to drop such
* foreign keys manually.
*/
ErrorIfAnyPartitionRelationInvolvedInNonInheritedFKey(partitionList);
Oid partitionRelationId = InvalidOid;
foreach_oid(partitionRelationId, partitionList)
{

View File

@ -1212,3 +1212,46 @@ UpdateConstraintIsValid(Oid constraintId, bool isValid)
systable_endscan(scanDescriptor);
table_close(pgConstraint, NoLock);
}
/*
* RelationInvolvedInAnyNonInheritedForeignKeys returns true if relation involved
* in a foreign key that is not inherited from its parent relation.
*/
bool
RelationInvolvedInAnyNonInheritedForeignKeys(Oid relationId)
{
List *referencingForeignKeys = GetForeignKeyOids(relationId,
INCLUDE_REFERENCING_CONSTRAINTS |
INCLUDE_ALL_TABLE_TYPES);
/*
* We already capture self-referencing foreign keys above, so use
* EXCLUDE_SELF_REFERENCES here
*/
List *referencedForeignKeys = GetForeignKeyOids(relationId,
INCLUDE_REFERENCED_CONSTRAINTS |
EXCLUDE_SELF_REFERENCES |
INCLUDE_ALL_TABLE_TYPES);
List *foreignKeysRelationInvolved = list_concat(referencingForeignKeys,
referencedForeignKeys);
Oid foreignKeyId = InvalidOid;
foreach_oid(foreignKeyId, foreignKeysRelationInvolved)
{
HeapTuple heapTuple = SearchSysCache1(CONSTROID, ObjectIdGetDatum(foreignKeyId));
if (!HeapTupleIsValid(heapTuple))
{
/* not possible but be on the safe side */
continue;
}
Form_pg_constraint constraintForm = (Form_pg_constraint) GETSTRUCT(heapTuple);
Oid parentConstraintId = constraintForm->conparentid;
if (!OidIsValid(parentConstraintId))
{
return true;
}
}
return false;
}

View File

@ -174,6 +174,7 @@ extern bool ConstraintWithIdIsOfType(Oid constraintId, char targetConstraintType
extern bool TableHasExternalForeignKeys(Oid relationId);
extern List * GetForeignKeyOids(Oid relationId, int flags);
extern Oid GetReferencedTableId(Oid foreignKeyId);
extern bool RelationInvolvedInAnyNonInheritedForeignKeys(Oid relationId);
/* function.c - forward declarations */
@ -407,6 +408,7 @@ typedef enum CascadeOperationType
extern void CascadeOperationForConnectedRelations(Oid relationId, LOCKMODE relLockMode,
CascadeOperationType
cascadeOperationType);
extern void ErrorIfAnyPartitionRelationInvolvedInNonInheritedFKey(List *relationIdList);
extern void ExecuteAndLogDDLCommandList(List *ddlCommandList);
extern void ExecuteAndLogDDLCommand(const char *commandString);

View File

@ -276,6 +276,25 @@ SELECT create_distributed_table('partitioned_table_2', 'col_1');
(1 row)
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
CREATE TABLE distributed_table_4 (col_1 INT UNIQUE, col_2 INT);
SELECT create_distributed_table('distributed_table_4', 'col_1');
create_distributed_table
---------------------------------------------------------------------
(1 row)
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
CREATE TABLE reference_table_3 (col_1 INT UNIQUE, col_2 INT UNIQUE);
SELECT create_reference_table('reference_table_3');
create_reference_table
@ -285,6 +304,26 @@ SELECT create_reference_table('reference_table_3');
ALTER TABLE partitioned_table_1 ADD CONSTRAINT fkey_9 FOREIGN KEY (col_1) REFERENCES reference_table_3(col_2);
ALTER TABLE partitioned_table_2 ADD CONSTRAINT fkey_10 FOREIGN KEY (col_1) REFERENCES reference_table_3(col_2);
-- as pg < 12 doesn't support foreign keys between partitioned tables,
-- define below foreign key conditionally instead of adding another
-- test output
DO $proc$
BEGIN
IF substring(current_Setting('server_version'), '\d+')::int >= 12 THEN
EXECUTE
$$
ALTER TABLE partitioned_table_1 ADD CONSTRAINT fkey_15 FOREIGN KEY (col_1) REFERENCES partitioned_table_1(col_1);
$$;
END IF;
END$proc$;
BEGIN;
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
undistribute_table
---------------------------------------------------------------------
(1 row)
ROLLBACK;
BEGIN;
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
undistribute_table
@ -308,6 +347,96 @@ BEGIN;
fkey_9 | partitioned_table_1 | reference_table_3
(6 rows)
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('distributed_table_4', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_2_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('distributed_table_4', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2 ADD CONSTRAINT fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_1_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('reference_table_3', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_2_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_2_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ERROR: cannot cascade operation via foreign keys as partition table undistribute_table_cascade.partitioned_table_2_100_200 involved in a foreign key relationship that is not inherited from it's parent table
ROLLBACK;
-- as pg < 12 doesn't support foreign keys between partitioned tables,
-- define below foreign key conditionally instead of adding another

View File

@ -154,12 +154,44 @@ CREATE TABLE partitioned_table_2_100_200 PARTITION OF partitioned_table_2 FOR VA
CREATE TABLE partitioned_table_2_200_300 PARTITION OF partitioned_table_2 FOR VALUES FROM (200) TO (300);
SELECT create_distributed_table('partitioned_table_2', 'col_1');
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', true);
ROLLBACK;
CREATE TABLE distributed_table_4 (col_1 INT UNIQUE, col_2 INT);
SELECT create_distributed_table('distributed_table_4', 'col_1');
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', true);
ROLLBACK;
CREATE TABLE reference_table_3 (col_1 INT UNIQUE, col_2 INT UNIQUE);
SELECT create_reference_table('reference_table_3');
ALTER TABLE partitioned_table_1 ADD CONSTRAINT fkey_9 FOREIGN KEY (col_1) REFERENCES reference_table_3(col_2);
ALTER TABLE partitioned_table_2 ADD CONSTRAINT fkey_10 FOREIGN KEY (col_1) REFERENCES reference_table_3(col_2);
-- as pg < 12 doesn't support foreign keys between partitioned tables,
-- define below foreign key conditionally instead of adding another
-- test output
DO $proc$
BEGIN
IF substring(current_Setting('server_version'), '\d+')::int >= 12 THEN
EXECUTE
$$
ALTER TABLE partitioned_table_1 ADD CONSTRAINT fkey_15 FOREIGN KEY (col_1) REFERENCES partitioned_table_1(col_1);
$$;
END IF;
END$proc$;
BEGIN;
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
@ -171,6 +203,96 @@ BEGIN;
ORDER BY 1,2,3;
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES reference_table_3(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY(col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('distributed_table_4', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE distributed_table_4 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_1_100_200 ADD CONSTRAINT fkey FOREIGN KEY(col_1) REFERENCES distributed_table_4(col_1);
SELECT undistribute_table('distributed_table_4', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2 ADD CONSTRAINT fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_1_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('reference_table_3', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_2', cascade_via_foreign_keys=>true);
ROLLBACK;
BEGIN;
set citus.multi_shard_modify_mode to 'sequential';
ALTER TABLE partitioned_table_2_100_200 ADD CONSTRAINT non_inherited_fkey FOREIGN KEY (col_1) REFERENCES partitioned_table_2_100_200(col_1);
SELECT undistribute_table('partitioned_table_1', cascade_via_foreign_keys=>true);
ROLLBACK;
-- as pg < 12 doesn't support foreign keys between partitioned tables,
-- define below foreign key conditionally instead of adding another
-- test output