From d8521b9b9104e7f329bc8f644bfea17c2577b498 Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Fri, 11 Apr 2003 18:41:20 +0000 Subject: [PATCH] Revision --- doc/src/sgml/trigger.sgml | 389 ++++++++++++++++++++------------------ 1 file changed, 201 insertions(+), 188 deletions(-) diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index c2f952aaa9..37870c42f9 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -1,30 +1,32 @@ Triggers - PostgreSQL has various server-side - function interfaces. Server-side functions can be written in - SQL, C, or any defined procedural - language. Trigger functions can be written in C and most procedural - languages, but not in SQL. Both per-row and - per-statement triggers are supported. A trigger procedure can - execute BEFORE or AFTER a INSERT, - DELETE or UPDATE, either once - per modified row, or once per SQL statement. + This chapter describes how to write trigger functions. In + particular, it describes the C-language interface for trigger + functions. The trigger interfaces in most procedural languages + work analogously. (Trigger functions cannot be written in SQL.) + + + + A trigger function can execute before or after a + INSERT, UPDATE, or + DELETE, either once per modified row, or once + per SQL statement. Trigger Definition - 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. + If a trigger event occurs, the trigger manager is called by the + executor. It sets up an information structure of type + TriggerData (described below) and calls the trigger + function to handle the event. @@ -42,15 +44,16 @@ $Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.27 2003/03/25 16:15:38 pet - Trigger functions return a HeapTuple to the calling - executor. The return value is ignored for triggers fired AFTER an - operation, but it allows BEFORE triggers to: + Trigger functions return a value of type HeapTuple, + which represents a table row, to the calling executor. The return + value is ignored for triggers fired after an operation, but a + triggers fired before an operation has the following choices: - Return a NULL pointer to skip the operation for the - current tuple (and so the tuple will not be + It can return a NULL pointer to skip the operation + for the current row (and so the row will not be inserted/updated/deleted). @@ -58,60 +61,54 @@ $Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.27 2003/03/25 16:15:38 pet For INSERT and UPDATE - triggers only, the returned tuple becomes the tuple which will - be inserted or will replace the tuple being updated. This + 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 the same NEW tuple it is passed. - - - - Note that there is no initialization performed by the - CREATE TRIGGER handler. This may be changed in - the future. + A before trigger that does not intend to cause either of these + behaviors must be careful to return the same row that was passed + in as the new row (see below). If more than one trigger is defined for the same event on the same relation, the triggers will be fired in alphabetical order by - name. In the case of BEFORE triggers, the possibly-modified tuple + 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 NULL, the operation is - abandoned and subsequent triggers are not fired. + If any before trigger returns a NULL pointer, the + operation is abandoned and subsequent triggers are not fired. - If a trigger function executes SQL-queries (using SPI) then these - queries may fire triggers again. This is known as cascading + If a trigger function executes SQL commands (using SPI) 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 recursive invocation - of the same trigger --- for example, an INSERT - trigger might execute a query that inserts an additional tuple + 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 defined, a number of arguments can be - specified. 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 field 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 - fields, 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. + When a trigger is being defined, arguments can be specified for + it. 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. @@ -122,26 +119,20 @@ $Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.27 2003/03/25 16:15:38 pet 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 + trigger function in C. If you are using a higher-level language then these details are handled for you. - - - The interface described here applies for - PostgreSQL 7.1 and later. - Earlier versions passed the TriggerData pointer in a global - variable CurrentTriggerData. - - - When a function is called by the trigger manager, it is not passed - any normal parameters, but it is passed a context + 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 + +CALLED_AS_TRIGGER(fcinfo) + + which expands to ((fcinfo)->context != NULL && IsA((fcinfo)->context, TriggerData)) @@ -176,7 +167,7 @@ typedef struct TriggerData type - Always T_TriggerData if this is a trigger event. + Always T_TriggerData. @@ -185,69 +176,69 @@ typedef struct TriggerData tg_event - describes the event for which the function is called. You may use the + Describes the event for which the function is called. You may use the following macros to examine tg_event: - TRIGGER_FIRED_BEFORE(tg_event) + TRIGGER_FIRED_BEFORE(tg_event) - returns TRUE if trigger fired BEFORE. + Returns true if the trigger fired before the operation. - TRIGGER_FIRED_AFTER(tg_event) + TRIGGER_FIRED_AFTER(tg_event) - Returns TRUE if trigger fired AFTER. + Returns true if the trigger fired after the operation. - TRIGGER_FIRED_FOR_ROW(event) + TRIGGER_FIRED_FOR_ROW(tg_event) - Returns TRUE if trigger fired for a ROW-level event. + Returns true if the trigger fired for a row-level event. - TRIGGER_FIRED_FOR_STATEMENT(event) + TRIGGER_FIRED_FOR_STATEMENT(tg_event) - Returns TRUE if trigger fired for STATEMENT-level event. + Returns true if the trigger fired for a statement-level event. - TRIGGER_FIRED_BY_INSERT(event) + TRIGGER_FIRED_BY_INSERT(tg_event) - Returns TRUE if trigger fired by INSERT. + Returns true if the trigger was fired by an INSERT command. - TRIGGER_FIRED_BY_DELETE(event) + TRIGGER_FIRED_BY_UPDATE(tg_event) - Returns TRUE if trigger fired by DELETE. + Returns true if the trigger was fired by an UPDATE command. - TRIGGER_FIRED_BY_UPDATE(event) + TRIGGER_FIRED_BY_DELETE(tg_event) - Returns TRUE if trigger fired by UPDATE. + Returns true if the trigger was fired by a DELETE command. @@ -260,14 +251,14 @@ typedef struct TriggerData tg_relation - is a pointer to structure describing the triggered - relation. Look at utils/rel.h for details about + 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's name. This is not char*, but - NameData. Use - SPI_getrelname(tg_relation) to get char* if you + (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). @@ -277,15 +268,13 @@ typedef struct TriggerData tg_trigtuple - 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 this trigger was fired for an - INSERT or DELETE then this - is what you should return to the Executor if you don't want to - replace the tuple with a different one (in the case of - INSERT) or skip the operation (in the case of - DELETE). + 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. @@ -294,12 +283,13 @@ typedef struct TriggerData tg_newtuple - 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. + 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. @@ -308,7 +298,8 @@ typedef struct TriggerData tg_trigger - is pointer to structure Trigger defined in utils/rel.h: + A pointer to a structure of type Trigger, + defined in utils/rel.h: typedef struct Trigger @@ -330,9 +321,9 @@ typedef struct Trigger where tgname is the trigger's name, tgnargs is number of arguments in - tgargs, tgargs is an array of + tgargs, and tgargs is an array of pointers to the arguments specified in the CREATE - TRIGGER statement. Other members are for internal use + TRIGGER statement. The other members are for internal use only. @@ -345,59 +336,73 @@ typedef struct Trigger Visibility of Data Changes - PostgreSQL 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 + If you are using the SPI interface to execute SQL commands in your + trigger functions written in C (or you are using a different + language and execute SQL commands in some way, which internally + goes through SPI as well), be sure to read so that you know which data is visible + at which point during the execution of a trigger. For triggers, + the most important consequences of the data visibility rules are: - -INSERT INTO a SELECT * FROM a; - + + + + The row being inserted (tg_trigtuple) is + not visible to SQL commands executed in a + before trigger. + + - 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. + + + The row being inserted (tg_trigtuple) + is visible to SQL commands executed in an + after trigger (because it was just inserted). + + + + + + A just-inserted row is visible to all SQL commands executed + within any trigger that is fired later in the execution of the + outer command (e.g., for the next row). + + + - But keep in mind this notice about visibility in the SPI documentation: - -
- -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. - -
-
- - - 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! + The next section contains a demonstration of these rules applied. - - Examples + + A Complete Example - There are more complex examples in - src/test/regress/regress.c and - in contrib/spi. + Here is a very simple example of a trigger function written in C. + 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.) - 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 a null value into x (i.e - it 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 */ +#include "commands/trigger.h" /* ... and triggers */ extern Datum trigf(PG_FUNCTION_ARGS); @@ -414,11 +419,11 @@ trigf(PG_FUNCTION_ARGS) bool isnull; int ret, i; - /* Make sure trigdata is pointing at what I expect */ + /* make sure it's called as a trigger at all */ if (!CALLED_AS_TRIGGER(fcinfo)) - elog(ERROR, "trigf: not fired by trigger manager"); + elog(ERROR, "trigf: not called by trigger manager"); - /* tuple to return to Executor */ + /* tuple to return to executor */ if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event)) rettuple = trigdata->tg_newtuple; else @@ -436,29 +441,29 @@ trigf(PG_FUNCTION_ARGS) tupdesc = trigdata->tg_relation->rd_att; - /* Connect to SPI manager */ + /* connect to SPI manager */ if ((ret = SPI_connect()) < 0) elog(INFO, "trigf (fired %s): SPI_connect returned %d", when, ret); - /* Get number of tuples in relation */ + /* 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 as of PG 7.2, so be careful to convert */ - i = (int) DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], - SPI_tuptable->tupdesc, - 1, - &isnull)); + /* count(*) returns int8, so be careful to convert */ + i = DatumGetInt64(SPI_getbinval(SPI_tuptable->vals[0], + SPI_tuptable->tupdesc, + 1, + &isnull)); - elog (NOTICE, "trigf (fired %s): there are %d tuples in ttest", when, i); + elog (INFO, "trigf (fired %s): there are %d rows in ttest", when, i); SPI_finish(); if (checknull) { - (void) SPI_getbinval(rettuple, tupdesc, 1, &isnull); + SPI_getbinval(rettuple, tupdesc, 1, &isnull); if (isnull) rettuple = NULL; } @@ -469,36 +474,38 @@ trigf(PG_FUNCTION_ARGS) - Now, compile and create the trigger function: - + After you have compiled the source code, declare the function and + the triggers: -CREATE FUNCTION trigf () RETURNS TRIGGER AS -'...path_to_so' LANGUAGE C; +CREATE FUNCTION trigf() RETURNS trigger + AS 'filename' + LANGUAGE C; -CREATE TABLE ttest (x int4); +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(); + - -vac=> CREATE TRIGGER tbefore BEFORE INSERT OR UPDATE OR DELETE ON ttest -FOR EACH ROW EXECUTE PROCEDURE trigf(); -CREATE -vac=> CREATE TRIGGER tafter AFTER INSERT OR UPDATE OR DELETE ON ttest -FOR EACH ROW EXECUTE PROCEDURE trigf(); -CREATE -vac=> INSERT INTO ttest VALUES (NULL); -WARNING: trigf (fired before): there are 0 tuples in ttest + + 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 -vac=> SELECT * FROM ttest; +=> SELECT * FROM ttest; x --- (0 rows) -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 +=> 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 @@ -508,25 +515,25 @@ vac=> SELECT * FROM ttest; 1 (1 row) -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 - ^^^^^^^^ +=> 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 -vac=> SELECT * FROM ttest; +=> SELECT * FROM ttest; x --- 1 2 (2 rows) -vac=> UPDATE ttest SET x = NULL WHERE x = 2; -INFO: trigf (fired before): there are 2 tuples in ttest +=> UPDATE ttest SET x = NULL WHERE x = 2; +INFO: trigf (fired before): there are 2 rows in ttest UPDATE 0 -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 +=> 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 @@ -535,21 +542,27 @@ vac=> SELECT * FROM ttest; 4 (2 rows) -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 - ^^^^^^^^ +=> 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 -vac=> SELECT * FROM ttest; +=> SELECT * FROM ttest; x --- (0 rows) - +
+ + + There are more complex examples in + src/test/regress/regress.c and + in contrib/spi. +