doc: ALTER DEFAULT PRIVILEGES does not affect inherited roles
[pgsql.git] / doc / src / sgml / ref / create_trigger.sgml
blob982ab6f3ee4509cc813021c734c32f20fb6b0810
1 <!--
2 doc/src/sgml/ref/create_trigger.sgml
3 PostgreSQL documentation
4 -->
6 <refentry id="sql-createtrigger">
7 <indexterm zone="sql-createtrigger">
8 <primary>CREATE TRIGGER</primary>
9 </indexterm>
11 <indexterm>
12 <primary>transition tables</primary>
13 <seealso>ephemeral named relation</seealso>
14 </indexterm>
16 <refmeta>
17 <refentrytitle>CREATE TRIGGER</refentrytitle>
18 <manvolnum>7</manvolnum>
19 <refmiscinfo>SQL - Language Statements</refmiscinfo>
20 </refmeta>
22 <refnamediv>
23 <refname>CREATE TRIGGER</refname>
24 <refpurpose>define a new trigger</refpurpose>
25 </refnamediv>
27 <refsynopsisdiv>
28 <synopsis>
29 CREATE [ OR REPLACE ] [ CONSTRAINT ] TRIGGER <replaceable class="parameter">name</replaceable> { BEFORE | AFTER | INSTEAD OF } { <replaceable class="parameter">event</replaceable> [ OR ... ] }
30 ON <replaceable class="parameter">table_name</replaceable>
31 [ FROM <replaceable class="parameter">referenced_table_name</replaceable> ]
32 [ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ]
33 [ REFERENCING { { OLD | NEW } TABLE [ AS ] <replaceable class="parameter">transition_relation_name</replaceable> } [ ... ] ]
34 [ FOR [ EACH ] { ROW | STATEMENT } ]
35 [ WHEN ( <replaceable class="parameter">condition</replaceable> ) ]
36 EXECUTE { FUNCTION | PROCEDURE } <replaceable class="parameter">function_name</replaceable> ( <replaceable class="parameter">arguments</replaceable> )
38 <phrase>where <replaceable class="parameter">event</replaceable> can be one of:</phrase>
40 INSERT
41 UPDATE [ OF <replaceable class="parameter">column_name</replaceable> [, ... ] ]
42 DELETE
43 TRUNCATE
44 </synopsis>
45 </refsynopsisdiv>
47 <refsect1>
48 <title>Description</title>
50 <para>
51 <command>CREATE TRIGGER</command> creates a new trigger.
52 <command>CREATE OR REPLACE TRIGGER</command> will either create a
53 new trigger, or replace an existing trigger. The
54 trigger will be associated with the specified table, view, or foreign table
55 and will execute the specified
56 function <replaceable class="parameter">function_name</replaceable> when
57 certain operations are performed on that table.
58 </para>
60 <para>
61 To replace the current definition of an existing trigger, use
62 <command>CREATE OR REPLACE TRIGGER</command>, specifying the existing
63 trigger's name and parent table. All other properties are replaced.
64 </para>
66 <para>
67 The trigger can be specified to fire before the
68 operation is attempted on a row (before constraints are checked and
69 the <command>INSERT</command>, <command>UPDATE</command>, or
70 <command>DELETE</command> is attempted); or after the operation has
71 completed (after constraints are checked and the
72 <command>INSERT</command>, <command>UPDATE</command>, or
73 <command>DELETE</command> has completed); or instead of the operation
74 (in the case of inserts, updates or deletes on a view).
75 If the trigger fires before or instead of the event, the trigger can skip
76 the operation for the current row, or change the row being inserted (for
77 <command>INSERT</command> and <command>UPDATE</command> operations
78 only). If the trigger fires after the event, all changes, including
79 the effects of other triggers, are <quote>visible</quote>
80 to the trigger.
81 </para>
83 <para>
84 A trigger that is marked <literal>FOR EACH ROW</literal> is called
85 once for every row that the operation modifies. For example, a
86 <command>DELETE</command> that affects 10 rows will cause any
87 <literal>ON DELETE</literal> triggers on the target relation to be
88 called 10 separate times, once for each deleted row. In contrast, a
89 trigger that is marked <literal>FOR EACH STATEMENT</literal> only
90 executes once for any given operation, regardless of how many rows
91 it modifies (in particular, an operation that modifies zero rows
92 will still result in the execution of any applicable <literal>FOR
93 EACH STATEMENT</literal> triggers).
94 </para>
96 <para>
97 Triggers that are specified to fire <literal>INSTEAD OF</literal> the trigger
98 event must be marked <literal>FOR EACH ROW</literal>, and can only be defined
99 on views. <literal>BEFORE</literal> and <literal>AFTER</literal> triggers on a view
100 must be marked as <literal>FOR EACH STATEMENT</literal>.
101 </para>
103 <para>
104 In addition, triggers may be defined to fire for
105 <command>TRUNCATE</command>, though only
106 <literal>FOR EACH STATEMENT</literal>.
107 </para>
109 <para>
110 The following table summarizes which types of triggers may be used on
111 tables, views, and foreign tables:
112 </para>
114 <informaltable id="supported-trigger-types">
115 <tgroup cols="4">
116 <thead>
117 <row>
118 <entry>When</entry>
119 <entry>Event</entry>
120 <entry>Row-level</entry>
121 <entry>Statement-level</entry>
122 </row>
123 </thead>
124 <tbody>
125 <row>
126 <entry align="center" morerows="1"><literal>BEFORE</literal></entry>
127 <entry align="center"><command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command></entry>
128 <entry align="center">Tables and foreign tables</entry>
129 <entry align="center">Tables, views, and foreign tables</entry>
130 </row>
131 <row>
132 <entry align="center"><command>TRUNCATE</command></entry>
133 <entry align="center">&mdash;</entry>
134 <entry align="center">Tables and foreign tables</entry>
135 </row>
136 <row>
137 <entry align="center" morerows="1"><literal>AFTER</literal></entry>
138 <entry align="center"><command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command></entry>
139 <entry align="center">Tables and foreign tables</entry>
140 <entry align="center">Tables, views, and foreign tables</entry>
141 </row>
142 <row>
143 <entry align="center"><command>TRUNCATE</command></entry>
144 <entry align="center">&mdash;</entry>
145 <entry align="center">Tables and foreign tables</entry>
146 </row>
147 <row>
148 <entry align="center" morerows="1"><literal>INSTEAD OF</literal></entry>
149 <entry align="center"><command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command></entry>
150 <entry align="center">Views</entry>
151 <entry align="center">&mdash;</entry>
152 </row>
153 <row>
154 <entry align="center"><command>TRUNCATE</command></entry>
155 <entry align="center">&mdash;</entry>
156 <entry align="center">&mdash;</entry>
157 </row>
158 </tbody>
159 </tgroup>
160 </informaltable>
162 <para>
163 Also, a trigger definition can specify a Boolean <literal>WHEN</literal>
164 condition, which will be tested to see whether the trigger should
165 be fired. In row-level triggers the <literal>WHEN</literal> condition can
166 examine the old and/or new values of columns of the row. Statement-level
167 triggers can also have <literal>WHEN</literal> conditions, although the feature
168 is not so useful for them since the condition cannot refer to any values
169 in the table.
170 </para>
172 <para>
173 If multiple triggers of the same kind are defined for the same event,
174 they will be fired in alphabetical order by name.
175 </para>
177 <para>
178 When the <literal>CONSTRAINT</literal> option is specified, this command creates a
179 <firstterm>constraint trigger</firstterm>.<indexterm><primary>trigger</primary>
180 <secondary>constraint trigger</secondary></indexterm>
181 This is the same as a regular trigger
182 except that the timing of the trigger firing can be adjusted using
183 <link linkend="sql-set-constraints"><command>SET CONSTRAINTS</command></link>.
184 Constraint triggers must be <literal>AFTER ROW</literal> triggers on plain
185 tables (not foreign tables). They
186 can be fired either at the end of the statement causing the triggering
187 event, or at the end of the containing transaction; in the latter case they
188 are said to be <firstterm>deferred</firstterm>. A pending deferred-trigger firing
189 can also be forced to happen immediately by using <command>SET
190 CONSTRAINTS</command>. Constraint triggers are expected to raise an exception
191 when the constraints they implement are violated.
192 </para>
194 <para>
195 The <literal>REFERENCING</literal> option enables collection
196 of <firstterm>transition relations</firstterm>, which are row sets that include all
197 of the rows inserted, deleted, or modified by the current SQL statement.
198 This feature lets the trigger see a global view of what the statement did,
199 not just one row at a time. This option is only allowed for
200 an <literal>AFTER</literal> trigger that is not a constraint trigger; also, if
201 the trigger is an <literal>UPDATE</literal> trigger, it must not specify
202 a <replaceable class="parameter">column_name</replaceable> list.
203 <literal>OLD TABLE</literal> may only be specified once, and only for a trigger
204 that can fire on <literal>UPDATE</literal> or <literal>DELETE</literal>; it creates a
205 transition relation containing the <firstterm>before-images</firstterm> of all rows
206 updated or deleted by the statement.
207 Similarly, <literal>NEW TABLE</literal> may only be specified once, and only for
208 a trigger that can fire on <literal>UPDATE</literal> or <literal>INSERT</literal>;
209 it creates a transition relation containing the <firstterm>after-images</firstterm>
210 of all rows updated or inserted by the statement.
211 </para>
213 <para>
214 <command>SELECT</command> does not modify any rows so you cannot
215 create <command>SELECT</command> triggers. Rules and views may provide
216 workable solutions to problems that seem to need <command>SELECT</command>
217 triggers.
218 </para>
220 <para>
221 Refer to <xref linkend="triggers"/> for more information about triggers.
222 </para>
223 </refsect1>
225 <refsect1>
226 <title>Parameters</title>
228 <variablelist>
229 <varlistentry>
230 <term><replaceable class="parameter">name</replaceable></term>
231 <listitem>
232 <para>
233 The name to give the new trigger. This must be distinct from
234 the name of any other trigger for the same table.
235 The name cannot be schema-qualified &mdash; the trigger inherits the
236 schema of its table. For a constraint trigger, this is also the name to
237 use when modifying the trigger's behavior using
238 <command>SET CONSTRAINTS</command>.
239 </para>
240 </listitem>
241 </varlistentry>
243 <varlistentry>
244 <term><literal>BEFORE</literal></term>
245 <term><literal>AFTER</literal></term>
246 <term><literal>INSTEAD OF</literal></term>
247 <listitem>
248 <para>
249 Determines whether the function is called before, after, or instead of
250 the event. A constraint trigger can only be specified as
251 <literal>AFTER</literal>.
252 </para>
253 </listitem>
254 </varlistentry>
256 <varlistentry>
257 <term><replaceable class="parameter">event</replaceable></term>
258 <listitem>
259 <para>
260 One of <literal>INSERT</literal>, <literal>UPDATE</literal>,
261 <literal>DELETE</literal>, or <literal>TRUNCATE</literal>;
262 this specifies the event that will fire the trigger. Multiple
263 events can be specified using <literal>OR</literal>, except when
264 transition relations are requested.
265 </para>
267 <para>
268 For <literal>UPDATE</literal> events, it is possible to
269 specify a list of columns using this syntax:
270 <synopsis>
271 UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</replaceable> ... ]
272 </synopsis>
273 The trigger will only fire if at least one of the listed columns
274 is mentioned as a target of the <command>UPDATE</command> command
275 or if one of the listed columns is a generated column that depends on a
276 column that is the target of the <command>UPDATE</command>.
277 </para>
279 <para>
280 <literal>INSTEAD OF UPDATE</literal> events do not allow a list of columns.
281 A column list cannot be specified when requesting transition relations,
282 either.
283 </para>
284 </listitem>
285 </varlistentry>
287 <varlistentry>
288 <term><replaceable class="parameter">table_name</replaceable></term>
289 <listitem>
290 <para>
291 The name (optionally schema-qualified) of the table, view, or foreign
292 table the trigger is for.
293 </para>
294 </listitem>
295 </varlistentry>
297 <varlistentry>
298 <term><replaceable class="parameter">referenced_table_name</replaceable></term>
299 <listitem>
300 <para>
301 The (possibly schema-qualified) name of another table referenced by the
302 constraint. This option is used for foreign-key constraints and is not
303 recommended for general use. This can only be specified for
304 constraint triggers.
305 </para>
306 </listitem>
307 </varlistentry>
309 <varlistentry>
310 <term><literal>DEFERRABLE</literal></term>
311 <term><literal>NOT DEFERRABLE</literal></term>
312 <term><literal>INITIALLY IMMEDIATE</literal></term>
313 <term><literal>INITIALLY DEFERRED</literal></term>
314 <listitem>
315 <para>
316 The default timing of the trigger.
317 See the <xref linkend="sql-createtable"/> documentation for details of
318 these constraint options. This can only be specified for constraint
319 triggers.
320 </para>
321 </listitem>
322 </varlistentry>
324 <varlistentry>
325 <term><literal>REFERENCING</literal></term>
326 <listitem>
327 <para>
328 This keyword immediately precedes the declaration of one or two
329 relation names that provide access to the transition relations of the
330 triggering statement.
331 </para>
332 </listitem>
333 </varlistentry>
335 <varlistentry>
336 <term><literal>OLD TABLE</literal></term>
337 <term><literal>NEW TABLE</literal></term>
338 <listitem>
339 <para>
340 This clause indicates whether the following relation name is for the
341 before-image transition relation or the after-image transition
342 relation.
343 </para>
344 </listitem>
345 </varlistentry>
347 <varlistentry>
348 <term><replaceable class="parameter">transition_relation_name</replaceable></term>
349 <listitem>
350 <para>
351 The (unqualified) name to be used within the trigger for this
352 transition relation.
353 </para>
354 </listitem>
355 </varlistentry>
357 <varlistentry>
358 <term><literal>FOR EACH ROW</literal></term>
359 <term><literal>FOR EACH STATEMENT</literal></term>
361 <listitem>
362 <para>
363 This specifies whether the trigger function should be fired
364 once for every row affected by the trigger event, or just once
365 per SQL statement. If neither is specified, <literal>FOR EACH
366 STATEMENT</literal> is the default. Constraint triggers can only
367 be specified <literal>FOR EACH ROW</literal>.
368 </para>
369 </listitem>
370 </varlistentry>
372 <varlistentry>
373 <term><replaceable class="parameter">condition</replaceable></term>
374 <listitem>
375 <para>
376 A Boolean expression that determines whether the trigger function
377 will actually be executed. If <literal>WHEN</literal> is specified, the
378 function will only be called if the <replaceable
379 class="parameter">condition</replaceable> returns <literal>true</literal>.
380 In <literal>FOR EACH ROW</literal> triggers, the <literal>WHEN</literal>
381 condition can refer to columns of the old and/or new row values
382 by writing <literal>OLD.<replaceable
383 class="parameter">column_name</replaceable></literal> or
384 <literal>NEW.<replaceable
385 class="parameter">column_name</replaceable></literal> respectively.
386 Of course, <literal>INSERT</literal> triggers cannot refer to <literal>OLD</literal>
387 and <literal>DELETE</literal> triggers cannot refer to <literal>NEW</literal>.
388 </para>
390 <para><literal>INSTEAD OF</literal> triggers do not support <literal>WHEN</literal>
391 conditions.
392 </para>
394 <para>
395 Currently, <literal>WHEN</literal> expressions cannot contain
396 subqueries.
397 </para>
399 <para>
400 Note that for constraint triggers, evaluation of the <literal>WHEN</literal>
401 condition is not deferred, but occurs immediately after the row update
402 operation is performed. If the condition does not evaluate to true then
403 the trigger is not queued for deferred execution.
404 </para>
405 </listitem>
406 </varlistentry>
408 <varlistentry>
409 <term><replaceable class="parameter">function_name</replaceable></term>
410 <listitem>
411 <para>
412 A user-supplied function that is declared as taking no arguments
413 and returning type <literal>trigger</literal>, which is executed when
414 the trigger fires.
415 </para>
417 <para>
418 In the syntax of <literal>CREATE TRIGGER</literal>, the keywords
419 <literal>FUNCTION</literal> and <literal>PROCEDURE</literal> are
420 equivalent, but the referenced function must in any case be a function,
421 not a procedure. The use of the keyword <literal>PROCEDURE</literal>
422 here is historical and deprecated.
423 </para>
424 </listitem>
425 </varlistentry>
427 <varlistentry>
428 <term><replaceable class="parameter">arguments</replaceable></term>
429 <listitem>
430 <para>
431 An optional comma-separated list of arguments to be provided to
432 the function when the trigger is executed. The arguments are
433 literal string constants. Simple names and numeric constants
434 can be written here, too, but they will all be converted to
435 strings. Please check the description of the implementation
436 language of the trigger function to find out how these arguments
437 can be accessed within the function; it might be different from
438 normal function arguments.
439 </para>
440 </listitem>
441 </varlistentry>
442 </variablelist>
443 </refsect1>
445 <refsect1 id="sql-createtrigger-notes">
446 <title>Notes</title>
448 <para>
449 To create or replace a trigger on a table, the user must have the
450 <literal>TRIGGER</literal> privilege on the table. The user must
451 also have <literal>EXECUTE</literal> privilege on the trigger function.
452 </para>
454 <para>
455 Use <link linkend="sql-droptrigger"><command>DROP TRIGGER</command></link> to remove a trigger.
456 </para>
458 <para>
459 Creating a row-level trigger on a partitioned table will cause an
460 identical <quote>clone</quote> trigger to be created on each of its
461 existing partitions; and any partitions created or attached later will have
462 an identical trigger, too. If there is a conflictingly-named trigger on a
463 child partition already, an error occurs unless <command>CREATE OR REPLACE
464 TRIGGER</command> is used, in which case that trigger is replaced with a
465 clone trigger. When a partition is detached from its parent, its clone
466 triggers are removed.
467 </para>
469 <para>
470 A column-specific trigger (one defined using the <literal>UPDATE OF
471 <replaceable>column_name</replaceable></literal> syntax) will fire when any
472 of its columns are listed as targets in the <command>UPDATE</command>
473 command's <literal>SET</literal> list. It is possible for a column's value
474 to change even when the trigger is not fired, because changes made to the
475 row's contents by <literal>BEFORE UPDATE</literal> triggers are not considered.
476 Conversely, a command such as <literal>UPDATE ... SET x = x ...</literal>
477 will fire a trigger on column <literal>x</literal>, even though the column's
478 value did not change.
479 </para>
481 <para>
482 In a <literal>BEFORE</literal> trigger, the <literal>WHEN</literal> condition is
483 evaluated just before the function is or would be executed, so using
484 <literal>WHEN</literal> is not materially different from testing the same
485 condition at the beginning of the trigger function. Note in particular
486 that the <literal>NEW</literal> row seen by the condition is the current value,
487 as possibly modified by earlier triggers. Also, a <literal>BEFORE</literal>
488 trigger's <literal>WHEN</literal> condition is not allowed to examine the
489 system columns of the <literal>NEW</literal> row (such as <literal>ctid</literal>),
490 because those won't have been set yet.
491 </para>
493 <para>
494 In an <literal>AFTER</literal> trigger, the <literal>WHEN</literal> condition is
495 evaluated just after the row update occurs, and it determines whether an
496 event is queued to fire the trigger at the end of statement. So when an
497 <literal>AFTER</literal> trigger's <literal>WHEN</literal> condition does not return
498 true, it is not necessary to queue an event nor to re-fetch the row at end
499 of statement. This can result in significant speedups in statements that
500 modify many rows, if the trigger only needs to be fired for a few of the
501 rows.
502 </para>
504 <para>
505 In some cases it is possible for a single SQL command to fire more than
506 one kind of trigger. For instance an <command>INSERT</command> with
507 an <literal>ON CONFLICT DO UPDATE</literal> clause may cause both insert and
508 update operations, so it will fire both kinds of triggers as needed.
509 The transition relations supplied to triggers are
510 specific to their event type; thus an <command>INSERT</command> trigger
511 will see only the inserted rows, while an <command>UPDATE</command>
512 trigger will see only the updated rows.
513 </para>
515 <para>
516 Row updates or deletions caused by foreign-key enforcement actions, such
517 as <literal>ON UPDATE CASCADE</literal> or <literal>ON DELETE SET NULL</literal>, are
518 treated as part of the SQL command that caused them (note that such
519 actions are never deferred). Relevant triggers on the affected table will
520 be fired, so that this provides another way in which an SQL command might
521 fire triggers not directly matching its type. In simple cases, triggers
522 that request transition relations will see all changes caused in their
523 table by a single original SQL command as a single transition relation.
524 However, there are cases in which the presence of an <literal>AFTER ROW</literal>
525 trigger that requests transition relations will cause the foreign-key
526 enforcement actions triggered by a single SQL command to be split into
527 multiple steps, each with its own transition relation(s). In such cases,
528 any statement-level triggers that are present will be fired once per
529 creation of a transition relation set, ensuring that the triggers see
530 each affected row in a transition relation once and only once.
531 </para>
533 <para>
534 Statement-level triggers on a view are fired only if the action on the
535 view is handled by a row-level <literal>INSTEAD OF</literal> trigger.
536 If the action is handled by an <literal>INSTEAD</literal> rule, then
537 whatever statements are emitted by the rule are executed in place of the
538 original statement naming the view, so that the triggers that will be
539 fired are those on tables named in the replacement statements.
540 Similarly, if the view is automatically updatable, then the action is
541 handled by automatically rewriting the statement into an action on the
542 view's base table, so that the base table's statement-level triggers are
543 the ones that are fired.
544 </para>
546 <para>
547 Modifying a partitioned table or a table with inheritance children fires
548 statement-level triggers attached to the explicitly named table, but not
549 statement-level triggers for its partitions or child tables. In contrast,
550 row-level triggers are fired on the rows in affected partitions or
551 child tables, even if they are not explicitly named in the query.
552 If a statement-level trigger has been defined with transition relations
553 named by a <literal>REFERENCING</literal> clause, then before and after
554 images of rows are visible from all affected partitions or child tables.
555 In the case of inheritance children, the row images include only columns
556 that are present in the table that the trigger is attached to.
557 </para>
559 <para>
560 Currently, row-level triggers with transition relations cannot be defined
561 on partitions or inheritance child tables. Also, triggers on partitioned
562 tables may not be <literal>INSTEAD OF</literal>.
563 </para>
565 <para>
566 Currently, the <literal>OR REPLACE</literal> option is not supported for
567 constraint triggers.
568 </para>
570 <para>
571 Replacing an existing trigger within a transaction that has already
572 performed updating actions on the trigger's table is not recommended.
573 Trigger firing decisions, or portions of firing decisions, that have
574 already been made will not be reconsidered, so the effects could be
575 surprising.
576 </para>
578 <para>
579 There are a few built-in trigger functions that can be used to
580 solve common problems without having to write your own trigger code;
581 see <xref linkend="functions-trigger"/>.
582 </para>
583 </refsect1>
585 <refsect1 id="sql-createtrigger-examples">
586 <title>Examples</title>
588 <para>
589 Execute the function <function>check_account_update</function> whenever
590 a row of the table <literal>accounts</literal> is about to be updated:
592 <programlisting>
593 CREATE TRIGGER check_update
594 BEFORE UPDATE ON accounts
595 FOR EACH ROW
596 EXECUTE FUNCTION check_account_update();
597 </programlisting>
599 Modify that trigger definition to only execute the function if
600 column <literal>balance</literal> is specified as a target in
601 the <command>UPDATE</command> command:
603 <programlisting>
604 CREATE OR REPLACE TRIGGER check_update
605 BEFORE UPDATE OF balance ON accounts
606 FOR EACH ROW
607 EXECUTE FUNCTION check_account_update();
608 </programlisting>
610 This form only executes the function if column <literal>balance</literal>
611 has in fact changed value:
613 <programlisting>
614 CREATE TRIGGER check_update
615 BEFORE UPDATE ON accounts
616 FOR EACH ROW
617 WHEN (OLD.balance IS DISTINCT FROM NEW.balance)
618 EXECUTE FUNCTION check_account_update();
619 </programlisting>
621 Call a function to log updates of <literal>accounts</literal>, but only if
622 something changed:
624 <programlisting>
625 CREATE TRIGGER log_update
626 AFTER UPDATE ON accounts
627 FOR EACH ROW
628 WHEN (OLD.* IS DISTINCT FROM NEW.*)
629 EXECUTE FUNCTION log_account_update();
630 </programlisting>
632 Execute the function <function>view_insert_row</function> for each row to insert
633 rows into the tables underlying a view:
635 <programlisting>
636 CREATE TRIGGER view_insert
637 INSTEAD OF INSERT ON my_view
638 FOR EACH ROW
639 EXECUTE FUNCTION view_insert_row();
640 </programlisting>
642 Execute the function <function>check_transfer_balances_to_zero</function> for each
643 statement to confirm that the <literal>transfer</literal> rows offset to a net of
644 zero:
646 <programlisting>
647 CREATE TRIGGER transfer_insert
648 AFTER INSERT ON transfer
649 REFERENCING NEW TABLE AS inserted
650 FOR EACH STATEMENT
651 EXECUTE FUNCTION check_transfer_balances_to_zero();
652 </programlisting>
654 Execute the function <function>check_matching_pairs</function> for each row to
655 confirm that changes are made to matching pairs at the same time (by the
656 same statement):
658 <programlisting>
659 CREATE TRIGGER paired_items_update
660 AFTER UPDATE ON paired_items
661 REFERENCING NEW TABLE AS newtab OLD TABLE AS oldtab
662 FOR EACH ROW
663 EXECUTE FUNCTION check_matching_pairs();
664 </programlisting>
665 </para>
667 <para>
668 <xref linkend="trigger-example"/> contains a complete example of a trigger
669 function written in C.
670 </para>
671 </refsect1>
673 <refsect1 id="sql-createtrigger-compatibility">
674 <title>Compatibility</title>
676 <!--
677 It's not clear whether SQL/MED contemplates triggers on foreign tables.
678 Its <drop basic column definition> General Rules do mention the possibility
679 of a reference from a trigger column list. On the other hand, nothing
680 overrides the fact that CREATE TRIGGER only targets base tables. For now,
681 do not document the compatibility status of triggers on foreign tables.
684 <para>
685 The <command>CREATE TRIGGER</command> statement in
686 <productname>PostgreSQL</productname> implements a subset of the
687 <acronym>SQL</acronym> standard. The following functionalities are currently
688 missing:
690 <itemizedlist>
691 <listitem>
692 <para>
693 While transition table names for <literal>AFTER</literal> triggers are
694 specified using the <literal>REFERENCING</literal> clause in the standard way,
695 the row variables used in <literal>FOR EACH ROW</literal> triggers may not be
696 specified in a <literal>REFERENCING</literal> clause. They are available in a
697 manner that is dependent on the language in which the trigger function
698 is written, but is fixed for any one language. Some languages
699 effectively behave as though there is a <literal>REFERENCING</literal> clause
700 containing <literal>OLD ROW AS OLD NEW ROW AS NEW</literal>.
701 </para>
702 </listitem>
704 <listitem>
705 <para>
706 The standard allows transition tables to be used with
707 column-specific <literal>UPDATE</literal> triggers, but then the set of rows
708 that should be visible in the transition tables depends on the
709 trigger's column list. This is not currently implemented by
710 <productname>PostgreSQL</productname>.
711 </para>
712 </listitem>
714 <listitem>
715 <para>
716 <productname>PostgreSQL</productname> only allows the execution
717 of a user-defined function for the triggered action. The standard
718 allows the execution of a number of other SQL commands, such as
719 <command>CREATE TABLE</command>, as the triggered action. This
720 limitation is not hard to work around by creating a user-defined
721 function that executes the desired commands.
722 </para>
723 </listitem>
725 </itemizedlist>
726 </para>
728 <para>
729 SQL specifies that multiple triggers should be fired in
730 time-of-creation order. <productname>PostgreSQL</productname> uses
731 name order, which was judged to be more convenient.
732 </para>
734 <para>
735 SQL specifies that <literal>BEFORE DELETE</literal> triggers on cascaded
736 deletes fire <emphasis>after</emphasis> the cascaded <literal>DELETE</literal> completes.
737 The <productname>PostgreSQL</productname> behavior is for <literal>BEFORE
738 DELETE</literal> to always fire before the delete action, even a cascading
739 one. This is considered more consistent. There is also nonstandard
740 behavior if <literal>BEFORE</literal> triggers modify rows or prevent
741 updates during an update that is caused by a referential action. This can
742 lead to constraint violations or stored data that does not honor the
743 referential constraint.
744 </para>
746 <para>
747 The ability to specify multiple actions for a single trigger using
748 <literal>OR</literal> is a <productname>PostgreSQL</productname> extension of
749 the SQL standard.
750 </para>
752 <para>
753 The ability to fire triggers for <command>TRUNCATE</command> is a
754 <productname>PostgreSQL</productname> extension of the SQL standard, as is the
755 ability to define statement-level triggers on views.
756 </para>
758 <para>
759 <command>CREATE CONSTRAINT TRIGGER</command> is a
760 <productname>PostgreSQL</productname> extension of the <acronym>SQL</acronym>
761 standard.
762 So is the <literal>OR REPLACE</literal> option.
763 </para>
765 </refsect1>
767 <refsect1>
768 <title>See Also</title>
770 <simplelist type="inline">
771 <member><xref linkend="sql-altertrigger"/></member>
772 <member><xref linkend="sql-droptrigger"/></member>
773 <member><xref linkend="sql-createfunction"/></member>
774 <member><xref linkend="sql-set-constraints"/></member>
775 </simplelist>
776 </refsect1>
777 </refentry>