PostgreSQL LOCK TREE 조회 스크립트
WITH RECURSIVE lt AS (
SELECT p.datname
, p.usename
, p.pid
, pg_blocking_pids(p.pid) AS blocking_by
, p.application_name
, p.wait_event_type
, p.state
, p.query_start
, p.query
, (
SELECT array_agg(( SELECT relname
FROM pg_class pc
WHERE pc.oid = pl.relation ))
FROM pg_locks pl
WHERE pl.pid = p.pid
AND locktype = 'relation'
) AS relation
, 0 AS level
, row_number() over() AS rn
FROM pg_stat_activity p
WHERE cardinality(pg_blocking_pids(p.pid))= 0
UNION
SELECT p.datname
, p.usename
, p.pid
, pg_blocking_pids(p.pid) AS blocking_by
, p.application_name
, p.wait_event_type
, p.state
, p.query_start
, p.query
, ( SELECT array_agg(( SELECT relname FROM pg_class pc WHERE pc.oid = pl.relation ))
FROM pg_locks pl
WHERE pl.pid = p.pid
AND locktype = 'relation'
) AS relation
, level + 1 as level
, lt.rn
FROM pg_stat_activity p
INNER JOIN lt ON lt.pid = any(pg_blocking_pids(p.pid))
)
SELECT p.datname
, p.usename
, p.pid
, p.blocking_by
, p.application_name
, p.wait_event_type
, p.state
, p.relation
, now() - p.query_start AS elapsed_time
, p.query
FROM (
SELECT lt.rn
, lt.level
, lt.datname
, lt.usename
, lt.pid
, lt.blocking_by
, lt.application_name
, lt.wait_event_type
, lt.state
, lt.relation
, lt.query_start
, lt.query
, count( rn ) over( PARTITION BY rn ) AS blocked_cnt
FROM lt
) AS p
WHERE p.blocked_cnt > 1
ORDER by p.rn, p.level, p.blocking_by
;
1) pg_cancel_backend(pid) -- current query kill and not disconnect
2) pg_terminate_backend(pid) -- connection disconnect.
3) kill -9 process
'1. IT Story > Scripts' 카테고리의 다른 글
Oracle 락 홀더(Locks Holders) 조회 스크립트 (0) | 2019.03.12 |
---|---|
PostgreSQL 인덱스 관리 스크립트 (0) | 2019.03.10 |
PostgreSQL 테이블 상세 정보 조회 스크립트 (0) | 2019.03.09 |
PostgreSQL 테이블별 사이즈 확인 스크립트 (0) | 2019.03.08 |
오라클 RAC Estd.interconnect Traffic 관리 스크립트 (0) | 2019.03.06 |
오라클 물리적 IO 관리 스크립트 (0) | 2019.03.05 |
오라클 인덱스 상세 조회 스크립트 (0) | 2019.03.04 |
Oracle 수행 시간 기준 SQL 추출 스크립트 (0) | 2019.03.03 |