43.10. Trigger Functions
PL/pgSQL can be used to define trigger functions on data changes or database events. A trigger function is created with the CREATE FUNCTION
command, declaring it as a function with no arguments and a return type of trigger
(for data change triggers) or event_trigger
(for database event triggers). Special local variables named TG_
something
are automatically defined to describe the condition that triggered the call.
43.10.1. Triggers on Data Changes
A data change trigger is declared as a function with no arguments and a return type of trigger
. Note that the function must be declared with no arguments even if it expects to receive some arguments specified in CREATE TRIGGER
— such arguments are passed via TG_ARGV
, as described below.
When a PL/pgSQL function is called as a trigger, several special variables are created automatically in the top-level block. They are:
NEW
Data type RECORD
; variable holding the new database row for INSERT
/UPDATE
operations in row-level triggers. This variable is null in statement-level triggers and for DELETE
operations.
OLD
Data type RECORD
; variable holding the old database row for UPDATE
/DELETE
operations in row-level triggers. This variable is null in statement-level triggers and for INSERT
operations.
TG_NAME
Data type name
; variable that contains the name of the trigger actually fired.
TG_WHEN
Data type text
; a string of BEFORE
, AFTER
, or INSTEAD OF
, depending on the trigger's definition.
TG_LEVEL
Data type text
; a string of either ROW
or STATEMENT
depending on the trigger's definition.
TG_OP
Data type text
; a string of INSERT
, UPDATE
, DELETE
, or TRUNCATE
telling for which operation the trigger was fired.
TG_RELID
Data type oid
; the object ID of the table that caused the trigger invocation.
TG_RELNAME
Data type name
; the name of the table that caused the trigger invocation. This is now deprecated, and could disappear in a future release. Use TG_TABLE_NAME
instead.
TG_TABLE_NAME
Data type name
; the name of the table that caused the trigger invocation.
TG_TABLE_SCHEMA
Data type name
; the name of the schema of the table that caused the trigger invocation.
TG_NARGS
Data type integer
; the number of arguments given to the trigger function in the CREATE TRIGGER
statement.
TG_ARGV[]
Data type array of text
; the arguments from the CREATE TRIGGER
statement. The index counts from 0. Invalid indexes (less than 0 or greater than or equal to tg_nargs
) result in a null value.
A trigger function must return either NULL
or a record/row value having exactly the structure of the table the trigger was fired for.
Row-level triggers fired BEFORE
can return null to signal the trigger manager to skip the rest of the operation for this row (i.e., subsequent triggers are not fired, and the INSERT
/UPDATE
/DELETE
does not occur for this row). If a nonnull value is returned then the operation proceeds with that row value. Returning a row value different from the original value of NEW
alters the row that will be inserted or updated. Thus, if the trigger function wants the triggering action to succeed normally without altering the row value, NEW
(or a value equal thereto) has to be returned. To alter the row to be stored, it is possible to replace single values directly in NEW
and return the modified NEW
, or to build a complete new record/row to return. In the case of a before-trigger on DELETE
, the returned value has no direct effect, but it has to be nonnull to allow the trigger action to proceed. Note that NEW
is null in DELETE
triggers, so returning that is usually not sensible. The usual idiom in DELETE
triggers is to return OLD
.
INSTEAD OF
triggers (which are always row-level triggers, and may only be used on views) can return null to signal that they did not perform any updates, and that the rest of the operation for this row should be skipped (i.e., subsequent triggers are not fired, and the row is not counted in the rows-affected status for the surrounding INSERT
/UPDATE
/DELETE
). Otherwise a nonnull value should be returned, to signal that the trigger performed the requested operation. For INSERT
and UPDATE
operations, the return value should be NEW
, which the trigger function may modify to support INSERT RETURNING
and UPDATE RETURNING
(this will also affect the row value passed to any subsequent triggers, or passed to a special EXCLUDED
alias reference within an INSERT
statement with an ON CONFLICT DO UPDATE
clause). For DELETE
operations, the return value should be OLD
.
The return value of a row-level trigger fired AFTER
or a statement-level trigger fired BEFORE
or AFTER
is always ignored; it might as well be null. However, any of these types of triggers might still abort the entire operation by raising an error.
Example 43.3 shows an example of a trigger function in PL/pgSQL.
Example 43.3. A PL/pgSQL Trigger Function
This example trigger ensures that any time a row is inserted or updated in the table, the current user name and time are stamped into the row. And it checks that an employee's name is given and that the salary is a positive value.
Another way to log changes to a table involves creating a new table that holds a row for each insert, update, or delete that occurs. This approach can be thought of as auditing changes to a table. Example 43.4 shows an example of an audit trigger function in PL/pgSQL.
Example 43.4. A PL/pgSQL Trigger Function for Auditing
This example trigger ensures that any insert, update or delete of a row in the emp
table is recorded (i.e., audited) in the emp_audit
table. The current time and user name are stamped into the row, together with the type of operation performed on it.
A variation of the previous example uses a view joining the main table to the audit table, to show when each entry was last modified. This approach still records the full audit trail of changes to the table, but also presents a simplified view of the audit trail, showing just the last modified timestamp derived from the audit trail for each entry. Example 43.5 shows an example of an audit trigger on a view in PL/pgSQL.
Example 43.5. A PL/pgSQL View Trigger Function for Auditing
This example uses a trigger on the view to make it updatable, and ensure that any insert, update or delete of a row in the view is recorded (i.e., audited) in the emp_audit
table. The current time and user name are recorded, together with the type of operation performed, and the view displays the last modified time of each row.
One use of triggers is to maintain a summary table of another table. The resulting summary can be used in place of the original table for certain queries — often with vastly reduced run times. This technique is commonly used in Data Warehousing, where the tables of measured or observed data (called fact tables) might be extremely large. Example 43.6 shows an example of a trigger function in PL/pgSQL that maintains a summary table for a fact table in a data warehouse.
Example 43.6. A PL/pgSQL Trigger Function for Maintaining a Summary Table
The schema detailed here is partly based on the Grocery Store example from The Data Warehouse Toolkit by Ralph Kimball.
AFTER
triggers can also make use of transition tables to inspect the entire set of rows changed by the triggering statement. The CREATE TRIGGER
command assigns names to one or both transition tables, and then the function can refer to those names as though they were read-only temporary tables. Example 43.7 shows an example.
Example 43.7. Auditing with Transition Tables
This example produces the same results as Example 43.4, but instead of using a trigger that fires for every row, it uses a trigger that fires once per statement, after collecting the relevant information in a transition table. This can be significantly faster than the row-trigger approach when the invoking statement has modified many rows. Notice that we must make a separate trigger declaration for each kind of event, since the REFERENCING
clauses must be different for each case. But this does not stop us from using a single trigger function if we choose. (In practice, it might be better to use three separate functions and avoid the run-time tests on TG_OP
.)
43.10.2. Triggers on Events
PL/pgSQL can be used to define event triggers. PostgreSQL requires that a function that is to be called as an event trigger must be declared as a function with no arguments and a return type of event_trigger
.
When a PL/pgSQL function is called as an event trigger, several special variables are created automatically in the top-level block. They are:
TG_EVENT
Data type text
; a string representing the event the trigger is fired for.
TG_TAG
Data type text
; variable that contains the command tag for which the trigger is fired.
Example 43.8 shows an example of an event trigger function in PL/pgSQL.
Example 43.8. A PL/pgSQL Event Trigger Function
This example trigger simply raises a NOTICE
message each time a supported command is executed.
Last updated