Transactions
A transaction is the logical unit of work when performing database operations. A transaction is created by grouping a sequence of one or more DML statements into a single, all-or-nothing proposition with the following characteristics.
AtomicityAll statements must complete successfully or the entire set is aborted.
ConsistencyThe statements' net effect is to leave the database in a consistent state.
IsolationIntermediate statements should not be visible to other transactions.
DurabilityWhen the transaction is complete, the changes are made permanent.
These four characteristics of a transaction are often abbreviated ACID. To ensure the consistency of the data, we need to identify the boundaries of a transaction and the SQL statements it comprises. Oracle then does the rest of the work necessary for ensuring that the transaction passes the ACID test.
The environment in which we are executing SQL, whether it's SQL*Plus, SQLJ, or JDBC, normally allows us to execute our statements in one of two modes, manual commit or auto-commit. In auto-commit mode, changes made to the database with DML statements are immediately made permanent in the database and are immediately visible to other transactions. In other words, transactions can include only a single SQL DML statement. In this case, Oracle ensures that the transaction meets the ACID requirements.
In manual commit mode, Oracle provides isolation and durability. Changes made to the database with DML are not visible to other transactions and are made permanent only once the transaction has been successfully completed. We take responsibility for atomicity and consistency. We determine what set of DML statements we want to group as an atomic set, and we perform any intermediate validation or error checking that might be necessary.
We group DML statements by marking the boundaries of the transactionthe beginning and the end. Oracle has no statement to mark the start of a transaction explicitly; a transaction begins either at the start of a session (or connection) or after the previous transaction has ended by being committed or cancelled. There are two statements used to mark the end of a transaction:
COMMITSave the results of the transactions permanently in the database.
ROLLBACKAbort the transaction and return the database to its state at the beginning of the transaction.
In addition, DDL statements, such as CREATE TABLE, ALTER TABLE, and DROP TABLE, have an implied COMMIT.
A Transaction: All or Nothing
SQL*Plus, like other interfaces to Oracle, has an auto-commit feature. When this feature is enabled, every SQL statement is automatically committed as it is entered. By default, auto-commit is off in SQL*Plus, so we can manually control a transaction by entering a sequence of SQL statements, then decide at the end whether to call COMMIT or ROLLBACK.
In other interfaces, we need to be aware of the default and change it if necessary to support transaction processing. In SQLJ, auto-commit is off by default. In JDBC, it is on by default, meaning that each SQL statement we send to the database is committed automatically; this is less efficient and less flexible than auto-commit.
Suppose that we are adding a CD to our CD collection by typing SQL statements directly into SQL*Plus. We need to update two tablesthe CD_COLLECTION table, which contains information about the CD as a whole, and the SONGS table, which contains information for all the songs. We don't want to have incomplete information available in the database, so we'll consider the SQL statement that inserts the CD information and the SQL statements that insert each of the songs into the database as a single transaction.
Assuming that the session just started or that we have just called either COMMIT or ROLLBACK for the previous transaction, we are ready to begin a new transaction:
INSERT INTO CD_COLLECTION (CD_ID, ARTIST, ALBUM_TITLE, RELEASE_DATE, COUNTRY, LABEL) VALUES (100, 'PJ Harvey','Rid of Me','1-JAN-1993','UK','Island'); INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) (1,100, 'Rid of Me','Harvey',1); INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) VALUES (2, 100, 'Missed','Harvey', 2); INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) VALUES (NULL, 100, 'Missed','Harvey', 3);
Suppose that, at this point, we realize it is far too tedious to enter each song manually and decide we'll write a script to do this, instead. We can undo all that we've done so far by typing ROLLBACK. All of the records that we entered up until that point in this session will be removed from the database.
If, on the other hand, we decide we'll just pick up from here later, either with a script or manually, we would commit the transaction so far by entering:
COMMIT;
Up until the time we enter the COMMIT statement, the records we enter into SQL*Plus are not visible in other users' sessions. We can stop partway through, for example, and query the database, and we will see any records we have entered into the CD_COLLECTION table or the SONGS table. But nobody else can see the new records. You can verify this by opening another SQL*Plus session and querying the databases in the second session. You will find that until you type COMMIT in the first, you will not see the updates in the second.
Partial Rollbacks
In addition to allowing us to commit or roll back a group of SQL statements as a whole, Oracle also allows us to mark intermediate points to allow a partial rollback. The commands to do this are:
SAVEPOINT savepoint_nameNames a point to which we can selectively roll back a transaction.
ROLLBACK TO savepoint_nameRolls back a transaction to previously named SAVEPOINT.
This is not as generally useful as the basic COMMIT/ROLLBACK arrangement, but it allows creating a more sophisticated scheme for recovering from a partial failure while processing a transaction.
For example, suppose that we have an application with a user interface that allows a user to enter the information for a CD. Suppose we will allow the users to enter just the general CD information or the general information and all the songs. Now suppose that a user tries to enter information and songs, but an error occurs while inserting the songs. We can prompt the user with three choices:
Save just the general CD information.
Try to pick up where the error occurred.
Abandon the entire transaction.
We won't present the application code here to support this logic, but here is a sequence of SQL statements that could cause an error like thisnotice NULL in the third INSERT into the SONGS table:
INSERT INTO CD_COLLECTION (CD_ID, ARTIST, ALBUM_TITLE, RELEASE_DATE, COUNTRY, LABEL) VALUES (100, 'PJ Harvey','Rid of Me','1-JAN-1993','UK','Island'); SAVEPOINT CD_INFO; INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) (1,100, 'Rid of Me','Harvey',1); SAVEPOINT SONG_1; INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) VALUES (2, 100, 'Missed','Harvey', 2); SAVEPOINT SONG_2; INSERT INTO SONGS (SONG_ID, CD_ID, SONG_TITLE, COMPOSER, TRACK) VALUES (NULL, 100, 'Missed','Harvey', 3); SAVEPOINT SONG_3;
Because the third insert is missing its primary key, this causes an error. At this point, if the user chose option 1, to save just the CD information, we would perform a partial rollback and commit:
/* Save just CD information */ ROLLBACK TO CD_INFO; COMMIT;
If the user chose instead to pick up from where the error occurred, we could roll back to SONG_2, the last successful insert, and let the user start again from there:
/* Start again just before first error */ ROLLBACK TO SONG_2; /* Continue inserting more songs ? */
If the user chose to abandon the entire transaction, we would use an unqualified ROLLBACK, which returns the database to its state prior to starting the transaction:
/* Abandon transaction entirely */ ROLLBACK;
Partial rollbacks should be approached cautiously. It is easy to create complicated scenarios that can be hard to manage and which can leave the application in an invalid or undetermined state from which it is impossible to recover.