The SET TRANSACTION statement sets the isolation level, read only attribute, or diagnostics area size for the current unit of work.
This statement can be embedded within an application program or issued interactively. It is an executable statement that can be dynamically prepared.
None required.
>>-SET TRANSACTION----------------------------------------------> .-,-----------------------------------------. V .-SERIALIZABLE-----. | (1) >----+-ISOLATION LEVEL--+-NO COMMIT--------+-+-+--------------->< | +-READ UNCOMMITTED-+ | | +-READ COMMITTED---+ | | '-REPEATABLE READ--' | | .-READ ONLY--. | +-+-READ WRITE-+------------------------+ '-DIAGNOSTICS SIZE--+-integer--+--------' '-variable-'
Scope of SET TRANSACTION: The SET TRANSACTION statement sets the isolation level for SQL statements for the current activation group of the process. If that activation group has commitment control scoped to the job, then the SET TRANSACTION statement sets the isolation level of all other activation groups with job commit scoping as well.
If an isolation clause is specified in an SQL statement, that isolation level overrides the transaction isolation level and is used for the SQL statement.
The scope of the SET TRANSACTION statement is based on the context in which it is run. If the SET TRANSACTION statement is run in a trigger, the isolation level specified applies to all subsequent SQL statements until another SET TRANSACTION statement occurs or until the trigger completes, whichever happens first. If the SET TRANSACTION statement is run outside a trigger, the isolation level specified applies to all subsequent SQL statements (except those statements within a trigger that are executed after a SET TRANSACTION statement in the trigger) until a COMMIT or ROLLBACK operation occurs.
For more information about isolation levels, see Isolation level.
SET TRANSACTION restrictions: The SET TRANSACTION statement can only be executed when it is the first SQL statement in a unit of work, unless:
In a trigger, SET TRANSACTION with READ ONLY is allowed only on a COMMIT boundary. The SET TRANSACTION statement can be executed in a trigger at any time, but it is recommended that it be executed as the first statement in the trigger. The SET TRANSACTION statement is useful within triggers to set the isolation level for SQL statements in the trigger to the same level as the application which caused the trigger to be activated.
A SET TRANSACTION statement is not allowed if the current connection is to a remote application server unless it is in a trigger at the current server. Once a SET TRANSACTION statement is executed, CONNECT and SET CONNECTION statements are not allowed until the unit of work is committed or rolled back.
The SET TRANSACTION statement has no effect on WITH HOLD cursors that are still open when the SET TRANSACTION statement is executed.
Syntax alternatives: The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:
Example 1: The following SET TRANSACTION statement sets the isolation level to NONE (equivalent to specifying *NONE on the SQL precompiler command).
EXEC SQL SET TRANSACTION ISOLATION LEVEL NO COMMIT;
Example 2: The following SET TRANSACTION statement sets the isolation level to SERIALIZABLE.
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE