作者简介
何小栋,从事产品研发和架构设计工作,对PostgreSQL数据库及其源代码有深入研究。现就职于广州海量数据库技术有限公司,系统架构师。
校对者简介
崔鹏,任职于海能达通信股份有限公司,数据库开发高级工程师,致力于postgresql数据库在专网通信领域、公共安全领域的应用与推广。
一、PostgreSQL RR Isolation Level
时间点 | T1 | T2 |
t1 | START TRANSACTION ISOLATION LEVEL REPEATABLE READ; | |
t2 | START TRANSACTION ISOLATION LEVEL REPEATABLE READ; | |
t3 | update t1 set id = 1 where id = 5; | |
t4 | update t1 set id = 11 where id = 5; | |
t5 | commit; | |
t6 | 提示出错 |
-- T1[local]:5432 postgres@testdb=# START TRANSACTION ISOLATION LEVEL REPEATABLE READ;START TRANSACTIONTime: 0.197 ms-- T2[local]:5432 postgres@testdb=# START TRANSACTION ISOLATION LEVEL REPEATABLE READ;START TRANSACTIONTime: 0.181 ms-- T1[local]:5432 postgres@testdb=#* update t1 set id = 1 where id = 5;UPDATE 1Time: 0.430 ms-- T2[local]:5432 postgres@testdb=#* update t1 set id = 11 where id = 5;---------->wait-- T1[local]:5432 postgres@testdb=#* commit;COMMITTime: 3.241 ms-- T2[local]:5432 postgres@testdb=#* update t1 set id = 11 where id = 5;ERROR: could not serialize access due to concurrent updateTime: 3172.768 ms (00:03.173)
二、MySQL RR Isolation Level
MySQL默认的隔离级别是RR
mysql> select version();+-----------+| version() |+-----------+| 8.0.21 |+-----------+1 row in set (0.00 sec)mysql> show variables like '%isolation%';+-----------------------+-----------------+| Variable_name | Value |+-----------------------+-----------------+| transaction_isolation | REPEATABLE-READ |+-----------------------+-----------------+1 row in set (0.00 sec)
use testdb;CREATE TABLE tbl1(counter int);CREATE TABLE tbl2(counter int);
SQL执行顺序:
时间点 | T1 | T2 |
t1 | begin; | |
t2 | begin; | |
t3 | INSERT INTO tbl1 SELECT count(*) FROM tbl2; | |
t4 | INSERT INTO tbl2 SELECT count(*) FROM tbl1; | |
<Session Hang!> | ||
t5 | commit; | |
t6 | 执行成功 |
在Session Hang的时候使用show engine innodb status;命令查看TRANSACTIONS信息
------------TRANSACTIONS------------Trx id counter 2591Purge done for trx's n:o < 2587 undo n:o < 0 state: running but idleHistory list length 2LIST OF TRANSACTIONS FOR EACH SESSION:---TRANSACTION 421821791990000, not started0 lock struct(s), heap size 1136, 0 row lock(s)---TRANSACTION 421821791988288, not started0 lock struct(s), heap size 1136, 0 row lock(s)---TRANSACTION 421821791987432, not started0 lock struct(s), heap size 1136, 0 row lock(s)---TRANSACTION 2590, ACTIVE 63 sec starting index readmysql tables in use 2, locked 2LOCK WAIT 2 lock struct(s), heap size 1136, 2 row lock(s)MySQL thread id 13, OS thread handle 140346785715968, query id 52 localhost root executingINSERT INTO tbl2 SELECT count(*) FROM tbl1------- TRX HAS BEEN WAITING 4 SEC FOR THIS LOCK TO BE GRANTED:RECORD LOCKS space id 9 page no 4 n bits 72 index GEN_CLUST_INDEX of table `testdb`.`tbl1` trx id 2590 lock mode S waitingRecord lock, heap no 2 PHYSICAL RECORD: n_fields 4; compact format; info bits 00: len 6; hex 000000020300; asc ;;1: len 6; hex 000000000a1d; asc ;;2: len 7; hex 81000001090110; asc ;;3: len 4; hex 80000000; asc ;;---------------------TRANSACTION 2589, ACTIVE 80 sec4 lock struct(s), heap size 1136, 2 row lock(s), undo log entries 1MySQL thread id 12, OS thread handle 140346786010880, query id 36 localhost root--------
...RECORD LOCKS space id 9 page no 4 n bits 72 index GEN_CLUST_INDEX of table `testdb`.`tbl1` trx id 2590 lock mode S waiting...
mysql> SELECT ENGINE_LOCK_ID,ENGINE_TRANSACTION_ID,object_schema,object_name,index_name,LOCK_TYPE,lock_mode,lock_status,lock_data FROM performance_schema.data_locks where object_name='tbl1' and index_name is not null order by ENGINE_TRANSACTION_ID;+---------------------------------------+-----------------------+---------------+-------------+-----------------+-----------+---------------+-------------+----------------+| ENGINE_LOCK_ID | ENGINE_TRANSACTION_ID | object_schema | object_name | index_name | LOCK_TYPE | lock_mode | lock_status | lock_data |+---------------------------------------+-----------------------+---------------+-------------+-----------------+-----------+---------------+-------------+----------------+| 140346815278488:9:4:2:140346713517384 | 2589 | testdb | tbl1 | GEN_CLUST_INDEX | RECORD | X,REC_NOT_GAP | GRANTED | 0x000000020300 || 140346815280200:9:4:2:140346713529984 | 2590 | testdb | tbl1 | GEN_CLUST_INDEX | RECORD | S | WAITING | 0x000000020300 |+---------------------------------------+-----------------------+---------------+-------------+-----------------+-----------+---------------+-------------+----------------+2 rows in set (0.00 sec)
mysql> drop table tbl;Query OK, 0 rows affected (0.03 sec)mysql> CREATE TABLE tbl(id int);Query OK, 0 rows affected (0.03 sec)mysql> INSERT INTO tbl VALUES (1),(2),(3),(4);Query OK, 4 rows affected (0.01 sec)Records: 4 Duplicates: 0 Warnings: 0
执行顺序:
时间点 | T1 | T2 |
t1 | begin; | |
t2 | begin; | |
t3 | UPDATE tbl SET id=id-1; | |
t4 | SELECT * FROM tbl; | |
t5 | DELETE FROM tbl WHERE id=4; | |
Session Wait! | ||
t6 | commit; | |
t7 | select * from tbl; | |
t8 | DELETE FROM tbl WHERE id=4; |
执行结果是:
...-- T1mysql> select * from tbl;+------+| id |+------+| 0 || 1 || 2 || 3 |+------+4 rows in set (0.00 sec)-- T2...mysql> select * from tbl;+------+| id |+------+| 1 || 2 || 3 || 4 |+------+4 rows in set (0.00 sec)mysql> DELETE FROM tbl WHERE id=4;Query OK, 0 rows affected (0.00 sec)
三、参考资料
[1] MySQL Document,InnoDB Locking,GEN_CLUST_INDEX...
[2] Daniel Verite,Isolation Repeatable Read in PostgreSQL versus MySQL

扫二维码|报名参与
2020 PostgreSQL第十届
中国技术大会
PostgreSQL中文社区欢迎广大技术人员投稿
投稿邮箱:press@postgres.cn




