A consistent read
means that InnoDB uses multi-versioning to
present to a query a snapshot of the database at a point in
time. The query sees the changes made by transactions that
committed before that point of time, and no changes made by
later or uncommitted transactions. The exception to this rule is
that the query sees the changes made by earlier statements
within the same transaction. This exception causes the following
anomaly: If you update some rows in a table, a
SELECT sees the latest version of
the updated rows, but it might also see older versions of any
rows. If other sessions simultaneously update the same table,
the anomaly means that you might see the table in a state that
never existed in the database.
If the transaction
isolation level is
REPEATABLE READ (the default
level), all consistent reads within the same transaction read
the snapshot established by the first such read in that
transaction. You can get a fresher snapshot for your queries by
committing the current transaction and after that issuing new
queries.
With READ COMMITTED isolation
level, each consistent read within a transaction sets and reads
its own fresh snapshot.
Consistent read is the default mode in which
InnoDB processes
SELECT statements in
READ COMMITTED and
REPEATABLE READ isolation
levels. A consistent read does not set any locks on the tables
it accesses, and therefore other sessions are free to modify
those tables at the same time a consistent read is being
performed on the table.
Suppose that you are running in the default
REPEATABLE READ isolation
level. When you issue a consistent read (that is, an ordinary
SELECT statement),
InnoDB gives your transaction a timepoint
according to which your query sees the database. If another
transaction deletes a row and commits after your timepoint was
assigned, you do not see the row as having been deleted. Inserts
and updates are treated similarly.
The snapshot of the database state applies to
SELECT statements within a
transaction, not necessarily to
DML statements. If you insert
or modify some rows and then commit that transaction, a
DELETE or
UPDATE statement issued from
another concurrent REPEATABLE READ
transaction could affect those just-committed rows, even
though the session could not query them. If a transaction does
update or delete rows committed by a different transaction,
those changes do become visible to the current transaction.
For example, you might encounter a situation like the
following:
SELECT COUNT(c1) FROM t1 WHERE c1 = 'xyz'; -- Returns 0: no rows match. DELETE FROM t1 WHERE c1 = 'xyz'; -- Deletes several rows recently committed by other transaction. SELECT COUNT(c2) FROM t1 WHERE c2 = 'abc'; -- Returns 0: no rows match. UPDATE t1 SET c2 = 'cba' WHERE c2 = 'abc'; -- Affects 10 rows: another txn just committed 10 rows with 'abc' values. SELECT COUNT(c2) FROM t1 WHERE c2 = 'cba'; -- Returns 10: this txn can now see the rows it just updated.
You can advance your timepoint by committing your transaction
and then doing another SELECT or
START TRANSACTION WITH
CONSISTENT SNAPSHOT.
This is called multi-versioned concurrency control.
In the following example, session A sees the row inserted by B only when B has committed the insert and A has committed as well, so that the timepoint is advanced past the commit of B.
Session A Session B
SET autocommit=0; SET autocommit=0;
time
| SELECT * FROM t;
| empty set
| INSERT INTO t VALUES (1, 2);
|
v SELECT * FROM t;
empty set
COMMIT;
SELECT * FROM t;
empty set
COMMIT;
SELECT * FROM t;
---------------------
| 1 | 2 |
---------------------
If you want to see the “freshest” state of the
database, use either the READ
COMMITTED isolation level or a
locking read:
SELECT * FROM t LOCK IN SHARE MODE;
With READ COMMITTED isolation
level, each consistent read within a transaction sets and reads
its own fresh snapshot. With LOCK IN SHARE
MODE, a locking read occurs instead: A
SELECT blocks until the transaction
containing the freshest rows ends (see
Section 14.8.2.4, “Locking Reads”).
Consistent read does not work over certain DDL statements:
Consistent read does not work over
DROP TABLE, because MySQL cannot use a table that has been dropped andInnoDBdestroys the table.Consistent read does not work over
ALTER TABLE, because that statement makes a temporary copy of the original table and deletes the original table when the temporary copy is built. When you reissue a consistent read within a transaction, rows in the new table are not visible because those rows did not exist when the transaction's snapshot was taken.
The type of read varies for selects in clauses like
INSERT INTO ...
SELECT, UPDATE
... (SELECT), and
CREATE TABLE ...
SELECT that do not specify FOR
UPDATE or LOCK IN SHARE MODE:
By default,
InnoDBuses stronger locks and theSELECTpart acts likeREAD COMMITTED, where each consistent read, even within the same transaction, sets and reads its own fresh snapshot.To use a consistent read in such cases, enable the
innodb_locks_unsafe_for_binlogoption and set the isolation level of the transaction toREAD UNCOMMITTED,READ COMMITTED, orREPEATABLE READ(that is, anything other thanSERIALIZABLE). In this case, no locks are set on rows read from the selected table.
The following very simple test locks out a reader in innodb. Tested in 5.0.67. I reported it as a bug and was told it's normal, expected behavior:
Session #1
----------
mysql> create table t1(a int) engine=innodb;
Query OK, 0 rows affected (0.05 sec)
mysql> start transaction;
Query OK, 0 rows affected (0.00 sec)
mysql> insert into t1 values (3);
Query OK, 1 row affected (0.02 sec)
Session #2 (fire up a separate window without closing the above)
-----------
mysql> select * from t1;
^CQuery aborted by Ctrl+C
ERROR 1317 (70100): Query execution was interrupted
(I had to kill the query after several seconds)
Setting "set session transaction isolation level read committed;" did not help.
Setting "set session transaction isolation level read uncommitted;" did not help.
Using lock tables on either side did not help.
Setting innodb_locks_unsafe_for_binlog=1 in my.cnf fixes the problem, but I guess the downside is that now I will not be able to use replication in this database.
*HOWEVER*
If you change the simple select statement to a CREATE TEMPORARY TABLE ... AS SELECT ..., and the target involves an index range, then even innodb_locks_unsafe_for_binlog does not help.
http://forums.mysql.com/read.php?22,281645,287007#msg-287007
Session A :
mysql> select * from person_test where id=1;
1 row in set (0.00 sec)
Session B :
mysql> alter table person_test add (city char(20));
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
ERROR 1317 (70100): Query execution was interrupted