1CREATE TRIGGER() SQL Commands CREATE TRIGGER()
2
3
4
6 CREATE TRIGGER - define a new trigger
7
8
10 CREATE TRIGGER name { BEFORE | AFTER } { event [ OR ... ] }
11 ON table [ FOR [ EACH ] { ROW | STATEMENT } ]
12 EXECUTE PROCEDURE funcname ( arguments )
13
14
16 CREATE TRIGGER creates a new trigger. The trigger will be associated
17 with the specified table and will execute the specified function func‐
18 name when certain events occur.
19
20 The trigger can be specified to fire either before the operation is
21 attempted on a row (before constraints are checked and the INSERT,
22 UPDATE, or DELETE is attempted) or after the operation has completed
23 (after constraints are checked and the INSERT, UPDATE, or DELETE has
24 completed). If the trigger fires before the event, the trigger may skip
25 the operation for the current row, or change the row being inserted
26 (for INSERT and UPDATE operations only). If the trigger fires after the
27 event, all changes, including the last insertion, update, or deletion,
28 are ``visible'' to the trigger.
29
30 A trigger that is marked FOR EACH ROW is called once for every row that
31 the operation modifies. For example, a DELETE that affects 10 rows will
32 cause any ON DELETE triggers on the target relation to be called 10
33 separate times, once for each deleted row. In contrast, a trigger that
34 is marked FOR EACH STATEMENT only executes once for any given opera‐
35 tion, regardless of how many rows it modifies (in particular, an opera‐
36 tion that modifies zero rows will still result in the execution of any
37 applicable FOR EACH STATEMENT triggers).
38
39 If multiple triggers of the same kind are defined for the same event,
40 they will be fired in alphabetical order by name.
41
42 SELECT does not modify any rows so you can not create SELECT triggers.
43 Rules and views are more appropriate in such cases.
44
45 Refer to in the documentation for more information about triggers.
46
48 name The name to give the new trigger. This must be distinct from the
49 name of any other trigger for the same table.
50
51 BEFORE
52
53 AFTER Determines whether the function is called before or after the
54 event.
55
56 event One of INSERT, UPDATE, or DELETE; this specifies the event that
57 will fire the trigger. Multiple events can be specified using
58 OR.
59
60 table The name (optionally schema-qualified) of the table the trigger
61 is for.
62
63 FOR EACH ROW
64
65 FOR EACH STATEMENT
66 This specifies whether the trigger procedure should be fired
67 once for every row affected by the trigger event, or just once
68 per SQL statement. If neither is specified, FOR EACH STATEMENT
69 is the default.
70
71 funcname
72 A user-supplied function that is declared as taking no arguments
73 and returning type trigger, which is executed when the trigger
74 fires.
75
76 arguments
77 An optional comma-separated list of arguments to be provided to
78 the function when the trigger is executed. The arguments are
79 literal string constants. Simple names and numeric constants may
80 be written here, too, but they will all be converted to strings.
81 Please check the description of the implementation language of
82 the trigger function about how the trigger arguments are acces‐
83 sible within the function; it may be different from normal func‐
84 tion arguments.
85
87 To create a trigger on a table, the user must have the TRIGGER privi‐
88 lege on the table.
89
90 In PostgreSQL versions before 7.3, it was necessary to declare trigger
91 functions as returning the placeholder type opaque, rather than trig‐
92 ger. To support loading of old dump files, CREATE TRIGGER will accept a
93 function declared as returning opaque, but it will issue a notice and
94 change the function's declared return type to trigger.
95
96 Use DROP TRIGGER [drop_trigger(7)] to remove a trigger.
97
99 in the documentation contains a complete example.
100
102 The CREATE TRIGGER statement in PostgreSQL implements a subset of the
103 SQL standard. The following functionality is currently missing:
104
105 · SQL allows triggers to fire on updates to specific columns (e.g.,
106 AFTER UPDATE OF col1, col2).
107
108 · SQL allows you to define aliases for the ``old'' and ``new'' rows or
109 tables for use in the definition of the triggered action (e.g., CRE‐
110 ATE TRIGGER ... ON tablename REFERENCING OLD ROW AS somename NEW ROW
111 AS othername ...). Since PostgreSQL allows trigger procedures to be
112 written in any number of user-defined languages, access to the data
113 is handled in a language-specific way.
114
115 · PostgreSQL only allows the execution of a user-defined function for
116 the triggered action. The standard allows the execution of a number
117 of other SQL commands, such as CREATE TABLE as the triggered action.
118 This limitation is not hard to work around by creating a user-defined
119 function that executes the desired commands.
120
121 SQL specifies that multiple triggers should be fired in time-of-cre‐
122 ation order. PostgreSQL uses name order, which was judged to be more
123 convenient.
124
125 SQL specifies that BEFORE DELETE triggers on cascaded deletes fire
126 after the cascaded DELETE completes. The PostgreSQL behavior is for
127 BEFORE DELETE to always fire before the delete action, even a cascading
128 one. This is considered more consistent. There is also unpredictable
129 behavior when BEFORE triggers modify rows that are later to be modified
130 by referential actions. This can lead to constraint violations or
131 stored data that does not honor the referential constraint.
132
133 The ability to specify multiple actions for a single trigger using OR
134 is a PostgreSQL extension of the SQL standard.
135
137 CREATE FUNCTION [create_function(7)], ALTER TRIGGER [alter_trigger(l)],
138 DROP TRIGGER [drop_trigger(l)]
139
140
141
142SQL - Language Statements 2008-06-08 CREATE TRIGGER()