1CREATE TRIGGER(7)                SQL Commands                CREATE TRIGGER(7)
2
3
4

NAME

6       CREATE TRIGGER - define a new trigger
7
8

SYNOPSIS

10       CREATE TRIGGER name { BEFORE | AFTER } { event [ OR ... ] }
11           ON table [ FOR [ EACH ] { ROW | STATEMENT } ]
12           EXECUTE PROCEDURE funcname ( arguments )
13
14

DESCRIPTION

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 can 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       In addition, triggers may be defined to fire  for  a  TRUNCATE,  though
40       only FOR EACH STATEMENT.
41
42       If  multiple  triggers of the same kind are defined for the same event,
43       they will be fired in alphabetical order by name.
44
45       SELECT does not modify any rows so you cannot create  SELECT  triggers.
46       Rules and views are more appropriate in such cases.
47
48       Refer to in the documentation for more information about triggers.
49

PARAMETERS

51       name   The name to give the new trigger. This must be distinct from the
52              name of any other trigger for the same table.
53
54       BEFORE
55
56       AFTER  Determines whether the function is called before  or  after  the
57              event.
58
59       event  One  of  INSERT, UPDATE, DELETE, or TRUNCATE; this specifies the
60              event that will fire the trigger. Multiple events can be  speci‐
61              fied using OR.
62
63       table  The  name (optionally schema-qualified) of the table the trigger
64              is for.
65
66       FOR EACH ROW
67
68       FOR EACH STATEMENT
69              This specifies whether the trigger  procedure  should  be  fired
70              once  for  every row affected by the trigger event, or just once
71              per SQL statement. If neither is specified, FOR  EACH  STATEMENT
72              is the default.
73
74       funcname
75              A user-supplied function that is declared as taking no arguments
76              and returning type trigger, which is executed when  the  trigger
77              fires.
78
79       arguments
80              An  optional comma-separated list of arguments to be provided to
81              the function when the trigger is  executed.  The  arguments  are
82              literal string constants. Simple names and numeric constants can
83              be written here, too, but they will all be converted to strings.
84              Please  check  the description of the implementation language of
85              the trigger function about how the trigger arguments are  acces‐
86              sible  within  the  function;  it might be different from normal
87              function arguments.
88

NOTES

90       To create a trigger on a table, the user must have the  TRIGGER  privi‐
91       lege on the table.
92
93       Use DROP TRIGGER [drop_trigger(7)] to remove a trigger.
94
95       In  PostgreSQL versions before 7.3, it was necessary to declare trigger
96       functions as returning the placeholder type opaque, rather  than  trig‐
97       ger. To support loading of old dump files, CREATE TRIGGER will accept a
98       function declared as returning opaque, but it will issue a  notice  and
99       change the function's declared return type to trigger.
100

EXAMPLES

102       in the documentation contains a complete example.
103

COMPATIBILITY

105       The  CREATE  TRIGGER statement in PostgreSQL implements a subset of the
106       SQL standard. The following functionality is currently missing:
107
108       · SQL allows triggers to fire on updates  to  specific  columns  (e.g.,
109         AFTER UPDATE OF col1, col2).
110
111       · SQL  allows you to define aliases for the ``old'' and ``new'' rows or
112         tables for use in the definition of the triggered action (e.g.,  CRE‐
113         ATE  TRIGGER ... ON tablename REFERENCING OLD ROW AS somename NEW ROW
114         AS othername ...). Since PostgreSQL allows trigger procedures  to  be
115         written  in  any number of user-defined languages, access to the data
116         is handled in a language-specific way.
117
118       · PostgreSQL only allows the execution of a user-defined  function  for
119         the  triggered  action. The standard allows the execution of a number
120         of other SQL commands, such as CREATE TABLE as the triggered  action.
121         This limitation is not hard to work around by creating a user-defined
122         function that executes the desired commands.
123
124       SQL specifies that multiple triggers should be  fired  in  time-of-cre‐
125       ation  order.  PostgreSQL  uses name order, which was judged to be more
126       convenient.
127
128       SQL specifies that BEFORE DELETE  triggers  on  cascaded  deletes  fire
129       after  the  cascaded  DELETE completes.  The PostgreSQL behavior is for
130       BEFORE DELETE to always fire before the delete action, even a cascading
131       one.  This  is  considered more consistent. There is also unpredictable
132       behavior when BEFORE triggers modify rows that are later to be modified
133       by  referential  actions.  This  can  lead  to constraint violations or
134       stored data that does not honor the referential constraint.
135
136       The ability to specify multiple actions for a single trigger  using  OR
137       is a PostgreSQL extension of the SQL standard.
138
139       The  ability to fire triggers for TRUNCATE is a PostgreSQL extension of
140       the SQL standard.
141

SEE ALSO

143       CREATE FUNCTION [create_function(7)], ALTER TRIGGER [alter_trigger(7)],
144       DROP TRIGGER [drop_trigger(7)]
145
146
147
148SQL - Language Statements         2011-09-22                 CREATE TRIGGER(7)
Impressum