■ 个人介绍
作者:何小栋
博客:http://blog.itpub.net/6906/
个人简介:从事产品研发和架构设计工作,ITPUB数据库版块资深版主,对PostgreSQL数据库及其源代码有深入研究。现就职于广州云图数据技术有限公司,系统架构师。
一
相关理论
1、数据库对象逻辑结构
PostgreSQL的逻辑对象体系结构如下图所示:

2、多粒度锁机制

3、两阶段锁(2PL)
二
PostgreSQL的表级锁和行级锁
基于上面介绍的理论基础,理解PostgreSQL中的锁相对容易一些(Oracle、MySQL同理)。
1、表级锁
PostgreSQL表级锁包括:Access Share(AS)、Row Share(RS)、Row Exclusive(RE)、Share Update Exclusive(SUE)、Share(S)、Share Row Exclusive(SRE)、Exclusive(E)、Access Exclusive(AE),共8种类型。不少PostgreSQL的初学者看到这么多锁估计会发懵,但如果我们结合上一节的多粒度锁机制来理解就会相对比较容易。
我们从两个维度来看:粒度和操作。粒度分为Relation和Row,操作分为读(Share)、写(Exclusive)和读写(Share Exclusive),根据这两个维度得到下面的矩阵:



2、行级锁

//t_infomask说明1 #define HEAP_HASNULL 0x0001 * has null attribute(s) */10 #define HEAP_HASVARWIDTH 0x0002 * has variable-width attribute(s) */100 #define HEAP_HASEXTERNAL 0x0004 * has external stored attribute(s) */1000 #define HEAP_HASOID 0x0008 * has an object-id field */10000 #define HEAP_XMAX_KEYSHR_LOCK 0x0010 * xmax is a key-shared locker */100000 #define HEAP_COMBOCID 0x0020 * t_cid is a combo cid */1000000 #define HEAP_XMAX_EXCL_LOCK 0x0040 * xmax is exclusive locker */10000000 #define HEAP_XMAX_LOCK_ONLY 0x0080 * xmax, if valid, is only a locker */* xmax is a shared locker */#define HEAP_XMAX_SHR_LOCK (HEAP_XMAX_EXCL_LOCK | HEAP_XMAX_KEYSHR_LOCK)#define HEAP_LOCK_MASK (HEAP_XMAX_SHR_LOCK | HEAP_XMAX_EXCL_LOCK | \HEAP_XMAX_KEYSHR_LOCK)100000000 #define HEAP_XMIN_COMMITTED 0x0100 * t_xmin committed */1000000000 #define HEAP_XMIN_INVALID 0x0200 * t_xmin invalid/aborted */#define HEAP_XMIN_FROZEN (HEAP_XMIN_COMMITTED|HEAP_XMIN_INVALID)10000000000 #define HEAP_XMAX_COMMITTED 0x0400 * t_xmax committed */100000000000 #define HEAP_XMAX_INVALID 0x0800 * t_xmax invalid/aborted */1000000000000 #define HEAP_XMAX_IS_MULTI 0x1000 * t_xmax is a MultiXactId */10000000000000 #define HEAP_UPDATED 0x2000 * this is UPDATEd version of row */100000000000000 #define HEAP_MOVED_OFF 0x4000 * moved to another place by pre-9.0* VACUUM FULL; kept for binary* upgrade support */1000000000000000 #define HEAP_MOVED_IN 0x8000 * moved from another place by pre-9.0* VACUUM FULL; kept for binary* upgrade support */#define HEAP_MOVED (HEAP_MOVED_OFF | HEAP_MOVED_IN)1111111111110000 #define HEAP_XACT_MASK 0xFFF0 /* visibility-related bits *///t_infomask2说明11111111111 #define HEAP_NATTS_MASK 0x07FF10000000000000 #define HEAP_KEYS_UPDATED 0x2000100000000000000 #define HEAP_HOT_UPDATED 0x40001000000000000000 #define HEAP_ONLY_TUPLE 0x80001110000000000000 #define HEAP2_XACT_MASK 0xE0001111111111111110 #define SpecTokenOffsetNumber 0xfffe
3、案例研究
drop table lockdemo;create table lockdemo(id int,c1 varchar);insert into lockdemo(id,c1) select x,'c1'||x from generate_series(1,10000) as x;
drop function get_tuple_locks;create or replace function get_tuple_locks(pi_name in varchar) returns setof record as $$SELECT '(0,'||lp||')' AS ctid, -- tuple ctidt_xmax as xmax, -- xmaxCASE WHEN (t_infomask & 128) > 0 THEN 't' END AS lock_only, -- 0x0080,HEAP_XMAX_LOCK_ONLYCASE WHEN (t_infomask & 4096) > 0 THEN 't' END AS is_multi, -- 0x1000,HEAP_XMAX_IS_MULTICASE WHEN (t_infomask2 & 8192) > 0 THEN 't' END AS keys_upd, -- 0x2000,HEAP_KEYS_UPDATEDCASE WHEN (t_infomask & 16) > 0 THEN 't' END AS keyshr_lock, -- 0x0010,HEAP_XMAX_KEYSHR_LOCKCASE WHEN (t_infomask & 16+64) = 16+64 THEN 't' END AS shr_lock -- 0x0010 & 0x0040,HEAP_XMAX_SHR_LOCK = HEAP_XMAX_KEYSHR_LOCK | HEAP_XMAX_EXCL_LOCKFROM heap_page_items(get_raw_page(pi_name,0))ORDER BY lp;$$ language sql;
除此之外,PostgreSQL还提供了pgrowlocks插件用于查询行级锁。
create extension pgrowlocks;
session 1
[local:/opt/data5012]:5012 pg12@testdb=# select pg_backend_pid();pg_backend_pid----------------1714(1 row)Time: 2.994 ms[local:/opt/data5012]:5012 pg12@testdb=# begin;BEGINTime: 0.154 ms[local:/opt/data5012]:5012 pg12@testdb=#* update lockdemo set c1 = 'x';UPDATE 10000Time: 15.786 ms[local:/opt/data5012]:5012 pg12@testdb=#*[local:/opt/data5012]:5012 pg12@testdb=#* select txid_current();txid_current--------------529(1 row)Time: 2.916 ms
session 2
[local:/opt/data5012]:5012 pg12@testdb=# select pg_backend_pid();pg_backend_pid----------------1712(1 row)Time: 0.616 ms[local:/opt/data5012]:5012 pg12@testdb=# begin;BEGINTime: 0.310 ms[local:/opt/data5012]:5012 pg12@testdb=#* update lockdemo set c1 = 'y';
查询session 1和2的锁信息
-- session 1[local:/opt/data5012]:5012 pg12@testdb=# select pid,locktype,relation::regclass,page,tuple,transactionid,mode,granted,fastpath from pg_locks where pid = 1714;pid | locktype | relation | page | tuple | transactionid | mode | granted | fastpath------+---------------+----------+------+-------+---------------+------------------+---------+----------1714 | relation | lockdemo | | | | RowExclusiveLock | t | t1714 | virtualxid | | | | | ExclusiveLock | t | t1714 | transactionid | | | | 529 | ExclusiveLock | t | f(3 rows)Time: 5.251 ms-- session 2[local:/opt/data5012]:5012 pg12@testdb=# select pid,locktype,relation::regclass,page,tuple,transactionid,mode,granted,fastpath from pg_locks where pid = 1712;pid | locktype | relation | page | tuple | transactionid | mode | granted | fastpath------+---------------+----------+------+-------+---------------+------------------+---------+----------1712 | relation | lockdemo | | | | RowExclusiveLock | t | t1712 | virtualxid | | | | | ExclusiveLock | t | t1712 | transactionid | | | | 529 | ShareLock | f | f1712 | tuple | lockdemo | 0 | 1 | | ExclusiveLock | t | f1712 | transactionid | | | | 531 | ExclusiveLock | t | f(5 rows)Time: 0.797 ms[local:/opt/data5012]:5012 pg12@testdb=#
[local:/opt/data5012]:5012 pg12@testdb=# select pg_backend_pid();pg_backend_pid----------------1837(1 row)Time: 0.644 ms[local:/opt/data5012]:5012 pg12@testdb=# begin;BEGINTime: 0.455 ms[local:/opt/data5012]:5012 pg12@testdb=#* update lockdemo set c1='z';
查询session 3的锁信息
[local:/opt/data5012]:5012 pg12@testdb=# select pid,locktype,relation::regclass,page,tuple,transactionid,mode,granted,fastpath from pg_locks where pid = 1837;pid | locktype | relation | page | tuple | transactionid | mode | granted | fastpath------+---------------+----------+------+-------+---------------+------------------+---------+----------1837 | relation | lockdemo | | | | RowExclusiveLock | t | t1837 | virtualxid | | | | | ExclusiveLock | t | t1837 | tuple | lockdemo | 0 | 1 | | ExclusiveLock | f | f1837 | transactionid | | | | 532 | ExclusiveLock | t | f(4 rows)Time: 0.705 ms[local:/opt/data5012]:5012 pg12@testdb=#
[local:/opt/data5012]:5012 pg12@testdb=# select get_tuple_locks('lockdemo');get_tuple_locks----------------------("(0,1)",529,,,,,)("(0,2)",529,,,,,)("(0,3)",529,,,,,)("(0,4)",529,,,,,)("(0,5)",529,,,,,)("(0,6)",529,,,,,)("(0,7)",529,,,,,)("(0,8)",529,,,,,)...[local:/opt/data5012]:5012 pg12@testdb=# select * from pgrowlocks('lockdemo');locked_row | locker | multi | xids | modes | pids------------+--------+-------+-------+-------------------+--------(0,1) | 529 | f | {529} | {"No Key Update"} | {1714}...
由于更新SQL没有带条件,因此XID 529在lockdemo上的每个元组都加锁。
三
小结
四
参考资料
[1] PostgreSQL Source Code,README.tuplock
[2] PostgreSQL Manual
[3] Postgres Professional,erogov,Locks in PostgreSQL
[4] Unlocking the Postgres Lock Manager,BRUCE MOMJIAN

扫二维码|关注我们
每周免费看直播
PostgreSQL中文社区欢迎广大技术人员投稿
投稿邮箱:press@postgres.cn




