1CREATE TRIGGER(7)        PostgreSQL 15.4 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      │
74       ├───────────┼──────────────────────┼────────────────┼─────────────────┤
75       │           │ INSERT/UPDATE/DELETE │ Tables and     │ Tables, views,  │
76       │           │                      │ foreign tables │ and foreign     │
77       │  AFTER    │                      │                │ tables          │
78       │           ├──────────────────────┼────────────────┼─────────────────┤
79       │           │       TRUNCATE       │       —        │     Tables      │
80       ├───────────┼──────────────────────┼────────────────┼─────────────────┤
81       │           │ INSERT/UPDATE/DELETE │     Views      │        —        │
82       │INSTEAD OF ├──────────────────────┼────────────────┼─────────────────┤
83       │           │       TRUNCATE       │       —        │        —        │
84       └───────────┴──────────────────────┴────────────────┴─────────────────┘
85
86       Also, a trigger definition can specify a Boolean WHEN condition, which
87       will be tested to see whether the trigger should be fired. In row-level
88       triggers the WHEN condition can examine the old and/or new values of
89       columns of the row. Statement-level triggers can also have WHEN
90       conditions, although the feature is not so useful for them since the
91       condition cannot refer to any values in the table.
92
93       If multiple triggers of the same kind are defined for the same event,
94       they will be fired in alphabetical order by name.
95
96       When the CONSTRAINT option is specified, this command creates a
97       constraint trigger.  This is the same as a regular trigger except that
98       the timing of the trigger firing can be adjusted using SET CONSTRAINTS.
99       Constraint triggers must be AFTER ROW triggers on plain tables (not
100       foreign tables). They can be fired either at the end of the statement
101       causing the triggering event, or at the end of the containing
102       transaction; in the latter case they are said to be deferred. A pending
103       deferred-trigger firing can also be forced to happen immediately by
104       using SET CONSTRAINTS. Constraint triggers are expected to raise an
105       exception when the constraints they implement are violated.
106
107       The REFERENCING option enables collection of transition relations,
108       which are row sets that include all of the rows inserted, deleted, or
109       modified by the current SQL statement. This feature lets the trigger
110       see a global view of what the statement did, not just one row at a
111       time. This option is only allowed for an AFTER trigger that is not a
112       constraint trigger; also, if the trigger is an UPDATE trigger, it must
113       not specify a column_name list.  OLD TABLE may only be specified once,
114       and only for a trigger that can fire on UPDATE or DELETE; it creates a
115       transition relation containing the before-images of all rows updated or
116       deleted by the statement. Similarly, NEW TABLE may only be specified
117       once, and only for a trigger that can fire on UPDATE or INSERT; it
118       creates a transition relation containing the after-images of all rows
119       updated or inserted by the statement.
120
121       SELECT does not modify any rows so you cannot create SELECT triggers.
122       Rules and views may provide workable solutions to problems that seem to
123       need SELECT triggers.
124
125       Refer to Chapter 39 for more information about triggers.
126

PARAMETERS

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

NOTES

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

EXAMPLES

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

COMPATIBILITY

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

SEE ALSO

453       ALTER TRIGGER (ALTER_TRIGGER(7)), DROP TRIGGER (DROP_TRIGGER(7)),
454       CREATE FUNCTION (CREATE_FUNCTION(7)), SET CONSTRAINTS
455       (SET_CONSTRAINTS(7))
456
457
458
459PostgreSQL 15.4                      2023                    CREATE TRIGGER(7)
Impressum