作者:高鹏 

文章末尾有他著作的《深入理解MySQL主从原理 32讲》,深入透彻理解MySQL主从,GTID相关技术知识。

一、问题由来

这是我同事问我的一个问题,在网上看到了如下案例,本案例RC RR都可以出现,其实这个死锁原因也比较简单,我们来具体看看:

构造数据
  1. CREATE database deadlock_test;

  2. use deadlock_test;

  3. CREATE TABLE `push_token` (

  4. `id` bigint(20) NOT NULL AUTO_INCREMENT,

  5. `token` varchar(128) NOT NULL COMMENT 'push token',

  6. `app_id` varchar(128) DEFAULT NULL COMMENT 'appid',

  7. `deleted` tinyint(1) NOT NULL COMMENT '是否已删除 0:否 1:是',

  8. PRIMARY KEY (`id`),

  9. UNIQUE KEY `uk_token_appid` (`token`,`app_id`)

  10. ) ENGINE=InnoDB AUTO_INCREMENT=3384 DEFAULT CHARSET=utf8 COMMENT='pushtoken表';


  11. insert into push_token (id, token, app_id, deleted) values(1,"token1",1,0);

操作数据

二、分析方法

我使用的分析方法是把整个加锁的日志打印出来,当然需要用到我自己做了输出修改的一个版本,如下:

https://github.com/gaopengcarl/percona-server-locks-detail-5.7.22

这个版本我打开了的日志记录参数如下:

  1. mysql> show variables like '%gaopeng%';

  2. +--------------------------------+-------+

  3. | Variable_name | Value |

  4. +--------------------------------+-------+

  5. | gaopeng_mdl_detail | OFF |

  6. | innodb_gaopeng_row_lock_detail | ON |

  7. +--------------------------------+-------+

  8. 2 rows in set (0.01 sec)

这样大部分的Innodb加锁记录都会记录到errlog日志了。
好了下面我详细分析一下日志:

三、分析过程

初始化的情况整个表只有1条记录,本表包含一个主键和一个唯一键。

1. s1(TRX_ID367661)执行语句

  1. begin;

  2. UPDATE push_token SET deleted = 1 WHERE token = 'token1' AND app_id = '1';

日志输出:
  1. 2019-08-18T19:10:05.117317+08:00 6 [Note] InnoDB: TRX ID:(367661) table:deadlock_test/push_token index:uk_token_appid space_id: 449 page_id:4 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  2. PHYSICAL RECORD: n_fields 3; compact format; info bits 0

  3. 0: len 6; hex 746f6b656e31; asc token1;;

  4. 1: len 1; hex 31; asc 1;;

  5. 2: len 8; hex 8000000000000001; asc ;;

  6. 2019-08-18T19:10:05.117714+08:00 6 [Note] InnoDB: TRX ID:(367661) table:deadlock_test/push_token index:PRIMARY space_id: 449 page_id:3 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  7. PHYSICAL RECORD: n_fields 6; compact format; info bits 0

  8. 0: len 8; hex 8000000000000001; asc ;;

  9. 1: len 6; hex 000000059c2c; asc ,;;

  10. 2: len 7; hex bf000000420110; asc B ;;

  11. 3: len 6; hex 746f6b656e31; asc token1;;

  12. 4: len 1; hex 31; asc 1;;

  13. 5: len 1; hex 80; asc ;;

我们看到主键和唯一键都加锁了,模式为LOCKX|LOCKNOT_GAP|如下图:

并且这个时候数据实际上是标记删除状态。

2. s2(TRX_ID367662) 执行语句

  1. begin;DELETE FROM push_token WHERE id IN (1);

日志输出:
  1. 2019-08-18T19:10:22.751467+08:00 9 [Note] InnoDB: TRX ID:(367662) table:deadlock_test/push_token index:PRIMARY space_id: 449 page_id:3 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  2. PHYSICAL RECORD: n_fields 6; compact format; info bits 0

  3. 0: len 8; hex 8000000000000001; asc ;;

  4. 1: len 6; hex 000000059c2d; asc -;;

  5. 2: len 7; hex 400000002a1dc8; asc @ * ;;

  6. 3: len 6; hex 746f6b656e31; asc token1;;

  7. 4: len 1; hex 31; asc 1;;

  8. 5: len 1; hex 81; asc ;;

  9. 2019-08-18T19:10:22.752753+08:00 9 [Note] InnoDB: Trx(367662) is blocked!!!!!

这个时候S2需要获取主键上的:LOCKX|LOCKNOT_GAP| 锁,因此被堵塞了如下图:

3. s3(TRX_ID367663) 执行语句

  1. begin; UPDATE push_token SET deleted = 1 WHERE token = 'token1' AND app_id = '1';

日志输出:
  1. 2019-08-18T19:10:30.822111+08:00 8 [Note] InnoDB: TRX ID:(367663) table:deadlock_test/push_token index:uk_token_appid space_id: 449 page_id:4 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  2. PHYSICAL RECORD: n_fields 3; compact format; info bits 0

  3. 0: len 6; hex 746f6b656e31; asc token1;;

  4. 1: len 1; hex 31; asc 1;;

  5. 2: len 8; hex 8000000000000001; asc ;;

  6. 2019-08-18T19:10:30.918248+08:00 8 [Note] InnoDB: Trx(367663) is blocked!!!!!

这个时候S3需要获取唯一键上的LOCKX|LOCKNOT_GAP 锁,因此被堵塞了如下图:

4. s1(TRX_ID367661) 执行语句

这一步完成后死锁出现。
  1. commit;

日志输出如下:
  1. 367663和367662各自获取需要的锁


  2. 2019-08-18T19:10:36.566733+08:00 8 [Note] InnoDB: TRX ID:(367663) table:deadlock_test/push_token index:uk_token_appid space_id: 449 page_id:4 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  3. PHYSICAL RECORD: n_fields 3; compact format; info bits 0

  4. 0: len 6; hex 746f6b656e31; asc token1;;

  5. 1: len 1; hex 31; asc 1;;

  6. 2: len 8; hex 8000000000000001; asc ;;

  7. 2019-08-18T19:10:36.568711+08:00 9 [Note] InnoDB: TRX ID:(367662) table:deadlock_test/push_token index:PRIMARY space_id: 449 page_id:3 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  8. PHYSICAL RECORD: n_fields 6; compact format; info bits 0

  9. 0: len 8; hex 8000000000000001; asc ;;

  10. 1: len 6; hex 000000059c2d; asc -;;

  11. 2: len 7; hex 400000002a1dc8; asc @ * ;;

  12. 3: len 6; hex 746f6b656e31; asc token1;;

  13. 4: len 1; hex 31; asc 1;;

  14. 5: len 1; hex 81; asc ;;


  15. 367663获取主键锁堵塞、367662获取唯一键锁堵塞,死锁形成

  16. 2019-08-18T19:10:36.570313+08:00 8 [Note] InnoDB: TRX ID:(367663) table:deadlock_test/push_token index:PRIMARY space_id: 449 page_id:3 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  17. PHYSICAL RECORD: n_fields 6; compact format; info bits 0

  18. 0: len 8; hex 8000000000000001; asc ;;

  19. 1: len 6; hex 000000059c2d; asc -;;

  20. 2: len 7; hex 400000002a1dc8; asc @ * ;;

  21. 3: len 6; hex 746f6b656e31; asc token1;;

  22. 4: len 1; hex 31; asc 1;;

  23. 5: len 1; hex 81; asc ;;

  24. 2019-08-18T19:10:36.571199+08:00 8 [Note] InnoDB: Trx(367663) is blocked!!!!!

  25. 2019-08-18T19:10:36.572481+08:00 9 [Note] InnoDB: TRX ID:(367662) table:deadlock_test/push_token index:uk_token_appid space_id: 449 page_id:4 heap_no:2 row lock mode:LOCK_X|LOCK_NOT_GAP|

  26. PHYSICAL RECORD: n_fields 3; compact format; info bits 0

  27. 0: len 6; hex 746f6b656e31; asc token1;;

  28. 1: len 1; hex 31; asc 1;;

  29. 2: len 8; hex 8000000000000001; asc ;;

  30. 2019-08-18T19:10:36.573073+08:00 9 [Note] InnoDB: Transactions deadlock detected, dumping detailed information.

完成这一步 s1实际上释放了锁, 然后我们首先看到s2获取了主键上的LOCKX|LOCKNOTGAP锁,s3获取了唯一键上的LOCKX|LOCKNOTGAP 锁。但是随后s3获取主键上的LOCKX|LOCKNOTGAP锁堵塞,s2获取唯一键上的LOCKX|LOCKNOTGAP锁堵塞。因此死锁形成,如下图:

好了我们看到了死锁就这样出现。整个分析过程我们只要看到加锁的日志实际上很容易就分析得出来。

近期社区动态