<?xml version="1.0" encoding="utf-8"?> <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"> <html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us"> <head> <meta http-equiv="Content-Type" content="text/html; charset=utf-8" /> <meta name="dc.language" scheme="rfc1766" content="en-us" /> <!-- All rights reserved. Licensed Materials Property of IBM --> <!-- US Government Users Restricted Rights --> <!-- Use, duplication or disclosure restricted by --> <!-- GSA ADP Schedule Contract with IBM Corp. --> <meta name="dc.date" scheme="iso8601" content="2005-09-19" /> <meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" /> <meta name="security" content="public" /> <meta name="Robots" content="index,follow"/> <meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' /> <meta name="keywords" content="SET TRANSACTION statement, SET TRANSACTION, SQL statements, set using SET TRANSACTION, isolation level, NO COMMIT clause, ISOLATION LEVEL clause, READ UNCOMMITTED clause, READ COMMITTED clause, REPEATABLE READ clause, SERIALIZABLE clause, setting isolation level, trigger, effect on SET TRANSACTION, COMMIT, ROLLBACK" /> <title>SET TRANSACTION</title> <link rel="stylesheet" type="text/css" href="ibmidwb.css" /> <link rel="stylesheet" type="text/css" href="ic.css" /> </head> <body> <a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link --> <script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script> <a name="settraj"></a> <h2 id="settraj"><a href="rbafzmst02.htm#ToC_1348">SET TRANSACTION</a></h2><a id="idx3212" name="idx3212"></a><a id="idx3213" name="idx3213"></a><a id="idx3214" name="idx3214"></a> <a name="settran"></a> <p id="settran">The SET TRANSACTION statement sets the isolation level, read only attribute, or diagnostics area size for the current unit of work.</p> <a name="wq1795"></a> <h3 id="wq1795"><a href="rbafzmst02.htm#ToC_1349">Invocation</a></h3> <p>This statement can be embedded within an application program or issued interactively. It is an executable statement that can be dynamically prepared.</p> <a name="wq1796"></a> <h3 id="wq1796"><a href="rbafzmst02.htm#ToC_1350">Authorization</a></h3> <p>None required.</p> <a name="wq1797"></a> <h3 id="wq1797"><a href="rbafzmst02.htm#ToC_1351">Syntax</a></h3> <a href="rbafzmstsettraj.htm#synsst"><img src="c.gif" alt="Click to skip syntax diagram" /></a> <pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn393.htm" border="0" /></span><a href="#skipsyn-392"><img src="c.gif" alt="Skip visual syntax diagram" border="0" /></a>>>-SET TRANSACTION----------------------------------------------> .-,-----------------------------------------. V .-SERIALIZABLE-----. | (1) >----+-ISOLATION LEVEL--+-NO COMMIT--------+-+-+--------------->< | +-READ UNCOMMITTED-+ | | +-READ COMMITTED---+ | | '-REPEATABLE READ--' | | .-READ ONLY--. | +-+-READ WRITE-+------------------------+ '-DIAGNOSTICS SIZE--+-<span class="italic">integer</span>--+--------' '-<span><span class="italic">variable</span></span>-' </pre> <a name="skipsyn-392" id="skipsyn-392"></a> <a name="wq1798"></a> <div class="notelisttitle" id="wq1798">Notes:</div> <ol type="1"> <li>Only one ISOLATION LEVEL clause, one READ WRITE or READ ONLY clause, and one DIAGNOSTICS SIZE clause may be specified.</li> </ol> <a name="synsst"></a> <h3 id="synsst"><a href="rbafzmst02.htm#ToC_1352">Description</a></h3> <dl class="parml"> <dt class="bold">ISOLATION LEVEL</dt> <dd>Specifies the isolation level of the transaction. If the ISOLATION LEVEL clause is not specified, ISOLATION LEVEL SERIALIZABLE is implicit <dl class="parml"> <dt class="bold">NO COMMIT </dt><a id="idx3215" name="idx3215"></a><a id="idx3216" name="idx3216"></a> <dd>Specifies isolation level NC (COMMIT(*NONE)). </dd> <dt class="bold">READ UNCOMMITTED</dt><a id="idx3217" name="idx3217"></a> <dd>Specifies isolation level UR (COMMIT(*CHG)). </dd> <dt class="bold">READ COMMITTED </dt><a id="idx3218" name="idx3218"></a> <dd>Specifies isolation level CS (COMMIT(*CS)). </dd> <dt class="bold">REPEATABLE READ <sup class="fn"><a id="wq1800" name="wq1800" href="rbafzmstsettraj.htm#wq1801">82</a></sup></dt><a id="idx3219" name="idx3219"></a> <dd>Specifies isolation level RS (COMMIT(*ALL)). </dd> <dt class="bold">SERIALIZABLE </dt><a id="idx3220" name="idx3220"></a> <dd>Specifies isolation level RR (COMMIT(*RR)). </dd> </dl> </dd> <dt class="bold">READ WRITE or READ ONLY</dt> <dd>Specifies whether the transaction allows data change operations. <dl class="parml"> <dt class="bold">READ WRITE</dt> <dd>Specifies that all SQL operations are allowed. This is the default unless ISOLATION LEVEL READ UNCOMMITTED is specified. </dd> <dt class="bold">READ ONLY</dt> <dd>Specifies that only SQL operations that do not change SQL data are allowed. If ISOLATION LEVEL READ UNCOMMITTED is specified, this is the default. </dd> </dl> </dd> <dt class="bold">DIAGNOSTICS SIZE</dt> <dd>Specifies the maximum number of GET DIAGNOSTICS condition areas for the current transaction. The GET DIAGNOSTICS <var class="pv">statement-information-item</var> MORE will be set to 'Y' for the current statement if the statement exceeds the maximum number of condition areas for the current transaction. The specified maximum number of condition areas must be between 1 and 32767. <dl class="parml"> <dt class="bold"><var class="pv">integer</var></dt> <dd>An integer constant that specifies the maximum number of condition areas for the current transaction. </dd> <dt class="bold"><var class="pv">variable</var></dt> <dd>Identifies a variable which contains the maximum number of condition areas for the current transaction. The variable must be a numeric variable with a zero scale and must not be followed by an indicator variable. </dd> </dl> </dd> </dl> <a name="wq1802"></a> <h3 id="wq1802"><a href="rbafzmst02.htm#ToC_1353">Notes</a></h3> <p><span class="bold">Scope of SET TRANSACTION:</span> 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.</p> <p>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.</p> <p>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.</p> <p>For more information about isolation levels, see <a href="rbafzmstisol.htm#isol">Isolation level</a>.</p><a id="idx3221" name="idx3221"></a> <p><span class="bold">SET TRANSACTION restrictions:</span> The SET TRANSACTION statement can only be executed when it is the first SQL statement in a unit of work, unless:</p> <ul> <li>all previous statements executed in the unit of work are SET TRANSACTION statements or statements that are executed under isolation level NC, or</li> <li>it is executed in a trigger.</li></ul><p class="indatacontent">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.</p> <p>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.</p><a id="idx3222" name="idx3222"></a><a id="idx3223" name="idx3223"></a> <p>The SET TRANSACTION statement has no effect on WITH HOLD cursors that are still open when the SET TRANSACTION statement is executed.</p> <p><span class="bold">Syntax alternatives:</span> The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:</p> <ul> <li>The keywords NC or NONE can be used as synonyms for NO COMMIT.</li> <li>The keywords UR and CHG can be used as synonyms for READ UNCOMMITTED.</li> <li>The keyword CS can be used as a synonym for READ COMMITTED.</li> <li>The keywords RS or ALL can be used as synonyms for REPEATABLE READ.</li> <li>The keyword RR can be used as a synonym for SERIALIZABLE.</li></ul> <a name="wq1803"></a> <h3 id="wq1803"><a href="rbafzmst02.htm#ToC_1354">Examples</a></h3> <p><span class="italic">Example 1:</span> The following SET TRANSACTION statement sets the isolation level to NONE (equivalent to specifying *NONE on the SQL precompiler command). </p> <pre class="xmp"> EXEC SQL <span class="bold">SET TRANSACTION ISOLATION LEVEL NO COMMIT;</span></pre> <p><span class="italic">Example 2:</span> The following SET TRANSACTION statement sets the isolation level to SERIALIZABLE. </p> <pre class="xmp"> <span class="bold">SET TRANSACTION ISOLATION LEVEL SERIALIZABLE</span></pre> <p><a id="idx3224" name="idx3224"></a><a id="idx3225" name="idx3225"></a></p> <hr /><div class="fnnum"><a id="wq1801" name="wq1801" href="rbafzmstsettraj.htm#wq1800">82</a>.</div> <div class="fntext">REPEATABLE READ is the ISO and ANS standard term that corresponds to the isolation level of *ALL for DB2 UDB for iSeries and the isolation level of Read Stability (RS) in IBM® SQL. SERIALIZABLE is used in the ISO and ANS standard for what IBM SQL calls Repeatable Read (RR).</div> <br /> <hr /><br /> [ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzsetsessionauth.htm">Previous Page</a> | <a href="rbafzmstsettranv.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> | <a href="rbafzmstindex.htm#index">Index</a> ] <a id="Bot_Of_Page" name="Bot_Of_Page"></a> </body> </html>