MySQL社区

 找回密码
 注册

QQ登录

只需一步,快速开始

扫一扫,访问微社区

搜索
查看: 3119|回复: 0

[事务及锁] 查找原始MySQL死锁ID

[复制链接]
发表于 2013-4-18 18:20:15 | 显示全部楼层 |阅读模式
本帖最后由 yueliangdao0608 于 2013-4-18 18:22 编辑

如果遇到死锁了,怎么解决呢?找到原始的锁ID,然后KILL掉一直持有的那个线程就可以了, 但是众多线程,可怎么找到引起死锁的线程ID呢? MySQL 发展到现在,已经非常强大了,这个问题很好解决。 直接从数据字典连查找。


我们来演示下。

线程A,我们用来锁定某些记录,假设这个线程一直没提交,或者忘掉提交了。 那么就一直存在,但是数据里面显示的只是SLEEP状态。
  1. mysql> set @@autocommit=0;
  2. Query OK, 0 rows affected (0.00 sec)

  3. mysql> use test;
  4. Reading table information for completion of table and column names
  5. You can turn off this feature to get a quicker startup with -A

  6. Database changed
  7. mysql> show tables;
  8. +----------------+
  9. | Tables_in_test |
  10. +----------------+
  11. | demo_test      |
  12. | t3             |
  13. +----------------+
  14. 2 rows in set (0.00 sec)

  15. mysql> select * from t3;
  16. +----+--------+--------+------------+----+----+----+
  17. | id | fname  | lname  | birthday   | c1 | c2 | c3 |
  18. +----+--------+--------+------------+----+----+----+
  19. | 19 | lily19 | lucy19 | 2013-04-18 | 19 |  0 |  0 |
  20. | 20 | lily20 | lucy20 | 2013-03-13 | 20 |  0 |  0 |
  21. +----+--------+--------+------------+----+----+----+
  22. 2 rows in set (0.00 sec)

  23. mysql> update t3 set birthday = '2022-02-23' where id = 19;
  24. Query OK, 1 row affected (0.00 sec)
  25. Rows matched: 1  Changed: 1  Warnings: 0

  26. mysql> select connection_id();
  27. +-----------------+
  28. | connection_id() |
  29. +-----------------+
  30. |              16 |
  31. +-----------------+
  32. 1 row in set (0.00 sec)

  33. mysql>
复制代码
线程B, 我们用来进行普通的更新,但是遇到问题了,此时不知道是哪个线程把这行记录给锁定了?
  1. mysql> use test;
  2. Reading table information for completion of table and column names
  3. You can turn off this feature to get a quicker startup with -A

  4. Database changed
  5. mysql> select @@autocommit;
  6. +--------------+
  7. | @@autocommit |
  8. +--------------+
  9. |            1 |
  10. +--------------+
  11. 1 row in set (0.00 sec)

  12. mysql> update t3 set birthday='2018-01-03' where id = 19;
  13. ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction
  14. mysql> select connection_id();
  15. +-----------------+
  16. | connection_id() |
  17. +-----------------+
  18. |              17 |
  19. +-----------------+
  20. 1 row in set (0.00 sec)

  21. mysql> show processlist;
  22. +----+------+-----------+------+---------+------+-------+------------------+
  23. | Id | User | Host      | db   | Command | Time | State | Info             |
  24. +----+------+-----------+------+---------+------+-------+------------------+
  25. | 10 | root | localhost | NULL | Sleep   | 1540 |       | NULL             |
  26. | 11 | root | localhost | NULL | Sleep   |  722 |       | NULL             |
  27. | 16 | root | localhost | test | Sleep   |  424 |       | NULL             |
  28. | 17 | root | localhost | test | Query   |    0 | init  | show processlist |
  29. | 18 | root | localhost | NULL | Sleep   |    5 |       | NULL             |
  30. +----+------+-----------+------+---------+------+-------+------------------+
  31. 5 rows in set (0.00 sec)

  32. mysql> show engine innodb status\G


  33. ------------
  34. TRANSACTIONS
  35. ------------
  36. Trx id counter 189327
  37. Purge done for trx's n:o < 189323 undo n:o < 0 state: running but idle
  38. History list length 343
  39. LIST OF TRANSACTIONS FOR EACH SESSION:
  40. ---TRANSACTION 0, not started
  41. MySQL thread id 11, OS thread handle 0x7f70a0c98700, query id 994 localhost root init
  42. show engine innodb status
  43. ---TRANSACTION 189326, ACTIVE 2 sec starting index read
  44. mysql tables in use 1, locked 1
  45. LOCK WAIT 2 lock struct(s), heap size 376, 1 row lock(s)
  46. MySQL thread id 17, OS thread handle 0x7f70a0bd5700, query id 993 localhost root updating
  47. update t3 set birthday='2018-01-03' where id = 19
  48. ------- TRX HAS BEEN WAITING 2 SEC FOR THIS LOCK TO BE GRANTED:
  49. RECORD LOCKS space id 529 page no 3 n bits 72 index `PRIMARY` of table `test`.`t3` trx id 189326 lock_mode X waiting
  50. Record lock, heap no 2 PHYSICAL RECORD: n_fields 9; compact format; info bits 0
  51. 0: len 2; hex 3139; asc 19;;
  52. 1: len 6; hex 00000002e38c; asc       ;;
  53. 2: len 7; hex 7e00000d2827c9; asc ~   (' ;;
  54. 3: len 6; hex 6c696c793139; asc lily19;;
  55. 4: len 6; hex 6c7563793139; asc lucy19;;
  56. 5: len 3; hex 8fcc57; asc   W;;
  57. 6: len 4; hex 80000013; asc     ;;
  58. 7: len 4; hex 80000000; asc     ;;
  59. 8: len 4; hex 80000000; asc     ;;

  60. ------------------
  61. ---TRANSACTION 189324, ACTIVE 641 sec
  62. 2 lock struct(s), heap size 376, 3 row lock(s), undo log entries 1
  63. MySQL thread id 16, OS thread handle 0x7f70a0b94700, query id 985 localhost root cleaning up
  64. Trx read view will not see trx with id >= 189325, sees < 189325
复制代码
上面的信息很繁多,也看不清楚到底哪里是哪里。

不过现在,我们只要从数据字典里面拿出来这部分信息就OK了。
  1. mysql> SELECT * FROM information_schema.INNODB_TRX\G
  2. *************************** 1. row ***************************
  3.                     trx_id: 189324
  4.                  trx_state: RUNNING
  5.                trx_started: 2013-04-18 17:48:14
  6.      trx_requested_lock_id: NULL
  7.           trx_wait_started: NULL
  8.                 trx_weight: 3
  9.        trx_mysql_thread_id: 16
  10.                  trx_query: NULL
  11.        trx_operation_state: NULL
  12.          trx_tables_in_use: 0
  13.          trx_tables_locked: 0
  14.           trx_lock_structs: 2
  15.      trx_lock_memory_bytes: 376
  16.            trx_rows_locked: 3
  17.          trx_rows_modified: 1
  18.    trx_concurrency_tickets: 0
  19.        trx_isolation_level: REPEATABLE READ
  20.          trx_unique_checks: 1
  21.     trx_foreign_key_checks: 1
  22. trx_last_foreign_key_error: NULL
  23. trx_adaptive_hash_latched: 0
  24. trx_adaptive_hash_timeout: 10000
  25.           trx_is_read_only: 0
  26. trx_autocommit_non_locking: 0
  27. 1 row in set (0.01 sec)

  28. mysql>  
复制代码
原来是线程16忘掉COMMIT了。

您需要登录后才可以回帖 登录 | 注册

本版积分规则

QQ|申请友链|小黑屋|Archiver|手机版|MySQL社区 ( 京ICP备07012489号   
联系人:周生; 联系电话:13911732319

GMT+8, 2024-3-29 15:22 , Processed in 0.070349 second(s), 26 queries , Gzip On.

Powered by Discuz! X3.2

© 2001-2013 Comsenz Inc.

快速回复 返回顶部 返回列表