The SET transition-variable statement assigns values to new transition-variables.
This statement can only be used as an SQL statement in a BEFORE trigger. It is an executable statement that cannot be dynamically prepared.
If a row-fullselect is specified, see fullselect for an explanation of the authorization required for each subselect.
.-,-------------------------------------------------------------------------. V | >>-SET----+-transition-variable-- = --+-expression-+------------------------------+-+->< | +-NULL-------+ | | '-DEFAULT----' | | .-,-------------------. .-,--------------. | | V | V | (1) | '-(----transition-variable-+--)-- = --(--+---+-expression-+-+------+--)-' | +-NULL-------+ | | '-DEFAULT----' | | (2) | '-row-fullselect----------'
A transition-variable must not be identified more than once in the same SET transition-variable statement.
The data type of each transition-variable must be compatible with its corresponding result column. Values are assigned to transition-variables according to the assignment rules to a column. For more information see Assignments and comparisons.
An expression may contain references to OLD and NEW transition-variables. If the CREATE TRIGGER statement contains both OLD and NEW clauses, references to transition-variables must be qualified by the correlation-name.
Example 1: Ensure that the salary column is never greater than 50000. If the new value is greater than 50000, set it to 50000.
CREATE TRIGGER LIMIT_SALARY BEFORE INSERT ON EMPLOYEE REFERENCING NEW AS NEW_VAR FOR EACH ROW MODE DB2SQL WHEN (NEW_VAR.SALARY > 50000) BEGIN ATOMIC SET NEW_VAR.SALARY = 50000; END
Example 2: When the job title is updated, increase the salary based on the new job title. Assign the years in the position to 0.
CREATE TRIGGER SET_SALARY BEFORE UPDATE OF JOB ON STAFF REFERENCING OLD AS OLD_VAR NEW AS NEW_VAR FOR EACH ROW MODE DB2SQL BEGIN ATOMIC SET (NEW_VAR.SALARY, NEW_VAR.YEARS) = (OLD_VAR.SALARY * CASE NEW_VAR.JOB WHEN 'Sales' THEN 1.1 WHEN 'Mgr' THEN 1.05 ELSE 1 END ,0); END