暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

PG 13 锁机制思维导图

PostgreSQL数据库工作学习随笔 2022-05-28
479



    一个SQL
    with
    t_wait as
    (
    select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
    a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,a.fastpath,
    b.state,b.query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
    from pg_locks a,pg_stat_activity b where a.pid=b.pid and not a.granted
    ),
    t_run as
    (
    select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
    a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,a.fastpath,
    b.state,b.query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
    from pg_locks a,pg_stat_activity b where a.pid=b.pid and a.granted
    ),
    t_overlap as
    (
    select r.* from t_wait w join t_run r on
    (
    r.locktype is not distinct from w.locktype and
    r.database is not distinct from w.database and
    r.relation is not distinct from w.relation and
    r.page is not distinct from w.page and
    r.tuple is not distinct from w.tuple and
    r.virtualxid is not distinct from w.virtualxid and
    r.transactionid is not distinct from w.transactionid and
    r.classid is not distinct from w.classid and
    r.objid is not distinct from w.objid and
    r.objsubid is not distinct from w.objsubid and
    r.pid <> w.pid
    )
    ),
    t_unionall as
    (
    select r.* from t_overlap r
    union all
    select w.* from t_wait w
    )
    select locktype,datname,relation::regclass,page,tuple,virtualxid,transactionid::text,classid::regclass,objid,objsubid,
    string_agg(
    'Pid: '||case when pid is null then 'NULL' else pid::text end||chr(10)||
    'Lock_Granted: '||case when granted is null then 'NULL' else granted::text end||' , Mode: '||case when mode is null then 'NULL' else mode::text end||' , FastPath: '||case when fastpath is null then 'NULL' else fastpath::text end||' , VirtualTransaction: '||case when virtualtransaction is null then 'NULL' else virtualtransaction::text end||' , Session_State: '||case when state is null then 'NULL' else state::text end||chr(10)||
    'Username: '||case when usename is null then 'NULL' else usename::text end||' , Database: '||case when datname is null then 'NULL' else datname::text end||' , Client_Addr: '||case when client_addr is null then 'NULL' else client_addr::text end||' , Client_Port: '||case when client_port is null then 'NULL' else client_port::text end||' , Application_Name: '||case when application_name is null then 'NULL' else application_name::text end||chr(10)||
    'Xact_Start: '||case when xact_start is null then 'NULL' else xact_start::text end||' , Query_Start: '||case when query_start is null then 'NULL' else query_start::text end||' , Xact_Elapse: '||case when (now()-xact_start) is null then 'NULL' else (now()-xact_start)::text end||' , Query_Elapse: '||case when (now()-query_start) is null then 'NULL' else (now()-query_start)::text end||chr(10)||
    'SQL (Current SQL in Transaction): '||chr(10)||
    case when query is null then 'NULL' else query::text end,
    chr(10)||'--------'||chr(10)
    order by
    ( case mode
    when 'INVALID' then 0
    when 'AccessShareLock' then 1
    when 'RowShareLock' then 2
    when 'RowExclusiveLock' then 3
    when 'ShareUpdateExclusiveLock' then 4
    when 'ShareLock' then 5
    when 'ShareRowExclusiveLock' then 6
    when 'ExclusiveLock' then 7
    when 'AccessExclusiveLock' then 8
    else 0
    end ) desc,
    (case when granted then 0 else 1 end)
    ) as lock_conflict
    from t_unionall
    group by
    locktype,datname,relation,page,tuple,virtualxid,transactionid::text,classid,objid,objsubid ;


    文章转载自PostgreSQL数据库工作学习随笔,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

    评论