summaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/create_trigger.sgml
blob: 857066d963f34a55e866030a30c3d1c45b5feca6 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_trigger.sgml,v 1.38 2003/11/29 19:51:38 pgsql Exp $
PostgreSQL documentation
-->

<refentry id="SQL-CREATETRIGGER">
 <refmeta>
  <refentrytitle id="SQL-CREATETRIGGER-TITLE">CREATE TRIGGER</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>CREATE TRIGGER</refname>
  <refpurpose>define a new trigger</refpurpose>
 </refnamediv>

 <indexterm zone="sql-createtrigger">
  <primary>CREATE TRIGGER</primary>
 </indexterm>

 <refsynopsisdiv>
<synopsis>
CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTER } { <replaceable class="PARAMETER">event</replaceable> [ OR ... ] }
    ON <replaceable class="PARAMETER">table</replaceable> [ FOR [ EACH ] { ROW | STATEMENT } ]
    EXECUTE PROCEDURE <replaceable class="PARAMETER">funcname</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
</synopsis>
 </refsynopsisdiv>
 
 <refsect1>
  <title>Description</title>

  <para>
   <command>CREATE TRIGGER</command> creates a new trigger.  The
   trigger will be associated with the specified table and will
   execute the specified function <replaceable
   class="parameter">func</replaceable> when certain events occur.
  </para>

  <para>
   The trigger can be specified to fire either before before the
   operation is attempted on a row (before constraints are checked and
   the <command>INSERT</command>, <command>UPDATE</command>, or
   <command>DELETE</command> is attempted) or after the operation has
   completed (after constraints are checked and the
   <command>INSERT</command>, <command>UPDATE</command>, or
   <command>DELETE</command> has completed). If the trigger fires
   before the event, the trigger may skip the operation for the
   current row, or change the row being inserted (for
   <command>INSERT</command> and <command>UPDATE</command> operations
   only). If the trigger fires after the event, all changes, including
   the last insertion, update, or deletion, are <quote>visible</quote>
   to the trigger.
  </para>

  <para>
   A trigger that is marked <literal>FOR EACH ROW</literal> is called
   once for every row that the operation modifies. For example, a
   <command>DELETE</command> that affects 10 rows will cause any
   <literal>ON DELETE</literal> triggers on the target relation to be
   called 10 separate times, once for each deleted row. In contrast, a
   trigger that is marked <literal>FOR EACH STATEMENT</literal> only
   executes once for any given operation, regardless of how many rows
   it modifies (in particular, an operation that modifies zero rows
   will still result in the execution of any applicable <literal>FOR
   EACH STATEMENT</literal> triggers).
  </para>

  <para>
   If multiple triggers of the same kind are defined for the same event,
   they will be fired in alphabetical order by name.
  </para>

  <para>
   <command>SELECT</command> does not modify any rows so you can not
   create <command>SELECT</command> triggers. Rules and views are more
   appropriate in such cases.
  </para>

  <para>
   Refer to <xref linkend="triggers"> for more information about triggers.
  </para>
 </refsect1>
  
 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><replaceable class="parameter">name</replaceable></term>
    <listitem>
     <para>
      The name to give the new trigger.  This must be distinct from
      the name of any other trigger for the same table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>BEFORE</literal></term>
    <term><literal>AFTER</literal></term>
    <listitem>
     <para>
      Determines whether the function is called before or after the
      event.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">event</replaceable></term>
    <listitem>
     <para>
      One of <command>INSERT</command>, <command>UPDATE</command>, or
      <command>DELETE</command>; this specifies the event that will
      fire the trigger. Multiple events can be specified using
      <literal>OR</literal>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">table</replaceable></term>
    <listitem>
     <para>
      The name (optionally schema-qualified) of the table the trigger
      is for.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>FOR EACH ROW</literal></term>
    <term><literal>FOR EACH STATEMENT</literal></term>

    <listitem>
     <para>
      This specifies whether the trigger procedure should be fired
      once for every row affected by the trigger event, or just once
      per SQL statement. If neither is specified, <literal>FOR EACH
      STATEMENT</literal> is the default.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">func</replaceable></term>
    <listitem>
     <para>
      A user-supplied function that is declared as taking no arguments
      and returning type <literal>trigger</>, which is executed when
      the trigger fires.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">arguments</replaceable></term>
    <listitem>
     <para>
      An optional comma-separated list of arguments to be provided to
      the function when the trigger is executed.  The arguments are
      literal string constants.  Simple names and numeric constants
      may be written here, too, but they will all be converted to
      strings.  Please check the description of the implementation
      language of the trigger function about how the trigger arguments
      are accessible within the function; it may be different from
      normal function arguments.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1 id="SQL-CREATETRIGGER-notes">
  <title>Notes</title>

  <para>
   To create a trigger on a table, the user must have the
   <literal>TRIGGER</literal> privilege on the table.
  </para>

  <para>
   In <productname>PostgreSQL</productname> versions before 7.3, it was
   necessary to declare trigger functions as returning the placeholder
   type <type>opaque</>, rather than <type>trigger</>.  To support loading
   of old dump files, <command>CREATE TRIGGER</> will accept a function
   declared as returning <type>opaque</>, but it will issue a notice and
   change the function's declared return type to <type>trigger</>.
  </para>

  <para>
   Use <xref linkend="sql-droptrigger"
   endterm="sql-droptrigger-title"> to remove a trigger.
  </para>
 </refsect1>

 <refsect1 id="R1-SQL-CREATETRIGGER-2">
  <title>Examples</title>

  <para>
   <xref linkend="trigger-example"> contains a complete example.
  </para>
 </refsect1>

 <refsect1 id="SQL-CREATETRIGGER-compatibility">
  <title>Compatibility</title>
  
  <para>
   The <command>CREATE TRIGGER</command> statement in
   <productname>PostgreSQL</productname> implements a subset of the
   SQL99 standard.  (There are no provisions for triggers in SQL92.)
   The following functionality is missing:

   <itemizedlist>
    <listitem>
     <para>
      SQL99 allows triggers to fire on updates to specific columns
      (e.g., <literal>AFTER UPDATE OF col1, col2</literal>).
     </para>
    </listitem>

    <listitem>
     <para>
      SQL99 allows you to define aliases for the <quote>old</quote>
      and <quote>new</quote> rows or tables for use in the definition
      of the triggered action (e.g., <literal>CREATE TRIGGER ... ON
      tablename REFERENCING OLD ROW AS somename NEW ROW AS othername
      ...</literal>).  Since <productname>PostgreSQL</productname>
      allows trigger procedures to be written in any number of
      user-defined languages, access to the data is handled in a
      language-specific way.
     </para>
    </listitem>

    <listitem>
     <para>
      <productname>PostgreSQL</productname> only allows the execution
      of a user-defined function for the triggered action.  SQL99
      allows the execution of a number of other SQL commands, such as
      <command>CREATE TABLE</command> as triggered action.  This
      limitation is not hard to work around by creating a user-defined
      function that executes the desired commands.
     </para>
    </listitem>
   </itemizedlist>
  </para>

  <para>
   SQL99 specifies that multiple triggers should be fired in
   time-of-creation order.  <productname>PostgreSQL</productname> uses
   name order, which was judged more convenient to work with.
  </para>

  <para>
   The ability to specify multiple actions for a single trigger using
   <literal>OR</literal> is a <productname>PostgreSQL</> extension of
   the SQL standard.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-createfunction" endterm="sql-createfunction-title"></member>
   <member><xref linkend="sql-altertrigger" endterm="sql-altertrigger-title"></member>
   <member><xref linkend="sql-droptrigger" endterm="sql-droptrigger-title"></member>
  </simplelist>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->