Triggers
trigger
This chapter describes how to write trigger functions. Trigger
functions can be written in C or in some of the available procedural
languages. It is not currently possible to write a SQL-language
trigger function.
Overview of Trigger Behavior
A trigger can be defined to execute before or after an
INSERT, UPDATE, or
DELETE operation, either once per modified row,
or once per SQL statement.
If a trigger event occurs, the trigger's function is called
at the appropriate time to handle the event.
The trigger function must be defined before the trigger itself can be
created. The trigger function must be declared as a
function taking no arguments and returning type trigger>.
(The trigger function receives its input through a specially-passed
TriggerData> structure, not in the form of ordinary function
arguments.)
Once a suitable trigger function has been created, the trigger is
established with
.
The same trigger function can be used for multiple triggers.
Trigger functions return a table row (a value of type
HeapTuple>) to the calling executor.
A trigger fired before an operation has the following choices:
It can return a NULL> pointer to skip the operation
for the current row (and so the row will not be
inserted/updated/deleted).
For INSERT and UPDATE
triggers only, the returned row becomes the row that will
be inserted or will replace the row being updated. This
allows the trigger function to modify the row being inserted or
updated.
A before trigger that does not intend to cause either of these
behaviors must be careful to return as its result the same row that was
passed in (that is, the NEW row for INSERT and
UPDATE triggers, the OLD row for
DELETE triggers).
The return
value is ignored for triggers fired after an operation, and so
they may as well return NULL>.
If more than one trigger is defined for the same event on the same
relation, the triggers will be fired in alphabetical order by trigger
name. In the case of before triggers, the possibly-modified row
returned by each trigger becomes the input to the next trigger.
If any before trigger returns a NULL> pointer, the
operation is abandoned and subsequent triggers are not fired.
If a trigger function executes SQL commands then these
commands may fire triggers again. This is known as cascading
triggers. There is no direct limitation on the number of cascade
levels. It is possible for cascades to cause a recursive invocation
of the same trigger; for example, an INSERT
trigger might execute a command that inserts an additional row
into the same table, causing the INSERT trigger
to be fired again. It is the trigger programmer's responsibility
to avoid infinite recursion in such scenarios.
When a trigger is being defined, arguments can be specified for
it.trigger>arguments for trigger
functions> The purpose of including arguments in the
trigger definition is to allow different triggers with similar
requirements to call the same function. As an example, there
could be a generalized trigger function that takes as its
arguments two column names and puts the current user in one and
the current time stamp in the other. Properly written, this
trigger function would be independent of the specific table it is
triggering on. So the same function could be used for
INSERT events on any table with suitable
columns, to automatically track creation of records in a
transaction table for example. It could also be used to track
last-update events if defined as an UPDATE
trigger.
Visibility of Data Changes
If you execute SQL commands in your trigger function, and these
commands access the table that the trigger is for, then
you need to be aware of the data visibility rules, because they determine
whether these SQL commands will see the data change that the trigger
is fired for. Briefly:
The data change (insertion, update, or deletion) causing the trigger
to fire is naturally
not visible to SQL commands executed in a
before trigger, because it hasn't happened yet.
However, SQL commands executed in a before trigger
will see the effects of data changes
for rows previously processed in the same outer command. This
requires caution, since the ordering of these change events
is not in general predictable; a SQL command that affects
multiple rows may visit the rows in any order.
When an after trigger is fired, all data changes made by the outer
command are already complete, and are visible to executed SQL commands.
Further information about data visibility rules can be found in
. The example in contains a demonstration of these rules.
Writing Trigger Functions in C
trigger
in C
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
language then these details are handled for you. The documentation
of each procedural language explains how to write a trigger in that
language.
Trigger functions must use the version 1> function manager
interface.
When a function is called by the trigger manager, it is not passed
any normal arguments, but it is passed a 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
CALLED_AS_TRIGGER(fcinfo)
which expands to
((fcinfo)->context != NULL && IsA((fcinfo)->context, TriggerData))
If this returns true, then it is safe to cast
fcinfo->context> to type TriggerData
* and make use of the pointed-to
TriggerData> structure. The function must
not alter the TriggerData>
structure or any of the data it points to.
struct TriggerData is defined in
commands/trigger.h:
typedef struct TriggerData
{
NodeTag type;
TriggerEvent tg_event;
Relation tg_relation;
HeapTuple tg_trigtuple;
HeapTuple tg_newtuple;
Trigger *tg_trigger;
} TriggerData;
where the members are defined as follows:
type>
Always T_TriggerData.
tg_event>
Describes the event for which the function is called. You may use the
following macros to examine tg_event:
TRIGGER_FIRED_BEFORE(tg_event)
Returns true if the trigger fired before the operation.
TRIGGER_FIRED_AFTER(tg_event)
Returns true if the trigger fired after the operation.
TRIGGER_FIRED_FOR_ROW(tg_event)
Returns true if the trigger fired for a row-level event.
TRIGGER_FIRED_FOR_STATEMENT(tg_event)
Returns true if the trigger fired for a statement-level event.
TRIGGER_FIRED_BY_INSERT(tg_event)
Returns true if the trigger was fired by an INSERT command.
TRIGGER_FIRED_BY_UPDATE(tg_event)
Returns true if the trigger was fired by an UPDATE command.
TRIGGER_FIRED_BY_DELETE(tg_event)
Returns true if the trigger was fired by a DELETE command.
tg_relation>
A pointer to a structure describing the relation that the trigger fired for.
Look at utils/rel.h> for details about
this structure. The most interesting things are
tg_relation->rd_att> (descriptor of the relation
tuples) and tg_relation->rd_rel->relname>
(relation name; the type is not char*> but
NameData>; use
SPI_getrelname(tg_relation)> to get a char*> if you
need a copy of the name).
tg_trigtuple>
A pointer to the row for which the trigger was fired. This is
the row being inserted, updated, or deleted. If this trigger
was fired for an INSERT or
DELETE then this is what you should return
to from the function if you don't want to replace the row with
a different one (in the case of INSERT) or
skip the operation.
tg_newtuple>
A pointer to the new version of the row, if the trigger was
fired for an UPDATE, and NULL> if
it is for an INSERT or a
DELETE. This is what you have to return
from the function if the event is an UPDATE
and you don't want to replace this row by a different one or
skip the operation.
tg_trigger>
A pointer to a structure of type Trigger>,
defined in utils/rel.h>:
typedef struct Trigger
{
Oid tgoid;
char *tgname;
Oid tgfoid;
int16 tgtype;
bool tgenabled;
bool tgisconstraint;
Oid tgconstrrelid;
bool tgdeferrable;
bool tginitdeferred;
int16 tgnargs;
int16 tgattr[FUNC_MAX_ARGS];
char **tgargs;
} Trigger;
where tgname> is the trigger's name,
tgnargs> is number of arguments in
tgargs>, and tgargs> is an array of
pointers to the arguments specified in the CREATE
TRIGGER statement. The other members are for internal use
only.
A trigger function must return either NULL> or a
HeapTuple> pointer. Be careful to return either
tg_trigtuple> or tg_newtuple>,
as appropriate, if you don't want to modify the row being operated on.
A Complete Example
Here is a very simple example of a trigger function written in C.
(Examples of triggers written in procedural languages may be found
in the documentation of the procedural languages.)
The function trigf> reports the number of rows in the
table ttest> and skips the actual operation if the
command attempts to insert a null value into the column
x>. (So the trigger acts as a not-null constraint but
doesn't abort the transaction.)
First, the table definition:
CREATE TABLE ttest (
x integer
);
This is the source code of the trigger function:
#include "postgres.h"
#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);
PG_FUNCTION_INFO_V1(trigf);
Datum
trigf(PG_FUNCTION_ARGS)
{
TriggerData *trigdata = (TriggerData *) fcinfo->context;
TupleDesc tupdesc;
HeapTuple rettuple;
char *when;
bool checknull = false;
bool isnull;
int ret, i;
/* make sure it's called as a trigger at all */
if (!CALLED_AS_TRIGGER(fcinfo))
elog(ERROR, "trigf: not called by trigger manager");
/* tuple to return to executor */
if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
rettuple = trigdata->tg_newtuple;
else
rettuple = trigdata->tg_trigtuple;
/* check for null values */
if (!TRIGGER_FIRED_BY_DELETE(trigdata->tg_event)
&& TRIGGER_FIRED_BEFORE(trigdata->tg_event))
checknull = true;
if (TRIGGER_FIRED_BEFORE(trigdata->tg_event))
when = "before";
else
when = "after ";
tupdesc = trigdata->tg_relation->rd_att;
/* connect to SPI manager */
if ((ret = SPI_connect()) < 0)
elog(INFO, "trigf (fired %s): SPI_connect returned %d", when, ret);
/* get number of rows in table */
ret = SPI_exec("SELECT count(*) FROM ttest", 0);
if (ret < 0)
elog(NOTICE, "trigf (fired %s): SPI_exec returned %d", when, ret);
/* count(*) returns int8, so be careful to convert */
i = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0],
SPI_tuptable->tupdesc,
1,
&isnull));
elog (INFO, "trigf (fired %s): there are %d rows in ttest", when, i);
SPI_finish();
if (checknull)
{
SPI_getbinval(rettuple, tupdesc, 1, &isnull);
if (isnull)
rettuple = NULL;
}
return PointerGetDatum(rettuple);
}
After you have compiled the source code, declare the function and
the triggers:
CREATE FUNCTION trigf() RETURNS trigger
AS 'filename>'
LANGUAGE C;
CREATE TRIGGER tbefore BEFORE INSERT OR UPDATE OR DELETE ON ttest
FOR EACH ROW EXECUTE PROCEDURE trigf();
CREATE TRIGGER tafter AFTER INSERT OR UPDATE OR DELETE ON ttest
FOR EACH ROW EXECUTE PROCEDURE trigf();
Now you can test the operation of the trigger:
=> INSERT INTO ttest VALUES (NULL);
INFO: trigf (fired before): there are 0 rows in ttest
INSERT 0 0
-- Insertion skipped and AFTER trigger is not fired
=> SELECT * FROM ttest;
x
---
(0 rows)
=> INSERT INTO ttest VALUES (1);
INFO: trigf (fired before): there are 0 rows in ttest
INFO: trigf (fired after ): there are 1 rows in ttest
^^^^^^^^
remember what we said about visibility.
INSERT 167793 1
vac=> SELECT * FROM ttest;
x
---
1
(1 row)
=> INSERT INTO ttest SELECT x * 2 FROM ttest;
INFO: trigf (fired before): there are 1 rows in ttest
INFO: trigf (fired after ): there are 2 rows in ttest
^^^^^^
remember what we said about visibility.
INSERT 167794 1
=> SELECT * FROM ttest;
x
---
1
2
(2 rows)
=> UPDATE ttest SET x = NULL WHERE x = 2;
INFO: trigf (fired before): there are 2 rows in ttest
UPDATE 0
=> UPDATE ttest SET x = 4 WHERE x = 2;
INFO: trigf (fired before): there are 2 rows in ttest
INFO: trigf (fired after ): there are 2 rows in ttest
UPDATE 1
vac=> SELECT * FROM ttest;
x
---
1
4
(2 rows)
=> DELETE FROM ttest;
INFO: trigf (fired before): there are 2 rows in ttest
INFO: trigf (fired after ): there are 1 rows in ttest
INFO: trigf (fired before): there are 1 rows in ttest
INFO: trigf (fired after ): there are 0 rows in ttest
^^^^^^
remember what we said about visibility.
DELETE 2
=> SELECT * FROM ttest;
x
---
(0 rows)
There are more complex examples in
src/test/regress/regress.c and
in contrib/spi.