Enable adding FOREIGN KEY constraints on Citus tables without a name. (#6616)

DESCRIPTION: Enable adding FOREIGN KEY constraints on Citus tables
without a name

This PR enables adding a foreign key to a distributed/reference/Citus
local table without specifying the name of the constraint, e.g. `ALTER
TABLE items ADD FOREIGN KEY (user_id) REFERENCES users (id);`
pull/6629/head
Emel Şimşek 2023-01-20 01:43:52 +03:00 committed by GitHub
parent 2388fbea6e
commit 58368b7783
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 1180 additions and 18 deletions

View File

@ -702,12 +702,50 @@ PostprocessAlterTableSchemaStmt(Node *node, const char *queryString)
}
/*
* ChooseForeignKeyConstraintNameAddition returns the string of column names to be used when generating a foreign
* key constraint name. This function is copied from postgres codebase.
*/
static char *
ChooseForeignKeyConstraintNameAddition(List *columnNames)
{
char buf[NAMEDATALEN * 2];
int buflen = 0;
buf[0] = '\0';
String *columnNameString = NULL;
foreach_ptr(columnNameString, columnNames)
{
const char *name = strVal(columnNameString);
if (buflen > 0)
{
buf[buflen++] = '_'; /* insert _ between names */
}
/*
* At this point we have buflen <= NAMEDATALEN. name should be less
* than NAMEDATALEN already, but use strlcpy for paranoia.
*/
strlcpy(buf + buflen, name, NAMEDATALEN);
buflen += strlen(buf + buflen);
if (buflen >= NAMEDATALEN)
{
break;
}
}
return pstrdup(buf);
}
/*
* GenerateConstraintName creates and returns a default name for the constraints Citus supports
* for default naming. See ConstTypeCitusCanDefaultName function for the supported constraint types.
*/
static char *
GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constraint)
GenerateConstraintName(const char *tableName, Oid namespaceId, Constraint *constraint)
{
char *conname = NULL;
@ -715,7 +753,7 @@ GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constra
{
case CONSTR_PRIMARY:
{
conname = ChooseIndexName(tabname, namespaceId,
conname = ChooseIndexName(tableName, namespaceId,
NULL, NULL, true, true);
break;
}
@ -732,7 +770,7 @@ GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constra
indexParams = lappend(indexParams, iparam);
}
conname = ChooseIndexName(tabname, namespaceId,
conname = ChooseIndexName(tableName, namespaceId,
ChooseIndexColumnNames(indexParams),
NULL, false, true);
break;
@ -756,7 +794,7 @@ GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constra
excludeOpNames = lappend(excludeOpNames, opname);
}
conname = ChooseIndexName(tabname, namespaceId,
conname = ChooseIndexName(tableName, namespaceId,
ChooseIndexColumnNames(indexParams),
excludeOpNames,
false, true);
@ -765,11 +803,22 @@ GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constra
case CONSTR_CHECK:
{
conname = ChooseConstraintName(tabname, NULL, "check", namespaceId, NULL);
conname = ChooseConstraintName(tableName, NULL, "check", namespaceId, NIL);
break;
}
case CONSTR_FOREIGN:
{
conname = ChooseConstraintName(tableName,
ChooseForeignKeyConstraintNameAddition(
constraint->fk_attrs),
"fkey",
namespaceId,
NIL);
break;
}
default:
{
ereport(ERROR, (errmsg(
@ -783,6 +832,42 @@ GenerateConstraintName(const char *tabname, Oid namespaceId, Constraint *constra
}
/*
* EnsureSequentialModeForAlterTableOperation makes sure that the current transaction is already in
* sequential mode, or can still safely be put in sequential mode, it errors if that is
* not possible. The error contains information for the user to retry the transaction with
* sequential mode set from the beginning.
*/
static void
EnsureSequentialModeForAlterTableOperation(void)
{
const char *objTypeString = "ALTER TABLE ... ADD FOREIGN KEY";
if (ParallelQueryExecutedInTransaction())
{
ereport(ERROR, (errmsg("cannot run %s command because there was a "
"parallel operation on a distributed table in the "
"transaction", objTypeString),
errdetail("When running command on/for a distributed %s, Citus "
"needs to perform all operations over a single "
"connection per node to ensure consistency.",
objTypeString),
errhint("Try re-running the transaction with "
"\"SET LOCAL citus.multi_shard_modify_mode TO "
"\'sequential\';\"")));
}
ereport(DEBUG1, (errmsg("switching to sequential query execution mode"),
errdetail(
"A command for a distributed %s is run. To make sure subsequent "
"commands see the %s correctly we need to make sure to "
"use only one connection for all future commands",
objTypeString, objTypeString)));
SetLocalMultiShardModifyModeToSequential();
}
/*
* SwitchToSequentialAndLocalExecutionIfConstraintNameTooLong generates the longest index constraint name
* among the shards of the partitions, and if exceeds the limit switches to sequential and
@ -860,16 +945,16 @@ SwitchToSequentialAndLocalExecutionIfConstraintNameTooLong(Oid relationId,
/*
* PreprocessAlterTableAddIndexConstraint creates a new constraint name for the index constraints {PRIMARY KEY, UNIQUE, EXCLUDE}
* and changes the original alterTableCommand run by the utility hook to use the new constraint name.
* Then converts the ALTER TABLE ... ADD {PRIMARY KEY, UNIQUE, EXCLUDE} ... command
* into ALTER TABLE ... ADD CONSTRAINT <constraint name> {PRIMARY KEY, UNIQUE, EXCLUDE} format and returns the DDLJob
* PreprocessAlterTableAddConstraint creates a new constraint name for {PRIMARY KEY, UNIQUE, EXCLUDE, CHECK, FOREIGN KEY}
* and changes the original alterTableCommand run by the standard utility hook to use the new constraint name.
* Then it converts the ALTER TABLE ... ADD {PRIMARY KEY, UNIQUE, EXCLUDE, CHECK, FOREIGN KEY} ... command
* into ALTER TABLE ... ADD CONSTRAINT <constraint name> {PRIMARY KEY, UNIQUE, EXCLUDE, CHECK, FOREIGN KEY} format and returns the DDLJob
* to run this command in the workers.
*/
static List *
PreprocessAlterTableAddIndexConstraint(AlterTableStmt *alterTableStatement, Oid
relationId,
Constraint *constraint)
PreprocessAlterTableAddConstraint(AlterTableStmt *alterTableStatement, Oid
relationId,
Constraint *constraint)
{
/* We should only preprocess an ADD CONSTRAINT command if we are changing the it.
* This only happens when we have to create a constraint name in citus since the client does
@ -899,7 +984,40 @@ PreprocessAlterTableAddIndexConstraint(AlterTableStmt *alterTableStatement, Oid
ObjectAddressSet(ddlJob->targetObjectAddress, RelationRelationId, relationId);
ddlJob->startNewTransaction = false;
ddlJob->metadataSyncCommand = ddlCommand;
ddlJob->taskList = DDLTaskList(relationId, ddlCommand);
if (constraint->contype == CONSTR_FOREIGN)
{
Oid rightRelationId = RangeVarGetRelid(constraint->pktable, NoLock,
false);
if (IsCitusTableType(rightRelationId, REFERENCE_TABLE))
{
EnsureSequentialModeForAlterTableOperation();
}
/*
* If one of the relations involved in the FOREIGN KEY constraint is not a distributed table, citus errors out eventually.
* PreprocessAlterTableStmt function returns an empty tasklist in those cases.
* leftRelation is checked in PreprocessAlterTableStmt before
* calling PreprocessAlterTableAddConstraint. However, we need to handle the rightRelation since PreprocessAlterTableAddConstraint
* returns early.
*/
bool referencedIsLocalTable = !IsCitusTable(rightRelationId);
if (referencedIsLocalTable)
{
ddlJob->taskList = NIL;
}
else
{
ddlJob->taskList = InterShardDDLTaskList(relationId, rightRelationId,
ddlCommand);
}
}
else
{
ddlJob->taskList = DDLTaskList(relationId, ddlCommand);
}
return list_make1(ddlJob);
}
@ -1143,6 +1261,13 @@ PreprocessAlterTableStmt(Node *node, const char *alterTableCommand,
* transaction is in process, which causes deadlock.
*/
constraint->skip_validation = true;
if (constraint->conname == NULL)
{
return PreprocessAlterTableAddConstraint(alterTableStatement,
leftRelationId,
constraint);
}
}
else if (constraint->conname == NULL)
{
@ -1153,9 +1278,9 @@ PreprocessAlterTableStmt(Node *node, const char *alterTableCommand,
* ALTER TABLE ... ADD CONSTRAINT <conname> PRIMARY KEY ... form and create the ddl jobs
* for running this form of the command on the workers.
*/
return PreprocessAlterTableAddIndexConstraint(alterTableStatement,
leftRelationId,
constraint);
return PreprocessAlterTableAddConstraint(alterTableStatement,
leftRelationId,
constraint);
}
}
}
@ -1939,7 +2064,8 @@ ConstrTypeCitusCanDefaultName(ConstrType constrType)
return constrType == CONSTR_PRIMARY ||
constrType == CONSTR_UNIQUE ||
constrType == CONSTR_EXCLUSION ||
constrType == CONSTR_CHECK;
constrType == CONSTR_CHECK ||
constrType == CONSTR_FOREIGN;
}

View File

@ -112,6 +112,33 @@ AppendAlterTableStmt(StringInfo buf, AlterTableStmt *stmt)
}
/*
* AppendColumnNameList converts a list of columns into comma separated string format
* (colname_1, colname_2, .., colname_n).
*/
static void
AppendColumnNameList(StringInfo buf, List *columns)
{
appendStringInfoString(buf, " (");
ListCell *lc;
bool firstkey = true;
foreach(lc, columns)
{
if (firstkey == false)
{
appendStringInfoString(buf, ", ");
}
appendStringInfo(buf, "%s", quote_identifier(strVal(lfirst(lc))));
firstkey = false;
}
appendStringInfoString(buf, " )");
}
/*
* AppendAlterTableCmdAddConstraint builds the add constraint command for index constraints
* in the ADD CONSTRAINT <conname> {PRIMARY KEY, UNIQUE, EXCLUSION} form and appends it to the buf.
@ -273,6 +300,109 @@ AppendAlterTableCmdAddConstraint(StringInfo buf, Constraint *constraint,
appendStringInfo(buf, " NO INHERIT");
}
}
else if (constraint->contype == CONSTR_FOREIGN)
{
appendStringInfoString(buf, " FOREIGN KEY");
AppendColumnNameList(buf, constraint->fk_attrs);
appendStringInfoString(buf, " REFERENCES");
appendStringInfo(buf, " %s", quote_identifier(constraint->pktable->relname));
if (list_length(constraint->pk_attrs) > 0)
{
AppendColumnNameList(buf, constraint->pk_attrs);
}
/* Append supported options if provided */
/* FKCONSTR_MATCH_SIMPLE is default. Append matchtype if not default */
if (constraint->fk_matchtype == FKCONSTR_MATCH_FULL)
{
appendStringInfoString(buf, " MATCH FULL");
}
switch (constraint->fk_del_action)
{
case FKCONSTR_ACTION_SETDEFAULT:
{
appendStringInfoString(buf, " ON DELETE SET DEFAULT");
break;
}
case FKCONSTR_ACTION_SETNULL:
{
appendStringInfoString(buf, " ON DELETE SET NULL");
break;
}
case FKCONSTR_ACTION_NOACTION:
{
appendStringInfoString(buf, " ON DELETE NO ACTION");
break;
}
case FKCONSTR_ACTION_RESTRICT:
{
appendStringInfoString(buf, " ON DELETE RESTRICT");
break;
}
case FKCONSTR_ACTION_CASCADE:
{
appendStringInfoString(buf, " ON DELETE CASCADE");
break;
}
default:
{
elog(ERROR, "unsupported FK delete action type: %d",
(int) constraint->fk_del_action);
break;
}
}
switch (constraint->fk_upd_action)
{
case FKCONSTR_ACTION_SETDEFAULT:
{
appendStringInfoString(buf, " ON UPDATE SET DEFAULT");
break;
}
case FKCONSTR_ACTION_SETNULL:
{
appendStringInfoString(buf, " ON UPDATE SET NULL");
break;
}
case FKCONSTR_ACTION_NOACTION:
{
appendStringInfoString(buf, " ON UPDATE NO ACTION");
break;
}
case FKCONSTR_ACTION_RESTRICT:
{
appendStringInfoString(buf, " ON UPDATE RESTRICT");
break;
}
case FKCONSTR_ACTION_CASCADE:
{
appendStringInfoString(buf, " ON UPDATE CASCADE");
break;
}
default:
{
elog(ERROR, "unsupported FK update action type: %d",
(int) constraint->fk_upd_action);
break;
}
}
}
if (constraint->deferrable)
{

View File

@ -0,0 +1,545 @@
--
-- MULTI_ALTER_TABLE_ADD_FOREIGN_KEY_WITHOUT_NAME
--
ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1770000;
ALTER SEQUENCE pg_catalog.pg_dist_placement_placementid_seq RESTART 1770000;
SET citus.shard_count TO 4;
CREATE SCHEMA at_add_fk;
SET SEARCH_PATH = at_add_fk;
SET citus.shard_replication_factor TO 1;
-- create tables
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
-- self referencing table with replication factor > 1
SET citus.shard_replication_factor TO 2;
CREATE TABLE self_referencing_table(id int, ref_id int, PRIMARY KEY (id, ref_id));
SELECT create_distributed_table('self_referencing_table', 'id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE self_referencing_table ADD FOREIGN KEY(id,ref_id) REFERENCES self_referencing_table(id, ref_id);
ERROR: cannot create foreign key constraint
DETAIL: Citus currently supports foreign key constraints only for "citus.shard_replication_factor = 1".
HINT: Please change "citus.shard_replication_factor to 1". To learn more about using foreign keys with other replication factors, please contact us at https://citusdata.com/about/contact_us.
DROP TABLE self_referencing_table;
-- test foreign constraint creation on NOT co-located tables
SET citus.shard_replication_factor TO 1;
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
-- test foreign constraint creation on non-partition columns
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(id) REFERENCES referenced_table(id);
ERROR: cannot create foreign key constraint
DETAIL: Foreign keys are supported in two cases, either in between two colocated tables including partition column in the same ordinal in the both tables or from distributed to reference tables
DROP TABLE referencing_table;
-- test foreign constraint creation while column list are in incorrect order
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column);
ERROR: cannot create foreign key constraint
DETAIL: Foreign keys are supported in two cases, either in between two colocated tables including partition column in the same ordinal in the both tables or from distributed to reference tables
DROP TABLE referencing_table;
-- test foreign constraint with replication factor > 1
SET citus.shard_replication_factor TO 2;
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
ERROR: cannot create foreign key constraint since relations are not colocated or not referencing a reference table
DETAIL: A distributed table can only have foreign keys if it is referencing another colocated hash distributed table or a reference table
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint creation on append and range distributed tables
-- foreign keys are supported either in between distributed tables including the
-- distribution column or from distributed tables to reference tables.
SET citus.shard_replication_factor TO 1;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'id', 'append');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY (id) REFERENCES referenced_table(id);
ERROR: cannot create foreign key constraint since relations are not colocated or not referencing a reference table
DETAIL: A distributed table can only have foreign keys if it is referencing another colocated hash distributed table or a reference table
DROP TABLE referencing_table;
DROP TABLE referenced_table;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'range');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'id', 'range');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY (id) REFERENCES referenced_table(id);
ERROR: cannot create foreign key constraint since relations are not colocated or not referencing a reference table
DETAIL: A distributed table can only have foreign keys if it is referencing another colocated hash distributed table or a reference table
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint creation is not supported when one of the tables is not a citus table
CREATE TABLE referenced_local_table(id int PRIMARY KEY, other_column int);
CREATE TABLE reference_table(id int, referencing_column int);
SELECT create_reference_table('reference_table');
create_reference_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE reference_table ADD FOREIGN KEY (referencing_column) REFERENCES referenced_local_table(id);
ERROR: referenced table "referenced_local_table" must be a distributed table or a reference table
DETAIL: To enforce foreign keys, the referencing and referenced rows need to be stored on the same node.
HINT: You could use SELECT create_reference_table('referenced_local_table') to replicate the referenced table to all nodes or consider dropping the foreign key
DROP TABLE referenced_local_table;
DROP TABLE reference_table;
-- test foreign constraint with correct conditions
CREATE TABLE referenced_table(id int PRIMARY KEY, test_column int);
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referenced_table', 'id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname
---------------------------------------------------------------------
referencing_table_ref_id_fkey
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%';
conname
---------------------------------------------------------------------
referencing_table_ref_id_fkey
referencing_table_ref_id_fkey_1770033
referencing_table_ref_id_fkey_1770035
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- Test "ADD FOREIGN KEY (...) REFERENCING pk_table" format
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table;
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname
---------------------------------------------------------------------
referencing_table_ref_id_fkey
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%';
conname
---------------------------------------------------------------------
referencing_table_ref_id_fkey
referencing_table_ref_id_fkey_1770033
referencing_table_ref_id_fkey_1770035
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint options
-- test ON DELETE CASCADE
SET citus.shard_replication_factor TO 1;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referenced_table', 'id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
create_distributed_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE CASCADE;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | c | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | c | s
referencing_table_ref_id_fkey_1770041 | a | c | s
referencing_table_ref_id_fkey_1770043 | a | c | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON DELETE NO ACTION + DEFERABLE + INITIALLY DEFERRED
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE NO ACTION DEFERRABLE INITIALLY DEFERRED;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | a | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | a | s
referencing_table_ref_id_fkey_1770041 | a | a | s
referencing_table_ref_id_fkey_1770043 | a | a | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON DELETE RESTRICT
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE RESTRICT;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | r | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_fkey | a | r | s
referencing_table_ref_id_fkey_1770041 | a | r | s
referencing_table_ref_id_fkey_1770043 | a | r | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON UPDATE NO ACTION + DEFERABLE + INITIALLY DEFERRED
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE NO ACTION DEFERRABLE INITIALLY DEFERRED;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | s
referencing_table_ref_id_id_fkey_1770041 | a | a | s
referencing_table_ref_id_id_fkey_1770043 | a | a | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test ON UPDATE RESTRICT
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE RESTRICT;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | r | a | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | r | a | s
referencing_table_ref_id_id_fkey_1770041 | r | a | s
referencing_table_ref_id_id_fkey_1770043 | r | a | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test MATCH SIMPLE
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) MATCH SIMPLE;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | s
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | s
referencing_table_ref_id_id_fkey_1770041 | a | a | s
referencing_table_ref_id_id_fkey_1770043 | a | a | s
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test MATCH FULL
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) MATCH FULL;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | f
(1 row)
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
conname | confupdtype | confdeltype | confmatchtype
---------------------------------------------------------------------
referencing_table_ref_id_id_fkey | a | a | f
referencing_table_ref_id_id_fkey_1770041 | a | a | f
referencing_table_ref_id_id_fkey_1770043 | a | a | f
(3 rows)
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- verify that we skip foreign key validation when citus.skip_constraint_validation is set to ON
-- not skipping validation would result in a distributed query, which emits debug messages
BEGIN;
SET LOCAL citus.skip_constraint_validation TO on;
SET LOCAL client_min_messages TO DEBUG1;
ALTER TABLE referencing_table ADD FOREIGN KEY (ref_id) REFERENCES referenced_table (id);
ABORT;
-- test foreign constraint creation with not supported parameters
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET NULL;
ERROR: cannot create foreign key constraint
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation when distribution key is included in the foreign key constraint
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT;
ERROR: cannot create foreign key constraint
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation when distribution key is included in the foreign key constraint
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET NULL;
ERROR: cannot create foreign key constraint
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET DEFAULT;
ERROR: cannot create foreign key constraint
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
ERROR: cannot create foreign key constraint
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
-- test ADD FOREIGN KEY from distributed to reference table.
SET citus.shard_replication_factor = 1;
CREATE TABLE dist_table(id int, referencing_column int);
SELECT create_distributed_table('dist_table', 'referencing_column');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE reference_table(id int PRIMARY KEY, another_column int);
SELECT create_reference_table('reference_table');
create_reference_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'dist_table';
conname
---------------------------------------------------------------------
dist_table_referencing_column_fkey
(1 row)
ALTER TABLE dist_table DROP CONSTRAINT dist_table_referencing_column_fkey;
BEGIN;
SELECT count(*) FROM dist_table;
count
---------------------------------------------------------------------
0
(1 row)
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
ERROR: cannot run ALTER TABLE ... ADD FOREIGN KEY command because there was a parallel operation on a distributed table in the transaction
DETAIL: When running command on/for a distributed ALTER TABLE ... ADD FOREIGN KEY, Citus needs to perform all operations over a single connection per node to ensure consistency.
HINT: Try re-running the transaction with "SET LOCAL citus.multi_shard_modify_mode TO 'sequential';"
ROLLBACK;
-- try inside a sequential block
BEGIN;
SET LOCAL citus.multi_shard_modify_mode TO 'sequential';
SELECT count(*) FROM dist_table;
count
---------------------------------------------------------------------
0
(1 row)
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
ROLLBACK;
DROP TABLE dist_table CASCADE;
DROP TABLE reference_table CASCADE;
-- test ADD FOREIGN KEY from citus local to reference table
SELECT 1 FROM master_add_node('localhost', :master_port, groupId => 0);
NOTICE: localhost:xxxxx is the coordinator and already contains metadata, skipping syncing the metadata
?column?
---------------------------------------------------------------------
1
(1 row)
CREATE TABLE citus_local_table(l1 int);
SELECT citus_add_local_table_to_metadata('citus_local_table');
citus_add_local_table_to_metadata
---------------------------------------------------------------------
(1 row)
CREATE TABLE reference_table(r1 int primary key); SELECT create_reference_table('reference_table');
create_reference_table
---------------------------------------------------------------------
(1 row)
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1);
-- test ADD FOREIGN KEY from citus local to reference table with supported options
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE CASCADE;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE SET NULL;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE SET DEFAULT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE NO ACTION;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE RESTRICT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE CASCADE;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE SET NULL;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE SET DEFAULT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE NO ACTION;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE RESTRICT;
DROP TABLE citus_local_table CASCADE;
SELECT 1 FROM master_remove_node('localhost', :master_port);
?column?
---------------------------------------------------------------------
1
(1 row)
RESET SEARCH_PATH;
RESET client_min_messages;
DROP SCHEMA at_add_fk CASCADE;
NOTICE: drop cascades to 4 other objects
DETAIL: drop cascades to table at_add_fk.referenced_table
drop cascades to table at_add_fk.referencing_table
drop cascades to table at_add_fk.reference_table
drop cascades to table at_add_fk.reference_table_1770051

View File

@ -466,7 +466,6 @@ ERROR: cannot execute ADD CONSTRAINT command with other subcommands
HINT: You can issue each subcommand separately
-- test foreign constraint creation without giving explicit name
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
ERROR: cannot create constraint without a name on a distributed table
-- test foreign constraint creation on NOT co-located tables
DROP TABLE referencing_table;
DROP TABLE referenced_table;

View File

@ -152,6 +152,7 @@ test: multi_index_statements
test: multi_alter_table_statements
test: multi_alter_table_add_constraints
test: multi_alter_table_add_constraints_without_name
test: multi_alter_table_add_foreign_key_without_name
# ----------
# Tests to check if we inform the user about potential caveats of creating new

View File

@ -0,0 +1,361 @@
--
-- MULTI_ALTER_TABLE_ADD_FOREIGN_KEY_WITHOUT_NAME
--
ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1770000;
ALTER SEQUENCE pg_catalog.pg_dist_placement_placementid_seq RESTART 1770000;
SET citus.shard_count TO 4;
CREATE SCHEMA at_add_fk;
SET SEARCH_PATH = at_add_fk;
SET citus.shard_replication_factor TO 1;
-- create tables
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'hash');
-- self referencing table with replication factor > 1
SET citus.shard_replication_factor TO 2;
CREATE TABLE self_referencing_table(id int, ref_id int, PRIMARY KEY (id, ref_id));
SELECT create_distributed_table('self_referencing_table', 'id', 'hash');
ALTER TABLE self_referencing_table ADD FOREIGN KEY(id,ref_id) REFERENCES self_referencing_table(id, ref_id);
DROP TABLE self_referencing_table;
-- test foreign constraint creation on NOT co-located tables
SET citus.shard_replication_factor TO 1;
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
-- test foreign constraint creation on non-partition columns
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
-- test foreign constraint creation while column list are in incorrect order
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column);
DROP TABLE referencing_table;
-- test foreign constraint with replication factor > 1
SET citus.shard_replication_factor TO 2;
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint creation on append and range distributed tables
-- foreign keys are supported either in between distributed tables including the
-- distribution column or from distributed tables to reference tables.
SET citus.shard_replication_factor TO 1;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'hash');
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'id', 'append');
ALTER TABLE referencing_table ADD FOREIGN KEY (id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
DROP TABLE referenced_table;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
SELECT create_distributed_table('referenced_table', 'id', 'range');
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referencing_table', 'id', 'range');
ALTER TABLE referencing_table ADD FOREIGN KEY (id) REFERENCES referenced_table(id);
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint creation is not supported when one of the tables is not a citus table
CREATE TABLE referenced_local_table(id int PRIMARY KEY, other_column int);
CREATE TABLE reference_table(id int, referencing_column int);
SELECT create_reference_table('reference_table');
ALTER TABLE reference_table ADD FOREIGN KEY (referencing_column) REFERENCES referenced_local_table(id);
DROP TABLE referenced_local_table;
DROP TABLE reference_table;
-- test foreign constraint with correct conditions
CREATE TABLE referenced_table(id int PRIMARY KEY, test_column int);
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referenced_table', 'id', 'hash');
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%';
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- Test "ADD FOREIGN KEY (...) REFERENCING pk_table" format
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table;
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%';
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
DROP TABLE referencing_table;
DROP TABLE referenced_table;
-- test foreign constraint options
-- test ON DELETE CASCADE
SET citus.shard_replication_factor TO 1;
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
CREATE TABLE referencing_table(id int, ref_id int);
SELECT create_distributed_table('referenced_table', 'id', 'hash');
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE CASCADE;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON DELETE NO ACTION + DEFERABLE + INITIALLY DEFERRED
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE NO ACTION DEFERRABLE INITIALLY DEFERRED;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON DELETE RESTRICT
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE RESTRICT;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_fkey;
-- test ON UPDATE NO ACTION + DEFERABLE + INITIALLY DEFERRED
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE NO ACTION DEFERRABLE INITIALLY DEFERRED;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test ON UPDATE RESTRICT
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE RESTRICT;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test MATCH SIMPLE
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) MATCH SIMPLE;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- test MATCH FULL
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) MATCH FULL;
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'referencing_table';
\c - - :public_worker_1_host :worker_1_port
SELECT con.conname, con.confupdtype, con.confdeltype, con.confmatchtype
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname LIKE 'referencing_table%' ORDER BY con.conname ASC;
\c - - :master_host :master_port
SET SEARCH_PATH = at_add_fk;
ALTER TABLE referencing_table DROP CONSTRAINT referencing_table_ref_id_id_fkey;
-- verify that we skip foreign key validation when citus.skip_constraint_validation is set to ON
-- not skipping validation would result in a distributed query, which emits debug messages
BEGIN;
SET LOCAL citus.skip_constraint_validation TO on;
SET LOCAL client_min_messages TO DEBUG1;
ALTER TABLE referencing_table ADD FOREIGN KEY (ref_id) REFERENCES referenced_table (id);
ABORT;
-- test foreign constraint creation with not supported parameters
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET NULL;
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT;
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET NULL;
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET DEFAULT;
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
-- test ADD FOREIGN KEY from distributed to reference table.
SET citus.shard_replication_factor = 1;
CREATE TABLE dist_table(id int, referencing_column int);
SELECT create_distributed_table('dist_table', 'referencing_column');
CREATE TABLE reference_table(id int PRIMARY KEY, another_column int);
SELECT create_reference_table('reference_table');
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
SELECT con.conname
FROM pg_catalog.pg_constraint con
INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid
INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace
WHERE rel.relname = 'dist_table';
ALTER TABLE dist_table DROP CONSTRAINT dist_table_referencing_column_fkey;
BEGIN;
SELECT count(*) FROM dist_table;
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
ROLLBACK;
-- try inside a sequential block
BEGIN;
SET LOCAL citus.multi_shard_modify_mode TO 'sequential';
SELECT count(*) FROM dist_table;
ALTER TABLE dist_table ADD FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
ROLLBACK;
DROP TABLE dist_table CASCADE;
DROP TABLE reference_table CASCADE;
-- test ADD FOREIGN KEY from citus local to reference table
SELECT 1 FROM master_add_node('localhost', :master_port, groupId => 0);
CREATE TABLE citus_local_table(l1 int);
SELECT citus_add_local_table_to_metadata('citus_local_table');
CREATE TABLE reference_table(r1 int primary key); SELECT create_reference_table('reference_table');
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1);
-- test ADD FOREIGN KEY from citus local to reference table with supported options
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE CASCADE;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE SET NULL;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE SET DEFAULT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE NO ACTION;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON UPDATE RESTRICT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE CASCADE;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE SET NULL;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE SET DEFAULT;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE NO ACTION;
ALTER TABLE citus_local_table ADD FOREIGN KEY(l1) REFERENCES reference_table(r1) ON DELETE RESTRICT;
DROP TABLE citus_local_table CASCADE;
SELECT 1 FROM master_remove_node('localhost', :master_port);
RESET SEARCH_PATH;
RESET client_min_messages;
DROP SCHEMA at_add_fk CASCADE;