1 <!-- doc/src/sgml/trigger.sgml -->
3 <chapter id=
"triggers">
4 <title>Triggers
</title>
6 <indexterm zone=
"triggers">
7 <primary>trigger
</primary>
11 This chapter provides general information about writing trigger functions.
12 Trigger functions can be written in most of the available procedural
14 <application>PL/pgSQL
</application> (
<xref linkend=
"plpgsql"/>),
15 <application>PL/Tcl
</application> (
<xref linkend=
"pltcl"/>),
16 <application>PL/Perl
</application> (
<xref linkend=
"plperl"/>), and
17 <application>PL/Python
</application> (
<xref linkend=
"plpython"/>).
18 After reading this chapter, you should consult the chapter for
19 your favorite procedural language to find out the language-specific
20 details of writing a trigger in it.
24 It is also possible to write a trigger function in C, although
25 most people find it easier to use one of the procedural languages.
26 It is not currently possible to write a trigger function in the
27 plain SQL function language.
30 <sect1 id=
"trigger-definition">
31 <title>Overview of Trigger Behavior
</title>
34 A trigger is a specification that the database should automatically
35 execute a particular function whenever a certain type of operation is
36 performed. Triggers can be attached to tables (partitioned or not),
37 views, and foreign tables.
41 On tables and foreign tables, triggers can be defined to execute either
42 before or after any
<command>INSERT
</command>,
<command>UPDATE
</command>,
43 or
<command>DELETE
</command> operation, either once per modified row,
44 or once per
<acronym>SQL
</acronym> statement.
45 <command>UPDATE
</command> triggers can moreover be set to fire only if
46 certain columns are mentioned in the
<literal>SET
</literal> clause of
47 the
<command>UPDATE
</command> statement. Triggers can also fire
48 for
<command>TRUNCATE
</command> statements. If a trigger event occurs,
49 the trigger's function is called at the appropriate time to handle the
54 On views, triggers can be defined to execute instead of
55 <command>INSERT
</command>,
<command>UPDATE
</command>, or
56 <command>DELETE
</command> operations.
57 Such
<literal>INSTEAD OF
</literal> triggers
58 are fired once for each row that needs to be modified in the view.
59 It is the responsibility of the
60 trigger's function to perform the necessary modifications to the view's
61 underlying base table(s) and, where appropriate, return the modified
62 row as it will appear in the view. Triggers on views can also be defined
63 to execute once per
<acronym>SQL
</acronym> statement, before or after
64 <command>INSERT
</command>,
<command>UPDATE
</command>, or
65 <command>DELETE
</command> operations.
66 However, such triggers are fired only if there is also
67 an
<literal>INSTEAD OF
</literal> trigger on the view. Otherwise,
68 any statement targeting the view must be rewritten into a statement
69 affecting its underlying base table(s), and then the triggers
70 that will be fired are the ones attached to the base table(s).
74 The trigger function must be defined before the trigger itself can be
75 created. The trigger function must be declared as a
76 function taking no arguments and returning type
<literal>trigger
</literal>.
77 (The trigger function receives its input through a specially-passed
78 <structname>TriggerData
</structname> structure, not in the form of ordinary function
83 Once a suitable trigger function has been created, the trigger is
85 <xref linkend=
"sql-createtrigger"/>.
86 The same trigger function can be used for multiple triggers.
90 <productname>PostgreSQL
</productname> offers both
<firstterm>per-row
</firstterm>
91 triggers and
<firstterm>per-statement
</firstterm> triggers. With a per-row
92 trigger, the trigger function
93 is invoked once for each row that is affected by the statement
94 that fired the trigger. In contrast, a per-statement trigger is
95 invoked only once when an appropriate statement is executed,
96 regardless of the number of rows affected by that statement. In
97 particular, a statement that affects zero rows will still result
98 in the execution of any applicable per-statement triggers. These
99 two types of triggers are sometimes called
<firstterm>row-level
</firstterm>
100 triggers and
<firstterm>statement-level
</firstterm> triggers,
101 respectively. Triggers on
<command>TRUNCATE
</command> may only be
102 defined at statement level, not per-row.
106 Triggers are also classified according to whether they fire
107 <firstterm>before
</firstterm>,
<firstterm>after
</firstterm>, or
108 <firstterm>instead of
</firstterm> the operation. These are referred to
109 as
<literal>BEFORE
</literal> triggers,
<literal>AFTER
</literal> triggers, and
110 <literal>INSTEAD OF
</literal> triggers respectively.
111 Statement-level
<literal>BEFORE
</literal> triggers naturally fire before the
112 statement starts to do anything, while statement-level
<literal>AFTER
</literal>
113 triggers fire at the very end of the statement. These types of
114 triggers may be defined on tables, views, or foreign tables. Row-level
115 <literal>BEFORE
</literal> triggers fire immediately before a particular row is
116 operated on, while row-level
<literal>AFTER
</literal> triggers fire at the end of
117 the statement (but before any statement-level
<literal>AFTER
</literal> triggers).
118 These types of triggers may only be defined on tables and
119 foreign tables, not views.
120 <literal>INSTEAD OF
</literal> triggers may only be
121 defined on views, and only at row level; they fire immediately as each
122 row in the view is identified as needing to be operated on.
126 The execution of an
<literal>AFTER
</literal> trigger can be deferred
127 to the end of the transaction, rather than the end of the statement,
128 if it was defined as a
<firstterm>constraint trigger
</firstterm>.
129 In all cases, a trigger is executed as part of the same transaction as
130 the statement that triggered it, so if either the statement or the
131 trigger causes an error, the effects of both will be rolled back.
135 If an
<command>INSERT
</command> contains an
<literal>ON CONFLICT
136 DO UPDATE
</literal> clause, it is possible for row-level
137 <literal>BEFORE
</literal> <command>INSERT
</command> and then
138 <literal>BEFORE
</literal> <command>UPDATE
</command> triggers
139 to be executed on triggered rows. Such interactions can be
140 complex if the triggers are not idempotent because change made by
141 <literal>BEFORE
</literal> <command>INSERT
</command> triggers will be
142 seen by
<literal>BEFORE
</literal> <command>UPDATE
</command> triggers,
143 including changes to
<varname>EXCLUDED
</varname> columns.
147 Note that statement-level
148 <command>UPDATE
</command> triggers are executed when
<literal>ON
149 CONFLICT DO UPDATE
</literal> is specified, regardless of whether or not
150 any rows were affected by the
<command>UPDATE
</command> (and
151 regardless of whether the alternative
<command>UPDATE
</command>
152 path was ever taken). An
<command>INSERT
</command> with an
153 <literal>ON CONFLICT DO UPDATE
</literal> clause will execute
154 statement-level
<literal>BEFORE
</literal> <command>INSERT
</command>
155 triggers first, then statement-level
<literal>BEFORE
</literal>
156 <command>UPDATE
</command> triggers, followed by statement-level
157 <literal>AFTER
</literal> <command>UPDATE
</command> triggers and finally
158 statement-level
<literal>AFTER
</literal> <command>INSERT
</command>
163 A statement that targets a parent table in an inheritance or partitioning
164 hierarchy does not cause the statement-level triggers of affected child
165 tables to be fired; only the parent table's statement-level triggers are
166 fired. However, row-level triggers of any affected child tables will be
171 If an
<command>UPDATE
</command> on a partitioned table causes a row to move
172 to another partition, it will be performed as a
<command>DELETE
</command>
173 from the original partition followed by an
<command>INSERT
</command> into
174 the new partition. In this case, all row-level
<literal>BEFORE
</literal>
175 <command>UPDATE
</command> triggers and all row-level
176 <literal>BEFORE
</literal> <command>DELETE
</command> triggers are fired on
177 the original partition. Then all row-level
<literal>BEFORE
</literal>
178 <command>INSERT
</command> triggers are fired on the destination partition.
179 The possibility of surprising outcomes should be considered when all these
180 triggers affect the row being moved. As far as
<literal>AFTER ROW
</literal>
181 triggers are concerned,
<literal>AFTER
</literal> <command>DELETE
</command>
182 and
<literal>AFTER
</literal> <command>INSERT
</command> triggers are
183 applied; but
<literal>AFTER
</literal> <command>UPDATE
</command> triggers
184 are not applied because the
<command>UPDATE
</command> has been converted to
185 a
<command>DELETE
</command> and an
<command>INSERT
</command>. As far as
186 statement-level triggers are concerned, none of the
187 <command>DELETE
</command> or
<command>INSERT
</command> triggers are fired,
188 even if row movement occurs; only the
<command>UPDATE
</command> triggers
189 defined on the target table used in the
<command>UPDATE
</command> statement
194 No separate triggers are defined for
<command>MERGE
</command>. Instead,
195 statement-level or row-level
<command>UPDATE
</command>,
196 <command>DELETE
</command>, and
<command>INSERT
</command> triggers are fired
197 depending on (for statement-level triggers) what actions are specified in
198 the
<command>MERGE
</command> query and (for row-level triggers) what
199 actions are performed.
203 While running a
<command>MERGE
</command> command, statement-level
204 <literal>BEFORE
</literal> and
<literal>AFTER
</literal> triggers are
205 fired for events specified in the actions of the
<command>MERGE
</command>
206 command, irrespective of whether or not the action is ultimately performed.
207 This is the same as an
<command>UPDATE
</command> statement that updates
208 no rows, yet statement-level triggers are fired.
209 The row-level triggers are fired only when a row is actually updated,
210 inserted or deleted. So it's perfectly legal that while statement-level
211 triggers are fired for certain types of action, no row-level triggers
212 are fired for the same kind of action.
216 Trigger functions invoked by per-statement triggers should always
217 return
<symbol>NULL
</symbol>. Trigger functions invoked by per-row
218 triggers can return a table row (a value of
219 type
<structname>HeapTuple
</structname>) to the calling executor,
220 if they choose. A row-level trigger fired before an operation has
221 the following choices:
226 It can return
<symbol>NULL
</symbol> to skip the operation for the
227 current row. This instructs the executor to not perform the
228 row-level operation that invoked the trigger (the insertion,
229 modification, or deletion of a particular table row).
235 For row-level
<command>INSERT
</command>
236 and
<command>UPDATE
</command> triggers only, the returned row
237 becomes the row that will be inserted or will replace the row
238 being updated. This allows the trigger function to modify the
239 row being inserted or updated.
244 A row-level
<literal>BEFORE
</literal> trigger that does not intend to cause
245 either of these behaviors must be careful to return as its result the same
246 row that was passed in (that is, the
<varname>NEW
</varname> row
247 for
<command>INSERT
</command> and
<command>UPDATE
</command>
248 triggers, the
<varname>OLD
</varname> row for
249 <command>DELETE
</command> triggers).
253 A row-level
<literal>INSTEAD OF
</literal> trigger should either return
254 <symbol>NULL
</symbol> to indicate that it did not modify any data from
255 the view's underlying base tables, or it should return the view
256 row that was passed in (the
<varname>NEW
</varname> row
257 for
<command>INSERT
</command> and
<command>UPDATE
</command>
258 operations, or the
<varname>OLD
</varname> row for
259 <command>DELETE
</command> operations). A nonnull return value is
260 used to signal that the trigger performed the necessary data
261 modifications in the view. This will cause the count of the number
262 of rows affected by the command to be incremented. For
263 <command>INSERT
</command> and
<command>UPDATE
</command> operations only, the trigger
264 may modify the
<varname>NEW
</varname> row before returning it. This will
265 change the data returned by
266 <command>INSERT RETURNING
</command> or
<command>UPDATE RETURNING
</command>,
267 and is useful when the view will not show exactly the same data
272 The return value is ignored for row-level triggers fired after an
273 operation, and so they can return
<symbol>NULL
</symbol>.
277 Some considerations apply for generated
278 columns.
<indexterm><primary>generated column
</primary><secondary>in
279 triggers
</secondary></indexterm> Stored generated columns are computed after
280 <literal>BEFORE
</literal> triggers and before
<literal>AFTER
</literal>
281 triggers. Therefore, the generated value can be inspected in
282 <literal>AFTER
</literal> triggers. In
<literal>BEFORE
</literal> triggers,
283 the
<literal>OLD
</literal> row contains the old generated value, as one
284 would expect, but the
<literal>NEW
</literal> row does not yet contain the
285 new generated value and should not be accessed. In the C language
286 interface, the content of the column is undefined at this point; a
287 higher-level programming language should prevent access to a stored
288 generated column in the
<literal>NEW
</literal> row in a
289 <literal>BEFORE
</literal> trigger. Changes to the value of a generated
290 column in a
<literal>BEFORE
</literal> trigger are ignored and will be
295 If more than one trigger is defined for the same event on the same
296 relation, the triggers will be fired in alphabetical order by
297 trigger name. In the case of
<literal>BEFORE
</literal> and
298 <literal>INSTEAD OF
</literal> triggers, the possibly-modified row returned by
299 each trigger becomes the input to the next trigger. If any
300 <literal>BEFORE
</literal> or
<literal>INSTEAD OF
</literal> trigger returns
301 <symbol>NULL
</symbol>, the operation is abandoned for that row and subsequent
302 triggers are not fired (for that row).
306 A trigger definition can also specify a Boolean
<literal>WHEN
</literal>
307 condition, which will be tested to see whether the trigger should
308 be fired. In row-level triggers the
<literal>WHEN
</literal> condition can
309 examine the old and/or new values of columns of the row. (Statement-level
310 triggers can also have
<literal>WHEN
</literal> conditions, although the feature
311 is not so useful for them.) In a
<literal>BEFORE
</literal> trigger, the
312 <literal>WHEN
</literal>
313 condition is evaluated just before the function is or would be executed,
314 so using
<literal>WHEN
</literal> is not materially different from testing the
315 same condition at the beginning of the trigger function. However, in
316 an
<literal>AFTER
</literal> trigger, the
<literal>WHEN
</literal> condition is evaluated
317 just after the row update occurs, and it determines whether an event is
318 queued to fire the trigger at the end of statement. So when an
319 <literal>AFTER
</literal> trigger's
320 <literal>WHEN
</literal> condition does not return true, it is not necessary
321 to queue an event nor to re-fetch the row at end of statement. This
322 can result in significant speedups in statements that modify many
323 rows, if the trigger only needs to be fired for a few of the rows.
324 <literal>INSTEAD OF
</literal> triggers do not support
325 <literal>WHEN
</literal> conditions.
329 Typically, row-level
<literal>BEFORE
</literal> triggers are used for checking or
330 modifying the data that will be inserted or updated. For example,
331 a
<literal>BEFORE
</literal> trigger might be used to insert the current time into a
332 <type>timestamp
</type> column, or to check that two elements of the row are
333 consistent. Row-level
<literal>AFTER
</literal> triggers are most sensibly
334 used to propagate the updates to other tables, or make consistency
335 checks against other tables. The reason for this division of labor is
336 that an
<literal>AFTER
</literal> trigger can be certain it is seeing the final
337 value of the row, while a
<literal>BEFORE
</literal> trigger cannot; there might
338 be other
<literal>BEFORE
</literal> triggers firing after it. If you have no
339 specific reason to make a trigger
<literal>BEFORE
</literal> or
340 <literal>AFTER
</literal>, the
<literal>BEFORE
</literal> case is more efficient, since
341 the information about
342 the operation doesn't have to be saved until end of statement.
346 If a trigger function executes SQL commands then these
347 commands might fire triggers again. This is known as cascading
348 triggers. There is no direct limitation on the number of cascade
349 levels. It is possible for cascades to cause a recursive invocation
350 of the same trigger; for example, an
<command>INSERT
</command>
351 trigger might execute a command that inserts an additional row
352 into the same table, causing the
<command>INSERT
</command> trigger
353 to be fired again. It is the trigger programmer's responsibility
354 to avoid infinite recursion in such scenarios.
358 If a foreign key constraint specifies referential actions (that
359 is, cascading updates or deletes), those actions are performed via
360 ordinary SQL
<command>UPDATE
</command> or
<command>DELETE
</command>
361 commands on the referencing table.
362 In particular, any triggers that exist on the referencing table
363 will be fired for those changes. If such a trigger modifies or
364 blocks the effect of one of these commands, the end result could
365 be to break referential integrity. It is the trigger programmer's
366 responsibility to avoid that.
371 <primary>trigger
</primary>
372 <secondary>arguments for trigger functions
</secondary>
374 When a trigger is being defined, arguments can be specified for
375 it. The purpose of including arguments in the
376 trigger definition is to allow different triggers with similar
377 requirements to call the same function. As an example, there
378 could be a generalized trigger function that takes as its
379 arguments two column names and puts the current user in one and
380 the current time stamp in the other. Properly written, this
381 trigger function would be independent of the specific table it is
382 triggering on. So the same function could be used for
383 <command>INSERT
</command> events on any table with suitable
384 columns, to automatically track creation of records in a
385 transaction table for example. It could also be used to track
386 last-update events if defined as an
<command>UPDATE
</command>
391 Each programming language that supports triggers has its own method
392 for making the trigger input data available to the trigger function.
393 This input data includes the type of trigger event (e.g.,
394 <command>INSERT
</command> or
<command>UPDATE
</command>) as well as any
395 arguments that were listed in
<command>CREATE TRIGGER
</command>.
396 For a row-level trigger, the input data also includes the
397 <varname>NEW
</varname> row for
<command>INSERT
</command> and
398 <command>UPDATE
</command> triggers, and/or the
<varname>OLD
</varname> row
399 for
<command>UPDATE
</command> and
<command>DELETE
</command> triggers.
403 By default, statement-level triggers do not have any way to examine the
404 individual row(s) modified by the statement. But an
<literal>AFTER
405 STATEMENT
</literal> trigger can request that
<firstterm>transition tables
</firstterm>
406 be created to make the sets of affected rows available to the trigger.
407 <literal>AFTER ROW
</literal> triggers can also request transition tables, so
408 that they can see the total changes in the table as well as the change in
409 the individual row they are currently being fired for. The method for
410 examining the transition tables again depends on the programming language
411 that is being used, but the typical approach is to make the transition
412 tables act like read-only temporary tables that can be accessed by SQL
413 commands issued within the trigger function.
418 <sect1 id=
"trigger-datachanges">
419 <title>Visibility of Data Changes
</title>
422 If you execute SQL commands in your trigger function, and these
423 commands access the table that the trigger is for, then
424 you need to be aware of the data visibility rules, because they determine
425 whether these SQL commands will see the data change that the trigger
426 is fired for. Briefly:
432 Statement-level triggers follow simple visibility rules: none of
433 the changes made by a statement are visible to statement-level
434 <literal>BEFORE
</literal> triggers, whereas all
435 modifications are visible to statement-level
<literal>AFTER
</literal>
442 The data change (insertion, update, or deletion) causing the
443 trigger to fire is naturally
<emphasis>not
</emphasis> visible
444 to SQL commands executed in a row-level
<literal>BEFORE
</literal> trigger,
445 because it hasn't happened yet.
451 However, SQL commands executed in a row-level
<literal>BEFORE
</literal>
452 trigger
<emphasis>will
</emphasis> see the effects of data
453 changes for rows previously processed in the same outer
454 command. This requires caution, since the ordering of these
455 change events is not in general predictable; an SQL command that
456 affects multiple rows can visit the rows in any order.
462 Similarly, a row-level
<literal>INSTEAD OF
</literal> trigger will see the
463 effects of data changes made by previous firings of
<literal>INSTEAD
464 OF
</literal> triggers in the same outer command.
470 When a row-level
<literal>AFTER
</literal> trigger is fired, all data
472 by the outer command are already complete, and are visible to
473 the invoked trigger function.
480 If your trigger function is written in any of the standard procedural
481 languages, then the above statements apply only if the function is
482 declared
<literal>VOLATILE
</literal>. Functions that are declared
483 <literal>STABLE
</literal> or
<literal>IMMUTABLE
</literal> will not see changes made by
484 the calling command in any case.
488 Further information about data visibility rules can be found in
489 <xref linkend=
"spi-visibility"/>. The example in
<xref
490 linkend=
"trigger-example"/> contains a demonstration of these rules.
494 <sect1 id=
"trigger-interface">
495 <title>Writing Trigger Functions in C
</title>
497 <indexterm zone=
"trigger-interface">
498 <primary>trigger
</primary>
499 <secondary>in C
</secondary>
503 <primary>transition tables
</primary>
504 <secondary>referencing from C trigger
</secondary>
508 This section describes the low-level details of the interface to a
509 trigger function. This information is only needed when writing
510 trigger functions in C. If you are using a higher-level language then
511 these details are handled for you. In most cases you should consider
512 using a procedural language before writing your triggers in C. The
513 documentation of each procedural language explains how to write a
514 trigger in that language.
518 Trigger functions must use the
<quote>version
1</quote> function manager
523 When a function is called by the trigger manager, it is not passed
524 any normal arguments, but it is passed a
<quote>context
</quote>
525 pointer pointing to a
<structname>TriggerData
</structname> structure. C
526 functions can check whether they were called from the trigger
527 manager or not by executing the macro:
529 CALLED_AS_TRIGGER(fcinfo)
533 ((fcinfo)-
>context != NULL
&& IsA((fcinfo)-
>context, TriggerData))
535 If this returns true, then it is safe to cast
536 <literal>fcinfo-
>context
</literal> to type
<literal>TriggerData
537 *
</literal> and make use of the pointed-to
538 <structname>TriggerData
</structname> structure. The function must
539 <emphasis>not
</emphasis> alter the
<structname>TriggerData
</structname>
540 structure or any of the data it points to.
544 <structname>struct TriggerData
</structname> is defined in
545 <filename>commands/trigger.h
</filename>:
548 typedef struct TriggerData
551 TriggerEvent tg_event;
552 Relation tg_relation;
553 HeapTuple tg_trigtuple;
554 HeapTuple tg_newtuple;
556 TupleTableSlot *tg_trigslot;
557 TupleTableSlot *tg_newslot;
558 Tuplestorestate *tg_oldtable;
559 Tuplestorestate *tg_newtable;
560 const Bitmapset *tg_updatedcols;
564 where the members are defined as follows:
568 <term><structfield>type
</structfield></term>
571 Always
<literal>T_TriggerData
</literal>.
577 <term><structfield>tg_event
</structfield></term>
580 Describes the event for which the function is called. You can use the
581 following macros to examine
<literal>tg_event
</literal>:
585 <term><literal>TRIGGER_FIRED_BEFORE(tg_event)
</literal></term>
588 Returns true if the trigger fired before the operation.
594 <term><literal>TRIGGER_FIRED_AFTER(tg_event)
</literal></term>
597 Returns true if the trigger fired after the operation.
603 <term><literal>TRIGGER_FIRED_INSTEAD(tg_event)
</literal></term>
606 Returns true if the trigger fired instead of the operation.
612 <term><literal>TRIGGER_FIRED_FOR_ROW(tg_event)
</literal></term>
615 Returns true if the trigger fired for a row-level event.
621 <term><literal>TRIGGER_FIRED_FOR_STATEMENT(tg_event)
</literal></term>
624 Returns true if the trigger fired for a statement-level event.
630 <term><literal>TRIGGER_FIRED_BY_INSERT(tg_event)
</literal></term>
633 Returns true if the trigger was fired by an
<command>INSERT
</command> command.
639 <term><literal>TRIGGER_FIRED_BY_UPDATE(tg_event)
</literal></term>
642 Returns true if the trigger was fired by an
<command>UPDATE
</command> command.
648 <term><literal>TRIGGER_FIRED_BY_DELETE(tg_event)
</literal></term>
651 Returns true if the trigger was fired by a
<command>DELETE
</command> command.
657 <term><literal>TRIGGER_FIRED_BY_TRUNCATE(tg_event)
</literal></term>
660 Returns true if the trigger was fired by a
<command>TRUNCATE
</command> command.
670 <term><structfield>tg_relation
</structfield></term>
673 A pointer to a structure describing the relation that the trigger fired for.
674 Look at
<filename>utils/rel.h
</filename> for details about
675 this structure. The most interesting things are
676 <literal>tg_relation-
>rd_att
</literal> (descriptor of the relation
677 tuples) and
<literal>tg_relation-
>rd_rel-
>relname
</literal>
678 (relation name; the type is not
<type>char*
</type> but
679 <type>NameData
</type>; use
680 <literal>SPI_getrelname(tg_relation)
</literal> to get a
<type>char*
</type> if you
681 need a copy of the name).
687 <term><structfield>tg_trigtuple
</structfield></term>
690 A pointer to the row for which the trigger was fired. This is
691 the row being inserted, updated, or deleted. If this trigger
692 was fired for an
<command>INSERT
</command> or
693 <command>DELETE
</command> then this is what you should return
694 from the function if you don't want to replace the row with
695 a different one (in the case of
<command>INSERT
</command>) or
696 skip the operation. For triggers on foreign tables, values of system
697 columns herein are unspecified.
703 <term><structfield>tg_newtuple
</structfield></term>
706 A pointer to the new version of the row, if the trigger was
707 fired for an
<command>UPDATE
</command>, and
<symbol>NULL
</symbol> if
708 it is for an
<command>INSERT
</command> or a
709 <command>DELETE
</command>. This is what you have to return
710 from the function if the event is an
<command>UPDATE
</command>
711 and you don't want to replace this row by a different one or
712 skip the operation. For triggers on foreign tables, values of system
713 columns herein are unspecified.
719 <term><structfield>tg_trigger
</structfield></term>
722 A pointer to a structure of type
<structname>Trigger
</structname>,
723 defined in
<filename>utils/reltrigger.h
</filename>:
726 typedef struct Trigger
750 where
<structfield>tgname
</structfield> is the trigger's name,
751 <structfield>tgnargs
</structfield> is the number of arguments in
752 <structfield>tgargs
</structfield>, and
<structfield>tgargs
</structfield> is an array of
753 pointers to the arguments specified in the
<command>CREATE
754 TRIGGER
</command> statement. The other members are for internal use
761 <term><structfield>tg_trigslot
</structfield></term>
764 The slot containing
<structfield>tg_trigtuple
</structfield>,
765 or a
<symbol>NULL
</symbol> pointer if there is no such tuple.
771 <term><structfield>tg_newslot
</structfield></term>
774 The slot containing
<structfield>tg_newtuple
</structfield>,
775 or a
<symbol>NULL
</symbol> pointer if there is no such tuple.
781 <term><structfield>tg_oldtable
</structfield></term>
784 A pointer to a structure of type
<structname>Tuplestorestate
</structname>
785 containing zero or more rows in the format specified by
786 <structfield>tg_relation
</structfield>, or a
<symbol>NULL
</symbol> pointer
787 if there is no
<literal>OLD TABLE
</literal> transition relation.
793 <term><structfield>tg_newtable
</structfield></term>
796 A pointer to a structure of type
<structname>Tuplestorestate
</structname>
797 containing zero or more rows in the format specified by
798 <structfield>tg_relation
</structfield>, or a
<symbol>NULL
</symbol> pointer
799 if there is no
<literal>NEW TABLE
</literal> transition relation.
805 <term><structfield>tg_updatedcols
</structfield></term>
808 For
<literal>UPDATE
</literal> triggers, a bitmap set indicating the
809 columns that were updated by the triggering command. Generic trigger
810 functions can use this to optimize actions by not having to deal with
811 columns that were not changed.
815 As an example, to determine whether a column with attribute number
816 <varname>attnum
</varname> (
1-based) is a member of this bitmap set,
817 call
<literal>bms_is_member(attnum -
818 FirstLowInvalidHeapAttributeNumber,
819 trigdata-
>tg_updatedcols))
</literal>.
823 For triggers other than
<literal>UPDATE
</literal> triggers, this will
824 be
<symbol>NULL
</symbol>.
832 To allow queries issued through SPI to reference transition tables, see
833 <xref linkend=
"spi-spi-register-trigger-data"/>.
837 A trigger function must return either a
838 <structname>HeapTuple
</structname> pointer or a
<symbol>NULL
</symbol> pointer
839 (
<emphasis>not
</emphasis> an SQL null value, that is, do not set
<parameter>isNull
</parameter> true).
840 Be careful to return either
841 <structfield>tg_trigtuple
</structfield> or
<structfield>tg_newtuple
</structfield>,
842 as appropriate, if you don't want to modify the row being operated on.
846 <sect1 id=
"trigger-example">
847 <title>A Complete Trigger Example
</title>
850 Here is a very simple example of a trigger function written in C.
851 (Examples of triggers written in procedural languages can be found
852 in the documentation of the procedural languages.)
856 The function
<function>trigf
</function> reports the number of rows in the
857 table
<structname>ttest
</structname> and skips the actual operation if the
858 command attempts to insert a null value into the column
859 <structfield>x
</structfield>. (So the trigger acts as a not-null constraint but
860 doesn't abort the transaction.)
864 First, the table definition:
873 This is the source code of the trigger function:
874 <programlisting><![CDATA[
875 #include
"postgres.h"
877 #include
"executor/spi.h" /* this is what you need to work with SPI */
878 #include
"commands/trigger.h" /* ... triggers ... */
879 #include
"utils/rel.h" /* ... and relations */
883 PG_FUNCTION_INFO_V1(trigf);
886 trigf(PG_FUNCTION_ARGS)
888 TriggerData *trigdata = (TriggerData *) fcinfo-
>context;
892 bool checknull = false;
896 /* make sure it's called as a trigger at all */
897 if (!CALLED_AS_TRIGGER(fcinfo))
898 elog(ERROR,
"trigf: not called by trigger manager");
900 /* tuple to return to executor */
901 if (TRIGGER_FIRED_BY_UPDATE(trigdata-
>tg_event))
902 rettuple = trigdata-
>tg_newtuple;
904 rettuple = trigdata-
>tg_trigtuple;
906 /* check for null values */
907 if (!TRIGGER_FIRED_BY_DELETE(trigdata-
>tg_event)
908 && TRIGGER_FIRED_BEFORE(trigdata-
>tg_event))
911 if (TRIGGER_FIRED_BEFORE(trigdata-
>tg_event))
916 tupdesc = trigdata-
>tg_relation-
>rd_att;
918 /* connect to SPI manager */
921 /* get number of rows in table */
922 ret = SPI_exec(
"SELECT count(*) FROM ttest",
0);
925 elog(ERROR,
"trigf (fired %s): SPI_exec returned %d", when, ret);
927 /* count(*) returns int8, so be careful to convert */
928 i = DatumGetInt64(SPI_getbinval(SPI_tuptable-
>vals[
0],
929 SPI_tuptable-
>tupdesc,
933 elog (INFO,
"trigf (fired %s): there are %d rows in ttest", when, i);
939 SPI_getbinval(rettuple, tupdesc,
1, &isnull);
944 return PointerGetDatum(rettuple);
951 After you have compiled the source code (see
<xref
952 linkend=
"dfunc"/>), declare the function and the triggers:
954 CREATE FUNCTION trigf() RETURNS trigger
955 AS '
<replaceable>filename
</replaceable>'
958 CREATE TRIGGER tbefore BEFORE INSERT OR UPDATE OR DELETE ON ttest
959 FOR EACH ROW EXECUTE FUNCTION trigf();
961 CREATE TRIGGER tafter AFTER INSERT OR UPDATE OR DELETE ON ttest
962 FOR EACH ROW EXECUTE FUNCTION trigf();
967 Now you can test the operation of the trigger:
969 =
> INSERT INTO ttest VALUES (NULL);
970 INFO: trigf (fired before): there are
0 rows in ttest
973 -- Insertion skipped and AFTER trigger is not fired
975 =
> SELECT * FROM ttest;
980 =
> INSERT INTO ttest VALUES (
1);
981 INFO: trigf (fired before): there are
0 rows in ttest
982 INFO: trigf (fired after ): there are
1 rows in ttest
984 remember what we said about visibility.
986 vac=
> SELECT * FROM ttest;
992 =
> INSERT INTO ttest SELECT x *
2 FROM ttest;
993 INFO: trigf (fired before): there are
1 rows in ttest
994 INFO: trigf (fired after ): there are
2 rows in ttest
996 remember what we said about visibility.
998 =
> SELECT * FROM ttest;
1005 =
> UPDATE ttest SET x = NULL WHERE x =
2;
1006 INFO: trigf (fired before): there are
2 rows in ttest
1008 =
> UPDATE ttest SET x =
4 WHERE x =
2;
1009 INFO: trigf (fired before): there are
2 rows in ttest
1010 INFO: trigf (fired after ): there are
2 rows in ttest
1012 vac=
> SELECT * FROM ttest;
1019 =
> DELETE FROM ttest;
1020 INFO: trigf (fired before): there are
2 rows in ttest
1021 INFO: trigf (fired before): there are
1 rows in ttest
1022 INFO: trigf (fired after ): there are
0 rows in ttest
1023 INFO: trigf (fired after ): there are
0 rows in ttest
1025 remember what we said about visibility.
1027 =
> SELECT * FROM ttest;
1036 There are more complex examples in
1037 <filename>src/test/regress/regress.c
</filename> and
1038 in
<xref linkend=
"contrib-spi"/>.