mirror of https://github.com/citusdata/citus.git
FK from dist to ref can be added with alter table
parent
58486fd1b9
commit
2fa4e38841
|
@ -34,12 +34,16 @@
|
|||
* environment.
|
||||
*
|
||||
* To support foreign constraints, we require that;
|
||||
* - Referencing and referenced tables are hash distributed.
|
||||
* - If referencing and referenced tables are hash-distributed
|
||||
* - Referencing and referenced tables are co-located.
|
||||
* - Foreign constraint is defined over distribution column.
|
||||
* - ON DELETE/UPDATE SET NULL, ON DELETE/UPDATE SET DEFAULT and ON UPDATE CASCADE options
|
||||
* are not used.
|
||||
* - Replication factors of referencing and referenced table are 1.
|
||||
* - If referenced table is a reference table
|
||||
* - ON DELETE/UPDATE SET NULL, ON DELETE/UPDATE SET DEFAULT and ON UPDATE CASCADE options
|
||||
* are not used on the distribution key of the referencing column.
|
||||
* - If referencing table is a reference table, error out
|
||||
*/
|
||||
void
|
||||
ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
||||
|
@ -66,6 +70,8 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
|||
int attrIdx = 0;
|
||||
bool foreignConstraintOnPartitionColumn = false;
|
||||
bool selfReferencingTable = false;
|
||||
bool referencedTableIsAReferenceTable = false;
|
||||
bool referencingColumnsIncludeDistKey = false;
|
||||
|
||||
pgConstraint = heap_open(ConstraintRelationId, AccessShareLock);
|
||||
ScanKeyInit(&scanKey[0], Anum_pg_constraint_conrelid, BTEqualStrategyNumber, F_OIDEQ,
|
||||
|
@ -85,55 +91,26 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
|||
continue;
|
||||
}
|
||||
|
||||
/*
|
||||
* We should make this check in this loop because the error message will only
|
||||
* be given if the table has a foreign constraint and the table is a reference
|
||||
* table.
|
||||
*/
|
||||
if (distributionMethod == DISTRIBUTE_BY_NONE)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint because "
|
||||
"reference tables are not supported as the "
|
||||
"referencing table of a foreign constraint"),
|
||||
errdetail("Reference tables are only supported as the "
|
||||
"referenced table of a foreign key when the "
|
||||
"referencing table is a hash distributed "
|
||||
"table")));
|
||||
}
|
||||
|
||||
referencedTableId = constraintForm->confrelid;
|
||||
selfReferencingTable = referencingTableId == referencedTableId;
|
||||
|
||||
/*
|
||||
* We do not support foreign keys for reference tables. Here we skip the second
|
||||
* part of check if the table is a self referencing table because;
|
||||
* - PartitionMethod only works for distributed tables and this table may not be
|
||||
* distributed yet.
|
||||
* - Since referencing and referenced tables are same, it is OK to not checking
|
||||
* distribution method twice.
|
||||
*/
|
||||
if (distributionMethod == DISTRIBUTE_BY_NONE ||
|
||||
(!selfReferencingTable &&
|
||||
PartitionMethod(referencedTableId) == DISTRIBUTE_BY_NONE))
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint from or to "
|
||||
"reference tables")));
|
||||
}
|
||||
|
||||
/*
|
||||
* ON DELETE SET NULL and ON DELETE SET DEFAULT is not supported. Because we do
|
||||
* not want to set partition column to NULL or default value.
|
||||
*/
|
||||
if (constraintForm->confdeltype == FKCONSTR_ACTION_SETNULL ||
|
||||
constraintForm->confdeltype == FKCONSTR_ACTION_SETDEFAULT)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("SET NULL or SET DEFAULT is not supported"
|
||||
" in ON DELETE operation.")));
|
||||
}
|
||||
|
||||
/*
|
||||
* ON UPDATE SET NULL, ON UPDATE SET DEFAULT and UPDATE CASCADE is not supported.
|
||||
* Because we do not want to set partition column to NULL or default value. Also
|
||||
* cascading update operation would require re-partitioning. Updating partition
|
||||
* column value is not allowed anyway even outside of foreign key concept.
|
||||
*/
|
||||
if (constraintForm->confupdtype == FKCONSTR_ACTION_SETNULL ||
|
||||
constraintForm->confupdtype == FKCONSTR_ACTION_SETDEFAULT ||
|
||||
constraintForm->confupdtype == FKCONSTR_ACTION_CASCADE)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("SET NULL, SET DEFAULT or CASCADE is not"
|
||||
" supported in ON UPDATE operation.")));
|
||||
}
|
||||
|
||||
/*
|
||||
* Some checks are not meaningful if foreign key references the table itself.
|
||||
* Therefore we will skip those checks.
|
||||
|
@ -148,28 +125,43 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
|||
"table.")));
|
||||
}
|
||||
|
||||
/* to enforce foreign constraints, tables must be co-located */
|
||||
referencedTableColocationId = TableColocationId(referencedTableId);
|
||||
if (colocationId == INVALID_COLOCATION_ID ||
|
||||
colocationId != referencedTableColocationId)
|
||||
/*
|
||||
* PartitionMethod errors out when it is called for non-distributed
|
||||
* tables. This is why we make this check under !selfReferencingTable
|
||||
* and after !IsDistributedTable(referencedTableId).
|
||||
*/
|
||||
if (PartitionMethod(referencedTableId) == DISTRIBUTE_BY_NONE)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("Foreign key constraint can only be created"
|
||||
" on co-located tables.")));
|
||||
referencedTableIsAReferenceTable = true;
|
||||
}
|
||||
|
||||
/*
|
||||
* Partition column must exist in both referencing and referenced side of the
|
||||
* foreign key constraint. They also must be in same ordinal.
|
||||
* To enforce foreign constraints, tables must be co-located unless a
|
||||
* reference table is referenced.
|
||||
*/
|
||||
referencedTableColocationId = TableColocationId(referencedTableId);
|
||||
if (colocationId == INVALID_COLOCATION_ID ||
|
||||
(colocationId != referencedTableColocationId &&
|
||||
!referencedTableIsAReferenceTable))
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint since "
|
||||
"relations are not colocated or not referencing "
|
||||
"a reference table"),
|
||||
errdetail(
|
||||
"A distributed table can only have foreign keys "
|
||||
"if it is referencing another colocated hash "
|
||||
"distributed table or a reference table")));
|
||||
}
|
||||
|
||||
referencedTablePartitionColumn = DistPartitionKey(referencedTableId);
|
||||
}
|
||||
else
|
||||
{
|
||||
/*
|
||||
* Partition column must exist in both referencing and referenced side of the
|
||||
* foreign key constraint. They also must be in same ordinal.
|
||||
* If the referenced table is not a reference table, the distribution
|
||||
* column in referencing table should be the distribution column in
|
||||
* referenced table as well.
|
||||
*/
|
||||
referencedTablePartitionColumn = distributionColumn;
|
||||
}
|
||||
|
@ -198,28 +190,83 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
|||
AttrNumber referencedAttrNo = DatumGetInt16(referencedColumnArray[attrIdx]);
|
||||
|
||||
if (distributionColumn->varattno == referencingAttrNo &&
|
||||
referencedTablePartitionColumn->varattno == referencedAttrNo)
|
||||
(!referencedTableIsAReferenceTable &&
|
||||
referencedTablePartitionColumn->varattno == referencedAttrNo))
|
||||
{
|
||||
foreignConstraintOnPartitionColumn = true;
|
||||
}
|
||||
|
||||
if (distributionColumn->varattno == referencingAttrNo)
|
||||
{
|
||||
referencingColumnsIncludeDistKey = true;
|
||||
}
|
||||
}
|
||||
|
||||
if (!foreignConstraintOnPartitionColumn)
|
||||
|
||||
/*
|
||||
* If columns in the foreign key includes the distribution key from the
|
||||
* referencing side, we do not allow update/delete operations through
|
||||
* foreign key constraints (e.g. ... ON UPDATE SET NULL)
|
||||
*/
|
||||
|
||||
if (referencingColumnsIncludeDistKey)
|
||||
{
|
||||
/*
|
||||
* ON DELETE SET NULL and ON DELETE SET DEFAULT is not supported. Because we do
|
||||
* not want to set partition column to NULL or default value.
|
||||
*/
|
||||
if (constraintForm->confdeltype == FKCONSTR_ACTION_SETNULL ||
|
||||
constraintForm->confdeltype == FKCONSTR_ACTION_SETDEFAULT)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("Partition column must exist both "
|
||||
"referencing and referenced side of the "
|
||||
"foreign constraint statement and it must "
|
||||
"be in the same ordinal in both sides.")));
|
||||
errdetail("SET NULL or SET DEFAULT is not supported"
|
||||
" in ON DELETE operation when distribution "
|
||||
"key is included in the foreign key constraint")));
|
||||
}
|
||||
|
||||
/*
|
||||
* ON UPDATE SET NULL, ON UPDATE SET DEFAULT and UPDATE CASCADE is not supported.
|
||||
* Because we do not want to set partition column to NULL or default value. Also
|
||||
* cascading update operation would require re-partitioning. Updating partition
|
||||
* column value is not allowed anyway even outside of foreign key concept.
|
||||
*/
|
||||
if (constraintForm->confupdtype == FKCONSTR_ACTION_SETNULL ||
|
||||
constraintForm->confupdtype == FKCONSTR_ACTION_SETDEFAULT ||
|
||||
constraintForm->confupdtype == FKCONSTR_ACTION_CASCADE)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("SET NULL, SET DEFAULT or CASCADE is not "
|
||||
"supported in ON UPDATE operation when "
|
||||
"distribution key included in the foreign "
|
||||
"constraint.")));
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
* if tables are hash-distributed and colocated, we need to make sure that
|
||||
* the distribution key is included in foreign constraint.
|
||||
*/
|
||||
if (!referencedTableIsAReferenceTable && !foreignConstraintOnPartitionColumn)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot create foreign key constraint"),
|
||||
errdetail("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")));
|
||||
}
|
||||
|
||||
/*
|
||||
* We do not allow to create foreign constraints if shard replication factor is
|
||||
* greater than 1. Because in our current design, multiple replicas may cause
|
||||
* locking problems and inconsistent shard contents. We don't check the referenced
|
||||
* table, since referenced and referencing tables should be co-located and
|
||||
* colocation check has been done above.
|
||||
* locking problems and inconsistent shard contents.
|
||||
*
|
||||
* Note that we allow referenced table to be a reference table (e.g., not a
|
||||
* single replicated table). This is allowed since (a) we are sure that
|
||||
* placements always be in the same state (b) executors are aware of reference
|
||||
* tables and handle concurrency related issues accordingly.
|
||||
*/
|
||||
if (IsDistributedTable(referencingTableId))
|
||||
{
|
||||
|
@ -231,6 +278,8 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
|
|||
}
|
||||
else
|
||||
{
|
||||
Assert(distributionMethod == DISTRIBUTE_BY_HASH);
|
||||
|
||||
/* check whether creating single replicated table with foreign constraint */
|
||||
if (ShardReplicationFactor > 1)
|
||||
{
|
||||
|
|
|
@ -1380,6 +1380,17 @@ PlanAlterTableStmt(AlterTableStmt *alterTableStatement, const char *alterTableCo
|
|||
/* if foreign key related, use specialized task list function ... */
|
||||
ddlJob->taskList = InterShardDDLTaskList(leftRelationId, rightRelationId,
|
||||
alterTableCommand);
|
||||
|
||||
/*
|
||||
* We need to execute the ddls working with reference tables on the
|
||||
* right side sequentially, because parallel ddl operations
|
||||
* relating to one and only shard of a reference table on a worker
|
||||
* may cause self-deadlocks.
|
||||
*/
|
||||
if (PartitionMethod(rightRelationId) == DISTRIBUTE_BY_NONE)
|
||||
{
|
||||
ddlJob->executeSequentially = true;
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
|
@ -2885,13 +2896,14 @@ ExecuteDistributedDDLJob(DDLJob *ddlJob)
|
|||
SendCommandToWorkers(WORKERS_WITH_METADATA, (char *) ddlJob->commandString);
|
||||
}
|
||||
|
||||
if (MultiShardConnectionType == PARALLEL_CONNECTION)
|
||||
if (MultiShardConnectionType == SEQUENTIAL_CONNECTION ||
|
||||
ddlJob->executeSequentially)
|
||||
{
|
||||
ExecuteModifyTasksWithoutResults(ddlJob->taskList);
|
||||
ExecuteModifyTasksSequentiallyWithoutResults(ddlJob->taskList, CMD_UTILITY);
|
||||
}
|
||||
else
|
||||
{
|
||||
ExecuteModifyTasksSequentiallyWithoutResults(ddlJob->taskList, CMD_UTILITY);
|
||||
ExecuteModifyTasksWithoutResults(ddlJob->taskList);
|
||||
}
|
||||
}
|
||||
else
|
||||
|
@ -3102,6 +3114,7 @@ InterShardDDLTaskList(Oid leftRelationId, Oid rightRelationId,
|
|||
char *leftSchemaName = get_namespace_name(leftSchemaId);
|
||||
char *escapedLeftSchemaName = quote_literal_cstr(leftSchemaName);
|
||||
|
||||
char rightPartitionMethod = PartitionMethod(rightRelationId);
|
||||
List *rightShardList = LoadShardIntervalList(rightRelationId);
|
||||
ListCell *rightShardCell = NULL;
|
||||
Oid rightSchemaId = get_rel_namespace(rightRelationId);
|
||||
|
@ -3112,6 +3125,29 @@ InterShardDDLTaskList(Oid leftRelationId, Oid rightRelationId,
|
|||
uint64 jobId = INVALID_JOB_ID;
|
||||
int taskId = 1;
|
||||
|
||||
/*
|
||||
* If the rightPartitionMethod is a reference table, we need to make sure
|
||||
* that the tasks are created in a way that the right shard stays the same
|
||||
* since we only have one placement per worker. This hack is first implemented
|
||||
* for foreign constraint support from distributed tables to reference tables.
|
||||
*/
|
||||
if (rightPartitionMethod == DISTRIBUTE_BY_NONE)
|
||||
{
|
||||
ShardInterval *rightShardInterval = NULL;
|
||||
int rightShardCount = list_length(rightShardList);
|
||||
int leftShardCount = list_length(leftShardList);
|
||||
int shardCounter = 0;
|
||||
|
||||
Assert(rightShardCount == 1);
|
||||
|
||||
rightShardInterval = (ShardInterval *) linitial(rightShardList);
|
||||
for (shardCounter = rightShardCount; shardCounter < leftShardCount;
|
||||
shardCounter++)
|
||||
{
|
||||
rightShardList = lappend(rightShardList, rightShardInterval);
|
||||
}
|
||||
}
|
||||
|
||||
/* lock metadata before getting placement lists */
|
||||
LockShardListMetadata(leftShardList, ShareLock);
|
||||
|
||||
|
|
|
@ -25,6 +25,7 @@ typedef struct DDLJob
|
|||
{
|
||||
Oid targetRelationId; /* oid of the target distributed relation */
|
||||
bool concurrentIndexCmd; /* related to a CONCURRENTLY index command? */
|
||||
bool executeSequentially;
|
||||
const char *commandString; /* initial (coordinator) DDL command string */
|
||||
List *taskList; /* worker DDL tasks to execute */
|
||||
} DDLJob;
|
||||
|
|
|
@ -0,0 +1,991 @@
|
|||
--
|
||||
-- FOREIGN_KEY_TO_REFERENCE_TABLE
|
||||
--
|
||||
CREATE SCHEMA fkey_reference_table;
|
||||
SET search_path TO 'fkey_reference_table';
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SET citus.shard_count TO 8;
|
||||
SET citus.next_shard_id TO 7000000;
|
||||
CREATE TYPE foreign_details AS (name text, relid text, refd_relid text);
|
||||
SELECT run_command_on_workers($$CREATE TYPE foreign_details AS (name text, relid text, refd_relid text)$$);
|
||||
run_command_on_workers
|
||||
-----------------------------------
|
||||
(localhost,57637,t,"CREATE TYPE")
|
||||
(localhost,57638,t,"CREATE TYPE")
|
||||
(2 rows)
|
||||
|
||||
CREATE VIEW table_fkeys_in_workers AS
|
||||
SELECT
|
||||
(json_populate_record(NULL::foreign_details,
|
||||
json_array_elements_text((run_command_on_workers( $$
|
||||
SELECT
|
||||
COALESCE(json_agg(row_to_json(d)), '[]'::json)
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
distinct name,
|
||||
relid::regclass::text,
|
||||
refd_relid::regclass::text
|
||||
FROM
|
||||
table_fkey_cols
|
||||
)
|
||||
d $$ )).RESULT::json )::json )).* ;
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- we still do not support update/delete operations through foreign constraints if the foreign key includes the distribution column
|
||||
-- All should fail
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref 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
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref 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
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref 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.
|
||||
DROP TABLE referencing_table;
|
||||
-- try with multiple columns including the distribution column
|
||||
DROP TABLE referenced_table;
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id, test_column));
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column) 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.
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column) 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.
|
||||
DROP TABLE referencing_table;
|
||||
-- all of the above is supported if the foreign key does not include distribution column
|
||||
DROP TABLE referenced_table;
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id));
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON DELETE SET NULL;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------------------+------------------------------------------------+-----------------------------------------------
|
||||
fkey_ref_7000043 | fkey_reference_table.referencing_table_7000043 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000044 | fkey_reference_table.referencing_table_7000044 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000045 | fkey_reference_table.referencing_table_7000045 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000046 | fkey_reference_table.referencing_table_7000046 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000047 | fkey_reference_table.referencing_table_7000047 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000048 | fkey_reference_table.referencing_table_7000048 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000049 | fkey_reference_table.referencing_table_7000049 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000050 | fkey_reference_table.referencing_table_7000050 | fkey_reference_table.referenced_table_7000042
|
||||
(8 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------------------+------------------------------------------------+-----------------------------------------------
|
||||
fkey_ref_7000051 | fkey_reference_table.referencing_table_7000051 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000052 | fkey_reference_table.referencing_table_7000052 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000053 | fkey_reference_table.referencing_table_7000053 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000054 | fkey_reference_table.referencing_table_7000054 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000055 | fkey_reference_table.referencing_table_7000055 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000056 | fkey_reference_table.referencing_table_7000056 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000057 | fkey_reference_table.referencing_table_7000057 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000058 | fkey_reference_table.referencing_table_7000058 | fkey_reference_table.referenced_table_7000042
|
||||
(8 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE SET NULL;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------------------+------------------------------------------------+-----------------------------------------------
|
||||
fkey_ref_7000059 | fkey_reference_table.referencing_table_7000059 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000060 | fkey_reference_table.referencing_table_7000060 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000061 | fkey_reference_table.referencing_table_7000061 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000062 | fkey_reference_table.referencing_table_7000062 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000063 | fkey_reference_table.referencing_table_7000063 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000064 | fkey_reference_table.referencing_table_7000064 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000065 | fkey_reference_table.referencing_table_7000065 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000066 | fkey_reference_table.referencing_table_7000066 | fkey_reference_table.referenced_table_7000042
|
||||
(8 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE SET DEFAULT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------------------+------------------------------------------------+-----------------------------------------------
|
||||
fkey_ref_7000067 | fkey_reference_table.referencing_table_7000067 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000068 | fkey_reference_table.referencing_table_7000068 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000069 | fkey_reference_table.referencing_table_7000069 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000070 | fkey_reference_table.referencing_table_7000070 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000071 | fkey_reference_table.referencing_table_7000071 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000072 | fkey_reference_table.referencing_table_7000072 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000073 | fkey_reference_table.referencing_table_7000073 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000074 | fkey_reference_table.referencing_table_7000074 | fkey_reference_table.referenced_table_7000042
|
||||
(8 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------------------+------------------------------------------------+-----------------------------------------------
|
||||
fkey_ref_7000075 | fkey_reference_table.referencing_table_7000075 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000076 | fkey_reference_table.referencing_table_7000076 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000077 | fkey_reference_table.referencing_table_7000077 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000078 | fkey_reference_table.referencing_table_7000078 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000079 | fkey_reference_table.referencing_table_7000079 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000080 | fkey_reference_table.referencing_table_7000080 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000081 | fkey_reference_table.referencing_table_7000081 | fkey_reference_table.referenced_table_7000042
|
||||
fkey_ref_7000082 | fkey_reference_table.referencing_table_7000082 | fkey_reference_table.referenced_table_7000042
|
||||
(8 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
-- foreign keys are only supported when the 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');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(id);
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Citus Community Edition 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.
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------+-------+------------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
-- foreign keys are supported either in between distributed tables including the
|
||||
-- distribution column or from distributed tables to reference tables.
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'append');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref 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
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------+-------+------------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'range');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref 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
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
------+-------+------------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
-- test foreign constraint with correct conditions
|
||||
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_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(id);
|
||||
-- test inserts
|
||||
-- test insert to referencing table while there is NO corresponding value in referenced table
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
ERROR: insert or update on table "referencing_table_7000092" violates foreign key constraint "fkey_ref_7000092"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_7000091".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- test insert to referencing while there is corresponding value in referenced table
|
||||
INSERT INTO referenced_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
INSERT INTO referencing_table SELECT x, x from generate_series(1,500) as f(x);
|
||||
-- test deletes
|
||||
-- test delete from referenced table while there is corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id > 3;
|
||||
ERROR: update or delete on table "referenced_table_7000091" violates foreign key constraint "fkey_ref_7000094" on table "referencing_table_7000094"
|
||||
DETAIL: Key (id)=(4) is still referenced from table "referencing_table_7000094".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- test delete from referenced table while there is NO corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id = 501;
|
||||
-- test cascading truncate
|
||||
-- will fail for now
|
||||
TRUNCATE referenced_table CASCADE;
|
||||
NOTICE: truncate cascades to table "referencing_table"
|
||||
ERROR: canceling the transaction since it was involved in a distributed deadlock
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
500
|
||||
(1 row)
|
||||
|
||||
-- drop table for next tests
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
-- self referencing foreign key on reference tables are not allowed
|
||||
-- TODO try create_reference_table with already created foreign key.
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_reference_table('referencing_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
-- self referencing foreign key
|
||||
ALTER TABLE referenced_table ADD CONSTRAINT fkey_ref FOREIGN KEY (test_column) REFERENCES referenced_table(id);
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- foreign Keys from reference table to reference table are not allowed
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
DROP TABLE referenced_table;
|
||||
DROP TABLE referencing_table;
|
||||
-- cascades on delete with different schemas
|
||||
CREATE SCHEMA referenced_schema;
|
||||
CREATE SCHEMA referencing_schema;
|
||||
CREATE TABLE referenced_schema.referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
CREATE TABLE referencing_schema.referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_schema.referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_schema.referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_schema.referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_schema.referenced_table(id) ON DELETE CASCADE;
|
||||
INSERT INTO referenced_schema.referenced_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
INSERT INTO referencing_schema.referencing_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
DELETE FROM referenced_schema.referenced_table WHERE id > 800;
|
||||
SELECT count(*) FROM referencing_schema.referencing_table;
|
||||
count
|
||||
-------
|
||||
800
|
||||
(1 row)
|
||||
|
||||
DROP SCHEMA referenced_schema CASCADE;
|
||||
NOTICE: drop cascades to 2 other objects
|
||||
DETAIL: drop cascades to table referenced_schema.referenced_table
|
||||
drop cascades to constraint fkey_ref on table referencing_schema.referencing_table
|
||||
DROP SCHEMA referencing_schema CASCADE;
|
||||
NOTICE: drop cascades to table referencing_schema.referencing_table
|
||||
-- on delete set update cascades properly
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT 1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT;
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
DELETE FROM referenced_table WHERE test_column > 800;
|
||||
SELECT count(*) FROM referencing_table WHERE ref_id = 1;
|
||||
count
|
||||
-------
|
||||
201
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
-- foreign key as composite key
|
||||
CREATE TYPE fkey_reference_table.composite AS (key1 int, key2 int);
|
||||
SELECT run_command_on_workers($$CREATE TYPE fkey_reference_table.composite AS (key1 int, key2 int)$$) ORDER BY 1;
|
||||
run_command_on_workers
|
||||
-----------------------------------
|
||||
(localhost,57637,t,"CREATE TYPE")
|
||||
(localhost,57638,t,"CREATE TYPE")
|
||||
(2 rows)
|
||||
|
||||
CREATE TABLE referenced_table(test_column composite, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, referencing_composite composite);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (referencing_composite) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
INSERT INTO referenced_table SELECT (x+1, x+1)::composite FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, (x+1, x+1)::composite FROM generate_series(1,1000) AS f(x);
|
||||
DELETE FROM referenced_table WHERE (test_column).key1 > 900;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
899
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we'll use a SERIAL column as the referenced column
|
||||
-- in the foreign constraint. We'll first show that and insert on non-serial
|
||||
-- column successfully inserts into the serial and referenced column.
|
||||
-- Accordingly, the inserts into the referencing table which references to the
|
||||
-- serial column will be successful.
|
||||
CREATE TABLE referenced_table(test_column SERIAL PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
INSERT INTO referenced_table(test_column2) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
DELETE FROM referenced_table WHERE test_column2 > 10;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we'll use a SERIAL column as the referencing column
|
||||
-- in the foreign constraint. We'll first show that the values that exist
|
||||
-- in the referenced tables are successfully generated by the serial column
|
||||
-- and inserted to the distributed table. However, if the values that are generated
|
||||
-- by serial column do not exist on the referenced table, the query fails.
|
||||
CREATE TABLE referenced_table(test_column int PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id SERIAL);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
INSERT INTO referenced_table SELECT x,x FROM generate_series(1,1000) AS f(x);
|
||||
-- Success for existing inserts
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Fails for non existing value inserts (serial is already incremented)
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,10) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000144" violates foreign key constraint "fkey_ref_7000144"
|
||||
DETAIL: Key (ref_id)=(1006) is not present in table "referenced_table_7000138".
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we'll use a SERIAL column as the referencing column
|
||||
-- and referenced columns in a foreign constraint. We'll first show that the
|
||||
-- the inserts into referenced column will successfully generate and insert
|
||||
-- data into serial column. Then, we will be successfully insert the same amount
|
||||
-- of data into referencing table. However, if the values that are generated
|
||||
-- by serial column do not exist on the referenced table, the query fails.
|
||||
CREATE TABLE referenced_table(test_column SERIAL PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id SERIAL);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
INSERT INTO referenced_table(test_column2) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Success for existing values
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Fails for non existing value inserts (serial is already incremented)
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,10) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000151" violates foreign key constraint "fkey_ref_7000151"
|
||||
DETAIL: Key (ref_id)=(1003) is not present in table "referenced_table_7000147".
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we use a volatile function in the referencing
|
||||
-- column in a foreign constraint. We show that if the data exists in the
|
||||
-- referenced table, we can successfully use volatile functions with
|
||||
-- foreign constraints.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT;
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x,(random()*1000)::int FROM generate_series(0,1000) AS f(x);
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we show that Citus currently does not support
|
||||
-- VALIDATE command.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT NOT VALID;
|
||||
-- Even if the foreign constraint is added with "NOT VALID",
|
||||
-- we make sure that it is still applied to the upcoming inserts.
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
-- we expect this to fail because of the foreign constraint.
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1000,1001) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000171" violates foreign key constraint "fkey_ref_7000171"
|
||||
DETAIL: Key (ref_id)=(1001) is not present in table "referenced_table_7000165".
|
||||
-- currently not supported
|
||||
ALTER TABLE referencing_table VALIDATE CONSTRAINT fkey_ref;
|
||||
ERROR: alter table command is currently unsupported
|
||||
DETAIL: Only ADD|DROP COLUMN, SET|DROP NOT NULL, SET|DROP DEFAULT, ADD|DROP CONSTRAINT, SET (), RESET (), ATTACH|DETACH PARTITION and TYPE subcommands are supported.
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following tests, we create a foreign constraint with
|
||||
-- ON UPDATE CASCADE and see if it works properly with cascading upsert
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON UPDATE CASCADE;
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referenced_table VALUES (1,2), (2,3), (3,4), (4,5)
|
||||
ON CONFLICT (test_column)
|
||||
DO UPDATE
|
||||
SET test_column = -1 * EXCLUDED.test_column;
|
||||
SELECT * FROM referencing_table WHERE ref_id < 0 ORDER BY 1;
|
||||
id | ref_id
|
||||
----+--------
|
||||
1 | -1
|
||||
2 | -2
|
||||
3 | -3
|
||||
4 | -4
|
||||
(4 rows)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- Chained references
|
||||
-- In the following test, we create foreign keys from one column in a distributed
|
||||
-- table to two reference tables. We expect to see that even if a data exist in
|
||||
-- one reference table, it is not going to be inserted in to referencing table
|
||||
-- because of lack of the key in the other table. Data can only be inserted into
|
||||
-- referencing table if it exists in both referenced tables.
|
||||
-- Additionally, delete or update in one referenced table should cascade properly.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referenced_table2(test_column int, test_column2 int, PRIMARY KEY(test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_reference_table('referenced_table2');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT foreign_key_2 FOREIGN KEY (id) REFERENCES referenced_table2(test_column2) ON DELETE CASCADE;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
-----------------------+------------------------------------------------+------------------------------------------------
|
||||
fkey_ref_7000185 | fkey_reference_table.referencing_table_7000185 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000186 | fkey_reference_table.referencing_table_7000186 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000187 | fkey_reference_table.referencing_table_7000187 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000188 | fkey_reference_table.referencing_table_7000188 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000189 | fkey_reference_table.referencing_table_7000189 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000190 | fkey_reference_table.referencing_table_7000190 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000191 | fkey_reference_table.referencing_table_7000191 | fkey_reference_table.referenced_table_7000183
|
||||
fkey_ref_7000192 | fkey_reference_table.referencing_table_7000192 | fkey_reference_table.referenced_table_7000183
|
||||
foreign_key_2_7000185 | fkey_reference_table.referencing_table_7000185 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000186 | fkey_reference_table.referencing_table_7000186 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000187 | fkey_reference_table.referencing_table_7000187 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000188 | fkey_reference_table.referencing_table_7000188 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000189 | fkey_reference_table.referencing_table_7000189 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000190 | fkey_reference_table.referencing_table_7000190 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000191 | fkey_reference_table.referencing_table_7000191 | fkey_reference_table.referenced_table2_7000184
|
||||
foreign_key_2_7000192 | fkey_reference_table.referencing_table_7000192 | fkey_reference_table.referenced_table2_7000184
|
||||
(16 rows)
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referenced_table2 SELECT x, x+1 FROM generate_series(500,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,1500) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000192" violates foreign key constraint "foreign_key_2_7000192"
|
||||
DETAIL: Key (id)=(9) is not present in table "referenced_table2_7000184".
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000192" violates foreign key constraint "foreign_key_2_7000192"
|
||||
DETAIL: Key (id)=(9) is not present in table "referenced_table2_7000184".
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(1000,1400) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000192" violates foreign key constraint "fkey_ref_7000192"
|
||||
DETAIL: Key (id)=(1023) is not present in table "referenced_table_7000183".
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(600,900) AS f(x);
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
301
|
||||
(1 row)
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column < 700;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
201
|
||||
(1 row)
|
||||
|
||||
DELETE FROM referenced_table2 WHERE test_column2 > 800;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
101
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referenced_table2 CASCADE;
|
||||
NOTICE: drop cascades to constraint foreign_key_2 on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we create foreign keys from two columns in a distributed
|
||||
-- table to two reference tables separately. We expect to see that even if a data
|
||||
-- exist in one reference table for one column, it is not going to be inserted in
|
||||
-- to referencing table because the other constraint doesn't hold. Data can only
|
||||
-- be inserted into referencing table if both columns exist in respective columns
|
||||
-- in referenced tables.
|
||||
-- Additionally, delete or update in one referenced table should cascade properly.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referenced_table2(test_column int, test_column2 int, PRIMARY KEY(test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_reference_table('referenced_table2');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
BEGIN;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT foreign_key_2 FOREIGN KEY (ref_id) REFERENCES referenced_table2(test_column2) ON DELETE CASCADE;
|
||||
COMMIT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
-----------------------+------------------------------------------------+------------------------------------------------
|
||||
fkey_ref_7000195 | fkey_reference_table.referencing_table_7000195 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000196 | fkey_reference_table.referencing_table_7000196 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000197 | fkey_reference_table.referencing_table_7000197 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000198 | fkey_reference_table.referencing_table_7000198 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000199 | fkey_reference_table.referencing_table_7000199 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000200 | fkey_reference_table.referencing_table_7000200 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000201 | fkey_reference_table.referencing_table_7000201 | fkey_reference_table.referenced_table_7000193
|
||||
fkey_ref_7000202 | fkey_reference_table.referencing_table_7000202 | fkey_reference_table.referenced_table_7000193
|
||||
foreign_key_2_7000195 | fkey_reference_table.referencing_table_7000195 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000196 | fkey_reference_table.referencing_table_7000196 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000197 | fkey_reference_table.referencing_table_7000197 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000198 | fkey_reference_table.referencing_table_7000198 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000199 | fkey_reference_table.referencing_table_7000199 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000200 | fkey_reference_table.referencing_table_7000200 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000201 | fkey_reference_table.referencing_table_7000201 | fkey_reference_table.referenced_table2_7000194
|
||||
foreign_key_2_7000202 | fkey_reference_table.referencing_table_7000202 | fkey_reference_table.referenced_table2_7000194
|
||||
(16 rows)
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referenced_table2 SELECT x, x+1 FROM generate_series(500,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,1500) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000197" violates foreign key constraint "foreign_key_2_7000197"
|
||||
DETAIL: Key (ref_id)=(5) is not present in table "referenced_table2_7000194".
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000197" violates foreign key constraint "foreign_key_2_7000197"
|
||||
DETAIL: Key (ref_id)=(5) is not present in table "referenced_table2_7000194".
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(1000,1400) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table_7000197" violates foreign key constraint "fkey_ref_7000197"
|
||||
DETAIL: Key (id)=(1015) is not present in table "referenced_table_7000193".
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+501 FROM generate_series(0,1000) AS f(x);
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
1001
|
||||
(1 row)
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column < 700;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
301
|
||||
(1 row)
|
||||
|
||||
DELETE FROM referenced_table2 WHERE test_column2 > 800;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referenced_table2 CASCADE;
|
||||
NOTICE: drop cascades to constraint foreign_key_2 on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- two distributed tables are referencing to one reference table and
|
||||
-- in the same time the distributed table 2 is referencing to
|
||||
-- distributed table 1. Thus, we have a triangular
|
||||
-- distributed table 1 has a foreign key from the distribution column to reference table
|
||||
-- distributed table 2 has a foreign key from a non-distribution column to reference table
|
||||
-- distributed table 2 has a foreign key to distributed table 1 on the distribution column
|
||||
-- We show that inserts into distributed table 2 will fail if the data does not exist in distributed table 1
|
||||
-- Delete from reference table cascades to both of the distributed tables properly
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int UNIQUE, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int PRIMARY KEY, ref_id int);
|
||||
CREATE TABLE referencing_table2(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table2', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
BEGIN;
|
||||
SET LOCAL citus.multi_shard_modify_mode TO 'sequential';
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table2 ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column2) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table2 ADD CONSTRAINT fkey_ref_to_dist FOREIGN KEY (id) REFERENCES referencing_table(id) ON DELETE CASCADE;
|
||||
COMMIT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
--------------------------+-------------------------------------------------+------------------------------------------------
|
||||
fkey_ref_7000204 | fkey_reference_table.referencing_table_7000204 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000205 | fkey_reference_table.referencing_table_7000205 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000206 | fkey_reference_table.referencing_table_7000206 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000207 | fkey_reference_table.referencing_table_7000207 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000208 | fkey_reference_table.referencing_table_7000208 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000209 | fkey_reference_table.referencing_table_7000209 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000210 | fkey_reference_table.referencing_table_7000210 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000211 | fkey_reference_table.referencing_table_7000211 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000212 | fkey_reference_table.referencing_table2_7000212 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000213 | fkey_reference_table.referencing_table2_7000213 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000214 | fkey_reference_table.referencing_table2_7000214 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000215 | fkey_reference_table.referencing_table2_7000215 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000216 | fkey_reference_table.referencing_table2_7000216 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000217 | fkey_reference_table.referencing_table2_7000217 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000218 | fkey_reference_table.referencing_table2_7000218 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_7000219 | fkey_reference_table.referencing_table2_7000219 | fkey_reference_table.referenced_table_7000203
|
||||
fkey_ref_to_dist_7000212 | fkey_reference_table.referencing_table2_7000212 | fkey_reference_table.referencing_table_7000204
|
||||
fkey_ref_to_dist_7000213 | fkey_reference_table.referencing_table2_7000213 | fkey_reference_table.referencing_table_7000205
|
||||
fkey_ref_to_dist_7000214 | fkey_reference_table.referencing_table2_7000214 | fkey_reference_table.referencing_table_7000206
|
||||
fkey_ref_to_dist_7000215 | fkey_reference_table.referencing_table2_7000215 | fkey_reference_table.referencing_table_7000207
|
||||
fkey_ref_to_dist_7000216 | fkey_reference_table.referencing_table2_7000216 | fkey_reference_table.referencing_table_7000208
|
||||
fkey_ref_to_dist_7000217 | fkey_reference_table.referencing_table2_7000217 | fkey_reference_table.referencing_table_7000209
|
||||
fkey_ref_to_dist_7000218 | fkey_reference_table.referencing_table2_7000218 | fkey_reference_table.referencing_table_7000210
|
||||
fkey_ref_to_dist_7000219 | fkey_reference_table.referencing_table2_7000219 | fkey_reference_table.referencing_table_7000211
|
||||
(24 rows)
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(0,100) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table2_7000215" violates foreign key constraint "fkey_ref_to_dist_7000215"
|
||||
DETAIL: Key (id)=(0) is not present in table "referencing_table_7000207".
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(200,500) AS f(x);
|
||||
ERROR: insert or update on table "referencing_table2_7000215" violates foreign key constraint "fkey_ref_to_dist_7000215"
|
||||
DETAIL: Key (id)=(407) is not present in table "referencing_table_7000207".
|
||||
-- should success
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(0,300) AS f(x);
|
||||
DELETE FROM referenced_table WHERE test_column < 200;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
count
|
||||
-------
|
||||
201
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM referencing_table2;
|
||||
count
|
||||
-------
|
||||
101
|
||||
(1 row)
|
||||
|
||||
DELETE FROM referencing_table WHERE id > 200;
|
||||
SELECT count(*) FROM referencing_table2;
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to 2 other objects
|
||||
DETAIL: drop cascades to constraint fkey_ref on table referencing_table2
|
||||
drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref_to_dist on table referencing_table2
|
||||
DROP TABLE referencing_table2 CASCADE;
|
||||
-- In this test we have a chained relationship in form of
|
||||
-- distributed table (referencing_referencing_table) has a foreign key with two columns
|
||||
-- to another distributed table (referencing_table)
|
||||
-- referencing_table has another foreign key with 2 columns to referenced_table.
|
||||
-- We will show that a cascading delete on referenced_table reaches to referencing_referencing_table.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column, test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int, ref_id2 int, PRIMARY KEY(id, ref_id));
|
||||
CREATE TABLE referencing_referencing_table(id int, ref_id int, FOREIGN KEY (id, ref_id) REFERENCES referencing_table(id, ref_id) ON DELETE CASCADE);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
create_reference_table
|
||||
------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT create_distributed_table('referencing_referencing_table', 'id');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id, ref_id2) REFERENCES referenced_table(test_column, test_column2) ON DELETE CASCADE;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.referencing%' ORDER BY 1,2,3;
|
||||
name | relid | refd_relid
|
||||
-----------------------------------------------+------------------------------------------------------------+------------------------------------------------
|
||||
fkey_ref_7000221 | fkey_reference_table.referencing_table_7000221 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000222 | fkey_reference_table.referencing_table_7000222 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000223 | fkey_reference_table.referencing_table_7000223 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000224 | fkey_reference_table.referencing_table_7000224 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000225 | fkey_reference_table.referencing_table_7000225 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000226 | fkey_reference_table.referencing_table_7000226 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000227 | fkey_reference_table.referencing_table_7000227 | fkey_reference_table.referenced_table_7000220
|
||||
fkey_ref_7000228 | fkey_reference_table.referencing_table_7000228 | fkey_reference_table.referenced_table_7000220
|
||||
referencing_referencing_table_id_fkey_7000229 | fkey_reference_table.referencing_referencing_table_7000229 | fkey_reference_table.referencing_table_7000221
|
||||
referencing_referencing_table_id_fkey_7000230 | fkey_reference_table.referencing_referencing_table_7000230 | fkey_reference_table.referencing_table_7000222
|
||||
referencing_referencing_table_id_fkey_7000231 | fkey_reference_table.referencing_referencing_table_7000231 | fkey_reference_table.referencing_table_7000223
|
||||
referencing_referencing_table_id_fkey_7000232 | fkey_reference_table.referencing_referencing_table_7000232 | fkey_reference_table.referencing_table_7000224
|
||||
referencing_referencing_table_id_fkey_7000233 | fkey_reference_table.referencing_referencing_table_7000233 | fkey_reference_table.referencing_table_7000225
|
||||
referencing_referencing_table_id_fkey_7000234 | fkey_reference_table.referencing_referencing_table_7000234 | fkey_reference_table.referencing_table_7000226
|
||||
referencing_referencing_table_id_fkey_7000235 | fkey_reference_table.referencing_referencing_table_7000235 | fkey_reference_table.referencing_table_7000227
|
||||
referencing_referencing_table_id_fkey_7000236 | fkey_reference_table.referencing_referencing_table_7000236 | fkey_reference_table.referencing_table_7000228
|
||||
(16 rows)
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x+1, x+2 FROM generate_series(1,999) AS f(x);
|
||||
INSERT INTO referencing_referencing_table SELECT x, x+1 FROM generate_series(1,999) AS f(x);
|
||||
DELETE FROM referenced_table WHERE test_column > 800;
|
||||
SELECT max(ref_id) FROM referencing_referencing_table;
|
||||
max
|
||||
-----
|
||||
800
|
||||
(1 row)
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fkey_ref on table referencing_table
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
NOTICE: drop cascades to constraint referencing_referencing_table_id_fkey on table referencing_referencing_table
|
||||
DROP TABLE referencing_referencing_table;
|
||||
DROP SCHEMA fkey_reference_table CASCADE;
|
||||
NOTICE: drop cascades to 3 other objects
|
||||
DETAIL: drop cascades to type foreign_details
|
||||
drop cascades to view table_fkeys_in_workers
|
||||
drop cascades to type composite
|
||||
SET search_path TO DEFAULT;
|
|
@ -16,47 +16,66 @@ SELECT create_distributed_table('referenced_table', 'id', 'hash');
|
|||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET NULL);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation.
|
||||
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation when distribution key is included in the foreign key constraint
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation.
|
||||
DETAIL: SET NULL or SET DEFAULT is not supported in ON DELETE operation when distribution key is included in the foreign key constraint
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET NULL);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation.
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET DEFAULT);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation.
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
|
||||
DROP TABLE referencing_table;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE CASCADE);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation.
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
|
||||
DROP TABLE referencing_table;
|
||||
-- self referencing table with replication factor > 1
|
||||
CREATE TABLE self_referencing_table(id int, ref_id int, PRIMARY KEY (id, ref_id), FOREIGN KEY(id,ref_id) REFERENCES self_referencing_table(id, ref_id));
|
||||
SELECT create_distributed_table('self_referencing_table', 'id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Citus Community Edition 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;
|
||||
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 CONSTRAINT fkey FOREIGN KEY(id,ref_id) REFERENCES self_referencing_table(id, ref_id);
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Citus Community Edition 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_count TO 8;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Foreign key constraint can only be created on co-located tables.
|
||||
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;
|
||||
SET citus.shard_count TO 32;
|
||||
-- test foreign constraint creation on non-partition columns
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Partition column must exist both referencing and referenced side of the foreign constraint statement and it must be in the same ordinal in both sides.
|
||||
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, FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column));
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Partition column must exist both referencing and referenced side of the foreign constraint statement and it must be in the same ordinal in both sides.
|
||||
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
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id));
|
||||
|
@ -66,9 +85,38 @@ DETAIL: Citus Community Edition currently supports foreign key constraints only
|
|||
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 referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
-- test foreign constraint with correct conditions
|
||||
-- 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, FOREIGN KEY (id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'id', 'append');
|
||||
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,FOREIGN KEY (id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'id', 'range');
|
||||
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 with correct conditions
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referenced_table', 'id', 'hash');
|
||||
create_distributed_table
|
||||
|
@ -85,8 +133,8 @@ SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
|||
-- test inserts
|
||||
-- test insert to referencing table while there is NO corresponding value in referenced table
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
ERROR: insert or update on table "referencing_table_1350065" violates foreign key constraint "referencing_table_ref_id_fkey_1350065"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350033".
|
||||
ERROR: insert or update on table "referencing_table_1350129" violates foreign key constraint "referencing_table_ref_id_fkey_1350129"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350097".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
-- test insert to referencing while there is corresponding value in referenced table
|
||||
INSERT INTO referenced_table VALUES(1, 1);
|
||||
|
@ -94,8 +142,8 @@ INSERT INTO referencing_table VALUES(1, 1);
|
|||
-- test deletes
|
||||
-- test delete from referenced table while there is corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350033" violates foreign key constraint "referencing_table_ref_id_fkey_1350065" on table "referencing_table_1350065"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350065".
|
||||
ERROR: update or delete on table "referenced_table_1350097" violates foreign key constraint "referencing_table_ref_id_fkey_1350129" on table "referencing_table_1350129"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350129".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
-- test delete from referenced table while there is NO corresponding value in referencing table
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
|
@ -189,8 +237,8 @@ SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
|||
INSERT INTO referenced_table VALUES(1, 1);
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350161" violates foreign key constraint "referencing_table_ref_id_fkey_1350193" on table "referencing_table_1350193"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350193".
|
||||
ERROR: update or delete on table "referenced_table_1350225" violates foreign key constraint "referencing_table_ref_id_fkey_1350257" on table "referencing_table_1350257"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350257".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
BEGIN;
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
|
@ -227,8 +275,8 @@ INSERT INTO referenced_table VALUES(1, 1);
|
|||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
BEGIN;
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350225" violates foreign key constraint "referencing_table_ref_id_fkey_1350257" on table "referencing_table_1350257"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350257".
|
||||
ERROR: update or delete on table "referenced_table_1350289" violates foreign key constraint "referencing_table_ref_id_fkey_1350321" on table "referencing_table_1350321"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350321".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block
|
||||
|
@ -265,8 +313,8 @@ SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
|||
INSERT INTO referenced_table VALUES(1, 1);
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
UPDATE referenced_table SET test_column = 10 WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350289" violates foreign key constraint "referencing_table_ref_id_fkey_1350321" on table "referencing_table_1350321"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350321".
|
||||
ERROR: update or delete on table "referenced_table_1350353" violates foreign key constraint "referencing_table_ref_id_fkey_1350385" on table "referencing_table_1350385"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350385".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
BEGIN;
|
||||
UPDATE referenced_table SET test_column = 10 WHERE id = 1;
|
||||
|
@ -305,8 +353,8 @@ INSERT INTO referenced_table VALUES(1, 1);
|
|||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
BEGIN;
|
||||
UPDATE referenced_table SET test_column = 20 WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350353" violates foreign key constraint "referencing_table_ref_id_fkey_1350385" on table "referencing_table_1350385"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350385".
|
||||
ERROR: update or delete on table "referenced_table_1350417" violates foreign key constraint "referencing_table_ref_id_fkey_1350449" on table "referencing_table_1350449"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350449".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
UPDATE referencing_table SET id = 20 WHERE ref_id = 1;
|
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block
|
||||
|
@ -366,7 +414,7 @@ SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
|||
(1 row)
|
||||
|
||||
INSERT INTO referencing_table VALUES(null, 2);
|
||||
ERROR: insert or update on table "referencing_table_1350536" violates foreign key constraint "referencing_table_ref_id_fkey_1350536"
|
||||
ERROR: insert or update on table "referencing_table_1350600" violates foreign key constraint "referencing_table_ref_id_fkey_1350600"
|
||||
DETAIL: MATCH FULL does not allow mixing of null and nonnull key values.
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
SELECT * FROM referencing_table;
|
||||
|
@ -378,29 +426,18 @@ DROP TABLE referencing_table;
|
|||
DROP TABLE referenced_table;
|
||||
-- Similar tests, but this time we push foreign key constraints created by ALTER TABLE queries
|
||||
-- create tables
|
||||
SET citus.shard_count TO 4;
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
SELECT master_create_distributed_table('referenced_table', 'id', 'hash');
|
||||
master_create_distributed_table
|
||||
---------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT master_create_worker_shards('referenced_table', 4, 1);
|
||||
master_create_worker_shards
|
||||
-----------------------------
|
||||
SELECT create_distributed_table('referenced_table', 'id', 'hash');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT master_create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
master_create_distributed_table
|
||||
---------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT master_create_worker_shards('referencing_table', 4, 1);
|
||||
master_create_worker_shards
|
||||
-----------------------------
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
|
@ -415,19 +452,19 @@ ABORT;
|
|||
-- test foreign constraint creation with not supported parameters
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint 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.
|
||||
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 CONSTRAINT test_constraint 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.
|
||||
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 CONSTRAINT test_constraint 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.
|
||||
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 CONSTRAINT test_constraint 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.
|
||||
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 CONSTRAINT test_constraint 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.
|
||||
DETAIL: SET NULL, SET DEFAULT or CASCADE is not supported in ON UPDATE operation when distribution key included in the foreign constraint.
|
||||
-- test foreign constraint creation with multiple subcommands
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id),
|
||||
ADD CONSTRAINT test_constraint FOREIGN KEY(id) REFERENCES referenced_table(test_column);
|
||||
|
@ -437,9 +474,25 @@ HINT: You can issue each subcommand separately
|
|||
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;
|
||||
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', 'ref_id', 'hash', colocate_with => 'none');
|
||||
create_distributed_table
|
||||
--------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Foreign key constraint can only be created on co-located tables.
|
||||
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
|
||||
-- create co-located tables
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
@ -463,38 +516,38 @@ ERROR: number of referencing and referenced columns for foreign key disagree
|
|||
-- test foreign constraint creation on non-partition columns
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(id) REFERENCES referenced_table(id);
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Partition column must exist both referencing and referenced side of the foreign constraint statement and it must be in the same ordinal in both sides.
|
||||
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
|
||||
-- test foreign constraint creation while column list are in incorrect order
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column);
|
||||
ERROR: cannot create foreign key constraint
|
||||
DETAIL: Partition column must exist both referencing and referenced side of the foreign constraint statement and it must be in the same ordinal in both sides.
|
||||
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
|
||||
-- test foreign constraint creation while column list are not in same length
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id, test_column);
|
||||
ERROR: number of referencing and referenced columns for foreign key disagree
|
||||
-- test foreign constraint creation while existing tables does not satisfy the constraint
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
|
||||
ERROR: insert or update on table "referencing_table_1350585" violates foreign key constraint "test_constraint_1350585"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350553".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: insert or update on table "referencing_table_1350628" violates foreign key constraint "test_constraint_1350628"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350624".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- test foreign constraint with correct conditions
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
|
||||
-- test inserts
|
||||
-- test insert to referencing table while there is NO corresponding value in referenced table
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
ERROR: insert or update on table "referencing_table_1350585" violates foreign key constraint "test_constraint_1350585"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350553".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: insert or update on table "referencing_table_1350628" violates foreign key constraint "test_constraint_1350628"
|
||||
DETAIL: Key (ref_id)=(1) is not present in table "referenced_table_1350624".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- test insert to referencing while there is corresponding value in referenced table
|
||||
INSERT INTO referenced_table VALUES(1, 1);
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
-- test deletes
|
||||
-- test delete from referenced table while there is corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350553" violates foreign key constraint "test_constraint_1350585" on table "referencing_table_1350585"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350585".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: update or delete on table "referenced_table_1350624" violates foreign key constraint "test_constraint_1350628" on table "referencing_table_1350628"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350628".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- test delete from referenced table while there is NO corresponding value in referencing table
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
|
@ -522,9 +575,9 @@ ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id)
|
|||
INSERT INTO referenced_table VALUES(1, 1);
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350553" violates foreign key constraint "test_constraint_1350585" on table "referencing_table_1350585"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350585".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: update or delete on table "referenced_table_1350624" violates foreign key constraint "test_constraint_1350628" on table "referencing_table_1350628"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350628".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
BEGIN;
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
|
@ -546,9 +599,9 @@ INSERT INTO referenced_table VALUES(1, 1);
|
|||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
BEGIN;
|
||||
DELETE FROM referenced_table WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350553" violates foreign key constraint "test_constraint_1350585" on table "referencing_table_1350585"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350585".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: update or delete on table "referenced_table_1350624" violates foreign key constraint "test_constraint_1350628" on table "referencing_table_1350628"
|
||||
DETAIL: Key (id)=(1) is still referenced from table "referencing_table_1350628".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
DELETE FROM referencing_table WHERE ref_id = 1;
|
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block
|
||||
COMMIT;
|
||||
|
@ -568,9 +621,9 @@ ALTER TABLE referencing_table DROP CONSTRAINT test_constraint;
|
|||
-- test ON UPDATE NO ACTION + DEFERABLE + INITIALLY DEFERRED
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE NO ACTION DEFERRABLE INITIALLY DEFERRED;
|
||||
UPDATE referenced_table SET test_column = 10 WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350553" violates foreign key constraint "test_constraint_1350585" on table "referencing_table_1350585"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350585".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: update or delete on table "referenced_table_1350624" violates foreign key constraint "test_constraint_1350628" on table "referencing_table_1350628"
|
||||
DETAIL: Key (id, test_column)=(1, 1) is still referenced from table "referencing_table_1350628".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
BEGIN;
|
||||
UPDATE referenced_table SET test_column = 10 WHERE id = 1;
|
||||
UPDATE referencing_table SET id = 10 WHERE ref_id = 1;
|
||||
|
@ -592,9 +645,9 @@ ALTER TABLE referencing_table DROP CONSTRAINT test_constraint;
|
|||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) ON UPDATE RESTRICT;
|
||||
BEGIN;
|
||||
UPDATE referenced_table SET test_column = 20 WHERE id = 1;
|
||||
ERROR: update or delete on table "referenced_table_1350553" violates foreign key constraint "test_constraint_1350585" on table "referencing_table_1350585"
|
||||
DETAIL: Key (id, test_column)=(1, 10) is still referenced from table "referencing_table_1350585".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: update or delete on table "referenced_table_1350624" violates foreign key constraint "test_constraint_1350628" on table "referencing_table_1350628"
|
||||
DETAIL: Key (id, test_column)=(1, 10) is still referenced from table "referencing_table_1350628".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
UPDATE referencing_table SET id = 20 WHERE ref_id = 1;
|
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block
|
||||
COMMIT;
|
||||
|
@ -626,9 +679,9 @@ ALTER TABLE referencing_table DROP CONSTRAINT test_constraint;
|
|||
-- test MATCH FULL
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id, id) REFERENCES referenced_table(id, test_column) MATCH FULL;
|
||||
INSERT INTO referencing_table VALUES(null, 2);
|
||||
ERROR: insert or update on table "referencing_table_1350608" violates foreign key constraint "test_constraint_1350608"
|
||||
ERROR: insert or update on table "referencing_table_1350631" violates foreign key constraint "test_constraint_1350631"
|
||||
DETAIL: MATCH FULL does not allow mixing of null and nonnull key values.
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
SELECT * FROM referencing_table;
|
||||
id | ref_id
|
||||
----+--------
|
||||
|
@ -658,9 +711,9 @@ ALTER TABLE cyclic_reference_table1 ADD CONSTRAINT cyclic_constraint1 FOREIGN KE
|
|||
ALTER TABLE cyclic_reference_table2 ADD CONSTRAINT cyclic_constraint2 FOREIGN KEY(id, table1_id) REFERENCES cyclic_reference_table1(table2_id, id) DEFERRABLE INITIALLY DEFERRED;
|
||||
-- test insertion to a table which has cyclic foreign constraints, we expect that to fail
|
||||
INSERT INTO cyclic_reference_table1 VALUES(1, 1);
|
||||
ERROR: insert or update on table "cyclic_reference_table1_1350617" violates foreign key constraint "cyclic_constraint1_1350617"
|
||||
DETAIL: Key (id, table2_id)=(1, 1) is not present in table "cyclic_reference_table2_1350649".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: insert or update on table "cyclic_reference_table1_1350632" violates foreign key constraint "cyclic_constraint1_1350632"
|
||||
DETAIL: Key (id, table2_id)=(1, 1) is not present in table "cyclic_reference_table2_1350636".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- proper insertion to table with cyclic dependency
|
||||
BEGIN;
|
||||
INSERT INTO cyclic_reference_table1 VALUES(1, 1);
|
||||
|
@ -740,9 +793,9 @@ SELECT create_distributed_table('self_referencing_table1', 'id', 'hash');
|
|||
INSERT INTO self_referencing_table1 VALUES(1, 1, 1);
|
||||
-- we expect this query to fail
|
||||
INSERT INTO self_referencing_table1 VALUES(1, 2, 3);
|
||||
ERROR: insert or update on table "self_referencing_table1_1350681" violates foreign key constraint "self_referencing_table1_id_fkey_1350681"
|
||||
DETAIL: Key (id, other_column_ref)=(1, 3) is not present in table "self_referencing_table1_1350681".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: insert or update on table "self_referencing_table1_1350640" violates foreign key constraint "self_referencing_table1_id_fkey_1350640"
|
||||
DETAIL: Key (id, other_column_ref)=(1, 3) is not present in table "self_referencing_table1_1350640".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- verify that rows are actually inserted
|
||||
SELECT * FROM self_referencing_table1;
|
||||
id | other_column | other_column_ref
|
||||
|
@ -765,9 +818,9 @@ ALTER TABLE self_referencing_table2 ADD CONSTRAINT self_referencing_fk_constrain
|
|||
INSERT INTO self_referencing_table2 VALUES(1, 1, 1);
|
||||
-- we expect this query to fail
|
||||
INSERT INTO self_referencing_table2 VALUES(1, 2, 3);
|
||||
ERROR: insert or update on table "self_referencing_table2_1350713" violates foreign key constraint "self_referencing_fk_constraint_1350713"
|
||||
DETAIL: Key (id, other_column_ref)=(1, 3) is not present in table "self_referencing_table2_1350713".
|
||||
CONTEXT: while executing command on localhost:57638
|
||||
ERROR: insert or update on table "self_referencing_table2_1350644" violates foreign key constraint "self_referencing_fk_constraint_1350644"
|
||||
DETAIL: Key (id, other_column_ref)=(1, 3) is not present in table "self_referencing_table2_1350644".
|
||||
CONTEXT: while executing command on localhost:57637
|
||||
-- verify that rows are actually inserted
|
||||
SELECT * FROM self_referencing_table2;
|
||||
id | other_column | other_column_ref
|
||||
|
@ -788,8 +841,9 @@ SELECT create_distributed_table('referenced_by_reference_table', 'id');
|
|||
|
||||
CREATE TABLE reference_table(id int, referencing_column int REFERENCES referenced_by_reference_table(id));
|
||||
SELECT create_reference_table('reference_table');
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
-- test foreign key creation on CREATE TABLE to reference table
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on CREATE TABLE from + to reference table
|
||||
DROP TABLE reference_table;
|
||||
CREATE TABLE reference_table(id int PRIMARY KEY, referencing_column int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
|
@ -798,22 +852,18 @@ SELECT create_reference_table('reference_table');
|
|||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE references_to_reference_table(id int, referencing_column int REFERENCES reference_table(id));
|
||||
SELECT create_distributed_table('references_to_reference_table', 'referencing_column');
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
-- test foreign key creation on CREATE TABLE from + to reference table
|
||||
CREATE TABLE reference_table_second(id int, referencing_column int REFERENCES reference_table(id));
|
||||
SELECT create_reference_table('reference_table_second');
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on CREATE TABLE from reference table to local table
|
||||
CREATE TABLE referenced_local_table(id int PRIMARY KEY, other_column int);
|
||||
DROP TABLE reference_table CASCADE;
|
||||
NOTICE: drop cascades to 2 other objects
|
||||
DETAIL: drop cascades to constraint references_to_reference_table_referencing_column_fkey on table references_to_reference_table
|
||||
drop cascades to constraint reference_table_second_referencing_column_fkey on table reference_table_second
|
||||
NOTICE: drop cascades to constraint reference_table_second_referencing_column_fkey on table reference_table_second
|
||||
CREATE TABLE reference_table(id int, referencing_column int REFERENCES referenced_local_table(id));
|
||||
SELECT create_reference_table('reference_table');
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on CREATE TABLE on self referencing reference table
|
||||
CREATE TABLE self_referencing_reference_table(
|
||||
id int,
|
||||
|
@ -823,7 +873,8 @@ CREATE TABLE self_referencing_reference_table(
|
|||
FOREIGN KEY(id, other_column_ref) REFERENCES self_referencing_reference_table(id, other_column)
|
||||
);
|
||||
SELECT create_reference_table('self_referencing_reference_table');
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on ALTER TABLE from reference table
|
||||
DROP TABLE reference_table;
|
||||
CREATE TABLE reference_table(id int PRIMARY KEY, referencing_column int);
|
||||
|
@ -834,9 +885,9 @@ SELECT create_reference_table('reference_table');
|
|||
(1 row)
|
||||
|
||||
ALTER TABLE reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES referenced_by_reference_table(id);
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on ALTER TABLE to reference table
|
||||
DROP TABLE references_to_reference_table;
|
||||
CREATE TABLE references_to_reference_table(id int, referencing_column int);
|
||||
SELECT create_distributed_table('references_to_reference_table', 'referencing_column');
|
||||
create_distributed_table
|
||||
|
@ -845,7 +896,6 @@ SELECT create_distributed_table('references_to_reference_table', 'referencing_co
|
|||
(1 row)
|
||||
|
||||
ALTER TABLE references_to_reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
-- test foreign key creation on ALTER TABLE from + to reference table
|
||||
DROP TABLE reference_table_second;
|
||||
CREATE TABLE reference_table_second(id int, referencing_column int);
|
||||
|
@ -856,9 +906,11 @@ SELECT create_reference_table('reference_table_second');
|
|||
(1 row)
|
||||
|
||||
ALTER TABLE reference_table_second ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- test foreign key creation on ALTER TABLE from reference table to local table
|
||||
DROP TABLE reference_table;
|
||||
DROP TABLE reference_table CASCADE;
|
||||
NOTICE: drop cascades to constraint fk on table references_to_reference_table
|
||||
CREATE TABLE reference_table(id int PRIMARY KEY, referencing_column int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
create_reference_table
|
||||
|
@ -883,6 +935,7 @@ SELECT create_reference_table('self_referencing_reference_table');
|
|||
(1 row)
|
||||
|
||||
ALTER TABLE self_referencing_reference_table ADD CONSTRAINT fk FOREIGN KEY(id, other_column_ref) REFERENCES self_referencing_reference_table(id, other_column);
|
||||
ERROR: cannot create foreign key constraint from or to reference tables
|
||||
ERROR: cannot create foreign key constraint because reference tables are not supported as the referencing table of a foreign constraint
|
||||
DETAIL: Reference tables are only supported as the referenced table of a foreign key when the referencing table is a hash distributed table
|
||||
-- we no longer need those tables
|
||||
DROP TABLE referenced_by_reference_table, references_to_reference_table, reference_table, reference_table_second, referenced_local_table, self_referencing_reference_table;
|
||||
|
|
|
@ -164,7 +164,7 @@ test: multi_modifications
|
|||
test: multi_distribution_metadata
|
||||
test: multi_generate_ddl_commands multi_create_shards multi_prune_shard_list multi_repair_shards
|
||||
test: multi_upsert multi_simple_queries multi_create_insert_proxy multi_data_types
|
||||
test: multi_utilities
|
||||
test: multi_utilities foreign_key_to_reference_table
|
||||
test: multi_modifying_xacts
|
||||
test: multi_repartition_udt multi_repartitioned_subquery_udf multi_subtransactions
|
||||
test: multi_transaction_recovery
|
||||
|
|
|
@ -0,0 +1,498 @@
|
|||
--
|
||||
-- FOREIGN_KEY_TO_REFERENCE_TABLE
|
||||
--
|
||||
|
||||
CREATE SCHEMA fkey_reference_table;
|
||||
SET search_path TO 'fkey_reference_table';
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SET citus.shard_count TO 8;
|
||||
SET citus.next_shard_id TO 7000000;
|
||||
|
||||
CREATE TYPE foreign_details AS (name text, relid text, refd_relid text);
|
||||
SELECT run_command_on_workers($$CREATE TYPE foreign_details AS (name text, relid text, refd_relid text)$$);
|
||||
|
||||
CREATE VIEW table_fkeys_in_workers AS
|
||||
SELECT
|
||||
(json_populate_record(NULL::foreign_details,
|
||||
json_array_elements_text((run_command_on_workers( $$
|
||||
SELECT
|
||||
COALESCE(json_agg(row_to_json(d)), '[]'::json)
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
distinct name,
|
||||
relid::regclass::text,
|
||||
refd_relid::regclass::text
|
||||
FROM
|
||||
table_fkey_cols
|
||||
)
|
||||
d $$ )).RESULT::json )::json )).* ;
|
||||
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
|
||||
-- we still do not support update/delete operations through foreign constraints if the foreign key includes the distribution column
|
||||
-- All should fail
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET NULL;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(ref_id) REFERENCES referenced_table(id) ON UPDATE SET NULL;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
-- try with multiple columns including the distribution column
|
||||
DROP TABLE referenced_table;
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id, test_column));
|
||||
SELECT create_reference_table('referenced_table');
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column) ON UPDATE SET DEFAULT;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id, ref_id) REFERENCES referenced_table(id, test_column) ON UPDATE CASCADE;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
-- all of the above is supported if the foreign key does not include distribution column
|
||||
DROP TABLE referenced_table;
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id));
|
||||
SELECT create_reference_table('referenced_table');
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON DELETE SET NULL;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON DELETE SET DEFAULT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE SET NULL;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE SET DEFAULT;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
-- foreign keys are only supported when the 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');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(id);
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
|
||||
-- foreign keys are supported either in between distributed tables including the
|
||||
-- distribution column or from distributed tables to reference tables.
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'append');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(id);
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'range');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(id);
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
||||
-- test foreign constraint with correct conditions
|
||||
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_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(id);
|
||||
|
||||
|
||||
-- test inserts
|
||||
-- test insert to referencing table while there is NO corresponding value in referenced table
|
||||
INSERT INTO referencing_table VALUES(1, 1);
|
||||
|
||||
-- test insert to referencing while there is corresponding value in referenced table
|
||||
INSERT INTO referenced_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
INSERT INTO referencing_table SELECT x, x from generate_series(1,500) as f(x);
|
||||
|
||||
|
||||
-- test deletes
|
||||
-- test delete from referenced table while there is corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id > 3;
|
||||
|
||||
-- test delete from referenced table while there is NO corresponding value in referencing table
|
||||
DELETE FROM referenced_table WHERE id = 501;
|
||||
|
||||
-- test cascading truncate
|
||||
-- will fail for now
|
||||
TRUNCATE referenced_table CASCADE;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
|
||||
-- drop table for next tests
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
||||
-- self referencing foreign key on reference tables are not allowed
|
||||
-- TODO try create_reference_table with already created foreign key.
|
||||
CREATE TABLE referenced_table(id int, test_column int, PRIMARY KEY(id));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_reference_table('referencing_table');
|
||||
-- self referencing foreign key
|
||||
ALTER TABLE referenced_table ADD CONSTRAINT fkey_ref FOREIGN KEY (test_column) REFERENCES referenced_table(id);
|
||||
-- foreign Keys from reference table to reference table are not allowed
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY(id) REFERENCES referenced_table(id) ON UPDATE CASCADE;
|
||||
|
||||
DROP TABLE referenced_table;
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
-- cascades on delete with different schemas
|
||||
CREATE SCHEMA referenced_schema;
|
||||
CREATE SCHEMA referencing_schema;
|
||||
CREATE TABLE referenced_schema.referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
CREATE TABLE referencing_schema.referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_schema.referenced_table');
|
||||
SELECT create_distributed_table('referencing_schema.referencing_table', 'id');
|
||||
ALTER TABLE referencing_schema.referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_schema.referenced_table(id) ON DELETE CASCADE;
|
||||
|
||||
INSERT INTO referenced_schema.referenced_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
INSERT INTO referencing_schema.referencing_table SELECT x, x from generate_series(1,1000) as f(x);
|
||||
|
||||
DELETE FROM referenced_schema.referenced_table WHERE id > 800;
|
||||
SELECT count(*) FROM referencing_schema.referencing_table;
|
||||
|
||||
DROP SCHEMA referenced_schema CASCADE;
|
||||
DROP SCHEMA referencing_schema CASCADE;
|
||||
|
||||
-- on delete set update cascades properly
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT 1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column > 800;
|
||||
SELECT count(*) FROM referencing_table WHERE ref_id = 1;
|
||||
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
||||
-- foreign key as composite key
|
||||
CREATE TYPE fkey_reference_table.composite AS (key1 int, key2 int);
|
||||
SELECT run_command_on_workers($$CREATE TYPE fkey_reference_table.composite AS (key1 int, key2 int)$$) ORDER BY 1;
|
||||
|
||||
CREATE TABLE referenced_table(test_column composite, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, referencing_composite composite);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (referencing_composite) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
|
||||
INSERT INTO referenced_table SELECT (x+1, x+1)::composite FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, (x+1, x+1)::composite FROM generate_series(1,1000) AS f(x);
|
||||
|
||||
DELETE FROM referenced_table WHERE (test_column).key1 > 900;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
-- In the following test, we'll use a SERIAL column as the referenced column
|
||||
-- in the foreign constraint. We'll first show that and insert on non-serial
|
||||
-- column successfully inserts into the serial and referenced column.
|
||||
-- Accordingly, the inserts into the referencing table which references to the
|
||||
-- serial column will be successful.
|
||||
CREATE TABLE referenced_table(test_column SERIAL PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
|
||||
INSERT INTO referenced_table(test_column2) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1,1000) AS f(x);
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column2 > 10;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
-- In the following test, we'll use a SERIAL column as the referencing column
|
||||
-- in the foreign constraint. We'll first show that the values that exist
|
||||
-- in the referenced tables are successfully generated by the serial column
|
||||
-- and inserted to the distributed table. However, if the values that are generated
|
||||
-- by serial column do not exist on the referenced table, the query fails.
|
||||
CREATE TABLE referenced_table(test_column int PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id SERIAL);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
|
||||
INSERT INTO referenced_table SELECT x,x FROM generate_series(1,1000) AS f(x);
|
||||
-- Success for existing inserts
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Fails for non existing value inserts (serial is already incremented)
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,10) AS f(x);
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
-- In the following test, we'll use a SERIAL column as the referencing column
|
||||
-- and referenced columns in a foreign constraint. We'll first show that the
|
||||
-- the inserts into referenced column will successfully generate and insert
|
||||
-- data into serial column. Then, we will be successfully insert the same amount
|
||||
-- of data into referencing table. However, if the values that are generated
|
||||
-- by serial column do not exist on the referenced table, the query fails.
|
||||
CREATE TABLE referenced_table(test_column SERIAL PRIMARY KEY, test_column2 int);
|
||||
CREATE TABLE referencing_table(id int, ref_id SERIAL);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
|
||||
INSERT INTO referenced_table(test_column2) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Success for existing values
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,1000) AS f(x);
|
||||
-- Fails for non existing value inserts (serial is already incremented)
|
||||
INSERT INTO referencing_table(id) SELECT x FROM generate_series(1,10) AS f(x);
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
-- In the following test, we use a volatile function in the referencing
|
||||
-- column in a foreign constraint. We show that if the data exists in the
|
||||
-- referenced table, we can successfully use volatile functions with
|
||||
-- foreign constraints.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x,(random()*1000)::int FROM generate_series(0,1000) AS f(x);
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
-- In the following test, we show that Citus currently does not support
|
||||
-- VALIDATE command.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON DELETE SET DEFAULT NOT VALID;
|
||||
|
||||
-- Even if the foreign constraint is added with "NOT VALID",
|
||||
-- we make sure that it is still applied to the upcoming inserts.
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
-- we expect this to fail because of the foreign constraint.
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(1000,1001) AS f(x);
|
||||
|
||||
-- currently not supported
|
||||
ALTER TABLE referencing_table VALIDATE CONSTRAINT fkey_ref;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
-- In the following tests, we create a foreign constraint with
|
||||
-- ON UPDATE CASCADE and see if it works properly with cascading upsert
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int DEFAULT -1);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column) ON UPDATE CASCADE;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x FROM generate_series(0,1000) AS f(x);
|
||||
|
||||
INSERT INTO referenced_table VALUES (1,2), (2,3), (3,4), (4,5)
|
||||
ON CONFLICT (test_column)
|
||||
DO UPDATE
|
||||
SET test_column = -1 * EXCLUDED.test_column;
|
||||
|
||||
SELECT * FROM referencing_table WHERE ref_id < 0 ORDER BY 1;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
|
||||
-- Chained references
|
||||
-- In the following test, we create foreign keys from one column in a distributed
|
||||
-- table to two reference tables. We expect to see that even if a data exist in
|
||||
-- one reference table, it is not going to be inserted in to referencing table
|
||||
-- because of lack of the key in the other table. Data can only be inserted into
|
||||
-- referencing table if it exists in both referenced tables.
|
||||
-- Additionally, delete or update in one referenced table should cascade properly.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referenced_table2(test_column int, test_column2 int, PRIMARY KEY(test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_reference_table('referenced_table2');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT foreign_key_2 FOREIGN KEY (id) REFERENCES referenced_table2(test_column2) ON DELETE CASCADE;
|
||||
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referenced_table2 SELECT x, x+1 FROM generate_series(500,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(1000,1400) AS f(x);
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(600,900) AS f(x);
|
||||
|
||||
SELECT count(*) FROM referencing_table;
|
||||
DELETE FROM referenced_table WHERE test_column < 700;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
DELETE FROM referenced_table2 WHERE test_column2 > 800;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referenced_table2 CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
|
||||
-- In the following test, we create foreign keys from two columns in a distributed
|
||||
-- table to two reference tables separately. We expect to see that even if a data
|
||||
-- exist in one reference table for one column, it is not going to be inserted in
|
||||
-- to referencing table because the other constraint doesn't hold. Data can only
|
||||
-- be inserted into referencing table if both columns exist in respective columns
|
||||
-- in referenced tables.
|
||||
-- Additionally, delete or update in one referenced table should cascade properly.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referenced_table2(test_column int, test_column2 int, PRIMARY KEY(test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_reference_table('referenced_table2');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
|
||||
BEGIN;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT foreign_key_2 FOREIGN KEY (ref_id) REFERENCES referenced_table2(test_column2) ON DELETE CASCADE;
|
||||
COMMIT;
|
||||
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%' ORDER BY 1,2,3;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
INSERT INTO referenced_table2 SELECT x, x+1 FROM generate_series(500,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,1500) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(1000,1400) AS f(x);
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+501 FROM generate_series(0,1000) AS f(x);
|
||||
|
||||
SELECT count(*) FROM referencing_table;
|
||||
DELETE FROM referenced_table WHERE test_column < 700;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
DELETE FROM referenced_table2 WHERE test_column2 > 800;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referenced_table2 CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
|
||||
|
||||
-- two distributed tables are referencing to one reference table and
|
||||
-- in the same time the distributed table 2 is referencing to
|
||||
-- distributed table 1. Thus, we have a triangular
|
||||
-- distributed table 1 has a foreign key from the distribution column to reference table
|
||||
-- distributed table 2 has a foreign key from a non-distribution column to reference table
|
||||
-- distributed table 2 has a foreign key to distributed table 1 on the distribution column
|
||||
-- We show that inserts into distributed table 2 will fail if the data does not exist in distributed table 1
|
||||
-- Delete from reference table cascades to both of the distributed tables properly
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int UNIQUE, PRIMARY KEY(test_column));
|
||||
CREATE TABLE referencing_table(id int PRIMARY KEY, ref_id int);
|
||||
CREATE TABLE referencing_table2(id int, ref_id int);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
SELECT create_distributed_table('referencing_table2', 'id');
|
||||
BEGIN;
|
||||
SET LOCAL citus.multi_shard_modify_mode TO 'sequential';
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (id) REFERENCES referenced_table(test_column) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table2 ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id) REFERENCES referenced_table(test_column2) ON DELETE CASCADE;
|
||||
ALTER TABLE referencing_table2 ADD CONSTRAINT fkey_ref_to_dist FOREIGN KEY (id) REFERENCES referencing_table(id) ON DELETE CASCADE;
|
||||
COMMIT;
|
||||
|
||||
SELECT * FROM table_fkeys_in_workers WHERE name LIKE 'fkey_ref%' ORDER BY 1,2,3;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(0,1000) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(0,100) AS f(x);
|
||||
-- should success
|
||||
INSERT INTO referencing_table SELECT x, x+1 FROM generate_series(0,400) AS f(x);
|
||||
-- should fail
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(200,500) AS f(x);
|
||||
-- should success
|
||||
INSERT INTO referencing_table2 SELECT x, x+1 FROM generate_series(0,300) AS f(x);
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column < 200;
|
||||
SELECT count(*) FROM referencing_table;
|
||||
SELECT count(*) FROM referencing_table2;
|
||||
DELETE FROM referencing_table WHERE id > 200;
|
||||
SELECT count(*) FROM referencing_table2;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
DROP TABLE referencing_table2 CASCADE;
|
||||
|
||||
|
||||
-- In this test we have a chained relationship in form of
|
||||
-- distributed table (referencing_referencing_table) has a foreign key with two columns
|
||||
-- to another distributed table (referencing_table)
|
||||
-- referencing_table has another foreign key with 2 columns to referenced_table.
|
||||
-- We will show that a cascading delete on referenced_table reaches to referencing_referencing_table.
|
||||
CREATE TABLE referenced_table(test_column int, test_column2 int, PRIMARY KEY(test_column, test_column2));
|
||||
CREATE TABLE referencing_table(id int, ref_id int, ref_id2 int, PRIMARY KEY(id, ref_id));
|
||||
CREATE TABLE referencing_referencing_table(id int, ref_id int, FOREIGN KEY (id, ref_id) REFERENCES referencing_table(id, ref_id) ON DELETE CASCADE);
|
||||
SELECT create_reference_table('referenced_table');
|
||||
SELECT create_distributed_table('referencing_table', 'id');
|
||||
SELECT create_distributed_table('referencing_referencing_table', 'id');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT fkey_ref FOREIGN KEY (ref_id, ref_id2) REFERENCES referenced_table(test_column, test_column2) ON DELETE CASCADE;
|
||||
|
||||
SELECT * FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.referencing%' ORDER BY 1,2,3;
|
||||
|
||||
INSERT INTO referenced_table SELECT x, x+1 FROM generate_series(1,1000) AS f(x);
|
||||
INSERT INTO referencing_table SELECT x, x+1, x+2 FROM generate_series(1,999) AS f(x);
|
||||
INSERT INTO referencing_referencing_table SELECT x, x+1 FROM generate_series(1,999) AS f(x);
|
||||
|
||||
DELETE FROM referenced_table WHERE test_column > 800;
|
||||
SELECT max(ref_id) FROM referencing_referencing_table;
|
||||
|
||||
DROP TABLE referenced_table CASCADE;
|
||||
DROP TABLE referencing_table CASCADE;
|
||||
DROP TABLE referencing_referencing_table;
|
||||
|
||||
DROP SCHEMA fkey_reference_table CASCADE;
|
||||
SET search_path TO DEFAULT;
|
|
@ -32,6 +32,16 @@ CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCE
|
|||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
DROP TABLE referencing_table;
|
||||
|
||||
-- self referencing table with replication factor > 1
|
||||
CREATE TABLE self_referencing_table(id int, ref_id int, PRIMARY KEY (id, ref_id), FOREIGN KEY(id,ref_id) REFERENCES self_referencing_table(id, ref_id));
|
||||
SELECT create_distributed_table('self_referencing_table', 'id', 'hash');
|
||||
DROP TABLE self_referencing_table;
|
||||
|
||||
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 CONSTRAINT fkey 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_count TO 8;
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id));
|
||||
|
@ -55,9 +65,27 @@ SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
|||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
||||
-- test foreign constraint with correct conditions
|
||||
-- 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, FOREIGN KEY (id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'id', 'append');
|
||||
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,FOREIGN KEY (id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referencing_table', 'id', 'range');
|
||||
DROP TABLE referencing_table;
|
||||
DROP TABLE referenced_table;
|
||||
|
||||
-- test foreign constraint with correct conditions
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
CREATE TABLE referencing_table(id int, ref_id int, FOREIGN KEY(ref_id) REFERENCES referenced_table(id));
|
||||
SELECT create_distributed_table('referenced_table', 'id', 'hash');
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
|
@ -211,13 +239,12 @@ DROP TABLE referenced_table;
|
|||
|
||||
-- Similar tests, but this time we push foreign key constraints created by ALTER TABLE queries
|
||||
-- create tables
|
||||
SET citus.shard_count TO 4;
|
||||
CREATE TABLE referenced_table(id int UNIQUE, test_column int, PRIMARY KEY(id, test_column));
|
||||
SELECT master_create_distributed_table('referenced_table', 'id', 'hash');
|
||||
SELECT master_create_worker_shards('referenced_table', 4, 1);
|
||||
SELECT create_distributed_table('referenced_table', 'id', 'hash');
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT master_create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
SELECT master_create_worker_shards('referencing_table', 4, 1);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash');
|
||||
|
||||
-- verify that we skip foreign key validation when propagation is turned off
|
||||
-- not skipping validation would result in a distributed query, which emits debug messages
|
||||
|
@ -243,6 +270,13 @@ ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id)
|
|||
ALTER TABLE referencing_table ADD FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
|
||||
|
||||
-- test foreign constraint creation on NOT co-located tables
|
||||
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', 'hash');
|
||||
|
||||
CREATE TABLE referencing_table(id int, ref_id int);
|
||||
SELECT create_distributed_table('referencing_table', 'ref_id', 'hash', colocate_with => 'none');
|
||||
ALTER TABLE referencing_table ADD CONSTRAINT test_constraint FOREIGN KEY(ref_id) REFERENCES referenced_table(id);
|
||||
|
||||
-- create co-located tables
|
||||
|
@ -468,15 +502,11 @@ SELECT create_distributed_table('referenced_by_reference_table', 'id');
|
|||
CREATE TABLE reference_table(id int, referencing_column int REFERENCES referenced_by_reference_table(id));
|
||||
SELECT create_reference_table('reference_table');
|
||||
|
||||
-- test foreign key creation on CREATE TABLE to reference table
|
||||
-- test foreign key creation on CREATE TABLE from + to reference table
|
||||
DROP TABLE reference_table;
|
||||
CREATE TABLE reference_table(id int PRIMARY KEY, referencing_column int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
|
||||
CREATE TABLE references_to_reference_table(id int, referencing_column int REFERENCES reference_table(id));
|
||||
SELECT create_distributed_table('references_to_reference_table', 'referencing_column');
|
||||
|
||||
-- test foreign key creation on CREATE TABLE from + to reference table
|
||||
CREATE TABLE reference_table_second(id int, referencing_column int REFERENCES reference_table(id));
|
||||
SELECT create_reference_table('reference_table_second');
|
||||
|
||||
|
@ -503,7 +533,6 @@ SELECT create_reference_table('reference_table');
|
|||
ALTER TABLE reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES referenced_by_reference_table(id);
|
||||
|
||||
-- test foreign key creation on ALTER TABLE to reference table
|
||||
DROP TABLE references_to_reference_table;
|
||||
CREATE TABLE references_to_reference_table(id int, referencing_column int);
|
||||
SELECT create_distributed_table('references_to_reference_table', 'referencing_column');
|
||||
ALTER TABLE references_to_reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
|
||||
|
@ -515,7 +544,7 @@ SELECT create_reference_table('reference_table_second');
|
|||
ALTER TABLE reference_table_second ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES reference_table(id);
|
||||
|
||||
-- test foreign key creation on ALTER TABLE from reference table to local table
|
||||
DROP TABLE reference_table;
|
||||
DROP TABLE reference_table CASCADE;
|
||||
CREATE TABLE reference_table(id int PRIMARY KEY, referencing_column int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
ALTER TABLE reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES referenced_local_table(id);
|
||||
|
|
Loading…
Reference in New Issue