Triggers Fundamentals

Introduction to Triggers

When an action has been performed on a table, such as adding a new record, changing (editing/updating) an existing record, or deleting a (or some) record(s), the table produces a notification. We say that the table fires an event. You can use that occurring event to take some action.

A trigger is an action that is performed behind-the-scenes when an event occurs on a table or a view.

Practical LearningPractical Learning: Introducing Triggers

  1. Open the KoloBank1 file
  2. Select the whole document (click inside the document and press Ctrl + A) and copy it (press Ctrl + C)
  3. Start Microsoft SQL Server and connect
  4. On the Standard toolbar, click the New Query button New Query
  5. Paste the content of the clipboard (right-(click inside the document and click Paste)
  6. To execute, on the main menu, click Query -> Execute
  7. Click inside the Query Editor, press Ctrl + A, and press Delete

Creating a Trigger

You create a trigger using SQL code. Later on, we will start analyzing the code necessary to do this. To assist you with skeleton code, open a Query Editor. Then, in the Template Explorer, expand the Triggers node. Drag Create T-SQL Trigger (New Menu) and drop it in the window:

-- ================================================
-- Template generated from Template Explorer using:
-- Create Trigger (New Menu).SQL
--
-- Use the Specify Values for Template Parameters 
-- command (Ctrl-Shift-M) to fill in the parameter 
-- values below.
--
-- See additional Create Trigger templates for more
-- examples of different Trigger statements.
--
-- This block of comments will not be included in
-- the definition of the function.
-- ================================================
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author:		<Author,,Name>
-- Create date: <Create Date,,>
-- Description:	<Description,,>
-- =============================================
CREATE TRIGGER <Schema_Name, 
		sysname, 
		Schema_Name>.<Trigger_Name, 
			      sysname, 
			      Trigger_Name> 
   ON  <Schema_Name, sysname, Schema_Name>.<Table_Name, sysname, Table_Name> 
   AFTER <Data_Modification_Statements, , INSERT,DELETE,UPDATE>
AS 
BEGIN
	-- SET NOCOUNT ON added to prevent extra result sets from
	-- interfering with SELECT statements.
	SET NOCOUNT ON;

    -- Insert statements for trigger here

END
GO

Executing a Trigger

Unlike a stored procedure, you never have to execute a trigger. The operating system (through the object(s) event(s)) and the database engine take care of this. A trigger acts behind the scenes when the object to which it is associated fires the appropriate event. In fact, the event fires whether the object received a change or not (whether a record was created, edited, deleted, or not).

Microsoft SQL Server supports three types of triggers: DML, DDL, and logon.

DML Triggers

 

Introduction

A DML trigger is a procedure that acts as a result of a data manipulation language (DML) event occurring on a table. This means that the trigger must be created in connection to a table of a non-system database.

AFTER/FOR INSERT Triggers

An insert trigger is a DML trigger that acts when a new record is added to its intended table. Such a trigger uses the INSERT keywork. The primary formula to create an INSERT DML trigger on a table is:

CREATE TRIGGER Schema_Name.TriggerName
ON TableName
AFTER/FOR INSERT
AS
    TriggerCode

The statement starts with CREATE TRIGGER. If you want to specify a schema, type it, followed by a a period and the name of the trigger. The name follows the rules we have applied so far to database objects.

After specifying the name of the trigger, write ON followed by the name of the table on which the trigger will apply. Of course, the table must exist in the database. If the table belongs to a schema other than dbo, the trigger must use the same schema. Put it another way, if you precede the name of the a trigger withe a schema, the table must belong to the same schema and you must precede the name of the table with the same schema. Of course, you must have previously created the schema and the table must have been assigned to that schema.

In our formula, we assume that the trigger will apply when a record has been added to the table. Therefore, you use either the AFTER INSERT or the FOR INSERT expression.

Triggers

To start the SQL code that constitutes the trigger, write AS, and then write your code.

After creating an INSERT trigger, at the right time (when its intended event fires), it will execute. When this happens, the database engine automatically and internally creates a temporary table named inserted. This table holds a copy of the records that were created. You can access those records if you want.

Practical LearningPractical Learning: Creating a DML Trigger

  1. To create a new trigger, type the following:
    USE KoloBank1;
    GO
    
    -- ========================================================
    -- DML Triggers:
    -- Description:	These triggers update the Management.DatabaseOperations
    --		by letting it know that a new operation has
    --		taken place on a table of the database table. The trigger
    --		also specifies the name of the employee
    --		who performed the operation and the time
    --		this occurred
    -- ========================================================
    CREATE TRIGGER Accounts.ForCustomers
    ON Accounts.Customers
    AFTER INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Customers', SUSER_SNAME(), 
    	       N'Processed a deposit', GETDATE())
    END
    GO
    -- ========================================================
    CREATE TRIGGER Transactions.ForDeposits
    ON Transactions.Deposits
    AFTER INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Deposits', SUSER_SNAME(), 
    	       N'Processed a deposit', GETDATE())
    END
    GO
    -- ========================================================
    CREATE TRIGGER Transactions.ForWithdrawals
    ON Transactions.Withdrawals
    AFTER INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Withdrawals', SUSER_SNAME(), 
    	   N'Processed a withdrawal', GETDATE())
    END
    GO
    -- ========================================================
    CREATE TRIGGER Transactions.ForChecksCashed
    ON Transactions.CheckCashing
    AFTER INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'CheckCashing', SUSER_SNAME(), 
    	   N'Cashed a check', GETDATE())
    END
    GO
  2. Press F5 to execute
  3. In the Object Explorer, right-click Databases and click Refresh
  4. Expand Databases and expand KoloBank1
  5. Expand its Tables node
  6. Right-click Accounts.Customers and click Edit Top 200 Rows
  7. Create a record using the following values:
     
    AccountNumber: 20-304042-49
    DateCreated: 01/04/2013
    EmployeeNumber: 715-204
    AccountType: Checking
    FirstName: Ophellie
    LastName: Wyman
    Address: 104 G St. S. E.
    City: Washington
    State: DC
    ZIPCode: 20005
    PhoneNumber: (202) 622-8674
    Account Status: Active
  8. Create another record as follows:
     
    AccountNumber: 68-304605-84
    DateCreated: 01/04/2013
    EmployeeNumber: 294-075
    AccountType: Checking
    FirstName: Jonathan
    MiddleName: Horace
    LastName: Myler
    Address: 9337 Cachet St
    City: Arlington
    State: VA
    ZIPCode: 20140
    PhoneNumber: (703) 554-8724
    AccountStatus: Active
  9. Create one more record as follows:
     
    AccountNumber: 38-402217-59
    EmployeeNumber: 461-842
    DateCreated: 01/12/2013
    AccountTypeID: Checking
    FirstName: James
    MiddleName: Scott
    LastName: Schneider
    Address: 1277 Cecil Maurice Ave
    City: Chevy Chase
    State: MD
    ZIPCode: 20815
    PhoneNumber: (301) 768-4024
    WorkPhone: (301) 570-5227
    AccountStatus: Active
  10. Close the table
  11. In the Object Explorer, under the Tables node of KoloBank1, right-click Transactions.Deposits and click Edit Top 200 Rows
  12. Enter a record as follows:
     
    LocationCode Employee # Account # DepositDate DepositAmount Notes
    ALXJPZ 294-075 68-304605-84 01/04/2013 325 Deposit for a new bank account
    DCK10S 715-204 20-304042-49 01/04/2013 500 Deposit for a new bank account
  13. Close the table
  14. In the Object Explorer, right-click Transactions.Withdrawals and click Edit Top 200 Rows
  15. Enter a new record as follows:
     
    LocationCode Employee # Account # WithdrawalDate WithdrawalAmount Notes
    CPKUMD 481-114 20-304042-49 01/06/2013 225 Withdrawal from cashier
    0WPLZM 000-100 20-304042-49 01/06/2013 20 Drive-in withdrawal
  16. Close the table
  17. In the Object Explorer, right-click Management.Customers and click Edit Top 200 Rows
  18. Create a new record as follows:
     
    AccountNumber: 94-477085-03
    EmployeeNumber: 533-825
    DateCreated: 01/12/2013
    AccountTypeID: Saving
    FirstName: Ismail
    LastName: Zorbah
    Address: 2888 Gwett Richards Ave
    City: Rockville
    State: MD
    ZIPCode: 20815
    PhoneNumber: (301) 478-8244
    WorkPhone: (301) 726-8224
    AccountStatus: Active
  19. Close the table
  20. In the Transactions.Deposits tab, enter two new records as follows:
     
    LocationCode Employee # Account # DepositDate DepositAmount Notes
    WHTFLT 533-825 38-402217-59 01/12/2013 735.25 Deposit for a new bank account
  21. Close the table
  22. In the Object Explorer, right-click Management.Customers and click Edit Top 200 Rows
  23. Enter a nee record as follows:
     
    AccountNumber: 28-370082-80
    EmployeeNumber: 552-884
    DateCreated: 01/12/2013
    AccountType: Saving
    FirstName: Gloria
    MiddleName: Aldridge
    LastName: Wright
    Address: 1022 Arlington Rd
    City: Arlington
    State: VA
    ZIPCode: 20164
    PhoneNumber: (703) 645-1492
    WorkPhone: (703) 450-5577
    AccountStatus: Active
  24. Close the Customers table
  25. In the Object Explorer, right-click Transactions.Deposits and click Edit Top 200 Rows
  26. Create two new records as follows:
     
    LocationCode Employee # Account # DepositDate DepositAmount Notes
    ALXJPZ 552-884 28-370082-80 01/12/2013 1450.00 Deposit for a new bank account
    WHTFLT 712-083 20-304042-49 01/12/2013 75.95  
  27. Close the Deposits table
  28. In the Object Explorer, right-click Management.Customers and click Edit Top 200 Rows
  29. Create a new record with the following values:
     
    AccountNumber: 27-314257-84
    EmployeeNumber: 952-846
    DateCreated: 1/20/2013
    AccountType: Checking
    FirstName: Robert
    MiddleName: Daniel
    LastName: Luner
    Address: 802 Lilas Ave
    City: Baltimore
    State: MD
    ZIPCode: 21207
    PhoneNumber: (410) 321-6730
    WorkPhone: (410) 5391135
    AccountStatus: Active
  30. Close the Customers table
  31. In the Object Explorer, right-click Transactions.Deposits and click Edit Top 200 Rows
  32. Enter a new record as follows:
     
    LocationCode Employee # Account # DepositDate DepositAmount Notes
    SLVSSL 952-846 27-314257-84 01/12/2013 500 Deposit for a new bank account
  33. Close the Deposits table
  34. In the Object Explorer, right-click Transactions.Withdrawals and click Edit Top 200 Rows
  35. Create two new records as follows:
     
    LocationCode Employee # Account # WithdrawalDate WithdrawalAmount
    CPKUMD 481-114 68-304605-84 01/12/2013 522.75
    0SSMTR 284-725 27-314257-84 01/12/2013 20
  36. Close the Transactions.Withdrawals table
  37. Click inside the Query Editor and press Ctrl + A
  38. Type the following:
    USE KoloBank1;
    GO
    
    SELECT * FROM Management.DatabaseOperations;
    GO
  39. Right-click the Query Editor and click Execute
     
    Trigger

AFTER/FOR UPDATE Triggers

Instead of record insertion time, a DML trigger can act when a record has been updated on a table.

To support this operation, you can use the following formula:

CREATE TRIGGER TriggerName
ON TableName
AFTER/FOR UPDATE
AS
    TriggerCode

The new keyword in this formula is UPDATE. This indicates that the DML trigger will act when the record has been updated. Everything else is as described for the INSERT operator.

Triggers

Remember to use either AFTER UPDATE or FOR UPDATE.

Practical LearningPractical Learning: Updating With a DML Trigger

  1. Click the Query Editor and press Ctrl + A
  2. To create new triggers, type the following:
    USE KoloBank1;
    GO
    
    -- ========================================================
    -- DML Triggers:Records Updates
    -- Description:	These trigger adds a new record to the 
    --		Management.DatabaseOperations when an existing record 
    --		of a table has been updated.
    -- ========================================================
    CREATE TRIGGER Accounts.CustomerUpdated
    ON Accounts.Customers
    AFTER UPDATE
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Customers', SUSER_SNAME(), 
    	   N'Some detail changed about a customer record.',
    	   GETDATE())
    END
    GO
    CREATE TRIGGER Transactions.DepositUpdated
    ON Transactions.Deposits
    AFTER UPDATE
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Deposits', SUSER_SNAME(), 
    	   N'Changed some information about a deposit of a bank account.',
    	   GETDATE())
    END
    GO
    CREATE TRIGGER Transactions.WithdrawalUpdated
    ON Transactions.Withdrawals
    AFTER UPDATE
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Withdrawals', SUSER_SNAME(), 
    	   N'Updated a withdrawal of a bank account.', GETDATE())
    END
    GO
  3. Press F5 to execute
  4. In the Object Explorer, right-click Accounts.Customers and click Edit Top 200 Rows
  5. Locate the customer whose account number is 28-370082-80
  6. Change the ZIP Code to 22202
  7. Close the Customers table
  8. In the Object Explorer, right-click Transactions.Deposits and click Edit Top 200 Rows
  9. Change the first and the third records as follows:
    • In the first record, change the employee number, the deposit amount, and the notes
    • In the third record, change the employee number, the account number, and the notes
     
    LocationCode Employee # Account # DepositDate DepositAmount Notes
    SLVSSL 952-846 68-304605-84 2013-01-04 3250 There was a mistake in the amount deposited. Instead of 325, it was 3250
    WHTFLT 484-050 94-477085-03 2013-01-14 735.25 Oops, the money was deposited in the wrong bank account. It has been corrected with no incident.
  10. Close the Deposits table
  11. In the Object Explorer, right-click Transactions.Withdrawals and click Edit Top 200 Rows
  12. Change the third record as follows (change the employee number and the Notes fields):
     
    LocationCode Employee # Account # WithdrawalDate WithdrawalAmount Notes
    CPKUMD 248-552 68-304605-84 2013-01-12 522.75 The withdrawal was actually processed by 248-552. Everything else is the same.
  13. Close the Withdrawals table
  14. In the SQLQuery1.sql window, click inside the top area and press Ctrl + A
  15. Type the following:
    USE KoloBank1;
    GO
    
    SELECT * FROM Management.DatabaseOperations;
    GO
  16. Right-click the Query Editor and click Execute
    Trigger

AFTER/FOR DELETE Triggers

When a record has been removed from a table, you can apply a DML trigger in response. To make it possible, you can use the following formula:

CREATE TRIGGER TriggerName
ON TableName
AFTER/FOR DELETE
AS
    TriggerCode

This time, the formula uses the DELETE operator as in AFTER DELETE or FOR DELETE. The other things follow the same description we saw for the INSERT operator.

When a DELETE trigger has acted on a table, the database engine creates a special temporary table named deleted. This table holds a copy of the records that were deleted. Eventually, if necessary, you can access this table to find out about those records.

Practical LearningPractical Learning: Deleting With a DML Trigger

  1. Click inside the Query Editor and press Ctrl + A to select everything
  2. To create two new triggers, type the following:
    USE KoloBank1;
    GO
    
    -- ========================================================
    -- Description:	These triggers add a new record to the 
    --		Management.DatabaseOperations when an existing record 
    --		of a table has been deleted.
    -- ========================================================
    CREATE TRIGGER Transactions.DepositDeleted
    ON Transactions.Deposits
    AFTER DELETE
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Deposits', SUSER_SNAME(), 
    	   N'Deleted a deposit from a bank account.', GETDATE())
    END
    GO
    
    CREATE TRIGGER Transactions.WithdrawalDeleted
    ON Transactions.Withdrawals
    AFTER DELETE
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(default, N'Withdrawals', SUSER_SNAME(), 
    	   N'Deleted a withdrawal from a bank account.', GETDATE())
    END
    GO
  3. Press F5 to execute
  4. In the Object Explorer, right-click Transactions.Deposits and click Edit Top 200 Rows
  5. To delete a record, right-click the row header of the 5th record
     
    To delete a record, right-click the row header of the 5th record
  6. Click Delete
     
    To delete a record, right-click the row header of the 5th record
  7. To confirm that you want to delete, click Yes
  8. Close the Deposits table
  9. Click the top section of the SQLQuery1.sql tab and press Ctrl + A
  10. Type the following:
    USE KoloBank1;
    GO
    
    SELECT * FROM Management.DatabaseOperations;
    GO
  11. Right-click the Query Editor and click Execute
     
    Trigger

Trigger Management

Modifying a Trigger

A trigger is a database object. As such, it has a name. It can be modified. It can also be deleted.

If the behavior of a trigger is not appropriate, you can change it. The formula to modify a trigger is:

ALTER TRIGGER schema_name.trigger_name 
ON  schema_name.table_name
AFTER , UPDATE>
AS
    statement

To get skeleton code generated for you, open a Query Editor. In the Templates Explorer, expand the Triggers node, drag the Alter option and drop it in the Query Editor:

--======================================
--  Alter T-SQL Trigger Template
--======================================
USE <database_name, sysname, AdventureWorks>
GO

ALTER TRIGGER <schema_name, sysname, Sales>.<trigger_name, sysname, uStore> 
ON  <schema_name, sysname, Sales>.<table_name, sysname, Store> 
AFTER <data_modification_statements, , UPDATE>
AS <T-SQL_statement,
   ,
   UPDATE Sales.Store 
   SET ModifiedDate = GETDATE()
   FROM inserted WHERE inserted.CustomerID = Sales.Store.CustomerID>
GO

Deleting a Trigger

If you do not need a trigger anymore, you can remove it. The formula to do this is:

DROP TRIGGER TriggerName

After the DROP TRIGGER expression, enter the name (of the trigger).

Executing a Trigger As Somebody

As you may know already, Microsoft SQL Server 2008 (unlike some previous versions) requires that a person logs in order to access a database or one of its objects. In the same way, as we mentioned already, when a user uses an object like a table, a view, etc, the database engine must authenticate who the user is, what permissions that user has and on what objects. Transact-SQL allows you to specify an alternate accont under which a trigger must execute. To provide this information, when creating the trigger, after the ON expression and before specifing the type of trigger, type WITH EXECUTE AS followed by the login name of the alternate account you want to use. The formula to follow:

ALTER TRIGGER schema_name.trigger_name 
ON  schema_name.table_name
WITH EXECUTE AS LoginName
AFTER , UPDATE>
AS
    statement

Here us an example:

CREATE TRIGGER Management.WithCustomers
ON Management.Customers
WITH EXECUTE AS N'Pat Kat'
AFTER INSERT
AS
BEGIN
    INSERT INTO Management.DatabaseOperations
    VALUES(default, N'Customers', SUSER_SNAME(), 
	       N'Processed a deposit', GETDATE());
END
GO

As you can imagine, this solution allows you to let a user with more restrictive permissions to run a trigger on behalf of a user with less restrictive rights.

Characteristics of DML Triggers

 

Introduction

Although we created only one trigger for a table so far, you can go farther than that:

DML triggers present many other characteristics.

DML Triggers and Constraints

You know that, to assist a user with data entry, you can specify that a column would allow or not allow null values. If a column is marked as NOT NULL, during data entry, if the user does not or cannot provide a value for that column, the record cannot be created. If you create a DML trigger that must act against that table, if the nullity rule is violated, the trigger will not run.

You know that you can create a check constraint on a table to make sure that every new record, or a record that is being edited, follows a certain rule. You know that if the record does not abide by that rule, the record will not be created or changed. If a DML trigger is supposed to act on the table and if this rule is not respected, the trigger would fail.

One of the limitations of a check constraint is that it applies only to the table that owns it. A DML trigger can be created to perform a check constraint on more than one table. This provides its advantage over the normal check constraint.

You probably know already about data relationships and referential integrity. This makes sure that, when a record is edited in a parent table, the change is also made on the child table. This also means that the integrity is applied to more than one table. When a DML trigger runs, if a referential rule is violated, the trigger, which also checks the referential integrity, fails.

Instead of DML Triggers

 

Introduction

Consider the following tables in a database:

CREATE DATABASE SmallBusiness;
GO

USE SmallBusiness;
GO

CREATE TABLE Customers
(
    CustomerID int identity(1, 1) primary key not null,
    AccountNumber nchar(10),
    FullName nvarchar(50)
);
GO

CREATE TABLE Management.DatabaseOperations
(
    EmployeeName nvarchar(50),
    ActionPerformed nvarchar(50),
    TimePerformed time
);
GO

From what we have seen so far, when a user opens a table or a view to perform data entry, when a new record has been created, the table or view fires an event. We saw that, using a DML trigger, you can make a notification. For example, you can fill out a log to keep track of the changes. By default, when a record is submitted, it gets saved. In some cases, when a user has opened a table and tried to make a change, such as adding a new record, editing an existing record, or deleting a record, instead of accepting the change, you can dismiss it. You can then use a DML trigger to make a note. This is the basis of another category of DML triggers: an "instead of" trigger.

Practical LearningPractical Learning: Introducing Instead of DML Triggers

  1. Click inside the Query Editor (the SQLQuery1.sql window) and press Ctrl + A to select everything
  2. To create two views triggers, type the following code:
    USE KoloBank1;
    GO
    
    CREATE VIEW Transactions.DepositsSummary
    AS
        SELECT LocationCode,
               EmployeeNumber,
               AccountNumber,
               DepositDate,
               DepositAmount
        FROM Transactions.Deposits;
    GO
    
    CREATE VIEW Transactions.WithdrawalsSummary
    AS
        SELECT LocationCode,
               EmployeeNumber,
               AccountNumber,
               WithdrawalDate,
               WithdrawalAmount
        FROM Transactions.Withdrawals
    GO
  3. Press F5 to execute

Creating an INSTEAD OF Trigger

While an AFTER/FOR trigger acts on a table after the action has occurred, you may want to do something before the event fires. For example, you may want to prevent the user from adding a new record on a table, or from changing an existing record, or from deleting a record. Of course, it is better to take care of this before the action is performed. One way you can do this is by creating an "instead of" trigger.

While an AFTER trigger can be applied to a table only, an "instead of" trigger can be associated with either a table or a view. Therefore, to create an "instead of" trigger, use the following formula:

CREATE TRIGGER TriggerName
ON TableOrView
INSTEAD OF INSERT/UPDATE/DELETE
AS
    TriggerCode

You start with the CREATE TRIGGER expression followed by a name for the trigger. After the name of the trigger, type ON followed by the name of either a table or a view on which the trigger will act.

From our review of the AFTER trigger, the new expression here is INSTEAD OF. This expression is followed by the type of operation to perform:

To start the triggering code, type AS and write the desired code.

If you use the INSTEAD OF expression, the trigger starts when the table or view is opened but before a change has taken place. The difference with the AFTER trigger is that, this time, you can perform some action(s) before the change is made on the table or view. This also implies that, if the code of the trigger is to create a new record, at this time, the record doest not yet exist, which means you cannot catch that record. At this time also, you can prevent the record from being created (since it has not yet been created anyway). For example, the following code will not accept that a new record be added to the table:

USE SmallBusiness;
GO

CREATE TRIGGER CreateCustomer
ON Customers
INSTEAD OF INSERT
AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(SUSER_SNAME(), 
	       N'Attempt to create new record', GETDATE())
    END
GO

If you want to get a copy of the record that was affected by the event, you can access it from the inserted (for an INSERT or UPDATE trigger) or from the deleted (for a DELETE) trigger. Here is an example:

USE SmallBusiness;
GO

DROP TRIGGER CreateCustomer;
GO

CREATE TRIGGER CreateCustomer
ON Customers
INSTEAD OF INSERT
AS
BEGIN
    INSERT INTO Customers 
    SELECT AccountNumber, FullName FROM inserted
END
GO

Practical LearningPractical Learning: Creating INSTEAD OF Triggers

  1. Click inside the Query Editor (the SQLQuery1.sql window) and press Ctrl + A to select everything
  2. To create two new triggers, type the following code:
    USE KoloBank1;
    GO
    
    -- ========================================================
    -- This trigger acts on a view to update the
    -- Management.DatabaseOperations to let it know that an 
    -- attempt was made to create a new room
    -- ========================================================
    CREATE TRIGGER Transactions.AttemptedDeposit
    ON Transactions.DepositsSummary
    INSTEAD OF INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(N'View', N'DepositsSummary', SUSER_SNAME(), 
    	   N'Attempted to make a new deposit.', GETDATE())
    END
    GO
    
    -- ========================================================
    -- This trigger acts on a view to update the
    -- Management.DatabaseOperations to let it know that an 
    -- attempt was made to create a new room
    -- ========================================================
    CREATE TRIGGER Transactions.AttemptedWithdrawal
    ON Transactions.WithdrawalsSummary
    INSTEAD OF INSERT
    AS
    BEGIN
        INSERT INTO Management.DatabaseOperations
        VALUES(N'View', N'WithdrawalsSummary', SUSER_SNAME(), 
    	   N'An attempt was made to withdraw money.', GETDATE())
    END
    GO
  3. Press F5 to execute
  4. In the Object Explorer, under KoloBank1, expand Views
  5. Right-click Transactions.DepositsSummary and click Edit Top 200 Rows
  6. Create a new record as follows:
     
    LocationCode Employee # Account # DepositDate DepositAmount
    GTWMST 482-799 68-304605-84 01/22/2013 137.85
  7. Close the DepositsSummary view
  8. In the Object Explorer, under the Views node of KoloBank1, right-click Transactions.WithdrawalsSummary and click Edit Top 200 Rows
  9. Create a new record as follows:
     
    LocationCode Employee # Account # WithdrawalDate WithdrawalAmount
    ALXJPZ 284-725 27-314257-84 01/24/2013 744.25
  10. Close the WithdrawalsSummary view
  11. Click inside the Query Editor and press Ctrl + A
  12. Type the following:
    USE KoloBank1;
    GO
    
    SELECT * FROM Management.DatabaseOperations;
    GO
  13. Right-click the Query Editor and click Execute
     
    Trigger

Characteristics of INSTEAD OF Triggers

An AFTER/FOR and an INSTEAD OF triggers have many differences. For example:

DDL Triggers

 

Introduction

You probably know that the creation of a database uses a Data Definition Language (DDL) command. You may also know another example of a DDL command that involves creating a table. Each one of these creation operations fires an event.

A DDL trigger is a trigger that acts when a certain type of DDL event fires. These include the creation, modification, and removal of an object, not its records. This is the primary difference with a DML trigger that fires when a record is added or acted upon.

A DDL trigger gives you the opportunity to do some administrative work in response to the event. For example, you can get a notification, or notify someone else using an automatically generated email, that an object (and what object) has been created, or you can use a DDL trigger to discard the operation.

Creating a DDL Trigger

You create a DDL trigger using code. The basic formula is:

CREATE TRIGGER TriggerName
ON DATABASE/ALL SERVER
FOR/AFTER WhatEvent
AS
    TriggerCode

You start a DDL trigger with the CREATE TRIGGER expression followed by a name for the new trigger. The name follows the same rules we have applied to objects so far. After the name of the trigger, type the ON keyword:

After specifying the object (the whole server or only the current database) on which the trigger will act, type either FOR or AFTER. This is followed by the event against which the trigger will act. As mentioned already, the events are DDL commands. To specify the event, use the formula of the command with the words separated by an underscore. For example, if you want the trigger to act when a CREATE TABLE command is executed, specify the event as CREATE_TABLE.

After specifying the event that will fire, type AS followed by the normal code of the trigger.

Here is an example that makes a note and adds it (the note) to a table when a new table has been created:

USE SmallBusiness;
GO

CREATE TRIGGER LogNewTableCreation
ON DATABASE
FOR CREATE_TABLE
AS
BEGIN
    INSERT INTO Management.DatabaseOperations
    VALUES(SUSER_SNAME(), 
	   N'A new table was created', GETDATE())
END
GO

Whenever a new table is created in the current database, the trigger runs, gets the name of the user who created the table, the date and time the table was created, and a small message. These pieces of information are then stored in a log table.

As mentioned for DML triggers, you manage DDL triggers by modifying or deleting them. These are done using the same description we saw for DML triggers.

Practical LearningPractical Learning: Ending the Lesson

  1. Close Microsoft SQL Server
  2. When asked whether you want to save, click No

Previous Copyright © 2009-2022, FunctionX Next