- 2.1. The Server SQL Mode
- 2.2. MySQL Identifier Syntax and Naming Rules
- 2.3. Case Sensitivity in SQL Statements
- 2.4. Character Set Support
- 2.5. Selecting, Creating, Dropping, and Altering Databases
- 2.6. Creating, Dropping, Indexing, and Altering Tables
- 2.7. Obtaining Database Metadata
- 2.8. Performing Multiple-Table Retrievals with Joins
- 2.9. Performing Multiple-Table Retrievals with Subqueries
- 2.10. Performing Multiple-Table Retrievals with UNION
- 2.11. Multiple-Table Deletes and Updates
- 2.12. Performing Transactions
- 2.13. Foreign Keys and Referential Integrity
- 2.14. Using FULLTEXT Searches
2.12. Performing Transactions
A transaction is a set of SQL statements that execute as a unit and can be canceled if necessary. Either all the statements execute successfully, or none of them have any effect. This is achieved through the use of commit and rollback capabilities. If all of the statements in the transaction succeed, you commit it to record their effects permanently in the database. If an error occurs during the transaction, you roll it back to cancel it. Any statements executed up to that point within the transaction are undone, leaving the database in the state it was in prior to the point at which the transaction began.
Commit and rollback provide the means to ensure that halfway-done operations don’t make their way into your database and leave it in a partially updated (inconsistent) state. The canonical example involves a financial transfer where money from one account is placed into another account. Suppose that Bill writes a check to Bob for $100.00 and Bob cashes the check. Bill’s account should be decremented by $100.00 and Bob’s account incremented by the same amount:
UPDATE account SET balance = balance - 100 WHERE name = 'Bill'; UPDATE account SET balance = balance + 100 WHERE name = 'Bob';
If a crash occurs between the two statements, the operation is incomplete. Depending on which statement executes first, Bill is $100 short without Bob having been credited, or Bob is given $100 without Bill having been debited. Neither outcome is correct. If transactional capabilities are not available, you must figure out the state of ongoing operations at crash time by examining your logs manually to determine how to undo them or complete them. The rollback capabilities of transaction support enable you to handle this situation properly by undoing the effect of the statements that executed before the error occurred. (You may still have to determine which transactions weren’t entered and re-issue them, but at least you don’t have to worry about half-transactions making your database inconsistent.)
Another use for transactions is to make sure that the rows involved in an operation are not modified by other clients while you’re working with them. MySQL automatically performs locking for single SQL statements to keep clients from interfering with each other, but this is not always sufficient to guarantee that a database operation achieves its intended result, because some operations are performed over the course of several statements. In this case, different clients might interfere with each other. A transaction groups statements into a single execution unit to prevent concurrency problems that could otherwise occur in a multiple-client environment.
Transactional systems typically are characterized as providing ACID properties. ACID is an acronym for Atomic, Consistent, Isolated, and Durable, referring to four properties transactions should have:
- Atomicity: The statements comprising a transaction form a logical unit. You can’t have just some of them execute.
- Consistency: The database is consistent before and after the transaction executes. For example, if rows in one table cannot have an ID that is not listed in another table, a transaction that attempts to insert a row with an invalid ID will fail and roll back.
- Isolation: One transaction has no effect on another, so that transactions executed concurrently have the same effect as if done one after the other.
- Durability: When a transaction executes successfully to completion, its effects are recorded permanently in the database.
Transactional processing provides stronger guarantees about the outcome of database operations, but also requires more overhead in CPU cycles, memory, and disk space. MySQL offers storage engines that are transaction-safe (such as InnoDB), and that are not transaction-safe (such as MyISAM and MEMORY). Transactional properties are essential for some applications and not for others, and you can choose which ones make the most sense for your applications. Financial operations typically need transactions, and the guarantees of data integrity outweigh the cost of additional overhead. On the other hand, for an application that logs web page accesses to a database table, a loss of a few rows if the server host crashes might be tolerable. In this case, using a nontransactional storage engine avoids the overhead required for transactional processing.
2.12.1. Using Transactions to Ensure Safe Statement Execution
Use of transactions requires a transactional storage engine such as InnoDB. Engines such as MyISAM and MEMORY will not work. If you’re not sure whether your MySQL server supports transactional storage engines, see Section 2.6.1.1, “Checking Which Storage Engines Are Available.”
By default, MySQL runs in autocommit mode, which means that changes made by individual statements are committed to the database immediately to make them permanent. In effect, each statement is its own transaction implicitly. To perform transactions explicitly, disable autocommit mode and then tell MySQL when to commit or roll back changes.
One way to perform a transaction is to issue a START TRANSACTION (or BEGIN) statement to suspend autocommit mode, execute the statements that make up the transaction, and end the transaction with a COMMIT statement to make the changes permanent. If an error occurs during the transaction, cancel it by issuing a ROLLBACK statement instead to undo the changes. START TRANSACTION suspends the current autocommit mode, so after the transaction has been committed or rolled back, the mode reverts to its state prior to the START TRANSACTION. If autocommit was enabled beforehand, ending the transaction puts you back in autocommit mode. If it was disabled, ending the current transaction causes you to begin the next one.
The following example illustrates this approach. First, create a table to use:
mysql> CREATE TABLE t (name CHAR(20), UNIQUE (name)) ENGINE=InnoDB;
Next, initiate a transaction with START TRANSACTION, add a couple of rows to the table, commit the transaction, and then see what the table looks like:
mysql> START TRANSACTION; mysql> INSERT INTO t SET name = 'William'; mysql> INSERT INTO t SET name = 'Wallace'; mysql> COMMIT; mysql> SELECT * FROM t; +---------+ | name | +---------+ | Wallace | | William | +---------+
You can see that the rows have been recorded in the table. If you had started up a second instance of mysql and selected the contents of t after the inserts but before the commit, the rows would not show up. They would not become visible to the second mysql process until the COMMIT statement had been issued by the first one.
If an error occurs during a transaction, you can cancel it with ROLLBACK. Using the t table again, you can see this by issuing the following statements:
mysql> START TRANSACTION; mysql> INSERT INTO t SET name = 'Gromit'; mysql> INSERT INTO t SET name = 'Wallace'; ERROR 1062 (23000): Duplicate entry 'Wallace' for key 'name' mysql> ROLLBACK; mysql> SELECT * FROM t; +---------+ | name | +---------+ | Wallace | | William | +---------+
The second INSERT attempts to place a row into the table that duplicates an existing name value, but fails because name has a UNIQUE index. After issuing the ROLLBACK, the table has only the two rows that it contained prior to the failed transaction. In particular, the successful INSERT that was performed before the failed one has been undone and its effect is not recorded in the table.
Issuing a START TRANSACTION statement while a transaction is in process commits the current transaction implicitly before beginning a new one.
Another way to perform transactions is to manipulate the autocommit mode directly using SET statements:
SET autocommit = 0; SET autocommit = 1;
Setting the autocommit variable to zero disables autocommit, The effects of any statements that follow become part of the current transaction, which you end by issuing a COMMIT or ROLLBACK statement to commit or cancel it. With this method, autocommit remains off until you turn it back on, so ending one transaction also begins the next one. You can also commit a transaction by re-enabling autocommit.
To see how this approach works, begin with the same table as for the previous examples:
mysql> DROP TABLE t; mysql> CREATE TABLE t (name CHAR(20), UNIQUE (name)) ENGINE=InnoDB;
Then disable autocommit mode, insert some rows, and commit the transaction:
mysql> SET autocommit = 0; mysql> INSERT INTO t SET name = 'William'; mysql> INSERT INTO t SET name = 'Wallace'; mysql> COMMIT; mysql> SELECT * FROM t; +---------+ | name | +---------+ | Wallace | | William | +---------+
At this point, the two rows have been committed to the table, but autocommit mode remains disabled. If you issue further statements, they become part of a new transaction, which may be committed or rolled back independently of the first transaction. To verify that autocommit is still off and that ROLLBACK will cancel uncommitted statements, issue the following statements:
mysql> INSERT INTO t SET name = 'Gromit'; mysql> INSERT INTO t SET name = 'Wallace'; ERROR 1062 (23000): Duplicate entry 'Wallace' for key 'name' mysql> ROLLBACK; mysql> SELECT * FROM t; +---------+ | name | +---------+ | Wallace | | William | +---------+
To re-enable autocommit mode, use this statement:
mysql> SET autocommit = 1;
As just described, a transaction ends when you issue a COMMIT or ROLLBACK statement, or when you re-enable autocommit while it is disabled. Transactions also end under other circumstances. In addition to the SET autocommit, START TRANSACTION, BEGIN, COMMIT, and ROLLBACK statements that affect transactions explicitly, certain other statements do so implicitly because they cannot be part of a transaction. In general, these tend to be DDL (data definition language) statements that create, alter, or drop databases or objects in them, or statements that are lock-related. For example, if you issue any of the following statements while a transaction is in progress, the server commits the transaction first before executing the statement:
ALTER TABLE CREATE INDEX DROP DATABASE DROP INDEX DROP TABLE LOCK TABLES RENAME TABLE SET autocommit = 1 (if not already set to 1) TRUNCATE TABLE UNLOCK TABLES (if tables currently are locked)
For a complete list of statements that cause implicit commits in your version of MySQL, see the MySQL Reference Manual.
A transaction also ends if a client’s session ends or is broken before a commit occurs. In this case, the server automatically rolls back any transaction the client had in progress.
If a client program automatically reconnects after its session with the server is lost, the connection is reset to its default state of having autocommit enabled.
Transactions are useful in all kinds of situations. Suppose that you’re working with the score table that is part of the grade-keeping project and you discover that the grades for two students have gotten mixed up and need to be switched. The incorrectly entered grades are as follows:
mysql> SELECT * FROM score WHERE event_id = 5 AND student_id IN (8,9); +------------+----------+-------+ | student_id | event_id | score | +------------+----------+-------+ | 8 | 5 | 18 | | 9 | 5 | 13 | +------------+----------+-------+
To fix this, student 8 should be given a score of 13 and student 9 a score of 18. That can be done easily with two statements:
UPDATE score SET score = 13 WHERE event_id = 5 AND student_id = 8; UPDATE score SET score = 18 WHERE event_id = 5 AND student_id = 9;
However, it’s necessary to ensure that both statements succeed as a unit. This is a problem to which transactional methods may be applied. To use START TRANSACTION, do this:
mysql> START TRANSACTION; mysql> UPDATE score SET score = 13 WHERE event_id = 5 AND student_id = 8; mysql> UPDATE score SET score = 18 WHERE event_id = 5 AND student_id = 9; mysql> COMMIT;
To accomplish the same thing by manipulating the autocommit mode explicitly instead, do this:
mysql> SET autocommit = 0; mysql> UPDATE score SET score = 13 WHERE event_id = 5 AND student_id = 8; mysql> UPDATE score SET score = 18 WHERE event_id = 5 AND student_id = 9; mysql> COMMIT; mysql> SET autocommit = 1;
Either way, the result is that the scores are swapped properly:
mysql> SELECT * FROM score WHERE event_id = 5 AND student_id IN (8,9); +------------+----------+-------+ | student_id | event_id | score | +------------+----------+-------+ | 8 | 5 | 13 | | 9 | 5 | 18 | +------------+----------+-------+
2.12.2. Using Transaction Savepoints
MySQL enables you to perform a partial rollback of a transaction. To do this, issue a SAVEPOINT statement within the transaction to set a named marker. To roll back to just that point in the transaction later, use a ROLLBACK statement that names the savepoint. The following statements illustrate how this works:
mysql> CREATE TABLE t (i INT) ENGINE=InnoDB; mysql> START TRANSACTION; mysql> INSERT INTO t VALUES(1); mysql> SAVEPOINT my_savepoint; mysql> INSERT INTO t VALUES(2); mysql> ROLLBACK TO SAVEPOINT my_savepoint; mysql> INSERT INTO t VALUES(3); mysql> COMMIT; mysql> SELECT * FROM t; +------+ | i | +------+ | 1 | | 3 | +------+
After executing these statements, the first and third rows have been inserted, but the second one has been canceled by the partial rollback to the my_savepoint savepoint.
2.12.3. Transaction Isolation
Because MySQL is a multiple-user database system, different clients can attempt to use any given table at the same time. Storage engines such as MyISAM use table locking to keep clients from modifying a table at the same time, but this does not provide good concurrency performance when there are many updates. The InnoDB storage engine takes a different approach. It uses row-level locking for finer-grained control over table access by clients. One client can modify a row at the same time that another client reads or modifies a different row in the same table. If both clients want to modify a row at the same time, whichever of them acquires a lock on the row gets to modify it first. This provides better concurrency than table locking. However, there is the question of whether one client’s transaction should be able to see the changes made by another client’s transaction.
InnoDB implements transaction isolation levels to give clients control over what kind of changes made by other transactions they want to see. Different isolation levels permit or prevent problems that can occur when different transactions run simultaneously:
- Dirty reads. A dirty read occurs when a change made by one transaction can be seen by other transactions before the transaction has been committed. Another transaction thus might think the row has been changed, even though that will not really be true if the transaction that changed the row later is rolled back.
- Nonrepeatable reads. A nonrepeatable read refers to failure by a transaction to get the same result for a given SELECT statement each time it executes it. This might happen if one transaction performs a SELECT twice but another transaction changes some of the rows in between the two executions.
- Phantom rows. A phantom is a row that becomes visible to a transaction when it was not previously. Suppose that a transaction performs a SELECT and then another transaction inserts a row. If the first transaction runs the same SELECT again and sees the new row, that is a phantom.
To deal with these problems, InnoDB supports four transaction isolation levels. These levels determine which modifications made by one transaction can be seen by other transactions that execute at the same time:
- READ UNCOMMITTED: A transaction can see row modifications made by other transactions even before they have been committed.
- READ COMMITTED: A transaction can see row modifications made by other transactions only if they have been committed.
- REPEATABLE READ: If a transaction performs a given SELECT twice, the result is repeatable. That is, it gets the same result each time, even if other transactions have changed or inserted rows in the meantime.
- SERIALIZABLE: This isolation level is similar to REPEATABLE READ but isolates transactions more completely: Rows examined by one transaction cannot be modified by other transactions until the first transaction completes. This enables one transaction to read rows and at the same time prevent them from being modified by other transactions until it is done with them.
Table 2.4 shows for each isolation level whether it permits dirty reads, nonrepeatable reads, or phantom rows. The table is InnoDB-specific in that REPEATABLE READ does not permit phantom rows to occur. Some database systems do permit phantoms at the REPEATABLE READ isolation level.
Table 2.4. Problems Permitted by Isolation Levels
Isolation Level |
Dirty Reads |
Nonrepeatable Reads |
Phantom Rows |
READ UNCOMMITTED |
Yes |
Yes |
Yes |
READ COMMITTED |
No |
Yes |
Yes |
REPEATABLE READ |
No |
No |
No |
SERIALIZABLE |
No |
No |
No |
The default InnoDB isolation level is REPEATABLE READ. This can be changed at server startup with the --transaction-isolation option, or at runtime with the SET TRANSACTION statement. The statement has three forms:
SET GLOBAL TRANSACTION ISOLATION LEVEL level; SET SESSION TRANSACTION ISOLATION LEVEL level; SET TRANSACTION ISOLATION LEVEL level;
A client that has the SUPER privilege can use SET TRANSACTION to change the global isolation level, which then applies to any clients that connect thereafter. In addition, any client can change its own transaction isolation level, either for all subsequent transactions within its session with the server (if SESSION is specified) or for its next transaction only (if SESSION is omitted). No special privileges are required for the client-specific levels.