aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/create_trigger.sgml
blob: 2917050b789774a45f2c383c9b408e98f985906f (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
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_trigger.sgml,v 1.31 2002/12/17 17:41:30 momjian 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>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
   <date>2000-03-25</date>
  </refsynopsisdivinfo>
  <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">func</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
  </synopsis>
  
  <refsect2 id="R2-SQL-CREATETRIGGER-1">
   <refsect2info>
    <date>1998-09-21</date>
   </refsect2info>
   <title>
    Inputs
   </title>
   <para>

    <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>BEFORE</term>
      <term>AFTER</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>DELETE</command> or
		<command>UPDATE</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>FOR EACH ROW</term>
	  <term>FOR EACH STATEMENT</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</>.
       </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, along with the standard
	trigger data such as old and new tuple contents.  The arguments
	are literal string constants.  Simple names and numeric constants
	may be written here too, but they will all be converted to
	strings. Note that these arguments are not provided as normal
	function parameters (since a trigger procedure must be declared to
	take zero parameters), but are instead accessed through the
	<literal>TG_ARGV</literal> array.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>

  <refsect2 id="R2-SQL-CREATETRIGGER-2">
   <refsect2info>
    <date>1998-09-21</date>
   </refsect2info>
   <title>
    Outputs
   </title>
   <para>

    <variablelist>
     <varlistentry>
      <term><computeroutput>
CREATE TRIGGER
       </computeroutput></term>
      <listitem>
       <para>
	This message is returned if the trigger is successfully created.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>
 </refsynopsisdiv>
 
 <refsect1 id="R1-SQL-CREATETRIGGER-1">
  <refsect1info>
   <date>1998-09-21</date>
  </refsect1info>
  <title>
   Description
  </title>

  <para>
   <command>CREATE TRIGGER</command> will enter a new trigger into the current
   database.  The trigger will be associated with the relation
   <replaceable class="parameter">table</replaceable> and will execute
   the specified function <replaceable class="parameter">func</replaceable>.
  </para>

  <para>
   The trigger can be specified to fire either before BEFORE the
   operation is attempted on a tuple (before constraints are checked and
   the <command>INSERT</command>, <command>UPDATE</command> or
   <command>DELETE</command> is attempted) or AFTER the operation has
   been attempted (e.g., 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 tuple,
   or change the tuple 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 executes <literal>FOR EACH ROW</literal> of the
   specified operation 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 tuple. In contrast, a trigger that executes <literal>FOR
   EACH STATEMENT</literal> of the specified operation 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 the chapters on SPI and Triggers in the
   <citetitle>PostgreSQL Programmer's Guide</citetitle>  for  more
   information.
  </para>
 </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>
   Refer to the <xref linkend="sql-droptrigger" endterm="sql-droptrigger-title"> command for
   information on how to remove triggers.
  </para>
 </refsect1>

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

  <para>
   Check if the specified distributor code exists in the distributors
   table before appending or updating a row in the table films:

<programlisting>
CREATE TRIGGER if_dist_exists
    BEFORE INSERT OR UPDATE ON films FOR EACH ROW
    EXECUTE PROCEDURE check_primary_key ('did', 'distributors', 'did');
</programlisting>
  </para>

  <para>
   Before cancelling a distributor or updating its code, remove every
   reference to the table films:
<programlisting>
CREATE TRIGGER if_film_exists 
    BEFORE DELETE OR UPDATE ON distributors FOR EACH ROW
    EXECUTE PROCEDURE check_foreign_key (1, 'CASCADE', 'did', 'films', 'did');
</programlisting>
  </para>

  <para>
   The second example can also be done by using a foreign key,
   constraint as in:

<programlisting>
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40),
    CONSTRAINT if_film_exists
    FOREIGN KEY(did) REFERENCES films
    ON UPDATE CASCADE ON DELETE CASCADE  
);
</programlisting>
  </para>
 </refsect1>

 <refsect1 id="SQL-CREATETRIGGER-compatibility">
  <title>Compatibility</title>
  
  <variablelist>
   <varlistentry>
    <term>SQL92</term>
    <listitem>
     <para>
      There is no <command>CREATE TRIGGER</command> statement in <acronym>SQL92</acronym>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>SQL99</term>
    <listitem>
     <para>
      The <command>CREATE TRIGGER</command> statement in
      <productname>PostgreSQL</productname> implements a subset of the
      SQL99 standard.  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 stored procedure 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
         stored procedure that executes these 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>
    </listitem>
   </varlistentry>
  </variablelist>
 </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>
   <member><citetitle>PostgreSQL Programmer's Guide</citetitle></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:
-->