Triggers and MERGE Requests - Advanced SQL Engine - Teradata Database

SQL Data Definition Language Detailed Topics

Product
Advanced SQL Engine
Teradata Database
Release Number
17.05
17.00
Published
June 2020
Language
English (United States)
Last Update
2021-01-24
dita:mapPath
jpx1556733107962.ditamap
dita:ditavalPath
lze1555437562152.ditaval
dita:id
B035-1184
lifecycle
previous
Product Category
Teradata Vantage™

MERGE requests can be used as triggering statements to fire triggers; however, they cannot be used as triggered statements.

When a MERGE request executes, triggers defined on UPDATE actions become activated if a WHEN MATCHED clause is specified, and triggers defined on INSERT actions become activated if a WHEN NOT MATCHED clause is specified.

The order of activation of UPDATE and INSERT triggers is the same as the order of WHEN MATCHED and WHEN NOT MATCHED clauses in the MERGE statement.

There is a slight deviation between the Teradata implementation of triggers with MERGE and the ANSI SQL:2011 standard for the implementation of triggers with MERGE. The ANSI SQL:2011 standard recommends that triggers be implemented in MERGE requests as follows.

First Clause Specified When Updates to Rows and Inserts of New Rows in the Target Table Occur Sequence of Actions During MERGE
WHEN MATCHED (UPDATE specification)
  1. All BEFORE triggers associated with UPDATE action are applied.
  2. The updates specified by the UPDATE specification are applied.
  3. Constraints are checked, which may result in executing referential actions.
  4. AFTER triggers associated with the UPDATE action are applied.
  5. BEFORE triggers associated with the INSERT action are applied.
  6. Inserts specified by the INSERT specification are applied.
  7. Constraints are checked, which might result in executing referential actions.
  8. AFTER triggers associated with the INSERT action are applied.
WHEN NOT MATCHED (INSERT specification)
  1. BEFORE triggers associated with the INSERT action are applied.
  2. Inserts specified by the INSERT specification are applied.
  3. Constraints are checked, which may result in executing referential actions.
  4. AFTER triggers associated with the INSERT action are applied.
  5. All BEFORE triggers associated with the UPDATE action are applied.
  6. The updates specified by the UPDATE specification are applied.
  7. Constraints are checked, which might result in executing referential actions.
  8. AFTER triggers associated with the UPDATE action are applied.

In contrast, Teradata Database implements triggers in MERGE requests as follows:

First Clause Specified When Updates to Rows and Inserts of New Rows in the Target Table Occur Sequence of Actions During MERGE
WHEN MATCHED (UPDATE specification)
  1. All BEFORE triggers associated with UPDATE action are applied.
  2. All BEFORE triggers associated with INSERT action are applied.
  3. The updates specified by the UPDATE specification are applied.
  4. Constraints are checked, which might result in executing referential actions.
  5. Inserts specified by the INSERT specification are applied.
  6. Constraints are checked, which might result in executing referential actions.
  7. AFTER triggers associated with UPDATE action are applied.
  8. AFTER triggers associated with INSERT action are applied.
WHEN NOT MATCHED (INSERT specification)
  1. All BEFORE triggers associated with INSERT action are applied.
  2. All BEFORE triggers associated with UPDATE action are applied.
  3. The updates specified by the UPDATE specification are applied.
  4. Constraints are checked, which might result in executing referential actions.
  5. Inserts specified by the INSERT specification are applied.
  6. Constraints are checked, which might result in executing referential actions.
  7. AFTER triggers associated with INSERT action are applied.
  8. AFTER triggers associated with UPDATE action are applied.

For information about the MERGE statement, see “MERGE” in Teradata Vantage™ - SQL Data Manipulation Language, B035-1146.