├── 1.md ├── 10.md ├── 11.md ├── 12.md ├── 13.md ├── 14.md ├── 15.md ├── 16.md ├── 17.md ├── 18.md ├── 19.md ├── 2.md ├── 20.md ├── 3.md ├── 4.md ├── 5.md ├── 6.md ├── 7.md ├── 8.md ├── 9.md ├── README.md ├── docker ├── conf │ └── mysqld.cnf ├── db │ ├── t16.sql │ ├── t18.sql │ ├── t20.sql │ └── t8.sql └── docker-compose.yml └── images └── 16-17.jpeg /1.md: -------------------------------------------------------------------------------- 1 | insert-wait-lock-mode-x-insert-intention-vs-insert-wait-lock-mode-x-insert-intention-holds-lock-mode-x 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. insert WAITING FOR lock_mode X insert intention waiting 7 | 2. insert WAITING FOR lock_mode X insert intention waiting, HOLDS lock_mode X 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 2014-12-23 15:47:11 1f4c 17 | *** (1) TRANSACTION: 18 | TRANSACTION 19896526, ACTIVE 0 sec inserting 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 5 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 1 21 | MySQL thread id 17988, OS thread handle 0x17bc, query id 5701353 localhost 127.0.0.1 root update 22 | insert into PlayerClub (modifiedBy, timeCreated, currentClubId, endingLevelPosition, nextClubId, account_id) values (0, '2014-12-23 15:47:11.596', 180, 4, 181, 561) 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 49735 page no 4 n bits 72 index `UK_cagoa3q409gsukj51ltiokjoh` of table `db`.`playerclub` trx id 19896526 lock_mode X insert intention waiting 25 | Record lock, heap no 1 PHYSICAL RECORD: n_fields 1; compact format; info bits 0 26 | 0: len 8; hex 73757072656d756d; asc supremum;; 27 | 28 | *** (2) TRANSACTION: 29 | TRANSACTION 19896542, ACTIVE 0 sec inserting, thread declared inside InnoDB 5000 30 | mysql tables in use 1, locked 1 31 | 5 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 1 32 | MySQL thread id 17979, OS thread handle 0x1f4c, query id 5701360 localhost 127.0.0.1 root update 33 | insert into PlayerClub (modifiedBy, timeCreated, currentClubId, endingLevelPosition, nextClubId, account_id) values (0, '2014-12-23 15:47:11.611', 180, 4, 181, 563) 34 | *** (2) HOLDS THE LOCK(S): 35 | RECORD LOCKS space id 49735 page no 4 n bits 72 index `UK_cagoa3q409gsukj51ltiokjoh` of table `db`.`playerclub` trx id 19896542 lock_mode X 36 | Record lock, heap no 1 PHYSICAL RECORD: n_fields 1; compact format; info bits 0 37 | 0: len 8; hex 73757072656d756d; asc supremum;; 38 | 39 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 40 | RECORD LOCKS space id 49735 page no 4 n bits 72 index `UK_cagoa3q409gsukj51ltiokjoh` of table `db`.`playerclub` trx id 19896542 lock_mode X insert intention waiting 41 | Record lock, heap no 1 PHYSICAL RECORD: n_fields 1; compact format; info bits 0 42 | 0: len 8; hex 73757072656d756d; asc supremum;; 43 | 44 | *** WE ROLL BACK TRANSACTION (2) 45 | ``` 46 | 47 | ## 表结构 48 | 49 | ```sql 50 | CREATE TABLE `PlayerClub` ( 51 | `id` bigint(20) NOT NULL AUTO_INCREMENT, 52 | `modifiedBy` bigint(20) DEFAULT NULL, 53 | `timeCreated` datetime NOT NULL, 54 | `account_id` bigint(20) DEFAULT NULL, 55 | `currentClubId` bigint(20) DEFAULT NULL, 56 | `endingLevelPosition` int(11) NOT NULL, 57 | `nextClubId` bigint(20) DEFAULT NULL, 58 | PRIMARY KEY (`id`), 59 | UNIQUE KEY `UK_cagoa3q409gsukj51ltiokjoh` (`account_id`), 60 | KEY `FK_cagoa3q409gsukj51ltiokjoh` (`account_id`), 61 | CONSTRAINT `FK_cagoa3q409gsukj51ltiokjoh` FOREIGN KEY (`account_id`) REFERENCES `PlayerAccount` (`id`) 62 | ) ENGINE=InnoDB AUTO_INCREMENT=6 DEFAULT CHARSET=latin1; 63 | ``` 64 | 65 | ## 重现步骤 66 | 67 | | Session 1 | Session 2 | 68 | | --- | --- | 69 | | delete from PlayerClub where account_id = 561; | | 70 | | | delete from PlayerClub where account_id = 563; | 71 | | insert into PlayerClub (modifiedBy, timeCreated, currentClubId, endingLevelPosition, nextClubId, account_id) values (0, '2014-12-23 15:47:11.596', 180, 4, 181, 561); | | 72 | | | insert into PlayerClub (modifiedBy, timeCreated, currentClubId, endingLevelPosition, nextClubId, account_id) values (0, '2014-12-23 15:47:11.596', 180, 4, 181, 563); | 73 | 74 | ## 分析 75 | 76 | 从死锁日志可以看出事务 2 HOLDS lock_mode X 锁(Next-key锁),并且这个锁锁在 supremum 这条记录上,这个锁不可能是 insert 语句加的,可以推测在 insert 语句前面肯定还有其他 sql 语句,譬如: 77 | 78 | ``` 79 | delete from PlayerClub where account_id = 561; 80 | ``` 81 | 82 | 或者: 83 | 84 | ``` 85 | update PlayerClub set ... where account_id = 561; 86 | ``` 87 | 88 | 这里有一个有意思的点,如果要删除的二级索引 account_id = 561 不存在,按理来说加的应该是 gap 锁(locks gap before rec),但是这里看到的日志却是 lock_mode X,也就是 Next-key 锁;而且更有意思的是,按理来说两个 Next-key 锁应该是冲突的,但是这里却两个事务同时在 supremum 这条记录上加了 Next-key 锁。我的理解是,这里是 gap 锁,而非 Next-key 锁,不能被日志误导,所以看到 supremum 的时候要特别注意(supremum 的 heap no = 1)。 89 | 90 | 另外,插入意向锁也和 gap 锁类似,如果在最大值处插入,日志显示 `lock_mode X insert intention`,如果在中间处插入,显示 `lock_mode X locks gap before rec insert intention`,也要注意。 91 | 92 | ## 参考 93 | 94 | 1. [MySQL InnoDB Deadlock For 2 simple insert queries](https://dba.stackexchange.com/questions/86878/mysql-innodb-deadlock-for-2-simple-insert-queries) 95 | 2. [Why am I getting deadlock in MySQL](https://stackoverflow.com/questions/23615641/why-am-i-getting-deadlock-in-mysql) 96 | 3. [一个线上死锁问题分析](http://mysqllover.com/?p=437) 97 | 4. https://github.com/octachrome/innodb-locks 98 | 5. [一个死锁问题](http://xiaobaoqiu.github.io/blog/2016/07/22/%5B%3F%5D-ge-si-suo-wen-ti/) 99 | -------------------------------------------------------------------------------- /10.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-s 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode S 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 141009 12:54:59 16 | *** (1) TRANSACTION: 17 | TRANSACTION AEE50DCB, ACTIVE 0 sec starting index read 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s) 20 | MySQL thread id 6055694, OS thread handle 0x7f4345c8d700, query id 2443700084 192.168.249.154 crm_w updating 21 | DELETE FROM crm_business WHERE serial_number = 'CH01313320' 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 244 page no 817 n bits 824 index `uniq_serial_number_business_type` of table `crm`.`crm_business` trx id AEE50DCB lock_mode X waiting 24 | *** (2) TRANSACTION: 25 | TRANSACTION AEE50DCA, ACTIVE 0 sec inserting, thread declared inside InnoDB 500 26 | mysql tables in use 1, locked 1 27 | 3 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 1 28 | MySQL thread id 6055696, OS thread handle 0x7f4344941700, query id 2443700084 192.168.249.154 crm_w update 29 | INSERT INTO crm_business(serial_number, business_type) values ('CH01313318', 2) 30 | *** (2) HOLDS THE LOCK(S): 31 | RECORD LOCKS space id 244 page no 817 n bits 824 index `uniq_serial_number_business_type` of table `crm`.`crm_business` trx id AEE50DCA lock mode S 32 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 33 | RECORD LOCKS space id 244 page no 817 n bits 824 index `uniq_serial_number_business_type` of table `crm`.`crm_business` trx id AEE50DCA lock_mode X locks gap before rec insert intention waiting 34 | *** WE ROLL BACK TRANSACTION (1) 35 | ``` 36 | 37 | # 表结构 38 | 39 | ```sql 40 | CREATE TABLE `crm_business` ( 41 | `id` int(11) unsigned NOT NULL AUTO_INCREMENT COMMENT '主键ID', 42 | `serial_number` varchar(50) NOT NULL COMMENT '商户编号', 43 | `business_type` tinyint(1) NOT NULL COMMENT '业务类型', 44 | PRIMARY KEY (`id`), 45 | UNIQUE KEY `uniq_serial_number_business_type` (`serial_number`,`business_type`) 46 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT='合作业务' 47 | ``` 48 | 49 | ## 重现步骤 50 | 51 | | Session 1 | Session 2 | 52 | | --------- | --------- | 53 | |DELETE FROM crm_business WHERE serial_number = 'CH01313320'|INSERT INTO crm_business(serial_number, business_type) values ('CH01313318', 2)| 54 | 55 | ## 分析 56 | 57 | 这又是一个单语句导致死锁的案例,具体的分析还是要将 insert 语句的加锁过程进行拆解,和 [delete-wait-lock-mode-x-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x-locks-rec-but-not-gap](5.md) 一样。 58 | 59 | 分析如下: 60 | 61 | | Session 1 | Session 2 | 62 | | --------- | --------- | 63 | ||INSERT INTO crm_business(serial_number, business_type) values ('CH01313318', 2); insert第1阶段:事务2申请S锁进行duplicate key进行检查。检查成功。| 64 | |DELETE FROM crm_business WHERE serial_number = 'CH01313320'; 对索引加 X 锁,和 S 锁冲突,等待|| 65 | ||INSERT INTO crm_business(serial_number, business_type) values ('CH01313318', 2); insert第2阶段:事务2开始插入数据,S锁升级为X锁,类型为insert intention。同理,X锁进入队列排队,形成循环等待,死锁产生。| 66 | 67 | ## 参考 68 | 69 | 1. [线上Mysql Delete 和 Insert 操作导致死锁问题分析](https://ketao1989.github.io/2014/10/09/Mysql-Delete-Insert-Deadlock-Analyse/) 70 | -------------------------------------------------------------------------------- /11.md: -------------------------------------------------------------------------------- 1 | update-wait-lock-mode-x-locks-rec-but-not-gap-vs-update-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. update WAITING FOR lock_mode X locks rec but not gap 7 | 2. update WAITING FOR lock mode S, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2015-01-23 14:24:16 10ceed000 16 | *** (1) TRANSACTION: 17 | TRANSACTION 24897, ACTIVE 3 sec starting index read 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 2 lock struct(s), heap size 360, 1 row lock(s) 20 | MySQL thread id 8, OS thread handle 0x10cea5000, query id 138 127.0.0.1 root updating 21 | update tt set id = 4 where fileid = 1 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 495 page no 4 n bits 72 index `fileid` of table `test`.`tt` trx id 24897 lock_mode X locks rec but not gap waiting 24 | Record lock, heap no 2 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 25 | 0: len 4; hex 80000001; asc ;; 26 | 1: len 4; hex 80000002; asc ;; 27 | 28 | *** (2) TRANSACTION: 29 | TRANSACTION 24896, ACTIVE 8 sec updating or deleting 30 | mysql tables in use 1, locked 1 31 | 4 lock struct(s), heap size 1184, 3 row lock(s), undo log entries 2 32 | MySQL thread id 7, OS thread handle 0x10ceed000, query id 136 127.0.0.1 root updating 33 | update tt set id = 3 where fileid = 1 34 | *** (2) HOLDS THE LOCK(S): 35 | RECORD LOCKS space id 495 page no 4 n bits 72 index `fileid` of table `test`.`tt` trx id 24896 lock_mode X locks rec but not gap 36 | Record lock, heap no 2 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 37 | 0: len 4; hex 80000001; asc ;; 38 | 1: len 4; hex 80000002; asc ;; 39 | 40 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 41 | RECORD LOCKS space id 495 page no 4 n bits 72 index `fileid` of table `test`.`tt` trx id 24896 lock mode S waiting 42 | Record lock, heap no 2 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 43 | 0: len 4; hex 80000001; asc ;; 44 | 1: len 4; hex 80000002; asc ;; 45 | 46 | *** WE ROLL BACK TRANSACTION (1) 47 | ``` 48 | 49 | ## 表结构 50 | 51 | ```sql 52 | CREATE TABLE `tt` ( 53 | `id` int(11) NOT NULL DEFAULT '0', 54 | `fileid` int(11) DEFAULT NULL, 55 | PRIMARY KEY (`id`), 56 | UNIQUE KEY `fileid` (`fileid`) 57 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 58 | ``` 59 | 60 | ## 重现步骤 61 | 62 | | Session 1 | Session 2 | Session 3 | 63 | | --- | --- | --- | 64 | | update tt set id = 2 where fileid = 1; ||| 65 | ||update tt set id = 3 where fileid = 1;|| 66 | |||update tt set id = 4 where fileid = 1;| 67 | |commit;||.| 68 | 69 | ## 分析 70 | 71 | TODO 72 | 73 | ## 参考 74 | 75 | 1. [MySQL问题两则](http://siddontang.com/2015/01/25/two-mysql-problems/) 76 | -------------------------------------------------------------------------------- /12.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 2017-09-09 22:34:13 7f78eab82700 17 | *** (1) TRANSACTION: 18 | TRANSACTION 462308399, ACTIVE 33 sec starting index read 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 2 lock struct(s), heap size 360, 1 row lock(s) 21 | MySQL thread id 3525577, OS thread handle 0x7f896cc4b700, query id 780039657 localhost root updating 22 | delete from ty where a=5 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 219 page no 4 n bits 72 index `idxa` of table `test`.`ty` trx id 462308399 lock_mode X waiting 25 | *** (2) TRANSACTION: 26 | TRANSACTION 462308398, ACTIVE 61 sec inserting, thread declared inside InnoDB 5000 27 | mysql tables in use 1, locked 1 28 | 5 lock struct(s), heap size 1184, 4 row lock(s), undo log entries 2 29 | MySQL thread id 3525490, OS thread handle 0x7f78eab82700, query id 780039714 localhost root update 30 | insert into ty(a,b) values(2,10) 31 | *** (2) HOLDS THE LOCK(S): 32 | RECORD LOCKS space id 219 page no 4 n bits 72 index `idxa` of table `test`.`ty` trx id 462308398 lock_mode X 33 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 34 | RECORD LOCKS space id 219 page no 4 n bits 72 index `idxa` of table `test`.`ty` trx id 462308398 lock_mode X locks gap before rec insert intention waiting 35 | *** WE ROLL BACK TRANSACTION (1) 36 | ``` 37 | 38 | ## 表结构 39 | 40 | ```sql 41 | CREATE TABLE `ty` ( 42 | `id` int(11) NOT NULL AUTO_INCREMENT, 43 | `a` int(11) DEFAULT NULL, 44 | `b` int(11) DEFAULT NULL, 45 | PRIMARY KEY (`id`), 46 | KEY `idxa` (`a`) 47 | ) ENGINE=InnoDB AUTO_INCREMENT=8 DEFAULT CHARSET=utf8mb4 48 | ``` 49 | 50 | 初始数据: 51 | 52 | ```sql 53 | insert into ty(a,b) values(2,3),(5,4),(6,7); 54 | ``` 55 | 56 | ## 重现步骤 57 | 58 | | Session 1 | Session 2 | 59 | | --------- | --------- | 60 | |delete from ty where a=5;|| 61 | ||delete from ty where a=5;| 62 | |insert into ty(a,b) values(2,10);|.| 63 | 64 | ## 分析 65 | 66 | 这个死锁和 [insert-wait-lock-mode-x-insert-intention-vs-insert-wait-lock-mode-x-insert-intention-holds-lock-mode-x](1.md) 有异曲同工之妙,都是插入意向锁和 Gap 锁冲突导致的。案例一为插入意向锁和 Gap 锁冲突,两个 insert 互相等待导致死锁;而这个案例为插入意向锁和 Next-key 锁冲突,而 Next-key 锁和 Next-key 锁也冲突导致了死锁。 67 | 68 | ## 参考 69 | 70 | 1. [【MySQL】如何阅读死锁日志](http://blog.itpub.net/22664653/viewspace-2145133/) 71 | 2. [【MySQL】死锁案例之一](http://blog.itpub.net/22664653/viewspace-2145073/) 72 | -------------------------------------------------------------------------------- /13.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-insert-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. insert WAITING FOR lock mode S, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2017-09-10 00:03:31 7f78ea936700 16 | *** (1) TRANSACTION: 17 | TRANSACTION 462308445, ACTIVE 9 sec starting index read 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 2 lock struct(s), heap size 360, 1 row lock(s) 20 | MySQL thread id 3526009, OS thread handle 0x7f896cc4b700, query id 780047877 localhost root updating 21 | delete from t2 where a=5 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 221 page no 4 n bits 72 index `idxa` of table `test`.`t2` trx id 462308445 lock_mode X waiting 24 | *** (2) TRANSACTION: 25 | TRANSACTION 462308444, ACTIVE 17 sec inserting, thread declared inside InnoDB 5000 26 | mysql tables in use 1, locked 1 27 | 4 lock struct(s), heap size 1184, 3 row lock(s), undo log entries 2 28 | MySQL thread id 3526051, OS thread handle 0x7f78ea936700, query id 780047890 localhost root update 29 | insert t2(a,b) values(5,10) 30 | *** (2) HOLDS THE LOCK(S): 31 | RECORD LOCKS space id 221 page no 4 n bits 72 index `idxa` of table `test`.`t2` trx id 462308444 lock_mode X locks rec but not gap 32 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 33 | RECORD LOCKS space id 221 page no 4 n bits 72 index `idxa` of table `test`.`t2` trx id 462308444 lock mode S waiting 34 | *** WE ROLL BACK TRANSACTION (1) 35 | ``` 36 | 37 | ## 表结构 38 | 39 | ```sql 40 | CREATE TABLE `t2` ( 41 | `id` int(11) NOT NULL AUTO_INCREMENT, 42 | `a` int(11) DEFAULT NULL, 43 | `b` int(11) DEFAULT NULL, 44 | PRIMARY KEY (`id`), 45 | unique KEY `idxa` (`a`) 46 | ) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=utf8mb4; 47 | ``` 48 | 49 | 初始数据: 50 | 51 | ```sql 52 | insert into ty(a,b) values(2,3),(5,4),(6,7); 53 | ``` 54 | 55 | ## 重现步骤 56 | 57 | | Session 1 | Session 2 | 58 | | --------- | --------- | 59 | |delete from ty where a=5;|| 60 | ||delete from ty where a=5;| 61 | |insert into ty(a,b) values(2,10);|.| 62 | 63 | ## 分析 64 | 65 | 这个死锁和案例 12 的表结构几乎完全一样,只是这里的索引 a 为唯一索引。要分析这个死锁,只要记住两点就很好理解了: 66 | 67 | 1. 一般情况下根据唯一索引来 delete,加的是记录锁(rec but not gap),但是如果该记录已经被标记为删除,加的就是 Next-key 锁(lock_mode X); 68 | 2. insert 在插入唯一索引时需要加 S 锁进行唯一性检查; 69 | 70 | ## 参考 71 | 72 | 1. [【MySQL】死锁案例之一](http://blog.itpub.net/22664653/viewspace-2145073/) 73 | -------------------------------------------------------------------------------- /14.md: -------------------------------------------------------------------------------- 1 | insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x-locks-gap-before-rec 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. insert WAITING FOR lock_mode X locks gap before rec insert intention 7 | 2. insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X locks gap before rec 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2017-09-11 14:51:03 7f78eaf25700 16 | *** (1) TRANSACTION: 17 | TRANSACTION 462308535, ACTIVE 20 sec inserting 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 3 lock struct(s), heap size 360, 2 row lock(s), undo log entries 1 20 | MySQL thread id 3584515, OS thread handle 0x7f78ea5f5700, query id 780258123 localhost root update 21 | insert into t4(`kdt_id`, `admin_id`, `biz`, `role_id`, `shop_id`, `operator`, `operator_id`, `create_time`, `update_time`) 22 | VALUES('18', '2', 'retail', '2', '0', '0', '0', CURRENT_TIMESTAMP, CURRENT_TIMESTAMP) 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 225 page no 4 n bits 72 index `uniq_kid_aid_biz_rid` of table `test`.`t4` trx id 462308535 lock_mode X locks gap before rec insert intention waiting 25 | *** (2) TRANSACTION: 26 | TRANSACTION 462308534, ACTIVE 29 sec inserting, thread declared inside InnoDB 5000 27 | mysql tables in use 1, locked 1 28 | 3 lock struct(s), heap size 360, 2 row lock(s), undo log entries 1 29 | MySQL thread id 3584572, OS thread handle 0x7f78eaf25700, query id 780258153 localhost root update 30 | INSERT INTO t4(`kdt_id`, `admin_id`, `biz`, `role_id`, `shop_id`, `operator`, `operator_id`, `create_time`, `update_time`) 31 | VALUES ('15', '1', 'retail', '2', '0', '0', '0', CURRENT_TIMESTAMP, CURRENT_TIMESTAMP) 32 | *** (2) HOLDS THE LOCK(S): 33 | RECORD LOCKS space id 225 page no 4 n bits 72 index `uniq_kid_aid_biz_rid` of table `test`.`t4` trx id 462308534 lock_mode X locks gap before rec 34 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 35 | RECORD LOCKS space id 225 page no 4 n bits 72 index `uniq_kid_aid_biz_rid` of table `test`.`t4` trx id 462308534 lock_mode X locks gap before rec insert intention waiting 36 | *** WE ROLL BACK TRANSACTION (2) 37 | ``` 38 | 39 | ## 表结构 40 | 41 | ```sql 42 | CREATE TABLE `t4` ( 43 | `id` bigint(20) unsigned NOT NULL AUTO_INCREMENT , 44 | `kdt_id` int(11) unsigned NOT NULL , 45 | `admin_id` int(11) unsigned NOT NULL , 46 | `biz` varchar(20) NOT NULL DEFAULT '1' , 47 | `role_id` int(11) unsigned NOT NULL , 48 | `shop_id` int(11) unsigned NOT NULL DEFAULT '0' , 49 | `operator` varchar(20) NOT NULL DEFAULT '0' , 50 | `operator_id` int(11) NOT NULL DEFAULT '0' , 51 | `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', 52 | `update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '更新时间', 53 | PRIMARY KEY (`id`), 54 | UNIQUE KEY `uniq_kid_aid_biz_rid` (`kdt_id`,`admin_id`,`role_id`,`biz`) 55 | ) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=utf8; 56 | ``` 57 | 58 | 初始数据: 59 | 60 | ```sql 61 | INSERT INTO `t4` (`id`, `kdt_id`, `admin_id`, `biz`, `role_id`, `shop_id`, `operator`, `operator_id`, `create_time`, `update_time`) 62 | VALUES 63 | (1,10,1,'retail',1,0,'0',0,'2017-05-09 15:55:26','2017-05-09 15:55:26'), 64 | (2,20,1,'retail',1,0,'0',0,'2017-05-09 15:55:40','2017-05-09 15:55:40'), 65 | (3,30,1,'retail',1,0,'0',0,'2017-05-09 15:55:55','2017-05-09 15:55:55'), 66 | (4,40,1,'retail',1,0,'0',0,'2017-05-09 15:56:06','2017-05-09 15:56:06'), 67 | (5,50,1,'retail',1,0,'0',0,'2017-05-09 15:56:16','2017-05-09 15:56:16'); 68 | ``` 69 | 70 | ## 重现步骤 71 | 72 | | Session 1 | Session 2 | 73 | | --- | --- | 74 | |delete from t4 where kdt_id = 15 and admin_id = 1 and biz = 'retail' and role_id = '1';|| 75 | ||delete from t4 where kdt_id = 18 and admin_id = 2 and biz = 'retail' and role_id = '1';| 76 | ||insert into t4(kdt_id, admin_id, biz, role_id, shop_id, operator, operator_id, create_time, update_time) VALUES('18', '2', 'retail', '2', '0', '0', '0', CURRENT_TIMESTAMP,CURRENT_TIMESTAMP);| 77 | |INSERT INTO t4(kdt_id, admin_id, biz, role_id, shop_id, operator, operator_id, create_time, update_time) VALUES ('15', '1', 'retail', '2', '0', '0', '0', CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);|.| 78 | 79 | ## 分析 80 | 81 | 这个死锁和案例 1 一模一样,都是插入意向锁和 Gap 锁冲突导致的死锁。不过案例 1 插入的位置在 supremum record 上,这里插入的位置就是一个普通的 gap。 82 | 83 | 当在 supremum record 上加锁时,`locks gap before rec` 会省略掉,所以这里的 `insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X locks gap before rec` 和 案例 1 里的 `insert WAITING FOR lock_mode X insert intention waiting, HOLDS lock_mode X` 没任何区别,对这个死锁的分析参见案例 1 或参考链接,这里就不赘述了。 84 | 85 | ## 参考 86 | 87 | 1. [【MySQL】死锁案例之二](http://blog.itpub.net/22664653/viewspace-2145072/) 88 | -------------------------------------------------------------------------------- /15.md: -------------------------------------------------------------------------------- 1 | insert-wait-lock-mode-s-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. insert WAITING FOR lock mode S 7 | 2. insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2017-09-17 15:15:03 7f78eac15700 16 | *** (1) TRANSACTION: 17 | TRANSACTION 462308661, ACTIVE 6 sec inserting 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 2 lock struct(s), heap size 360, 1 row lock(s), undo log entries 1 20 | MySQL thread id 3796966, OS thread handle 0x7f78ead9d700, query id 781045166 localhost root update 21 | insert into t7(id,a) values(30,10) 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 231 page no 4 n bits 72 index `ua` of table `test`.`t7` trx id 462308661 lock mode S waiting 24 | *** (2) TRANSACTION: 25 | TRANSACTION 462308660, ACTIVE 43 sec inserting, thread declared inside InnoDB 5000 26 | mysql tables in use 1, locked 1 27 | 4 lock struct(s), heap size 1184, 3 row lock(s), undo log entries 2 28 | MySQL thread id 3796960, OS thread handle 0x7f78eac15700, query id 781045192 localhost root update 29 | insert into t7(id,a) values(40,9) 30 | *** (2) HOLDS THE LOCK(S): 31 | RECORD LOCKS space id 231 page no 4 n bits 72 index `ua` of table `test`.`t7` trx id 462308660 lock_mode X locks rec but not gap 32 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 33 | RECORD LOCKS space id 231 page no 4 n bits 72 index `ua` of table `test`.`t7` trx id 462308660 lock_mode X locks gap before rec insert intention waiting 34 | *** WE ROLL BACK TRANSACTION (1) 35 | ``` 36 | 37 | ## 表结构 38 | 39 | ```sql 40 | create table t7( 41 | id int not null primary key auto_increment, 42 | a int not null , 43 | unique key ua(a) 44 | ) engine=innodb; 45 | ``` 46 | 47 | 初始数据: 48 | 49 | ```sql 50 | insert into t7(id,a) values(1,1),(5,4),(20,20),(25,12); 51 | ``` 52 | 53 | ## 重现步骤 54 | 55 | | Session 1 | Session 2 | 56 | | --- | --- | 57 | ||insert into t7(id,a) values(26,10);| 58 | |insert into t7(id,a) values(30,10);|| 59 | ||insert into t7(id,a) values(40,9);| 60 | 61 | ## 分析 62 | 63 | 事务一在插入时由于跟事务二插入的记录唯一键冲突,所以对 a=10 这个唯一索引加 S 锁(Next-key)并处于锁等待,事务二再插入 a=9 这条记录,需要获取插入意向锁(lock_mode X locks gap before rec insert intention)和事务一持有的 Next-key 锁冲突,从而导致死锁。 64 | 65 | ## 参考 66 | 67 | 1. [【MySQL】死锁案例之三](http://blog.itpub.net/22664653/viewspace-2145068/) 68 | -------------------------------------------------------------------------------- /16.md: -------------------------------------------------------------------------------- 1 | update-wait-lock-mode-x-vs-update-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. update WAITING FOR lock mode X 7 | 2. update WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2019-03-31 02:50:17 0x7f6d180b7700 16 | *** (1) TRANSACTION: 17 | TRANSACTION 400442, ACTIVE 0 sec fetching rows 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 4 lock struct(s), heap size 1136, 5 row lock(s) 20 | MySQL thread id 27, OS thread handle 140106532366080, query id 596977 localhost root Searching rows for update 21 | update t16 set xid = 3, valid = 0 where xid = 3 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 400442 lock_mode X waiting 24 | Record lock, heap no 12 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 25 | 0: len 4; hex 80000003; asc ;; 26 | 1: len 4; hex 80000001; asc ;; 27 | 2: len 4; hex 80000005; asc ;; 28 | 29 | *** (2) TRANSACTION: 30 | TRANSACTION 400441, ACTIVE 0 sec updating or deleting 31 | mysql tables in use 1, locked 1 32 | 6 lock struct(s), heap size 1136, 9 row lock(s), undo log entries 2 33 | MySQL thread id 29, OS thread handle 140106531567360, query id 596975 localhost root updating 34 | update t16 set xid = 3, valid = 1 where xid = 2 35 | *** (2) HOLDS THE LOCK(S): 36 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 400441 lock_mode X locks rec but not gap 37 | Record lock, heap no 12 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 38 | 0: len 4; hex 80000003; asc ;; 39 | 1: len 4; hex 80000001; asc ;; 40 | 2: len 4; hex 80000005; asc ;; 41 | 42 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 43 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 400441 lock_mode X locks gap before rec insert intention waiting 44 | Record lock, heap no 4 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 45 | 0: len 4; hex 80000003; asc ;; 46 | 1: len 4; hex 80000001; asc ;; 47 | 2: len 4; hex 80000003; asc ;; 48 | 49 | *** WE ROLL BACK TRANSACTION (1) 50 | ``` 51 | 52 | ## 表结构 53 | 54 | ```sql 55 | CREATE TABLE `t16` ( 56 | `id` int(11) NOT NULL AUTO_INCREMENT, 57 | `xid` int(11) DEFAULT NULL, 58 | `valid` int(11) DEFAULT NULL, 59 | PRIMARY KEY (`id`), 60 | KEY `xid_valid` (`xid`,`valid`) 61 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 62 | ``` 63 | 64 | 初始数据: 65 | 66 | ```sql 67 | INSERT INTO t16(id, xid, valid) VALUES(1, 1, 0); 68 | INSERT INTO t16(id, xid, valid) VALUES(2, 2, 1); 69 | INSERT INTO t16(id, xid, valid) VALUES(3, 3, 1); 70 | INSERT INTO t16(id, xid, valid) VALUES(4, 1, 0); 71 | INSERT INTO t16(id, xid, valid) VALUES(5, 2, 0); 72 | INSERT INTO t16(id, xid, valid) VALUES(6, 3, 1); 73 | INSERT INTO t16(id, xid, valid) VALUES(7, 1, 1); 74 | INSERT INTO t16(id, xid, valid) VALUES(8, 2, 1); 75 | INSERT INTO t16(id, xid, valid) VALUES(9, 3, 0); 76 | INSERT INTO t16(id, xid, valid) VALUES(10, 1, 1); 77 | ``` 78 | 79 | ## 重现步骤 80 | 81 | | Session 1 | Session 2 | 82 | | --- | --- | 83 | |update t16 set xid = 3, valid = 0 where xid = 3;|update t16 set xid = 3, valid = 1 where xid = 2;| 84 | 85 | ## 分析 86 | 87 | 首先要明白 UPDATE 的加锁顺序:在 InnoDB 中,通过二级索引更新记录,首先会在 WHERE 条件使用到的二级索引上加 Next-Key 类型的X锁,以防止查找记录期间的其它插入/删除记录,然后通过二级索引找到 primary key 并在 primary key 上加 Record 类型的X锁,之后更新记录并检查更新字段是否是其它索引中的某列,如果存在这样的索引,通过 update 的旧值到二级索引中删除相应的 entry,此时x锁类型为 Record。 88 | 89 | 这个死锁和案例 17 的场景一模一样,但是触发死锁的时机稍有不同,可以先看下案例 17 的死锁,这个比较好理解。 90 | 91 | 和案例 17 一样,对二级索引 xid_valid 的更新过程如下所示: 92 | 93 | ![](../master/images/16-17.jpeg) 94 | 95 | 在事务 2 中, `update t16 set xid = 3, valid = 1 where xid = 2` 首先会对 `xid = 2` 的三条记录加上 Next-Key 锁,并在 `2-1|8` 和 `3-0|9` 之间加上 Gap 锁,然后开始更新二级索引,更新后的位置会加记录锁(lock_mode X locks rec but not gap),而在更新的时候,会将新纪录插入到新的位置,所以和 INSERT 加锁流程类似,需要加插入意向锁,如果该位置有 Gap 锁,则会阻塞。 96 | 97 | 不过要注意的是,如果同时更新多条记录,MySQL 和 InnoDb 之间的交互如下: 98 | 99 | ![](http://www.aneasystone.com/usr/uploads/2017/10/201797556.png) 100 | 101 | 从图中可以看到当 UPDATE 语句被发给 MySQL 后,MySQL Server 会根据 WHERE 条件读取第一条满足条件的记录,然后 InnoDB 引擎会将第一条记录返回并加锁(current read),待 MySQL Server 收到这条加锁的记录之后,会再发起一个 UPDATE 请求,更新这条记录。一条记录操作完成,再读取下一条记录,直至没有满足条件的记录为止。因此,MySQL 在操作多条记录时 InnoDB 与 MySQL Server 的交互是一条一条进行的,加锁也是一条一条依次进行的,先对一条满足条件的记录加锁,返回给 MySQL Server,做一些 DML 操作,然后在读取下一条加锁,直至读取完毕。 102 | 103 | 所以看死锁日志,就大概能明白死锁的过程了: 104 | 105 | 事务 2 首先处理第一条满足 WHERE 条件的记录 `2-0|5`,将 `2-0|5` 更新成 `3-1|5`,这个过程会在 `2-0|5` 上加 Next-Key 锁,并在 `3-1|5` 上加记录锁,然后以此类推,处理后面的记录。 106 | 107 | 与此同时,在事务 1 中,`update t16 set xid = 3, valid = 0 where xid = 3` 会对 `xid = 3` 的记录挨个处理,特别要注意的是,这里的查询使用的是当前读,所以事务 2 刚刚插入进来的 `3-1|5` 一样可以读到。所以事务 1 对 `3-0|9`,`3-1|3`,`3-1|5` 和 `3-1|6` 挨个处理,首先是 `3-0|9` 无需处理,然后是 `3-1|3` 更新成 `3-0|3`,会在 `3-1|3` 上加 Next-Key 锁,并在 `3-0|3` 上加记录锁,然后到处理 `3-1|5` 的时候,也会对 `3-1|5` 加 Next-Key 锁,但是这和事务 2 加在 `3-1|5` 上的记录锁冲突,所以事务 1 阻塞。 108 | 109 | 而事务 2 在更新完 `2-0|5` 之后,继续将 `2-1|2` 更新成 `3-1|2`,这不仅需要在 `2-1|2` 上加 Next-Key 锁,在 `3-1|2` 上加记录锁,而且还要在 `3-0|9` 和 `3-1|3` 之间加插入意向锁,这和事务 1 加在 `3-1|3` 上的 Next-Key 锁冲突了,从而导致死锁。 110 | 111 | ## 参考 112 | 113 | 1. [InnoDB inplace-update加锁流程分析 | Learn and live.](http://www.gpfeng.com/?p=406) 114 | -------------------------------------------------------------------------------- /17.md: -------------------------------------------------------------------------------- 1 | update-wait-lock-mode-x-locks-gap-before-rec-insert-intention-vs-update-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. update WAITING FOR lock_mode X locks gap before rec insert intention 7 | 2. update WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2019-03-31 02:50:16 0x7f6d1817a700 16 | *** (1) TRANSACTION: 17 | TRANSACTION 399960, ACTIVE 0 sec updating or deleting 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 5 lock struct(s), heap size 1136, 8 row lock(s), undo log entries 1 20 | MySQL thread id 29, OS thread handle 140106531567360, query id 596255 localhost root updating 21 | update t16 set xid = 3, valid = 1 where xid = 2 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 399960 lock_mode X locks gap before rec insert intention waiting 24 | Record lock, heap no 7 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 25 | 0: len 4; hex 80000003; asc ;; 26 | 1: len 4; hex 80000001; asc ;; 27 | 2: len 4; hex 80000006; asc ;; 28 | 29 | *** (2) TRANSACTION: 30 | TRANSACTION 399959, ACTIVE 0 sec updating or deleting 31 | mysql tables in use 1, locked 1 32 | 4 lock struct(s), heap size 1136, 8 row lock(s), undo log entries 2 33 | MySQL thread id 27, OS thread handle 140106532366080, query id 596254 localhost root updating 34 | update t16 set xid = 3, valid = 0 where xid = 3 35 | *** (2) HOLDS THE LOCK(S): 36 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 399959 lock_mode X 37 | Record lock, heap no 1 PHYSICAL RECORD: n_fields 1; compact format; info bits 0 38 | 0: len 8; hex 73757072656d756d; asc supremum;; 39 | 40 | Record lock, heap no 4 PHYSICAL RECORD: n_fields 3; compact format; info bits 32 41 | 0: len 4; hex 80000003; asc ;; 42 | 1: len 4; hex 80000001; asc ;; 43 | 2: len 4; hex 80000003; asc ;; 44 | 45 | Record lock, heap no 7 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 46 | 0: len 4; hex 80000003; asc ;; 47 | 1: len 4; hex 80000001; asc ;; 48 | 2: len 4; hex 80000006; asc ;; 49 | 50 | Record lock, heap no 10 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 51 | 0: len 4; hex 80000003; asc ;; 52 | 1: len 4; hex 80000000; asc ;; 53 | 2: len 4; hex 80000009; asc ;; 54 | 55 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 56 | RECORD LOCKS space id 23 page no 4 n bits 80 index xid_valid of table `dldb`.`t16` trx id 399959 lock_mode X locks gap before rec insert intention waiting 57 | Record lock, heap no 10 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 58 | 0: len 4; hex 80000003; asc ;; 59 | 1: len 4; hex 80000000; asc ;; 60 | 2: len 4; hex 80000009; asc ;; 61 | 62 | *** WE ROLL BACK TRANSACTION (2) 63 | ``` 64 | 65 | ## 表结构 66 | 67 | ```sql 68 | CREATE TABLE `t16` ( 69 | `id` int(11) NOT NULL AUTO_INCREMENT, 70 | `xid` int(11) DEFAULT NULL, 71 | `valid` int(11) DEFAULT NULL, 72 | PRIMARY KEY (`id`), 73 | KEY `xid_valid` (`xid`,`valid`) 74 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 75 | ``` 76 | 77 | 初始数据: 78 | 79 | ```sql 80 | INSERT INTO t16(id, xid, valid) VALUES(1, 1, 0); 81 | INSERT INTO t16(id, xid, valid) VALUES(2, 2, 1); 82 | INSERT INTO t16(id, xid, valid) VALUES(3, 3, 1); 83 | INSERT INTO t16(id, xid, valid) VALUES(4, 1, 0); 84 | INSERT INTO t16(id, xid, valid) VALUES(5, 2, 0); 85 | INSERT INTO t16(id, xid, valid) VALUES(6, 3, 1); 86 | INSERT INTO t16(id, xid, valid) VALUES(7, 1, 1); 87 | INSERT INTO t16(id, xid, valid) VALUES(8, 2, 1); 88 | INSERT INTO t16(id, xid, valid) VALUES(9, 3, 0); 89 | INSERT INTO t16(id, xid, valid) VALUES(10, 1, 1); 90 | ``` 91 | 92 | ## 重现步骤 93 | 94 | | Session 1 | Session 2 | 95 | | --- | --- | 96 | |update t16 set xid = 3, valid = 1 where xid = 2;|update t16 set xid = 3, valid = 0 where xid = 3;| 97 | 98 | ## 分析 99 | 100 | 首先要明白 UPDATE 的加锁顺序:在 InnoDB 中,通过二级索引更新记录,首先会在 WHERE 条件使用到的二级索引上加 Next-Key 类型的X锁,以防止查找记录期间的其它插入/删除记录,然后通过二级索引找到 primary key 并在 primary key 上加 Record 类型的X锁,之后更新记录并检查更新字段是否是其它索引中的某列,如果存在这样的索引,通过 update 的旧值到二级索引中删除相应的 entry,此时x锁类型为 Record。 101 | 102 | 这个死锁和案例 16 的场景一模一样。 103 | 104 | 上例中,对二级索引 xid_valid 的更新过程如下所示: 105 | 106 | ![](../master/images/16-17.jpeg) 107 | 108 | 在事务 2 中, `update t16 set xid = 3, valid = 0 where xid = 3` 首先会对 `xid = 3` 的三条记录加上 Next-Key 锁,并在 supremum 上加 Gap 锁,然后开始更新二级索引,由于更新的时候会将新纪录插入到新的位置,所以和 INSERT 加锁流程类似,需要加插入意向锁,如果该位置有 Gap 锁,则会阻塞。 109 | 110 | 同理,在事务 1 中,`update t16 set xid = 3, valid = 1 where xid = 2` 首先会对 `xid = 2` 的三条记录加上 Next-Key 锁,并在 `2-1|8` 和 `3-0|9` 之间加上 Gap 锁,很显然,上面的事务 2 会往 `2-1|8` 和 `3-0|9` 之间插入新记录,所以事务 2 阻塞。同时,事务 1 在处理插入新记录时,和事务 2 的几个 Next-Key 锁冲突,从而导致死锁。 111 | 112 | ## 参考 113 | 114 | 1. [InnoDB inplace-update加锁流程分析 | Learn and live.](http://www.gpfeng.com/?p=406) 115 | -------------------------------------------------------------------------------- /18.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-insert-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X locks rec but not gap 7 | 2. insert WAITING FOR lock mode S, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | ``` 11 | ------------------------ 12 | LATEST DETECTED DEADLOCK 13 | ------------------------ 14 | 2019-04-26 23:52:06 0x7fcb04122700 15 | *** (1) TRANSACTION: 16 | TRANSACTION 2290, ACTIVE 0 sec starting index read 17 | mysql tables in use 1, locked 1 18 | LOCK WAIT 2 lock struct(s), heap size 1136, 1 row lock(s) 19 | MySQL thread id 5, OS thread handle 140509923120896, query id 861 localhost root updating 20 | delete from t18 where id = 4 21 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 22 | RECORD LOCKS space id 24 page no 3 n bits 80 index PRIMARY of table `dldb`.`t18` trx id 2290 lock_mode X locks rec but not gap waiting 23 | Record lock, heap no 5 PHYSICAL RECORD: n_fields 3; compact format; info bits 32 24 | 0: len 4; hex 00000004; asc ;; 25 | 1: len 6; hex 0000000008f1; asc ;; 26 | 2: len 7; hex 7a000001ce01ca; asc z ;; 27 | 28 | *** (2) TRANSACTION: 29 | TRANSACTION 2289, ACTIVE 0 sec inserting 30 | mysql tables in use 1, locked 1 31 | 3 lock struct(s), heap size 1136, 2 row lock(s), undo log entries 1 32 | MySQL thread id 4, OS thread handle 140509923387136, query id 862 localhost root update 33 | insert into t18 (id) values (4) 34 | *** (2) HOLDS THE LOCK(S): 35 | RECORD LOCKS space id 24 page no 3 n bits 80 index PRIMARY of table `dldb`.`t18` trx id 2289 lock_mode X locks rec but not gap 36 | Record lock, heap no 5 PHYSICAL RECORD: n_fields 3; compact format; info bits 32 37 | 0: len 4; hex 00000004; asc ;; 38 | 1: len 6; hex 0000000008f1; asc ;; 39 | 2: len 7; hex 7a000001ce01ca; asc z ;; 40 | 41 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 42 | RECORD LOCKS space id 24 page no 3 n bits 80 index PRIMARY of table `dldb`.`t18` trx id 2289 lock mode S waiting 43 | Record lock, heap no 5 PHYSICAL RECORD: n_fields 3; compact format; info bits 32 44 | 0: len 4; hex 00000004; asc ;; 45 | 1: len 6; hex 0000000008f1; asc ;; 46 | 2: len 7; hex 7a000001ce01ca; asc z ;; 47 | 48 | *** WE ROLL BACK TRANSACTION (1) 49 | ``` 50 | 51 | ## 表结构 52 | 53 | ```sql 54 | CREATE TABLE `t18` ( 55 | `id` int(11) unsigned NOT NULL AUTO_INCREMENT, 56 | PRIMARY KEY (`id`) 57 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 58 | ``` 59 | 60 | 初始数据: 61 | 62 | ```sql 63 | INSERT INTO `t18`(`id`) VALUES (1); 64 | INSERT INTO `t18`(`id`) VALUES (2); 65 | INSERT INTO `t18`(`id`) VALUES (3); 66 | INSERT INTO `t18`(`id`) VALUES (4); 67 | INSERT INTO `t18`(`id`) VALUES (5); 68 | INSERT INTO `t18`(`id`) VALUES (6); 69 | INSERT INTO `t18`(`id`) VALUES (7); 70 | INSERT INTO `t18`(`id`) VALUES (8); 71 | ``` 72 | 73 | ## 重现步骤 74 | 75 | | Session 1 | Session 2 | 76 | | --------- | --------- | 77 | |delete from t18 where id = 4;//ok, 0 rows affected|| 78 | ||delete from t18 where id = 4; //wating,被阻塞| 79 | |insert into t18 values(4);//Query OK, 1 row affected (0.01 sec)|| 80 | | | ERROR 1213 (40001): Deadlock found when trying to get lock;| 81 | 82 | ## 分析 83 | 84 | 1. 事务一delete语句加记录锁(lock_mode X locks rec but not gap) 85 | 2. 事务一delete语句等待记录锁(lock_mode X locks rec but not gap waiting) 86 | 3. 事务一执行insert检查到 duplicate key(或者有一个被标记删除的duplicate key)加LOCK_S锁,且针对主键索引加LOCK_ORDINARY类型的记录锁(NEXT-KEY LOCK);此时事务2已经在申请record lock X锁,在申请队列中了,事务1再加NEXT-KEY LOCK S锁则需要等待事务2提交,这就造成了相互等待。 87 | 88 | 89 | ## 参考 90 | 91 | 1. [并发delete+insert duplicate-key冲突导致死锁](https://my.oschina.net/hebaodan/blog/3033276) 92 | 2. [InnoDB 事务锁系统简介](http://mysql.taobao.org/monthly/2016/01/01/) -------------------------------------------------------------------------------- /19.md: -------------------------------------------------------------------------------- 1 | update-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-holds-lock-mode-s 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. update WAITING FOR lock_mode X locks rec but not gap 7 | 2. delete WAITING FOR lock_mode X , HOLDS lock mode S 8 | 9 | ## 死锁日志 10 | ``` 11 | ------------------------ 12 | LATEST DETECTED DEADLOCK 13 | ------------------------ 14 | 2019-08-02 11:46:04 0x7f2a1409b700 15 | *** (1) TRANSACTION: 16 | TRANSACTION 25567, ACTIVE 3 sec starting index read 17 | mysql tables in use 1, locked 1 18 | LOCK WAIT 6 lock struct(s), heap size 1136, 3 row lock(s), undo log entries 2 19 | MySQL thread id 97, OS thread handle 139818703664896, query id 1444 10.0.56.104 root updating 20 | UPDATE order_pay_status 21 | SET curr_status = 4, 22 | modified = now() 23 | WHERE 24 | id = 9 25 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 26 | RECORD LOCKS space id 259 page no 3 n bits 72 index PRIMARY of table `med_settle_purse`.`order_pay_status` trx id 25567 lock_mode X locks rec but not gap waiting 27 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 10; compact format; info bits 0 28 | 0: len 8; hex 0000000000000009; asc ;; 29 | 1: len 6; hex 0000000063de; asc c ;; 30 | 2: len 7; hex 340000021c1184; asc 4 ;; 31 | 3: len 1; hex 81; asc ;; 32 | 4: len 8; hex 800000000000007b; asc {;; 33 | 5: len 1; hex 83; asc ;; 34 | 6: SQL NULL; 35 | 7: len 1; hex 81; asc ;; 36 | 8: len 5; hex 99a36afc59; asc j Y;; 37 | 9: len 5; hex 99a3c4bb41; asc A;; 38 | 39 | *** (2) TRANSACTION: 40 | TRANSACTION 25569, ACTIVE 3 sec fetching rows 41 | mysql tables in use 2, locked 2 42 | 6 lock struct(s), heap size 1136, 6 row lock(s) 43 | MySQL thread id 98, OS thread handle 139818701534976, query id 1450 10.0.56.104 root Sending data 44 | DELETE from order_pay_status 45 | where id in ( 46 | select b.id from ( 47 | select id from order_pay_status 48 | where id > 0 49 | AND DATE_FORMAT(created,'%Y-%m-%d') < DATE_FORMAT('2019-05-02 19:46:02.555','%Y-%m-%d') 50 | order by id 51 | limit 500 52 | ) b 53 | ) 54 | *** (2) HOLDS THE LOCK(S): 55 | RECORD LOCKS space id 259 page no 3 n bits 72 index PRIMARY of table `med_settle_purse`.`order_pay_status` trx id 25569 lock mode S 56 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 10; compact format; info bits 0 57 | 0: len 8; hex 0000000000000009; asc ;; 58 | 1: len 6; hex 0000000063de; asc c ;; 59 | 2: len 7; hex 340000021c1184; asc 4 ;; 60 | 3: len 1; hex 81; asc ;; 61 | 4: len 8; hex 800000000000007b; asc {;; 62 | 5: len 1; hex 83; asc ;; 63 | 6: SQL NULL; 64 | 7: len 1; hex 81; asc ;; 65 | 8: len 5; hex 99a36afc59; asc j Y;; 66 | 9: len 5; hex 99a3c4bb41; asc A;; 67 | 68 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 69 | RECORD LOCKS space id 259 page no 3 n bits 72 index PRIMARY of table `med_settle_purse`.`order_pay_status` trx id 25569 lock_mode X waiting 70 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 10; compact format; info bits 0 71 | 0: len 8; hex 0000000000000009; asc ;; 72 | 1: len 6; hex 0000000063de; asc c ;; 73 | 2: len 7; hex 340000021c1184; asc 4 ;; 74 | 3: len 1; hex 81; asc ;; 75 | 4: len 8; hex 800000000000007b; asc {;; 76 | 5: len 1; hex 83; asc ;; 77 | 6: SQL NULL; 78 | 7: len 1; hex 81; asc ;; 79 | 8: len 5; hex 99a36afc59; asc j Y;; 80 | 9: len 5; hex 99a3c4bb41; asc A;; 81 | 82 | *** WE ROLL BACK TRANSACTION (2) 83 | ``` 84 | 85 | ## 表结构 86 | 87 | ```sql 88 | CREATE TABLE `order_pay_status` ( 89 | `id` bigint(11) unsigned NOT NULL AUTO_INCREMENT COMMENT '自增主键', 90 | `curr_status` tinyint(1) DEFAULT NULL COMMENT '当前支付状态,值来自account_statement.pay_status', 91 | `status` tinyint(1) DEFAULT NULL COMMENT '1:有效 0:无效', 92 | PRIMARY KEY (`id`), 93 | ) ENGINE=InnoDB AUTO_INCREMENT=42 DEFAULT CHARSET=utf8 COMMENT='支付状态表'; 94 | ``` 95 | 96 | 初始数据: 97 | 98 | ```sql 99 | INSERT INTO `order_pay_status` VALUES (1, 1, 1); 100 | INSERT INTO `order_pay_status` VALUES (2, 1, 1); 101 | INSERT INTO `order_pay_status` VALUES (3, 1, 1); 102 | INSERT INTO `order_pay_status` VALUES (4, 1, 1); 103 | INSERT INTO `order_pay_status` VALUES (9, 1, 1); 104 | INSERT INTO `order_pay_status` VALUES (10, 1, 1); 105 | ``` 106 | 107 | ## 重现步骤 108 | 109 | | Session 1 | Session 2 | 110 | | --------- | --------- | 111 | |DELETE from order_pay_status where id in ( select b.id from ( select id from order_pay_status where id > 3 order by id limit 500 ) b);// 先执行子查询加S锁|| 112 | ||update order_pay_status set curr_status = 4 where id = 9; //lock_mode X locks rec but not gap wating,被阻塞| 113 | |DELETE from order_pay_status where id in ( select b.id from ( select id from order_pay_status where id > 3 order by id limit 500 ) b);// lock_mode X waiting|| 114 | | | ERROR 1213 (40001): Deadlock found when trying to get lock;| 115 | 116 | ## 分析 117 | 118 | 1. 事物A对id=9的记录加lock mode S,成功. 119 | 2. 事物B对id=9的记录加lock_mode X locks rec but not gap waiting,等待。 120 | 3. 事物A对id=9的记录加lock_mode X,等待。因为锁队列是先到先得的,事务B等待事务A的lock mode S锁,事务A等待事务B的lock_mode X locks rec but not gap锁,所以发生死锁。 121 | 122 | 123 | ## 参考 124 | 125 | 1. [并发delete+insert duplicate-key冲突导致死锁](https://my.oschina.net/hebaodan/blog/3033276) 126 | 2. [InnoDB 事务锁系统简介](http://mysql.taobao.org/monthly/2016/01/01/) -------------------------------------------------------------------------------- /2.md: -------------------------------------------------------------------------------- 1 | insert-wait-lock-mode-x-insert-intention-vs-insert-wait-lock-mode-x-insert-intention-holds-lock-mode-s 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. insert WAITING FOR lock_mode X insert intention waiting 7 | 2. insert WAITING FOR lock_mode X insert intention waiting, HOLDS lock_mode S 8 | 3. 隔离级别:RR、RC 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 130701 20:47:57 17 | *** (1) TRANSACTION: 18 | TRANSACTION 4F3D6D24, ACTIVE 13 sec inserting, thread declared inside InnoDB 1 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 4 lock struct(s), heap size 1248, 2 row lock(s), undo log entries 1 21 | MySQL thread id 18124702, OS thread handle 0x7fe706fdf700, query id 1435659684 localhost root update 22 | insert into lingluo values(100214,215,215,312) 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 3351 page no 4 n bits 80 index `uk_bc` of table `test`.`lingluo` trx id 4F3D6D24 lock_mode X insert intention waiting 25 | *** (2) TRANSACTION: 26 | TRANSACTION 4F3D6F33, ACTIVE 11 sec inserting, thread declared inside InnoDB 1 27 | mysql tables in use 1, locked 1 28 | 4 lock struct(s), heap size 1248, 2 row lock(s), undo log entries 1 29 | MySQL thread id 18124715, OS thread handle 0x7fea34912700, query id 1435660081 localhost root update 30 | insert into lingluo values(100215,215,215,312) 31 | *** (2) HOLDS THE LOCK(S): 32 | RECORD LOCKS space id 3351 page no 4 n bits 80 index `uk_bc` of table `test`.`lingluo` trx id 4F3D6F33 lock mode S 33 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 34 | RECORD LOCKS space id 3351 page no 4 n bits 80 index `uk_bc` of table `test`.`lingluo` trx id 4F3D6F33 lock_mode X insert intention waiting 35 | *** WE ROLL BACK TRANSACTION (2) 36 | ``` 37 | 38 | ## 表结构 39 | 40 | ```sql 41 | CREATE TABLE `lingluo` ( 42 | `a` int(11) NOT NULL DEFAULT '0', 43 | `b` int(11) DEFAULT NULL, 44 | `c` int(11) DEFAULT NULL, 45 | `d` int(11) DEFAULT NULL, 46 | PRIMARY KEY (`a`), 47 | UNIQUE KEY `uk_bc` (`b`,`c`) 48 | ) ENGINE=InnoDB DEFAULT CHARSET=gbk 49 | ``` 50 | 51 | ## 重现步骤 52 | 53 | | Session 1 | Session 2 | Session 3 | 54 | | --------- | --------- | --------- | 55 | | insert into lingluo values(100213,215,215,312); | | | 56 | | | insert into lingluo values(100214,215,215,312); | | 57 | | | | insert into lingluo values(100215,215,215,312); | 58 | | rollback; ||| 59 | |||deadlock| 60 | 61 | ## 分析 62 | 63 | 这个死锁的分析分三步: 64 | 65 | 1. 三个事务依次执行 insert 语句,由于 (b,c) 是唯一索引,所以后两个事务会出现唯一键冲突。但此时要注意的是事务一还没有提交,所以并不会立即报错。insert 语句本来加的是隐式锁,在出现唯一键冲突时,事务一的隐式锁升级为显式锁(LOCK_REC_NOT_GAP | LOCK_REC | LOCK_X),事务二和事务三为了判断是否出现唯一键冲突,必须进行一次当前读,加的锁是 Next-Key 锁,所以进入锁等待(LOCK_GAP | LOCK_REC | LOCK_S | LOCK_WAIT)。要注意的是,就算在 RC 隔离级别下,一样会加 Next-Key 锁,所以说出现 GAP 锁不一定就是 RR 隔离级别; 66 | 2. 事务一回滚,此时事务二和事务三成功获取记录上的 S 锁(LOCK_GAP | LOCK_REC | LOCK_S); 67 | 3. 事务二和事务三继续执行插入操作,需要依次请求记录上的插入意向锁(LOCK_INSERT_INTENTION | LOCK_GAP | LOCK_X),插入意向锁和 GAP 锁冲突,所以事务二等待事务三,事务三等待事务二,形成死锁。 68 | 69 | ## 参考 70 | 71 | 1. [Bug #43210 Deadlock detected on concurrent insert into same table (InnoDB)](https://bugs.mysql.com/bug.php?id=43210) 72 | 1. [有趣的insert死锁](http://www.cnblogs.com/sunss/p/3166550.html) 73 | 1. [【MySQL】死锁案例之四](http://blog.itpub.net/22664653/viewspace-2145092/) 74 | 1. [Locks Set by Different SQL Statements in InnoDB](https://dev.mysql.com/doc/refman/5.5/en/innodb-locks-set.html) 75 | -------------------------------------------------------------------------------- /20.md: -------------------------------------------------------------------------------- 1 | Multiple indexes used to get X lock lead to deadlock 2 | === 3 | 4 | ## 数据库信息 5 | 6 | 1. mysql Ver 14.14 Distrib 5.7.27, for Linux (x86_64) using EditLine wrapper 7 | 2. RR(REPEATABLE-READ) Isolation level 8 | 9 | ## 死锁特征 10 | 11 | 1. update WAITING FOR lock_mode X locks rec but not gap waiting 12 | 2. update WAITING FOR lock_mode X locks rec but not gap waiting, hold lock_mode X locks rec but not gap 13 | 14 | 15 | ## 死锁日志 16 | ``` 17 | ------------------------ 18 | LATEST DETECTED DEADLOCK 19 | ------------------------ 20 | 2019-08-22 09:25:58 0x7f8d9b111700 21 | *** (1) TRANSACTION: 22 | TRANSACTION 121318803, ACTIVE 0 sec fetching rows 23 | mysql tables in use 3, locked 3 24 | LOCK WAIT 7 lock struct(s), heap size 1136, 6 row lock(s) 25 | MySQL thread id 3321668, OS thread handle 140246167299840, query id 145836743 localhost momo Creating sort index 26 | SELECT `rank24h`.`id`, `rank24h`.`date`, `rank24h`.`amount`, `rank24h`.`reward`, `rank24h`.`symbol` FROM `rank24h` WHERE (`rank24h`.`date` = '2019-08-23' AND `rank24h`.`symbol` = 'GOLD') ORDER BY `rank24h`.`id` ASC LIMIT 1 FOR UPDATE 27 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 28 | RECORD LOCKS space id 1127 page no 3 n bits 128 index PRIMARY of table `business`.`rank24h` trx id 121318803 lock_mode X locks rec but not gap waiting 29 | Record lock, heap no 51 PHYSICAL RECORD: n_fields 7; compact format; info bits 0 30 | 0: len 4; hex 80000032; asc 2;; 31 | 1: len 6; hex 0000073b2d5c; asc ;-\;; 32 | 2: len 7; hex 7e000001f72da0; asc ~ - ;; 33 | 3: len 3; hex 8fc717; asc ;; 34 | 4: len 10; hex 80000000530000000000; asc S ;; 35 | 5: len 10; hex 80000000140000000000; asc ;; 36 | 6: len 4; hex 56495441; asc SILVER;; 37 | 38 | *** (2) TRANSACTION: 39 | TRANSACTION 121318802, ACTIVE 0 sec fetching rows 40 | mysql tables in use 3, locked 3 41 | 6 lock struct(s), heap size 1136, 3 row lock(s) 42 | MySQL thread id 3321665, OS thread handle 140246168704768, query id 145836737 localhost momo Creating sort index 43 | SELECT `rank24h`.`id`, `rank24h`.`date`, `rank24h`.`amount`, `rank24h`.`reward`, `rank24h`.`symbol` FROM `rank24h` WHERE (`rank24h`.`date` = '2019-08-23' AND `rank24h`.`symbol` = 'SILVER') ORDER BY `rank24h`.`id` ASC LIMIT 1 FOR UPDATE 44 | *** (2) HOLDS THE LOCK(S): 45 | RECORD LOCKS space id 1127 page no 3 n bits 128 index PRIMARY of table `business`.`rank24h` trx id 121318802 lock_mode X locks rec but not gap 46 | Record lock, heap no 51 PHYSICAL RECORD: n_fields 7; compact format; info bits 0 47 | 0: len 4; hex 80000032; asc 2;; 48 | 1: len 6; hex 0000073b2d5c; asc ;-\;; 49 | 2: len 7; hex 7e000001f72da0; asc ~ - ;; 50 | 3: len 3; hex 8fc717; asc ;; 51 | 4: len 10; hex 80000000530000000000; asc S ;; 52 | 5: len 10; hex 80000000140000000000; asc ;; 53 | 6: len 4; hex 56495441; asc SILVER;; 54 | 55 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 56 | RECORD LOCKS space id 1127 page no 4 n bits 128 index rank24h_date_8afc2781 of table `business`.`rank24h` trx id 121318802 lock_mode X locks rec but not gap waiting 57 | Record lock, heap no 51 PHYSICAL RECORD: n_fields 2; compact format; info bits 0 58 | 0: len 3; hex 8fc717; asc ;; 59 | 1: len 4; hex 80000032; asc 2;; 60 | 61 | *** WE ROLL BACK TRANSACTION (2) 62 | ``` 63 | 64 | ## 表结构 65 | 66 | ```sql 67 | DROP TABLE IF EXISTS `rank24h`; 68 | CREATE TABLE `rank24h` ( 69 | `id` int(11) NOT NULL AUTO_INCREMENT, 70 | `date` date NOT NULL, 71 | `amount` decimal(20,10) NOT NULL, 72 | `reward` decimal(20,10) NOT NULL, 73 | `symbol` varchar(8) COLLATE utf8mb4_unicode_ci NOT NULL, 74 | PRIMARY KEY (`id`), 75 | KEY `rank24h_date_8afc2781` (`date`), 76 | KEY `rank24h_symbol_b5eff497` (`symbol`) 77 | ) ENGINE=InnoDB AUTO_INCREMENT=57 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; 78 | ``` 79 | 80 | 初始数据: 81 | 82 | ```sql 83 | INSERT INTO `rank24h` VALUES ('2019-08-23', 100, 100, 'GOLD'); 84 | INSERT INTO `rank24h` VALUES ('2019-08-23', 100, 100, 'SILVER'); 85 | ``` 86 | 87 | ## 重现步骤 88 | 89 | 由于是多索引引起的死锁,暂时无法在数据库层面重现。参考下面的分析过程。 90 | 91 | 92 | ## 分析 93 | 1. 事务二给 symbol 加锁 **(非聚簇索引加锁)** 94 | 2. 事务二给 id=1 加锁 **(聚簇索引加锁)** 95 | 3. 事务一给 symbol 加锁 **(非聚簇索引加锁)** 96 | 4. 事务一给 id=2 加锁 **(聚簇索引加锁)** 97 | 5. 事务二给 date 加锁 **(非聚簇索引加锁)** 98 | 6. 事务二给 id=1,id=2 加锁,和事务一冲突,等待 **(聚簇索引加锁)** 99 | 7. 事务一给 date加锁,和事务二冲突,导致死锁 **(非聚簇索引加锁)** 100 | 101 | ## 变种 102 | 103 | 在使用单一索引和多索引并发更新的时候也会出现死锁: 104 | 105 | ```sql 106 | -- 单索引 事务- 107 | SELECT `rank24h`.`id`, `rank24h`.`date`, `rank24h`.`amount`, `rank24h`.`reward`, `rank24h`.`symbol` FROM `rank24h` WHERE `rank24h`.`date` = '2019-08-23' FOR UPDATE 108 | 109 | -- 多索引 事务二 110 | SELECT `rank24h`.`id`, `rank24h`.`date`, `rank24h`.`amount`, `rank24h`.`reward`, `rank24h`.`symbol` FROM `rank24h` WHERE (`rank24h`.`date` = '2019-08-23' AND `rank24h`.`symbol` = 'GOLD') ORDER BY `rank24h`.`id` ASC LIMIT 1 FOR UPDATE 111 | ``` 112 | 113 | 1. 事务二给 symbol 加锁 **(非聚簇索引加锁)** 114 | 2. 事务二给 id=1 加锁 **(聚簇索引加锁)** 115 | 3. 事务一给 date 加锁 **(非聚簇索引加锁)** 116 | 4. 事务一给 id=1,id=2 加锁,和事务二冲突,等待 **(聚簇索引加锁)** 117 | 5. 事务二给 date 加锁,和事务一冲突,导致死锁 **(非聚簇索引加锁)** 118 | 119 | 120 | ## 参考 121 | 122 | 1. [解决死锁之路(终结篇) - 再见死锁](https://www.aneasystone.com/archives/2018/04/solving-dead-locks-four.html) 123 | 2. [史上最全的select加锁分析(Mysql)](https://www.cnblogs.com/rjzheng/p/9950951.html) 124 | 3. [index merge 引起的死锁分析](http://seanlook.com/2017/03/11/mysql-index_merge-deadlock/) 125 | 4. [一则由于索引导致的MySQL死锁分析](https://www.jianshu.com/p/1dc4250c6f6f) -------------------------------------------------------------------------------- /3.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-holds-lock-mode-x 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X locks rec but not gap 7 | 2. delete WAITING FOR lock_mode X, HOLDS lock_mode X 8 | 3. 隔离级别:RR、RC 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | *** (1) TRANSACTION: 17 | TRANSACTION 1E7D49CDD, ACTIVE 69 sec fetching rows 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 4 lock struct(s), heap size 1248, 4 row lock(s), undo log entries 1 20 | MySQL thread id 1385867, OS thread handle 0x7fcebd956700, query id 837909262 10.246.145.78 im_mobile updating 21 | delete from offmsg_0007 WHERE target_id = 'Y25oaHVwYW7mmZbmmZblpKnkvb8=' and gmt_modified <= '2012-12-14 15:07:14' 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 203 page no 475912 n bits 88 index `PRIMARY` of table `im_mobile`.`offmsg_0007` trx id 1E7D49CDD lock_mode X locks rec but not gap waiting 24 | *** (2) TRANSACTION: 25 | TRANSACTION 1E7CE0399, ACTIVE 1222 sec fetching rows, thread declared inside InnoDB 272 26 | mysql tables in use 1, locked 1 27 | 1346429 lock struct(s), heap size 119896504, 11973543 row lock(s), undo log entries 1 28 | MySQL thread id 1090268, OS thread handle 0x7fcebf48c700, query id 837483530 10.246.145.78 im_mobile updating 29 | delete from offmsg_0007 WHERE target_id = 'Y25oaHVwYW7niLHkuZ3kuYU5OQ==' and gmt_modified <= '2012-12-14 14:13:28' 30 | *** (2) HOLDS THE LOCK(S): 31 | RECORD LOCKS space id 203 page no 475912 n bits 88 index `PRIMARY` of table `im_mobile`.`offmsg_0007` trx id 1E7CE0399 lock_mode X 32 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 33 | RECORD LOCKS space id 203 page no 1611099 n bits 88 index `PRIMARY` of table `im_mobile`.`offmsg_0007` trx id 1E7CE0399 lock_mode X waiting 34 | ``` 35 | 36 | ## 表结构 37 | 38 | ```sql 39 | CREATE TABLE `msg` ( 40 | `id` bigint(20) NOT NULL AUTO_INCREMENT, 41 | `target_id` varchar(100) COLLATE utf8_bin NOT NULL , 42 | `flag` tinyint(4) NOT NULL , 43 | `gmt_create` datetime NOT NULL, 44 | `gmt_modified` datetime NOT NULL, 45 | `datablob` blob, 46 | `nickname` varchar(64) COLLATE utf8_bin DEFAULT NULL , 47 | `source` tinyint(4) DEFAULT NULL , 48 | PRIMARY KEY (`id`), 49 | KEY `idx_o_tid` (`target_id`,`gmt_modified`,`source`,`flag`) 50 | ) ENGINE=InnoDB 51 | ``` 52 | 53 | ## 重现步骤 54 | 55 | | Session 1 | Session 2 | 56 | | --------- | --------- | 57 | | delete from offmsg_0007 WHERE target_id = 'Y25oaHVwYW7niLHkuZ3kuYU5OQ==' and gmt_modified <= '2012-12-14 14:13:28' | delete from offmsg_0007 WHERE target_id = 'Y25oaHVwYW7mmZbmmZblpKnkvb8=' and gmt_modified <= '2012-12-14 15:07:14' | 58 | 59 | ## 分析 60 | 61 | 从死锁日志里可以看出事务二已经持有了 page no 475912 主键上的 next-key 锁,并想要继续获取 page no 1611099 主键上的 next-key 锁,并且这个事务状态为 `fetching rows`,可以推测出事务二正在走主键扫描。而事务一要获取的锁为主键上的记录锁(lock_mode X locks rec but not gap),这是 delete 语句走二级索引正常情况下的加锁模式。 62 | 63 | 那么为什么事务二没有走二级索引?原因很可能是事务二的 WHERE 条件匹配的数据行太多,这种情况 MySQL 的优化器会认为走二级索引回表效率低,还不如直接走主键全表扫描。 64 | 65 | 虽然两个 delete 语句很类似,但是由于走不同索引,对主键索引的加锁顺序的不一致将导致死锁。 66 | 67 | ## 参考 68 | 69 | 1. [[MySQL 学习] Innodb锁系统(1)之如何阅读死锁日志](http://mysqllover.com/?p=411) 70 | 2. [[MySQL 学习] Innodb锁系统(2)关键函数路径](http://mysqllover.com/?p=416) 71 | 3. [[MySQL学习] Innodb锁系统(3)关键结构体及函数](http://mysqllover.com/?p=425) 72 | 4. [[MySQL学习] Innodb锁系统(4) Insert/Delete 锁处理及死锁示例分析](http://mysqllover.com/?p=431) 73 | -------------------------------------------------------------------------------- /4.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-insert-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. insert WAITING FOR lock mode S, HOLDS lock_mode X locks rec but not gap 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 170219 13:31:31 17 | *** (1) TRANSACTION: 18 | TRANSACTION 2A8BD, ACTIVE 11 sec starting index read 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s) 21 | MySQL thread id 448218, OS thread handle 0x2abe5fb5d700, query id 18923238 renjun.fangcloud.net 121.41.41.92 root updating 22 | delete from test where a = 2 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BD lock_mode X waiting 25 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 26 | 0: len 4; hex 00000002; asc ;; 27 | 1: len 4; hex 00000002; asc ;; 28 | *** (2) TRANSACTION: 29 | TRANSACTION 2A8BC, ACTIVE 18 sec inserting 30 | mysql tables in use 1, locked 1 31 | 4 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 2 32 | MySQL thread id 448217, OS thread handle 0x2abe5fd65700, query id 18923239 renjun.fangcloud.net 121.41.41.92 root update 33 | insert into test (id,a) values (10,2) 34 | *** (2) HOLDS THE LOCK(S): 35 | 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 36 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 37 | 0: len 4; hex 00000002; asc ;; 38 | 1: len 4; hex 00000002; asc ;; 39 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 40 | RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BC lock mode S waiting 41 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 42 | 0: len 4; hex 00000002; asc ;; 43 | 1: len 4; hex 00000002; asc ;; 44 | *** WE ROLL BACK TRANSACTION (1) 45 | ``` 46 | 47 | ## 表结构 48 | 49 | ```sql 50 | CREATE TABLE `test` ( 51 | `id` int(11) unsigned NOT NULL AUTO_INCREMENT, 52 | `a` int(11) unsigned DEFAULT NULL, 53 | PRIMARY KEY (`id`), 54 | UNIQUE KEY `a` (`a`) 55 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 56 | ``` 57 | 58 | 初始数据: 59 | 60 | ``` 61 | insert into test(id, a) values(1,1),(2,2),(3,3),(4,4),(5,5),(6,6),(7,7),(8,8); 62 | ``` 63 | 64 | ## 重现步骤 65 | 66 | | Session 1 | Session 2 | 67 | | --------- | --------- | 68 | ||delete from test where a = 2;| 69 | |delete from test where a = 2; || 70 | ||insert into test (id, a) values (10, 2);| 71 | 72 | ## 分析 73 | 74 | delete 语句正常情况下会对存在的记录加记录锁(lock_mode X locks rec but not gap),但是事务一的 delete 语句却在加 next-key 锁(lock_mode X),只有当这条记录已经被标记为删除时才会出现这种情况,我们从 `info bits 32` 也可以看出来这条记录已经被标记为删除了。 75 | 76 | 再从事务二的 `undo log entries 2` 可以推测在执行 insert 之前还执行了至少一条语句,从它 HOLDS 的锁是 lock_mode X locks rec but not gap,并且 page no 也是 923,大致可以猜出事务二先执行了 delete 语句。 77 | 78 | 另外,事务二正在执行 insert 语句,并尝试获取 lock mode S waiting 锁,这是为了检测唯一键是否重复,必须进行一次当前读,要加 S 锁。要注意的是,这里的 S 锁是 lock mode S,而不是 lock_mode S locks rec but not gap,,也就是说检测唯一键加的是 Next-Key 锁,而不是记录锁。 79 | 80 | ## 参考 81 | 82 | 1. [记录一次Mysql死锁排查过程](http://www.kissyu.org/2017/02/19/%E8%AE%B0%E5%BD%95%E4%B8%80%E6%AC%A1Mysql%E6%AD%BB%E9%94%81%E6%8E%92%E6%9F%A5%E8%BF%87%E7%A8%8B/) 83 | 1. [MySQL · 引擎特性 · InnoDB 事务锁系统简介](http://mysql.taobao.org/monthly/2016/01/01/) 84 | -------------------------------------------------------------------------------- /5.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-insert-wait-lock-mode-x-locks-gap-before-rec-insert-intention-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. insert WAITING FOR lock_mode X locks gap before rec insert intention, HOLDS lock_mode X locks rec but not gap 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 170219 13:31:31 17 | *** (1) TRANSACTION: 18 | TRANSACTION 2A8BD, ACTIVE 11 sec starting index read 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s) 21 | MySQL thread id 448218, OS thread handle 0x2abe5fb5d700, query id 18923238 renjun.fangcloud.net 121.41.41.92 root updating 22 | delete from test where a = 2 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BD lock_mode X waiting 25 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 26 | 0: len 4; hex 00000002; asc ;; 27 | 1: len 4; hex 00000002; asc ;; 28 | *** (2) TRANSACTION: 29 | TRANSACTION 2A8BC, ACTIVE 18 sec inserting 30 | mysql tables in use 1, locked 1 31 | 4 lock struct(s), heap size 1248, 3 row lock(s), undo log entries 2 32 | MySQL thread id 448217, OS thread handle 0x2abe5fd65700, query id 18923239 renjun.fangcloud.net 121.41.41.92 root update 33 | insert into test (id,a) values (10,2) 34 | *** (2) HOLDS THE LOCK(S): 35 | 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 36 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 37 | 0: len 4; hex 00000002; asc ;; 38 | 1: len 4; hex 00000002; asc ;; 39 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 40 | RECORD LOCKS space id 0 page no 923 n bits 80 index `a` of table `oauthdemo`.`test` trx id 2A8BC lock_mode X locks gap before rec insert intention waiting 41 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 2; compact format; info bits 32 42 | 0: len 4; hex 00000002; asc ;; 43 | 1: len 4; hex 00000002; asc ;; 44 | *** WE ROLL BACK TRANSACTION (1) 45 | ``` 46 | 47 | ## 表结构 48 | 49 | ```sql 50 | CREATE TABLE `test` ( 51 | `id` int(11) unsigned NOT NULL AUTO_INCREMENT, 52 | `a` int(11) unsigned DEFAULT NULL, 53 | PRIMARY KEY (`id`), 54 | UNIQUE KEY `a` (`a`) 55 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 56 | ``` 57 | 58 | ## 重现步骤 59 | 60 | | Session 1 | Session 2 | 61 | | --------- | --------- | 62 | ||delete from test where a = 2;| 63 | ||insert into test (id, a) values (10, 2); insert第1阶段:事务2申请S锁进行duplicate key进行检查。检查成功。| 64 | |delete from test where a = 2; || 65 | ||insert into test (id, a) values (10, 2); insert第2阶段:事务2开始插入数据,S锁升级为X锁,类型为insert intention。同理,X锁进入队列排队,形成循环等待,死锁产生。| 66 | 67 | ## 分析 68 | 69 | 这个场景和 [delete-wait-lock-mode-x-vs-insert-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap](4.md) 一模一样,但是没办法手动重现,只能在高并发情况下可能会出现。 70 | 71 | 这个死锁的原因在于 insert 加锁分几个阶段:先检查唯一键约束,加 S 锁,再加插入意向锁,最后插入成功时升级为 X 锁。 72 | 73 | [delete-wait-lock-mode-x-vs-insert-wait-lock-mode-s-holds-lock-mode-x-locks-rec-but-not-gap](4.md) 中,insert 加 S 锁时冲突导致死锁,而这里是加插入意向锁时冲突导致死锁。 74 | 75 | ## 参考 76 | 77 | 1. [记录一次Mysql死锁排查过程](http://www.kissyu.org/2017/02/19/%E8%AE%B0%E5%BD%95%E4%B8%80%E6%AC%A1Mysql%E6%AD%BB%E9%94%81%E6%8E%92%E6%9F%A5%E8%BF%87%E7%A8%8B/) 78 | -------------------------------------------------------------------------------- /6.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-vs-delete-wait-lock-mode-x-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X 7 | 2. delete WAITING FOR lock mode X, HOLDS lock_mode X locks rec but not gap 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 140122 18:11:58 17 | *** (1) TRANSACTION: 18 | TRANSACTION 930F9, ACTIVE 0 sec starting index read 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s) 21 | MySQL thread id 2096, OS thread handle 0x7f3570976700, query id 1485879 localhost 127.0.0.1 rj updating 22 | delete from dltask where a = 'b' and b = 'b' and c = 'a' 23 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 24 | RECORD LOCKS space id 0 page no 12713 n bits 96 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 930F9 lock_mode X waiting 25 | *** (2) TRANSACTION: 26 | TRANSACTION 930F3, ACTIVE 0 sec starting index read 27 | mysql tables in use 1, locked 1 28 | 3 lock struct(s), heap size 376, 2 row lock(s) 29 | MySQL thread id 2101, OS thread handle 0x7f3573d88700, query id 1485872 localhost 127.0.0.1 rj updating 30 | delete from dltask where a = 'b' and b = 'b' and c = 'a' 31 | *** (2) HOLDS THE LOCK(S): 32 | RECORD LOCKS space id 0 page no 12713 n bits 96 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 930F3 lock_mode X locks rec but not gap 33 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 34 | RECORD LOCKS space id 0 page no 12713 n bits 80 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 930F3 lock mode X waiting 35 | *** WE ROLL BACK TRANSACTION (1) 36 | ``` 37 | 38 | ## 表结构 39 | 40 | ```sql 41 | CREATE TABLE dltask ( 42 | id bigint unsigned NOT NULL AUTO_INCREMENT COMMENT ‘auto id’, 43 | a varchar(30) NOT NULL COMMENT ‘uniq.a’, 44 | b varchar(30) NOT NULL COMMENT ‘uniq.b’, 45 | c varchar(30) NOT NULL COMMENT ‘uniq.c’, 46 | x varchar(30) NOT NULL COMMENT ‘data’, 47 | PRIMARY KEY (id), 48 | UNIQUE KEY uniq_a_b_c (a, b, c) 49 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT=’deadlock test’; 50 | ``` 51 | 52 | ## 重现步骤 53 | 54 | | Session 1 | Session 2 | Session 3 | 55 | | --------- | --------- | --------- | 56 | |delete from dltask where a=’a’ and b=’b’ and c=’c’;|delete from dltask where a=’a’ and b=’b’ and c=’c’;|delete from dltask where a=’a’ and b=’b’ and c=’c’;| 57 | 58 | ## 分析 59 | 60 | delete 语句的加锁有三种情况: 61 | 1. 记录存在且有效:加记录X锁(lock_mode X locks rec but not gap); 62 | 2. 记录存在但无效(被标记为删除):加 Next-key 锁(lock_mode X); 63 | 3. 记录不存在:加 gap 锁(locks gap before rec); 64 | 65 | 从事务二 HOLDS THE LOCK `lock_mode X locks rec but not gap` 可以看出事务二已经成功删除了这条记录,并且给这条记录打上了删除标记,所以事务一在删除的时候 WAIT 的锁是 Next-key 锁(lock_mode X)。但是,为什么事务二都已经成功删除了记录,却还要等待 Next-key 锁呢? 66 | 67 | 其实这个地方我们有点先入为主了,持有记录锁(locks rec but not gap)的事务不一定就是成功删除记录的事务,因为从获取记录锁到把记录标记为删除,这中间还有一个时间间隙,所以在大并发下,可能会出现两个事务同时争取记录锁。 68 | 69 | | Session 1 | Session 2 | 70 | | --------- | --------- | 71 | |获取记录锁(locks rec but not gap)|| 72 | ||获取记录锁(locks rec but not gap),和事务一冲突,等待| 73 | |将记录标记为删除,并提交事务|| 74 | ||记录锁获取成功| 75 | 76 | 这个时候虽然事务二也获取了记录锁,但是这条记录已经发生了变动,MySQL 会重新对该记录加锁,但是原来加的记录锁并不会释放,如果此时再有一个事务发起 delete 操作,就有可能发生死锁。 77 | 78 | | Session 2 | Session 3 | 79 | | --------- | --------- | 80 | |记录变动,需重新加锁,但记录锁保持不变|| 81 | ||发起删除操作,由于记录标记为删除,所以获取 Next-key 锁,和事务二的记录锁冲突| 82 | |重新加锁时获取 Next-key 锁,和事务三冲突,发生死锁 |.| 83 | 84 | 关于这个死锁,还有另一个形式:[delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-holds-lock-mode-x-locks-rec-but-not-gap](7.md) 85 | 86 | 更多的分析可以阅读后面的参考链接。 87 | 88 | ## 参考 89 | 90 | 1. [一个最不可思议的MySQL死锁分析](http://hedengcheng.com/?p=844) 91 | 2. http://hedengcheng.com/?p=771#comment-5549 92 | -------------------------------------------------------------------------------- /7.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X locks rec but not gap 7 | 2. delete WAITING FOR lock mode X, HOLDS lock_mode X locks rec but not gap 8 | 3. 隔离级别:RR 9 | 10 | ## 死锁日志 11 | 12 | ``` 13 | ------------------------ 14 | LATEST DETECTED DEADLOCK 15 | ------------------------ 16 | 2014-01-22 20:48:08 7f4248516700 17 | *** (1) TRANSACTION: 18 | TRANSACTION 2268, ACTIVE 0 sec starting index read 19 | mysql tables in use 1, locked 1 20 | LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s) 21 | MySQL thread id 11, OS thread handle 0x7f4248494700, query id 1207 localhost 127.0.0.1 rj updating 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 6 page no 4 n bits 96 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 2268 lock_mode X locks rec but not gap waiting 24 | *** (2) TRANSACTION: 25 | TRANSACTION 2271, ACTIVE 0 sec starting index read 26 | mysql tables in use 1, locked 1 27 | 3 lock struct(s), heap size 376, 2 row lock(s) 28 | MySQL thread id 9, OS thread handle 0x7f4248516700, query id 1208 localhost 127.0.0.1 rj updating 29 | delete from dltask where a=’b’ and b=’a’ and c=’c’ 30 | *** (2) HOLDS THE LOCK(S): 31 | RECORD LOCKS space id 6 page no 4 n bits 96 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 2271 lock_mode X locks rec but not gap 32 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 33 | RECORD LOCKS space id 6 page no 4 n bits 96 index `uniq_a_b_c` of table `dltst`.`dltask` trx id 2271 lock_mode X waiting 34 | *** WE ROLL BACK TRANSACTION (1) 35 | ``` 36 | 37 | ## 表结构 38 | 39 | ```sql 40 | CREATE TABLE dltask ( 41 | id bigint unsigned NOT NULL AUTO_INCREMENT COMMENT ‘auto id’, 42 | a varchar(30) NOT NULL COMMENT ‘uniq.a’, 43 | b varchar(30) NOT NULL COMMENT ‘uniq.b’, 44 | c varchar(30) NOT NULL COMMENT ‘uniq.c’, 45 | x varchar(30) NOT NULL COMMENT ‘data’, 46 | PRIMARY KEY (id), 47 | UNIQUE KEY uniq_a_b_c (a, b, c) 48 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT=’deadlock test’; 49 | ``` 50 | 51 | ## 重现步骤 52 | 53 | | Session 1 | Session 2 | Session 3 | Session 4 | 54 | | --------- | --------- | --------- | --------- | 55 | |delete from dltask where a=’a’ and b=’b’ and c=’c’;|delete from dltask where a=’a’ and b=’b’ and c=’c’;|delete from dltask where a=’a’ and b=’b’ and c=’c’;|delete from dltask where a=’a’ and b=’b’ and c=’c’;| 56 | 57 | ## 分析 58 | 59 | 这个死锁和 [delete-wait-lock-mode-x-vs-delete-wait-lock-mode-x-holds-lock-mode-x-locks-rec-but-not-gap](6.md) 场景是一样的,只是稍微要复杂一点。我推测的结果如下(不一定正确,如有不足,欢迎斧正): 60 | 61 | | Session 1 | Session 2 | Session 3 | Session 4 | 62 | | --------- | --------- | --------- | --------- | 63 | |获取记录锁(locks rec but not gap)|||| 64 | ||获取记录锁(locks rec but not gap),和事务一冲突,等待||| 65 | |||获取记录锁(locks rec but not gap),和事务二冲突,等待|| 66 | |将记录标记为删除,并提交事务|||| 67 | ||记录锁获取成功||| 68 | ||记录变动,需重新加锁,但记录锁保持不变||| 69 | ||||发起删除操作,由于记录标记为删除,所以获取 Next-key 锁,和事务三的记录锁冲突| 70 | ||重新加锁时获取 Next-key 锁,和事务四冲突,发生死锁 ||.| 71 | 72 | 至此,事务三等待事务二,事务四等待事务三,事务二等待事务四,三个事务相互等待导致死锁。 73 | 74 | 注意死锁日志中只会显示两个事务,在遇到多个事务导致死锁时就不好分析。 75 | 76 | ## 参考 77 | 78 | 1. [一个最不可思议的MySQL死锁分析](http://hedengcheng.com/?p=844) 79 | 2. http://hedengcheng.com/?p=771#comment-5549 80 | -------------------------------------------------------------------------------- /8.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-locks-rec-but-not-gap-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X locks rec but not gap 7 | 2. delete WAITING FOR lock_mode X locks rec but not gap, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2018-04-03 13:22:29 0xbd0 16 | *** (1) TRANSACTION: 17 | TRANSACTION 245852, ACTIVE 0 sec starting index read 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 3 lock struct(s), heap size 1136, 2 row lock(s), undo log entries 1 20 | MySQL thread id 91, OS thread handle 6964, query id 366044 localhost ::1 root updating 21 | delete from t where id = 2 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 87 page no 3 n bits 72 index PRIMARY of table `sys`.`t` trx id 245852 lock_mode X locks rec but not gap waiting 24 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 6; compact format; info bits 32 25 | 0: len 4; hex 80000002; asc ;; 26 | 1: len 6; hex 00000003c05d; asc ];; 27 | 2: len 7; hex 70000001850bf6; asc p ;; 28 | 3: len 4; hex 80000004; asc ;; 29 | 4: len 4; hex 80000005; asc ;; 30 | 5: len 4; hex 80000006; asc ;; 31 | 32 | *** (2) TRANSACTION: 33 | TRANSACTION 245853, ACTIVE 0 sec starting index read, thread declared inside InnoDB 5000 34 | mysql tables in use 1, locked 1 35 | 3 lock struct(s), heap size 1136, 2 row lock(s), undo log entries 1 36 | MySQL thread id 93, OS thread handle 3024, query id 366045 localhost ::1 root updating 37 | delete from t where id = 1 38 | *** (2) HOLDS THE LOCK(S): 39 | RECORD LOCKS space id 87 page no 3 n bits 72 index PRIMARY of table `sys`.`t` trx id 245853 lock_mode X locks rec but not gap 40 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 6; compact format; info bits 32 41 | 0: len 4; hex 80000002; asc ;; 42 | 1: len 6; hex 00000003c05d; asc ];; 43 | 2: len 7; hex 70000001850bf6; asc p ;; 44 | 3: len 4; hex 80000004; asc ;; 45 | 4: len 4; hex 80000005; asc ;; 46 | 5: len 4; hex 80000006; asc ;; 47 | 48 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 49 | RECORD LOCKS space id 87 page no 3 n bits 72 index PRIMARY of table `sys`.`t` trx id 245853 lock_mode X locks rec but not gap waiting 50 | Record lock, heap no 2 PHYSICAL RECORD: n_fields 6; compact format; info bits 32 51 | 0: len 4; hex 80000001; asc ;; 52 | 1: len 6; hex 00000003c05c; asc \;; 53 | 2: len 7; hex 6f0000015a1a7e; asc o Z ~;; 54 | 3: len 4; hex 80000001; asc ;; 55 | 4: len 4; hex 80000002; asc ;; 56 | 5: len 4; hex 80000003; asc ;; 57 | 58 | *** WE ROLL BACK TRANSACTION (2) 59 | ``` 60 | 61 | ## 表结构 62 | 63 | ```sql 64 | CREATE TABLE `t` ( 65 | `id` INT(11) NOT NULL AUTO_INCREMENT, 66 | `a` INT(11) DEFAULT NULL, 67 | PRIMARY KEY (`id`) 68 | ) ENGINE=INNODB 69 | ``` 70 | 71 | ## 重现步骤 72 | 73 | | Session 1 | Session 2 | 74 | | --------- | --------- | 75 | |delete from t where id = 1|| 76 | ||delete from t where id = 2| 77 | |delete from t where id = 2|| 78 | ||delete from t where id = 1| 79 | 80 | 也可以通过下面的 mysqlslap 命令模拟死锁场景: 81 | 82 | ``` 83 | mysqlslap --create-schema sys -q "begin; delete from t where id = 1; delete from t where id = 2; rollback;" --number-of-queries=100000 -uroot -p 84 | mysqlslap --create-schema sys -q "begin; delete from t where id = 2; delete from t where id = 1; rollback;" --number-of-queries=100000 -uroot -p 85 | ``` 86 | 87 | ## 分析 88 | 89 | 死锁的根本原因是有两个或多个事务之间加锁顺序的不一致导致的,这个死锁案例其实是最经典的死锁场景。 90 | 91 | 首先,事务一获取 id = 1 的锁,事务二获取 id = 2 的锁;然后,事务一试图获取 id = 2 的锁,事务二试图获取 id = 1 的锁,相互等待导致死锁。 92 | 93 | 这个死锁并不难理解,不过根据这个死锁日志倒推出死锁场景却并不容易,因为有些死锁场景和这个几乎一模一样,譬如 [delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-locks-rec-but-not-gap-holds-lock-mode-x-locks-rec-but-not-gap](9.md),而且这种死锁很可能是三个或三个以上的事务导致的,譬如下面这样: 94 | 95 | | Session 1 | Session 2 | Session 3 | 96 | | --------- | --------- | --------- | 97 | |delete from t where id = 1|delete from t where id = 2|delete from t where id = 3| 98 | ||delete from t where id = 1|| 99 | |||delete from t where id = 2| 100 | |delete from t where id = 3||| 101 | 102 | 这种场景的死锁日志和上述两个事务的死锁日志没有任何区别,所以具体情况还需要具体分析。 103 | 104 | 如果事务执行的两个 SQL 语句不属于同一个表,死锁情形是一样的,参考[1]。 105 | 106 | ## 参考 107 | 108 | 1. [MySQL死锁案例分析(一)](http://www.fordba.com/mysql_dead_lock_1st.html) 109 | -------------------------------------------------------------------------------- /9.md: -------------------------------------------------------------------------------- 1 | delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-locks-rec-but-not-gap-holds-lock-mode-x-locks-rec-but-not-gap 2 | === 3 | 4 | ## 死锁特征 5 | 6 | 1. delete WAITING FOR lock_mode X locks rec but not gap 7 | 2. delete WAITING FOR lock_mode X locks rec but not gap, HOLDS lock_mode X locks rec but not gap 8 | 9 | ## 死锁日志 10 | 11 | ``` 12 | ------------------------ 13 | LATEST DETECTED DEADLOCK 14 | ------------------------ 15 | 2018-04-03 09:50:13 0x2bec 16 | *** (1) TRANSACTION: 17 | TRANSACTION 239662, ACTIVE 0 sec starting index read 18 | mysql tables in use 1, locked 1 19 | LOCK WAIT 3 lock struct(s), heap size 1136, 2 row lock(s) 20 | MySQL thread id 87, OS thread handle 7632, query id 356196 localhost ::1 root updating 21 | delete from t where a = 4 22 | *** (1) WAITING FOR THIS LOCK TO BE GRANTED: 23 | RECORD LOCKS space id 87 page no 3 n bits 72 index PRIMARY of table `sys`.`t` trx id 239662 lock_mode X locks rec but not gap waiting 24 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 6; compact format; info bits 32 25 | 0: len 4; hex 80000002; asc ;; 26 | 1: len 6; hex 00000003a82d; asc -;; 27 | 2: len 7; hex 57000001a82e44; asc W .D;; 28 | 3: len 4; hex 80000004; asc ;; 29 | 4: len 4; hex 80000005; asc ;; 30 | 5: len 4; hex 80000006; asc ;; 31 | 32 | *** (2) TRANSACTION: 33 | TRANSACTION 239661, ACTIVE 0 sec updating or deleting, thread declared inside InnoDB 4999 34 | mysql tables in use 1, locked 1 35 | 4 lock struct(s), heap size 1136, 3 row lock(s), undo log entries 1 36 | MySQL thread id 89, OS thread handle 11244, query id 356194 localhost ::1 root updating 37 | delete from t where b = 5 38 | *** (2) HOLDS THE LOCK(S): 39 | RECORD LOCKS space id 87 page no 3 n bits 72 index PRIMARY of table `sys`.`t` trx id 239661 lock_mode X locks rec but not gap 40 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 6; compact format; info bits 32 41 | 0: len 4; hex 80000002; asc ;; 42 | 1: len 6; hex 00000003a82d; asc -;; 43 | 2: len 7; hex 57000001a82e44; asc W .D;; 44 | 3: len 4; hex 80000004; asc ;; 45 | 4: len 4; hex 80000005; asc ;; 46 | 5: len 4; hex 80000006; asc ;; 47 | 48 | *** (2) WAITING FOR THIS LOCK TO BE GRANTED: 49 | RECORD LOCKS space id 87 page no 4 n bits 72 index idx_a_b of table `sys`.`t` trx id 239661 lock_mode X locks rec but not gap waiting 50 | Record lock, heap no 3 PHYSICAL RECORD: n_fields 3; compact format; info bits 0 51 | 0: len 4; hex 80000004; asc ;; 52 | 1: len 4; hex 80000005; asc ;; 53 | 2: len 4; hex 80000002; asc ;; 54 | 55 | *** WE ROLL BACK TRANSACTION (1) 56 | ``` 57 | 58 | ## 表结构 59 | 60 | ```sql 61 | CREATE TABLE `t` ( 62 | `id` INT(11) NOT NULL AUTO_INCREMENT, 63 | `a` INT(11) DEFAULT NULL, 64 | `b` INT(11) DEFAULT NULL, 65 | `c` INT(11) DEFAULT NULL, 66 | PRIMARY KEY (`id`), 67 | KEY `idx_a_b` (`a`,`b`), 68 | KEY `idx_b` (`b`) 69 | ) ENGINE=INNODB 70 | ``` 71 | 72 | ## 重现步骤 73 | 74 | | Session 1 | Session 2 | 75 | | --------- | --------- | 76 | |delete from t where a = 4|delete from t where b = 5| 77 | 78 | 也可以通过下面的 mysqlslap 命令模拟死锁场景: 79 | 80 | ``` 81 | mysqlslap --create-schema sys -q "begin; delete from t where a = 4; rollback;" --number-of-queries=100000 -uroot -p 82 | mysqlslap --create-schema sys -q "begin; delete from t where b = 5; rollback;" --number-of-queries=100000 -uroot -p 83 | ``` 84 | 85 | ## 分析 86 | 87 | 这个死锁现象和 [delete-wait-lock-mode-x-locks-rec-but-not-gap-vs-delete-wait-lock-mode-x-locks-rec-but-not-gap-holds-lock-mode-x-locks-rec-but-not-gap](8.md) 几乎是一模一样的,区别在于锁的索引不一样,前者正在等待索引 idx_a_b 上的锁,而后者正在等待 PRIMARY 上的锁。 88 | 89 | 这个其实也是典型的由于两个事务之间加锁顺序不一致导致的死锁场景,虽然两个事务都只有一条 SQL 语句,但是这两条语句加锁的顺序是有区别的,如下: 90 | 91 | 事务一 `delete from t where a = 4` 走 idx_a_b 索引,首先会对 a = 4 对应的 idx_a_b 二级索引加锁,然后对主键索引 id = 2 加锁,最后会给 a = 4 对应的 idx_b 二级索引加锁;事务二 `delete from t where b = 5` 走的是 idx_b 索引,首先对 b = 5 对应的 idx_b 二级索引加锁,然后对主键索引 id = 2 加锁,最后会给 b = 5 对应的 idx_a_b 二级索引加锁,如下: 92 | 93 | | Session 1 | Session 2 | 94 | | --------- | --------- | 95 | ||对 idx_b 索引 b = 5 加锁| 96 | ||对主键 id = 2 加锁| 97 | |对 idx_a_b 索引 a = 4 加锁|| 98 | |对主键 id = 2 加锁,等待|| 99 | ||对 idx_a_b 索引 a = 4 加锁,等待,死锁| 100 | 101 | 这里的例子是 delete 语句,通过二级索引删除记录的加锁顺序为:二级索引(WHERE使用到二级索引)–> 主键索引 –> 所有其它二级索引;如果是 update 语句,加锁顺序也类似,通过二级索引更新记录的加锁顺序为:二级索引(WHERE条件使用二级索引)–> 主键索引 –> 包含更新字段的其它二级索引。 102 | 103 | ## 参考 104 | 105 | 1. [InnoDB inplace-update加锁流程分析](http://www.gpfeng.com/?p=406) 106 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # mysql-deadlocks 2 | 3 | 在工作过程中偶尔会遇到死锁问题,虽然这种问题遇到的概率不大,但每次遇到的时候要想彻底弄懂其原理并找到解决方案却并不容易。这个项目收集了一些常见的 MySQL 死锁案例,大多数案例都来源于网络,并对其进行分类汇总,试图通过死锁日志分析出每种死锁的原因,还原出死锁现场。 4 | 5 | 实际上,我们在定位死锁问题时,不仅应该对死锁日志进行分析,还应该结合具体的业务代码,或者根据 binlog,理出每个事务执行的 SQL 语句。 6 | 7 | 我将这些死锁按事务执行的语句和正在等待或已持有的锁进行分类汇总: 8 | 9 | |事务一语句|事务二语句|事务一等待锁|事务二等待锁|事务二持有锁|案例| 10 | |---------|-----------|---------|-----------|-----------|---| 11 | |insert|insert|lock_mode X insert intention|lock_mode X insert intention|lock_mode X|[1](/1.md)| 12 | |insert|insert|lock_mode X locks gap before rec insert intention|lock_mode X locks gap before rec insert intention|lock_mode X locks gap before rec|[14](/14.md)| 13 | |insert|insert|lock_mode X insert intention|lock_mode X insert intention|lock_mode S|[2](/2.md)| 14 | |insert|insert|lock mode S|lock_mode X locks gap before rec insert intention|lock_mode X locks rec but not gap|[15](/15.md)| 15 | |delete|insert|lock_mode X locks rec but not gap|lock mode S|lock_mode X locks rec but not gap|[18](/18.md)| 16 | |delete|delete|lock_mode X|lock mode S|lock_mode X locks rec but not gap|[4](/4.md)| 17 | |delete|delete|lock_mode X|lock mode X|lock_mode X locks rec but not gap|[6](/6.md)| 18 | |delete|delete|lock_mode X locks rec but not gap|lock_mode X|lock_mode X|[3](/3.md)| 19 | |delete|delete|lock_mode X locks rec but not gap|lock mode X|lock_mode X locks rec but not gap|[7](/7.md)| 20 | |delete|delete|lock_mode X locks rec but not gap|lock_mode X locks rec but not gap|lock_mode X locks rec but not gap|[8](/8.md),[9](/9.md)| 21 | |delete|insert|lock_mode X|lock_mode X locks gap before rec insert intention|lock_mode X locks rec but not gap|[5](/5.md)| 22 | |delete|insert|lock_mode X|lock_mode X locks gap before rec insert intention|lock_mode S|[10](/10.md)| 23 | |delete|insert|lock_mode X|lock_mode X locks gap before rec insert intention|lock_mode X|[12](/12.md)| 24 | |delete|insert|lock_mode X|lock mode S|lock_mode X locks rec but not gap|[13](/13.md)| 25 | |update|update|lock_mode X locks rec but not gap|lock mode S|lock_mode X locks rec but not gap|[11](/11.md)| 26 | |update|update|lock_mode X|lock_mode X locks gap before rec insert intention|lock_mode X locks rec but not gap|[16](/16.md)| 27 | |update|update|lock_mode X locks gap before rec insert intention|lock_mode X locks gap before rec insert intention|lock_mode X|[17](/17.md)| 28 | |update|delete|lock_mode X locks rec but not gap|lock_mode X|lock mode S|[19](/19.md)| 29 | |update|update|lock_mode X locks rec but not gap waiting|lock_mode X locks rec but not gap waiting|lock_mode X locks rec but not gap|[20](/20.md)| 30 | 31 | 表中的语句虽然大多数只列出了 delete 和 insert,但实际上绝大多数的 delete 语句和 update 或 select ... for update 加锁机制是一样的,所以为了避免重复,对于 update 语句就不在一起汇总了(当然也有例外,譬如使用 update 对索引进行更新时加锁机制和 delete 是有区别的,这种情况我会单独列出,如案例 11)。 32 | 33 | 对每一个死锁场景,我都会定义一个死锁名称(实际上就是事务等待和持有的锁),每一篇分析,我都分成了 死锁特征、死锁日志、表结构、重现步骤、分析和参考 这几个部分。 34 | 35 | 对于这种分类方法我感觉并不是很好,但也想不出什么其他更好的方案,如果你有更好的建议,欢迎讨论。另外,如果你有新的死锁案例,或者对某个死锁的解释有异议,欢迎给我提 Issue 或 PR。 36 | 37 | ## 死锁分析 38 | 39 | 之前写过关于死锁的一系列博客,供参考。 40 | 41 | * [解决死锁之路 - 学习事务与隔离级别](https://www.aneasystone.com/archives/2017/10/solving-dead-locks-one.html) 42 | * [解决死锁之路 - 了解常见的锁类型](https://www.aneasystone.com/archives/2017/11/solving-dead-locks-two.html) 43 | * [解决死锁之路 - 常见 SQL 语句的加锁分析](https://www.aneasystone.com/archives/2017/12/solving-dead-locks-three.html) 44 | * [解决死锁之路(终结篇) - 再见死锁](https://www.aneasystone.com/archives/2018/04/solving-dead-locks-four.html) 45 | * [读 MySQL 源码再看 INSERT 加锁流程](https://www.aneasystone.com/archives/2018/06/insert-locks-via-mysql-source-code.html) 46 | 47 | ## 死锁重现 48 | 49 | docker 目录下包含了各个死锁重现的测试脚本,测试步骤如下: 50 | 51 | 1. 创建数据库和初始数据 52 | 53 | ``` 54 | # cd docker 55 | # docker-compose up -d 56 | ``` 57 | 58 | 确保机器上安装了 docker 和 docker-compose,上面的命令会启动一个 mysql:5.7 的容器,并创建一个名为 dldb 的数据库,初始密码为 123456,并通过 `docker-entrypoint-initdb.d` 初始化所有案例所需要的表和数据。 59 | 60 | 2. 等待容器启动结束 61 | 62 | ``` 63 | # docker logs -f dldb 64 | ``` 65 | 66 | 使用 `dockere logs` 查看容器启动日志,如果出现数据初始化完成的提示,如下所示,则进入下一步。 67 | 68 | ``` 69 | MySQL init process in progress... 70 | Warning: Unable to load '/usr/share/zoneinfo/iso3166.tab' as time zone. Skipping it. 71 | Warning: Unable to load '/usr/share/zoneinfo/leap-seconds.list' as time zone. Skipping it. 72 | Warning: Unable to load '/usr/share/zoneinfo/zone.tab' as time zone. Skipping it. 73 | Warning: Unable to load '/usr/share/zoneinfo/zone1970.tab' as time zone. Skipping it. 74 | 75 | /usr/local/bin/docker-entrypoint.sh: running /docker-entrypoint-initdb.d/t16.sql 76 | mysql: [Warning] Using a password on the command line interface can be insecure. 77 | 78 | /usr/local/bin/docker-entrypoint.sh: running /docker-entrypoint-initdb.d/t18.sql 79 | mysql: [Warning] Using a password on the command line interface can be insecure. 80 | 81 | /usr/local/bin/docker-entrypoint.sh: running /docker-entrypoint-initdb.d/t8.sql 82 | mysql: [Warning] Using a password on the command line interface can be insecure. 83 | 84 | MySQL init process done. Ready for start up. 85 | ``` 86 | 87 | 3. 进入容器执行测试脚本 88 | 89 | 首先进入容器: 90 | 91 | ``` 92 | # docker exec -it dldb bash 93 | ``` 94 | 95 | 然后执行测试脚本,测试脚本在每一个案例对应的 SQL 文件中,比如案例 18 对应的测试脚本如下: 96 | 97 | ``` 98 | # mysqlslap --create-schema dldb -q "begin; delete from t18 where id = 4; insert into t18 (id) values (4); rollback;" --number-of-queries=100000 -uroot -p123456 & 99 | # mysqlslap --create-schema dldb -q "begin; delete from t18 where id = 4; rollback;" --number-of-queries=100000 -uroot -p123456 & 100 | ``` 101 | 102 | 测试脚本通过 `mysqlslap` 工具并发执行两个事务,每个事务执行 N 次(N = 100000),如果两个事务会出现死锁,则我们可以通过死锁日志看到。 103 | 104 | 4. 检查是否出现死锁日志 105 | 106 | ``` 107 | # tail -f /var/log/mysql/error.log 108 | ``` 109 | 110 | ## TODO 111 | 112 | - [ ] 重现案例 1 113 | - [ ] 重现案例 2 114 | - [ ] 重现案例 3 115 | - [ ] 重现案例 4 116 | - [ ] 重现案例 5 117 | - [ ] 重现案例 6 118 | - [ ] 重现案例 7 119 | - [x] 重现案例 8 120 | - [ ] 重现案例 9 121 | - [ ] 重现案例 10 122 | - [ ] 重现案例 11 123 | - [ ] 重现案例 12 124 | - [ ] 重现案例 13 125 | - [ ] 重现案例 14 126 | - [ ] 重现案例 15 127 | - [x] 重现案例 16 128 | - [ ] 重现案例 17 129 | - [x] 重现案例 18 130 | - [ ] 重现案例 19 131 | - [ ] 重现案例 20 132 | - [ ] 由于相同的测试脚本在并发的时候可能产生不同的死锁,后续可以写个脚本来解析 error.log 看看发生了多少次死锁 133 | - [ ] 使用 mysqlslap 测试不太方面,后续可以写个脚本来模拟并发事务 134 | -------------------------------------------------------------------------------- /docker/conf/mysqld.cnf: -------------------------------------------------------------------------------- 1 | # Copyright (c) 2014, 2016, Oracle and/or its affiliates. All rights reserved. 2 | # 3 | # This program is free software; you can redistribute it and/or modify 4 | # it under the terms of the GNU General Public License as published by 5 | # the Free Software Foundation; version 2 of the License. 6 | # 7 | # This program is distributed in the hope that it will be useful, 8 | # but WITHOUT ANY WARRANTY; without even the implied warranty of 9 | # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 10 | # GNU General Public License for more details. 11 | # 12 | # You should have received a copy of the GNU General Public License 13 | # along with this program; if not, write to the Free Software 14 | # Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA 15 | 16 | # 17 | # The MySQL Server configuration file. 18 | # 19 | # For explanations see 20 | # http://dev.mysql.com/doc/mysql/en/server-system-variables.html 21 | 22 | [mysqld] 23 | pid-file = /var/run/mysqld/mysqld.pid 24 | socket = /var/run/mysqld/mysqld.sock 25 | datadir = /var/lib/mysql 26 | log-error = /var/log/mysql/error.log 27 | 28 | # By default we only accept connections from localhost 29 | #bind-address = 127.0.0.1 30 | 31 | # Disabling symbolic-links is recommended to prevent assorted security risks 32 | symbolic-links=0 33 | 34 | # innodb locks 35 | innodb_status_output=ON 36 | innodb_status_output_locks=ON 37 | innodb_print_all_deadlocks=ON -------------------------------------------------------------------------------- /docker/db/t16.sql: -------------------------------------------------------------------------------- 1 | CREATE DATABASE /*!32312 IF NOT EXISTS*/`dldb` /*!40100 DEFAULT CHARACTER SET utf8 COLLATE utf8_unicode_ci */; 2 | 3 | USE `dldb`; 4 | 5 | CREATE TABLE `t16` ( 6 | `id` int(11) NOT NULL AUTO_INCREMENT, 7 | `xid` int(11) DEFAULT NULL, 8 | `valid` int(11) DEFAULT NULL, 9 | PRIMARY KEY (`id`), 10 | KEY `xid_valid` (`xid`,`valid`) 11 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 12 | 13 | INSERT INTO t16(id, xid, valid) VALUES(1, 1, 0); 14 | INSERT INTO t16(id, xid, valid) VALUES(2, 2, 1); 15 | INSERT INTO t16(id, xid, valid) VALUES(3, 3, 1); 16 | INSERT INTO t16(id, xid, valid) VALUES(4, 1, 0); 17 | INSERT INTO t16(id, xid, valid) VALUES(5, 2, 0); 18 | INSERT INTO t16(id, xid, valid) VALUES(6, 3, 1); 19 | INSERT INTO t16(id, xid, valid) VALUES(7, 1, 1); 20 | INSERT INTO t16(id, xid, valid) VALUES(8, 2, 1); 21 | INSERT INTO t16(id, xid, valid) VALUES(9, 3, 0); 22 | INSERT INTO t16(id, xid, valid) VALUES(10, 1, 1); 23 | 24 | /* 25 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 0 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 26 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 27 | */ 28 | 29 | /* 30 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 31 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 32 | */ 33 | 34 | /* 35 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 36 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 0 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 37 | */ 38 | 39 | /* 40 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 41 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 42 | */ 43 | 44 | /* 45 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 46 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 0 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 47 | */ 48 | 49 | /* 50 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 51 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 52 | */ 53 | 54 | /* 55 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 1 where xid = 3; rollback;" --number-of-queries=100000 -uroot -p123456 & 56 | mysqlslap --create-schema dldb -q "begin; update t16 set xid = 3, valid = 0 where xid = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 57 | */ 58 | -------------------------------------------------------------------------------- /docker/db/t18.sql: -------------------------------------------------------------------------------- 1 | CREATE DATABASE /*!32312 IF NOT EXISTS*/`dldb` /*!40100 DEFAULT CHARACTER SET utf8 COLLATE utf8_unicode_ci */; 2 | 3 | USE `dldb`; 4 | 5 | CREATE TABLE `t18` ( 6 | `id` int(11) unsigned NOT NULL AUTO_INCREMENT, 7 | PRIMARY KEY (`id`) 8 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 9 | 10 | INSERT INTO `t18`(`id`) VALUES (1); 11 | INSERT INTO `t18`(`id`) VALUES (2); 12 | INSERT INTO `t18`(`id`) VALUES (3); 13 | INSERT INTO `t18`(`id`) VALUES (4); 14 | INSERT INTO `t18`(`id`) VALUES (5); 15 | INSERT INTO `t18`(`id`) VALUES (6); 16 | INSERT INTO `t18`(`id`) VALUES (7); 17 | INSERT INTO `t18`(`id`) VALUES (8); 18 | 19 | /* 20 | mysqlslap --create-schema dldb -q "begin; delete from t18 where id = 4; insert into t18 (id) values (4); rollback;" --number-of-queries=100000 -uroot -p123456 & 21 | mysqlslap --create-schema dldb -q "begin; delete from t18 where id = 4; rollback;" --number-of-queries=100000 -uroot -p123456 & 22 | */ 23 | -------------------------------------------------------------------------------- /docker/db/t20.sql: -------------------------------------------------------------------------------- 1 | CREATE DATABASE /*!32312 IF NOT EXISTS*/`dldb` /*!40100 DEFAULT CHARACTER SET utf8 COLLATE utf8_unicode_ci */; 2 | 3 | USE `dldb`; 4 | 5 | CREATE TABLE `t20` ( 6 | `id` int(11) NOT NULL AUTO_INCREMENT, 7 | `a` int(11) DEFAULT NULL, 8 | `b` int(11) DEFAULT NULL, 9 | PRIMARY KEY (`id`), 10 | KEY `a` (`a`), 11 | KEY `b` (`b`) 12 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 13 | 14 | INSERT INTO t20(a, b) VALUES(1,5); 15 | INSERT INTO t20(a, b) VALUES(1,10); 16 | INSERT INTO t20(a, b) VALUES(2,5); 17 | INSERT INTO t20(a, b) VALUES(2,10); 18 | INSERT INTO t20(a, b) VALUES(3,5); 19 | INSERT INTO t20(a, b) VALUES(3,10); 20 | INSERT INTO t20(a, b) VALUES(4,5); 21 | INSERT INTO t20(a, b) VALUES(4,10); 22 | INSERT INTO t20(a, b) VALUES(5,5); 23 | INSERT INTO t20(a, b) VALUES(5,10); 24 | 25 | /* 26 | mysqlslap --create-schema dldb -q "begin; DELETE FROM t20 WHERE a = 3 AND b = 10; rollback;" --number-of-queries=100000 -uroot -p123456 & 27 | mysqlslap --create-schema dldb -q "begin; DELETE FROM t20 WHERE a = 5 AND b = 10; rollback;" --number-of-queries=100000 -uroot -p123456 & 28 | */ 29 | -------------------------------------------------------------------------------- /docker/db/t8.sql: -------------------------------------------------------------------------------- 1 | CREATE DATABASE /*!32312 IF NOT EXISTS*/`dldb` /*!40100 DEFAULT CHARACTER SET utf8 COLLATE utf8_unicode_ci */; 2 | 3 | USE `dldb`; 4 | 5 | CREATE TABLE `t8` ( 6 | `id` int(11) NOT NULL AUTO_INCREMENT, 7 | PRIMARY KEY (`id`) 8 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 9 | 10 | INSERT INTO `t8`(`id`) VALUES (1); 11 | INSERT INTO `t8`(`id`) VALUES (2); 12 | INSERT INTO `t8`(`id`) VALUES (3); 13 | INSERT INTO `t8`(`id`) VALUES (4); 14 | INSERT INTO `t8`(`id`) VALUES (5); 15 | INSERT INTO `t8`(`id`) VALUES (6); 16 | INSERT INTO `t8`(`id`) VALUES (7); 17 | INSERT INTO `t8`(`id`) VALUES (8); 18 | INSERT INTO `t8`(`id`) VALUES (9); 19 | INSERT INTO `t8`(`id`) VALUES (10); 20 | 21 | /* 22 | mysqlslap --create-schema dldb -q "begin; delete from t8 where id = 1; delete from t8 where id = 2; rollback;" --number-of-queries=100000 -uroot -p123456 & 23 | mysqlslap --create-schema dldb -q "begin; delete from t8 where id = 2; delete from t8 where id = 1; rollback;" --number-of-queries=100000 -uroot -p123456 & 24 | */ 25 | -------------------------------------------------------------------------------- /docker/docker-compose.yml: -------------------------------------------------------------------------------- 1 | version: '2.1' 2 | services: 3 | dldb: 4 | container_name: dldb 5 | image: mysql:5.7 6 | volumes: 7 | - ./db:/docker-entrypoint-initdb.d 8 | - ./conf/mysqld.cnf:/etc/mysql/mysql.conf.d/mysqld.cnf 9 | environment: 10 | - MYSQL_ROOT_PASSWORD=123456 11 | ports: 12 | - 53306:3306 13 | command: ['mysqld', '--character-set-server=utf8', '--collation-server=utf8_general_ci'] 14 | -------------------------------------------------------------------------------- /images/16-17.jpeg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aneasystone/mysql-deadlocks/d6e2283053687edfcd3d35a8981f1a37ef167ef0/images/16-17.jpeg --------------------------------------------------------------------------------