mirror of
https://github.com/postgres/postgres.git
synced 2025-08-21 10:42:50 +03:00
The newly added ON CONFLICT clause allows to specify an alternative to raising a unique or exclusion constraint violation error when inserting. ON CONFLICT refers to constraints that can either be specified using a inference clause (by specifying the columns of a unique constraint) or by naming a unique or exclusion constraint. DO NOTHING avoids the constraint violation, without touching the pre-existing row. DO UPDATE SET ... [WHERE ...] updates the pre-existing tuple, and has access to both the tuple proposed for insertion and the existing tuple; the optional WHERE clause can be used to prevent an update from being executed. The UPDATE SET and WHERE clauses have access to the tuple proposed for insertion using the "magic" EXCLUDED alias, and to the pre-existing tuple using the table name or its alias. This feature is often referred to as upsert. This is implemented using a new infrastructure called "speculative insertion". It is an optimistic variant of regular insertion that first does a pre-check for existing tuples and then attempts an insert. If a violating tuple was inserted concurrently, the speculatively inserted tuple is deleted and a new attempt is made. If the pre-check finds a matching tuple the alternative DO NOTHING or DO UPDATE action is taken. If the insertion succeeds without detecting a conflict, the tuple is deemed inserted. To handle the possible ambiguity between the excluded alias and a table named excluded, and for convenience with long relation names, INSERT INTO now can alias its target table. Bumps catversion as stored rules change. Author: Peter Geoghegan, with significant contributions from Heikki Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes. Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs, Dean Rasheed, Stephen Frost and many others.
588 lines
21 KiB
Plaintext
588 lines
21 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/create_trigger.sgml
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-CREATETRIGGER">
|
|
<indexterm zone="sql-createtrigger">
|
|
<primary>CREATE TRIGGER</primary>
|
|
</indexterm>
|
|
|
|
<refmeta>
|
|
<refentrytitle>CREATE TRIGGER</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE TRIGGER</refname>
|
|
<refpurpose>define a new trigger</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
CREATE [ CONSTRAINT ] TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTER | INSTEAD OF } { <replaceable class="PARAMETER">event</replaceable> [ OR ... ] }
|
|
ON <replaceable class="PARAMETER">table_name</replaceable>
|
|
[ FROM <replaceable class="parameter">referenced_table_name</replaceable> ]
|
|
[ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ]
|
|
[ FOR [ EACH ] { ROW | STATEMENT } ]
|
|
[ WHEN ( <replaceable class="parameter">condition</replaceable> ) ]
|
|
EXECUTE PROCEDURE <replaceable class="PARAMETER">function_name</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
|
|
|
|
<phrase>where <replaceable class="parameter">event</replaceable> can be one of:</phrase>
|
|
|
|
INSERT
|
|
UPDATE [ OF <replaceable class="parameter">column_name</replaceable> [, ... ] ]
|
|
DELETE
|
|
TRUNCATE
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>CREATE TRIGGER</command> creates a new trigger. The
|
|
trigger will be associated with the specified table, view, or foreign table
|
|
and will execute the specified
|
|
function <replaceable class="parameter">function_name</replaceable> when
|
|
certain events occur.
|
|
</para>
|
|
|
|
<para>
|
|
The trigger can be specified to fire before the
|
|
operation is attempted on a row (before constraints are checked and
|
|
the <command>INSERT</command>, <command>UPDATE</command>, or
|
|
<command>DELETE</command> is attempted); or after the operation has
|
|
completed (after constraints are checked and the
|
|
<command>INSERT</command>, <command>UPDATE</command>, or
|
|
<command>DELETE</command> has completed); or instead of the operation
|
|
(in the case of inserts, updates or deletes on a view).
|
|
If the trigger fires before or instead of the event, the trigger can skip
|
|
the operation for the current row, or change the row being inserted (for
|
|
<command>INSERT</command> and <command>UPDATE</command> operations
|
|
only). If the trigger fires after the event, all changes, including
|
|
the effects of other triggers, are <quote>visible</quote>
|
|
to the trigger.
|
|
</para>
|
|
|
|
<para>
|
|
A trigger that is marked <literal>FOR EACH ROW</literal> is called
|
|
once for every row that the operation modifies. For example, a
|
|
<command>DELETE</command> that affects 10 rows will cause any
|
|
<literal>ON DELETE</literal> triggers on the target relation to be
|
|
called 10 separate times, once for each deleted row. In contrast, a
|
|
trigger that is marked <literal>FOR EACH STATEMENT</literal> only
|
|
executes once for any given operation, regardless of how many rows
|
|
it modifies (in particular, an operation that modifies zero rows
|
|
will still result in the execution of any applicable <literal>FOR
|
|
EACH STATEMENT</literal> triggers). Note that with an
|
|
<command>INSERT</command> with an <literal>ON CONFLICT DO UPDATE</>
|
|
clause, both <command>INSERT</command> and
|
|
<command>UPDATE</command> statement level trigger will be fired.
|
|
</para>
|
|
|
|
<para>
|
|
Triggers that are specified to fire <literal>INSTEAD OF</> the trigger
|
|
event must be marked <literal>FOR EACH ROW</>, and can only be defined
|
|
on views. <literal>BEFORE</> and <literal>AFTER</> triggers on a view
|
|
must be marked as <literal>FOR EACH STATEMENT</>.
|
|
</para>
|
|
|
|
<para>
|
|
In addition, triggers may be defined to fire for
|
|
<command>TRUNCATE</command>, though only
|
|
<literal>FOR EACH STATEMENT</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
The following table summarizes which types of triggers may be used on
|
|
tables, views, and foreign tables:
|
|
</para>
|
|
|
|
<informaltable id="supported-trigger-types">
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>When</entry>
|
|
<entry>Event</entry>
|
|
<entry>Row-level</entry>
|
|
<entry>Statement-level</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry align="center" morerows="1"><literal>BEFORE</></entry>
|
|
<entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
|
|
<entry align="center">Tables and foreign tables</entry>
|
|
<entry align="center">Tables, views, and foreign tables</entry>
|
|
</row>
|
|
<row>
|
|
<entry align="center"><command>TRUNCATE</></entry>
|
|
<entry align="center">—</entry>
|
|
<entry align="center">Tables</entry>
|
|
</row>
|
|
<row>
|
|
<entry align="center" morerows="1"><literal>AFTER</></entry>
|
|
<entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
|
|
<entry align="center">Tables and foreign tables</entry>
|
|
<entry align="center">Tables, views, and foreign tables</entry>
|
|
</row>
|
|
<row>
|
|
<entry align="center"><command>TRUNCATE</></entry>
|
|
<entry align="center">—</entry>
|
|
<entry align="center">Tables</entry>
|
|
</row>
|
|
<row>
|
|
<entry align="center" morerows="1"><literal>INSTEAD OF</></entry>
|
|
<entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
|
|
<entry align="center">Views</entry>
|
|
<entry align="center">—</entry>
|
|
</row>
|
|
<row>
|
|
<entry align="center"><command>TRUNCATE</></entry>
|
|
<entry align="center">—</entry>
|
|
<entry align="center">—</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
|
|
<para>
|
|
Also, a trigger definition can specify a Boolean <literal>WHEN</>
|
|
condition, which will be tested to see whether the trigger should
|
|
be fired. In row-level triggers the <literal>WHEN</> condition can
|
|
examine the old and/or new values of columns of the row. Statement-level
|
|
triggers can also have <literal>WHEN</> conditions, although the feature
|
|
is not so useful for them since the condition cannot refer to any values
|
|
in the table.
|
|
</para>
|
|
|
|
<para>
|
|
If multiple triggers of the same kind are defined for the same event,
|
|
they will be fired in alphabetical order by name.
|
|
</para>
|
|
|
|
<para>
|
|
When the <literal>CONSTRAINT</> option is specified, this command creates a
|
|
<firstterm>constraint trigger</>. This is the same as a regular trigger
|
|
except that the timing of the trigger firing can be adjusted using
|
|
<xref linkend="SQL-SET-CONSTRAINTS">.
|
|
Constraint triggers must be <literal>AFTER ROW</> triggers on tables. They
|
|
can be fired either at the end of the statement causing the triggering
|
|
event, or at the end of the containing transaction; in the latter case they
|
|
are said to be <firstterm>deferred</>. A pending deferred-trigger firing
|
|
can also be forced to happen immediately by using <command>SET
|
|
CONSTRAINTS</>. Constraint triggers are expected to raise an exception
|
|
when the constraints they implement are violated.
|
|
</para>
|
|
|
|
<para>
|
|
<command>SELECT</command> does not modify any rows so you cannot
|
|
create <command>SELECT</command> triggers. Rules and views are more
|
|
appropriate in such cases.
|
|
</para>
|
|
|
|
<para>
|
|
Refer to <xref linkend="triggers"> for more information about triggers.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name to give the new trigger. This must be distinct from
|
|
the name of any other trigger for the same table.
|
|
The name cannot be schema-qualified — the trigger inherits the
|
|
schema of its table. For a constraint trigger, this is also the name to
|
|
use when modifying the trigger's behavior using
|
|
<command>SET CONSTRAINTS</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>BEFORE</literal></term>
|
|
<term><literal>AFTER</literal></term>
|
|
<term><literal>INSTEAD OF</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Determines whether the function is called before, after, or instead of
|
|
the event. A constraint trigger can only be specified as
|
|
<literal>AFTER</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">event</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
One of <literal>INSERT</literal>, <literal>UPDATE</literal>,
|
|
<literal>DELETE</literal>, or <literal>TRUNCATE</literal>;
|
|
this specifies the event that will fire the trigger. Multiple
|
|
events can be specified using <literal>OR</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
For <literal>UPDATE</literal> events, it is possible to
|
|
specify a list of columns using this syntax:
|
|
<synopsis>
|
|
UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</replaceable> ... ]
|
|
</synopsis>
|
|
The trigger will only fire if at least one of the listed columns
|
|
is mentioned as a target of the <command>UPDATE</> command.
|
|
</para>
|
|
|
|
<para><literal>INSTEAD OF UPDATE</> events do not support lists of columns.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">table_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the table, view, or foreign
|
|
table the trigger is for.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">referenced_table_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The (possibly schema-qualified) name of another table referenced by the
|
|
constraint. This option is used for foreign-key constraints and is not
|
|
recommended for general use. This can only be specified for
|
|
constraint triggers.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DEFERRABLE</literal></term>
|
|
<term><literal>NOT DEFERRABLE</literal></term>
|
|
<term><literal>INITIALLY IMMEDIATE</literal></term>
|
|
<term><literal>INITIALLY DEFERRED</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The default timing of the trigger.
|
|
See the <xref linkend="SQL-CREATETABLE"> documentation for details of
|
|
these constraint options. This can only be specified for constraint
|
|
triggers.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>FOR EACH ROW</literal></term>
|
|
<term><literal>FOR EACH STATEMENT</literal></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
This specifies whether the trigger procedure should be fired
|
|
once for every row affected by the trigger event, or just once
|
|
per SQL statement. If neither is specified, <literal>FOR EACH
|
|
STATEMENT</literal> is the default. Constraint triggers can only
|
|
be specified <literal>FOR EACH ROW</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">condition</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
A Boolean expression that determines whether the trigger function
|
|
will actually be executed. If <literal>WHEN</> is specified, the
|
|
function will only be called if the <replaceable
|
|
class="parameter">condition</replaceable> returns <literal>true</>.
|
|
In <literal>FOR EACH ROW</literal> triggers, the <literal>WHEN</>
|
|
condition can refer to columns of the old and/or new row values
|
|
by writing <literal>OLD.<replaceable
|
|
class="parameter">column_name</replaceable></literal> or
|
|
<literal>NEW.<replaceable
|
|
class="parameter">column_name</replaceable></literal> respectively.
|
|
Of course, <literal>INSERT</> triggers cannot refer to <literal>OLD</>
|
|
and <literal>DELETE</> triggers cannot refer to <literal>NEW</>.
|
|
</para>
|
|
|
|
<para><literal>INSTEAD OF</> triggers do not support <literal>WHEN</>
|
|
conditions.
|
|
</para>
|
|
|
|
<para>
|
|
Currently, <literal>WHEN</literal> expressions cannot contain
|
|
subqueries.
|
|
</para>
|
|
|
|
<para>
|
|
Note that for constraint triggers, evaluation of the <literal>WHEN</>
|
|
condition is not deferred, but occurs immediately after the row update
|
|
operation is performed. If the condition does not evaluate to true then
|
|
the trigger is not queued for deferred execution.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">function_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
A user-supplied function that is declared as taking no arguments
|
|
and returning type <literal>trigger</>, which is executed when
|
|
the trigger fires.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">arguments</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
An optional comma-separated list of arguments to be provided to
|
|
the function when the trigger is executed. The arguments are
|
|
literal string constants. Simple names and numeric constants
|
|
can be written here, too, but they will all be converted to
|
|
strings. Please check the description of the implementation
|
|
language of the trigger function to find out how these arguments
|
|
can be accessed within the function; it might be different from
|
|
normal function arguments.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1 id="SQL-CREATETRIGGER-notes">
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
To create a trigger on a table, the user must have the
|
|
<literal>TRIGGER</literal> privilege on the table. The user must
|
|
also have <literal>EXECUTE</literal> privilege on the trigger function.
|
|
</para>
|
|
|
|
<para>
|
|
Use <xref linkend="sql-droptrigger"> to remove a trigger.
|
|
</para>
|
|
|
|
<para>
|
|
A column-specific trigger (one defined using the <literal>UPDATE OF
|
|
<replaceable>column_name</replaceable></literal> syntax) will fire when any
|
|
of its columns are listed as targets in the <command>UPDATE</>
|
|
command's <literal>SET</> list. It is possible for a column's value
|
|
to change even when the trigger is not fired, because changes made to the
|
|
row's contents by <literal>BEFORE UPDATE</> triggers are not considered.
|
|
Conversely, a command such as <literal>UPDATE ... SET x = x ...</>
|
|
will fire a trigger on column <literal>x</>, even though the column's
|
|
value did not change.
|
|
</para>
|
|
|
|
<para>
|
|
In a <literal>BEFORE</> trigger, the <literal>WHEN</> condition is
|
|
evaluated just before the function is or would be executed, so using
|
|
<literal>WHEN</> is not materially different from testing the same
|
|
condition at the beginning of the trigger function. Note in particular
|
|
that the <literal>NEW</> row seen by the condition is the current value,
|
|
as possibly modified by earlier triggers. Also, a <literal>BEFORE</>
|
|
trigger's <literal>WHEN</> condition is not allowed to examine the
|
|
system columns of the <literal>NEW</> row (such as <literal>oid</>),
|
|
because those won't have been set yet.
|
|
</para>
|
|
|
|
<para>
|
|
In an <literal>AFTER</> trigger, the <literal>WHEN</> condition is
|
|
evaluated just after the row update occurs, and it determines whether an
|
|
event is queued to fire the trigger at the end of statement. So when an
|
|
<literal>AFTER</> trigger's <literal>WHEN</> condition does not return
|
|
true, it is not necessary to queue an event nor to re-fetch the row at end
|
|
of statement. This can result in significant speedups in statements that
|
|
modify many rows, if the trigger only needs to be fired for a few of the
|
|
rows.
|
|
</para>
|
|
|
|
<para>
|
|
In <productname>PostgreSQL</productname> versions before 7.3, it was
|
|
necessary to declare trigger functions as returning the placeholder
|
|
type <type>opaque</>, rather than <type>trigger</>. To support loading
|
|
of old dump files, <command>CREATE TRIGGER</> will accept a function
|
|
declared as returning <type>opaque</>, but it will issue a notice and
|
|
change the function's declared return type to <type>trigger</>.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="SQL-CREATETRIGGER-examples">
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Execute the function <function>check_account_update</> whenever
|
|
a row of the table <literal>accounts</> is about to be updated:
|
|
|
|
<programlisting>
|
|
CREATE TRIGGER check_update
|
|
BEFORE UPDATE ON accounts
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE check_account_update();
|
|
</programlisting>
|
|
|
|
The same, but only execute the function if column <literal>balance</>
|
|
is specified as a target in the <command>UPDATE</> command:
|
|
|
|
<programlisting>
|
|
CREATE TRIGGER check_update
|
|
BEFORE UPDATE OF balance ON accounts
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE check_account_update();
|
|
</programlisting>
|
|
|
|
This form only executes the function if column <literal>balance</>
|
|
has in fact changed value:
|
|
|
|
<programlisting>
|
|
CREATE TRIGGER check_update
|
|
BEFORE UPDATE ON accounts
|
|
FOR EACH ROW
|
|
WHEN (OLD.balance IS DISTINCT FROM NEW.balance)
|
|
EXECUTE PROCEDURE check_account_update();
|
|
</programlisting>
|
|
|
|
Call a function to log updates of <literal>accounts</>, but only if
|
|
something changed:
|
|
|
|
<programlisting>
|
|
CREATE TRIGGER log_update
|
|
AFTER UPDATE ON accounts
|
|
FOR EACH ROW
|
|
WHEN (OLD.* IS DISTINCT FROM NEW.*)
|
|
EXECUTE PROCEDURE log_account_update();
|
|
</programlisting>
|
|
|
|
Execute the function <function>view_insert_row</> for each row to insert
|
|
rows into the tables underlying a view:
|
|
|
|
<programlisting>
|
|
CREATE TRIGGER view_insert
|
|
INSTEAD OF INSERT ON my_view
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE view_insert_row();
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="trigger-example"> contains a complete example of a trigger
|
|
function written in C.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="SQL-CREATETRIGGER-compatibility">
|
|
<title>Compatibility</title>
|
|
|
|
<!--
|
|
It's not clear whether SQL/MED contemplates triggers on foreign tables.
|
|
Its <drop basic column definition> General Rules do mention the possibility
|
|
of a reference from a trigger column list. On the other hand, nothing
|
|
overrides the fact that CREATE TRIGGER only targets base tables. For now,
|
|
do not document the compatibility status of triggers on foreign tables.
|
|
-->
|
|
|
|
<para>
|
|
The <command>CREATE TRIGGER</command> statement in
|
|
<productname>PostgreSQL</productname> implements a subset of the
|
|
<acronym>SQL</> standard. The following functionalities are currently
|
|
missing:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
SQL allows you to define aliases for the <quote>old</quote>
|
|
and <quote>new</quote> rows or tables for use in the definition
|
|
of the triggered action (e.g., <literal>CREATE TRIGGER ... ON
|
|
tablename REFERENCING OLD ROW AS somename NEW ROW AS othername
|
|
...</literal>). Since <productname>PostgreSQL</productname>
|
|
allows trigger procedures to be written in any number of
|
|
user-defined languages, access to the data is handled in a
|
|
language-specific way.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<productname>PostgreSQL</productname> does not allow the old and new
|
|
tables to be referenced in statement-level triggers, i.e., the tables
|
|
that contain all the old and/or new rows, which are referred to by the
|
|
<literal>OLD TABLE</literal> and <literal>NEW TABLE</literal> clauses in
|
|
the <acronym>SQL</> standard.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para><productname>PostgreSQL</productname> only allows the execution
|
|
of a user-defined function for the triggered action. The standard
|
|
allows the execution of a number of other SQL commands, such as
|
|
<command>CREATE TABLE</command>, as the triggered action. This
|
|
limitation is not hard to work around by creating a user-defined
|
|
function that executes the desired commands.
|
|
</para>
|
|
</listitem>
|
|
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
SQL specifies that multiple triggers should be fired in
|
|
time-of-creation order. <productname>PostgreSQL</productname> uses
|
|
name order, which was judged to be more convenient.
|
|
</para>
|
|
|
|
<para>
|
|
SQL specifies that <literal>BEFORE DELETE</literal> triggers on cascaded
|
|
deletes fire <emphasis>after</> the cascaded <literal>DELETE</> completes.
|
|
The <productname>PostgreSQL</productname> behavior is for <literal>BEFORE
|
|
DELETE</literal> to always fire before the delete action, even a cascading
|
|
one. This is considered more consistent. There is also nonstandard
|
|
behavior if <literal>BEFORE</literal> triggers modify rows or prevent
|
|
updates during an update that is caused by a referential action. This can
|
|
lead to constraint violations or stored data that does not honor the
|
|
referential constraint.
|
|
</para>
|
|
|
|
<para>
|
|
The ability to specify multiple actions for a single trigger using
|
|
<literal>OR</literal> is a <productname>PostgreSQL</> extension of
|
|
the SQL standard.
|
|
</para>
|
|
|
|
<para>
|
|
The ability to fire triggers for <command>TRUNCATE</command> is a
|
|
<productname>PostgreSQL</> extension of the SQL standard, as is the
|
|
ability to define statement-level triggers on views.
|
|
</para>
|
|
|
|
<para>
|
|
<command>CREATE CONSTRAINT TRIGGER</command> is a
|
|
<productname>PostgreSQL</productname> extension of the <acronym>SQL</>
|
|
standard.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-altertrigger"></member>
|
|
<member><xref linkend="sql-droptrigger"></member>
|
|
<member><xref linkend="sql-createfunction"></member>
|
|
<member><xref linkend="sql-set-constraints"></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|