[ELMA3] Поиск и прерывание блокирующих запросов в PostgreSQL
Поиск блокирующего запроса.
- Выполняем запрос:
SELECT * FROM pg_stat_activity
Нас интересуют колонки waiting, state, query, xact_start, datname, pid (могут называться по-разному в разных версиях PgSQL)
Если state интересующего нас запроса = active, а waiting = ‘t’, скорее всего запрос заблокирован.
- Для поиска блокирующего запроса выполняем
SELECT blocked_locks.pid AS blocked_pid,
blocked_activity.usename AS blocked_user,
blocking_locks.pid AS blocking_pid,
blocking_activity.usename AS blocking_user,
blocked_activity.query AS blocked_statement,
blocking_activity.query AS current_statement_in_blocking_process
FROM pg_catalog.pg_locks blocked_locks
JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid
JOIN pg_catalog.pg_locks blocking_locks
ON blocking_locks.locktype = blocked_locks.locktype
AND blocking_locks.DATABASE IS NOT DISTINCT FROM blocked_locks.DATABASE
AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation
AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page
AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple
AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid
AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid
AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid
AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid
AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid
AND blocking_locks.pid != blocked_locks.pid
JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid
WHERE NOT blocked_locks.GRANTED;
Если в колонке blocked_statement есть интересующий нас запрос, смотрим на blocking_pid.
- Сверяем по pid запрос из результатов п.1. Если то что там выполняется можно спокойно прервать, то прерываем.
Прерывание блокирующего запроса
- Мягкое прерывание
SELECT pg_cancel_backend(PID);
- Жесткое прерывание
SELECT pg_terminate_backend(PID);