One single blocking session in a database can completely halt your application so identifying which session is blocking other sessions is a task you must be able to perform quickly. In Oracle you can query v$session for getting that information (blocking_session, final_blocking_session). Can you do the same in PostgreSQL? Yes, you definitely can, lets go.

As usual we’ll start by creating a test table:

postgres@pgbox:/home/postgres/ [PG10B] psql -X postgres
psql (10beta2 dbi services build)
Type "help" for help.

postgres=# create table t1 ( a int );
CREATE TABLE
postgres=# 

One way to force other sessions to wait is to start a new transaction, modify the table:

postgres=# begin;
BEGIN
postgres=# alter table t1 add column t2 text;
ALTER TABLE
postgres=#  

… and then try to insert data into the same table from another session:

postgres@pgbox:/home/postgres/ [PG10B] psql -X postgres
psql (10beta2 dbi services build)
Type "help" for help.

postgres=# insert into t1 (a) values (1);

The insert statement will hang/wait because the modification of the table is still ongoing (the transaction did neither commit nor rollback, remember that DDLs in PostgreSQL are transactional). Now that we have a blocking session how can we identify the session?

What “v$session” is in Oracle, pg_stat_activity is in PostgreSQL (Note: I am using PostgreSQL 10Beta2 here):

postgres=# d pg_stat_activity 
                      View "pg_catalog.pg_stat_activity"
      Column      |           Type           | Collation | Nullable | Default 
------------------+--------------------------+-----------+----------+---------
 datid            | oid                      |           |          | 
 datname          | name                     |           |          | 
 pid              | integer                  |           |          | 
 usesysid         | oid                      |           |          | 
 usename          | name                     |           |          | 
 application_name | text                     |           |          | 
 client_addr      | inet                     |           |          | 
 client_hostname  | text                     |           |          | 
 client_port      | integer                  |           |          | 
 backend_start    | timestamp with time zone |           |          | 
 xact_start       | timestamp with time zone |           |          | 
 query_start      | timestamp with time zone |           |          | 
 state_change     | timestamp with time zone |           |          | 
 wait_event_type  | text                     |           |          | 
 wait_event       | text                     |           |          | 
 state            | text                     |           |          | 
 backend_xid      | xid                      |           |          | 
 backend_xmin     | xid                      |           |          | 
 query            | text                     |           |          | 
 backend_type     | text         

There is no column which identifies a blocking session but there are other interesting columns:

postgres=# select datname,pid,usename,wait_event_type,wait_event,state,query from pg_stat_activity where backend_type = 'client backend' and pid != pg_backend_pid();
 datname  | pid  | usename  | wait_event_type | wait_event |        state        |               query                
----------+------+----------+-----------------+------------+---------------------+------------------------------------
 postgres | 2572 | postgres | Client          | ClientRead | idle in transaction | alter table t1 add column t2 text;
 postgres | 2992 | postgres | Lock            | relation   | active              | insert into t1 (a) values (1);
(2 rows)

This shows only client connections (excluding all the backend connections) and does not show the current session. In this case it is easy to identify the session which is blocking because we only have two sessions. When you have hundreds of sessions it becomes more tricky to identify the session which is blocking by looking at pg_stat_activity.

When you want to know which locks are currently being held/granted in PostgreSQL you can query pg_locks:

postgres=# d pg_locks
                   View "pg_catalog.pg_locks"
       Column       |   Type   | Collation | Nullable | Default 
--------------------+----------+-----------+----------+---------
 locktype           | text     |           |          | 
 database           | oid      |           |          | 
 relation           | oid      |           |          | 
 page               | integer  |           |          | 
 tuple              | smallint |           |          | 
 virtualxid         | text     |           |          | 
 transactionid      | xid      |           |          | 
 classid            | oid      |           |          | 
 objid              | oid      |           |          | 
 objsubid           | smallint |           |          | 
 virtualtransaction | text     |           |          | 
 pid                | integer  |           |          | 
 mode               | text     |           |          | 
 granted            | boolean  |           |          | 
 fastpath           | boolean  |           |          | 

What can we see here:

postgres=# select locktype,database,relation,pid,mode,granted from pg_locks where pid != pg_backend_pid();
   locktype    | database | relation | pid  |        mode         | granted 
---------------+----------+----------+------+---------------------+---------
 virtualxid    |          |          | 2992 | ExclusiveLock       | t
 virtualxid    |          |          | 2572 | ExclusiveLock       | t
 relation      |    13212 |    24576 | 2992 | RowExclusiveLock    | f
 relation      |    13212 |    24581 | 2572 | AccessExclusiveLock | t
 transactionid |          |          | 2572 | ExclusiveLock       | t
 relation      |    13212 |    24579 | 2572 | ShareLock           | t
 relation      |    13212 |    24576 | 2572 | AccessExclusiveLock | t
(7 rows)

There is one lock for session 2992 which is not granted and that is the session which currently is trying to insert a row in the table (see above). We can get more information by joining pg_locks with pg_database and pg_class taking the pids from above:

select b.locktype,d.datname,c.relname,b.pid,b.mode 
  from pg_locks b 
     , pg_database d
     , pg_class c
 where b.pid in (2572,2992)
   and b.database = d.oid
   and b.relation = c.oid;

 locktype | datname  | relname | pid  |        mode         
----------+----------+---------+------+---------------------
 relation | postgres | t1      | 2992 | RowExclusiveLock
 relation | postgres | t1      | 2572 | AccessExclusiveLock
(2 rows)

Does that help us beside that we now know that both sessions want to do some stuff against the t1 table? Not really. So how can we then identify a blocking session? Easy, use the pg_blocking_pids system information function passing in the session which is blocked:

postgres=# select pg_blocking_pids(2992);
 pg_blocking_pids 
------------------
 {2572}
(1 row)

This gives you a list of sessions which are blocking. Can we kill it? Yes, of course, PostgreSQL comes with a rich set of system administration functions:

postgres=# select pg_terminate_backend(2572);
 pg_terminate_backend 
----------------------
 t

… and the insert succeeds. Hope this helps …

PS: There is a great page on the PostgreSQL Wiki about locks.