了解原理
NOWAIT
skip locked
实战测试
mysql> CREATE TABLE t (i INT, PRIMARY KEY (i)) ENGINE = InnoDB; mysql> INSERT INTO t (i) VALUES(1),(2),(3);
mysql> SELECT * FROM t;
+---+
| i |
+---+
| 1 |
| 2 |
| 3 |
+---+
mysql> START TRANSACTION;
mysql> SELECT * FROM t WHERE i = 2 FOR UPDATE;
+---+
| i |
+---+
| 2 |
+---+
mysql> select * from t where i=2 for update;
ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction
mysql> START TRANSACTION;
mysql> SELECT * FROM t WHERE i = 2 FOR UPDATE NOWAIT;
ERROR 3572 (HY000): Statement aborted because lock(s) could not be acquired immediately and NOWAIT is set.
mysql> START TRANSACTION;
mysql> SELECT * FROM t FOR UPDATE SKIP LOCKED;
+---+
| i |
+---+
| 1 |
| 3 |
+---+
MySQL 当前锁情况
mysql> select * from sys.innodb_lock_waits\G;
*************************** 1. row ***************************
wait_started: 2021-06-07 00:56:24
wait_age: 00:00:10
wait_age_secs: 10
locked_table: `wubx`.`t`
locked_table_schema: wubx
locked_table_name: t
locked_table_partition: NULL
locked_table_subpartition: NULL
locked_index: PRIMARY
locked_type: RECORD
waiting_trx_id: 1633
waiting_trx_started: 2021-06-07 00:56:24
waiting_trx_age: 00:00:10
waiting_trx_rows_locked: 1
waiting_trx_rows_modified: 0
waiting_pid: 345
waiting_query: select * from t where i=2 for update
waiting_lock_id: 139804827496688:2:4:3:139804742333008
waiting_lock_mode: X,REC_NOT_GAP
blocking_trx_id: 1630
blocking_pid: 344
blocking_query: NULL
blocking_lock_id: 139804827495832:2:4:3:139804742326848
blocking_lock_mode: X,REC_NOT_GAP
blocking_trx_started: 2021-06-07 00:54:21
blocking_trx_age: 00:02:13
blocking_trx_rows_locked: 1
blocking_trx_rows_modified: 0
sql_kill_blocking_query: KILL QUERY 344
sql_kill_blocking_connection: KILL 344
1 row in set (0.00 sec)
使用场景
文章转载自MySQLBeginner,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。