postgresql/doc/src/sgml/trigger.sgml

623 lines
17 KiB
Plaintext
Raw Normal View History

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.22 2002/04/01 22:36:06 tgl Exp $
-->
<chapter id="triggers">
<title>Triggers</title>
<para>
<productname>PostgreSQL</productname> has various server-side function
2002-03-22 20:20:45 +01:00
interfaces. Server-side functions can be written in SQL, PL/pgSQL,
Tcl, or C. Trigger functions can be written in any of these
languages except SQL. Note that statement-level trigger events are not
2000-05-17 20:30:02 +02:00
supported in the current version. You can currently specify BEFORE or
AFTER on INSERT, DELETE or UPDATE of a tuple as a trigger event.
</para>
<sect1 id="trigger-create">
<title>Trigger Creation</title>
<para>
If a trigger event occurs, the trigger manager (called by the Executor)
sets up a TriggerData information structure (described below) and calls
the trigger function to handle the event.
</para>
<para>
The trigger function must be defined before the trigger is created as a
function taking no arguments and returning opaque. If the function is
written in C, it must use the <quote>version 1</> function manager interface.
</para>
<para>
The syntax for creating triggers is as follows:
<programlisting>
CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT | DELETE | UPDATE [ OR ... ] ]
ON <replaceable>relation</replaceable> FOR EACH [ ROW | STATEMENT ]
EXECUTE PROCEDURE <replaceable>procedure</replaceable>
(<replaceable>args</replaceable>);
</programlisting>
where the arguments are:
<variablelist>
<varlistentry>
<term>
<replaceable>trigger</replaceable>
</term>
<listitem>
<para>
The name of the trigger is
used if you ever have to delete the trigger.
It is used as an argument to the <command>DROP TRIGGER</command> command.
</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>INSERT</term>
<term>DELETE</term>
<term>UPDATE</term>
<listitem>
<para>
The next element of the command determines on what event(s) will trigger
the function. Multiple events can be specified separated by OR.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>relation</replaceable></term>
<listitem>
<para>
The relation name determines which table the event applies to.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ROW</term>
<term>STATEMENT</term>
<listitem>
<para>
The FOR EACH clause determines whether the trigger is fired for each
affected row or before (or after) the entire statement has completed.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>procedure</replaceable></term>
<listitem>
<para>
2000-05-17 19:44:13 +02:00
The procedure name is the function called.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>args</replaceable></term>
<listitem>
<para>
The arguments passed to the function in the TriggerData structure.
The purpose of passing arguments to the function is to allow different
triggers with similar requirements to call the same function.
</para>
<para>
Also, <replaceable>procedure</replaceable>
may be used for triggering different relations (these
functions are named as <firstterm>general trigger functions</>).
</para>
<para>
As example of using both features above, there could be a general
function that takes as its arguments two field names and puts the current
user in one and the current timestamp in the other. This allows triggers to
be written on INSERT events to automatically track creation of records in a
transaction table for example. It could also be used as a <quote>last updated</>
function if used in an UPDATE event.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
Trigger functions return HeapTuple to the calling Executor. This
is ignored for triggers fired after an INSERT, DELETE or UPDATE operation
but it allows BEFORE triggers to:
<itemizedlist>
<listitem>
<para>
Return NULL to skip the operation for the current tuple (and so the
tuple will not be inserted/updated/deleted).
</para>
</listitem>
<listitem>
<para>
Return a pointer to another tuple (INSERT and UPDATE only) which will
be inserted (as the new version of the updated tuple if UPDATE) instead
of original tuple.
</para>
</listitem>
</itemizedlist>
</para>
<para>
Note that there is no initialization performed by the CREATE TRIGGER
handler. This will be changed in the future. Also, if more than one trigger
is defined for the same event on the same relation, the order of trigger
firing is unpredictable. This may be changed in the future.
</para>
<para>
If a trigger function executes SQL-queries (using SPI) then these queries
may fire triggers again. This is known as cascading triggers. There is no
explicit limitation on the number of cascade levels.
</para>
<para>
If a trigger is fired by INSERT and inserts a new tuple in the same
relation then this trigger will be fired again. Currently, there is nothing
provided for synchronization (etc) of these cases but this may change. At
the moment, there is function funny_dup17() in the regress tests which uses
some techniques to stop recursion (cascading) on itself...
</para>
</sect1>
<sect1 id="trigger-manager">
<title>Interaction with the Trigger Manager</title>
<para>
This section describes the low-level details of the interface to a
trigger function. This information is only needed when writing a
trigger function in C. If you are using a higher-level function
language then these details are handled for you.
</para>
<note>
<para>
The interface described here applies for
<productname>PostgreSQL</productname> 7.1 and later.
Earlier versions passed the TriggerData pointer in a global
variable CurrentTriggerData.
</para>
</note>
<para>
When a function is called by the trigger manager, it is not passed any
normal parameters, but it is passed a <quote>context</> pointer pointing to a
TriggerData structure. C functions can check whether they were called
from the trigger manager or not by executing the macro
<literal>CALLED_AS_TRIGGER(fcinfo)</literal>, which expands to
<programlisting>
((fcinfo)->context != NULL && IsA((fcinfo)->context, TriggerData))
</programlisting>
If this returns TRUE, then it is safe to cast fcinfo->context to type
<literal>TriggerData *</literal> and make use of the pointed-to
TriggerData structure.
The function must <emphasis>not</emphasis> alter the TriggerData
structure or any of the data it points to.
</para>
<para>
2002-03-22 20:20:45 +01:00
<structname>struct TriggerData</structname> is defined in
<filename>commands/trigger.h</filename>:
2002-03-22 20:20:45 +01:00
<programlisting>
1998-03-01 09:16:16 +01:00
typedef struct TriggerData
{
NodeTag type;
TriggerEvent tg_event;
Relation tg_relation;
HeapTuple tg_trigtuple;
HeapTuple tg_newtuple;
Trigger *tg_trigger;
1998-03-01 09:16:16 +01:00
} TriggerData;
2002-03-22 20:20:45 +01:00
</programlisting>
where the members are defined as follows:
<variablelist>
<varlistentry>
<term>type</term>
<listitem>
<para>
Always <literal>T_TriggerData</literal> if this is a trigger event.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>tg_event</term>
<listitem>
<para>
describes the event for which the function is called. You may use the
following macros to examine <literal>tg_event</literal>:
<variablelist>
<varlistentry>
<term>TRIGGER_FIRED_BEFORE(tg_event)</term>
<listitem>
<para>
returns TRUE if trigger fired BEFORE.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_AFTER(tg_event)</term>
<listitem>
<para>
Returns TRUE if trigger fired AFTER.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_FOR_ROW(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired for
a ROW-level event.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_FOR_STATEMENT(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired for
STATEMENT-level event.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_BY_INSERT(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by INSERT.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_BY_DELETE(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by DELETE.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER_FIRED_BY_UPDATE(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by UPDATE.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>tg_relation</term>
<listitem>
<para>
is a pointer to structure describing the triggered relation. Look at
src/include/utils/rel.h for details about this structure. The most
interest things are tg_relation->rd_att (descriptor of the relation
tuples) and tg_relation->rd_rel->relname (relation's name. This is not
char*, but NameData. Use SPI_getrelname(tg_relation) to get char* if
you need a copy of name).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>tg_trigtuple</term>
<listitem>
<para>
is a pointer to the tuple for which the trigger is fired. This is the tuple
being inserted (if INSERT), deleted (if DELETE) or updated (if UPDATE).
If INSERT/DELETE then this is what you are to return to Executor if
you don't want to replace tuple with another one (INSERT) or skip the
operation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>tg_newtuple</term>
<listitem>
<para>
is a pointer to the new version of tuple if UPDATE and NULL if this is
for an INSERT or a DELETE. This is what you are to return to Executor if
UPDATE and you don't want to replace this tuple with another one or skip
the operation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>tg_trigger</term>
<listitem>
<para>
is pointer to structure Trigger defined in src/include/utils/rel.h:
<programlisting>
1998-03-01 09:16:16 +01:00
typedef struct Trigger
{
2000-01-11 06:37:11 +01:00
Oid tgoid;
char *tgname;
Oid tgfoid;
int16 tgtype;
bool tgenabled;
bool tgisconstraint;
Oid tgconstrrelid;
2000-01-11 06:37:11 +01:00
bool tgdeferrable;
bool tginitdeferred;
int16 tgnargs;
int16 tgattr[FUNC_MAX_ARGS];
char **tgargs;
1998-03-01 09:16:16 +01:00
} Trigger;
</programlisting>
where
tgname is the trigger's name, tgnargs is number of arguments in tgargs,
tgargs is an array of pointers to the arguments specified in the CREATE
TRIGGER statement. Other members are for internal use only.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</sect1>
<sect1 id="trigger-datachanges">
<title>Visibility of Data Changes</title>
<para>
<productname>PostgreSQL</productname> data changes visibility rule: during a query execution, data
changes made by the query itself (via SQL-function, SPI-function, triggers)
are invisible to the query scan. For example, in query
<programlisting>
INSERT INTO a SELECT * FROM a;
</programlisting>
tuples inserted are invisible for SELECT scan. In effect, this
duplicates the database table within itself (subject to unique index
rules, of course) without recursing.
</para>
<para>
But keep in mind this notice about visibility in the SPI documentation:
<blockquote>
<para>
Changes made by query Q are visible by queries that are started after
query Q, no matter whether they are started inside Q (during the
execution of Q) or after Q is done.
</para>
</blockquote>
</para>
<para>
This is true for triggers as well so, though a tuple being inserted
(tg_trigtuple) is not visible to queries in a BEFORE trigger, this tuple
(just inserted) is visible to queries in an AFTER trigger, and to queries
in BEFORE/AFTER triggers fired after this!
</para>
</sect1>
<sect1 id="trigger-examples">
<title>Examples</title>
<para>
There are more complex examples in
<filename>src/test/regress/regress.c</filename> and
in <filename>contrib/spi</filename>.
</para>
<para>
Here is a very simple example of trigger usage. Function trigf reports
the number of tuples in the triggered relation ttest and skips the
operation if the query attempts to insert NULL into x (i.e - it acts as a
NOT NULL constraint but doesn't abort the transaction).
<programlisting>
1998-03-01 09:16:16 +01:00
#include "executor/spi.h" /* this is what you need to work with SPI */
#include "commands/trigger.h" /* -"- and triggers */
extern Datum trigf(PG_FUNCTION_ARGS);
1998-03-01 09:16:16 +01:00
PG_FUNCTION_INFO_V1(trigf);
Datum
trigf(PG_FUNCTION_ARGS)
1998-03-01 09:16:16 +01:00
{
TriggerData *trigdata = (TriggerData *) fcinfo->context;
1998-03-01 09:16:16 +01:00
TupleDesc tupdesc;
HeapTuple rettuple;
char *when;
bool checknull = false;
bool isnull;
int ret, i;
/* Make sure trigdata is pointing at what I expect */
if (!CALLED_AS_TRIGGER(fcinfo))
elog(ERROR, "trigf: not fired by trigger manager");
1998-03-01 09:16:16 +01:00
/* tuple to return to Executor */
if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
rettuple = trigdata->tg_newtuple;
1998-03-01 09:16:16 +01:00
else
rettuple = trigdata->tg_trigtuple;
1998-03-01 09:16:16 +01:00
/* check for NULLs ? */
if (!TRIGGER_FIRED_BY_DELETE(trigdata->tg_event) &&
TRIGGER_FIRED_BEFORE(trigdata->tg_event))
1998-03-01 09:16:16 +01:00
checknull = true;
if (TRIGGER_FIRED_BEFORE(trigdata->tg_event))
1998-03-01 09:16:16 +01:00
when = "before";
else
when = "after ";
tupdesc = trigdata->tg_relation->rd_att;
1998-03-01 09:16:16 +01:00
/* Connect to SPI manager */
if ((ret = SPI_connect()) < 0)
elog(INFO, "trigf (fired %s): SPI_connect returned %d", when, ret);
1998-03-01 09:16:16 +01:00
/* Get number of tuples in relation */
2001-10-13 01:32:34 +02:00
ret = SPI_exec("SELECT count(*) FROM ttest", 0);
1998-03-01 09:16:16 +01:00
if (ret < 0)
elog(NOTICE, "trigf (fired %s): SPI_exec returned %d", when, ret);
/* count(*) returns int8 as of PG 7.2, so be careful to convert */
i = (int) DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0],
SPI_tuptable->tupdesc,
1,
&amp;isnull));
1998-03-01 09:16:16 +01:00
elog (NOTICE, "trigf (fired %s): there are %d tuples in ttest", when, i);
SPI_finish();
if (checknull)
{
(void) SPI_getbinval(rettuple, tupdesc, 1, &amp;isnull);
1998-03-01 09:16:16 +01:00
if (isnull)
rettuple = NULL;
}
return PointerGetDatum(rettuple);
1998-03-01 09:16:16 +01:00
}
</programlisting>
</para>
1998-03-01 09:16:16 +01:00
<para>
Now, compile and create the trigger function:
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE FUNCTION trigf () RETURNS OPAQUE AS
'...path_to_so' LANGUAGE 'C';
2001-10-13 01:32:34 +02:00
CREATE TABLE ttest (x int4);
</programlisting>
1998-03-01 09:16:16 +01:00
<programlisting>
2001-10-13 01:32:34 +02:00
vac=> CREATE TRIGGER tbefore BEFORE INSERT OR UPDATE OR DELETE ON ttest
FOR EACH ROW EXECUTE PROCEDURE trigf();
1998-03-01 09:16:16 +01:00
CREATE
2001-10-13 01:32:34 +02:00
vac=> CREATE TRIGGER tafter AFTER INSERT OR UPDATE OR DELETE ON ttest
FOR EACH ROW EXECUTE PROCEDURE trigf();
1998-03-01 09:16:16 +01:00
CREATE
2001-10-13 01:32:34 +02:00
vac=> INSERT INTO ttest VALUES (NULL);
WARNING: trigf (fired before): there are 0 tuples in ttest
1998-03-01 09:16:16 +01:00
INSERT 0 0
-- Insertion skipped and AFTER trigger is not fired
2001-10-13 01:32:34 +02:00
vac=> SELECT * FROM ttest;
1998-03-01 09:16:16 +01:00
x
-
(0 rows)
2001-10-13 01:32:34 +02:00
vac=> INSERT INTO ttest VALUES (1);
INFO: trigf (fired before): there are 0 tuples in ttest
INFO: trigf (fired after ): there are 1 tuples in ttest
1998-03-01 09:16:16 +01:00
^^^^^^^^
remember what we said about visibility.
INSERT 167793 1
2001-10-13 01:32:34 +02:00
vac=> SELECT * FROM ttest;
1998-03-01 09:16:16 +01:00
x
-
1
(1 row)
2001-10-13 01:32:34 +02:00
vac=> INSERT INTO ttest SELECT x * 2 FROM ttest;
INFO: trigf (fired before): there are 1 tuples in ttest
INFO: trigf (fired after ): there are 2 tuples in ttest
1998-03-01 09:16:16 +01:00
^^^^^^^^
remember what we said about visibility.
INSERT 167794 1
2001-10-13 01:32:34 +02:00
vac=> SELECT * FROM ttest;
1998-03-01 09:16:16 +01:00
x
-
1
2
(2 rows)
2001-10-13 01:32:34 +02:00
vac=> UPDATE ttest SET x = null WHERE x = 2;
INFO: trigf (fired before): there are 2 tuples in ttest
1998-03-01 09:16:16 +01:00
UPDATE 0
2001-10-13 01:32:34 +02:00
vac=> UPDATE ttest SET x = 4 WHERE x = 2;
INFO: trigf (fired before): there are 2 tuples in ttest
INFO: trigf (fired after ): there are 2 tuples in ttest
1998-03-01 09:16:16 +01:00
UPDATE 1
2001-10-13 01:32:34 +02:00
vac=> SELECT * FROM ttest;
1998-03-01 09:16:16 +01:00
x
-
1
4
(2 rows)
2001-10-13 01:32:34 +02:00
vac=> DELETE FROM ttest;
INFO: trigf (fired before): there are 2 tuples in ttest
INFO: trigf (fired after ): there are 1 tuples in ttest
INFO: trigf (fired before): there are 1 tuples in ttest
INFO: trigf (fired after ): there are 0 tuples in ttest
1998-03-01 09:16:16 +01:00
^^^^^^^^
remember what we said about visibility.
DELETE 2
2001-10-13 01:32:34 +02:00
vac=> SELECT * FROM ttest;
1998-03-01 09:16:16 +01:00
x
-
(0 rows)
</programlisting>
</para>
</sect1>
</chapter>
<!-- 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:
-->