4 CREATE TRIGGER — define a new trigger
8 CREATE [ OR REPLACE ] [ CONSTRAINT ] TRIGGER name { BEFORE | AFTER | INSTEAD OF
11 [ FROM referenced_table_name ]
12 [ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED
14 [ REFERENCING { { OLD | NEW } TABLE [ AS ] transition_relation_name } [ ...
16 [ FOR [ EACH ] { ROW | STATEMENT } ]
17 [ WHEN ( condition ) ]
18 EXECUTE { FUNCTION | PROCEDURE } function_name ( arguments )
20 where event can be one of:
23 UPDATE [ OF column_name [, ... ] ]
29 CREATE TRIGGER creates a new trigger. CREATE OR REPLACE TRIGGER will
30 either create a new trigger, or replace an existing trigger. The
31 trigger will be associated with the specified table, view, or foreign
32 table and will execute the specified function function_name when
33 certain operations are performed on that table.
35 To replace the current definition of an existing trigger, use CREATE OR
36 REPLACE TRIGGER, specifying the existing trigger's name and parent
37 table. All other properties are replaced.
39 The trigger can be specified to fire before the operation is attempted
40 on a row (before constraints are checked and the INSERT, UPDATE, or
41 DELETE is attempted); or after the operation has completed (after
42 constraints are checked and the INSERT, UPDATE, or DELETE has
43 completed); or instead of the operation (in the case of inserts,
44 updates or deletes on a view). If the trigger fires before or instead
45 of the event, the trigger can skip the operation for the current row,
46 or change the row being inserted (for INSERT and UPDATE operations
47 only). If the trigger fires after the event, all changes, including the
48 effects of other triggers, are “visible” to the trigger.
50 A trigger that is marked FOR EACH ROW is called once for every row that
51 the operation modifies. For example, a DELETE that affects 10 rows will
52 cause any ON DELETE triggers on the target relation to be called 10
53 separate times, once for each deleted row. In contrast, a trigger that
54 is marked FOR EACH STATEMENT only executes once for any given
55 operation, regardless of how many rows it modifies (in particular, an
56 operation that modifies zero rows will still result in the execution of
57 any applicable FOR EACH STATEMENT triggers).
59 Triggers that are specified to fire INSTEAD OF the trigger event must
60 be marked FOR EACH ROW, and can only be defined on views. BEFORE and
61 AFTER triggers on a view must be marked as FOR EACH STATEMENT.
63 In addition, triggers may be defined to fire for TRUNCATE, though only
66 The following table summarizes which types of triggers may be used on
67 tables, views, and foreign tables:
68 When Event Row-level Statement-level
69 BEFORE INSERT/UPDATE/DELETE Tables and foreign tables Tables, views,
71 TRUNCATE — Tables and foreign tables
72 AFTER INSERT/UPDATE/DELETE Tables and foreign tables Tables, views, and
74 TRUNCATE — Tables and foreign tables
75 INSTEAD OF INSERT/UPDATE/DELETE Views —
78 Also, a trigger definition can specify a Boolean WHEN condition, which
79 will be tested to see whether the trigger should be fired. In row-level
80 triggers the WHEN condition can examine the old and/or new values of
81 columns of the row. Statement-level triggers can also have WHEN
82 conditions, although the feature is not so useful for them since the
83 condition cannot refer to any values in the table.
85 If multiple triggers of the same kind are defined for the same event,
86 they will be fired in alphabetical order by name.
88 When the CONSTRAINT option is specified, this command creates a
89 constraint trigger. This is the same as a regular trigger except that
90 the timing of the trigger firing can be adjusted using SET CONSTRAINTS.
91 Constraint triggers must be AFTER ROW triggers on plain tables (not
92 foreign tables). They can be fired either at the end of the statement
93 causing the triggering event, or at the end of the containing
94 transaction; in the latter case they are said to be deferred. A pending
95 deferred-trigger firing can also be forced to happen immediately by
96 using SET CONSTRAINTS. Constraint triggers are expected to raise an
97 exception when the constraints they implement are violated.
99 The REFERENCING option enables collection of transition relations,
100 which are row sets that include all of the rows inserted, deleted, or
101 modified by the current SQL statement. This feature lets the trigger
102 see a global view of what the statement did, not just one row at a
103 time. This option is only allowed for an AFTER trigger on a plain table
104 (not a foreign table). The trigger should not be a constraint trigger.
105 Also, if the trigger is an UPDATE trigger, it must not specify a
106 column_name list when using this option. OLD TABLE may only be
107 specified once, and only for a trigger that can fire on UPDATE or
108 DELETE; it creates a transition relation containing the before-images
109 of all rows updated or deleted by the statement. Similarly, NEW TABLE
110 may only be specified once, and only for a trigger that can fire on
111 UPDATE or INSERT; it creates a transition relation containing the
112 after-images of all rows updated or inserted by the statement.
114 SELECT does not modify any rows so you cannot create SELECT triggers.
115 Rules and views may provide workable solutions to problems that seem to
116 need SELECT triggers.
118 Refer to Chapter 37 for more information about triggers.
123 The name to give the new trigger. This must be distinct from the
124 name of any other trigger for the same table. The name cannot be
125 schema-qualified — the trigger inherits the schema of its table.
126 For a constraint trigger, this is also the name to use when
127 modifying the trigger's behavior using SET CONSTRAINTS.
132 Determines whether the function is called before, after, or
133 instead of the event. A constraint trigger can only be specified
137 One of INSERT, UPDATE, DELETE, or TRUNCATE; this specifies the
138 event that will fire the trigger. Multiple events can be
139 specified using OR, except when transition relations are
142 For UPDATE events, it is possible to specify a list of columns
145 UPDATE OF column_name1 [, column_name2 ... ]
147 The trigger will only fire if at least one of the listed columns
148 is mentioned as a target of the UPDATE command or if one of the
149 listed columns is a generated column that depends on a column
150 that is the target of the UPDATE.
152 INSTEAD OF UPDATE events do not allow a list of columns. A
153 column list cannot be specified when requesting transition
157 The name (optionally schema-qualified) of the table, view, or
158 foreign table the trigger is for.
160 referenced_table_name
161 The (possibly schema-qualified) name of another table referenced
162 by the constraint. This option is used for foreign-key
163 constraints and is not recommended for general use. This can
164 only be specified for constraint triggers.
170 The default timing of the trigger. See the CREATE TABLE
171 documentation for details of these constraint options. This can
172 only be specified for constraint triggers.
175 This keyword immediately precedes the declaration of one or two
176 relation names that provide access to the transition relations
177 of the triggering statement.
181 This clause indicates whether the following relation name is for
182 the before-image transition relation or the after-image
185 transition_relation_name
186 The (unqualified) name to be used within the trigger for this
191 This specifies whether the trigger function should be fired once
192 for every row affected by the trigger event, or just once per
193 SQL statement. If neither is specified, FOR EACH STATEMENT is
194 the default. Constraint triggers can only be specified FOR EACH
198 A Boolean expression that determines whether the trigger
199 function will actually be executed. If WHEN is specified, the
200 function will only be called if the condition returns true. In
201 FOR EACH ROW triggers, the WHEN condition can refer to columns
202 of the old and/or new row values by writing OLD.column_name or
203 NEW.column_name respectively. Of course, INSERT triggers cannot
204 refer to OLD and DELETE triggers cannot refer to NEW.
206 INSTEAD OF triggers do not support WHEN conditions.
208 Currently, WHEN expressions cannot contain subqueries.
210 Note that for constraint triggers, evaluation of the WHEN
211 condition is not deferred, but occurs immediately after the row
212 update operation is performed. If the condition does not
213 evaluate to true then the trigger is not queued for deferred
217 A user-supplied function that is declared as taking no arguments
218 and returning type trigger, which is executed when the trigger
221 In the syntax of CREATE TRIGGER, the keywords FUNCTION and
222 PROCEDURE are equivalent, but the referenced function must in
223 any case be a function, not a procedure. The use of the keyword
224 PROCEDURE here is historical and deprecated.
227 An optional comma-separated list of arguments to be provided to
228 the function when the trigger is executed. The arguments are
229 literal string constants. Simple names and numeric constants can
230 be written here, too, but they will all be converted to strings.
231 Please check the description of the implementation language of
232 the trigger function to find out how these arguments can be
233 accessed within the function; it might be different from normal
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.
242 Use DROP TRIGGER to remove a trigger.
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.
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.
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.
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.
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.
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.
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.
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
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.
328 Currently, the OR REPLACE option is not supported for constraint
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
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
343 Execute the function check_account_update whenever a row of the table
344 accounts is about to be updated:
345 CREATE TRIGGER check_update
346 BEFORE UPDATE ON accounts
348 EXECUTE FUNCTION check_account_update();
350 Modify that trigger definition to only execute the function if column
351 balance is specified as a target in the UPDATE command:
352 CREATE OR REPLACE TRIGGER check_update
353 BEFORE UPDATE OF balance ON accounts
355 EXECUTE FUNCTION check_account_update();
357 This form only executes the function if column balance has in fact
359 CREATE TRIGGER check_update
360 BEFORE UPDATE ON accounts
362 WHEN (OLD.balance IS DISTINCT FROM NEW.balance)
363 EXECUTE FUNCTION check_account_update();
365 Call a function to log updates of accounts, but only if something
367 CREATE TRIGGER log_update
368 AFTER UPDATE ON accounts
370 WHEN (OLD.* IS DISTINCT FROM NEW.*)
371 EXECUTE FUNCTION log_account_update();
373 Execute the function view_insert_row for each row to insert rows into
374 the tables underlying a view:
375 CREATE TRIGGER view_insert
376 INSTEAD OF INSERT ON my_view
378 EXECUTE FUNCTION view_insert_row();
380 Execute the function check_transfer_balances_to_zero for each statement
381 to confirm that the transfer rows offset to a net of zero:
382 CREATE TRIGGER transfer_insert
383 AFTER INSERT ON transfer
384 REFERENCING NEW TABLE AS inserted
386 EXECUTE FUNCTION check_transfer_balances_to_zero();
388 Execute the function check_matching_pairs for each row to confirm that
389 changes are made to matching pairs at the same time (by the same
391 CREATE TRIGGER paired_items_update
392 AFTER UPDATE ON paired_items
393 REFERENCING NEW TABLE AS newtab OLD TABLE AS oldtab
395 EXECUTE FUNCTION check_matching_pairs();
397 Section 37.4 contains a complete example of a trigger function written
402 The CREATE TRIGGER statement in PostgreSQL implements a subset of the
403 SQL standard. The following functionalities are currently missing:
404 * While transition table names for AFTER triggers are specified using
405 the REFERENCING clause in the standard way, the row variables used
406 in FOR EACH ROW triggers may not be specified in a REFERENCING
407 clause. They are available in a manner that is dependent on the
408 language in which the trigger function is written, but is fixed for
409 any one language. Some languages effectively behave as though there
410 is a REFERENCING clause containing OLD ROW AS OLD NEW ROW AS NEW.
411 * The standard allows transition tables to be used with
412 column-specific UPDATE triggers, but then the set of rows that
413 should be visible in the transition tables depends on the trigger's
414 column list. This is not currently implemented by PostgreSQL.
415 * PostgreSQL only allows the execution of a user-defined function for
416 the triggered action. The standard allows the execution of a number
417 of other SQL commands, such as CREATE TABLE, as the triggered
418 action. This limitation is not hard to work around by creating a
419 user-defined function that executes the desired commands.
421 SQL specifies that multiple triggers should be fired in
422 time-of-creation order. PostgreSQL uses name order, which was judged to
425 SQL specifies that BEFORE DELETE triggers on cascaded deletes fire
426 after the cascaded DELETE completes. The PostgreSQL behavior is for
427 BEFORE DELETE to always fire before the delete action, even a cascading
428 one. This is considered more consistent. There is also nonstandard
429 behavior if BEFORE triggers modify rows or prevent updates during an
430 update that is caused by a referential action. This can lead to
431 constraint violations or stored data that does not honor the
432 referential constraint.
434 The ability to specify multiple actions for a single trigger using OR
435 is a PostgreSQL extension of the SQL standard.
437 The ability to fire triggers for TRUNCATE is a PostgreSQL extension of
438 the SQL standard, as is the ability to define statement-level triggers
441 CREATE CONSTRAINT TRIGGER is a PostgreSQL extension of the SQL
442 standard. So is the OR REPLACE option.
446 ALTER TRIGGER, DROP TRIGGER, CREATE FUNCTION, SET CONSTRAINTS