MySQL事务隔离级别

一、事务的基本要素(ACID)

  1. 原子性(Atomicity):事务开始后所有操作,要么全部做完,要么全部不做,不可能停滞在中间环节。事务执行过程中出错,会回滚到事务开始前的状态,所有的操作就像没有发生一样。也就是说事务是一个不可分割的整体,就像化学中学过的原子,是物质构成的基本单位。
  2. 一致性(Consistency):事务开始前和结束后,数据库的完整性约束没有被破坏 。比如A向B转账,不可能A扣了钱,B却没收到。
  3. 隔离性(Isolation):同一时间,只允许一个事务请求同一数据,不同的事务之间彼此没有任何干扰。比如A正在从一张银行卡中取钱,在A取钱的过程结束前,B不能向这张卡转账。
  4. 持久性(Durability):事务完成后,事务对数据库的所有更新将被保存到数据库,不能回滚。
  5. 小结:原子性是事务隔离的基础,隔离性和持久性是手段,最终目的是为了保持数据的一致性。

二、事务的并发问题

  1. 脏读:事务A读取了事务B更新的数据,然后B回滚操作,那么A读取到的数据是脏数据
  2. 不可重复读:事务 A 多次读取同一数据,事务 B 在事务A多次读取的过程中,对数据作了更新并提交,导致事务A多次读取同一数据时,结果 不一致。
  3. 幻读:系统管理员A将数据库中所有学生的成绩从具体分数改为ABCDE等级,但是系统管理员B就在这个时候插入了一条具体分数的记录,当系统管理员A改结束后发现还有一条记录没有改过来,就好像发生了幻觉一样,这就叫幻读。
  4. 小结:不可重复读的和幻读很容易混淆,不可重复读侧重于修改,幻读侧重于新增或删除。解决不可重复读的问题只需锁住满足条件的行,解决幻读需要锁表

三、MySQL事务隔离级别

事务隔离级别 脏读 不可重复读 幻读
读未提交(read-uncommitted)
不可重复读(read-committed)
可重复读(repeatable-read)
串行化(serializable)

MySQL默认的事务隔离级别为可重复读

1
2
3
4
5
6
mysql> SELECT @@tx_isolation;
+-----------------+
| @@tx_isolation |
+-----------------+
| REPEATABLE-READ |
+-----------------+

四、用例子说明各个隔离级别的情况

未提交读(read-uncommitted)

打开一个客户端A,并设置当前事务模式为read uncommitted(未提交读),查询表account的初始值:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
mysql> SET session TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
Query OK, 0 rows affected (0.00 sec)
mysql> select @@tx_isolation;
+------------------+
| @@tx_isolation |
+------------------+
| READ-UNCOMMITTED |
+------------------+
1 row in set (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 450 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
在客户端A的事务提交之前,打开另一个客户端B,更新表account:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
mysql> SET session TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> update account set balance = balance - 50 where id = 1;
Query OK, 1 row affected (0.01 sec)
Rows matched: 1 Changed: 1 Warnings: 0
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
这时,虽然客户端B的事务还没提交,但是客户端A就可以查询到B已经更新的数据:
1
2
3
4
5
6
7
8
9
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
一旦客户端B的事务因为某种原因回滚,所有的操作都将会被撤销,那客户端A查询到的数据其实就是脏数据:
1
2
3
4
5
6
7
8
9
10
11
12
mysql> rollback;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 450 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
客户端A执行更新语句update account set balance = balance - 50 where id =1,lilei的balance没有变成350,居然是400,是不是很奇怪,数据的一致性没问啊,如果你这么想就太天真 了,在应用程序中,我们会用400-50=350,并不知道其他会话回滚了,要想解决这个问题可以采用读已提交的隔离级别
1
2
3
4
5
6
7
8
9
10
11
12
13
mysql> update account set balance = balance - 50 where id = 1;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)

已提交读(read-committed)

打开一个客户端A,并设置当前事务模式为read committed(未提交读),查询表account的初始值:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
mysql> SET session TRANSACTION ISOLATION LEVEL READ COMMITTED;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 450 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
在客户端A的事务提交之前,打开另一个客户端B,更新表account:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
mysql> SET session TRANSACTION ISOLATION LEVEL READ COMMITTED;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> update account set balance = balance - 50 where id = 1;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
这时,客户端B的事务还没提交,客户端A不能查询到B已经更新的数据,解决了脏读问题:
1
2
3
4
5
6
7
8
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 450 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
客户端B的事务提交
1
2
3
4
5
6
7
8
9
10
11
12
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
mysql> commit;
Query OK, 0 rows affected (0.00 sec)
客户端A执行与上一步相同的查询,结果 与上一步不一致,即产生了不可重复读的问题,在应用程序中,假设我们处于客户端A的会话,查询到lilei的balance为450,但是其他事务将lilei的balance值改为400,我们并不知道,如果用450这个值去做其他操作,是有问题的,不过这个概率真的很小哦,要想避免这个问题,可以采用可重复读的隔离级别
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 450 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)

可重复读(repeatable-read)

打开一个客户端A,并设置当前事务模式为repeatable read,查询表account的初始值:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
mysql> SET session TRANSACTION ISOLATION LEVEL REPEATABLE READ;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
在客户端A的事务提交之前,打开另一个客户端B,更新表account并提交,客户端B的事务居然可以修改客户端A事务查询到的行,也就是mysql的可重复读不会锁住事务查询到的行,这一点出乎我的意料,sql标准中事务隔离级别为可重复读时,读写操作要锁行的,mysql居然没有锁,我了个去。在应用程序中要注意给行加锁,不然你会以步骤(1)中lilei的balance为400作为中间值去做其他操作
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
mysql> SET session TRANSACTION ISOLATION LEVEL REPEATABLE READ;
Query OK, 0 rows affected (0.00 sec)
mysql> update account set balance = balance - 50 where id = 1;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
mysql> commit;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 350 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
客户端A执行步骤(1)的查询:
1
2
3
4
5
6
7
8
9
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
客户端A,lilei的balance仍然是400与步骤(1)查询结果一致,没有出现不可重复读的问题;接着执行update balance = balance - 50 where id = 1,balance没有变成400-50=350,lilei的balance值用的是步骤(2)中的350来算的,所以是300,数据的一致性倒是没有被破坏,这个有点神奇,也许是mysql的特色吧
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 400 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
mysql> update account set balance = balance - 50 where id = 1;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 300 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
在客户端B开启事务,新增一条数据,其中balance字段值为600,并提交
1
2
3
4
5
6
7
8
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> insert into account values(null,'lily',600);
Query OK, 1 row affected (0.00 sec)
mysql> commit;
Query OK, 0 rows affected (0.00 sec)
客户端A计算balance之和,值为300+850+1850=3000,没有把客户端B的值算进去,客户端A提交后再计算balance之和,居然变成了3600,这是因为把客户端B的600算进去了,站在客户的角度,客户是看不到客户端B的,它会觉得是天下掉馅饼了,多了600块,这就是幻读,站在开发者的角度,数据的一致性并没有破坏。但是在应用程序中,我们得代码可能会把18700提交给用户了,如果你一定要避免这情况小概率状况的发生,那么就要采取下面要介绍的事务隔离级别“串行化”
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 300 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
+----+-----------+---------+
3 rows in set (0.00 sec)
mysql> select sum(balance) from account;
+--------------+
| sum(balance) |
+--------------+
| 3000 |
+--------------+
1 row in set (0.00 sec)
mysql> commit;
Query OK, 0 rows affected (0.00 sec)
mysql> select sum(balance) from account;
+--------------+
| sum(balance) |
+--------------+
| 3600 |
+--------------+
1 row in set (0.00 sec)

串行化(serializable)

打开一个客户端A,并设置当前事务模式为serializable,查询表account的初始值:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
mysql> SET session TRANSACTION ISOLATION LEVEL SERIALIZABLE;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> select * from account;
+----+-----------+---------+
| id | name | balance |
+----+-----------+---------+
| 1 | lilei | 300 |
| 2 | hanmeimei | 850 |
| 3 | tom | 1850 |
| 4 | lily | 600 |
+----+-----------+---------+
4 rows in set (0.00 sec)
打开一个客户端B,并设置当前事务模式为serializable,插入一条记录报错,表被锁了插入失败,mysql中事务隔离级别为serializable时会锁表,因此不会出现幻读的情况,这种隔离级别并发性极低,往往一个事务霸占了一张表,其他成千上万个事务只有干瞪眼,得等他用完提交才可以使用,开发中很少会用到。
1
2
3
4
5
6
7
8
mysql> SET session TRANSACTION ISOLATION LEVEL SERIALIZABLE;
Query OK, 0 rows affected (0.00 sec)
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> insert into account values(null,'lisa',0);
ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction

五、参考

MySQL的四种事务隔离级别