Lock Monitoring

From PostgreSQL wiki

(Difference between revisions)
Jump to: navigation, search
(+cat)
Line 22: Line 22:
 
       outer join pg_class on (pg_locks.relation = pg_class.oid)   
 
       outer join pg_class on (pg_locks.relation = pg_class.oid)   
 
     where pg_locks.pid=pg_stat_activity.procpid order by query_start;
 
     where pg_locks.pid=pg_stat_activity.procpid order by query_start;
 +
 +
* Here's almost quite the same thing but with some more details:
 +
 +
  select bl.pid as blocked_pid, a.usename as blocked_user,
 +
        ka.current_query as blocking_statement, now() - ka.query_start as blocking_duration,
 +
        kl.pid as blocking_pid, ka.usename as blocking_user, a.current_query as blocked_statement,
 +
        now() - a.query_start as blocked_duration
 +
  from pg_catalog.pg_locks bl
 +
      join pg_catalog.pg_stat_activity a
 +
      on bl.pid = a.procpid
 +
      join pg_catalog.pg_locks kl
 +
            join pg_catalog.pg_stat_activity ka
 +
            on kl.pid = ka.procpid
 +
      on bl.transactionid = kl.transactionid and bl.pid != kl.pid
 +
  where not bl.granted;
  
 
* If you suspect intermittent locks are causing problems only sometimes, but are having trouble catching them in one of these live views, setting the [http://www.postgresql.org/docs/current/static/runtime-config-logging.html#GUC-LOG-LOCK-WAITS log_lock_waits] and related [http://www.postgresql.org/docs/current/static/runtime-config-locks.html#GUC-DEADLOCK-TIMEOUT deadlock_timeout] parameters can be helpful.  Then slow lock acquisition will appear in the database logs for later analysis.
 
* If you suspect intermittent locks are causing problems only sometimes, but are having trouble catching them in one of these live views, setting the [http://www.postgresql.org/docs/current/static/runtime-config-logging.html#GUC-LOG-LOCK-WAITS log_lock_waits] and related [http://www.postgresql.org/docs/current/static/runtime-config-locks.html#GUC-DEADLOCK-TIMEOUT deadlock_timeout] parameters can be helpful.  Then slow lock acquisition will appear in the database logs for later analysis.

Revision as of 09:18, 25 May 2012

  • Looking at pg_locks shows you what locks are granted and what processes are waiting for locks to be acquired. A good query to start looking for lock problems:
 select relation::regclass, * from pg_locks where not granted;
  • Figuring out what the processes holding or waiting for locks is easier if you cross-reference against the information in pg_stat_activity
  • The following query may be helpful to see what processes are blocking SQL statements:
 select bl.pid as blocked_pid, a.usename as blocked_user, 
        kl.pid as blocking_pid, ka.usename as blocking_user, a.current_query as blocked_statement
 from pg_catalog.pg_locks bl
      join pg_catalog.pg_stat_activity a
      on bl.pid = a.procpid
      join pg_catalog.pg_locks kl
           join pg_catalog.pg_stat_activity ka
           on kl.pid = ka.procpid
      on bl.transactionid = kl.transactionid and bl.pid != kl.pid
 where not bl.granted;
  • Here's an alternate view of that same data that includes an idea how old the state is:
   select 
     pg_stat_activity.datname,pg_class.relname,pg_locks.transactionid, pg_locks.mode, pg_locks.granted,
     pg_stat_activity.usename,substr(pg_stat_activity.current_query,1,30), pg_stat_activity.query_start, 
     age(now(),pg_stat_activity.query_start) as "age", pg_stat_activity.procpid 
   from pg_stat_activity,pg_locks left 
     outer join pg_class on (pg_locks.relation = pg_class.oid)  
   where pg_locks.pid=pg_stat_activity.procpid order by query_start;
  • Here's almost quite the same thing but with some more details:
  select bl.pid as blocked_pid, a.usename as blocked_user,
        ka.current_query as blocking_statement, now() - ka.query_start as blocking_duration,
        kl.pid as blocking_pid, ka.usename as blocking_user, a.current_query as blocked_statement,
        now() - a.query_start as blocked_duration
 from pg_catalog.pg_locks bl
      join pg_catalog.pg_stat_activity a
      on bl.pid = a.procpid
      join pg_catalog.pg_locks kl
           join pg_catalog.pg_stat_activity ka
           on kl.pid = ka.procpid
      on bl.transactionid = kl.transactionid and bl.pid != kl.pid
 where not bl.granted;
  • If you suspect intermittent locks are causing problems only sometimes, but are having trouble catching them in one of these live views, setting the log_lock_waits and related deadlock_timeout parameters can be helpful. Then slow lock acquisition will appear in the database logs for later analysis.

See also Lock dependency information

Personal tools