f 用SQL 查詢Postgres 執行時間超過10分鐘 Query 中處於wait 狀態TOP 1 ~ 迪貝之家

Pages

用SQL 查詢Postgres 執行時間超過10分鐘 Query 中處於wait 狀態TOP 1

SET client_min_messages TO NOTICE;
do $$
declare
  version_check    boolean;
  r1               record;
  r2               record;
  outputinfo       varchar(80) :='N' ;
  waiting_threshold interval := '10 min';

begin

   SELECT substring((string_to_array(version(), ' '))[2] for 3) > '9.1' into version_check;
    if version_check
    then
      for r1 in  SELECT date_trunc('second',current_timestamp - query_start) AS runtime,
                    datname, usename,substring(query for 20) query,pid
FROM pg_stat_activity
WHERE state = 'active'
AND current_timestamp - query_start >=  waiting_threshold
-- and query !~* '(vacuum|analyze)'
                        and waiting
ORDER BY 1 DESC limit 1
    loop
  outputinfo := '';
  outputinfo := outputinfo || cast(r1.pid as varchar) ||'/'||cast(r1.runtime as varchar)||'/'||r1.query ;
              for r2 in 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,
                               substring(blocking_activity.query for 20)  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
                               AND  blocked_activity.pid = r1.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

        loop
          outputinfo := outputinfo ||':' ||cast(r2.blocking_pid as varchar)||'/'||r2.current_statement_in_blocking_process;
    end loop;
        end loop;
    else
      for r1 in  SELECT date_trunc('second',current_timestamp - query_start) AS runtime,
                    datname, usename, substring(current_query for 20) query,waiting,procpid
FROM pg_stat_activity
where current_timestamp - query_start >=  waiting_threshold
-- and query !~* '(vacuum|analyze)'
                        and waiting
ORDER BY 1 DESC limit 1
   loop
         outputinfo := '';
         outputinfo := outputinfo || cast(r1.procpid as varchar) ||'/'||cast(r1.runtime as varchar)||'/'||r1.query ;
              for r2 in 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.current_query    AS blocked_statement,
                               substring(blocking_activity.current_query for 20)  AS current_statement_in_blocking_process
                               FROM  pg_catalog.pg_locks         blocked_locks
                               JOIN pg_catalog.pg_stat_activity blocked_activity
         ON blocked_activity.procpid = blocked_locks.pid
   and  blocked_activity.procpid = r1.procpid
                               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.procpid = blocking_locks.pid
                               WHERE NOT blocked_locks.GRANTED

        loop
          outputinfo := outputinfo ||':' ||cast(r2.blocking_pid as varchar)||'/'||r2.current_statement_in_blocking_process;
    end loop;

       end loop;
    end if;
raise notice '%', outputinfo;
end$$;