目录
文/温国兵
一 引子
MySQL 5.5 中,information_schema 库中新增了三个关于锁的表,亦即 innodb_trx、innodb_locks 和 innodb_lock_waits。
其中 innodb_trx
表记录当前运行的所有事务,innodb_locks
表记录当前出现的锁,innodb_lock_waits
表记录锁等待的对应关系。
二 表结构说明
登录 MySQL 5.5。
mysql -S /tmp/mysql_5540.sock -uroot -proot
这是我的 MySQL 版本信息。
mysql> SHOW VARIABLES LIKE '%version%';
+-------------------------+------------------------------+
| Variable_name | Value |
+-------------------------+------------------------------+
| innodb_version | 5.5.40 |
| protocol_version | 10 |
| slave_type_conversions | |
| version | 5.5.40 |
| version_comment | MySQL Community Server (GPL) |
| version_compile_machine | i386 |
| version_compile_os | osx10.6 |
+-------------------------+------------------------------+
7 rows in set (0.00 sec)
查看 innodb_trx 表结构。
mysql> USE information_schema;
mysql> DESC innodb_trx;
下面对 innodb_trx 表的每个字段进行解释:
查看 innodb_locks 表结构。
mysql> DESC innodb_locks;
下面对 innodb_locks 表的每个字段进行解释:
查看 innodb_lock_waits 表结构。
mysql> DESC innodb_lock_waits;
下面对 innodb_lock_waits 表的每个字段进行解释:
三 INNODB 锁等待模拟
3.1 创建测试表,录入测试数据
创建测试表,录入测试数据。
mysql> USE test;
mysql> CREATE TABLE user
-> (id INT PRIMARY KEY,
-> name VARCHAR(20),
-> age INT,
-> sex CHAR(2),
-> city VARCHAR(20),
-> job VARCHAR(10)
-> ) DEFAULT CHARSET utf8 ENGINE = INNODB;
Query OK, 0 rows affected (0.15 sec)
mysql> INSERT INTO user(id, name, age, sex, city, job) \
-> VALUES(1, 'robin', 19, 'M', 'GZ', 'DBA');
Query OK, 1 row affected (0.00 sec)
mysql> INSERT INTO user(id, name, age, sex, city, job) \
-> VALUES(2, 'Wentasy', 19, 'M', 'GZ', 'DBA');
Query OK, 1 row affected (0.00 sec)
mysql> INSERT INTO user(id, name, age, sex, city, job) \
-> VALUES(3, 'dbarobin', 19, 'M', 'GZ', 'DBA');
Query OK, 1 row affected (0.00 sec)
mysql> COMMIT;
Query OK, 0 rows affected (0.00 sec)
3.2 模拟锁等待
Session 1 开始事务。
mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
mysql> UPDATE user SET name='wentasy' WHERE id = 2;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
-- 此时已经开始事务,所以 innodb_trx 表会有记录。
mysql> SELECT * FROM information_schema.innodb_trx \G
*************************** 1. row ***************************
trx_id: 360E
trx_state: RUNNING
trx_started: 2015-01-27 15:23:49
trx_requested_lock_id: NULL
trx_wait_started: NULL
trx_weight: 3
trx_mysql_thread_id: 1
trx_query: SELECT * FROM information_schema.innodb_trx
trx_operation_state: NULL
trx_tables_in_use: 0
trx_tables_locked: 0
trx_lock_structs: 2
trx_lock_memory_bytes: 376
trx_rows_locked: 1
trx_rows_modified: 1
trx_concurrency_tickets: 0
trx_isolation_level: REPEATABLE READ
trx_unique_checks: 1
trx_foreign_key_checks: 1
trx_last_foreign_key_error: NULL
trx_adaptive_hash_latched: 0
trx_adaptive_hash_timeout: 10000
1 row in set (0.00 sec)
-- 此时没有发生锁等待,故 innodb_locks表 和 innodb_lock_waits 表都没有数据。
mysql> SELECT * FROM information_schema.innodb_locks \G
Empty set (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_lock_waits \G
Empty set (0.00 sec)
Session 2 更新数据。
mysql -S /tmp/mysql_5540.sock -uroot -proot
mysql> USE test;
mysql> UPDATE user SET name="lock_waits" WHERE ID = 2;
Session 1 查看 innodb_trx 表、innodb_locks 表和 innodb_lock_waits 表,可以查看到数据。
在 innodb_trx 表的第一行,trx_id 为 360F 表示第二个事务,状态为等待状态,请求的锁 ID 为 360F:243:3:3,线程 ID 为 2,事务用到的表为 1,有 1 个表被锁。第二行中,trx_id 为 360E 表示第一个事务。
mysql> SELECT * FROM information_schema.innodb_trx \G
*************************** 1. row ***************************
trx_id: 360F
trx_state: LOCK WAIT
trx_started: 2015-01-27 15:28:48
trx_requested_lock_id: 360F:243:3:3
trx_wait_started: 2015-01-27 15:28:48
trx_weight: 2
trx_mysql_thread_id: 2
trx_query: UPDATE user SET name="lock_waits" WHERE ID = 2
trx_operation_state: starting index read
trx_tables_in_use: 1
trx_tables_locked: 1
trx_lock_structs: 2
trx_lock_memory_bytes: 376
trx_rows_locked: 1
trx_rows_modified: 0
trx_concurrency_tickets: 0
trx_isolation_level: REPEATABLE READ
trx_unique_checks: 1
trx_foreign_key_checks: 1
trx_last_foreign_key_error: NULL
trx_adaptive_hash_latched: 0
trx_adaptive_hash_timeout: 10000
*************************** 2. row ***************************
trx_id: 360E
trx_state: RUNNING
trx_started: 2015-01-27 15:23:49
trx_requested_lock_id: NULL
trx_wait_started: NULL
trx_weight: 3
trx_mysql_thread_id: 1
trx_query: SELECT * FROM information_schema.innodb_trx
trx_operation_state: NULL
trx_tables_in_use: 0
trx_tables_locked: 0
trx_lock_structs: 2
trx_lock_memory_bytes: 376
trx_rows_locked: 1
trx_rows_modified: 1
trx_concurrency_tickets: 0
trx_isolation_level: REPEATABLE READ
trx_unique_checks: 1
trx_foreign_key_checks: 1
trx_last_foreign_key_error: NULL
trx_adaptive_hash_latched: 0
trx_adaptive_hash_timeout: 10000
2 rows in set (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_locks \G
*************************** 1. row ***************************
lock_id: 360F:243:3:3
lock_trx_id: 360F
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
*************************** 2. row ***************************
lock_id: 360E:243:3:3
lock_trx_id: 360E
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
2 rows in set (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_lock_waits \G
*************************** 1. row ***************************
requesting_trx_id: 360F
requested_lock_id: 360F:243:3:3
blocking_trx_id: 360E
blocking_lock_id: 360E:243:3:3
1 row in set (0.00 sec)
由于默认的 innodb_lock_wait_timeout
是 50 秒,所以 50 秒过后,Session 2 出现如下提示:
3.3 再次模拟锁等待
再次模拟锁等待之前,把 innodb_lock_wait_timeout
设置为 10 分钟,方便后面的演示。
mysql> SHOW VARIABLES LIKE '%innodb_lock_wait%';
+--------------------------+-------+
| Variable_name | Value |
+--------------------------+-------+
| innodb_lock_wait_timeout | 50 |
+--------------------------+-------+
1 row in set (0.00 sec)
mysql> SET innodb_lock_wait_timeout=600;
Query OK, 0 rows affected (0.00 sec)
mysql> SET GLOBAL innodb_lock_wait_timeout=600;
Query OK, 0 rows affected (0.00 sec)
mysql> SHOW VARIABLES LIKE '%innodb_lock_wait%';
+--------------------------+-------+
| Variable_name | Value |
+--------------------------+-------+
| innodb_lock_wait_timeout | 600 |
+--------------------------+-------+
1 row in set (0.00 sec)
再次开启一个 Session,此时的 Session 姑且命名为 Session 3。然后再次更新数据,由于 Session 1 未提交,所以会发生锁等待。
mysql> USE test;
mysql> UPDATE user SET name="lock_waits" WHERE ID = 2;
3.4 查询锁等待
此时再次发生锁等待。我们在 Session 1 中使用不同的查询方法查看锁等待。
3.4.1 直接查看 innodb_lock_waits 表
mysql> SELECT * FROM innodb_lock_waits \G
*************************** 1. row ***************************
requesting_trx_id: 3612
requested_lock_id: 3612:243:3:3
blocking_trx_id: 360E
blocking_lock_id: 360E:243:3:3
1 row in set (0.00 sec)
3.4.2 innodb_locks 表和 innodb_lock_waits 表结合
mysql> SELECT * \
> FROM innodb_locks \
> WHERE lock_trx_id \
> IN (SELECT blocking_trx_id FROM innodb_lock_waits) \G
*************************** 1. row ***************************
lock_id: 360E:243:3:3
lock_trx_id: 360E
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
1 row in set (0.00 sec)
3.4.3 innodb_locks 表 JOIN innodb_lock_waits 表
mysql> SELECT innodb_locks.* \
> FROM innodb_locks \
> JOIN innodb_lock_waits \
> ON (innodb_locks.lock_trx_id = innodb_lock_waits.blocking_trx_id) \G
*************************** 1. row ***************************
lock_id: 360E:243:3:3
lock_trx_id: 360E
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
1 row in set (0.01 sec)
3.4.4 指定 innodb_locks 表的 lock_table 属性
需要注意 lock_table
值的写法。
mysql> SELECT * FROM innodb_locks \
> WHERE lock_table = '`test`.`user`' \G
*************************** 1. row ***************************
lock_id: 3612:243:3:3
lock_trx_id: 3612
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
*************************** 2. row ***************************
lock_id: 360E:243:3:3
lock_trx_id: 360E
lock_mode: X
lock_type: RECORD
lock_table: `test`.`user`
lock_index: `PRIMARY`
lock_space: 243
lock_page: 3
lock_rec: 3
lock_data: 2
2 rows in set (0.00 sec)
3.4.5 查询 innodb_trx 表
mysql> SELECT trx_id, trx_requested_lock_id, trx_mysql_thread_id, trx_query \
> FROM innodb_trx \
> WHERE trx_state = 'LOCK WAIT' \G
*************************** 1. row ***************************
trx_id: 3612
trx_requested_lock_id: 3612:243:3:3
trx_mysql_thread_id: 9
trx_query: UPDATE user SET name="lock_waits" WHERE ID = 2
1 row in set (0.00 sec)
3.4.6 SHOW ENGINE INNODB STATUS
mysql> SHOW ENGINE INNODB STATUS \G
在输出结果的最后,我们看到如下信息:
--------------
ROW OPERATIONS
--------------
0 queries inside InnoDB, 0 queries in queue
1 read views open inside InnoDB
Main thread id 4525080576, state: waiting for server activity
Number of rows inserted 6, updated 1, deleted 0, read 2
0.00 inserts/s, 0.00 updates/s, 0.00 deletes/s, 0.00 reads/s
----------------------------
END OF INNODB MONITOR OUTPUT
============================
1 row in set (0.00 sec)
3.4.7 SHOW PROCESSLIST
mysql> SHOW PROCESSLIST \G
*************************** 1. row ***************************
Id: 1
User: root
Host: localhost
db: information_schema
Command: Query
Time: 0
State: NULL
Info: SHOW PROCESSLIST
*************************** 2. row ***************************
Id: 9
User: root
Host: localhost
db: test
Command: Query
Time: 116
State: Updating
Info: UPDATE user SET name="lock_waits" WHERE ID = 2
2 rows in set (0.00 sec)
3.5 解决锁等待
既然我们从上述方法中得到了相关信息,我们可以得到发生锁等待的线程 ID,然后将其 KILL 掉。
Session 1 中 KILL 掉发生锁等待的线程。
mysql> kill 9;
Query OK, 0 rows affected (0.00 sec)
Session 3 中可以看到锁等待消除。
mysql> UPDATE user SET name="lock_waits" WHERE ID = 2;
有如下输出:
Session 1 中再次查看 PROCESSLIST,可以看到没有相关的信息了。
mysql> SHOW PROCESSLIST \G
*************************** 1. row ***************************
Id: 1
User: root
Host: localhost
db: information_schema
Command: Query
Time: 0
State: NULL
Info: SHOW PROCESSLIST
1 row in set (0.00 sec)
模拟完成后,我们提交,此时 innodb_trx 表、innodb_locks 表和 innodb_lock_waits 表中都没有数据。
mysql> COMMIT;
Query OK, 0 rows affected (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_trx \G
Empty set (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_locks \G
Empty set (0.00 sec)
mysql> SELECT * FROM information_schema.innodb_lock_waits \G
Empty set (0.00 sec)
把 innodb_lock_wait
还原为默认值。
mysql> SHOW VARIABLES LIKE '%innodb_lock_wait%';
+--------------------------+-------+
| Variable_name | Value |
+--------------------------+-------+
| innodb_lock_wait_timeout | 600 |
+--------------------------+-------+
1 row in set (0.00 sec)
mysql> SET GLOBAL innodb_lock_wait_timeout=50;
Query OK, 0 rows affected (0.00 sec)
mysql> SET innodb_lock_wait_timeout=50;
Query OK, 0 rows affected (0.00 sec)
mysql> SHOW VARIABLES LIKE '%innodb_lock_wait%';
+--------------------------+-------+
| Variable_name | Value |
+--------------------------+-------+
| innodb_lock_wait_timeout | 50 |
+--------------------------+-------+
1 row in set (0.00 sec)
四 小结
- information_schema 库中新增了三个关于锁的表,亦即 innodb_trx、innodb_locks 和 innodb_lock_waits;
- innodb_trx 表记录当前运行的所有事务;
- innodb_locks 表记录当前出现的锁;
- innodb_lock_waits 表记录锁等待的对应关系;
- 获得锁等待的技巧
- 从 innodb_trx、innodb_locks 和 innodb_lock_waits 表中得到;
- SHOW ENGINE INNODB STATUS;
- SHOW FULL PROCESSLIST;
- 启用 InnoDB Lock Monitor;
- 运行 mysqladmin debug;
- MySQK Error Log;
- SHOW CREATE TABLE 输出;
- 发生锁等待会引起系统资源的大量浪费,合理的监控和处理锁等待很重要。
五 Ref
- 21.28.3 The INFORMATION_SCHEMA INNODB_TRX Table
- 21.28.4 The INFORMATION_SCHEMA INNODB_LOCKS Table
- 21.28.5 The INFORMATION_SCHEMA INNODB_LOCK_WAITS Table
- How do I find which transaction is causing a “Waiting for table metadata lock” state?
- Getting “Lock wait timeout exceeded; try restarting transaction” even though I’m not using a transaction
- Advanced InnoDB Deadlock Troubleshooting – What SHOW INNODB STATUS Doesn’t Tell You, and What Diagnostics You Should be Looking At
- MySQL 加锁处理分析
–EOF–