背景
以前接触到的数据库死锁,都是批量更新时加锁顺序不一致而导致的死锁,但是上周却遇到了一个很难理解的死锁。借着这个机会又重新学习了一下 mysql 的死锁知识以及常见的死锁场景。在多方调研以及和同事们的讨论下终于发现了这个死锁问题的成因,收获颇多。虽然是后端程序员,我们不需要像 DBA 一样深入地去分析与锁相关的源码,但是如果我们能够掌握基本的死锁排查方法,对我们的日常开发还是大有裨益的。
PS:本文不会介绍死锁的基本知识,mysql 的加锁原理可以参考本文的参考资料提供的链接。
死锁起因
先介绍一下数据库和表情况,因为涉及到公司内部真是的数据,所以以下都做了模拟,不会影响具体的分析。
我们采用的是 5.5 版本的 mysql 数据库,事务隔离级别是默认的 RR(Repeatable-Read),采用 innodb 引擎。假设存在 test 表:
- CREATE TABLE `test` (
- `id` int(11) unsigned NOT NULL AUTO_INCREMENT,
- `a` int(11) unsigned DEFAULT NULL,
- PRIMARY KEY (`id`),
- UNIQUE KEY `a` (`a`)
- ) ENGINE=InnoDB AUTO_INCREMENT=100 DEFAULT CHARSET=utf8;
表的结构很简单,一个主键 id,另一个唯一索引 a。表里的数据如下:
- mysql> select * from test;
- +----+------+
- | id | a |
- +----+------+
- | 1 | 1 |
- | 2 | 2 |
- | 4 | 4 |
- +----+------+
- 3 rows in set (0.00 sec)
出现死锁的操作如下:
步骤 | 事务 1 | 事务 2 |
---|---|---|
1 | begin | |
2 | delete from test where a = 2; | |
3 | begin | |
4 | delete from test where a = 2; (事务 1 卡住) | |
5 | 提示出现死锁:ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction | insert into test (id, a) values (10, 2); |
然后我们可以通过 SHOW ENGINE INNODB STATUS; 来查看死锁日志:
- ------------------------
- LATEST DETECTED DEADLOCK
- ------------------------
- 170219 13:31:31
- *** (1) TRANSACTION:
- TRANSACTION 2A8BD, ACTIVE 11 sec starting index read
- mysql tables in use 1, locked 1
- LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s)
- MySQL thread id 448218, OS thread handle 0x2abe5fb5d700, query id 18923238 renjun.fangcloud.net 121.41.41.92 root updating
- delete from test where a = 2
- *** (1) WAITING FOR THIS LOCK TO BE GRANTED:
- RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BD lock_mode X waiting
- Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32
- 0: len 4; hex 00000002; asc ;;
- 1: len 4; hex 00000002; asc ;;
- *** (2) TRANSACTION:
- TRANSACTION 2A8BC, ACTIVE 18 sec inserting
- mysql tables in use 1, locked 1
- 4 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 2
- MySQL thread id 448217, OS thread handle 0x2abe5fd65700, query id 18923239 renjun.fangcloud.net 121.41.41.92 root update
- insert into test (id,a) values (10,2)
- *** (2) HOLDS THE LOCK(S):
- RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BC lock_mode X locks rec but not gap
- Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32
- 0: len 4; hex 00000002; asc ;;
- 1: len 4; hex 00000002; asc ;;
- *** (2) WAITING FOR THIS LOCK TO BE GRANTED: