CREATE TRIGGER
7
SQL - Language Statements
CREATE TRIGGER
define a new trigger
CREATE TRIGGER
CREATE [ CONSTRAINT ] TRIGGER name { BEFORE | AFTER | INSTEAD OF } { event [ OR ... ] }
ON table_name
[ FROM referenced_table_name ]
{ NOT DEFERRABLE | [ DEFERRABLE ] { INITIALLY IMMEDIATE | INITIALLY DEFERRED } }
[ FOR [ EACH ] { ROW | STATEMENT } ]
[ WHEN ( condition ) ]
EXECUTE PROCEDURE function_name ( arguments )
where event can be one of:
INSERT
UPDATE [ OF column_name [, ... ] ]
DELETE
TRUNCATE
Description
CREATE TRIGGER creates a new trigger. The
trigger will be associated with the specified table or view and will
execute the specified function function_name when certain events occur.
The trigger can be specified to fire before the
operation is attempted on a row (before constraints are checked and
the INSERT, UPDATE, or
DELETE is attempted); or after the operation has
completed (after constraints are checked and the
INSERT, UPDATE, or
DELETE 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
INSERT and UPDATE operations
only). If the trigger fires after the event, all changes, including
the effects of other triggers, are visible
to the trigger.
A trigger that is marked FOR EACH ROW is called
once for every row that the operation modifies. For example, a
DELETE that affects 10 rows will cause any
ON DELETE triggers on the target relation to be
called 10 separate times, once for each deleted row. In contrast, a
trigger that is marked FOR EACH STATEMENT 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 FOR
EACH STATEMENT triggers).
Triggers that are specified to fire INSTEAD OF> the trigger
event must be marked FOR EACH ROW>, and can only be defined
on views. BEFORE> and AFTER> triggers on a view
must be marked as FOR EACH STATEMENT>.
In addition, triggers may be defined to fire for
TRUNCATE, though only
FOR EACH STATEMENT.
The following table summarizes which types of triggers may be used on
tables and views:
When
Event
Row-level
Statement-level
BEFORE>
INSERT>/UPDATE>/DELETE>
Tables
Tables and views
TRUNCATE>
—
Tables
AFTER>
INSERT>/UPDATE>/DELETE>
Tables
Tables and views
TRUNCATE>
—
Tables
INSTEAD OF>
INSERT>/UPDATE>/DELETE>
Views
—
TRUNCATE>
—
—
Also, a trigger definition can specify a Boolean WHEN>
condition, which will be tested to see whether the trigger should
be fired. In row-level triggers the WHEN> condition can
examine the old and/or new values of columns of the row. Statement-level
triggers can also have WHEN> conditions, although the feature
is not so useful for them since the condition cannot refer to any values
in the table.
If multiple triggers of the same kind are defined for the same event,
they will be fired in alphabetical order by name.
When the CONSTRAINT> option is specified, this command creates a
constraint trigger>. This is the same as a regular trigger
except that the timing of the trigger firing can be adjusted using
.
Constraint triggers must be AFTER ROW> triggers. 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 deferred>. A pending deferred-trigger firing can
also be forced to happen immediately by using SET CONSTRAINTS>.
Constraint triggers are expected to raise an exception when the constraints
they implement are violated.
SELECT does not modify any rows so you cannot
create SELECT triggers. Rules and views are more
appropriate in such cases.
Refer to for more information about triggers.
Parameters
name
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
SET CONSTRAINTS>.
BEFORE
AFTER
INSTEAD OF
Determines whether the function is called before, after, or instead of
the event. A constraint trigger can only be specified as
AFTER>.
event
One of INSERT, UPDATE,
DELETE, or TRUNCATE;
this specifies the event that will fire the trigger. Multiple
events can be specified using OR.
For UPDATE events, it is possible to
specify a list of columns using this syntax:
UPDATE OF column_name1 [, column_name2 ... ]
The trigger will only fire if at least one of the listed columns
is mentioned as a target of the UPDATE> command.
INSTEAD OF UPDATE> events do not support lists of columns.
table_name
The name (optionally schema-qualified) of the table or view the trigger
is for.
referenced_table_name
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.
DEFERRABLE
NOT DEFERRABLE
INITIALLY IMMEDIATE
INITIALLY DEFERRED
The default timing of the trigger.
See the documentation for details of
these constraint options. This can only be specified for constraint
triggers.
FOR EACH ROW
FOR EACH STATEMENT
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, FOR EACH
STATEMENT is the default. Constraint triggers can only
be specified FOR EACH ROW>.
condition
A Boolean expression that determines whether the trigger function
will actually be executed. If WHEN> is specified, the
function will only be called if the condition returns true>.
In FOR EACH ROW triggers, the WHEN>
condition can refer to columns of the old and/or new row values
by writing OLD.column_name or
NEW.column_name respectively.
Of course, INSERT> triggers cannot refer to OLD>
and DELETE> triggers cannot refer to NEW>.
INSTEAD OF> triggers do not support WHEN>
conditions.
Currently, WHEN expressions cannot contain
subqueries.
Note that for constraint triggers, evaluation of the 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.
function_name
A user-supplied function that is declared as taking no arguments
and returning type trigger>, which is executed when
the trigger fires.
arguments
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.
Notes
To create a trigger on a table, the user must have the
TRIGGER privilege on the table. The user must
also have EXECUTE privilege on the trigger function.
Use to remove a trigger.
A column-specific trigger (one defined using the UPDATE OF
column_name syntax) will fire when any
of its columns are listed as targets in the UPDATE>
command's 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 BEFORE UPDATE> triggers are not considered.
Conversely, a command such as UPDATE ... SET x = x ...>
will fire a trigger on column x>, even though the column's
value did not change.
In a BEFORE> trigger, the WHEN> condition is
evaluated just before the function is or would be executed, so using
WHEN> is not materially different from testing the same
condition at the beginning of the trigger function. Note in particular
that the NEW> row seen by the condition is the current value,
as possibly modified by earlier triggers. Also, a BEFORE>
trigger's WHEN> condition is not allowed to examine the
system columns of the NEW> row (such as oid>),
because those won't have been set yet.
In an AFTER> trigger, the 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
AFTER> trigger's 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.
In PostgreSQL versions before 7.3, it was
necessary to declare trigger functions as returning the placeholder
type opaque>, rather than trigger>. To support loading
of old dump files, CREATE TRIGGER> will accept a function
declared as returning opaque>, but it will issue a notice and
change the function's declared return type to trigger>.
Examples
Execute the function check_account_update> whenever
a row of the table accounts> is about to be updated:
CREATE TRIGGER check_update
BEFORE UPDATE ON accounts
FOR EACH ROW
EXECUTE PROCEDURE check_account_update();
The same, but only execute the function if column balance>
is specified as a target in the UPDATE> command:
CREATE TRIGGER check_update
BEFORE UPDATE OF balance ON accounts
FOR EACH ROW
EXECUTE PROCEDURE check_account_update();
This form only executes the function if column balance>
has in fact changed value:
CREATE TRIGGER check_update
BEFORE UPDATE ON accounts
FOR EACH ROW
WHEN (OLD.balance IS DISTINCT FROM NEW.balance)
EXECUTE PROCEDURE check_account_update();
Call a function to log updates of accounts>, but only if
something changed:
CREATE TRIGGER log_update
AFTER UPDATE ON accounts
FOR EACH ROW
WHEN (OLD.* IS DISTINCT FROM NEW.*)
EXECUTE PROCEDURE log_account_update();
Execute the function view_insert_row> for each row to insert
rows into the tables underlying a view:
CREATE TRIGGER view_insert
INSTEAD OF INSERT ON my_view
FOR EACH ROW
EXECUTE PROCEDURE view_insert_row();
contains a complete example of a trigger
function written in C.
Compatibility
The CREATE TRIGGER statement in
PostgreSQL implements a subset of the
SQL> standard. The following functionalities are currently
missing:
SQL allows you to define aliases for the old
and new
rows or tables for use in the definition
of the triggered action (e.g., CREATE TRIGGER ... ON
tablename REFERENCING OLD ROW AS somename NEW ROW AS othername
...). Since PostgreSQL
allows trigger procedures to be written in any number of
user-defined languages, access to the data is handled in a
language-specific way.
PostgreSQL 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
OLD TABLE and NEW TABLE clauses in
the SQL> standard.
PostgreSQL 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
CREATE TABLE, as the triggered action. This
limitation is not hard to work around by creating a user-defined
function that executes the desired commands.
SQL specifies that multiple triggers should be fired in
time-of-creation order. PostgreSQL uses
name order, which was judged to be more convenient.
SQL specifies that BEFORE DELETE triggers on cascaded
deletes fire after> the cascaded DELETE> completes.
The PostgreSQL behavior is for BEFORE
DELETE to always fire before the delete action, even a cascading
one. This is considered more consistent. There is also nonstandard
behavior if BEFORE 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.
The ability to specify multiple actions for a single trigger using
OR is a PostgreSQL> extension of
the SQL standard.
The ability to fire triggers for TRUNCATE is a
PostgreSQL> extension of the SQL standard, as is the
ability to define statement-level triggers on views.
CREATE CONSTRAINT TRIGGER is a
PostgreSQL extension of the SQL>
standard.
See Also