Support foreign keys that reference partitioned tables

Previously, while primary keys could be made on partitioned tables, it
was not possible to define foreign keys that reference those primary
keys.  Now it is possible to do that.

Author: Álvaro Herrera
Reviewed-by: Amit Langote, Jesper Pedersen
Discussion: https://postgr.es/m/20181102234158.735b3fevta63msbj@alvherre.pgsql
This commit is contained in:
Alvaro Herrera 2019-04-03 14:38:20 -03:00
parent 9155580fd5
commit f56f8f8da6
15 changed files with 2059 additions and 451 deletions

View File

@ -379,9 +379,6 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<para>
Partitioned tables do not support <literal>EXCLUDE</literal> constraints;
however, you can define these constraints on individual partitions.
Also, while it's possible to define <literal>PRIMARY KEY</literal>
constraints on partitioned tables, creating foreign keys that
reference a partitioned table is not yet supported.
</para>
<para>
@ -1028,9 +1025,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
addition of a foreign key constraint requires a
<literal>SHARE ROW EXCLUSIVE</literal> lock on the referenced table.
Note that foreign key constraints cannot be defined between temporary
tables and permanent tables. Also note that while it is possible to
define a foreign key on a partitioned table, it is not possible to
declare a foreign key that references a partitioned table.
tables and permanent tables.
</para>
<para>

File diff suppressed because it is too large Load Diff

View File

@ -50,6 +50,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/ruleutils.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
@ -220,8 +221,8 @@ static void ri_ExtractValues(Relation rel, TupleTableSlot *slot,
Datum *vals, char *nulls);
static void ri_ReportViolation(const RI_ConstraintInfo *riinfo,
Relation pk_rel, Relation fk_rel,
TupleTableSlot *violator, TupleDesc tupdesc,
int queryno) pg_attribute_noreturn();
TupleTableSlot *violatorslot, TupleDesc tupdesc,
int queryno, bool partgone) pg_attribute_noreturn();
/*
@ -348,18 +349,22 @@ RI_FKey_check(TriggerData *trigdata)
char paramname[16];
const char *querysep;
Oid queryoids[RI_MAX_NUMKEYS];
const char *pk_only;
/* ----------
* The query string built is
* SELECT 1 FROM ONLY <pktable> x WHERE pkatt1 = $1 [AND ...]
* SELECT 1 FROM [ONLY] <pktable> x WHERE pkatt1 = $1 [AND ...]
* FOR KEY SHARE OF x
* The type id's for the $ parameters are those of the
* corresponding FK attributes.
* ----------
*/
initStringInfo(&querybuf);
pk_only = pk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
quoteRelationName(pkrelname, pk_rel);
appendStringInfo(&querybuf, "SELECT 1 FROM ONLY %s x", pkrelname);
appendStringInfo(&querybuf, "SELECT 1 FROM %s%s x",
pk_only, pkrelname);
querysep = "WHERE";
for (int i = 0; i < riinfo->nkeys; i++)
{
@ -471,19 +476,23 @@ ri_Check_Pk_Match(Relation pk_rel, Relation fk_rel,
char attname[MAX_QUOTED_NAME_LEN];
char paramname[16];
const char *querysep;
const char *pk_only;
Oid queryoids[RI_MAX_NUMKEYS];
/* ----------
* The query string built is
* SELECT 1 FROM ONLY <pktable> x WHERE pkatt1 = $1 [AND ...]
* SELECT 1 FROM [ONLY] <pktable> x WHERE pkatt1 = $1 [AND ...]
* FOR KEY SHARE OF x
* The type id's for the $ parameters are those of the
* PK attributes themselves.
* ----------
*/
initStringInfo(&querybuf);
pk_only = pk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
quoteRelationName(pkrelname, pk_rel);
appendStringInfo(&querybuf, "SELECT 1 FROM ONLY %s x", pkrelname);
appendStringInfo(&querybuf, "SELECT 1 FROM %s%s x",
pk_only, pkrelname);
querysep = "WHERE";
for (int i = 0; i < riinfo->nkeys; i++)
{
@ -1293,6 +1302,7 @@ RI_Initial_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
RangeTblEntry *fkrte;
const char *sep;
const char *fk_only;
const char *pk_only;
int save_nestlevel;
char workmembuf[32];
int spi_result;
@ -1350,7 +1360,7 @@ RI_Initial_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
/*----------
* The query string built is:
* SELECT fk.keycols FROM [ONLY] relname fk
* LEFT OUTER JOIN ONLY pkrelname pk
* LEFT OUTER JOIN [ONLY] pkrelname pk
* ON (pk.pkkeycol1=fk.keycol1 [AND ...])
* WHERE pk.pkkeycol1 IS NULL AND
* For MATCH SIMPLE:
@ -1377,9 +1387,11 @@ RI_Initial_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
quoteRelationName(fkrelname, fk_rel);
fk_only = fk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
pk_only = pk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
appendStringInfo(&querybuf,
" FROM %s%s fk LEFT OUTER JOIN ONLY %s pk ON",
fk_only, fkrelname, pkrelname);
" FROM %s%s fk LEFT OUTER JOIN %s%s pk ON",
fk_only, fkrelname, pk_only, pkrelname);
strcpy(pkattname, "pk.");
strcpy(fkattname, "fk.");
@ -1530,7 +1542,7 @@ RI_Initial_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
ri_ReportViolation(&fake_riinfo,
pk_rel, fk_rel,
slot, tupdesc,
RI_PLAN_CHECK_LOOKUPPK);
RI_PLAN_CHECK_LOOKUPPK, false);
ExecDropSingleTupleTableSlot(slot);
}
@ -1546,6 +1558,214 @@ RI_Initial_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
return true;
}
/*
* RI_PartitionRemove_Check -
*
* Verify no referencing values exist, when a partition is detached on
* the referenced side of a foreign key constraint.
*/
void
RI_PartitionRemove_Check(Trigger *trigger, Relation fk_rel, Relation pk_rel)
{
const RI_ConstraintInfo *riinfo;
StringInfoData querybuf;
char *constraintDef;
char pkrelname[MAX_QUOTED_REL_NAME_LEN];
char fkrelname[MAX_QUOTED_REL_NAME_LEN];
char pkattname[MAX_QUOTED_NAME_LEN + 3];
char fkattname[MAX_QUOTED_NAME_LEN + 3];
const char *sep;
const char *fk_only;
int save_nestlevel;
char workmembuf[32];
int spi_result;
SPIPlanPtr qplan;
int i;
riinfo = ri_FetchConstraintInfo(trigger, fk_rel, false);
/*
* We don't check permissions before displaying the error message, on the
* assumption that the user detaching the partition must have enough
* privileges to examine the table contents anyhow.
*/
/*----------
* The query string built is:
* SELECT fk.keycols FROM [ONLY] relname fk
* JOIN pkrelname pk
* ON (pk.pkkeycol1=fk.keycol1 [AND ...])
* WHERE (<partition constraint>) AND
* For MATCH SIMPLE:
* (fk.keycol1 IS NOT NULL [AND ...])
* For MATCH FULL:
* (fk.keycol1 IS NOT NULL [OR ...])
*
* We attach COLLATE clauses to the operators when comparing columns
* that have different collations.
*----------
*/
initStringInfo(&querybuf);
appendStringInfoString(&querybuf, "SELECT ");
sep = "";
for (i = 0; i < riinfo->nkeys; i++)
{
quoteOneName(fkattname,
RIAttName(fk_rel, riinfo->fk_attnums[i]));
appendStringInfo(&querybuf, "%sfk.%s", sep, fkattname);
sep = ", ";
}
quoteRelationName(pkrelname, pk_rel);
quoteRelationName(fkrelname, fk_rel);
fk_only = fk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
appendStringInfo(&querybuf,
" FROM %s%s fk JOIN %s pk ON",
fk_only, fkrelname, pkrelname);
strcpy(pkattname, "pk.");
strcpy(fkattname, "fk.");
sep = "(";
for (i = 0; i < riinfo->nkeys; i++)
{
Oid pk_type = RIAttType(pk_rel, riinfo->pk_attnums[i]);
Oid fk_type = RIAttType(fk_rel, riinfo->fk_attnums[i]);
Oid pk_coll = RIAttCollation(pk_rel, riinfo->pk_attnums[i]);
Oid fk_coll = RIAttCollation(fk_rel, riinfo->fk_attnums[i]);
quoteOneName(pkattname + 3,
RIAttName(pk_rel, riinfo->pk_attnums[i]));
quoteOneName(fkattname + 3,
RIAttName(fk_rel, riinfo->fk_attnums[i]));
ri_GenerateQual(&querybuf, sep,
pkattname, pk_type,
riinfo->pf_eq_oprs[i],
fkattname, fk_type);
if (pk_coll != fk_coll)
ri_GenerateQualCollation(&querybuf, pk_coll);
sep = "AND";
}
/*
* Start the WHERE clause with the partition constraint (except if this is
* the default partition and there's no other partition, because the
* partition constraint is the empty string in that case.)
*/
constraintDef = pg_get_partconstrdef_string(RelationGetRelid(pk_rel), "pk");
if (constraintDef && constraintDef[0] != '\0')
appendStringInfo(&querybuf, ") WHERE %s AND (",
constraintDef);
else
appendStringInfo(&querybuf, ") WHERE (");
sep = "";
for (i = 0; i < riinfo->nkeys; i++)
{
quoteOneName(fkattname, RIAttName(fk_rel, riinfo->fk_attnums[i]));
appendStringInfo(&querybuf,
"%sfk.%s IS NOT NULL",
sep, fkattname);
switch (riinfo->confmatchtype)
{
case FKCONSTR_MATCH_SIMPLE:
sep = " AND ";
break;
case FKCONSTR_MATCH_FULL:
sep = " OR ";
break;
}
}
appendStringInfoChar(&querybuf, ')');
/*
* Temporarily increase work_mem so that the check query can be executed
* more efficiently. It seems okay to do this because the query is simple
* enough to not use a multiple of work_mem, and one typically would not
* have many large foreign-key validations happening concurrently. So
* this seems to meet the criteria for being considered a "maintenance"
* operation, and accordingly we use maintenance_work_mem.
*
* We use the equivalent of a function SET option to allow the setting to
* persist for exactly the duration of the check query. guc.c also takes
* care of undoing the setting on error.
*/
save_nestlevel = NewGUCNestLevel();
snprintf(workmembuf, sizeof(workmembuf), "%d", maintenance_work_mem);
(void) set_config_option("work_mem", workmembuf,
PGC_USERSET, PGC_S_SESSION,
GUC_ACTION_SAVE, true, 0, false);
if (SPI_connect() != SPI_OK_CONNECT)
elog(ERROR, "SPI_connect failed");
/*
* Generate the plan. We don't need to cache it, and there are no
* arguments to the plan.
*/
qplan = SPI_prepare(querybuf.data, 0, NULL);
if (qplan == NULL)
elog(ERROR, "SPI_prepare returned %s for %s",
SPI_result_code_string(SPI_result), querybuf.data);
/*
* Run the plan. For safety we force a current snapshot to be used. (In
* transaction-snapshot mode, this arguably violates transaction isolation
* rules, but we really haven't got much choice.) We don't need to
* register the snapshot, because SPI_execute_snapshot will see to it. We
* need at most one tuple returned, so pass limit = 1.
*/
spi_result = SPI_execute_snapshot(qplan,
NULL, NULL,
GetLatestSnapshot(),
InvalidSnapshot,
true, false, 1);
/* Check result */
if (spi_result != SPI_OK_SELECT)
elog(ERROR, "SPI_execute_snapshot returned %s", SPI_result_code_string(spi_result));
/* Did we find a tuple that would violate the constraint? */
if (SPI_processed > 0)
{
TupleTableSlot *slot;
HeapTuple tuple = SPI_tuptable->vals[0];
TupleDesc tupdesc = SPI_tuptable->tupdesc;
RI_ConstraintInfo fake_riinfo;
slot = MakeSingleTupleTableSlot(tupdesc, &TTSOpsVirtual);
heap_deform_tuple(tuple, tupdesc,
slot->tts_values, slot->tts_isnull);
ExecStoreVirtualTuple(slot);
/*
* The columns to look at in the result tuple are 1..N, not whatever
* they are in the fk_rel. Hack up riinfo so that ri_ReportViolation
* will behave properly.
*
* In addition to this, we have to pass the correct tupdesc to
* ri_ReportViolation, overriding its normal habit of using the pk_rel
* or fk_rel's tupdesc.
*/
memcpy(&fake_riinfo, riinfo, sizeof(RI_ConstraintInfo));
for (i = 0; i < fake_riinfo.nkeys; i++)
fake_riinfo.pk_attnums[i] = i + 1;
ri_ReportViolation(&fake_riinfo, pk_rel, fk_rel,
slot, tupdesc, 0, true);
}
if (SPI_finish() != SPI_OK_FINISH)
elog(ERROR, "SPI_finish failed");
/*
* Restore work_mem.
*/
AtEOXact_GUC(true, save_nestlevel);
}
/* ----------
* Local functions below
@ -2078,7 +2298,7 @@ ri_PerformCheck(const RI_ConstraintInfo *riinfo,
pk_rel, fk_rel,
newslot ? newslot : oldslot,
NULL,
qkey->constr_queryno);
qkey->constr_queryno, false);
return SPI_processed != 0;
}
@ -2119,7 +2339,7 @@ static void
ri_ReportViolation(const RI_ConstraintInfo *riinfo,
Relation pk_rel, Relation fk_rel,
TupleTableSlot *violatorslot, TupleDesc tupdesc,
int queryno)
int queryno, bool partgone)
{
StringInfoData key_names;
StringInfoData key_values;
@ -2158,9 +2378,13 @@ ri_ReportViolation(const RI_ConstraintInfo *riinfo,
*
* Check table-level permissions next and, failing that, column-level
* privileges.
*
* When a partition at the referenced side is being detached/dropped, we
* needn't check, since the user must be the table owner anyway.
*/
if (check_enable_rls(rel_oid, InvalidOid, true) != RLS_ENABLED)
if (partgone)
has_perm = true;
else if (check_enable_rls(rel_oid, InvalidOid, true) != RLS_ENABLED)
{
aclresult = pg_class_aclcheck(rel_oid, GetUserId(), ACL_SELECT);
if (aclresult != ACLCHECK_OK)
@ -2222,7 +2446,16 @@ ri_ReportViolation(const RI_ConstraintInfo *riinfo,
}
}
if (onfk)
if (partgone)
ereport(ERROR,
(errcode(ERRCODE_FOREIGN_KEY_VIOLATION),
errmsg("removing partition \"%s\" violates foreign key constraint \"%s\"",
RelationGetRelationName(pk_rel),
NameStr(riinfo->conname)),
errdetail("Key (%s)=(%s) still referenced from table \"%s\".",
key_names.data, key_values.data,
RelationGetRelationName(fk_rel))));
else if (onfk)
ereport(ERROR,
(errcode(ERRCODE_FOREIGN_KEY_VIOLATION),
errmsg("insert or update on table \"%s\" violates foreign key constraint \"%s\"",

View File

@ -1836,6 +1836,24 @@ pg_get_partition_constraintdef(PG_FUNCTION_ARGS)
PG_RETURN_TEXT_P(string_to_text(consrc));
}
/*
* pg_get_partconstrdef_string
*
* Returns the partition constraint as a C-string for the input relation, with
* the given alias. No pretty-printing.
*/
char *
pg_get_partconstrdef_string(Oid partitionId, char *aliasname)
{
Expr *constr_expr;
List *context;
constr_expr = get_partition_qual_relid(partitionId);
context = deparse_context_for(aliasname, partitionId);
return deparse_expression((Node *) constr_expr, context, true, false);
}
/*
* pg_get_constraintdef
*

View File

@ -2452,9 +2452,12 @@ describeOneTableDetails(const char *schemaname,
" pg_catalog.pg_get_constraintdef(r.oid, true) as condef,\n"
" conrelid::pg_catalog.regclass AS ontable\n"
"FROM pg_catalog.pg_constraint r\n"
"WHERE r.conrelid = '%s' AND r.contype = 'f'\n"
"ORDER BY conname;",
"WHERE r.conrelid = '%s' AND r.contype = 'f'\n",
oid);
if (pset.sversion >= 120000)
appendPQExpBuffer(&buf, " AND conparentid = 0\n");
appendPQExpBuffer(&buf, "ORDER BY conname");
}
result = PSQLexec(buf.data);

View File

@ -76,10 +76,6 @@ extern void find_composite_type_dependencies(Oid typeOid,
extern void check_of_type(HeapTuple typetuple);
extern void createForeignKeyTriggers(Relation rel, Oid refRelOid,
Constraint *fkconstraint, Oid constraintOid,
Oid indexOid, bool create_action);
extern void register_on_commit_action(Oid relid, OnCommitAction action);
extern void remove_on_commit_action(Oid relid);

View File

@ -263,6 +263,8 @@ extern bool RI_FKey_fk_upd_check_required(Trigger *trigger, Relation fk_rel,
TupleTableSlot *old_slot, TupleTableSlot *new_slot);
extern bool RI_Initial_Check(Trigger *trigger,
Relation fk_rel, Relation pk_rel);
extern void RI_PartitionRemove_Check(Trigger *trigger, Relation fk_rel,
Relation pk_rel);
/* result values for RI_FKey_trigger_type: */
#define RI_TRIGGER_PK 1 /* is a trigger on the PK relation */

View File

@ -22,6 +22,7 @@ extern char *pg_get_indexdef_string(Oid indexrelid);
extern char *pg_get_indexdef_columns(Oid indexrelid, bool pretty);
extern char *pg_get_partkeydef_columns(Oid relid, bool pretty);
extern char *pg_get_partconstrdef_string(Oid partitionId, char *aliasname);
extern char *pg_get_constraintdef_command(Oid constraintId);
extern char *deparse_expression(Node *expr, List *dpcontext,

View File

@ -0,0 +1,133 @@
Parsed test spec with 2 sessions
starting permutation: s1b s1d s1c s2b s2a s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2b s1c s2a s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2b: begin;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2b s2a s1c s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s1d s1c s2a s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s1d s2a s1c s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk1 where a = 1;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s2a s1d s2c s1c
step s1b: begin;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s1b s2b s2a s2c s1d s1c
step s1b: begin;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s1b s1d s1c s2a s2c
step s2b: begin;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s2b s1b s1d s2a s1c s2c
step s2b: begin;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s2b s1b s2a s1d s2c s1c
step s2b: begin;
step s1b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s1b s2a s2c s1d s1c
step s2b: begin;
step s1b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s1b s1d s2c s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1b: begin;
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s1b s2c s1d s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1b: begin;
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s2c s1b s1d s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;

View File

@ -0,0 +1,70 @@
Parsed test spec with 2 sessions
starting permutation: s1b s1d s2b s2i s1c s2c
step s1b: begin;
step s1d: delete from ppk where a = 1;
step s2b: begin;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2bs s2i s1c s2c
step s1b: begin;
step s1d: delete from ppk where a = 1;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: could not serialize access due to concurrent update
step s2c: commit;
starting permutation: s1b s2b s1d s2i s1c s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk where a = 1;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2bs s1d s2i s1c s2c
step s1b: begin;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s1d: delete from ppk where a = 1;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: could not serialize access due to concurrent update
step s2c: commit;
starting permutation: s1b s2b s2i s1d s2c s1c
step s1b: begin;
step s2b: begin;
step s2i: insert into pfk values (1);
step s1d: delete from ppk where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s1b s2bs s2i s1d s2c s1c
step s1b: begin;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s2i: insert into pfk values (1);
step s1d: delete from ppk where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;

View File

@ -24,6 +24,8 @@ test: deadlock-soft-2
test: fk-contention
test: fk-deadlock
test: fk-deadlock2
test: fk-partitioned-1
test: fk-partitioned-2
test: eval-plan-qual
test: lock-update-delete
test: lock-update-traversal

View File

@ -0,0 +1,45 @@
# Verify that cloning a foreign key constraint to a partition ensures
# that referenced values exist, even if they're being concurrently
# deleted.
setup {
drop table if exists ppk, pfk, pfk1;
create table ppk (a int primary key) partition by list (a);
create table ppk1 partition of ppk for values in (1);
insert into ppk values (1);
create table pfk (a int references ppk) partition by list (a);
create table pfk1 (a int not null);
insert into pfk1 values (1);
}
session "s1"
step "s1b" { begin; }
step "s1d" { delete from ppk1 where a = 1; }
step "s1c" { commit; }
session "s2"
step "s2b" { begin; }
step "s2a" { alter table pfk attach partition pfk1 for values in (1); }
step "s2c" { commit; }
teardown { drop table ppk, pfk, pfk1; }
permutation "s1b" "s1d" "s1c" "s2b" "s2a" "s2c"
permutation "s1b" "s1d" "s2b" "s1c" "s2a" "s2c"
permutation "s1b" "s1d" "s2b" "s2a" "s1c" "s2c"
#permutation "s1b" "s1d" "s2b" "s2a" "s2c" "s1c"
permutation "s1b" "s2b" "s1d" "s1c" "s2a" "s2c"
permutation "s1b" "s2b" "s1d" "s2a" "s1c" "s2c"
#permutation "s1b" "s2b" "s1d" "s2a" "s2c" "s1c"
#permutation "s1b" "s2b" "s2a" "s1d" "s1c" "s2c"
permutation "s1b" "s2b" "s2a" "s1d" "s2c" "s1c"
permutation "s1b" "s2b" "s2a" "s2c" "s1d" "s1c"
permutation "s2b" "s1b" "s1d" "s1c" "s2a" "s2c"
permutation "s2b" "s1b" "s1d" "s2a" "s1c" "s2c"
#permutation "s2b" "s1b" "s1d" "s2a" "s2c" "s1c"
#permutation "s2b" "s1b" "s2a" "s1d" "s1c" "s2c"
permutation "s2b" "s1b" "s2a" "s1d" "s2c" "s1c"
permutation "s2b" "s1b" "s2a" "s2c" "s1d" "s1c"
#permutation "s2b" "s2a" "s1b" "s1d" "s1c" "s2c"
permutation "s2b" "s2a" "s1b" "s1d" "s2c" "s1c"
permutation "s2b" "s2a" "s1b" "s2c" "s1d" "s1c"
permutation "s2b" "s2a" "s2c" "s1b" "s1d" "s1c"

View File

@ -0,0 +1,29 @@
# Make sure that FKs referencing partitioned tables actually work.
setup {
drop table if exists ppk, pfk, pfk1;
create table ppk (a int primary key) partition by list (a);
create table ppk1 partition of ppk for values in (1);
insert into ppk values (1);
create table pfk (a int references ppk) partition by list (a);
create table pfk1 partition of pfk for values in (1);
}
session "s1"
step "s1b" { begin; }
step "s1d" { delete from ppk where a = 1; }
step "s1c" { commit; }
session "s2"
step "s2b" { begin; }
step "s2bs" { begin isolation level serializable; select 1; }
step "s2i" { insert into pfk values (1); }
step "s2c" { commit; }
teardown { drop table ppk, pfk, pfk1; }
permutation "s1b" "s1d" "s2b" "s2i" "s1c" "s2c"
permutation "s1b" "s1d" "s2bs" "s2i" "s1c" "s2c"
permutation "s1b" "s2b" "s1d" "s2i" "s1c" "s2c"
permutation "s1b" "s2bs" "s1d" "s2i" "s1c" "s2c"
permutation "s1b" "s2b" "s2i" "s1d" "s2c" "s1c"
permutation "s1b" "s2bs" "s2i" "s1d" "s2c" "s1c"

View File

@ -1532,19 +1532,6 @@ drop table pktable2, fktable2;
--
-- Foreign keys and partitioned tables
--
-- partitioned table in the referenced side are not allowed
CREATE TABLE fk_partitioned_pk (a int, b int, primary key (a, b))
PARTITION BY RANGE (a, b);
-- verify with create table first ...
CREATE TABLE fk_notpartitioned_fk (a int, b int,
FOREIGN KEY (a, b) REFERENCES fk_partitioned_pk);
ERROR: cannot reference partitioned table "fk_partitioned_pk"
-- and then with alter table.
CREATE TABLE fk_notpartitioned_fk_2 (a int, b int);
ALTER TABLE fk_notpartitioned_fk_2 ADD FOREIGN KEY (a, b)
REFERENCES fk_partitioned_pk;
ERROR: cannot reference partitioned table "fk_partitioned_pk"
DROP TABLE fk_partitioned_pk, fk_notpartitioned_fk_2;
-- Creation of a partitioned hierarchy with irregular definitions
CREATE TABLE fk_notpartitioned_pk (fdrop1 int, a int, fdrop2 int, b int,
PRIMARY KEY (a, b));
@ -1686,7 +1673,7 @@ CREATE TABLE fk_partitioned_fk_full (x int, y int) PARTITION BY RANGE (x);
CREATE TABLE fk_partitioned_fk_full_1 PARTITION OF fk_partitioned_fk_full DEFAULT;
INSERT INTO fk_partitioned_fk_full VALUES (1, NULL);
ALTER TABLE fk_partitioned_fk_full ADD FOREIGN KEY (x, y) REFERENCES fk_notpartitioned_pk MATCH FULL; -- fails
ERROR: insert or update on table "fk_partitioned_fk_full" violates foreign key constraint "fk_partitioned_fk_full_x_y_fkey"
ERROR: insert or update on table "fk_partitioned_fk_full_1" violates foreign key constraint "fk_partitioned_fk_full_x_y_fkey"
DETAIL: MATCH FULL does not allow mixing of null and nonnull key values.
TRUNCATE fk_partitioned_fk_full;
ALTER TABLE fk_partitioned_fk_full ADD FOREIGN KEY (x, y) REFERENCES fk_notpartitioned_pk MATCH FULL;
@ -1902,7 +1889,7 @@ CREATE TABLE fk_partitioned_fk_2_2 PARTITION OF fk_partitioned_fk_2 FOR VALUES F
INSERT INTO fk_partitioned_fk_2 VALUES (1600, 601), (1600, 1601);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2
FOR VALUES IN (1600);
ERROR: insert or update on table "fk_partitioned_fk_2" violates foreign key constraint "fk_partitioned_fk_a_b_fkey"
ERROR: insert or update on table "fk_partitioned_fk_2_1" violates foreign key constraint "fk_partitioned_fk_a_b_fkey"
DETAIL: Key (a, b)=(1600, 601) is not present in table "fk_notpartitioned_pk".
INSERT INTO fk_notpartitioned_pk VALUES (1600, 601), (1600, 1601);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2
@ -2037,3 +2024,320 @@ drop cascades to table fkpart1.fk_part
drop cascades to table fkpart1.fk_part_1
drop cascades to table fkpart0.pkey
drop cascades to table fkpart0.fk_part
-- Test a partitioned table as referenced table.
-- Verify basic functionality with a regular partition creation and a partition
-- with a different column layout, as well as partitions added (created and
-- attached) after creating the foreign key.
CREATE SCHEMA fkpart3;
SET search_path TO fkpart3;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (0) TO (1000);
CREATE TABLE pk2 (b int, a int);
ALTER TABLE pk2 DROP COLUMN b;
ALTER TABLE pk2 ALTER a SET NOT NULL;
ALTER TABLE pk ATTACH PARTITION pk2 FOR VALUES FROM (1000) TO (2000);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (0) TO (750);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE fk2 (b int, a int) ;
ALTER TABLE fk2 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk2 FOR VALUES FROM (750) TO (3500);
CREATE TABLE pk3 PARTITION OF pk FOR VALUES FROM (2000) TO (3000);
CREATE TABLE pk4 (LIKE pk);
ALTER TABLE pk ATTACH PARTITION pk4 FOR VALUES FROM (3000) TO (4000);
CREATE TABLE pk5 (c int, b int, a int NOT NULL) PARTITION BY RANGE (a);
ALTER TABLE pk5 DROP COLUMN b, DROP COLUMN c;
CREATE TABLE pk51 PARTITION OF pk5 FOR VALUES FROM (4000) TO (4500);
CREATE TABLE pk52 PARTITION OF pk5 FOR VALUES FROM (4500) TO (5000);
ALTER TABLE pk ATTACH PARTITION pk5 FOR VALUES FROM (4000) TO (5000);
CREATE TABLE fk3 PARTITION OF fk FOR VALUES FROM (3500) TO (5000);
-- these should fail: referenced value not present
INSERT into fk VALUES (1);
ERROR: insert or update on table "fk1" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(1) is not present in table "pk".
INSERT into fk VALUES (1000);
ERROR: insert or update on table "fk2" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(1000) is not present in table "pk".
INSERT into fk VALUES (2000);
ERROR: insert or update on table "fk2" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(2000) is not present in table "pk".
INSERT into fk VALUES (3000);
ERROR: insert or update on table "fk2" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(3000) is not present in table "pk".
INSERT into fk VALUES (4000);
ERROR: insert or update on table "fk3" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(4000) is not present in table "pk".
INSERT into fk VALUES (4500);
ERROR: insert or update on table "fk3" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(4500) is not present in table "pk".
-- insert into the referenced table, now they should work
INSERT into pk VALUES (1), (1000), (2000), (3000), (4000), (4500);
INSERT into fk VALUES (1), (1000), (2000), (3000), (4000), (4500);
-- should fail: referencing value present
DELETE FROM pk WHERE a = 1;
ERROR: update or delete on table "pk1" violates foreign key constraint "fk_a_fkey1" on table "fk"
DETAIL: Key (a)=(1) is still referenced from table "fk".
DELETE FROM pk WHERE a = 1000;
ERROR: update or delete on table "pk2" violates foreign key constraint "fk_a_fkey2" on table "fk"
DETAIL: Key (a)=(1000) is still referenced from table "fk".
DELETE FROM pk WHERE a = 2000;
ERROR: update or delete on table "pk3" violates foreign key constraint "fk_a_fkey3" on table "fk"
DETAIL: Key (a)=(2000) is still referenced from table "fk".
DELETE FROM pk WHERE a = 3000;
ERROR: update or delete on table "pk4" violates foreign key constraint "fk_a_fkey4" on table "fk"
DETAIL: Key (a)=(3000) is still referenced from table "fk".
DELETE FROM pk WHERE a = 4000;
ERROR: update or delete on table "pk51" violates foreign key constraint "fk_a_fkey6" on table "fk"
DETAIL: Key (a)=(4000) is still referenced from table "fk".
DELETE FROM pk WHERE a = 4500;
ERROR: update or delete on table "pk52" violates foreign key constraint "fk_a_fkey7" on table "fk"
DETAIL: Key (a)=(4500) is still referenced from table "fk".
UPDATE pk SET a = 2 WHERE a = 1;
ERROR: update or delete on table "pk1" violates foreign key constraint "fk_a_fkey1" on table "fk"
DETAIL: Key (a)=(1) is still referenced from table "fk".
UPDATE pk SET a = 1002 WHERE a = 1000;
ERROR: update or delete on table "pk2" violates foreign key constraint "fk_a_fkey2" on table "fk"
DETAIL: Key (a)=(1000) is still referenced from table "fk".
UPDATE pk SET a = 2002 WHERE a = 2000;
ERROR: update or delete on table "pk3" violates foreign key constraint "fk_a_fkey3" on table "fk"
DETAIL: Key (a)=(2000) is still referenced from table "fk".
UPDATE pk SET a = 3002 WHERE a = 3000;
ERROR: update or delete on table "pk4" violates foreign key constraint "fk_a_fkey4" on table "fk"
DETAIL: Key (a)=(3000) is still referenced from table "fk".
UPDATE pk SET a = 4002 WHERE a = 4000;
ERROR: update or delete on table "pk51" violates foreign key constraint "fk_a_fkey6" on table "fk"
DETAIL: Key (a)=(4000) is still referenced from table "fk".
UPDATE pk SET a = 4502 WHERE a = 4500;
ERROR: update or delete on table "pk52" violates foreign key constraint "fk_a_fkey7" on table "fk"
DETAIL: Key (a)=(4500) is still referenced from table "fk".
-- now they should work
DELETE FROM fk;
UPDATE pk SET a = 2 WHERE a = 1;
DELETE FROM pk WHERE a = 2;
UPDATE pk SET a = 1002 WHERE a = 1000;
DELETE FROM pk WHERE a = 1002;
UPDATE pk SET a = 2002 WHERE a = 2000;
DELETE FROM pk WHERE a = 2002;
UPDATE pk SET a = 3002 WHERE a = 3000;
DELETE FROM pk WHERE a = 3002;
UPDATE pk SET a = 4002 WHERE a = 4000;
DELETE FROM pk WHERE a = 4002;
UPDATE pk SET a = 4502 WHERE a = 4500;
DELETE FROM pk WHERE a = 4502;
CREATE SCHEMA fkpart4;
SET search_path TO fkpart4;
-- dropping/detaching PARTITIONs is prevented if that would break
-- a foreign key's existing data
CREATE TABLE droppk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE droppk1 PARTITION OF droppk FOR VALUES FROM (0) TO (1000);
CREATE TABLE droppk_d PARTITION OF droppk DEFAULT;
CREATE TABLE droppk2 PARTITION OF droppk FOR VALUES FROM (1000) TO (2000)
PARTITION BY RANGE (a);
CREATE TABLE droppk21 PARTITION OF droppk2 FOR VALUES FROM (1000) TO (1400);
CREATE TABLE droppk2_d PARTITION OF droppk2 DEFAULT;
INSERT into droppk VALUES (1), (1000), (1500), (2000);
CREATE TABLE dropfk (a int REFERENCES droppk);
INSERT into dropfk VALUES (1), (1000), (1500), (2000);
-- these should all fail
ALTER TABLE droppk DETACH PARTITION droppk_d;
ERROR: removing partition "droppk_d" violates foreign key constraint "dropfk_a_fkey5"
DETAIL: Key (a)=(2000) still referenced from table "dropfk".
ALTER TABLE droppk2 DETACH PARTITION droppk2_d;
ERROR: removing partition "droppk2_d" violates foreign key constraint "dropfk_a_fkey4"
DETAIL: Key (a)=(1500) still referenced from table "dropfk".
ALTER TABLE droppk DETACH PARTITION droppk1;
ERROR: removing partition "droppk1" violates foreign key constraint "dropfk_a_fkey1"
DETAIL: Key (a)=(1) still referenced from table "dropfk".
ALTER TABLE droppk DETACH PARTITION droppk2;
ERROR: removing partition "droppk2" violates foreign key constraint "dropfk_a_fkey2"
DETAIL: Key (a)=(1000) still referenced from table "dropfk".
ALTER TABLE droppk2 DETACH PARTITION droppk21;
ERROR: removing partition "droppk21" violates foreign key constraint "dropfk_a_fkey3"
DETAIL: Key (a)=(1000) still referenced from table "dropfk".
-- dropping partitions is disallowed
DROP TABLE droppk_d;
ERROR: cannot drop table droppk_d because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk_d
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk2_d;
ERROR: cannot drop table droppk2_d because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk2_d
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk1;
ERROR: cannot drop table droppk1 because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk1
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk2;
ERROR: cannot drop table droppk2 because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk2
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk21;
ERROR: cannot drop table droppk21 because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk21
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DELETE FROM dropfk;
-- dropping partitions is disallowed, even when no referencing values
DROP TABLE droppk_d;
ERROR: cannot drop table droppk_d because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk_d
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk2_d;
ERROR: cannot drop table droppk2_d because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk2_d
HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE droppk1;
ERROR: cannot drop table droppk1 because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk1
HINT: Use DROP ... CASCADE to drop the dependent objects too.
-- but DETACH is allowed, and DROP afterwards works
ALTER TABLE droppk2 DETACH PARTITION droppk21;
DROP TABLE droppk2;
ERROR: cannot drop table droppk2 because other objects depend on it
DETAIL: constraint dropfk_a_fkey on table dropfk depends on table droppk2
HINT: Use DROP ... CASCADE to drop the dependent objects too.
-- Verify that initial constraint creation and cloning behave correctly
CREATE SCHEMA fkpart5;
SET search_path TO fkpart5;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY LIST (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES IN (1);
CREATE TABLE fk (a int) PARTITION BY LIST (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES IN (1);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE pk2 PARTITION OF pk FOR VALUES IN (2);
CREATE TABLE pk3 (a int NOT NULL) PARTITION BY LIST (a);
CREATE TABLE pk31 PARTITION OF pk3 FOR VALUES IN (31);
CREATE TABLE pk32 (b int, a int NOT NULL);
ALTER TABLE pk32 DROP COLUMN b;
ALTER TABLE pk3 ATTACH PARTITION pk32 FOR VALUES IN (32);
ALTER TABLE pk ATTACH PARTITION pk3 FOR VALUES IN (31, 32);
CREATE TABLE fk2 PARTITION OF fk FOR VALUES IN (2);
CREATE TABLE fk3 (b int, a int);
ALTER TABLE fk3 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk3 FOR VALUES IN (3);
SELECT pg_describe_object('pg_constraint'::regclass, oid, 0), confrelid::regclass,
CASE WHEN conparentid <> 0 THEN pg_describe_object('pg_constraint'::regclass, conparentid, 0) ELSE 'TOP' END
FROM pg_catalog.pg_constraint
WHERE conrelid IN (SELECT relid FROM pg_partition_tree('fk'))
ORDER BY conrelid::regclass::text, conname;
pg_describe_object | confrelid | case
------------------------------------+-----------+-----------------------------------
constraint fk_a_fkey on table fk | pk | TOP
constraint fk_a_fkey1 on table fk | pk1 | constraint fk_a_fkey on table fk
constraint fk_a_fkey2 on table fk | pk11 | constraint fk_a_fkey1 on table fk
constraint fk_a_fkey3 on table fk | pk2 | constraint fk_a_fkey on table fk
constraint fk_a_fkey4 on table fk | pk3 | constraint fk_a_fkey on table fk
constraint fk_a_fkey5 on table fk | pk31 | constraint fk_a_fkey4 on table fk
constraint fk_a_fkey6 on table fk | pk32 | constraint fk_a_fkey4 on table fk
constraint fk_a_fkey on table fk1 | pk | constraint fk_a_fkey on table fk
constraint fk_a_fkey on table fk11 | pk | constraint fk_a_fkey on table fk1
constraint fk_a_fkey on table fk2 | pk | constraint fk_a_fkey on table fk
constraint fk_a_fkey on table fk3 | pk | constraint fk_a_fkey on table fk
(11 rows)
CREATE TABLE fk4 (LIKE fk);
INSERT INTO fk4 VALUES (50);
ALTER TABLE fk ATTACH PARTITION fk4 FOR VALUES IN (50);
ERROR: insert or update on table "fk4" violates foreign key constraint "fk_a_fkey"
DETAIL: Key (a)=(50) is not present in table "pk".
-- Verify ON UPDATE/DELETE behavior
CREATE SCHEMA fkpart6;
SET search_path TO fkpart6;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES FROM (1) TO (50);
CREATE TABLE pk12 PARTITION OF pk1 FOR VALUES FROM (50) TO (100);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE CASCADE ON DELETE CASCADE;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO pk VALUES (1);
INSERT INTO fk VALUES (1);
UPDATE pk SET a = 20;
SELECT tableoid::regclass, * FROM fk;
tableoid | a
----------+----
fk12 | 20
(1 row)
DELETE FROM pk WHERE a = 20;
SELECT tableoid::regclass, * FROM fk;
tableoid | a
----------+---
(0 rows)
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (50);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET NULL ON DELETE SET NULL;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (50);
UPDATE pk SET a = 21 WHERE a = 20;
DELETE FROM pk WHERE a = 50;
SELECT tableoid::regclass, * FROM fk;
tableoid | a
----------+---
fk_d |
fk_d |
(2 rows)
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30), (50);
CREATE TABLE fk (id int, a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET DEFAULT ON DELETE SET DEFAULT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (1, 20), (2, 30);
DELETE FROM pk WHERE a = 20 RETURNING *;
a
----
20
(1 row)
UPDATE pk SET a = 90 WHERE a = 30 RETURNING *;
a
----
90
(1 row)
SELECT tableoid::regclass, * FROM fk;
tableoid | id | a
----------+----+----
fk12 | 1 | 50
fk12 | 2 | 50
(2 rows)
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30);
CREATE TABLE fk (a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE RESTRICT ON DELETE RESTRICT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (30);
DELETE FROM pk WHERE a = 20;
ERROR: update or delete on table "pk11" violates foreign key constraint "fk_a_fkey2" on table "fk"
DETAIL: Key (a)=(20) is still referenced from table "fk".
UPDATE pk SET a = 90 WHERE a = 30;
ERROR: update or delete on table "pk11" violates foreign key constraint "fk_a_fkey2" on table "fk"
DETAIL: Key (a)=(30) is still referenced from table "fk".
SELECT tableoid::regclass, * FROM fk;
tableoid | a
----------+----
fk12 | 20
fk12 | 30
(2 rows)
DROP TABLE fk;

View File

@ -1145,18 +1145,6 @@ drop table pktable2, fktable2;
-- Foreign keys and partitioned tables
--
-- partitioned table in the referenced side are not allowed
CREATE TABLE fk_partitioned_pk (a int, b int, primary key (a, b))
PARTITION BY RANGE (a, b);
-- verify with create table first ...
CREATE TABLE fk_notpartitioned_fk (a int, b int,
FOREIGN KEY (a, b) REFERENCES fk_partitioned_pk);
-- and then with alter table.
CREATE TABLE fk_notpartitioned_fk_2 (a int, b int);
ALTER TABLE fk_notpartitioned_fk_2 ADD FOREIGN KEY (a, b)
REFERENCES fk_partitioned_pk;
DROP TABLE fk_partitioned_pk, fk_notpartitioned_fk_2;
-- Creation of a partitioned hierarchy with irregular definitions
CREATE TABLE fk_notpartitioned_pk (fdrop1 int, a int, fdrop2 int, b int,
PRIMARY KEY (a, b));
@ -1443,3 +1431,204 @@ alter table fkpart2.fk_part_1 drop constraint fkey; -- ok
alter table fkpart2.fk_part_1_1 drop constraint my_fkey; -- doesn't exist
drop schema fkpart0, fkpart1, fkpart2 cascade;
-- Test a partitioned table as referenced table.
-- Verify basic functionality with a regular partition creation and a partition
-- with a different column layout, as well as partitions added (created and
-- attached) after creating the foreign key.
CREATE SCHEMA fkpart3;
SET search_path TO fkpart3;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (0) TO (1000);
CREATE TABLE pk2 (b int, a int);
ALTER TABLE pk2 DROP COLUMN b;
ALTER TABLE pk2 ALTER a SET NOT NULL;
ALTER TABLE pk ATTACH PARTITION pk2 FOR VALUES FROM (1000) TO (2000);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (0) TO (750);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE fk2 (b int, a int) ;
ALTER TABLE fk2 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk2 FOR VALUES FROM (750) TO (3500);
CREATE TABLE pk3 PARTITION OF pk FOR VALUES FROM (2000) TO (3000);
CREATE TABLE pk4 (LIKE pk);
ALTER TABLE pk ATTACH PARTITION pk4 FOR VALUES FROM (3000) TO (4000);
CREATE TABLE pk5 (c int, b int, a int NOT NULL) PARTITION BY RANGE (a);
ALTER TABLE pk5 DROP COLUMN b, DROP COLUMN c;
CREATE TABLE pk51 PARTITION OF pk5 FOR VALUES FROM (4000) TO (4500);
CREATE TABLE pk52 PARTITION OF pk5 FOR VALUES FROM (4500) TO (5000);
ALTER TABLE pk ATTACH PARTITION pk5 FOR VALUES FROM (4000) TO (5000);
CREATE TABLE fk3 PARTITION OF fk FOR VALUES FROM (3500) TO (5000);
-- these should fail: referenced value not present
INSERT into fk VALUES (1);
INSERT into fk VALUES (1000);
INSERT into fk VALUES (2000);
INSERT into fk VALUES (3000);
INSERT into fk VALUES (4000);
INSERT into fk VALUES (4500);
-- insert into the referenced table, now they should work
INSERT into pk VALUES (1), (1000), (2000), (3000), (4000), (4500);
INSERT into fk VALUES (1), (1000), (2000), (3000), (4000), (4500);
-- should fail: referencing value present
DELETE FROM pk WHERE a = 1;
DELETE FROM pk WHERE a = 1000;
DELETE FROM pk WHERE a = 2000;
DELETE FROM pk WHERE a = 3000;
DELETE FROM pk WHERE a = 4000;
DELETE FROM pk WHERE a = 4500;
UPDATE pk SET a = 2 WHERE a = 1;
UPDATE pk SET a = 1002 WHERE a = 1000;
UPDATE pk SET a = 2002 WHERE a = 2000;
UPDATE pk SET a = 3002 WHERE a = 3000;
UPDATE pk SET a = 4002 WHERE a = 4000;
UPDATE pk SET a = 4502 WHERE a = 4500;
-- now they should work
DELETE FROM fk;
UPDATE pk SET a = 2 WHERE a = 1;
DELETE FROM pk WHERE a = 2;
UPDATE pk SET a = 1002 WHERE a = 1000;
DELETE FROM pk WHERE a = 1002;
UPDATE pk SET a = 2002 WHERE a = 2000;
DELETE FROM pk WHERE a = 2002;
UPDATE pk SET a = 3002 WHERE a = 3000;
DELETE FROM pk WHERE a = 3002;
UPDATE pk SET a = 4002 WHERE a = 4000;
DELETE FROM pk WHERE a = 4002;
UPDATE pk SET a = 4502 WHERE a = 4500;
DELETE FROM pk WHERE a = 4502;
CREATE SCHEMA fkpart4;
SET search_path TO fkpart4;
-- dropping/detaching PARTITIONs is prevented if that would break
-- a foreign key's existing data
CREATE TABLE droppk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE droppk1 PARTITION OF droppk FOR VALUES FROM (0) TO (1000);
CREATE TABLE droppk_d PARTITION OF droppk DEFAULT;
CREATE TABLE droppk2 PARTITION OF droppk FOR VALUES FROM (1000) TO (2000)
PARTITION BY RANGE (a);
CREATE TABLE droppk21 PARTITION OF droppk2 FOR VALUES FROM (1000) TO (1400);
CREATE TABLE droppk2_d PARTITION OF droppk2 DEFAULT;
INSERT into droppk VALUES (1), (1000), (1500), (2000);
CREATE TABLE dropfk (a int REFERENCES droppk);
INSERT into dropfk VALUES (1), (1000), (1500), (2000);
-- these should all fail
ALTER TABLE droppk DETACH PARTITION droppk_d;
ALTER TABLE droppk2 DETACH PARTITION droppk2_d;
ALTER TABLE droppk DETACH PARTITION droppk1;
ALTER TABLE droppk DETACH PARTITION droppk2;
ALTER TABLE droppk2 DETACH PARTITION droppk21;
-- dropping partitions is disallowed
DROP TABLE droppk_d;
DROP TABLE droppk2_d;
DROP TABLE droppk1;
DROP TABLE droppk2;
DROP TABLE droppk21;
DELETE FROM dropfk;
-- dropping partitions is disallowed, even when no referencing values
DROP TABLE droppk_d;
DROP TABLE droppk2_d;
DROP TABLE droppk1;
-- but DETACH is allowed, and DROP afterwards works
ALTER TABLE droppk2 DETACH PARTITION droppk21;
DROP TABLE droppk2;
-- Verify that initial constraint creation and cloning behave correctly
CREATE SCHEMA fkpart5;
SET search_path TO fkpart5;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY LIST (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES IN (1);
CREATE TABLE fk (a int) PARTITION BY LIST (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES IN (1);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE pk2 PARTITION OF pk FOR VALUES IN (2);
CREATE TABLE pk3 (a int NOT NULL) PARTITION BY LIST (a);
CREATE TABLE pk31 PARTITION OF pk3 FOR VALUES IN (31);
CREATE TABLE pk32 (b int, a int NOT NULL);
ALTER TABLE pk32 DROP COLUMN b;
ALTER TABLE pk3 ATTACH PARTITION pk32 FOR VALUES IN (32);
ALTER TABLE pk ATTACH PARTITION pk3 FOR VALUES IN (31, 32);
CREATE TABLE fk2 PARTITION OF fk FOR VALUES IN (2);
CREATE TABLE fk3 (b int, a int);
ALTER TABLE fk3 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk3 FOR VALUES IN (3);
SELECT pg_describe_object('pg_constraint'::regclass, oid, 0), confrelid::regclass,
CASE WHEN conparentid <> 0 THEN pg_describe_object('pg_constraint'::regclass, conparentid, 0) ELSE 'TOP' END
FROM pg_catalog.pg_constraint
WHERE conrelid IN (SELECT relid FROM pg_partition_tree('fk'))
ORDER BY conrelid::regclass::text, conname;
CREATE TABLE fk4 (LIKE fk);
INSERT INTO fk4 VALUES (50);
ALTER TABLE fk ATTACH PARTITION fk4 FOR VALUES IN (50);
-- Verify ON UPDATE/DELETE behavior
CREATE SCHEMA fkpart6;
SET search_path TO fkpart6;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES FROM (1) TO (50);
CREATE TABLE pk12 PARTITION OF pk1 FOR VALUES FROM (50) TO (100);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE CASCADE ON DELETE CASCADE;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO pk VALUES (1);
INSERT INTO fk VALUES (1);
UPDATE pk SET a = 20;
SELECT tableoid::regclass, * FROM fk;
DELETE FROM pk WHERE a = 20;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (50);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET NULL ON DELETE SET NULL;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (50);
UPDATE pk SET a = 21 WHERE a = 20;
DELETE FROM pk WHERE a = 50;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30), (50);
CREATE TABLE fk (id int, a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET DEFAULT ON DELETE SET DEFAULT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (1, 20), (2, 30);
DELETE FROM pk WHERE a = 20 RETURNING *;
UPDATE pk SET a = 90 WHERE a = 30 RETURNING *;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30);
CREATE TABLE fk (a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE RESTRICT ON DELETE RESTRICT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (30);
DELETE FROM pk WHERE a = 20;
UPDATE pk SET a = 90 WHERE a = 30;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;