Creates a trigger on a table. This statement applies to SAP Sybase IQ catalog store tables only.
CREATE [ OR REPLACE ] TRIGGER trigger-name trigger-type { trigger-event-list | UPDATE OF column-list } [ ORDER integer ] ON table-name [ REFERENCING [ OLD AS old-name ] [ NEW AS new-name ] [ REMOTE AS remote-name ] ] [ FOR EACH { ROW | STATEMENT } ] [ WHEN ( search-condition ) ] trigger-body
column-list : column-name[, ...]
trigger-type : BEFORE | AFTER | INSTEAD OF | RESOLVE
trigger-event-list : trigger-event[, ... ]
trigger-event : DELETE | INSERT | UPDATE ( column-name ) | UPDATING [ ( column-name-string ) ]
trigger-body : a BEGIN statement.
If you specify an UPDATE clause, you must also supply a REFERENCING clause to avoid syntax errors.
You can write separate triggers for each event that you need to handle or, if you have some shared actions and some actions that depend on the event, you can create a trigger for all events and use an IF statement to distinguish the action taking place.
If you specify an UPDATING clause, then you must also supply a REFERENCING clause to avoid syntax errors.
BEFORE UPDATE triggers fire any time an UPDATE occurs on a row, whether the new value differs from the old value. That is, if a column-list is specified for a BEFORE UPDATE trigger, then the trigger fires if any of the columns in column-list appear in the SET clause of the UPDATE statement. If a column-list is specified for an AFTER UPDATE trigger, then the trigger is fired only if the value of any of the columns in column-list is changed by the UPDATE statement.
INSTEAD OF triggers are the only form of trigger that you can define on a regular view. INSTEAD OF triggers replace the triggering action with another action. When an INSTEAD OF trigger fires, the triggering action is skipped and the specified action is performed. INSTEAD OF triggers can be defined as a row-level or a statement-level trigger. A statement-level INSTEAD OF trigger replaces the entire statement, including all row-level operations. If a statement-level INSTEAD OF trigger fires, then no row-level triggers fire as a result of that statement. However, the body of the statement-level trigger could perform other operations that, in turn, cause other row-level triggers to fire.
If you are defining an INSTEAD OF trigger, then you cannot use the UPDATE OF column-list clause, the ORDER clause, or the WHEN clause.
If you omit the ORDER clause, or specify 0, then the database server assigns the order of 1. However, if another same-type trigger is already set to 1, then an error is returned.
When adding additional triggers, you may need to modify the existing same-type triggers for the event, depending on whether the actions of the triggers interact. If they do not interact, then the new trigger must have an ORDER value higher than the existing triggers. If they do interact, you need to consider what the other triggers do, and you may need to change the order in which they fire.
The ORDER clause is not supported for INSTEAD OF triggers since there can only be one INSTEAD OF trigger of each type (insert, update, or delete) defined on a table or view.
An INSERT takes the REFERENCING NEW clause, which represents the inserted row. There is no REFERENCING OLD clause.
A DELETE takes the REFERENCING OLD clause, which represents the deleted row. There is no REFERENCING NEW clause.
An UPDATE takes the REFERENCING OLD clause, which represents the row before the update, and it takes the REFERENCING NEW clause, which represents the row after the update.
The meanings of REFERENCING OLD and REFERENCING NEW differ, depending on whether the trigger is a row-level or a statement-level trigger. For row-level triggers, the REFERENCING OLD clause allows you to refer to the values in a row before an update or delete, and the REFERENCING NEW clause allows you to refer to the inserted or updated values. The OLD and NEW rows can be referenced in BEFORE and AFTER triggers. The REFERENCING NEW clause allows you to modify the new row in a BEFORE trigger before the insert or update operation takes place.
For statement-level triggers, the REFERENCING OLD and REFERENCING NEW clauses refer to declared temporary tables holding the old and new values of the rows.
You can include trigger operation conditions in the BEGIN statement. Trigger operation conditions perform actions depending on the trigger event that caused the trigger to fire. For example, if the trigger is defined to fire for both updates and deletes, you can specify different actions for the two conditions.
The CREATE TRIGGER statement creates a trigger associated with a table in the database, and stores the trigger in the database.
You cannot define a trigger on a materialized view. If you do, a SQLE_INVALID_TRIGGER_MATVIEW error is returned.
A trigger is declared as either a row-level trigger, in which case it executes before or after each row is modified, or a statement-level trigger, in which case it executes after the entire triggering statement is completed.
CREATE TRIGGER puts a table lock on the table and requires exclusive use of the table.
You must have the CREATE ANY TRIGGER or CREATE ANY OBJECT system privilege. Additionally, you must be the owner of the table the trigger is built on or have one of the following privileges:
To create a trigger on a view owned by someone else, you must have either the CREATE ANY TRIGGER or CREATE ANY OBJECT system privilege, and you must have either the ALTER ANY VIEW or ALTER ANY OBJECT system privilege.
Automatic commit.
Some features of SAP Sybase IQ triggers are vendor extensions. These include:
The optional OR REPLACE syntax. If an existing trigger is replaced, authorization of the creation of the new trigger instance is bypassed.
The ORDER clause. In SQL/2008, triggers are fired in the order they were created.
RESOLVE triggers are a vendor extension.
This example creates a statement-level trigger. First, create a table as shown in this CREATE TABLE statement (requires the CREATE TABLE system privilege):
CREATE TABLE t0 ( id INTEGER NOT NULL, times TIMESTAMP NULL DEFAULT CURRENT TIMESTAMP, remarks TEXT NULL, PRIMARY KEY ( id ) );
Next, create a statement-level trigger for this table:
CREATE TRIGGER myTrig AFTER INSERT ORDER 4 ON t0 REFERENCING NEW AS new_name FOR EACH STATEMENT BEGIN DECLARE @id1 INTEGER; DECLARE @times1 TIMESTAMP; DECLARE @remarks1 LONG VARCHAR; DECLARE @err_notfound EXCEPTION FOR SQLSTATE VALUE '02000'; //declare a cursor for table new_name DECLARE new1 CURSOR FOR SELECT id, times, remarks FROM new_name; OPEN new1; //Open the cursor, and get the value LoopGetRow: LOOP FETCH NEXT new1 INTO @id1, @times1,@remarks1; IF SQLSTATE = @err_notfound THEN LEAVE LoopGetRow END IF; //print the value or for other use PRINT (@remarks1); END LOOP LoopGetRow; CLOSE new1 END;
The following example replaces the myTrig trigger created in the previous example.
CREATE OR REPLACE TRIGGER myTrig AFTER INSERT ORDER 4 ON t0 REFERENCING NEW AS new_name FOR EACH STATEMENT BEGIN FOR L1 AS new1 CURSOR FOR SELECT id, times, remarks FROM new_name DO //print the value or for other use PRINT (@remarks1); END FOR; END;
The next example shows how you can use REFERENCING NEW in a BEFORE UPDATE trigger. This example ensures that postal codes in the new Employees table are in uppercase. You must have SELECT, ALTER, and UPDATE privileges on GROUPO.Employees to execute this statement:
CREATE TRIGGER emp_upper_postal_code BEFORE UPDATE OF PostalCode ON GROUPO.Employees REFERENCING NEW AS new_emp FOR EACH ROW WHEN ( ISNUMERIC( new_emp.PostalCode ) = 0 ) BEGIN -- Ensure postal code is uppercase (employee might be -- in Canada where postal codes contain letters) SET new_emp.PostalCode = UPPER(new_emp.PostalCode) END; UPDATE GROUPO.Employees SET state='ON', PostalCode='n2x 4y7' WHERE EmployeeID=191; SELECT PostalCode FROM GROUPO.Employees WHERE EmployeeID = 191;
The next example shows how you can use REFERENCING OLD in a BEFORE DELETE trigger. This example prevents deleting an employee from the Employees table who has not been terminated.
CREATE TRIGGER TR_check_delete_employee BEFORE DELETE ON Employees REFERENCING OLD AS current_employee FOR EACH ROW WHEN ( current_employee.Terminate IS NULL ) BEGIN RAISERROR 30001 'You cannot delete an employee who has not been fired'; END;
The next example shows how you can use REFERENCING NEW and REFERENCING OLD in a BEFORE UPDATE trigger. This example prevents a decrease in an employee's salary.
CREATE TRIGGER TR_check_salary_decrease BEFORE UPDATE ON GROUPO.Employees REFERENCING OLD AS before_update NEW AS after_update FOR EACH ROW BEGIN IF after_update.salary < before_update.salary THEN RAISERROR 30002 'You cannot decrease a salary'; END IF; END;
The next example shows how you can use REFERENCING NEW in a BEFORE INSERT and UPDATE trigger. The following example creates a trigger that fires before a row in the SalesOrderItems table is inserted or updated.
CREATE TRIGGER TR_update_date BEFORE INSERT, UPDATE ON GROUPO.SalesOrderItems REFERENCING NEW AS new_row FOR EACH ROW BEGIN SET new_row.ShipDate = CURRENT TIMESTAMP; END;
The following trigger displays a message on the Messages tab of the Interactive SQL Results pane showing which action caused the trigger to fire.
CREATE TRIGGER tr BEFORE INSERT, UPDATE, DELETE ON sample_table REFERENCING OLD AS t1old FOR EACH ROW BEGIN DECLARE msg varchar(255); SET msg = 'This trigger was fired by an '; IF INSERTING THEN SET msg = msg || 'insert' ELSEIF DELETING THEN set msg = msg || 'delete' ELSEIF UPDATING THEN set msg = msg || 'update' END IF; MESSAGE msg TO CLIENT END;