锁列表
- 共享与列排他锁
- 意向锁
- 记录锁
- 间隙锁
- Next-Key锁
- 插入意向锁
- AUTO-INC锁
这次我们只来讨论和实验意向锁。
Next-Key锁
概述
Next-Key锁称为临键锁。
临键锁可以理解为锁住的是索引本身以及索引之前的间隙,是一个左开右闭的区间。当 SQL 执行按照非唯一索引进行数据的检索时,会给匹配到行上加上临键锁。
锁定区间
实验
以下实验基于MySQL 8.0.x版本。
建表语句:
CREATE TABLE `sys_user` ( `id` int NOT NULL AUTO_INCREMENT,
`name` varchar(10) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '姓名',
`name_pinyin` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '姓名拼音',
`id_card` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '身份证号',
`phone` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci DEFAULT NULL COMMENT '手机号',
PRIMARY KEY (`id`),
UNIQUE KEY `uni_idx_id_card` (`id_card`) USING BTREE COMMENT '唯一索引-身份证号',
KEY `idx_phone_name` (`phone`,`name`) USING BTREE COMMENT '普通索引-手机号' ) ENGINE=InnoDB AUTO_INCREMENT=3495 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='用户'
插入记录
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (1, '小六', 'xiaoliu', 300000000, 13000008000, 10);
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (2, '小六', 'xiaoliu', 300000001, 13000008000, 11);
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (3, '小六', 'xiaoliu', 300000002, 13000008000, 13);
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (4, '小六', 'xiaoliu', 300000003, 13000008000, 20);
记录键存在的间隙区间:
- (负无穷大,10]
- (10, 11]
- (11, 13]
- (13, 20]
- (20, 正无穷大]
临键锁区间
- (负无穷大,10]
- 间隙锁范围内插入
事务A:
begin;
select * from sys_user where age=10 for update;
事务B:
begin;
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (5, '小六', 'xiaoliu', 300000004, 13000008000, 9);
结果:
事务B被阻塞,无法被插入。
- 间隙锁范围外插入
事务A:
begin;
select * from sys_user where age=10 for update;
事务B:
begin;
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (5, '小六', 'xiaoliu', 300000004, 13000008000, 11);
结果:
事务B正常插入,无阻塞。
- (11, 13]~(13, 20)
- 间隙锁范围内插入,被阻塞
事务A:
begin;
select * from sys_user where age=13 for update;
事务B:
begin;
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (6, '小六', 'xiaoliu', 300000005, 13000008000, 12);
结果:
事务B无法正常插入,被阻塞。
- 间隙锁范围外插入,无阻塞正常插入
事务A:
begin;
select * from sys_user where age=13 for update;
事务B:
begin;
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (67, '小六', 'xiaoliu', 300000006, 13000008000, 10);
结果:
事务B正常插入。
- (20, 正无穷大]
- 间隙锁范围内插入被阻塞
事务A:
begin;
select * from sys_user where age=20 for update;
事务B:
begin;
// 以下两条都会阻塞
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (67, '小六', 'xiaoliu', 300000006, 13000008000, 13);
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (67, '小六', 'xiaoliu', 300000006, 13000008000, 100000);
结果:
事务B被阻塞。
- 间隙锁范围外正常插入
事务A:
begin;
select * from sys_user where age=20 for update;
事务B:
begin;
insert into sys_user (id, name, name_pinyin, id_card, phone, age)values (67, '小六', 'xiaoliu', 300000006, 13000008000, 12);
结果:
事务B正常插入。
注意
- 建议尽可能让所有的查询都使用主键或者唯一索引,这样可以避免临键锁,预防对记录大面积的锁。