行级锁就是锁住表中指定行的记录。
InnoDB行锁是通过给索引项加锁来实现的,如果没有建立索引,那么采用表默认的隐式主键来锁定。
mysql> select @@tx_isolation;
+-----------------+
| @@tx_isolation |
+-----------------+
| REPEATABLE-READ |
+-----------------+
1 row in set, 1 warning (0.00 sec)
共享锁、排他锁
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_user where id = "5045dfba5f5b4cb5b805c379fc538bcb" for update; | |
成功:select * from edu_user; | |
成功:select * from edu_user where id = "1234df4446cb4cb6bc2f639830b12345" for update; | |
阻塞:select * from edu_user where id = "5045dfba5f5b4cb5b805c379fc538bcb" for update; | |
commit; | |
执行阻塞内容 | |
commit; |
说明:锁住了id为5045dfba5f5b4cb5b805c379fc538bcb的记录,其他行记录可以查询,也可以锁操作、读写。
操作:
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_test where a_val = '11' for update; | |
成功:insert into edu_test select 6, '9', '9'; | |
成功:insert into edu_test select 7, '14', '14'; | |
成功:insert into edu_test select 9, '13', '13'; | |
阻塞:insert into edu_test select 10, '12', '12'; | |
阻塞:insert into edu_test select 11, '11', '11'; | |
阻塞:insert into edu_test select 12, '10', '10'; | |
commit | |
commit; | |
执行阻塞内容 |
说明:a_val非主键值设置了索引,a_val值为11上排他锁,那么锁定的范围应该为[10,11)、[11,13)。
操作:
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_test where a_val = '11' for update; | |
成功:insert into edu_test select 6, '12', '12'; | |
commit; | |
commit |
说明:a_val非主键值设置为唯一索引,a_val值为11上了排他锁,那么锁定只为a_val=11的记录,其他记录不锁定,当前锁已经退化为了单条记录锁,如果硬插入a_val=11的记录,那么只会报值重复错误,锁粒度减小,提高了并发性。
操作:
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_test where a_val = '12' for update; | |
成功:insert into edu_test select 6, 9, '9'; | |
成功:insert into edu_test select 7, 10, '10'; | |
成功:insert into edu_test select 8, 14, '14'; | |
成功:insert into edu_test select 9, 13, '13'; | |
阻塞:insert into edu_test select 10, 11, '11'; | |
阻塞:insert into edu_test select 11, 12, '12'; | |
commit | |
commit; | |
执行阻塞内容 |
说明:a_val非主键值设置了索引,a_val设置了不存在的排他锁,这样innodb会对Next-Key Lock优化,将其退化为Gap Lock。锁定范围是[11, 13)。
order by排序会先将当前需要查询的结果排序,然后根据查询索引值前后加锁。
操作:
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_test where a_val = 20 order by a_val desc for update; | |
成功:insert into edu_test select 6, 12, '12'; | |
成功:insert into edu_test select 7, 32, '32'; | |
成功:insert into edu_test select 8, 31, '31'; | |
阻塞:insert into edu_test select 9, 13, '13'; | |
阻塞:insert into edu_test select 10, 25, '25'; | |
commit | |
commit; | |
执行阻塞内容 |
分析:先倒序排序
31, 20, 13, 11, 10
说明:当前索引值a_val为20,那么锁定范围为(31,13]。
操作:
session1 | session2 |
---|---|
set autocommit = 0; | set autocommit = 0; |
select * from edu_test where a_val < 20 and a_val > 11 order by a_val desc for update; | |
成功:insert into edu_test select 6, 31, '31'; | |
阻塞:insert into edu_test select 7, 10, '10'; | |
commit | |
commit; | |
执行阻塞内容 |
分析:先倒序排序
31, 20, 13, 11, 10
说明:当前索引值a_val为小于20、大于11,那么锁定范围为(31,10]。
《MySQL技术内幕》InnoDB存储引擎