1
0
mirror of https://github.com/postgres/postgres.git synced 2025-05-01 01:04:50 +03:00

Fix NO ACTION temporal foreign keys when the referenced endpoints change

If a referenced UPDATE changes the temporal start/end times, shrinking
the span the row is valid, we get a false return from
ri_Check_Pk_Match(), but overlapping references may still be valid, if
their reference didn't overlap with the removed span.

We need to consider what span(s) are still provided in the referenced
table.  Instead of returning that from ri_Check_Pk_Match(), we can
just look it up in the main SQL query.

Reported-by: Sam Gabrielsson <sam@movsom.se>
Author: Paul Jungwirth <pj@illuminatedcomputing.com>
Discussion: https://www.postgresql.org/message-id/flat/CA+renyUApHgSZF9-nd-a0+OPGharLQLO=mDHcY4_qQ0+noCUVg@mail.gmail.com
This commit is contained in:
Peter Eisentraut 2025-01-21 14:34:44 +01:00
parent 888d4523f0
commit 1772d554b0
7 changed files with 233 additions and 7 deletions

View File

@ -1618,11 +1618,14 @@ DeconstructFkConstraintRow(HeapTuple tuple, int *numfks,
* aggedcontainedbyoperoid is also a ContainedBy operator,
* but one whose rhs is a multirange.
* That way foreign keys can compare fkattr <@ range_agg(pkattr).
* intersectoperoid is used by NO ACTION constraints to trim the range being considered
* to just what was updated/deleted.
*/
void
FindFKPeriodOpers(Oid opclass,
Oid *containedbyoperoid,
Oid *aggedcontainedbyoperoid)
Oid *aggedcontainedbyoperoid,
Oid *intersectoperoid)
{
Oid opfamily = InvalidOid;
Oid opcintype = InvalidOid;
@ -1663,6 +1666,18 @@ FindFKPeriodOpers(Oid opclass,
COMPARE_CONTAINED_BY,
aggedcontainedbyoperoid,
&strat);
switch (opcintype)
{
case ANYRANGEOID:
*intersectoperoid = OID_RANGE_INTERSECT_RANGE_OP;
break;
case ANYMULTIRANGEOID:
*intersectoperoid = OID_MULTIRANGE_INTERSECT_MULTIRANGE_OP;
break;
default:
elog(ERROR, "unexpected opcintype: %u", opcintype);
}
}
/*

View File

@ -10260,8 +10260,10 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel,
{
Oid periodoperoid;
Oid aggedperiodoperoid;
Oid intersectoperoid;
FindFKPeriodOpers(opclasses[numpks - 1], &periodoperoid, &aggedperiodoperoid);
FindFKPeriodOpers(opclasses[numpks - 1], &periodoperoid, &aggedperiodoperoid,
&intersectoperoid);
}
/* First, create the constraint catalog entry itself. */

View File

@ -129,6 +129,7 @@ typedef struct RI_ConstraintInfo
Oid ff_eq_oprs[RI_MAX_NUMKEYS]; /* equality operators (FK = FK) */
Oid period_contained_by_oper; /* anyrange <@ anyrange */
Oid agged_period_contained_by_oper; /* fkattr <@ range_agg(pkattr) */
Oid period_intersect_oper; /* anyrange * anyrange */
dlist_node valid_link; /* Link in list of valid entries */
} RI_ConstraintInfo;
@ -734,8 +735,11 @@ ri_restrict(TriggerData *trigdata, bool is_no_action)
* not do anything. However, this check should only be made in the NO
* ACTION case; in RESTRICT cases we don't wish to allow another row to be
* substituted.
*
* If the foreign key has PERIOD, we incorporate looking for replacement
* rows in the main SQL query below, so we needn't do it here.
*/
if (is_no_action &&
if (is_no_action && !riinfo->hasperiod &&
ri_Check_Pk_Match(pk_rel, fk_rel, oldslot, riinfo))
{
table_close(fk_rel, RowShareLock);
@ -753,8 +757,10 @@ ri_restrict(TriggerData *trigdata, bool is_no_action)
if ((qplan = ri_FetchPreparedPlan(&qkey)) == NULL)
{
StringInfoData querybuf;
char pkrelname[MAX_QUOTED_REL_NAME_LEN];
char fkrelname[MAX_QUOTED_REL_NAME_LEN];
char attname[MAX_QUOTED_NAME_LEN];
char periodattname[MAX_QUOTED_NAME_LEN];
char paramname[16];
const char *querysep;
Oid queryoids[RI_MAX_NUMKEYS];
@ -790,6 +796,89 @@ ri_restrict(TriggerData *trigdata, bool is_no_action)
querysep = "AND";
queryoids[i] = pk_type;
}
/*----------
* For temporal foreign keys, a reference could still be valid if the
* referenced range didn't change too much. Also if a referencing
* range extends past the current PK row, we don't want to check that
* part: some other PK row should fulfill it. We only want to check
* the part matching the PK record we've changed. Therefore to find
* invalid records we do this:
*
* SELECT 1 FROM [ONLY] <fktable> x WHERE $1 = x.fkatt1 [AND ...]
* -- begin temporal
* AND $n && x.fkperiod
* AND NOT coalesce((x.fkperiod * $n) <@
* (SELECT range_agg(r)
* FROM (SELECT y.pkperiod r
* FROM [ONLY] <pktable> y
* WHERE $1 = y.pkatt1 [AND ...] AND $n && y.pkperiod
* FOR KEY SHARE OF y) y2), false)
* -- end temporal
* FOR KEY SHARE OF x
*
* We need the coalesce in case the first subquery returns no rows.
* We need the second subquery because FOR KEY SHARE doesn't support
* aggregate queries.
*/
if (riinfo->hasperiod && is_no_action)
{
Oid pk_period_type = RIAttType(pk_rel, riinfo->pk_attnums[riinfo->nkeys - 1]);
Oid fk_period_type = RIAttType(fk_rel, riinfo->fk_attnums[riinfo->nkeys - 1]);
StringInfoData intersectbuf;
StringInfoData replacementsbuf;
char *pk_only = pk_rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE ?
"" : "ONLY ";
quoteOneName(attname, RIAttName(fk_rel, riinfo->fk_attnums[riinfo->nkeys - 1]));
sprintf(paramname, "$%d", riinfo->nkeys);
appendStringInfoString(&querybuf, " AND NOT coalesce(");
/* Intersect the fk with the old pk range */
initStringInfo(&intersectbuf);
appendStringInfoString(&intersectbuf, "(");
ri_GenerateQual(&intersectbuf, "",
attname, fk_period_type,
riinfo->period_intersect_oper,
paramname, pk_period_type);
appendStringInfoString(&intersectbuf, ")");
/* Find the remaining history */
initStringInfo(&replacementsbuf);
appendStringInfoString(&replacementsbuf, "(SELECT pg_catalog.range_agg(r) FROM ");
quoteOneName(periodattname, RIAttName(pk_rel, riinfo->pk_attnums[riinfo->nkeys - 1]));
quoteRelationName(pkrelname, pk_rel);
appendStringInfo(&replacementsbuf, "(SELECT y.%s r FROM %s%s y",
periodattname, pk_only, pkrelname);
/* Restrict pk rows to what matches */
querysep = "WHERE";
for (int i = 0; i < riinfo->nkeys; i++)
{
Oid pk_type = RIAttType(pk_rel, riinfo->pk_attnums[i]);
quoteOneName(attname,
RIAttName(pk_rel, riinfo->pk_attnums[i]));
sprintf(paramname, "$%d", i + 1);
ri_GenerateQual(&replacementsbuf, querysep,
paramname, pk_type,
riinfo->pp_eq_oprs[i],
attname, pk_type);
querysep = "AND";
queryoids[i] = pk_type;
}
appendStringInfoString(&replacementsbuf, " FOR KEY SHARE OF y) y2)");
ri_GenerateQual(&querybuf, "",
intersectbuf.data, fk_period_type,
riinfo->agged_period_contained_by_oper,
replacementsbuf.data, ANYMULTIRANGEOID);
/* end of coalesce: */
appendStringInfoString(&querybuf, ", false)");
}
appendStringInfoString(&querybuf, " FOR KEY SHARE OF x");
/* Prepare and save the plan */
@ -2251,7 +2340,8 @@ ri_LoadConstraintInfo(Oid constraintOid)
FindFKPeriodOpers(opclass,
&riinfo->period_contained_by_oper,
&riinfo->agged_period_contained_by_oper);
&riinfo->agged_period_contained_by_oper,
&riinfo->period_intersect_oper);
}
ReleaseSysCache(tup);

View File

@ -290,7 +290,8 @@ extern void DeconstructFkConstraintRow(HeapTuple tuple, int *numfks,
int *num_fk_del_set_cols, AttrNumber *fk_del_set_cols);
extern void FindFKPeriodOpers(Oid opclass,
Oid *containedbyoperoid,
Oid *aggedcontainedbyoperoid);
Oid *aggedcontainedbyoperoid,
Oid *intersectoperoid);
extern bool check_functional_grouping(Oid relid,
Index varno, Index varlevelsup,

View File

@ -3150,7 +3150,8 @@
{ oid => '3899', descr => 'range difference',
oprname => '-', oprleft => 'anyrange', oprright => 'anyrange',
oprresult => 'anyrange', oprcode => 'range_minus' },
{ oid => '3900', descr => 'range intersection',
{ oid => '3900', oid_symbol => 'OID_RANGE_INTERSECT_RANGE_OP',
descr => 'range intersection',
oprname => '*', oprleft => 'anyrange', oprright => 'anyrange',
oprresult => 'anyrange', oprcom => '*(anyrange,anyrange)',
oprcode => 'range_intersect' },
@ -3417,7 +3418,8 @@
{ oid => '4393', descr => 'multirange minus',
oprname => '-', oprleft => 'anymultirange', oprright => 'anymultirange',
oprresult => 'anymultirange', oprcode => 'multirange_minus' },
{ oid => '4394', descr => 'multirange intersect',
{ oid => '4394', oid_symbol => 'OID_MULTIRANGE_INTERSECT_MULTIRANGE_OP',
descr => 'multirange intersect',
oprname => '*', oprleft => 'anymultirange', oprright => 'anymultirange',
oprresult => 'anymultirange', oprcom => '*(anymultirange,anymultirange)',
oprcode => 'multirange_intersect' },

View File

@ -1704,6 +1704,37 @@ UPDATE temporal_rng
SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN daterange('2018-01-01', '2018-01-05')
WHEN lower(valid_at) = '2018-02-01' THEN daterange('2018-01-05', '2018-03-01') END
WHERE id = '[6,7)';
-- a PK update shrinking the referenced range but still valid:
-- There are two references: one fulfilled by the first pk row,
-- the other fulfilled by both pk rows combined.
INSERT INTO temporal_rng (id, valid_at) VALUES
('[1,2)', daterange('2018-01-01', '2018-03-01')),
('[1,2)', daterange('2018-03-01', '2018-06-01'));
INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES
('[1,2)', daterange('2018-01-15', '2018-02-01'), '[1,2)'),
('[2,3)', daterange('2018-01-15', '2018-05-01'), '[1,2)');
UPDATE temporal_rng SET valid_at = daterange('2018-01-15', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update growing the referenced range is fine:
UPDATE temporal_rng SET valid_at = daterange('2018-01-01', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date;
-- a PK update shrinking the referenced range and changing the id invalidates the whole range (error):
UPDATE temporal_rng SET id = '[2,3)', valid_at = daterange('2018-01-15', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng"
DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_rng2rng".
-- a PK update changing only the id invalidates the whole range (error):
UPDATE temporal_rng SET id = '[2,3)'
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
ERROR: update or delete on table "temporal_rng" violates foreign key constraint "temporal_fk_rng2rng_fk" on table "temporal_fk_rng2rng"
DETAIL: Key (id, valid_at)=([1,2), [2018-01-01,2018-03-01)) is still referenced from table "temporal_fk_rng2rng".
-- a PK update that loses time from both ends, but is still valid:
INSERT INTO temporal_rng (id, valid_at) VALUES
('[2,3)', daterange('2018-01-01', '2018-03-01'));
INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES
('[5,6)', daterange('2018-01-15', '2018-02-01'), '[2,3)');
UPDATE temporal_rng SET valid_at = daterange('2018-01-15', '2018-02-15')
WHERE id = '[2,3)';
-- a PK update that fails because both are referenced:
UPDATE temporal_rng SET valid_at = daterange('2016-01-01', '2016-02-01')
WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01');
@ -2196,6 +2227,37 @@ UPDATE temporal_mltrng
SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN datemultirange(daterange('2018-01-01', '2018-01-05'))
WHEN lower(valid_at) = '2018-02-01' THEN datemultirange(daterange('2018-01-05', '2018-03-01')) END
WHERE id = '[6,7)';
-- a PK update shrinking the referenced multirange but still valid:
-- There are two references: one fulfilled by the first pk row,
-- the other fulfilled by both pk rows combined.
INSERT INTO temporal_mltrng (id, valid_at) VALUES
('[1,2)', datemultirange(daterange('2018-01-01', '2018-03-01'))),
('[1,2)', datemultirange(daterange('2018-03-01', '2018-06-01')));
INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES
('[1,2)', datemultirange(daterange('2018-01-15', '2018-02-01')), '[1,2)'),
('[2,3)', datemultirange(daterange('2018-01-15', '2018-05-01')), '[1,2)');
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-15', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update growing the referenced multirange is fine:
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-01', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date;
-- a PK update shrinking the referenced multirange and changing the id invalidates the whole multirange (error):
UPDATE temporal_mltrng SET id = '[2,3)', valid_at = datemultirange(daterange('2018-01-15', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng"
DETAIL: Key (id, valid_at)=([1,2), {[2018-01-01,2018-03-01)}) is still referenced from table "temporal_fk_mltrng2mltrng".
-- a PK update changing only the id invalidates the whole multirange (error):
UPDATE temporal_mltrng SET id = '[2,3)'
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
ERROR: update or delete on table "temporal_mltrng" violates foreign key constraint "temporal_fk_mltrng2mltrng_fk" on table "temporal_fk_mltrng2mltrng"
DETAIL: Key (id, valid_at)=([1,2), {[2018-01-01,2018-03-01)}) is still referenced from table "temporal_fk_mltrng2mltrng".
-- a PK update that loses time from both ends, but is still valid:
INSERT INTO temporal_mltrng (id, valid_at) VALUES
('[2,3)', datemultirange(daterange('2018-01-01', '2018-03-01')));
INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES
('[5,6)', datemultirange(daterange('2018-01-15', '2018-02-01')), '[2,3)');
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-15', '2018-02-15'))
WHERE id = '[2,3)';
-- a PK update that fails because both are referenced:
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2016-01-01', '2016-02-01'))
WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01'));

View File

@ -1249,6 +1249,33 @@ UPDATE temporal_rng
SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN daterange('2018-01-01', '2018-01-05')
WHEN lower(valid_at) = '2018-02-01' THEN daterange('2018-01-05', '2018-03-01') END
WHERE id = '[6,7)';
-- a PK update shrinking the referenced range but still valid:
-- There are two references: one fulfilled by the first pk row,
-- the other fulfilled by both pk rows combined.
INSERT INTO temporal_rng (id, valid_at) VALUES
('[1,2)', daterange('2018-01-01', '2018-03-01')),
('[1,2)', daterange('2018-03-01', '2018-06-01'));
INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES
('[1,2)', daterange('2018-01-15', '2018-02-01'), '[1,2)'),
('[2,3)', daterange('2018-01-15', '2018-05-01'), '[1,2)');
UPDATE temporal_rng SET valid_at = daterange('2018-01-15', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update growing the referenced range is fine:
UPDATE temporal_rng SET valid_at = daterange('2018-01-01', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date;
-- a PK update shrinking the referenced range and changing the id invalidates the whole range (error):
UPDATE temporal_rng SET id = '[2,3)', valid_at = daterange('2018-01-15', '2018-03-01')
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update changing only the id invalidates the whole range (error):
UPDATE temporal_rng SET id = '[2,3)'
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update that loses time from both ends, but is still valid:
INSERT INTO temporal_rng (id, valid_at) VALUES
('[2,3)', daterange('2018-01-01', '2018-03-01'));
INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES
('[5,6)', daterange('2018-01-15', '2018-02-01'), '[2,3)');
UPDATE temporal_rng SET valid_at = daterange('2018-01-15', '2018-02-15')
WHERE id = '[2,3)';
-- a PK update that fails because both are referenced:
UPDATE temporal_rng SET valid_at = daterange('2016-01-01', '2016-02-01')
WHERE id = '[5,6)' AND valid_at = daterange('2018-01-01', '2018-02-01');
@ -1710,6 +1737,33 @@ UPDATE temporal_mltrng
SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01' THEN datemultirange(daterange('2018-01-01', '2018-01-05'))
WHEN lower(valid_at) = '2018-02-01' THEN datemultirange(daterange('2018-01-05', '2018-03-01')) END
WHERE id = '[6,7)';
-- a PK update shrinking the referenced multirange but still valid:
-- There are two references: one fulfilled by the first pk row,
-- the other fulfilled by both pk rows combined.
INSERT INTO temporal_mltrng (id, valid_at) VALUES
('[1,2)', datemultirange(daterange('2018-01-01', '2018-03-01'))),
('[1,2)', datemultirange(daterange('2018-03-01', '2018-06-01')));
INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES
('[1,2)', datemultirange(daterange('2018-01-15', '2018-02-01')), '[1,2)'),
('[2,3)', datemultirange(daterange('2018-01-15', '2018-05-01')), '[1,2)');
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-15', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update growing the referenced multirange is fine:
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-01', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-25'::date;
-- a PK update shrinking the referenced multirange and changing the id invalidates the whole multirange (error):
UPDATE temporal_mltrng SET id = '[2,3)', valid_at = datemultirange(daterange('2018-01-15', '2018-03-01'))
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update changing only the id invalidates the whole multirange (error):
UPDATE temporal_mltrng SET id = '[2,3)'
WHERE id = '[1,2)' AND valid_at @> '2018-01-15'::date;
-- a PK update that loses time from both ends, but is still valid:
INSERT INTO temporal_mltrng (id, valid_at) VALUES
('[2,3)', datemultirange(daterange('2018-01-01', '2018-03-01')));
INSERT INTO temporal_fk_mltrng2mltrng (id, valid_at, parent_id) VALUES
('[5,6)', datemultirange(daterange('2018-01-15', '2018-02-01')), '[2,3)');
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2018-01-15', '2018-02-15'))
WHERE id = '[2,3)';
-- a PK update that fails because both are referenced:
UPDATE temporal_mltrng SET valid_at = datemultirange(daterange('2016-01-01', '2016-02-01'))
WHERE id = '[5,6)' AND valid_at = datemultirange(daterange('2018-01-01', '2018-02-01'));