Creates a trigger, which is a type of stored procedure that is often used for enforcing integrity constraints. A trigger executes automatically when a user attempts a specified data modification statement on a specified table.
create trigger [owner.]trigger_name on [owner.]table_name {for {insert , update} | instead of {insert, update, delete}} [as [if update (column_name) [{and | or} update (column_name)]...] SQL_statements [if update (column_name) [{and | or} update (column_name)]... SQL_statements]...]
is the name of the trigger, which must conform to the rules for identifiers and be unique in the database. Specify the owner’s name to create another trigger of the same name owned by a different user in the current database. The default value for owner is the current user. If you use an owner name to qualify a trigger, you must explicitly qualify the table name the same way.
You cannot use a variable for a trigger name.
is the name of the table on which to create the trigger. If more than one table of the same name exists in the database, specify the owner’s name. The default value for owner is the current user.
for – used before insert, delete, or update to indicate what you are creating the trigger for.
instead of – creates and fills the inserted and deleted pseudo tables, which are used in the trigger to examine the rows that would have been modified by the original insert, delete, or update query.
can be included in any combination. delete cannot be used with the if update clause.
specifies trigger conditions and trigger actions. Trigger conditions determine whether the attempted insert, update, or delete causes the trigger actions to be carried out. The SQL statements often include a subquery preceded by the keyword if. In Example 2, below, the subquery that follows the keyword if is the trigger condition.
Trigger actions take effect when the user action (insert, update, or delete) is attempted. If multiple trigger actions are specified, they are grouped with begin and end.
See “Triggers and transactions” for a list of statements that are not allowed in a trigger definition. See “The deleted and inserted logical tables” for information about the deleted and inserted logical tables that can be included in trigger definitions.
tests whether the specified column is included in the set list of an update statement or is affected by an insert. if update allows specified trigger actions to be associated with updates to specified columns (see Example 3). More than one column can be specified, and you can use more than one if update statement in a create trigger statement (see Example 5).
Prints a message when anyone tries to add data or change data in the titles table:
create trigger reminder on titles for insert, update as print "Don't forget to print a report for accounting."
Prevents insertion of a new row into titleauthor if there is no corresponding title_id in the titles table:
create trigger t1 on titleauthor for insert as if (select count (*) from titles, inserted where titles.title_id = inserted.title_id) = 0 begin print "Please put the book's title_id in the titles table first." rollback transaction end
If the pub_id column of the publishers table is changed, make the corresponding change in the titles table:
create trigger t2 on publishers for update as if update (pub_id) and @@rowcount = 1 begin update titles set titles.pub_id = inserted.pub_id from titles, deleted, inserted where deleted.pub_id = titles.pub_id end
Deletes title from the titles table if any row is deleted from titleauthor. If the book was written by more than one author, other references to it in titleauthor are also deleted:
create trigger t3 on titleauthor for delete as begin delete titles from titles, deleted where deleted.title_id = titles.title_id delete titleauthor from titleauthor, deleted where deleted.title_id = titleauthor.title_id print "All references to this title have been deleted from titles and titleauthor." end
Prevents updates to the primary key on weekends. Prevents updates to the price or advance of a title unless the total revenue amount for that title surpasses its advance amount:
create trigger stopupdatetrig on titles for update as if update (title_id) and datename (dw, getdate ()) in ("Saturday", "Sunday") begin rollback transaction print "We don't allow changes to" print "primary keys on the weekend!" end if update (price) or update (advance) if (select count (*) from inserted where (inserted.price * inserted.total_sales) < inserted.advance) > 0 begin rollback transaction print "We don't allow changes to price or" print "advance for a title until its total" print "revenue exceeds its latest advance." end
Uses instead of triggers to update union views:
create table EmployeeWest ( empid int primary key, empname varchar(30), empdob datetime, region char(5) constraint region_chk check (region='West')) create table EmployeeEast ( empid int primary key, empname varchar(30), empdob datetime, region char(5) constraint region_chk check (region='East’)) create view Employees as select * from EmployeeEast union all select * from EmployeeWest create trigger EmployeesInsertTrig on Employees instead of insert as begin insert into EmployeeEast select * from inserted where region = "East" insert into EmployeeWest select * from inserted where region = "West" end --will insert the data into the EmployeeEast table insert into Employees values (10, 'Jane Doe', '11/11/1967', 'East') --will insert the data into the EmployeeWest table insert into Employees values (11, 'John Smith', '01/12/1977', 'West') --will insert multiple rows into EmployeeEast and --EmployeeWest tables. Employee2 table includes employees --from both East and West. insert into Employees select * from Employee2
Uses instead of triggers to implement encrypted column support, storing data in the database in encrypted form without changing applications (the user-defined functions, my_encrypt and my_decrypt, perform the encryption and decryption operations on the data):
CREATE TABLE Employee_t (id int PRIMARY KEY, name varchar(20), salary binary (64)) --where the id and name columns are stored unencrypted, salary is --encrypted and id is a primary key. create view employee_v as select id, name, my_decrypt (salary) from employee_t CREATE TRIGGER EmployeeInsert ON employee_v INSTEAD OF INSERT AS BEGIN INSERT employee_t SELECT id, name, my_encrypt (salary) FROM inserted END CREATE TRIGGER employeeUpdate ON employee_v INSTEAD OF UPDATE AS BEGIN DELETE FROM employee_t WHERE id IN (SELECT id FROM deleted) INSERT employee_t SELECT id, name, my_encrypt (salary) FROM inserted END CREATE TRIGGER employeeDelete ON employee_v INSTEAD OF DELETE AS BEGIN DELETE FROM employee_t WHERE id IN (SELECT id FROM deleted) END
To avoid seeing unexpected results due to changes in settings, run set rowcount 0 as your initial statement before executing create trigger. The scope of set is limited to only the create trigger command, and resets to your previous setting once the procedure exits.
A trigger fires only once per data modification statement. A complex query containing a while loop may repeat an update or insert many times, and the trigger is fired each time.
Triggers are commonly used to enforce referential integrity (integrity rules about relationships between the primary and foreign keys of tables or views), to supply cascading deletes, and to supply cascading updates (see Examples 2, 3, and 4, respectively).
A trigger fires only after the data modification statement has completed and Adaptive Server has checked for any datatype, rule, or integrity constraint violations. The trigger and the statement that fires it are treated as a single transaction that can be rolled back from within the trigger. If a severe error is detected, the entire transaction is rolled back.
You can also enforce referential integrity using constraints defined with the create table statement as an alternative to using create trigger. See create table and alter table for information about integrity constraints.
deleted and inserted are logical (conceptual) tables. They are structurally identical to the table for which the trigger is defined—that is, the table on which the user action is attempted—and hold the old values or new values of the rows that would be changed by the user action.
Both inserted and deleted tables appear as views on the transaction log, but they are fake tables on syslogs.
deleted and inserted tables can be examined by the trigger to determine whether or how the trigger action should be carried out, but the tables themselves cannot be altered by the trigger’s actions.
deleted tables are used with delete and update; inserted tables, with insert and update. An update is a delete followed by an insert: it affects the deleted table first, and then the inserted table.
You can create a trigger only in the current database. If you use an owner name to qualify a trigger, you must explicitly qualify the table name the same way. A trigger can reference objects outside the current database.
A trigger cannot apply to more than one table. However, the same trigger action can be defined for more than one user action (for example, insert and update) in the same create trigger statement. A table can have a maximum of three triggers—one each for insert, update, and delete.
Each new trigger in a table or column for the same operation (insert, update, or delete) overwrites the previous one. No warning message appears before the previous trigger is overwritten.
You cannot create a trigger on a session-specific temporary table.
You cannot create a trigger on a view.
You cannot create a trigger on a system table.
You cannot use triggers that select from a text, unitext, or image column of the inserted or deleted table.
Sybase recommends that triggers not include select statements that return results to the user, since special handling that allows modifications to the trigger table must be written into every application program for the returned results.
If a trigger references table names, column names, or view names that are not valid identifiers, you must set quoted_identifier on before the create trigger command, and enclose each such name in double quotes. The quoted_identifier option does not need to be on when the trigger fires.
In performance terms, trigger overhead is usually very low. The time involved in running a trigger is spent mostly in referencing other tables, which are either in memory or on the database device.
The deleted and inserted tables often referenced by triggers are always in memory rather than on the database device, because they are logical tables. The location of other tables referenced by the trigger determines the amount of time the operation takes.
You can use the set command inside a trigger. The set option you invoke remains in effect during the execution of the trigger, then reverts to its former setting. In particular, you can use the self_recursion option inside a trigger so that data modifications by the trigger itself can cause the trigger to fire again.
You must drop and re-create the trigger if you rename any of the objects referenced by the trigger. You can rename a trigger with sp_rename.
When you drop a table, any triggers associated with it are also dropped.
A truncate table command is not caught by a delete trigger. Although a truncate table statement is, in effect, like a delete without a where clause (it removes all rows), changes to the data rows are not logged, and so cannot fire a trigger.
Since permission for the truncate table command defaults to the table owner and is not transferable, only the table owner need worry about inadvertently circumventing a delete trigger with a truncate table statement.
The writetext command, whether logged or unlogged, does not cause a trigger to fire.
When a trigger is defined, the action it specifies on the table to which it applies is always implicitly part of a transaction, along with the trigger itself. Triggers are often used to roll back an entire transaction if an error is detected, or they can be used roll back the effects of a specific data modification:
When the trigger contains the rollback transaction command, the rollback aborts the entire batch, and any subsequent statements in the batch are not executed.
When the trigger contains the rollback trigger, the rollback affects only the data modification that caused the trigger to fire. The rollback trigger command can include a raiserror statement. Subsequent statements in the batch are executed.
Since triggers execute as part of a transaction, the following statements and system procedures are not allowed in a trigger:
All create commands, including create database, create default, create index, create procedure, create rule, create table, create trigger, and create view
All drop commands
sp_configure
disk init, disk refit, disk reinit, disk remirror, disk remirror, disk unmirror
select into
If a desired result (such as a summary value) depends on the number of rows affected by a data modification, use @@rowcount to test for multirow data modifications (an insert, delete, or update based on a select statement), and take appropriate actions. Any Transact-SQL statement that does not return rows (such as an if statement) sets @@rowcount to 0, so the test of @@rowcount should occur at the beginning of the trigger.
When an insert or update command executes, Adaptive Server adds rows to both the trigger table and the inserted table at the same time. The rows in the inserted table are always duplicates of one or more rows in the trigger table.
An update or insert trigger can use the if update command to determine whether the update or insert changed a particular column. if update (column_name) is true for an insert statement whenever the column is assigned a value in the select list or in the values clause. An explicit NULL or a default assigns a value to a column and thus activates the trigger. An implicit NULL, however, does not.
For example, if you create the following table and trigger:
create table junk (aaa int null, bbb int not null)
create trigger trigtest on junk for insert as if update (aaa) print "aaa updated" if update (bbb) print "bbb updated"
Inserting values into either column or into both columns fires the trigger for both column aaa and column bbb:
insert junk (aaa, bbb) values (1, 2)
aaa updated bbb updated
Inserting an explicit NULL into column aaa also fires the trigger:
insert junk values (NULL, 2)
aaa updated bbb updated
If there was a default for column aaa, the trigger would also fire.
However, with no default for column aaa and no value explicitly inserted, Adaptive Server generates an implicit NULL and the trigger does not fire:
insert junk (bbb) values (2)
bbb updated
if update is never true for a delete statement.
By default, Adaptive Server allows nested triggers. To prevent triggers from nesting, use sp_configure to set the allow nested triggers option to 0 (off):
sp_configure "allow nested triggers", 0
Triggers can be nested to a depth of 16 levels. If a trigger changes a table on which there is another trigger, the second trigger fires and can then call a third trigger, and so forth. If any trigger in the chain sets off an infinite loop, the nesting level is exceeded and the trigger aborts, rolling back the transaction that contains the trigger query.
Since triggers are put into a transaction, a failure at any level of a set of nested triggers cancels the entire transaction: all data modifications are rolled back. Supply your triggers with messages and other error handling and debugging aids to determine where the failure occurred.
The global variable @@nestlevel contains the nesting level of the current execution. Each time a stored procedure or trigger calls another stored procedure or trigger, the nesting level is incremented. The nesting level is also incremented by one when a cached statement is created. If the maximum of 16 is exceeded, the transaction aborts.
If a trigger calls a stored procedure that performs actions that would cause the trigger to fire again, the trigger is reactivated only if nested triggers are enabled. Unless there are conditions within the trigger that limit the number of recursions, this causes a nesting-level overflow.
For example, if an update trigger calls a stored procedure that performs an update, the trigger and stored procedure execute once if allow nested triggers is off. If allow nested triggers is on, and the number of updates is not limited by a condition in the trigger or procedure, the procedure or trigger loop continues until it exceeds the 16-level maximum nesting value.
By default, a trigger does not call itself in response to a second data modification to the same table within the trigger, regardless of the setting of the allow nested triggers configuration parameter. A set option, self_recursion, enables a trigger to fire again as a result of a data modification within the trigger. For example, if an update trigger on one column of a table results in an update to another column, the update trigger fires only once when self_recursion is disabled, but it can fire up to 16 times if self_recursion is set on. The allow nested triggers configuration parameter must also be enabled in order for self-recursion to take place.
You can interleave nesting instead of and for triggers. For example, an update statement on a view with an instead of update trigger causes the trigger to execute. If the trigger contains a SQL statement updating a table with a for trigger defined on it, that trigger fires. The for trigger may contain a SQL statement that updates another view with an instead of trigger that then executes, and so forth.
instead of and for triggers have different recursive behaviors. for triggers support recursion, while instead of triggers do not. If an instead of trigger references the same view on which the trigger was fired, the trigger is not called recursively. Rather, the triggering statement applies directly to the view; in other words, the statement is resolved as modifications against the base tables underlying the view. In this case, the view definition must meet all restrictions for an updatable view. If the view is not updatable, an error is raised.
For example, if a trigger is defined as an instead of update trigger for a view, the update statement executed against the same view within the instead of trigger does not cause the trigger to execute again. The update exercised by the trigger is processed against the view, as though the view did not have an instead of trigger. The columns changed by the update must be resolved to a single base table.
Restrictions for instead of:
If a trigger references table names, column names, or view names that are not valid identifiers, you must set quoted_identifier on before the create trigger command, and enclose each such name in double quotation marks. The quoted_identifier option does not need to be on when the trigger fires; bracketed identifiers also work.
Using the set cursor rows command with client cursors, cursors declared through Open Client calls, or Embedded SQL™, may prevent positioned delete and update from firing an instead of trigger. A positioned update statement is a SQL update statement that contains the where current of <cursorname> clause to update only the row upon which the cursor, <cursorname>, is currently positioned.
Joins are not allowed in searched delete and update statements that would fire an instead of trigger.
positioned delete and update on cursors defined with joins does not fire an instead of trigger.
A positioned delete (or positioned update) is a SQL delete (or update) statement containing a where current of <cursorname> clause to delete (or update) only the row upon which the cursor, <cursorname>, is currently positioned.
For positioned delete and update statements that fire an instead of trigger, the instead of trigger must exist when the cursor is declared.
The execution plan for a trigger is stored in sysprocedures.
Each trigger is assigned an identification number, which is stored as a new row in sysobjects with the object ID for the table to which it applies in the deltrig column, and also as an entry in the deltrig, instrig, and updtrig columns of the sysobjects row for the table to which it applies.
To display the text of a trigger, which is stored in syscomments, use sp_helptext.
If the system security officer has reset the allow select on syscomments.text column parameter with sp_configure (as required to run Adaptive Server in the evaluated configuration), you must be the creator of the trigger or a system administrator to view the text of the trigger through sp_helptext.
For a report on a trigger, use sp_help.
For a report on the tables and views that are referenced by a trigger, use sp_depends.
ANSI SQL – Compliance level: Transact-SQL extension.
Permissions on objects at trigger creation – When you create a trigger, Adaptive Server makes no permission checks on objects such as tables or views that the trigger references. Therefore, you can successfully create a trigger, even though you do not have access to its objects. All permission checks occur when the trigger fires.
Permissions on objects at trigger execution – When the trigger executes, permission checks on its objects depend on whether the trigger and its objects are owned by the same user.
If the trigger and its objects are not owned by the same user, the user who caused the trigger to fire must have been granted direct access to the objects. For example, if the trigger performs a select from a table the user cannot access, the trigger execution fails. In addition, the data modification that caused the trigger to fire is rolled back.
If a trigger and its objects are owned by the same user, special rules apply. The user automatically has implicit permission to access the trigger’s objects, even though the user cannot access them directly. See the detailed description of the rules for implicit permissions in the System Administration Guide.
Permissions for instead of and for triggers instead of – instead of triggers have the same permission requirements as for triggers: to create a view with instead of triggers, permission for insert/update/delete for the view, not the underlying tables, must be granted to the user.
The following describes permission checks for create trigger that differ based on your granular permissions settings.
Granular permissions enabled |
With granular permissions enabled, you must be the table owner and the create trigger privilege must not have been revoked. You must have create any trigger privilege to run create trigger on another user's table. |
Granular permissions disabled |
With granular permissions disabled: Only a system security officer can grant or revoke permissions to create triggers. The database owner has implicit permission to create a trigger on any user table. Users can create triggers only on tables that they own. The system security officer may revoke user permission to create triggers. Revoking permission to create triggers affects only the database in which the systems security officer issues the revoke command. Permission to run the create trigger command is restored to the users whose permission was revoked when the system security officer explicitly grants them create trigger permission. |
Values in event and extrainfo columns of sysaudits are:
Event |
Audit option |
Command or access audited |
Information in extrainfo |
---|---|---|---|
12 |
create |
create trigger |
|
Commands alter table, create procedure, drop trigger, rollback trigger, set
System procedures sp_commonkey, sp_configure, sp_depends, sp_foreignkey, sp_help, sp_helptext, sp_primarykey, sp_rename, sp_spaceused