- Understanding Transaction Processing
- Controlling Transactions
- Summary
Controlling Transactions
Now that you know what transactions processing is, let's look at what is involved in managing transactions.
CAUTION
Implementation Differences The exact syntax used to implement transaction processing differs from one DBMS to another. Refer to your DBMS documentation before proceeding.
The key to managing transactions involves breaking your SQL statements into logical chunks and explicitly stating when data should be rolled back and when it should not.
Some DBMSs require that you explicitly mark the start and end of transaction blocks. In SQL Server, for example, you can do the following:
BEGIN TRANSACTION ... COMMIT TRANSACTION
In this example, any SQL between the BEGIN TRANSACTION and COMMIT TRANSACTION statements must be executed entirely or not at all.
The equivalent code in MySQL is:
START TRANSACTION ...
PostgreSQL uses the ANSI SQL syntax:
BEGIN; ...
Other DBMSs use variations of the above.
Using ROLLBACK
The SQL ROLLBACK command is used to roll back (undo) SQL statements, as seen in this next statement:
DELETE FROM Orders; ROLLBACK;
In this example, a DELETE operation is performed and then undone using a ROLLBACK statement. Although not the most useful example, it does demonstrate that, within a transaction block, DELETE operations (like INSERT and UPDATE operations) are never final.
Using COMMIT
Usually SQL statements are executed and written directly to the database tables. This is known as an implicit committhe commit (write or save) operation happens automatically.
Within a transaction block, however, commits might not occur implicitly. This, too, is DBMS specific. Some DBMSs treat a transaction end as an implicit commit; others do not.
To force an explicit commit, the COMMIT statement is used. The following is a SQL Server example:
BEGIN TRANSACTION DELETE OrderItems WHERE order_num = 12345 DELETE Orders WHERE order_num = 12345 COMMIT TRANSACTION
In this SQL Server example, order number 12345 is deleted entirely from the system. Because this involves updating two database tables, Orders and OrderItems, a transaction block is used to ensure that the order is not partially deleted. The final COMMIT statement writes the change only if no error occurred. If the first DELETE worked, but the second failed, the DELETE would not be committed.
To accomplish the same thing in Oracle, you can do the following:
DELETE OrderItems WHERE order_num = 12345; DELETE Orders WHERE order_num = 12345; COMMIT;
Using Savepoints
Simple ROLLBACK and COMMIT statements enable you to write or undo an entire transaction. Although this works for simple transactions, more complex transactions might require partial commits or rollbacks.
For example, the process of adding an order described previously is a single transaction. If an error occurs, you only want to roll back to the point before the Orders row was added. You do not want to roll back the addition to the Customers table (if there was one).
To support the rollback of partial transactions, you must be able to put placeholders at strategic locations in the transaction block. Then, if a rollback is required, you can roll back to one of the placeholders.
In SQL, these placeholders are called savepoints. To create one in MySQL and Oracle, the SAVEPOINT statement is used, as follows:
SAVEPOINT delete1;
In SQL Server and Sybase, you do the following:
SAVE TRANSACTION delete1;
Each savepoint takes a unique name that identifies it so that, when you roll back, the DBMS knows where you are rolling back to. To roll back to this savepoint, do the following in SQL Server:
ROLLBACK TRANSACTION delete1;
In MySQL and Oracle you can do the following:
ROLLBACK TO delete1;
The following is a complete SQL Server example:
BEGIN TRANSACTION INSERT INTO Customers(cust_id, cust_name) VALUES('1000000010', 'Toys Emporium'); SAVE TRANSACTION StartOrder; INSERT INTO Orders(order_num, order_date, cust_id) VALUES(20100,'2001/12/1','1000000010'); IF @@ERROR <> 0 ROLLBACK TRANSACTION StartOrder; INSERT INTO OrderItems(order_num, order_item,
prod_id, quantity, item_price) VALUES(20010, 1, 'BR01', 100, 5.49); IF @@ERROR <> 0 ROLLBACK TRANSACTION StartOrder; INSERT INTO OrderItems(order_num, order_item,
prod_id, quantity, item_price) VALUES(20010, 2, 'BR03', 100, 10.99); IF @@ERROR <> 0 ROLLBACK TRANSACTION StartOrder; COMMIT TRANSACTION
Here are a set of four INSERT statements enclosed within a transaction block. A savepoint is defined after the first INSERT so that, if any of the subsequent INSERT operations fail, the transaction is only rolled back that far. In SQL Server, a variable named @@ERROR can be inspected to see if an operation succeeded. (Other DBMSs use different functions or variables to return this information.) If @@ERROR returns a value other than 0, an error occurred, and the transaction rolls back to the savepoint. If the entire transaction is processed, a COMMIT is issued to save the data.
TIP
The More Savepoints the Better You can have as many savepoints as you'd like within your SQL code, and the more the better. Why? Because the more savepoints you have the more flexibility you have in managing rollbacks exactly as you need them.