1CREATE TRIGGER(7)        PostgreSQL 16.1 Documentation       CREATE TRIGGER(7)
2
3
4

NAME

6       CREATE_TRIGGER - define a new trigger
7

SYNOPSIS

9       CREATE [ OR REPLACE ] [ CONSTRAINT ] TRIGGER name { BEFORE | AFTER | INSTEAD OF } { event [ OR ... ] }
10           ON table_name
11           [ FROM referenced_table_name ]
12           [ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ]
13           [ REFERENCING { { OLD | NEW } TABLE [ AS ] transition_relation_name } [ ... ] ]
14           [ FOR [ EACH ] { ROW | STATEMENT } ]
15           [ WHEN ( condition ) ]
16           EXECUTE { FUNCTION | PROCEDURE } function_name ( arguments )
17
18       where event can be one of:
19
20           INSERT
21           UPDATE [ OF column_name [, ... ] ]
22           DELETE
23           TRUNCATE
24

DESCRIPTION

26       CREATE TRIGGER creates a new trigger.  CREATE OR REPLACE TRIGGER will
27       either create a new trigger, or replace an existing trigger. The
28       trigger will be associated with the specified table, view, or foreign
29       table and will execute the specified function function_name when
30       certain operations are performed on that table.
31
32       To replace the current definition of an existing trigger, use CREATE OR
33       REPLACE TRIGGER, specifying the existing trigger's name and parent
34       table. All other properties are replaced.
35
36       The trigger can be specified to fire before the operation is attempted
37       on a row (before constraints are checked and the INSERT, UPDATE, or
38       DELETE is attempted); or after the operation has completed (after
39       constraints are checked and the INSERT, UPDATE, or DELETE has
40       completed); or instead of the operation (in the case of inserts,
41       updates or deletes on a view). If the trigger fires before or instead
42       of the event, the trigger can skip the operation for the current row,
43       or change the row being inserted (for INSERT and UPDATE operations
44       only). If the trigger fires after the event, all changes, including the
45       effects of other triggers, are “visible” to the trigger.
46
47       A trigger that is marked FOR EACH ROW is called once for every row that
48       the operation modifies. For example, a DELETE that affects 10 rows will
49       cause any ON DELETE triggers on the target relation to be called 10
50       separate times, once for each deleted row. In contrast, a trigger that
51       is marked FOR EACH STATEMENT only executes once for any given
52       operation, regardless of how many rows it modifies (in particular, an
53       operation that modifies zero rows will still result in the execution of
54       any applicable FOR EACH STATEMENT triggers).
55
56       Triggers that are specified to fire INSTEAD OF the trigger event must
57       be marked FOR EACH ROW, and can only be defined on views.  BEFORE and
58       AFTER triggers on a view must be marked as FOR EACH STATEMENT.
59
60       In addition, triggers may be defined to fire for TRUNCATE, though only
61       FOR EACH STATEMENT.
62
63       The following table summarizes which types of triggers may be used on
64       tables, views, and foreign tables:
65
66       ┌───────────┬──────────────────────┬────────────────┬─────────────────┐
67When       Event                Row-level      Statement-level 
68       ├───────────┼──────────────────────┼────────────────┼─────────────────┤
69       │           │ INSERT/UPDATE/DELETE │ Tables and     │ Tables, views,  │
70       │           │                      │ foreign tables │ and foreign     │
71       │  BEFORE   │                      │                │ tables          │
72       │           ├──────────────────────┼────────────────┼─────────────────┤
73       │           │       TRUNCATE       │       —        │ Tables and      │
74       │           │                      │                │ foreign tables  │
75       ├───────────┼──────────────────────┼────────────────┼─────────────────┤
76       │           │ INSERT/UPDATE/DELETE │ Tables and     │ Tables, views,  │
77       │           │                      │ foreign tables │ and foreign     │
78       │  AFTER    │                      │                │ tables          │
79       │           ├──────────────────────┼────────────────┼─────────────────┤
80       │           │       TRUNCATE       │       —        │ Tables and      │
81       │           │                      │                │ foreign tables  │
82       ├───────────┼──────────────────────┼────────────────┼─────────────────┤
83       │           │ INSERT/UPDATE/DELETE │     Views      │        —        │
84       │INSTEAD OF ├──────────────────────┼────────────────┼─────────────────┤
85       │           │       TRUNCATE       │       —        │        —        │
86       └───────────┴──────────────────────┴────────────────┴─────────────────┘
87
88       Also, a trigger definition can specify a Boolean WHEN condition, which
89       will be tested to see whether the trigger should be fired. In row-level
90       triggers the WHEN condition can examine the old and/or new values of
91       columns of the row. Statement-level triggers can also have WHEN
92       conditions, although the feature is not so useful for them since the
93       condition cannot refer to any values in the table.
94
95       If multiple triggers of the same kind are defined for the same event,
96       they will be fired in alphabetical order by name.
97
98       When the CONSTRAINT option is specified, this command creates a
99       constraint trigger.  This is the same as a regular trigger except that
100       the timing of the trigger firing can be adjusted using SET CONSTRAINTS.
101       Constraint triggers must be AFTER ROW triggers on plain tables (not
102       foreign tables). They can be fired either at the end of the statement
103       causing the triggering event, or at the end of the containing
104       transaction; in the latter case they are said to be deferred. A pending
105       deferred-trigger firing can also be forced to happen immediately by
106       using SET CONSTRAINTS. Constraint triggers are expected to raise an
107       exception when the constraints they implement are violated.
108
109       The REFERENCING option enables collection of transition relations,
110       which are row sets that include all of the rows inserted, deleted, or
111       modified by the current SQL statement. This feature lets the trigger
112       see a global view of what the statement did, not just one row at a
113       time. This option is only allowed for an AFTER trigger that is not a
114       constraint trigger; also, if the trigger is an UPDATE trigger, it must
115       not specify a column_name list.  OLD TABLE may only be specified once,
116       and only for a trigger that can fire on UPDATE or DELETE; it creates a
117       transition relation containing the before-images of all rows updated or
118       deleted by the statement. Similarly, NEW TABLE may only be specified
119       once, and only for a trigger that can fire on UPDATE or INSERT; it
120       creates a transition relation containing the after-images of all rows
121       updated or inserted by the statement.
122
123       SELECT does not modify any rows so you cannot create SELECT triggers.
124       Rules and views may provide workable solutions to problems that seem to
125       need SELECT triggers.
126
127       Refer to Chapter 39 for more information about triggers.
128

PARAMETERS

130       name
131           The name to give the new trigger. This must be distinct from the
132           name of any other trigger for the same table. The name cannot be
133           schema-qualified — the trigger inherits the schema of its table.
134           For a constraint trigger, this is also the name to use when
135           modifying the trigger's behavior using SET CONSTRAINTS.
136
137       BEFORE
138       AFTER
139       INSTEAD OF
140           Determines whether the function is called before, after, or instead
141           of the event. A constraint trigger can only be specified as AFTER.
142
143       event
144           One of INSERT, UPDATE, DELETE, or TRUNCATE; this specifies the
145           event that will fire the trigger. Multiple events can be specified
146           using OR, except when transition relations are requested.
147
148           For UPDATE events, it is possible to specify a list of columns
149           using this syntax:
150
151               UPDATE OF column_name1 [, column_name2 ... ]
152
153           The trigger will only fire if at least one of the listed columns is
154           mentioned as a target of the UPDATE command or if one of the listed
155           columns is a generated column that depends on a column that is the
156           target of the UPDATE.
157
158           INSTEAD OF UPDATE events do not allow a list of columns. A column
159           list cannot be specified when requesting transition relations,
160           either.
161
162       table_name
163           The name (optionally schema-qualified) of the table, view, or
164           foreign table the trigger is for.
165
166       referenced_table_name
167           The (possibly schema-qualified) name of another table referenced by
168           the constraint. This option is used for foreign-key constraints and
169           is not recommended for general use. This can only be specified for
170           constraint triggers.
171
172       DEFERRABLE
173       NOT DEFERRABLE
174       INITIALLY IMMEDIATE
175       INITIALLY DEFERRED
176           The default timing of the trigger. See the CREATE TABLE
177           (CREATE_TABLE(7)) documentation for details of these constraint
178           options. This can only be specified for constraint triggers.
179
180       REFERENCING
181           This keyword immediately precedes the declaration of one or two
182           relation names that provide access to the transition relations of
183           the triggering statement.
184
185       OLD TABLE
186       NEW TABLE
187           This clause indicates whether the following relation name is for
188           the before-image transition relation or the after-image transition
189           relation.
190
191       transition_relation_name
192           The (unqualified) name to be used within the trigger for this
193           transition relation.
194
195       FOR EACH ROW
196       FOR EACH STATEMENT
197           This specifies whether the trigger function should be fired once
198           for every row affected by the trigger event, or just once per SQL
199           statement. If neither is specified, FOR EACH STATEMENT is the
200           default. Constraint triggers can only be specified FOR EACH ROW.
201
202       condition
203           A Boolean expression that determines whether the trigger function
204           will actually be executed. If WHEN is specified, the function will
205           only be called if the condition returns true. In FOR EACH ROW
206           triggers, the WHEN condition can refer to columns of the old and/or
207           new row values by writing OLD.column_name or NEW.column_name
208           respectively. Of course, INSERT triggers cannot refer to OLD and
209           DELETE triggers cannot refer to NEW.
210
211           INSTEAD OF triggers do not support WHEN conditions.
212
213           Currently, WHEN expressions cannot contain subqueries.
214
215           Note that for constraint triggers, evaluation of the WHEN condition
216           is not deferred, but occurs immediately after the row update
217           operation is performed. If the condition does not evaluate to true
218           then the trigger is not queued for deferred execution.
219
220       function_name
221           A user-supplied function that is declared as taking no arguments
222           and returning type trigger, which is executed when the trigger
223           fires.
224
225           In the syntax of CREATE TRIGGER, the keywords FUNCTION and
226           PROCEDURE are equivalent, but the referenced function must in any
227           case be a function, not a procedure. The use of the keyword
228           PROCEDURE here is historical and deprecated.
229
230       arguments
231           An optional comma-separated list of arguments to be provided to the
232           function when the trigger is executed. The arguments are literal
233           string constants. Simple names and numeric constants can be written
234           here, too, but they will all be converted to strings. Please check
235           the description of the implementation language of the trigger
236           function to find out how these arguments can be accessed within the
237           function; it might be different from normal function arguments.
238

NOTES

240       To create or replace a trigger on a table, the user must have the
241       TRIGGER privilege on the table. The user must also have EXECUTE
242       privilege on the trigger function.
243
244       Use DROP TRIGGER to remove a trigger.
245
246       Creating a row-level trigger on a partitioned table will cause an
247       identical “clone” trigger to be created on each of its existing
248       partitions; and any partitions created or attached later will have an
249       identical trigger, too. If there is a conflictingly-named trigger on a
250       child partition already, an error occurs unless CREATE OR REPLACE
251       TRIGGER is used, in which case that trigger is replaced with a clone
252       trigger. When a partition is detached from its parent, its clone
253       triggers are removed.
254
255       A column-specific trigger (one defined using the UPDATE OF column_name
256       syntax) will fire when any of its columns are listed as targets in the
257       UPDATE command's SET list. It is possible for a column's value to
258       change even when the trigger is not fired, because changes made to the
259       row's contents by BEFORE UPDATE triggers are not considered.
260       Conversely, a command such as UPDATE ... SET x = x ...  will fire a
261       trigger on column x, even though the column's value did not change.
262
263       In a BEFORE trigger, the WHEN condition is evaluated just before the
264       function is or would be executed, so using WHEN is not materially
265       different from testing the same condition at the beginning of the
266       trigger function. Note in particular that the NEW row seen by the
267       condition is the current value, as possibly modified by earlier
268       triggers. Also, a BEFORE trigger's WHEN condition is not allowed to
269       examine the system columns of the NEW row (such as ctid), because those
270       won't have been set yet.
271
272       In an AFTER trigger, the WHEN condition is evaluated just after the row
273       update occurs, and it determines whether an event is queued to fire the
274       trigger at the end of statement. So when an AFTER trigger's WHEN
275       condition does not return true, it is not necessary to queue an event
276       nor to re-fetch the row at end of statement. This can result in
277       significant speedups in statements that modify many rows, if the
278       trigger only needs to be fired for a few of the rows.
279
280       In some cases it is possible for a single SQL command to fire more than
281       one kind of trigger. For instance an INSERT with an ON CONFLICT DO
282       UPDATE clause may cause both insert and update operations, so it will
283       fire both kinds of triggers as needed. The transition relations
284       supplied to triggers are specific to their event type; thus an INSERT
285       trigger will see only the inserted rows, while an UPDATE trigger will
286       see only the updated rows.
287
288       Row updates or deletions caused by foreign-key enforcement actions,
289       such as ON UPDATE CASCADE or ON DELETE SET NULL, are treated as part of
290       the SQL command that caused them (note that such actions are never
291       deferred). Relevant triggers on the affected table will be fired, so
292       that this provides another way in which an SQL command might fire
293       triggers not directly matching its type. In simple cases, triggers that
294       request transition relations will see all changes caused in their table
295       by a single original SQL command as a single transition relation.
296       However, there are cases in which the presence of an AFTER ROW trigger
297       that requests transition relations will cause the foreign-key
298       enforcement actions triggered by a single SQL command to be split into
299       multiple steps, each with its own transition relation(s). In such
300       cases, any statement-level triggers that are present will be fired once
301       per creation of a transition relation set, ensuring that the triggers
302       see each affected row in a transition relation once and only once.
303
304       Statement-level triggers on a view are fired only if the action on the
305       view is handled by a row-level INSTEAD OF trigger. If the action is
306       handled by an INSTEAD rule, then whatever statements are emitted by the
307       rule are executed in place of the original statement naming the view,
308       so that the triggers that will be fired are those on tables named in
309       the replacement statements. Similarly, if the view is automatically
310       updatable, then the action is handled by automatically rewriting the
311       statement into an action on the view's base table, so that the base
312       table's statement-level triggers are the ones that are fired.
313
314       Modifying a partitioned table or a table with inheritance children
315       fires statement-level triggers attached to the explicitly named table,
316       but not statement-level triggers for its partitions or child tables. In
317       contrast, row-level triggers are fired on the rows in affected
318       partitions or child tables, even if they are not explicitly named in
319       the query. If a statement-level trigger has been defined with
320       transition relations named by a REFERENCING clause, then before and
321       after images of rows are visible from all affected partitions or child
322       tables. In the case of inheritance children, the row images include
323       only columns that are present in the table that the trigger is attached
324       to.
325
326       Currently, row-level triggers with transition relations cannot be
327       defined on partitions or inheritance child tables. Also, triggers on
328       partitioned tables may not be INSTEAD OF.
329
330       Currently, the OR REPLACE option is not supported for constraint
331       triggers.
332
333       Replacing an existing trigger within a transaction that has already
334       performed updating actions on the trigger's table is not recommended.
335       Trigger firing decisions, or portions of firing decisions, that have
336       already been made will not be reconsidered, so the effects could be
337       surprising.
338
339       There are a few built-in trigger functions that can be used to solve
340       common problems without having to write your own trigger code; see
341       Section 9.28.
342

EXAMPLES

344       Execute the function check_account_update whenever a row of the table
345       accounts is about to be updated:
346
347           CREATE TRIGGER check_update
348               BEFORE UPDATE ON accounts
349               FOR EACH ROW
350               EXECUTE FUNCTION check_account_update();
351
352       Modify that trigger definition to only execute the function if column
353       balance is specified as a target in the UPDATE command:
354
355           CREATE OR REPLACE TRIGGER check_update
356               BEFORE UPDATE OF balance ON accounts
357               FOR EACH ROW
358               EXECUTE FUNCTION check_account_update();
359
360       This form only executes the function if column balance has in fact
361       changed value:
362
363           CREATE TRIGGER check_update
364               BEFORE UPDATE ON accounts
365               FOR EACH ROW
366               WHEN (OLD.balance IS DISTINCT FROM NEW.balance)
367               EXECUTE FUNCTION check_account_update();
368
369       Call a function to log updates of accounts, but only if something
370       changed:
371
372           CREATE TRIGGER log_update
373               AFTER UPDATE ON accounts
374               FOR EACH ROW
375               WHEN (OLD.* IS DISTINCT FROM NEW.*)
376               EXECUTE FUNCTION log_account_update();
377
378       Execute the function view_insert_row for each row to insert rows into
379       the tables underlying a view:
380
381           CREATE TRIGGER view_insert
382               INSTEAD OF INSERT ON my_view
383               FOR EACH ROW
384               EXECUTE FUNCTION view_insert_row();
385
386       Execute the function check_transfer_balances_to_zero for each statement
387       to confirm that the transfer rows offset to a net of zero:
388
389           CREATE TRIGGER transfer_insert
390               AFTER INSERT ON transfer
391               REFERENCING NEW TABLE AS inserted
392               FOR EACH STATEMENT
393               EXECUTE FUNCTION check_transfer_balances_to_zero();
394
395       Execute the function check_matching_pairs for each row to confirm that
396       changes are made to matching pairs at the same time (by the same
397       statement):
398
399           CREATE TRIGGER paired_items_update
400               AFTER UPDATE ON paired_items
401               REFERENCING NEW TABLE AS newtab OLD TABLE AS oldtab
402               FOR EACH ROW
403               EXECUTE FUNCTION check_matching_pairs();
404
405       Section 39.4 contains a complete example of a trigger function written
406       in C.
407

COMPATIBILITY

409       The CREATE TRIGGER statement in PostgreSQL implements a subset of the
410       SQL standard. The following functionalities are currently missing:
411
412       •   While transition table names for AFTER triggers are specified using
413           the REFERENCING clause in the standard way, the row variables used
414           in FOR EACH ROW triggers may not be specified in a REFERENCING
415           clause. They are available in a manner that is dependent on the
416           language in which the trigger function is written, but is fixed for
417           any one language. Some languages effectively behave as though there
418           is a REFERENCING clause containing OLD ROW AS OLD NEW ROW AS NEW.
419
420       •   The standard allows transition tables to be used with
421           column-specific UPDATE triggers, but then the set of rows that
422           should be visible in the transition tables depends on the trigger's
423           column list. This is not currently implemented by PostgreSQL.
424
425       •   PostgreSQL only allows the execution of a user-defined function for
426           the triggered action. The standard allows the execution of a number
427           of other SQL commands, such as CREATE TABLE, as the triggered
428           action. This limitation is not hard to work around by creating a
429           user-defined function that executes the desired commands.
430
431       SQL specifies that multiple triggers should be fired in
432       time-of-creation order.  PostgreSQL uses name order, which was judged
433       to be more convenient.
434
435       SQL specifies that BEFORE DELETE triggers on cascaded deletes fire
436       after the cascaded DELETE completes. The PostgreSQL behavior is for
437       BEFORE DELETE to always fire before the delete action, even a cascading
438       one. This is considered more consistent. There is also nonstandard
439       behavior if BEFORE triggers modify rows or prevent updates during an
440       update that is caused by a referential action. This can lead to
441       constraint violations or stored data that does not honor the
442       referential constraint.
443
444       The ability to specify multiple actions for a single trigger using OR
445       is a PostgreSQL extension of the SQL standard.
446
447       The ability to fire triggers for TRUNCATE is a PostgreSQL extension of
448       the SQL standard, as is the ability to define statement-level triggers
449       on views.
450
451       CREATE CONSTRAINT TRIGGER is a PostgreSQL extension of the SQL
452       standard. So is the OR REPLACE option.
453

SEE ALSO

455       ALTER TRIGGER (ALTER_TRIGGER(7)), DROP TRIGGER (DROP_TRIGGER(7)),
456       CREATE FUNCTION (CREATE_FUNCTION(7)), SET CONSTRAINTS
457       (SET_CONSTRAINTS(7))
458
459
460
461PostgreSQL 16.1                      2023                    CREATE TRIGGER(7)
Impressum