The CREATE TRIGGER statement creates a trigger, which defines a set of actions that are executed when a database event occurs on a specified table.
A database event is a delete, insert, or update operation. For example, if you define a trigger for a delete on a particular table, the trigger's action occurs whenever someone deletes a row or rows from the table.
Along with constraints, triggers can help enforce data integrity rules with actions such as cascading deletes or updates. Triggers can also perform a variety of functions such as issuing alerts, updating other tables, sending e-mail, and other useful actions.
You can define any number of triggers for a single table, including multiple triggers on the same table for the same event.
You can create a trigger in any schema where you are the schema owner. To create a trigger on a table that you do not own, you must be granted the TRIGGER privilege on that table. The database owner can also create triggers on any table in any schema.
A trigger operates with the privileges of the owner of the trigger. See "Configuring fine-grained user authorization" and "Privileges on views, triggers, constraints, and generated columns" in the Derby Security Guide for details.
The trigger does not need to reside in the same schema as the table on which the trigger is defined.
If a qualified trigger name is specified, the schema name cannot begin with SYS.
CREATE TRIGGER triggerName { AFTER | NO CASCADE BEFORE } { INSERT | DELETE | UPDATE [ OF columnName [ , columnName ]* ] } ON tableName [ referencingClause ] [ FOR EACH { ROW | STATEMENT } ] [ MODE DB2SQL ] [ WHEN ( booleanExpression ) ] triggeredSQLStatement
You can define any number of triggers for a given event on a given table. For update, you can specify columns.
Many triggeredSQLStatements need to refer to data that is currently being changed by the database event that caused them to fire. The triggeredSQLStatement might need to refer to the new (post-change or "after") values.
Derby provides you with a number of ways to refer to data that is currently being changed by the database event that caused the trigger to fire. Changed data can be referred to in the triggeredSQLStatement using transition variables or transition tables. The REFERENCING clause allows you to provide a correlation name or alias for these transition variables by specifying OLD/NEW AS correlationName .
REFERENCING OLD AS DELETEDROW
DELETE FROM HotelAvailability WHERE hotel_id = DELETEDROW.hotel_id
For statement triggers, transition tables serve as a table identifier for the triggeredSQLStatement or the trigger qualification. The REFERENCING clause allows you to provide a correlation name or alias for these transition tables by specifying OLD_TABLE/NEW_TABLE AS correlationName
REFERENCING OLD_TABLE AS DeletedHotels
DELETE FROM HotelAvailability WHERE hotel_id IN (SELECT hotel_id FROM DeletedHotels)
The REFERENCING clause can designate only one new correlation or identifier and only one old correlation or identifier. Row triggers cannot designate an identifier for a transition table and statement triggers cannot designate a correlation for transition variables.
The transition tables or transition variables defined in the REFERENCING clause can be referenced from the WHEN clause.
A statement trigger fires once per triggering event and regardless of whether any rows are modified by the insert, update, or delete event.
A row trigger fires once for each row affected by the triggering event. If no rows are affected, the trigger does not fire.
For more information on triggeredSQLStatements, see "Programming trigger actions" in the Derby Developer's Guide.
When multiple triggers are defined for the same database event for the same table for the same trigger time (before or after), triggers are fired in the order in which they were created.
-- Statements and triggers:
CREATE TRIGGER t1 NO CASCADE BEFORE UPDATE ON x
FOR EACH ROW MODE DB2SQL
values app.notifyEmail('Jerry', 'Table x is about to be updated');
CREATE TRIGGER FLIGHTSDELETE
AFTER DELETE ON FLIGHTS
REFERENCING OLD_TABLE AS DELETEDFLIGHTS
FOR EACH STATEMENT
DELETE FROM FLIGHTAVAILABILITY WHERE FLIGHT_ID IN
(SELECT FLIGHT_ID FROM DELETEDFLIGHTS);
CREATE TRIGGER FLIGHTSDELETE3
AFTER DELETE ON FLIGHTS
REFERENCING OLD AS OLD
FOR EACH ROW
DELETE FROM FLIGHTAVAILABILITY WHERE FLIGHT_ID = OLD.FLIGHT_ID;
The maximum trigger recursion depth is 16.