Oracle8 Application Developer's Guide Release 8.0 A58241-01 |
|
This chapter describes how Oracle processes Structured Query Language (SQL) statements. Topics include the following:
Although some Oracle tools and applications simplify or mask the use of SQL, all database operations are performed using SQL. Any other data access method would circumvent the security built into Oracle and potentially compromise data security and integrity.
Figure 3-1 outlines the stages commonly used to process and execute a SQL statement. In some cases, these steps might be executed in a slightly different order. For example, the DEFINE
stage could occur just before the FETCH
stage, depending on how your code is written.
For many Oracle tools, several of the stages are performed automatically. Most users need not be concerned with or aware of this level of detail. However, you might find this information useful when writing Oracle applications. Refer to Oracle8 Concepts for a description of each stage of SQL statement processing for each type of SQL statement.
The Federal Information Processing Standard for SQL (FIPS 127-2) requires a way to identify SQL statements that use vendor-supplied extensions. Oracle provides a FIPS flagger to help you write portable applications.
When FIPS flagging is active, your SQL statements are checked to see whether they include extensions that go beyond the ANSI/ISO SQL92 standard. If any non-standard constructs are found, the Oracle Server flags them as errors and displays the violating syntax.
The FIPS flagging feature supports flagging through interactive SQL statements submitted using Enterprise Manager or SQL*Plus. The Oracle Precompilers and SQL*Module also support FIPS flagging of embedded and module language SQL.
When flagging is on and non-standard SQL is encountered, the message returned is
ORA-00097: Use of Oracle SQL feature not in SQL92 level Level
where level can be either ENTRY, INTERMEDIATE,
or FULL
.
In general, only application designers using the programming interfaces to Oracle are concerned with which types of actions should be grouped together as one transaction. Transactions must be defined properly so work is accomplished in logical units and data is kept consistent. A transaction should consist of all of the necessary parts for one logical unit of work, no more and no less. Data in all referenced tables should be in a consistent state before the transaction begins and after it ends. Transactions should consist of only the SQL statements or PL/SQL blocks that comprise one consistent change to the data.
A transfer of funds between two accounts (the transaction or logical unit of work), for example, should include the debit to one account (one SQL statement) and the credit to another account (one SQL statement). Both actions should either fail or succeed together as a unit of work; the credit should not be committed without the debit. Other non-related actions, such as a new deposit to one account, should not be included in the transfer of funds transaction.
In addition to determining which types of actions form a transaction, when you design an application you must also determine if you can take any additional measures to improve performance. You should consider the following performance enhancements when designing and writing your application. Unless otherwise noted, each of these features is described in Oracle8 Tuning.
BEGIN_DISCRETE_TRANSACTION
procedure to improve the performance of short, non-distributed transactions.
SET TRANSACTION
command with the USE ROLLBACK SEGMENT
parameter to explicitly assign a transaction to an appropriate rollback segment. This can eliminate the need to dynamically allocate additional extents, which can reduce overall system performance.
SET TRANSACTION
command with the ISOLATION LEVEL
set to SERIALIZABLE
to get ANSI/ISO
serializable transactions.
ANALYZE
command to collect statistics that can be used by Oracle to implement a cost-based approach to SQL statement optimization. You can supply additional "hints" to the optimizer as needed.
DBMS_APPLICATION_INFO.SET_ACTION
procedure before beginning a transaction to register and name a transaction for later use when measuring performance across an application. You should specify what type of activity a transaction performs so that the system tuners can later see which transactions are taking up the most system resources.
MAX_OPEN_CURSORS
can often reduce the frequency of parsing and improve performance. The use of cursors is described on page 3-9 of this Guide.
To commit a transaction, use the COMMIT command. The following two statements are equivalent and commit the current transaction:
COMMIT WORK; COMMIT;
The COMMIT
command allows you to include the COMMENT
parameter along with a Comment (less than 50 characters) that provides information about the transaction being committed. This option is useful for including information about the origin of the transaction when you commit distributed transactions:
COMMIT COMMENT 'Dallas/Accts_pay/Trans_type 10B';
For additional information about committing in-doubt distributed transactions, see Oracle8 Distributed Database Systems.
To roll back an entire transaction or a part of a transaction (that is, to a savepoint), use the ROLLBACK
command. For example, either of the following statements rolls back the entire current transaction:
ROLLBACK WORK; ROLLBACK;
The WORK
option of the ROLLBACK
command has no function.
To roll back to a savepoint defined in the current transaction, the TO
option of the ROLLBACK
command must be used. For example, either of the following statements rolls back the current transaction to the savepoint named POINT1
:
ROLLBACK TO SAVEPOINT point1; ROLLBACK TO point1;
For additional information about rolling back in-doubt distributed transactions
To define a savepoint in a transaction, use the SAVEPOINT command. The following statement creates the savepoint named ADD_EMP1 in the current transaction:
SAVEPOINT add_emp1;
If you create a second savepoint with the same identifier as an earlier savepoint, the earlier savepoint is erased. After a savepoint has been created, you can roll back to the savepoint.
There is no limit on the number of active savepoints per session. An active savepoint is one that has been specified since the last commit or rollback.
The following series of SQL statements illustrates the use of COMMIT, SAVEPOINT, and ROLLBACK statements within a transaction:
No privileges are required to control your own transactions; any user can issue a COMMIT
, ROLLBACK
, or SAVEPOINT
statement within a transaction.
By default, the consistency model for Oracle guarantees statement-level read consistency, but does not guarantee transaction-level read consistency (repeatable reads). If you want transaction-level read consistency and your transaction does not require updates, you can specify a read-only transaction. After indicating that your transaction is read-only, you can execute as many queries as you like against any database table, knowing that the results of each query in the read-only transaction are consistent with respect to a single point in time.
A read-only transaction does not acquire any additional data locks to provide transaction-level read consistency. The multi-version consistency model used for statement-level read consistency is used to provide transaction-level read consistency; all queries return information with respect to the system control number (SCN) determined when the read-only transaction begins. Because no data locks are acquired, other transactions can query and update data being queried concurrently by a read-only transaction.
Changed data blocks queried by a read-only transaction are reconstructed using data from rollback segments. Therefore, long running read-only transactions sometimes receive a "snapshot too old" error (ORA-01555). Create more, or larger, rollback segments to avoid this. Alternatively, you could issue long-running queries when online transaction processing is at a minimum, or you could obtain a shared lock on the table you were querying, prohibiting any other modifications during the transaction.
A read-only transaction is started with a SET TRANSACTION
statement that includes the READ ONLY
option. For example:
SET TRANSACTION READ ONLY;
The SET TRANSACTION
statement must be the first statement of a new transaction; if any DML statements (including queries) or other non-DDL statements (such as SET ROLE
) precede a SET TRANSACTION READ ONLY
statement, an error is returned. Once a SET TRANSACTION READ ONLY
statement successfully executes, only SELECT
(without a FOR UPDATE
clause), COMMIT, ROLLBACK
, or non-DML statements (such as SET ROLE, ALTER SYSTEM, LOCK TABLE
) are allowed in the transaction. Otherwise, an error is returned. A COMMIT, ROLLBACK
, or DDL statement terminates the read-only transaction (a DDL statement causes an implicit commit of the read-only transaction and commits in its own transaction).
PL/SQL implicitly declares a cursor for all SQL data manipulation statements, including queries that return only one row. For queries that return more than one row, you can explicitly declare a cursor to process the rows individually.
A cursor is a handle to a specific private SQL area. In other words, a cursor can be thought of as a name for a specific private SQL area. A PL/SQL cursor variable enables the retrieval of multiple rows from a stored procedure. Cursor variables allow you to pass cursors as parameters in your 3GL application. Cursor variables are described in PL/SQL User's Guide and Reference.
Although most Oracle users rely on the automatic cursor handling of the Oracle utilities, the programmatic interfaces offer application designers more control over cursors. In application development, a cursor is a named resource available to a program, which can be specifically used for parsing SQL statements embedded within the application.
There is no absolute limit to the total number of cursors one session can have open at one time, subject to two constraints:
OPEN_CURSORS
found in the parameter file (such as INIT.ORA). Parameters are described in Oracle8 Reference.
Explicitly creating cursors for precompiler programs can offer some advantages in tuning those applications. For example, increasing the number of cursors can often reduce the frequency of parsing and improve performance. If you know how many cursors may be required at a given time, you can make sure you can open that many simultaneously.
After each stage of execution, the cursor retains enough information about the SQL statement to re-execute the statement without starting over, as long as no other SQL statement has been associated with that cursor. This is illustrated in Figure on page 3-3. Notice that the statement can be re-executed without including the parse stage.
By opening several cursors, the parsed representation of several SQL statements can be saved. Repeated execution of the same SQL statements can thus begin at the describe, define, bind, or execute step, saving the repeated cost of opening cursors and parsing.
Closing a cursor means that the information currently in the associated private area is lost and its memory is deallocated. Once a cursor is opened, it is not closed until one of the following events occurs:
Cancelling a cursor frees resources from the current fetch.The information currently in the associated private area is lost but the cursor remains open, parsed, and associated with its bind variables.
See Also:
For more information about cancelling cursors, see Oracle Call Interface Programmer's Guide. |
Oracle always performs necessary locking to ensure data concurrency, integrity, and statement-level read consistency. However, options are available to override the default locking mechanisms. Situations where it would be advantageous to override the default locking of Oracle include the following:
The automatic locking mechanisms can be overridden at two different levels:
The following sections describe each option available for overriding the default locking of Oracle. The initialization parameter DML_LOCKS
determines the maximum number of DML locks allowed (see the Oracle8 Reference for a discussion of parameters). The default value should be sufficient; however, if you are using additional manual locks, you may need to increase this value.
A transaction explicitly acquires the specified table locks when a LOCK TABLE
statement is executed. A LOCK TABLE
statement manually overrides default locking. When a LOCK TABLE
statement is issued on a view, the underlying base tables are locked. The following statement acquires exclusive table locks for the EMP
and DEPT
tables on behalf of the containing transaction:
LOCK TABLE emp, dept IN EXCLUSIVE MODE NOWAIT;
You can specify several tables or views to lock in the same mode; however, only a single lock mode can be specified per LOCK TABLE
statement.
You can also indicate if you do or do not want to wait to acquire the lock. If you specify the NOWAIT
option, you only acquire the table lock if it is immediately available. Otherwise an error is returned to notify that the lock is not available at this time. In this case, you can attempt to lock the resource at a later time. If NOWAIT
is omitted, the transaction does not proceed until the requested table lock is acquired. If the wait for a table lock is excessive, you might want to cancel the lock operation and retry at a later time; you can code this logic into your applications.
Note:
A distributed transaction waiting for a table lock can timeout waiting for the requested lock if the elapsed amount of time reaches the interval set by the initialization parameter |
The following paragraphs provide guidance on when it can be advantageous to acquire each type of table lock using the LOCK TABLE command.
LOCK TABLE table IN ROW SHARE MODE; LOCK TABLE table IN ROW EXCLUSIVE MODE;
Row share and row exclusive table locks offer the highest degree of concurrency. Conditions that possibly warrant the explicit acquisition of a row share or row exclusive table lock include the following:
LOCK TABLE table IN SHARE MODE;
Share table locks are rather restrictive data locks. The following conditions could warrant the explicit acquisition of a share table lock:
For example, assume that two tables, EMP
and BUDGET
, require a consistent set of data in a third table, DEPT
. That is, for a given department number, you want to update the information in both of these tables, and ensure that no new members are added to the department between these two transactions.
Although this scenario is quite rare, it can be accommodated by locking the DEPT
table in SHARE MODE
, as shown in the following example. Because the DEPT
table is not highly volatile, few, if any, users would need to update it while it was locked for the updates to EMP
and BUDGET
.
LOCK TABLE dept IN SHARE MODE UPDATE EMP SET sal = sal * 1.1 WHERE deptno IN (SELECT deptno FROM dept WHERE loc = 'DALLAS') UPDATE budget SET totsal = totsal * 1.1 WHERE deptno IN (SELECT deptno FROM dept WHERE loc = 'DALLAS') COMMIT /* This releases the lock */
LOCK TABLE table IN SHARE ROW EXCLUSIVE MODE;
Conditions that warrant the explicit acquisition of a share row exclusive table lock include the following:
FOR UPDATE
) by other transactions, which may or may not make UPDATE
and INSERT
statements in the locking transaction wait to update the table (that is, deadlocks might be observed).
LOCK TABLE table IN EXCLUSIVE MODE;
Conditions that warrant the explicit acquisition of an exclusive table lock include the following:
You can automatically acquire any type of table lock on tables in your schema; however, to acquire a table lock on a table in another schema, you must have the LOCK
ANY TABLE
system privilege or any object privilege (for example, SELECT
or UPDATE
) for the table.
You can override default locking with a SELECT
statement that includes the FOR
UPDATE
clause. SELECT... FOR UPDAT
E is used to acquire exclusive row locks for selected rows (as an UPDATE statement does) in anticipation of actually updating the selected rows.
You can use a SELECT... FOR UPDATE
statement to lock a row without actually changing it. For example, several triggers in Chapter 13, "Using Database Triggers", show how to implement referential integrity. In the EMP_DEPT_CHECK
trigger (see page 13-29), the row that contains the referenced parent key value is locked to guarantee that it remains for the duration of the transaction; if the parent key is updated or deleted, referential integrity would be violated.
SELECT... FOR UPDATE
statements are often used by interactive programs that allow a user to modify fields of one or more specific rows (which might take some time); row locks on the rows are acquired so that only a single interactive program user is updating the rows at any given time.
If a SELECT... FOR UPDATE
statement is used when defining a cursor, the rows in the return set are locked before the first fetch, when the cursor is opened; rows are not individually locked as they are fetched from the cursor. Locks are only released when the transaction that opened the cursor is committed or rolled back; locks are not released when a cursor is closed.
Each row in the return set of a SELECT... FOR UPDATE
statement is locked individually; the SELECT... FOR UPDATE
statement waits until the other transaction releases the conflicting row lock. Therefore, if a SELECT... FOR UPDATE
statement locks many rows in a table and the table experiences reasonable update activity, it would most likely improve performance if you instead acquired an exclusive table lock.
When acquiring row locks with SELECT... FOR UPDATE
, you can indicate if you do or do not want to wait to acquire the lock. If you specify the NOWAIT
option, you only acquire the row lock if it is immediately possible. Otherwise, an error is returned to notify you that the lock is not possible at this time. In this case, you can attempt to lock the row later. If NOWAIT
is omitted, the transaction does not proceed until the requested row lock is acquired. If the wait for a row lock is excessive, users might want to cancel the lock operation and retry later; you can code such logic into your applications.
As described on page 3-11, a distributed transaction waiting for a row lock can timeout waiting for the requested lock if the elapsed amount of time reaches the interval set by the initialization parameter DISTRIBUTED_LOCK_TIMEOUT.
Two factors determine how an instance handles locking: the SERIALIZABLE
option of the SET TRANSACTION
or ALTER SESSION
command and the ROW_LOCKING
initialization parameter. By default, SERIALIZABLE
is set to FALSE
and ROW_LOCKING
is set to ALWAYS
.
In almost every case, these parameters should not be altered. They are provided for sites that must run in ANSI/ISO compatible mode, or that want to use applications written to run with earlier versions of Oracle. Only these sites should consider altering these parameters, as there is a significant performance degradation caused by using other than the defaults.
The settings for these parameters should be changed only when an instance is shut down. If multiple instances are accessing a single database, all instances should use the same setting for these parameters.
Three combinations of settings for SERIALIZABLE
and ROW_LOCKING
, other than the default settings, are available to change the way locking occurs for transactions. Table 3-1 summarizes the non-default settings and why you might choose to execute your transactions in a non-default way.
Table 3-2 illustrates the difference in locking behavior resulting from the three possible settings of the SERIALIZABLE
option and ROW_LOCKING
initialization parameter, as shown in Table 3-1.
You can use Oracle Lock Management services for your applications. It is possible to request a lock of a specific mode, give it a unique name recognizable in another procedure in the same or another instance, change the lock mode, and release it. Because a reserved user lock is the same as an Oracle lock, it has all the functionality of an Oracle lock, such as deadlock detection. Be certain that any user locks used in distributed transactions are released upon COMMIT, or an undetected deadlock may occur.
The Oracle Lock Management services are available through procedures in the DBMS_LOCK
package. Table 3-3Summarizes the procedures available in the DBMS_LOCK
package.
User locks never conflict with Oracle locks because they are identified with the prefix "UL". You can view these locks using the Enterprise Manager lock monitor screen or the appropriate fixed views.
User locks are automatically released when a session terminates.
There might be operating system-specific limits on the maximum number of total locks available. This must be considered when using locks or making this package available to other users. Consider granting the EXECUTE
privilege only to specific users or roles.
A better alternative would be to create a cover package limiting the number of locks used and grant EXECUTE
privilege to specific users. An example of a cover package is documented in the DBMSLOCK.SQL
package specification file.
To create the DBMS_LOCK
package, submit the DBMSLOCK.SQL
and PRVTLOCK
.PLB
scripts when connected as the user SYS
. These scripts are run automatically by the CATPROC.SQL
script.
See Also:
See page 10-62 for information on granting the necessary privileges to users who will be executing this package. |
Lock identifiers are used to allow applications to coordinate their use of locks. User-assigned lock identifiers can be a number in the range of 0 to 1073741823, or locks can be identified by name. If you choose to identify locks by name, you can use ALLOCATE_UNIQUE
to generate a unique lock identification number for these named locks.
The parameters for the ALLOCATE_UNIQUE
procedure are described in Table 3-4. The syntax for this procedure is shown below.
DBMS_LOCK.ALLOCATE_UNIQUE(lockname IN VARCHAR2, lockhandle OUT VARCHAR2, expiration_secs IN INTEGER DEFAULT 864000);
To request a lock with a given mode, use the REQUEST
function. REQUEST
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
The parameters for the REQUEST function are described in Table 3-5 and the possible return values and their meanings are described in Table 3-6. The syntax for this function is shown below.
DBMS_LOCK.REQUEST(id IN INTEGER || lockhandle IN VARCHAR2, lockmode IN INTEGER DEFAULT X_MODE, timeout IN INTEGER DEFAULT MAXWAIT, release_on_commit IN BOOLEAN DEFAULT FALSE, RETURN INTEGER;
The default values, such as X_MODE and MAXWAIT, are defined in the DBMS_LOCK package specification. See the package specification, available on-line, for the current default values.
Parameter | Description |
---|---|
ID or LOCKHANDLE |
Specify the user assigned lock identifier, from 0 to 1073741823, or the lock handle, returned by |
LOCKMODE |
Specify the mode that you are requesting for the lock. The available modes and their associated integer identifiers are listed below. The abbreviations for these locks, as they appear in the V$ views and Enterprise Manager monitors are shown in parentheses.
5 - share row exclusive mode ( Each of these lock modes is explained in Oracle8 Concepts. |
TIMEOUT |
Specify the number of seconds to continue trying to grant the lock. If the lock cannot be granted within this time period, the call returns a value of 1 (timeout). |
RELEASE_ON_COMMIT |
Set this parameter to |
Return Value | Description |
---|---|
0 | success |
1 | timeout |
2 | deadlock |
3 | parameter error |
4 | already own lock specified by ID or LOCKHANDLE |
5 | illegal lock handle |
To convert a lock from one mode to another, use the CONVERT
function. CONVERT
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
The parameters for the CONVERT function are described in Table 3-7 and the possible return values and their meanings are described in Table 3-8. The syntax for this function is shown below.
DBMS_LOCK.CONVERT( id IN INTEGER || lockhandle IN VARCHAR2, lockmode IN INTEGER, timeout IN NUMBER DEFAULT MAXWAIT) RETURN INTEGER;
Table 3-7 DBMS_LOCK.CONVERT Function Parameters
Parameter
Description
ID
or
LOCKHANDLE
Specify the user assigned lock identifier, from 0 to 1073741823, or the lock handle, returned by ALLOCATE_UNIQUE
, of the lock whose mode you want to change.
LOCKMODE
Specify the new mode that you want to assign to the given lock. The available modes and their associated integer identifiers are listed below. The abbreviations for these locks, as they appear in the V$ views and Enterprise Manager monitors are shown in parentheses.
5 - share row exclusive mode (ULRSX
)
Each of these lock modes is explained in Oracle8 Concepts.
TIMEOUT
Specify the number of seconds to continue trying to change the lock mode. If the lock cannot be converted within this time period, the call returns a value of 1 (timeout).
Table 3-8 DBMS_LOCK.CONVERT Function Return Values
Return Value
Description
0
success
1
timeout
2
deadlock
3
parameter error
4
don't own lock specified by ID
or LOCKHANDLE
5
illegal lock handle
To explicitly release a lock previously acquired using the REQUEST
function, use the RELEASE
function. Locks are automatically released at the end of a session. RELEASE
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
The parameters for the RELEASE function are described in Table 3-9 and the possible return values and their meanings are described in Table 3-10. The syntax for this function is shown below.
DBMS_LOCK.RELEASE(id IN INTEGER) RETURN INTEGER; DBMS_LOCK.RELEASE(lockhandle IN VARCHAR2) RETURN INTEGER;
Table 3-9 DBMS_LOCK.RELEASE Function Parameter
Parameter
Description
ID
or
LOCKHANDLE
Specify the user-assigned lock identifier, from 0 to 1073741823, or the lock handle, returned by ALLOCATE_UNIQUE
, of the lock that you want to release.
Table 3-10 DBMS_LOCK.RELEASE Function Return Values
Return Value
Description
0
success
3
parameter error
4
do not own lock specified by ID
or LOCKHANDLE
5
illegal lock handle
To suspend the session for a given period of time, use the SLEEP
procedure.
The parameters for the SLEEP
procedure are described in Table 3-11. The syntax for the SLEEP
procedure is shown below.
DBMS_LOCK.SLEEP(seconds IN NUMBER);
Table 3-11 DBMS_LOCK.SLEEP Procedure Parameters
Parameter
Description
SECONDS
Specify the amount of time, in seconds, to suspend the session. The smallest increment can be entered in hundredths of a second; for example, 1.95 is a legal time value.
Some uses of user locks are:
The following Pro*COBOL precompiler example shows how locks can be used to ensure that there are no conflicts when multiple people need to access a single device.
***************************************************************** * Print Check * * Any cashier may issue a refund to a customer returning goods. * * Refunds under $50 are given in cash, above that by check. * * This code prints the check. The one printer is opened by all * * the cashiers to avoid the overhead of opening and closing it * * for every check. This means that lines of output from multiple* * cashiers could become interleaved if we don't ensure exclusive* * access to the printer. The DBMS_LOCK package is used to * * ensure exclusive access. * ***************************************************************** CHECK-PRINT * * Get the lock "handle" for the printer lock. MOVE "CHECKPRINT" TO LOCKNAME-ARR. MOVE 10 TO LOCKNAME-LEN. EXEC SQL EXECUTE BEGIN DBMS_LOCK.ALLOCATE_UNIQUE ( :LOCKNAME, :LOCKHANDLE ); END; END-EXEC. * * Lock the printer in exclusive mode (default mode). EXEC SQL EXECUTE BEGIN DBMS_LOCK.REQUEST ( :LOCKHANDLE ); END; END-EXEC. * We now have exclusive use of the printer, print the check. ... * * Unlock the printer so other people can use it * EXEC SQL EXECUTE BEGIN DBMS_LOCK.RELEASE ( :LOCKHANDLE ); END; END-EXEC.
Oracle provides two facilities to display locking information for ongoing transactions within an instance
:
Enterprise Manager Monitors (Lock and Latch Monitors) |
The Monitor feature of Enterprise Manager provides two monitors for displaying lock information of an instance. Refer to Oracle Server Manager User's Guide for complete information about the Enterprise Manager monitors. |
|
The |
By default, the Oracle Server permits concurrently executing transactions to modify, add, or delete rows in the same table, and in the same data block. Changes made by one transaction are not seen by another concurrent transaction until the transaction that made the changes commits.
If a transaction (A) attempts to update or delete a row that has been locked by another transaction B (by way of a DML or SELECT... FOR UPDATE
statement), then A's DML command blocks until B commits or rolls back. Once B commits, transaction A can see changes that B has made to the database.
For most applications, this concurrency model is the appropriate one. In some cases, however, it is advantageous to allow transactions to be serializable. Serializable transactions must execute in such a way that they appear to be executing one at a time (serially), rather than concurrently. In other words, concurrent transactions executing in serialized mode are only permitted to make database changes that they could have made if the transactions were scheduled to run one after the other.
The ANSI/ISO SQL standard SQL92 defines three possible kinds of transaction interaction, and four levels of isolation that provide increasing protection against these interactions. These interactions and isolation levels are summarized in Table 3-12.
The behavior of Oracle with respect to these isolation levels is summarized below
.
|
Oracle never permits "dirty reads." This is not required for high throughput with Oracle. |
|
Oracle meets the READ COMMITTED isolation standard. This is the default mode for all Oracle applications. Note that since an Oracle query only sees data that was committed at the beginning of the query (the snapshot time), Oracle offers more consistency than actually required by the ANSI/ISO SQL92 standards for READ COMMITTED isolation. |
|
Oracle does not support this isolation level, except as provided by SERIALIZABLE. |
|
You can set this isolation level using the SET TRANSACTION command or the ALTER SESSION command, as described on page 3-31. |
Figure 3-2 shows how a serializable transaction (Transaction B) interacts with another transaction (A, which can be either SERIALIZABLE or READ COMMITTED).
When a serializable transaction fails with an ORA-08177 error ("cannot serialize access"), the application can take any of several actions:
Oracle stores control information in each data block to manage access by concurrent transactions. To use the SERIALIZABLE
isolation level, you must use the INITRANS
clause of the CREATE TABLE
or ALTER TABLE
command to set aside storage for this control information. To use serializable mode, INITRANS
must be set to at least 3.
You can change the isolation level of a transaction using the ISOLATION LEVEL
clause of the SET TRANSACTION
command. The SET TRANSACTION
command must be the first command issued in a transaction. If it is not, the following error is issued:
ORA-01453: SET TRANSACTION must be first statement of transaction
Use the ALTER SESSION
command to set the transaction isolation level on a session-wide basis.
See Also:
Oracle8 SQL Reference for the complete syntax of the |
Oracle stores control information in each data block to manage access by concurrent transactions. Therefore, if you set the transaction isolation level to serializable, you must use the ALTER TABLE
command to set INITRANS
to at least 3. This parameter will cause Oracle to allocate sufficient storage in each block to record the history of recent transactions that accessed the block. Higher values should be used for tables that will undergo many transactions updating the same blocks.
Because Oracle does not use read locks, even in SERIALIZABLE
transactions, data read by one transaction can be overwritten by another. Transactions that perform database consistency checks at the application level should not assume that the data they read will not change during the execution of the transaction (even though such changes are not visible to the transaction). Database inconsistencies can result unless such application-level consistency checks are coded carefully, even when using SERIALIZABLE
transactions. Note, however, that the examples shown in this section are applicable for both READ COMMITTED
and SERIALIZABLE
transactions.
Figure 3-3 two different transactions that perform application-level checks to maintain the referential integrity parent/child relationship between two tables. One transaction reads the parent table to determine that a row with a specific primary key value exists before inserting corresponding child rows. The other transaction checks to see that no corresponding detail rows exist before proceeding to delete a parent row. In this case, both transactions assume (but do not ensure) that data they read will not change before the transaction completes.
Note that the read issued by transaction A does not prevent transaction B from deleting the parent row. Likewise, transaction B's query for child rows does not prevent the insertion of child rows by transaction A. Therefore the above scenario leaves in the database a child row with no corresponding parent row. This result would occur even if both A and B are SERIALIZABLE
transactions, because neither transaction prevents the other from making changes in the data it reads to check consistency.
As this example illustrates, for some transactions, application developers must specifically ensure that the data read by one transaction is not concurrently written by another. This requires a greater degree of transaction isolation than defined by SQL92 SERIALIZABLE
mode.
Fortunately, it is straightforward in Oracle to prevent the anomaly described above. Transaction A can use SELECT FOR UPDATE
to query and lock the parent row and thereby prevent transaction B from deleting the row. Transaction B can prevent Transaction A from gaining access to the parent row by reversing the order of its processing steps. Transaction B first deletes the parent row, and then rolls back if its subsequent query detects the presence of corresponding rows in the child table.
Referential integrity can also be enforced in Oracle using database triggers, instead of a separate query as in Transaction A above. For example, an INSERT
into the child table can fire a PRE-INSERT
row-level trigger to check for the corresponding parent row. The trigger queries the parent table using SELECT FOR UPDATE
, ensuring that parent row (if it exists) will remain in the database for the duration of the transaction inserting the child row. If the corresponding parent row does not exist, the trigger rejects the insert of the child row.
SQL statements issued by a database trigger execute in the context of the SQL statement that caused the trigger to fire. All SQL statements executed within a trigger see the database in the same state as the triggering statement. Thus, in a READ COMMITTED
transaction, the SQL statements in a trigger see the database as of the beginning of the triggering statement's execution, and in a transaction executing in SERIALIZABLE
mode, the SQL statements see the database as of the beginning of the transaction. In either case, the use of SELECT FOR UPDATE
by the trigger will correctly enforce referential integrity as explained above.
Oracle gives the application developer a choice of two transaction isolation levels with different characteristics. Both the READ COMMITTED
and SERIALIZABLE
isolation levels provide a high degree of consistency and concurrency. Both levels provide the contention-reducing benefits of Oracle's "read consistency" multi-version concurrency control model and exclusive row-level locking implementation, and are designed for real-world application deployment. The rest of this section compares the two isolation modes and provides information helpful in choosing between them.
A useful way to describe the READ COMMITTED
and SERIALIZABLE
isolation levels in Oracle is to consider the following:
An operation (a query or a transaction) is "transaction set consistent" if all its reads return data written by the same set of committed transactions. In an operation that is not transaction set consistent, some reads reflect the changes of one set of transactions, and other reads reflect changes made by other transactions. An operation that is not transaction set consistent in effect sees the database in a state that reflects no single set of committed transactions.
Oracle provides transactions executing in READ COMMITTED
mode with transaction set consistency on a per-statement basis (since all rows read by a query must have been committed before the query began). Similarly, Oracle SERIALIZABLE
mode provides transaction set consistency on a per-transaction basis, since all statements in a SERIALIZABLE
transaction execute with respect to an image of the database as of the beginning of the transaction.
In other database systems (unlike in Oracle), a single query run in READ COMMITTED
mode provides results that are not transaction set consistent. The query is not transaction set consistent because it may see only a subset of the changes made by another transaction. This means, for example, that a join of a master table with a detail table could see a master record inserted by another transaction, but not the corresponding details inserted by that transaction, or vice versa. Oracle's READ
COMMITTED
mode will not experience this effect, and so provides a greater degree of consistency than read-locking systems.
In read-locking systems, at the cost of preventing concurrent updates, SQL92 REPEATABLE READ
isolation provides transaction set consistency at the statement level, but not at the transaction level. The absence of phantom protection means two queries issued by the same transaction can see data committed by different sets of other transactions. Only the throughput-limiting and deadlock-susceptible SERIALIZABLE
mode in these systems provides transaction set consistency at the transaction level.
Table 3-13 summarizes key similarities and differences between READ COMMITTED and SERIALIZABLE transactions.
Application designers and developers should choose an isolation level that is appropriate to the specific application and workload, and may choose different isolation levels for different transactions. The choice should be based on performance and consistency needs, and consideration of application coding requirements.
For environments with many concurrent users rapidly submitting transactions, designers must assess transaction performance requirements in terms of the expected transaction arrival rate and response time demands, and choose an isolation level that provides the required degree of consistency while satisfying performance expectations. Frequently, for high performance environments, the choice of isolation levels involves making a trade-off between consistency and concurrency (transaction throughput).
Both Oracle isolation modes provide high levels of consistency and concurrency (and performance) through the combination of row-level locking and Oracle's multi-version concurrency control system. Because readers and writers don't block one another in Oracle, while queries still see consistent data, both READ COMMITTED
and SERIALIZABLE
isolation provide a high level of concurrency for high performance, without the need for reading uncommitted ("dirty") data.
READ COMMITTED
isolation can provide considerably more concurrency with a somewhat increased risk of inconsistent results (due to phantoms and non-repeatable reads) for some transactions. The SERIALIZABLE
isolation level provides somewhat more consistency by protecting against phantoms and non-repeatable reads, and may be important where a read/write transaction executes a query more than once. However, SERIALIZABLE
mode requires applications to check for the "can't serialize access" error, and can significantly reduce throughput in an environment with many concurrent transactions accessing the same data for update. Application logic that checks database consistency must take into account the fact reads don't block writes in either mode.
When a transaction runs in serializable mode, any attempt to change data that was changed by another transaction since the beginning of the serializable transaction results in the following error:
ORA-08177: Can't serialize access for this transaction.
When you get an ORA-08177
error, the appropriate action is to roll back the current transaction, and re-execute it. After a rollback, the transaction acquires a new transaction snapshot, and the DML operation is likely to succeed.
Since a rollback and repeat of the transaction is required, it is good development practice to put DML statements that might conflict with other concurrent transactions towards the beginning of your transaction, whenever possible.