427 lines
20 KiB
HTML
427 lines
20 KiB
HTML
<?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 lang="en-us" xml:lang="en-us">
|
||
<head>
|
||
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
|
||
<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="DC.Type" content="reference" />
|
||
<meta name="DC.Title" content="Commitment control" />
|
||
<meta name="abstract" content="The DB2 UDB for iSeries commitment control support provides a means to process a group of database changes like update, insert, DDL, or delete operations as a single unit of work (transaction)." />
|
||
<meta name="description" content="The DB2 UDB for iSeries commitment control support provides a means to process a group of database changes like update, insert, DDL, or delete operations as a single unit of work (transaction)." />
|
||
<meta name="DC.subject" content="data integrity, commitment control, description, security, Start Commitment Control (STRCMTCTL) command, command (CL), Start Commitment Control (STRCMTCTL), STRCMTCTL (Start Commitment Control), COMMIT, keyword, COMMIT statement, statements, ROLLBACK statement, ROLLBACK" />
|
||
<meta name="keywords" content="data integrity, commitment control, description, security, Start Commitment Control (STRCMTCTL) command, command (CL), Start Commitment Control (STRCMTCTL), STRCMTCTL (Start Commitment Control), COMMIT, keyword, COMMIT statement, statements, ROLLBACK statement, ROLLBACK" />
|
||
<meta name="DC.Relation" scheme="URI" content="rbafydataintex.htm" />
|
||
<meta name="DC.Relation" scheme="URI" content="../db2/rbafzmsth2clcu.htm" />
|
||
<meta name="DC.Relation" scheme="URI" content="../db2/rbafzmstisol.htm" />
|
||
<meta name="DC.Relation" scheme="URI" content="../rzakj/rzakjcommitkickoff.htm" />
|
||
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
|
||
<meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1998, 2006" />
|
||
<meta name="DC.Format" content="XHTML" />
|
||
<meta name="DC.Identifier" content="rbafydicomm" />
|
||
<meta name="DC.Language" 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. -->
|
||
<link rel="stylesheet" type="text/css" href="./ibmdita.css" />
|
||
<link rel="stylesheet" type="text/css" href="./ic.css" />
|
||
<title>Commitment control</title>
|
||
</head>
|
||
<body id="rbafydicomm"><a name="rbafydicomm"><!-- --></a>
|
||
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
||
<h1 class="topictitle1">Commitment control</h1>
|
||
<div><p>The <span class="keyword">DB2<sup>®</sup> UDB for iSeries™</span> commitment
|
||
control support provides a means to process a group of database changes like
|
||
update, insert, DDL, or delete operations as a single unit of work (transaction).</p>
|
||
<div class="section"><p>A commit operation guarantees that the group of operations is
|
||
completed. A rollback operation guarantees that the group of operations is
|
||
backed out. A savepoint can be used to break a transaction into smaller units
|
||
that can be rolled back. A commit operation can be issued through several
|
||
different interfaces. For example,</p>
|
||
<ul><li>An SQL COMMIT statement</li>
|
||
<li>A CL COMMIT command</li>
|
||
<li>A language commit statement (such as an RPG COMMIT statement)</li>
|
||
</ul>
|
||
<p> A rollback operation can be issued through several different interfaces.
|
||
For example,</p>
|
||
<ul><li>An SQL ROLLBACK statement</li>
|
||
<li>A CL ROLLBACK command</li>
|
||
<li>A language rollback statement (such as an RPG ROLBK statement)</li>
|
||
</ul>
|
||
</div>
|
||
<div class="section"><p>The only SQL statements that cannot be committed or rolled back
|
||
are: </p>
|
||
<ul><li>DROP SCHEMA</li>
|
||
<li>GRANT or REVOKE if an authority holder exists for the specified object</li>
|
||
</ul>
|
||
</div>
|
||
<div class="section"><p>If commitment control was not already started when either an SQL
|
||
statement is executed with an isolation level other than COMMIT(*NONE) or
|
||
a RELEASE statement is executed, then <span class="keyword">DB2 UDB for iSeries</span> sets
|
||
up the commitment control environment by implicitly calling the CL command
|
||
Start Commitment Control (STRCMTCTL). <span class="keyword">DB2 UDB for iSeries</span> specifies
|
||
NFYOBJ(*NONE) and CMTSCOPE(*ACTGRP) parameters along with LCKLVL on the STRCMTCTL
|
||
command. The LCKLVL specified is the lock level on the COMMIT parameter on
|
||
the CRTSQLxxx, STRSQL, or RUNSQLSTM commands. In REXX, the LCKLVL specified
|
||
is the lock level on the SET OPTION statement. You may use the STRCMTCTL command
|
||
to specify a different CMTSCOPE, NFYOBJ, or LCKLVL. If you specify CMTSCOPE(*JOB)
|
||
to start the job level commitment definition, <span class="keyword">DB2 UDB for iSeries</span> uses
|
||
the job level commitment definition for programs in that activation group.
|
||
</p>
|
||
<div class="note"><span class="notetitle">Notes:</span> <ol><li>When using commitment control, the tables referred to in the application
|
||
program by Data Manipulation Language statements must be journaled.</li>
|
||
<li>Note that the LCKLVL specified is only the default lock level. After commitment
|
||
control is started, the SET TRANSACTION SQL statement and the lock level specified
|
||
on the COMMIT parameter on the CRTSQLxxx, STRSQL, or RUNSQLSTM commands will
|
||
override the default lock level.</li>
|
||
</ol>
|
||
</div>
|
||
</div>
|
||
<div class="section"><div class="p">For cursors that use column functions, GROUP BY, or HAVING, and
|
||
are running under commitment control, a ROLLBACK HOLD has no effect on the
|
||
cursor's position. In addition, the following occurs under commitment control: <ul><li>If COMMIT(*CHG) and (ALWBLK(*NO) or (ALWBLK(*READ)) is specified for one
|
||
of these cursors, a message (CPI430B) is sent that says COMMIT(*CHG) requested
|
||
but not allowed.</li>
|
||
<li>If COMMIT(*ALL), COMMIT(*RR), or COMMIT(*CS) with the KEEP LOCKS clause
|
||
is specified for one of the cursors, <span class="keyword">DB2 UDB for iSeries</span> will
|
||
lock all referenced tables in shared mode (*SHRNUP). The lock prevents concurrent
|
||
application processes from executing any but read-only operations on the named
|
||
table. A message (either SQL7902 or CPI430A) is sent that says COMMIT(*ALL),
|
||
COMMIT(*RR), or COMMIT(*CS) with the KEEP LOCKS clause is specified for one
|
||
of the cursors requested but not allowed. Message SQL0595 may also be sent.</li>
|
||
</ul>
|
||
</div>
|
||
</div>
|
||
<div class="section"><p>For cursors where either COMMIT(*ALL), COMMIT(*RR), or COMMIT(*CS)
|
||
with the KEEP LOCKS clause is specified and either catalog files are used
|
||
or a temporary result table is required, <span class="keyword">DB2 UDB for iSeries</span> will
|
||
lock all referenced tables in shared mode (*SHRNUP). This will prevent concurrent
|
||
processes from executing anything but read-only operations on the table(s).
|
||
A message (either SQL7902 or CPI430A) is sent that says COMMIT(*ALL) is requested
|
||
but not allowed. Message SQL0595 may also be sent.</p>
|
||
</div>
|
||
<div class="section"><p>If ALWBLK(*ALLREAD) and COMMIT(*CHG) were specified, when the
|
||
program was precompiled, all read-only cursors will allow blocking of rows
|
||
and a ROLLBACK HOLD will not roll the cursor position back.</p>
|
||
</div>
|
||
<div class="section"><p>If COMMIT(*RR) is requested, the tables will be locked until the
|
||
query is closed. If the cursor is read-only, the table will be locked (*SHRNUP).
|
||
If the cursor is in update mode, the table will be locked (*EXCLRD). Since
|
||
other users will be locked out of the table, running with repeatable read
|
||
will prevent concurrent access of the table.</p>
|
||
</div>
|
||
<div class="section"><p>If an isolation level other then COMMIT(*NONE) was specified and
|
||
the application issues a ROLLBACK or the activation group ends abnormally
|
||
(and the commitment definition is not *JOB), all updates, inserts, deletes,
|
||
and DDL operations made within the unit of work are backed out. If the application
|
||
issues a COMMIT or the activation group ends normally, all updates, inserts,
|
||
deletes, and DDL operations made within the unit of work are committed.</p>
|
||
</div>
|
||
<div class="section"><p><span class="keyword">DB2 UDB for iSeries</span> uses locks
|
||
on rows to keep other jobs from accessing changed data before a unit of work
|
||
completes. If COMMIT(*ALL) is specified, read locks on rows fetched are also
|
||
used to prevent other jobs from changing data that was read before a unit
|
||
of work completes. This will not prevent other jobs from reading the unchanged
|
||
rows. This ensures that, if the same unit of work rereads a row, it gets the
|
||
same result. Read locks do not prevent other jobs from fetching the same rows.</p>
|
||
</div>
|
||
<div class="section"><p>Commitment control handles up to 500 million distinct row changes
|
||
in a unit of work. If COMMIT(*ALL) or COMMIT(*RR) is specified, all rows read
|
||
are also included in the limit. (If a row is changed or read more than once
|
||
in a unit of work, it is only counted once toward the limit.) Holding a large
|
||
number of locks adversely affects system performance and does not allow concurrent
|
||
users to access rows locked in the unit of work until the end of the unit
|
||
of work. It is in your best interest to keep the number of rows processed
|
||
in a unit of work small.</p>
|
||
</div>
|
||
<div class="section"><p>Commitment control will allow up to 512 files for each journal
|
||
to be open under commitment control or closed with pending changes in a unit
|
||
of work.</p>
|
||
</div>
|
||
<div class="section"><p>COMMIT HOLD and ROLLBACK HOLD allows you to keep the cursor open
|
||
and start another unit of work without issuing an OPEN again. The HOLD value
|
||
is not available when you are connected to a remote database that is not on
|
||
an <span class="keyword">iSeries</span> system. However,
|
||
the WITH HOLD option on DECLARE CURSOR may be used to keep the cursor open
|
||
after a COMMIT. This type of cursor is supported when you are connected to
|
||
a remote database that is not on an <span class="keyword">iSeries</span> system.
|
||
Such a cursor is closed on a rollback.</p>
|
||
</div>
|
||
|
||
<div class="tablenoborder"><a name="rbafydicomm__reclock"><!-- --></a><table cellpadding="4" cellspacing="0" summary="" id="rbafydicomm__reclock" width="100%" frame="border" border="1" rules="all"><caption>Table 1. Row lock duration</caption><thead align="left"><tr><th align="left" valign="bottom" width="20.754716981132077%" id="d0e194">SQL statement</th>
|
||
<th align="left" valign="bottom" width="22.641509433962266%" id="d0e196">COMMIT parameter (see note 5)</th>
|
||
<th align="left" valign="bottom" width="45.28301886792453%" id="d0e198">Duration of row locks</th>
|
||
<th align="left" valign="bottom" width="11.320754716981133%" id="d0e200">Lock type</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 "> <p>SELECT INTO<br />
|
||
SET variable<br />
|
||
VALUES INTO</p>
|
||
</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS (See note 6)<br />
|
||
*ALL (See note 2 and 7)</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>No locks<br />
|
||
No locks<br />
|
||
Row locked when read and released<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p> <br />
|
||
<br />
|
||
READ<br />
|
||
READ</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">FETCH (read-only cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS (See note 6)<br />
|
||
*ALL (See note 2 and 7)</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>No locks<br />
|
||
No locks<br />
|
||
From read until the next FETCH<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p> <br />
|
||
<br />
|
||
READ<br />
|
||
READ</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">FETCH (update or delete capable cursor) (See
|
||
note 1)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
*CHG<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
*CS<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>When row not updated or deleted<br />
|
||
from read until next FETCH<br />
|
||
When row is updated or deleted<br />
|
||
from read until UPDATE or DELETE<br />
|
||
When row not updated or deleted<br />
|
||
from read until next FETCH<br />
|
||
When row is updated or deleted<br />
|
||
from read until COMMIT or ROLLBACK<br />
|
||
When row not updated or deleted<br />
|
||
from read until next FETCH<br />
|
||
When row is updated or deleted<br />
|
||
from read until COMMIT or ROLLBACK<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>UPDATE<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
UPDATE<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
UPDATE<br />
|
||
<br />
|
||
<br />
|
||
<br />
|
||
UPDATE</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">INSERT (target table)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>No locks<br />
|
||
From insert until ROLLBACK or COMMIT<br />
|
||
From insert until ROLLBACK or COMMIT<br />
|
||
From insert until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p> <br />
|
||
UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE<sup>3</sup></p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">INSERT (tables in subselect)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>No locks<br />
|
||
No locks<br />
|
||
Each row locked while being read<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p> <br />
|
||
<br />
|
||
READ<br />
|
||
READ</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">UPDATE (non-cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>Each row locked while being updated<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">DELETE (non-cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>Each row locked while being deleted<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">UPDATE (with cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>Lock released when row updated<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">DELETE (with cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>Lock released when row deleted<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE<br />
|
||
UPDATE</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">Subqueries (update or delete capable cursor
|
||
or UPDATE or DELETE non-cursor)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL (see note 2)</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>From read until next FETCH<br />
|
||
From read until next FETCH<br />
|
||
From read until next FETCH<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p>READ<br />
|
||
READ<br />
|
||
READ<br />
|
||
READ</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="20.754716981132077%" headers="d0e194 ">Subqueries (read-only cursor or SELECT INTO)</td>
|
||
<td align="left" valign="top" width="22.641509433962266%" headers="d0e196 "> <p>*NONE<br />
|
||
*CHG<br />
|
||
*CS<br />
|
||
*ALL</p>
|
||
</td>
|
||
<td align="left" valign="top" width="45.28301886792453%" headers="d0e198 "> <p>No locks<br />
|
||
No locks<br />
|
||
Each row locked while being read<br />
|
||
From read until ROLLBACK or COMMIT</p>
|
||
</td>
|
||
<td align="left" valign="top" width="11.320754716981133%" headers="d0e200 "> <p> <br />
|
||
<br />
|
||
READ<br />
|
||
READ</p>
|
||
</td>
|
||
</tr>
|
||
<tr><td colspan="4" align="left" valign="top" headers="d0e194 d0e196 d0e198 d0e200 "><div class="note"><span class="notetitle">Notes:</span> <ol><li>A cursor is open with UPDATE or DELETE capabilities if the result table
|
||
is not read-only and if one of the following is true: <ul><li>The cursor is defined with a FOR UPDATE clause.</li>
|
||
<li>The cursor is defined without a FOR UPDATE, FOR READ ONLY, or ORDER BY
|
||
clause and the program contains at least one of the following: <ul><li>Cursor UPDATE referring to the same cursor-name</li>
|
||
<li>Cursor DELETE referring to the same cursor-name</li>
|
||
<li>An EXECUTE or EXECUTE IMMEDIATE statement and ALWBLK(*READ) or ALWBLK(*NONE)
|
||
was specified on the CRTSQLxxx command.</li>
|
||
</ul>
|
||
</li>
|
||
</ul>
|
||
</li>
|
||
<li>A table or view can be locked exclusively in order to satisfy COMMIT(*ALL).
|
||
If a subselect is processed that includes a UNION, or if the processing of
|
||
the query requires the use of a temporary result, an exclusive lock is acquired
|
||
to protect you from seeing uncommitted changes.</li>
|
||
<li>An UPDATE lock on rows of the target table and a READ lock on the rows
|
||
of the subselect table.</li>
|
||
<li>A table or view can be locked exclusively in order to satisfy repeatable
|
||
read. Row locking is still done under repeatable read. The locks acquired
|
||
and their duration are identical to *ALL.</li>
|
||
<li>Repeatable read (*RR) row locks will be the same as the locks indicated
|
||
for *ALL.</li>
|
||
<li>If the KEEP LOCKS clause is specified with *CS, any read locks are held
|
||
until the cursor is closed or until a COMMIT or ROLLBACK is done. If no cursors
|
||
are associated with the isolation clause, then locks are held until the completion
|
||
of the SQL statement.</li>
|
||
<li>If the USE AND KEEP EXCLUSIVE LOCKS clause is specified with the *RS or
|
||
*RR isolation level, an UPDATE lock on the row will be obtained instead of
|
||
a READ lock.</li>
|
||
</ol>
|
||
</div>
|
||
</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
</div>
|
||
<div>
|
||
<div class="familylinks">
|
||
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafydataintex.htm" title="Data integrity protects data from being destroyed or changed by unauthorized persons, system operation or hardware failures (such as physical damage to a disk), programming errors, interruptions before a job is completed (such as a power failure), or interference from running applications at the same time (such as serialization problems).">Data integrity</a></div>
|
||
</div>
|
||
<div class="relinfo"><strong>Related information</strong><br />
|
||
<div><a href="../db2/rbafzmsth2clcu.htm">DECLARE CURSOR statement</a></div>
|
||
<div><a href="../db2/rbafzmstisol.htm">Isolation Level</a></div>
|
||
<div><a href="../rzakj/rzakjcommitkickoff.htm">Commitment control</a></div>
|
||
</div>
|
||
</div>
|
||
</body>
|
||
</html> |