MySQL TOO BAD row's Range Lock Compare with PostgreSQL and Oracle

本文涉及的产品
云原生数据库 PolarDB MySQL 版,Serverless 5000PCU 100GB
RDS MySQL Serverless 基础系列,0.5-2RCU 50GB
云数据库 RDS MySQL,集群版 2核4GB 100GB
推荐场景:
搭建个人博客
简介:
MySQL的InnoDB引擎,当UPDATE一个范围的数据时,会锁住比预期更多的ROW,而Oracle和PostgreSQL没有这种现象.
来自《High Performance MySQL》一书。
测试版本:
MySQL 5.5.10
PostgreSQL 9.0.2
Oracle 10.2.0.4
举例如下:
1. MySQL (有索引的情况)
Session One:
mysql> create table tbl_user (id int,firstname varchar(32),lastname varchar(32),corp varchar(32),primary key (id)) engine=innodb;
Query OK, 0 rows affected (0.08 sec)
mysql> begin;
mysql> insert into tbl_user values(1,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(2,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(3,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(4,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(5,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(6,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(7,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(8,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(9,'zhou','digoal','sky-mobi');
mysql> insert into tbl_user values(10,'zhou','digoal','sky-mobi');
mysql> commit;
# 测试range scan in INDEX
# 从结果上看,这个session应该只对id=2,3,4的三行持锁,实际上不是
mysql> begin;
Query OK, 0 rows affected (0.00 sec)

mysql> select * from tbl_user where id<5 and id<>1 for update;
+----+-----------+----------+----------+
| id | firstname | lastname | corp     |
+----+-----------+----------+----------+
|  2 | zhou      | digoal   | sky-mobi |
|  3 | zhou      | digoal   | sky-mobi |
|  4 | zhou      | digoal   | sky-mobi |
+----+-----------+----------+----------+
3 rows in set (0.00 sec)
# 打开另一个SESSION来看看情况如何
Session TWO : 
mysql> begin;
Query OK, 0 rows affected (0.00 sec)

mysql> update tbl_user set corp='skymobi' where id=1;
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
ERROR 1317 (70100): Query execution was interrupted
# id=1的记录被锁
mysql> rollback;
Query OK, 0 rows affected (0.00 sec)

mysql> begin;
Query OK, 0 rows affected (0.00 sec)

mysql> update tbl_user set corp='skymobi' where id=5;
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
ERROR 1317 (70100): Query execution was interrupted
# id=5的记录被锁
mysql> 
mysql> begin;
Query OK, 0 rows affected (0.00 sec)

mysql> update tbl_user set corp='skymobi' where id=10;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1  Changed: 1  Warnings: 0

mysql> rollback;
Query OK, 0 rows affected (0.02 sec)

mysql> begin;
Query OK, 0 rows affected (0.00 sec)

mysql> update tbl_user set corp='skymobi' where id=6;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1  Changed: 1  Warnings: 0

mysql> rollback;
Query OK, 0 rows affected (0.02 sec)
# 比预期的多锁了两行id=1,5

# MySQL没有索引的情况,锁全表
Session One : 
mysql> create table tbl_user (id int,firstname varchar(32),lastname varchar(32),corp varchar(32)) engine=innodb;
mysql> select * from tbl_user where id<5 and id<>1 for update;
+------+-----------+----------+----------+
| id   | firstname | lastname | corp     |
+------+-----------+----------+----------+
|    2 | zhou      | digoal   | sky-mobi |
|    3 | zhou      | digoal   | sky-mobi |
|    4 | zhou      | digoal   | sky-mobi |
+------+-----------+----------+----------+
3 rows in set (0.00 sec)

Session Two : 

mysql> update tbl_user set corp='skymobi' where id=5;
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
ERROR 1317 (70100): Query execution was interrupted
mysql> 
mysql> update tbl_user set corp='skymobi' where id=6;
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
ERROR 1317 (70100): Query execution was interrupted
mysql> update tbl_user set corp='skymobi' where id=1;
Ctrl-C -- sending "KILL QUERY 4" to server ...
Ctrl-C -- query aborted.
^[[AERROR 1317 (70100): Query execution was interrupted

2. PostgreSQL同样的测试,不存在多锁的情况
Session One : 
digoal=> create table tbl_user (id serial,firstname varchar(32),lastname varchar(32),corp varchar(32),primary key (id));
NOTICE:  CREATE TABLE will create implicit sequence "tbl_user_id_seq" for serial column "tbl_user.id"
NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index "tbl_user_pkey" for table "tbl_user"
CREATE TABLE
digoal=> insert into tbl_user select generate_series(1,1000),'zhou','digoal','sky-mobi';
INSERT 0 1000
digoal=> begin;
BEGIN
digoal=> select * from tbl_user where id<5 and id<>1 for update;
 id | firstname | lastname |   corp   
----+-----------+----------+----------
  2 | zhou      | digoal   | sky-mobi
  3 | zhou      | digoal   | sky-mobi
  4 | zhou      | digoal   | sky-mobi
(3 rows)

Session Two : 
digoal=> begin;
BEGIN
digoal=> update tbl_user set corp='skymobi' where id=2;
Cancel request sent
ERROR:  canceling statement due to user request
digoal=> rollback;
ROLLBACK
digoal=> begin;
BEGIN
digoal=> update tbl_user set corp='skymobi' where id=1;
UPDATE 1
digoal=> rollback;
ROLLBACK
digoal=> begin;
BEGIN
digoal=> update tbl_user set corp='skymobi' where id=5;
UPDATE 1
digoal=> rollback;
ROLLBACK
digoal=> 

PostgreSQL无索引测试,结果和有索引一致
digoal=> create table tbl_user (id serial,firstname varchar(32),lastname varchar(32),corp varchar(32));
NOTICE:  CREATE TABLE will create implicit sequence "tbl_user_id_seq" for serial column "tbl_user.id"
CREATE TABLE
digoal=> insert into tbl_user select generate_series(1,1000),'zhou','digoal','sky-mobi';
INSERT 0 1000
digoal=> begin;
BEGIN
digoal=> select * from tbl_user where id<5 and id<>1 for update;
 id | firstname | lastname |   corp   
----+-----------+----------+----------
  2 | zhou      | digoal   | sky-mobi
  3 | zhou      | digoal   | sky-mobi
  4 | zhou      | digoal   | sky-mobi
(3 rows)

Session Two : 
digoal=> begin;
BEGIN
digoal=> update tbl_user set corp='skymobi' where id=5;
UPDATE 1
digoal=> update tbl_user set corp='skymobi' where id=1;
UPDATE 1
digoal=> update tbl_user set corp='skymobi' where id=2;
Cancel request sent
ERROR:  canceling statement due to user request
digoal=> rollback;
ROLLBACK

3. Oracle 同样的测试,不存在多锁的情况
Session One : 
SQL> create table tbl_user (id int,firstname varchar2(32),lastname varchar2(32),corp varchar2(32) ,primary key (id));

Table created.

SQL> insert into tbl_user select rownum,'zhou','digoal','sky-mobi' from dual connect by level <=1000;

1000 rows created.

SQL> commit;

Commit complete.

SQL> select * from tbl_user where id<5 and id<>1 for update;

        ID FIRSTNAME                        LASTNAME                         CORP
---------- -------------------------------- -------------------------------- --------------------------------
         2 zhou                             digoal                           sky-mobi
         3 zhou                             digoal                           sky-mobi
         4 zhou                             digoal                           sky-mobi

Session Two : 
SQL> update tbl_user set corp='skymobi' where id=1;

1 row updated.

SQL> rollback;

Rollback complete.

SQL> update tbl_user set corp='skymobi' where id=2;
update tbl_user set corp='skymobi' where id=2
       *
ERROR at line 1:
ORA-01013: user requested cancel of current operation



SQL> update tbl_user set corp='skymobi' where id=5;

1 row updated.

SQL> rollback;

Rollback complete.

# Oracle无索引和有索引结果一致
Session One : 
SQL> create table tbl_user (id int,firstname varchar2(32),lastname varchar2(32),corp varchar2(32));

Table created.

SQL> insert into tbl_user select rownum,'zhou','digoal','sky-mobi' from dual connect by level <=1000;

1000 rows created.

SQL> commit;

Commit complete.

SQL> select * from tbl_user where id<5 and id<>1 for update;

        ID FIRSTNAME                        LASTNAME                         CORP
---------- -------------------------------- -------------------------------- --------------------------------
         2 zhou                             digoal                           sky-mobi
         3 zhou                             digoal                           sky-mobi
         4 zhou                             digoal                           sky-mobi

Session Two : 
SQL> update tbl_user set corp='skymobi' where id=5;

1 row updated.

SQL> update tbl_user set corp='skymobi' where id=1;

1 row updated.

SQL> update tbl_user set corp='skymobi' where id=2;
update tbl_user set corp='skymobi' where id=2
       *
ERROR at line 1:
ORA-01013: user requested cancel of current operation


小结 : 
1. MySQL InnoDB引擎表按照范围来获取锁时,会锁住比预期更多的ROWS(使用索引略好,不使用索引的话就是全表)。
2. PostgreSQL和Oracle不存在这种情况.
越来越觉得MySQL High不起来了
3. 后续, Mysql 锁范围放大的原因. 
PostgreSQL repeatable read, serializable和read committed 隔离级别都不会造成这种锁范围放大的情况.
原因是PostgreSQL 的多版本并发控制机制利用了tuple infomask标记, 新老版本并存, committed 状态, 事务snapshot状态等信息.
并发能力相当高.
而mysql 锁范围放大和它的锁机制有关:
主要原因是mysql利用了索引来加锁. 除了read uncommitted, 其他隔离级别都会造成锁放大. 
默认隔离级别为repeatable read; 
repeatable read:
For locking reads (SELECT with FOR UPDATE or LOCK IN SHARE MODE), UPDATE, and DELETE statements, locking depends on whether the statement uses a unique index with a unique search condition, or a range-type search condition. For a unique index with a unique search condition, InnoDB locks only the index record found, not the gap before it. For other search conditions, InnoDB locks the index range scanned, using gap locks or next-key locks to block insertions by other sessions into the gaps covered by the range.

read committed:
For locking reads (SELECT with FOR UPDATE or LOCK IN SHARE MODE), UPDATE statements, and DELETE statements, InnoDB locks only index records, not the gaps before them, and thus permits the free insertion of new records next to locked records.

相关实践学习
如何在云端创建MySQL数据库
开始实验后,系统会自动创建一台自建MySQL的 源数据库 ECS 实例和一台 目标数据库 RDS。
全面了解阿里云能为你做什么
阿里云在全球各地部署高效节能的绿色数据中心,利用清洁计算为万物互联的新世界提供源源不断的能源动力,目前开服的区域包括中国(华北、华东、华南、香港)、新加坡、美国(美东、美西)、欧洲、中东、澳大利亚、日本。目前阿里云的产品涵盖弹性计算、数据库、存储与CDN、分析与搜索、云通信、网络、管理与监控、应用服务、互联网中间件、移动服务、视频服务等。通过本课程,来了解阿里云能够为你的业务带来哪些帮助 &nbsp; &nbsp; 相关的阿里云产品:云服务器ECS 云服务器 ECS(Elastic Compute Service)是一种弹性可伸缩的计算服务,助您降低 IT 成本,提升运维效率,使您更专注于核心业务创新。产品详情: https://www.aliyun.com/product/ecs
相关文章
|
5天前
|
数据采集 关系型数据库 MySQL
大数据-业务数据采集-FlinkCDC The MySQL server is not configured to use a ROW binlog_format
大数据-业务数据采集-FlinkCDC The MySQL server is not configured to use a ROW binlog_format
15 1
|
7天前
|
Oracle 关系型数据库 MySQL
Mysql和Oracle数据库死锁查看以及解决
【8月更文挑战第11天】本文介绍了解决MySQL与Oracle数据库死锁的方法。MySQL可通过`SHOW ENGINE INNODB STATUS`查看死锁详情,并自动回滚一个事务解除死锁;也可手动KILL事务。Oracle则通过查询V$LOCK与V$SESSION视图定位死锁,并用`ALTER SYSTEM KILL SESSION`命令终止相关会话。预防措施包括遵循ACID原则、优化索引及拆分大型事务。
|
7天前
|
关系型数据库 MySQL
解决MySQL insert出现Incorrect datetime value: ‘0000-00-00 00:00:00‘ for column ‘xxx‘ at row 1
解决MySQL insert出现Incorrect datetime value: ‘0000-00-00 00:00:00‘ for column ‘xxx‘ at row 1
24 2
|
3天前
|
关系型数据库 MySQL 数据库
探究数据库开源协议:PostgreSQL vs MySQL
探究数据库开源协议:PostgreSQL vs MySQL
|
1月前
|
SQL Oracle 关系型数据库
MySQL、SQL Server和Oracle数据库安装部署教程
数据库的安装部署教程因不同的数据库管理系统(DBMS)而异,以下将以MySQL、SQL Server和Oracle为例,分别概述其安装部署的基本步骤。请注意,由于软件版本和操作系统的不同,具体步骤可能会有所变化。
75 3
|
2月前
|
SQL 关系型数据库 数据库
nacos 2.2.3版本 查看配置文件的历史版本的接口 是针对MySQL数据库的sql 改成postgresql后 sql语句报错 该怎么解决
在Nacos 2.2.3中切换到PostgreSQL后,执行配置文件历史版本分页查询出错,因`LIMIT 0, 10`语法不被PostgreSQL支持,需改为`LIMIT 10 OFFSET 0`。仅当存在历史版本时报错。解决方案是调整查询SQL以兼容PostgreSQL语法。
|
3月前
|
关系型数据库 MySQL Java
项目从 MySQL 切换 PostgreSQL,踩了太多的坑!!!
底层自己操作数据库可能就无法修改源码了,只能修改数据库表字段类型了
85 1
|
2月前
|
存储 SQL 关系型数据库
【MySQL技术内幕】6.1-锁、lock和latch
【MySQL技术内幕】6.1-锁、lock和latch
35 0
|
2月前
|
SQL Oracle 关系型数据库
mysql和oracle 命令行执行sql文件 数据库执行sql文件 执行sql语句
mysql和oracle 命令行执行sql文件 数据库执行sql文件 执行sql语句
48 0
|
3月前
|
存储 关系型数据库 MySQL
MySQL的优化利器⭐️Multi Range Read与Covering Index是如何优化回表的?
本文以小白的视角使用通俗易懂的流程图深入浅出分析Multi Range Read与Covering Index是如何优化回表

推荐镜像

更多