Specific DDLs are sequentialized when there is FK

-[x] drop constraint
-[x] drop column
-[x] alter column type
-[x] truncate

are sequentialized if there is a foreign constraint from
a distributed table to a reference table on the affected relations
by the above commands.
pull/2240/head
mehmet furkan şahin 2018-06-07 14:41:52 +03:00
parent e37f76c276
commit 4db72c99f6
12 changed files with 994 additions and 33 deletions

View File

@ -22,12 +22,75 @@
#include "distributed/master_protocol.h"
#include "distributed/multi_join_order.h"
#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/relcache.h"
#include "utils/ruleutils.h"
#include "utils/syscache.h"
static bool HeapTupleOfForeignConstraintIncludesColumn(HeapTuple heapTuple, Oid
relationId, int pgConstraintKey,
char *columnName);
/*
* ConstraintIsAForeignKeyToReferenceTable function scans the pgConstraint to
* fetch all of the constraints on the given relationId and see if at least one
* of them is a foreign key referencing to a reference table.
*/
bool
ConstraintIsAForeignKeyToReferenceTable(char *constraintName, Oid relationId)
{
Relation pgConstraint = NULL;
SysScanDesc scanDescriptor = NULL;
ScanKeyData scanKey[1];
int scanKeyCount = 1;
HeapTuple heapTuple = NULL;
bool foreignKeyToReferenceTable = false;
pgConstraint = heap_open(ConstraintRelationId, AccessShareLock);
ScanKeyInit(&scanKey[0], Anum_pg_constraint_contype, BTEqualStrategyNumber, F_CHAREQ,
CharGetDatum(CONSTRAINT_FOREIGN));
scanDescriptor = systable_beginscan(pgConstraint, InvalidOid, false,
NULL, scanKeyCount, scanKey);
heapTuple = systable_getnext(scanDescriptor);
while (HeapTupleIsValid(heapTuple))
{
Oid referencedTableId = InvalidOid;
Form_pg_constraint constraintForm = (Form_pg_constraint) GETSTRUCT(heapTuple);
char *constraintName = (constraintForm->conname).data;
if (strncmp(constraintName, constraintName, NAMEDATALEN) != 0 ||
constraintForm->conrelid != relationId)
{
heapTuple = systable_getnext(scanDescriptor);
continue;
}
referencedTableId = constraintForm->confrelid;
Assert(IsDistributedTable(referencedTableId));
if (PartitionMethod(referencedTableId) == DISTRIBUTE_BY_NONE)
{
foreignKeyToReferenceTable = true;
break;
}
heapTuple = systable_getnext(scanDescriptor);
}
/* clean up scan and close system catalog */
systable_endscan(scanDescriptor);
heap_close(pgConstraint, AccessShareLock);
return foreignKeyToReferenceTable;
}
/*
* ErrorIfUnsupportedForeignConstraint runs checks related to foreign constraints and
* errors out if it is not possible to create one of the foreign constraint in distributed
@ -60,11 +123,11 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
uint32 referencedTableColocationId = INVALID_COLOCATION_ID;
Var *referencedTablePartitionColumn = NULL;
Datum referencingColumnsDatum;
Datum *referencingColumnArray;
Datum referencingColumnsDatum = 0;
Datum *referencingColumnArray = NULL;
int referencingColumnCount = 0;
Datum referencedColumnsDatum;
Datum *referencedColumnArray;
Datum referencedColumnsDatum = 0;
Datum *referencedColumnArray = NULL;
int referencedColumnCount = 0;
bool isNull = false;
int attrIdx = 0;
@ -309,6 +372,87 @@ ErrorIfUnsupportedForeignConstraint(Relation relation, char distributionMethod,
}
/*
* ColumnAppearsInForeignKeyToReferenceTable checks if there is foreign constraint
* from/to a reference table on the given column. We iterate pgConstraint to fetch
* the constraint on the given relationId and find if any of the constraints
* includes the given column.
*/
bool
ColumnAppearsInForeignKeyToReferenceTable(char *columnName, Oid relationId)
{
Relation pgConstraint = NULL;
SysScanDesc scanDescriptor = NULL;
ScanKeyData scanKey[1];
int scanKeyCount = 1;
HeapTuple heapTuple = NULL;
bool foreignKeyToReferenceTableIncludesGivenColumn = false;
pgConstraint = heap_open(ConstraintRelationId, AccessShareLock);
ScanKeyInit(&scanKey[0], Anum_pg_constraint_contype, BTEqualStrategyNumber, F_CHAREQ,
CharGetDatum(CONSTRAINT_FOREIGN));
scanDescriptor = systable_beginscan(pgConstraint, InvalidOid, false,
NULL, scanKeyCount, scanKey);
heapTuple = systable_getnext(scanDescriptor);
while (HeapTupleIsValid(heapTuple))
{
Oid referencedTableId = InvalidOid;
Oid referencingTableId = InvalidOid;
int pgConstraintKey = 0;
Form_pg_constraint constraintForm = (Form_pg_constraint) GETSTRUCT(heapTuple);
referencedTableId = constraintForm->confrelid;
referencingTableId = constraintForm->conrelid;
if (referencedTableId == relationId)
{
pgConstraintKey = Anum_pg_constraint_confkey;
}
else if (referencingTableId == relationId)
{
pgConstraintKey = Anum_pg_constraint_conkey;
}
else
{
/*
* If the constraint is not from/to the given relation, we should simply
* skip.
*/
heapTuple = systable_getnext(scanDescriptor);
continue;
}
/*
* We check if the referenced table is a reference table. There cannot be
* any foreign constraint from a distributed table to a local table.
*/
Assert(IsDistributedTable(referencedTableId));
if (PartitionMethod(referencedTableId) != DISTRIBUTE_BY_NONE)
{
heapTuple = systable_getnext(scanDescriptor);
continue;
}
if (HeapTupleOfForeignConstraintIncludesColumn(heapTuple, relationId,
pgConstraintKey, columnName))
{
foreignKeyToReferenceTableIncludesGivenColumn = true;
break;
}
heapTuple = systable_getnext(scanDescriptor);
}
/* clean up scan and close system catalog */
systable_endscan(scanDescriptor);
heap_close(pgConstraint, AccessShareLock);
return foreignKeyToReferenceTableIncludesGivenColumn;
}
/*
* GetTableForeignConstraints takes in a relationId, and returns the list of foreign
* constraint commands needed to reconstruct foreign constraints of that table.
@ -472,3 +616,36 @@ TableReferenced(Oid relationId)
return false;
}
/*
* HeapTupleOfForeignConstraintIncludesColumn fetches the columns from the foreign
* constraint and checks if the given column name matches one of them.
*/
static bool
HeapTupleOfForeignConstraintIncludesColumn(HeapTuple heapTuple, Oid relationId,
int pgConstraintKey, char *columnName)
{
Datum columnsDatum = 0;
Datum *columnArray = NULL;
int columnCount = 0;
int attrIdx = 0;
bool isNull = false;
columnsDatum = SysCacheGetAttr(CONSTROID, heapTuple, pgConstraintKey, &isNull);
deconstruct_array(DatumGetArrayTypeP(columnsDatum), INT2OID, 2, true,
's', &columnArray, NULL, &columnCount);
for (attrIdx = 0; attrIdx < columnCount; ++attrIdx)
{
AttrNumber attrNo = DatumGetInt16(columnArray[attrIdx]);
char *colName = get_relid_attribute_name(relationId, attrNo);
if (strncmp(colName, columnName, NAMEDATALEN) == 0)
{
return true;
}
}
return false;
}

View File

@ -310,8 +310,6 @@ ExecutePlanIntoDestReceiver(PlannedStmt *queryPlan, ParamListInfo params,
void
SetLocalMultiShardModifyModeToSequential()
{
WarnNoTransactionChain(true, "SET LOCAL");
set_config_option("citus.multi_shard_modify_mode", "sequential",
(superuser() ? PGC_SUSET : PGC_USERSET), PGC_S_SESSION,
GUC_ACTION_LOCAL, true, 0, false);

View File

@ -164,6 +164,12 @@ static void PostProcessUtility(Node *parsetree);
static List * CollectGrantTableIdList(GrantStmt *grantStmt);
static void ProcessDropTableStmt(DropStmt *dropTableStatement);
/*
* We need to run some of the commands sequentially if there is a foreign constraint
* from/to reference table.
*/
static bool ShouldExecuteAlterTableSequentially(Oid relationId, AlterTableCmd *command);
/*
* multi_ProcessUtility9x is the 9.x-compatible wrapper for Citus' main utility
@ -1247,6 +1253,7 @@ PlanAlterTableStmt(AlterTableStmt *alterTableStatement, const char *alterTableCo
bool isDistributedRelation = false;
List *commandList = NIL;
ListCell *commandCell = NULL;
bool executeSequentially = false;
/* first check whether a distributed relation is affected */
if (alterTableStatement->relation == NULL)
@ -1295,8 +1302,8 @@ PlanAlterTableStmt(AlterTableStmt *alterTableStatement, const char *alterTableCo
}
/*
* We check if there is a ADD FOREIGN CONSTRAINT command in sub commands list.
* If there is we assign referenced releation id to rightRelationId and we also
* We check if there is a ADD/DROP FOREIGN CONSTRAINT command in sub commands list.
* If there is we assign referenced relation id to rightRelationId and we also
* set skip_validation to true to prevent PostgreSQL to verify validity of the
* foreign constraint in master. Validity will be checked in workers anyway.
*/
@ -1368,28 +1375,27 @@ PlanAlterTableStmt(AlterTableStmt *alterTableStatement, const char *alterTableCo
rightRelationId = RangeVarGetRelid(partitionCommand->name, NoLock, false);
}
#endif
executeSequentially |= ShouldExecuteAlterTableSequentially(leftRelationId,
command);
}
ddlJob = palloc0(sizeof(DDLJob));
ddlJob->targetRelationId = leftRelationId;
ddlJob->concurrentIndexCmd = false;
ddlJob->commandString = alterTableCommand;
ddlJob->executeSequentially = executeSequentially;
if (rightRelationId)
{
/* 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)
if (!IsDistributedTable(rightRelationId))
{
ddlJob->executeSequentially = true;
ddlJob->taskList = NIL;
}
else
{
/* if foreign key related, use specialized task list function ... */
ddlJob->taskList = InterShardDDLTaskList(leftRelationId, rightRelationId,
alterTableCommand);
}
}
else
@ -3796,3 +3802,66 @@ ProcessDropTableStmt(DropStmt *dropTableStatement)
}
}
}
/*
* ShouldExecuteAlterTableSequentially checks if the given ALTER TABLE
* statements should be executed sequentially when there is a foreign
* constraint from a distributed table to a reference table.
* In case of a column related ALTER TABLE operation, we check explicitly
* if there is a foreign constraint on this column from/to a reference table.
* Additionally, if the command is run inside a transaction block, we call
* SetLocalMultiShardModifyModeToSequential so that the further commands
* in the same transaction uses the same connections and does not error out.
*/
static bool
ShouldExecuteAlterTableSequentially(Oid relationId, AlterTableCmd *command)
{
bool executeSequentially = false;
AlterTableType alterTableType = command->subtype;
if (alterTableType == AT_DropConstraint)
{
char *constraintName = command->name;
if (ConstraintIsAForeignKeyToReferenceTable(constraintName, relationId))
{
executeSequentially = true;
}
}
else if (alterTableType == AT_DropColumn || alterTableType == AT_AlterColumnType)
{
char *affectedColumnName = command->name;
if (ColumnAppearsInForeignKeyToReferenceTable(affectedColumnName,
relationId))
{
if (IsTransactionBlock() && alterTableType == AT_AlterColumnType)
{
SetLocalMultiShardModifyModeToSequential();
}
executeSequentially = true;
}
}
else if (alterTableType == AT_AddConstraint)
{
/*
* 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.
*/
Constraint *constraint = (Constraint *) command->def;
if (constraint->contype == CONSTR_FOREIGN)
{
Oid rightRelationId = RangeVarGetRelid(constraint->pktable, NoLock,
false);
if (IsDistributedTable(rightRelationId) &&
PartitionMethod(rightRelationId) == DISTRIBUTE_BY_NONE)
{
executeSequentially = true;
}
}
}
return executeSequentially;
}

View File

@ -26,6 +26,7 @@
#include "commands/event_trigger.h"
#include "distributed/citus_clauses.h"
#include "distributed/citus_ruleutils.h"
#include "distributed/foreign_constraint.h"
#include "distributed/listutils.h"
#include "distributed/master_metadata_utility.h"
#include "distributed/master_protocol.h"
@ -57,6 +58,7 @@
static List * ModifyMultipleShardsTaskList(Query *query, List *shardIntervalList, TaskType
taskType);
static bool ShouldExecuteTruncateStmtSequential(TruncateStmt *command);
PG_FUNCTION_INFO_V1(master_modify_multiple_shards);
@ -134,6 +136,11 @@ master_modify_multiple_shards(PG_FUNCTION_ARGS)
}
EnsureTablePermissions(relationId, ACL_TRUNCATE);
if (ShouldExecuteTruncateStmtSequential(truncateStatement))
{
SetLocalMultiShardModifyModeToSequential();
}
}
else
{
@ -243,3 +250,34 @@ ModifyMultipleShardsTaskList(Query *query, List *shardIntervalList, TaskType tas
return taskList;
}
/*
* ShouldExecuteTruncateStmtSequential decides if the TRUNCATE stmt needs
* to run sequential. If so, it calls SetLocalMultiShardModifyModeToSequential().
*
* If a reference table which has a foreign key from a distributed table is truncated
* we need to execute the command sequentially to avoid self-deadlock.
*/
static bool
ShouldExecuteTruncateStmtSequential(TruncateStmt *command)
{
List *relationList = command->relations;
ListCell *relationCell = NULL;
bool failOK = false;
foreach(relationCell, relationList)
{
RangeVar *rangeVar = (RangeVar *) lfirst(relationCell);
Oid relationId = RangeVarGetRelid(rangeVar, NoLock, failOK);
if (IsDistributedTable(relationId) &&
PartitionMethod(relationId) == DISTRIBUTE_BY_NONE &&
TableReferenced(relationId))
{
return true;
}
}
return false;
}

View File

@ -14,10 +14,14 @@
#include "utils/relcache.h"
#include "nodes/primnodes.h"
extern bool ConstraintIsAForeignKeyToReferenceTable(char *constraintName,
Oid leftRelationId);
extern void ErrorIfUnsupportedForeignConstraint(Relation relation, char
distributionMethod,
Var *distributionColumn, uint32
colocationId);
extern bool ColumnAppearsInForeignKeyToReferenceTable(char *columnName, Oid
relationId);
extern List * GetTableForeignConstraintCommands(Oid relationId);
extern bool HasForeignKeyToReferenceTable(Oid relationId);
extern bool TableReferenced(Oid relationId);

View File

@ -436,14 +436,12 @@ 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
0
(1 row)
-- drop table for next tests
@ -1286,8 +1284,7 @@ BEGIN;
(1 row)
ALTER TABLE test_table_2 ADD CONSTRAINT c_check FOREIGN KEY (value_1) REFERENCES test_table_1(id);
ERROR: relation "fkey_reference_table.test_table_1_7000325" does not exist
CONTEXT: while executing command on localhost:57637
ERROR: cannot perform query with placements that were modified over multiple connections
DROP TABLE test_table_1, test_table_2;
ERROR: current transaction is aborted, commands ignored until end of transaction block
COMMIT;
@ -1309,8 +1306,7 @@ BEGIN;
(1 row)
ALTER TABLE test_table_1 ADD CONSTRAINT c_check FOREIGN KEY (value_1) REFERENCES test_table_2(id);
ERROR: relation "fkey_reference_table.test_table_2_7000342" does not exist
CONTEXT: while executing command on localhost:57637
ERROR: cannot perform query with placements that were modified over multiple connections
DROP TABLE test_table_2 CASCADE;
ERROR: current transaction is aborted, commands ignored until end of transaction block
ROLLBACK;
@ -1357,6 +1353,455 @@ ERROR: cannot establish a new connection for placement 7000388, since DDL has b
DROP TABLE test_table_2, test_table_1;
ERROR: current transaction is aborted, commands ignored until end of transaction block
COMMIT;
-- The following tests check if the DDLs affecting foreign keys work as expected
-- check if we can drop the foreign constraint
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
8
(1 row)
ALTER TABLE test_table_2 DROP CONSTRAINT test_table_2_value_1_fkey;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the foreign constraint in a transaction right after ADD CONSTRAINT
-- FIXME: fails for now
BEGIN;
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int);
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_2 ADD CONSTRAINT foreign_key FOREIGN KEY(value_1) REFERENCES test_table_1(id);
ERROR: cannot perform query with placements that were modified over multiple connections
ALTER TABLE test_table_2 DROP CONSTRAINT test_table_2_value_1_fkey;
ERROR: current transaction is aborted, commands ignored until end of transaction block
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
ERROR: table "test_table_1" does not exist
-- check if we can drop the primary key which cascades to the foreign key
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_1 DROP CONSTRAINT test_table_1_pkey CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the primary key which cascades to the foreign key in a transaction block
BEGIN;
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_1 DROP CONSTRAINT test_table_1_pkey CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_2 DROP COLUMN value_1;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_2 DROP COLUMN value_1;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing to
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can alter the column type which foreign key is referencing to
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1,1), (2,2), (3,3);
INSERT INTO test_table_2 VALUES (1,1), (2,2), (3,3);
-- should succeed
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE bigint;
ALTER TABLE test_table_1 ALTER COLUMN id SET DATA TYPE bigint;
-- should fail since there is a bigint out of integer range > (2^32 - 1)
INSERT INTO test_table_1 VALUES (2147483648,4);
INSERT INTO test_table_2 VALUES (4,2147483648);
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE int;
ERROR: integer out of range
CONTEXT: while executing command on localhost:57637
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
8
(1 row)
DROP TABLE test_table_1 CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
DROP TABLE test_table_2;
-- check if we can alter the column type and drop it which foreign key is referencing to in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE bigint;
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
NOTICE: drop cascades to constraint test_table_2_value_1_fkey on table test_table_2
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
count
-------
0
(1 row)
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_1 CASCADE;
NOTICE: truncate cascades to table "test_table_2"
SELECT * FROM test_table_2;
id | value_1
----+---------
(0 rows)
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table in a transaction
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
BEGIN;
TRUNCATE test_table_1 CASCADE;
NOTICE: truncate cascades to table "test_table_2"
COMMIT;
SELECT * FROM test_table_2;
id | value_1
----+---------
(0 rows)
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table in a transaction after inserts
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_1 CASCADE;
NOTICE: truncate cascades to table "test_table_2"
COMMIT;
SELECT * FROM test_table_2;
id | value_1
----+---------
(0 rows)
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referencing table
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_2 CASCADE;
SELECT * FROM test_table_2;
id | value_1
----+---------
(0 rows)
SELECT * FROM test_table_1;
id
----
1
2
3
(3 rows)
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referencing table in a transaction
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
BEGIN;
TRUNCATE test_table_2 CASCADE;
COMMIT;
SELECT * FROM test_table_2;
id | value_1
----+---------
(0 rows)
SELECT * FROM test_table_1;
id
----
1
2
3
(3 rows)
DROP TABLE test_table_1, test_table_2;
-- check if we successfuly set multi_shard_modify_mode to sequential after sequentially running DDLs
-- in transaction since the upcoming DDLs need to run sequentially.
-- FIXME: fails for now
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int);
CREATE TABLE test_table_3(id int PRIMARY KEY, value_1 int);
SELECT create_reference_table('test_table_1');
create_reference_table
------------------------
(1 row)
SELECT create_distributed_table('test_table_2', 'id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('test_table_3', 'id');
create_distributed_table
--------------------------
(1 row)
BEGIN;
ALTER TABLE test_table_2 ADD CONSTRAINT fkey FOREIGN KEY (value_1) REFERENCES test_table_1(id);
ALTER TABLE test_table_3 ADD COLUMN test_column int;
ERROR: cannot establish a new connection for placement 7000556, since DDL has been executed on a connection that is in use
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
ERROR: current transaction is aborted, commands ignored until end of transaction block
ALTER TABLE test_table_1 ADD COLUMN id int;
ERROR: current transaction is aborted, commands ignored until end of transaction block
COMMIT;
DROP TABLE test_table_1, test_table_2, test_table_3;
DROP SCHEMA fkey_reference_table CASCADE;
NOTICE: drop cascades to 3 other objects
DETAIL: drop cascades to type foreign_details

View File

@ -919,7 +919,8 @@ SELECT create_reference_table('reference_table');
(1 row)
ALTER TABLE reference_table ADD CONSTRAINT fk FOREIGN KEY(referencing_column) REFERENCES referenced_local_table(id);
ERROR: relation referenced_local_table is not distributed
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 on self referencing reference table
DROP TABLE self_referencing_reference_table;
CREATE TABLE self_referencing_reference_table(

View File

@ -576,7 +576,7 @@ BEGIN;
101
(1 row)
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1');
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1') ORDER BY 1,2;
table_name | select_access | dml_access | ddl_access
------------+-----------------+--------------+--------------
table_1 | parallel_access | not_accessed | not_accessed

View File

@ -576,7 +576,7 @@ BEGIN;
101
(1 row)
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1');
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1') ORDER BY 1,2;
table_name | select_access | dml_access | ddl_access
------------+-----------------+--------------+--------------
table_1 | parallel_access | not_accessed | not_accessed

View File

@ -74,7 +74,6 @@ SELECT create_distributed_table('test_table', 'a');
-- not useful if not in transaction
SELECT set_local_multi_shard_modify_mode_to_sequential();
WARNING: SET LOCAL can only be used in transaction blocks
set_local_multi_shard_modify_mode_to_sequential
-------------------------------------------------

View File

@ -198,7 +198,6 @@ DELETE FROM referenced_table WHERE id > 3;
DELETE FROM referenced_table WHERE id = 501;
-- test cascading truncate
-- will fail for now
TRUNCATE referenced_table CASCADE;
SELECT count(*) FROM referencing_table;
@ -680,5 +679,236 @@ BEGIN;
DROP TABLE test_table_2, test_table_1;
COMMIT;
-- The following tests check if the DDLs affecting foreign keys work as expected
-- check if we can drop the foreign constraint
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
ALTER TABLE test_table_2 DROP CONSTRAINT test_table_2_value_1_fkey;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the foreign constraint in a transaction right after ADD CONSTRAINT
-- FIXME: fails for now
BEGIN;
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int);
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_2 ADD CONSTRAINT foreign_key FOREIGN KEY(value_1) REFERENCES test_table_1(id);
ALTER TABLE test_table_2 DROP CONSTRAINT test_table_2_value_1_fkey;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the primary key which cascades to the foreign key
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_1 DROP CONSTRAINT test_table_1_pkey CASCADE;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the primary key which cascades to the foreign key in a transaction block
BEGIN;
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_1 DROP CONSTRAINT test_table_1_pkey CASCADE;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_2 DROP COLUMN value_1;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_2 DROP COLUMN value_1;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing to
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can drop the column which foreign key is referencing from in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can alter the column type which foreign key is referencing to
CREATE TABLE test_table_1(id int PRIMARY KEY, id2 int);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1,1), (2,2), (3,3);
INSERT INTO test_table_2 VALUES (1,1), (2,2), (3,3);
-- should succeed
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE bigint;
ALTER TABLE test_table_1 ALTER COLUMN id SET DATA TYPE bigint;
-- should fail since there is a bigint out of integer range > (2^32 - 1)
INSERT INTO test_table_1 VALUES (2147483648,4);
INSERT INTO test_table_2 VALUES (4,2147483648);
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE int;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1 CASCADE;
DROP TABLE test_table_2;
-- check if we can alter the column type and drop it which foreign key is referencing to in a transaction block
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
ALTER TABLE test_table_2 ALTER COLUMN value_1 SET DATA TYPE bigint;
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
COMMIT;
SELECT count(*) FROM table_fkeys_in_workers WHERE relid LIKE 'fkey_reference_table.%' AND refd_relid LIKE 'fkey_reference_table.%';
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_1 CASCADE;
SELECT * FROM test_table_2;
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table in a transaction
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
BEGIN;
TRUNCATE test_table_1 CASCADE;
COMMIT;
SELECT * FROM test_table_2;
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referenced table in a transaction after inserts
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
BEGIN;
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_1 CASCADE;
COMMIT;
SELECT * FROM test_table_2;
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referencing table
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
TRUNCATE test_table_2 CASCADE;
SELECT * FROM test_table_2;
SELECT * FROM test_table_1;
DROP TABLE test_table_1, test_table_2;
-- check if we can TRUNCATE the referencing table in a transaction
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int, FOREIGN KEY(value_1) REFERENCES test_table_1(id));
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
INSERT INTO test_table_1 VALUES (1),(2),(3);
INSERT INTO test_table_2 VALUES (1,1),(2,2),(3,3);
BEGIN;
TRUNCATE test_table_2 CASCADE;
COMMIT;
SELECT * FROM test_table_2;
SELECT * FROM test_table_1;
DROP TABLE test_table_1, test_table_2;
-- check if we successfuly set multi_shard_modify_mode to sequential after sequentially running DDLs
-- in transaction since the upcoming DDLs need to run sequentially.
-- FIXME: fails for now
CREATE TABLE test_table_1(id int PRIMARY KEY);
CREATE TABLE test_table_2(id int PRIMARY KEY, value_1 int);
CREATE TABLE test_table_3(id int PRIMARY KEY, value_1 int);
SELECT create_reference_table('test_table_1');
SELECT create_distributed_table('test_table_2', 'id');
SELECT create_distributed_table('test_table_3', 'id');
BEGIN;
ALTER TABLE test_table_2 ADD CONSTRAINT fkey FOREIGN KEY (value_1) REFERENCES test_table_1(id);
ALTER TABLE test_table_3 ADD COLUMN test_column int;
ALTER TABLE test_table_1 DROP COLUMN id CASCADE;
ALTER TABLE test_table_1 ADD COLUMN id int;
COMMIT;
DROP TABLE test_table_1, test_table_2, test_table_3;
DROP SCHEMA fkey_reference_table CASCADE;
SET search_path TO DEFAULT;

View File

@ -348,7 +348,7 @@ ROLLBACK;
-- reference table join with a distributed table
BEGIN;
SELECT count(*) FROM table_1 JOIN table_6 USING(key);
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1');
SELECT * FROM relation_acesses WHERE table_name IN ('table_6', 'table_1') ORDER BY 1,2;
ROLLBACK;
-- TRUNCATE should be DDL