Isolation level

The isolation level used during the execution of SQL statements determines the degree to which the activation group is isolated from concurrently executing activation groups. Thus, when activation group P executes an SQL statement, the isolation level determines:

The isolation level can be explicitly specified on a DELETE, INSERT, SELECT INTO, UPDATE, or select-statement. If the isolation level is not explicitly specified, the isolation level used when the SQL statement is executed is the default isolation level.

DB2 UDB for iSeries provides several ways to specify the default isolation level:

These isolation levels are supported by automatically locking the appropriate data. Depending on the type of lock, this limits or prevents access to the data by concurrent activation groups that use different commitment definitions. Each database manager supports at least two types of locks:

Share
Limits concurrent activation groups that use different commitment definitions to read-only operations on the data.
Exclusive
Prevents concurrent activation groups using different commitment definitions from updating or deleting the data. Prevents concurrent activation groups using different commitment definitions that are running COMMIT(*RS), COMMIT(*CS), or COMMIT(*RR) from reading the data. Concurrent activation groups using different commitment definitions that are running COMMIT(*UR) or COMMIT(*NC) are allowed to read the data.

The following descriptions of isolation levels refer to locking data in row units. Individual implementations can lock data in larger physical units than base table rows. However, logically, locking occurs at the base-table row level across all products. Similarly, a database manager can escalate a lock to a higher level. An activation group is guaranteed at least the minimum requested lock level.

For a detailed description of record lock durations, see the discussion and table in the commitment control topic of the SQL Programming book.

DB2 UDB for iSeries supports five isolation levels. For all isolation levels except No Commit, the database manager places exclusive locks on every row that is inserted, updated, or deleted. This ensures that any row changed during a unit of work is not changed by any other activation group that uses a different commitment definition until the unit of work is complete. The isolation levels are:

Repeatable read

The Repeatable Read (RR) isolation level ensures:

In addition to any exclusive locks, an activation group running at level RR acquires at least share locks on all the rows it reads. Furthermore, the locking is performed so that the activation group is completely isolated from the effects of concurrent activation groups that use different commitment definitions.

In the SQL 2003 Core standard, Repeatable Read is called Serializable.

DB2 UDB for iSeries supports repeatable-read through COMMIT(*RR). Repeatable-read isolation level is supported by locking the tables containing any rows that are read or updated.

Read stability

Like level RR, level Read Stability (RS) ensures that:

Unlike RR, RS does not completely isolate the activation group from the effects of concurrent activation groups that use a different commitment definition. At level RS, activation groups that issue the same query more than once might see additional rows. These additional rows are called phantom rows.

For example, a phantom row can occur in the following situation:

  1. Activation group P1 reads the set of rows n that satisfy some search condition.
  2. Activation group P2 then INSERTs one or more rows that satisfy the search condition and COMMITs those INSERTs.
  3. P1 reads the set of rows again with the same search condition and obtains both the original rows and the rows inserted by P2.

In addition to any exclusive locks, an activation group running at level RS acquires at least share locks on all the rows it reads.

In the SQL 2003 Core standard, Read Stability is called Repeatable Read.

DB2 UDB for iSeries supports read stability through COMMIT(*ALL) or COMMIT(*RS).

Cursor stability

Like levels RR and RS, level Cursor Stability (CS) ensures that any row that was changed (or a row that is currently locked with an UPDATE row lock) by another activation group using a different commitment definition cannot be read until it is committed. Unlike RR and RS, level CS only ensures that the current row of every updatable cursor is not changed by other activation groups using different commitment definitions. Thus, the rows that were read during a unit of work can be changed by other activation groups that use a different commitment definition. In addition to any exclusive locks, an activation group running at level CS may acquire a share lock for the current row of every cursor.

In the SQL 2003 Core standard, Cursor Stability is called Read Committed.

DB2 UDB for iSeries supports cursor stability through COMMIT(*CS).

Uncommitted read

For a SELECT INTO, a FETCH with a read-only cursor, subquery, or fullselect used in an INSERT statement, level Uncommitted Read (UR) allows:

For other operations, the rules of level CS apply.

In the SQL 2003 Core standard, Uncommitted Read is called Read Uncommitted.

DB2 UDB for iSeries supports uncommitted read through COMMIT(*CHG) or COMMIT(*UR).

No commit

For all operations, the rules of level UR apply to No Commit (NC) except:

DB2 UDB for iSeries supports No Commit through COMMIT(*NONE) or COMMIT(*NC).

Note:
(For distributed applications.) When a requested isolation level is not supported by an application server, the isolation level is escalated to the next highest supported isolation level. For example, if RS is not supported by an application server, the RR isolation level is used.

Comparison of isolation levels

The following table summarizes information about isolation levels.

  NC UR CS RS RR
Can the application see uncommitted changes made by other application processes? Yes Yes No No No
Can the application update uncommitted changes made by other application processes? No No No No No
Can the re-execution of a statement be affected by other application processes? See phenomenon P3 (phantom) below. Yes Yes Yes Yes No
Can "updated" rows be updated by other application processes? Yes No No No No
Can "updated" rows be read by other application processes that are running at an isolation level other than UR and NC? Yes No No No No
Can "updated" rows be read by other application processes that are running at the UR or NC isolation level? Yes Yes Yes Yes Yes
Can "accessed" rows be updated by other application processes?

For RS, "accessed rows" typically means rows selected. For RR, see the product-specific documentation. See phenomenon P2 (nonrepeatable read) below.

Yes Yes Yes No No
Can "accessed" rows be read by other application processes? Yes Yes Yes Yes Yes
Can "current" row be updated or deleted by other application processes? See phenomenon P1 (dirty-read) below. See Note below See Note below See Note below No No
Note:
This depends on whether the cursor that is positioned on the "current" row is updatable:
  • If the cursor is updatable, the current row cannot be updated or deleted by other application processes
  • If the cursor is not updatable,
    • For UR or NC, the current row can be updated or deleted by other application processes.
    • For CS, the current row may be updatable in some circumstances.
Examples of Phenomena:
P1
Dirty Read. Unit of work UW1 modifies a row. Unit of work UW2 reads that row before UW1 performs a COMMIT. UW1 then performs a ROLLBACK. UW2 has read a nonexistent row.
P2
Nonrepeatable Read. Unit of work UW1 reads a row. Unit of work UW2 modifies that row and performs a COMMIT. UW1 then re-reads the row and obtains the modified data value.
P3
Phantom. Unit of work UW1 reads the set of n rows that satisfies some search condition. Unit of work UW2 then INSERTs one or more rows that satisfies the search condition. UW1 then repeats the initial read with the same search condition and obtains the original rows plus the inserted rows.

5.
For WITH HOLD cursors, these rules apply to when the rows were actually read. For read-only WITH HOLD cursors, the rows may have actually been read in a prior unit of work.



[ Top of Page | Previous Page | Next Page | Contents | Index ]