1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-31 22:04:40 +03:00

Fix some issues in contrib/spi/refint.c.

check_foreign_key incorrectly used a single cache entry for its saved
plans for a 'c' (cascade) trigger, although there are two different
queries to execute depending on whether it fires for an update or a
delete.  This caused the wrong things to be done if both types of
event occur in one session.  (This was indeed visible in the triggers
regression test, but apparently nobody ever questioned it.)  To fix,
add the operation type to the cache key.

Its debug log output failed to distinguish update from delete
events, too.

Also, change the intended trigger usage from BEFORE ROW to AFTER ROW,
and add checks insisting on that usage.  BEFORE is really rather
unsafe, since if there are other BEFORE triggers they might change or
cancel the operation we are trying to check.  AFTER triggers are the
standard way to propagate changes to other rows, so we should follow
that way here.

In passing, remove a useless duplicate lookup of the cache entry.

This code is mostly intended as a documentation example, so we
won't consider a back-patch.

Author: Dmitrii Bondar <d.bondar@postgrespro.ru>
Reviewed-by: Paul Jungwirth <pj@illuminatedcomputing.com>
Reviewed-by: Lilian Ontowhee <ontowhee@gmail.com>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Discussion: https://postgr.es/m/79755a2b18ed4fe5e29da6a87a1e00d1@postgrespro.ru
This commit is contained in:
Tom Lane
2025-04-07 15:54:09 -04:00
parent 8e293e689b
commit 8cfbdf8f4d
4 changed files with 55 additions and 34 deletions

View File

@ -84,6 +84,10 @@ check_primary_key(PG_FUNCTION_ARGS)
/* internal error */ /* internal error */
elog(ERROR, "check_primary_key: must be fired for row"); elog(ERROR, "check_primary_key: must be fired for row");
if (!TRIGGER_FIRED_AFTER(trigdata->tg_event))
/* internal error */
elog(ERROR, "check_primary_key: must be fired by AFTER trigger");
/* If INSERTion then must check Tuple to being inserted */ /* If INSERTion then must check Tuple to being inserted */
if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event)) if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
tuple = trigdata->tg_trigtuple; tuple = trigdata->tg_trigtuple;
@ -287,6 +291,10 @@ check_foreign_key(PG_FUNCTION_ARGS)
/* internal error */ /* internal error */
elog(ERROR, "check_foreign_key: cannot process INSERT events"); elog(ERROR, "check_foreign_key: cannot process INSERT events");
if (!TRIGGER_FIRED_AFTER(trigdata->tg_event))
/* internal error */
elog(ERROR, "check_foreign_key: must be fired by AFTER trigger");
/* Have to check tg_trigtuple - tuple being deleted */ /* Have to check tg_trigtuple - tuple being deleted */
trigtuple = trigdata->tg_trigtuple; trigtuple = trigdata->tg_trigtuple;
@ -338,10 +346,10 @@ check_foreign_key(PG_FUNCTION_ARGS)
kvals = (Datum *) palloc(nkeys * sizeof(Datum)); kvals = (Datum *) palloc(nkeys * sizeof(Datum));
/* /*
* Construct ident string as TriggerName $ TriggeredRelationId and try to * Construct ident string as TriggerName $ TriggeredRelationId $
* find prepared execution plan(s). * OperationType and try to find prepared execution plan(s).
*/ */
snprintf(ident, sizeof(ident), "%s$%u", trigger->tgname, rel->rd_id); snprintf(ident, sizeof(ident), "%s$%u$%c", trigger->tgname, rel->rd_id, is_update ? 'U' : 'D');
plan = find_plan(ident, &FPlans, &nFPlans); plan = find_plan(ident, &FPlans, &nFPlans);
/* if there is no plan(s) then allocate argtypes for preparation */ /* if there is no plan(s) then allocate argtypes for preparation */
@ -573,8 +581,6 @@ check_foreign_key(PG_FUNCTION_ARGS)
relname = args[0]; relname = args[0];
snprintf(ident, sizeof(ident), "%s$%u", trigger->tgname, rel->rd_id);
plan = find_plan(ident, &FPlans, &nFPlans);
ret = SPI_execp(plan->splan[r], kvals, NULL, tcount); ret = SPI_execp(plan->splan[r], kvals, NULL, tcount);
/* we have no NULLs - so we pass ^^^^ here */ /* we have no NULLs - so we pass ^^^^ here */
@ -596,9 +602,15 @@ check_foreign_key(PG_FUNCTION_ARGS)
else else
{ {
#ifdef REFINT_VERBOSE #ifdef REFINT_VERBOSE
const char *operation;
if (action == 'c')
operation = is_update ? "updated" : "deleted";
else
operation = "set to null";
elog(NOTICE, "%s: " UINT64_FORMAT " tuple(s) of %s are %s", elog(NOTICE, "%s: " UINT64_FORMAT " tuple(s) of %s are %s",
trigger->tgname, SPI_processed, relname, trigger->tgname, SPI_processed, relname, operation);
(action == 'c') ? "deleted" : "set to null");
#endif #endif
} }
args += nkeys + 1; /* to the next relation */ args += nkeys + 1; /* to the next relation */

View File

@ -36,7 +36,7 @@
<para> <para>
<function>check_primary_key()</function> checks the referencing table. <function>check_primary_key()</function> checks the referencing table.
To use, create a <literal>BEFORE INSERT OR UPDATE</literal> trigger using this To use, create an <literal>AFTER INSERT OR UPDATE</literal> trigger using this
function on a table referencing another table. Specify as the trigger function on a table referencing another table. Specify as the trigger
arguments: the referencing table's column name(s) which form the foreign arguments: the referencing table's column name(s) which form the foreign
key, the referenced table name, and the column names in the referenced table key, the referenced table name, and the column names in the referenced table
@ -46,7 +46,7 @@
<para> <para>
<function>check_foreign_key()</function> checks the referenced table. <function>check_foreign_key()</function> checks the referenced table.
To use, create a <literal>BEFORE DELETE OR UPDATE</literal> trigger using this To use, create an <literal>AFTER DELETE OR UPDATE</literal> trigger using this
function on a table referenced by other table(s). Specify as the trigger function on a table referenced by other table(s). Specify as the trigger
arguments: the number of referencing tables for which the function has to arguments: the number of referencing tables for which the function has to
perform checking, the action if a referencing key is found perform checking, the action if a referencing key is found
@ -60,6 +60,16 @@
unique index. unique index.
</para> </para>
<para>
Note that if these triggers are executed from
another <literal>BEFORE</literal> trigger, they can fail unexpectedly. For
example, if a user inserts row1 and then the <literal>BEFORE</literal>
trigger inserts row2 and calls a trigger with the
<function>check_foreign_key()</function>,
the <function>check_foreign_key()</function>
function will not see row1 and will fail.
</para>
<para> <para>
There are examples in <filename>refint.example</filename>. There are examples in <filename>refint.example</filename>.
</para> </para>

View File

@ -46,12 +46,12 @@ create unique index pkeys_i on pkeys (pkey1, pkey2);
-- (fkey3) --> fkeys2 (pkey23) -- (fkey3) --> fkeys2 (pkey23)
-- --
create trigger check_fkeys_pkey_exist create trigger check_fkeys_pkey_exist
before insert or update on fkeys after insert or update on fkeys
for each row for each row
execute function execute function
check_primary_key ('fkey1', 'fkey2', 'pkeys', 'pkey1', 'pkey2'); check_primary_key ('fkey1', 'fkey2', 'pkeys', 'pkey1', 'pkey2');
create trigger check_fkeys_pkey2_exist create trigger check_fkeys_pkey2_exist
before insert or update on fkeys after insert or update on fkeys
for each row for each row
execute function check_primary_key ('fkey3', 'fkeys2', 'pkey23'); execute function check_primary_key ('fkey3', 'fkeys2', 'pkey23');
-- --
@ -59,7 +59,7 @@ create trigger check_fkeys_pkey2_exist
-- (fkey21, fkey22) --> pkeys (pkey1, pkey2) -- (fkey21, fkey22) --> pkeys (pkey1, pkey2)
-- --
create trigger check_fkeys2_pkey_exist create trigger check_fkeys2_pkey_exist
before insert or update on fkeys2 after insert or update on fkeys2
for each row for each row
execute procedure execute procedure
check_primary_key ('fkey21', 'fkey22', 'pkeys', 'pkey1', 'pkey2'); check_primary_key ('fkey21', 'fkey22', 'pkeys', 'pkey1', 'pkey2');
@ -74,7 +74,7 @@ COMMENT ON TRIGGER check_fkeys2_pkey_exist ON fkeys2 IS NULL;
-- fkeys (fkey1, fkey2) and fkeys2 (fkey21, fkey22) -- fkeys (fkey1, fkey2) and fkeys2 (fkey21, fkey22)
-- --
create trigger check_pkeys_fkey_cascade create trigger check_pkeys_fkey_cascade
before delete or update on pkeys after delete or update on pkeys
for each row for each row
execute procedure execute procedure
check_foreign_key (2, 'cascade', 'pkey1', 'pkey2', check_foreign_key (2, 'cascade', 'pkey1', 'pkey2',
@ -85,7 +85,7 @@ create trigger check_pkeys_fkey_cascade
-- fkeys (fkey3) -- fkeys (fkey3)
-- --
create trigger check_fkeys2_fkey_restrict create trigger check_fkeys2_fkey_restrict
before delete or update on fkeys2 after delete or update on fkeys2
for each row for each row
execute procedure check_foreign_key (1, 'restrict', 'pkey23', 'fkeys', 'fkey3'); execute procedure check_foreign_key (1, 'restrict', 'pkey23', 'fkeys', 'fkey3');
insert into fkeys2 values (10, '1', 1); insert into fkeys2 values (10, '1', 1);
@ -116,12 +116,11 @@ delete from pkeys where pkey1 = 40 and pkey2 = '4';
NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys are deleted NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys are deleted
NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys2 are deleted NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys2 are deleted
update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 50 and pkey2 = '5'; update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 50 and pkey2 = '5';
NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys are deleted NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys are updated
ERROR: "check_fkeys2_fkey_restrict": tuple is referenced in "fkeys" NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys2 are updated
CONTEXT: SQL statement "delete from fkeys2 where fkey21 = $1 and fkey22 = $2 "
update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 10 and pkey2 = '1'; update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 10 and pkey2 = '1';
NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys are deleted ERROR: duplicate key value violates unique constraint "pkeys_i"
NOTICE: check_pkeys_fkey_cascade: 1 tuple(s) of fkeys2 are deleted DETAIL: Key (pkey1, pkey2)=(7, 70) already exists.
SELECT trigger_name, event_manipulation, event_object_schema, event_object_table, SELECT trigger_name, event_manipulation, event_object_schema, event_object_table,
action_order, action_condition, action_orientation, action_timing, action_order, action_condition, action_orientation, action_timing,
action_reference_old_table, action_reference_new_table action_reference_old_table, action_reference_new_table
@ -130,16 +129,16 @@ SELECT trigger_name, event_manipulation, event_object_schema, event_object_table
ORDER BY trigger_name COLLATE "C", 2; ORDER BY trigger_name COLLATE "C", 2;
trigger_name | event_manipulation | event_object_schema | event_object_table | action_order | action_condition | action_orientation | action_timing | action_reference_old_table | action_reference_new_table trigger_name | event_manipulation | event_object_schema | event_object_table | action_order | action_condition | action_orientation | action_timing | action_reference_old_table | action_reference_new_table
----------------------------+--------------------+---------------------+--------------------+--------------+------------------+--------------------+---------------+----------------------------+---------------------------- ----------------------------+--------------------+---------------------+--------------------+--------------+------------------+--------------------+---------------+----------------------------+----------------------------
check_fkeys2_fkey_restrict | DELETE | public | fkeys2 | 1 | | ROW | BEFORE | | check_fkeys2_fkey_restrict | DELETE | public | fkeys2 | 1 | | ROW | AFTER | |
check_fkeys2_fkey_restrict | UPDATE | public | fkeys2 | 1 | | ROW | BEFORE | | check_fkeys2_fkey_restrict | UPDATE | public | fkeys2 | 1 | | ROW | AFTER | |
check_fkeys2_pkey_exist | INSERT | public | fkeys2 | 1 | | ROW | BEFORE | | check_fkeys2_pkey_exist | INSERT | public | fkeys2 | 1 | | ROW | AFTER | |
check_fkeys2_pkey_exist | UPDATE | public | fkeys2 | 2 | | ROW | BEFORE | | check_fkeys2_pkey_exist | UPDATE | public | fkeys2 | 2 | | ROW | AFTER | |
check_fkeys_pkey2_exist | INSERT | public | fkeys | 1 | | ROW | BEFORE | | check_fkeys_pkey2_exist | INSERT | public | fkeys | 1 | | ROW | AFTER | |
check_fkeys_pkey2_exist | UPDATE | public | fkeys | 1 | | ROW | BEFORE | | check_fkeys_pkey2_exist | UPDATE | public | fkeys | 1 | | ROW | AFTER | |
check_fkeys_pkey_exist | INSERT | public | fkeys | 2 | | ROW | BEFORE | | check_fkeys_pkey_exist | INSERT | public | fkeys | 2 | | ROW | AFTER | |
check_fkeys_pkey_exist | UPDATE | public | fkeys | 2 | | ROW | BEFORE | | check_fkeys_pkey_exist | UPDATE | public | fkeys | 2 | | ROW | AFTER | |
check_pkeys_fkey_cascade | DELETE | public | pkeys | 1 | | ROW | BEFORE | | check_pkeys_fkey_cascade | DELETE | public | pkeys | 1 | | ROW | AFTER | |
check_pkeys_fkey_cascade | UPDATE | public | pkeys | 1 | | ROW | BEFORE | | check_pkeys_fkey_cascade | UPDATE | public | pkeys | 1 | | ROW | AFTER | |
(10 rows) (10 rows)
DROP TABLE pkeys; DROP TABLE pkeys;

View File

@ -57,13 +57,13 @@ create unique index pkeys_i on pkeys (pkey1, pkey2);
-- (fkey3) --> fkeys2 (pkey23) -- (fkey3) --> fkeys2 (pkey23)
-- --
create trigger check_fkeys_pkey_exist create trigger check_fkeys_pkey_exist
before insert or update on fkeys after insert or update on fkeys
for each row for each row
execute function execute function
check_primary_key ('fkey1', 'fkey2', 'pkeys', 'pkey1', 'pkey2'); check_primary_key ('fkey1', 'fkey2', 'pkeys', 'pkey1', 'pkey2');
create trigger check_fkeys_pkey2_exist create trigger check_fkeys_pkey2_exist
before insert or update on fkeys after insert or update on fkeys
for each row for each row
execute function check_primary_key ('fkey3', 'fkeys2', 'pkey23'); execute function check_primary_key ('fkey3', 'fkeys2', 'pkey23');
@ -72,7 +72,7 @@ create trigger check_fkeys_pkey2_exist
-- (fkey21, fkey22) --> pkeys (pkey1, pkey2) -- (fkey21, fkey22) --> pkeys (pkey1, pkey2)
-- --
create trigger check_fkeys2_pkey_exist create trigger check_fkeys2_pkey_exist
before insert or update on fkeys2 after insert or update on fkeys2
for each row for each row
execute procedure execute procedure
check_primary_key ('fkey21', 'fkey22', 'pkeys', 'pkey1', 'pkey2'); check_primary_key ('fkey21', 'fkey22', 'pkeys', 'pkey1', 'pkey2');
@ -88,7 +88,7 @@ COMMENT ON TRIGGER check_fkeys2_pkey_exist ON fkeys2 IS NULL;
-- fkeys (fkey1, fkey2) and fkeys2 (fkey21, fkey22) -- fkeys (fkey1, fkey2) and fkeys2 (fkey21, fkey22)
-- --
create trigger check_pkeys_fkey_cascade create trigger check_pkeys_fkey_cascade
before delete or update on pkeys after delete or update on pkeys
for each row for each row
execute procedure execute procedure
check_foreign_key (2, 'cascade', 'pkey1', 'pkey2', check_foreign_key (2, 'cascade', 'pkey1', 'pkey2',
@ -100,7 +100,7 @@ create trigger check_pkeys_fkey_cascade
-- fkeys (fkey3) -- fkeys (fkey3)
-- --
create trigger check_fkeys2_fkey_restrict create trigger check_fkeys2_fkey_restrict
before delete or update on fkeys2 after delete or update on fkeys2
for each row for each row
execute procedure check_foreign_key (1, 'restrict', 'pkey23', 'fkeys', 'fkey3'); execute procedure check_foreign_key (1, 'restrict', 'pkey23', 'fkeys', 'fkey3');