Browse Source
User-friendly output from the: - pg_stat_replication - pg_stat_progress_vacuum - pg_stat_progress_create_indexpull/12/head
3 changed files with 46 additions and 0 deletions
@ -0,0 +1,15 @@
@@ -0,0 +1,15 @@
|
||||
-- List active indexing sessions and their progress |
||||
SELECT p.pid |
||||
, date_trunc('second',now() - a.xact_start) AS dur |
||||
, coalesce(wait_event_type ||'.'|| wait_event, 'f') AS wait |
||||
, p.datname |
||||
, p.index_relid::regclass AS ind |
||||
, round(pg_total_relation_size(index_relid)/1024.0/1024) AS ind_ttl_mb |
||||
, p.command, p.phase |
||||
, CASE WHEN lockers_total > lockers_done AND p.phase ~ 'waiting' |
||||
THEN format('%s ( %s / %s )', current_locker_pid, lockers_done, lockers_total) END AS waiting |
||||
, CASE WHEN blocks_total > 0 THEN format('%s%% of %s', round(blocks_done::numeric / blocks_total * 100), blocks_total) END AS blocks |
||||
, CASE WHEN tuples_total > 0 THEN format('%s%% of %s', round(tuples_done::numeric / tuples_total * 100), tuples_total) END AS tuples |
||||
, CASE WHEN partitions_total > 0 THEN format('%s%% of %s', round(partitions_done::numeric / partitions_total * 100), partitions_total) END AS partitions |
||||
FROM pg_stat_progress_create_index p JOIN pg_stat_activity a using (pid) ORDER BY dur DESC; |
||||
|
||||
@ -0,0 +1,13 @@
@@ -0,0 +1,13 @@
|
||||
-- List active replication connections |
||||
SELECT client_addr AS client |
||||
, usename AS user |
||||
, application_name AS name |
||||
, state, sync_state AS mode, backend_xmin |
||||
, (pg_wal_lsn_diff(CASE WHEN pg_is_in_recovery() THEN pg_last_wal_replay_lsn() ELSE pg_current_wal_lsn() END,sent_lsn)/1024.0/1024)::numeric(10,1) AS pending_mb |
||||
, (pg_wal_lsn_diff(sent_lsn,write_lsn)/1024.0/1024)::numeric(10,1) AS write_mb |
||||
, (pg_wal_lsn_diff(write_lsn,flush_lsn)/1024.0/1024)::numeric(10,1) AS flush_mb |
||||
, (pg_wal_lsn_diff(flush_lsn,replay_lsn)/1024.0/1024)::numeric(10,1) AS replay_mb |
||||
, ((pg_wal_lsn_diff(CASE WHEN pg_is_in_recovery() THEN sent_lsn ELSE pg_current_wal_lsn() END,replay_lsn))::bigint/1024.0/1024)::numeric(10,1) AS total_mb |
||||
, replay_lag::interval(0) replay_lag |
||||
FROM pg_stat_replication; |
||||
|
||||
@ -0,0 +1,18 @@
@@ -0,0 +1,18 @@
|
||||
-- List active vacuums and their progress |
||||
SELECT p.pid |
||||
, date_trunc('second',now() - a.xact_start) AS dur |
||||
, coalesce(wait_event_type ||'.'|| wait_event, 'f') AS wait |
||||
, CASE WHEN a.query ~ 'to prevent wraparound' THEN 'freeze' ELSE 'regular' END AS mode |
||||
, (SELECT datname FROM pg_database WHERE oid = p.datid) AS dat |
||||
, p.relid::regclass AS tab |
||||
, p.phase |
||||
, round((p.heap_blks_total * current_setting('block_size')::int)/1024.0/1024) AS tab_mb |
||||
, round(pg_total_relation_size(relid)/1024.0/1024) AS ttl_mb |
||||
, round((p.heap_blks_scanned * current_setting('block_size')::int)/1024.0/1024) AS scan_mb |
||||
, round((p.heap_blks_vacuumed * current_setting('block_size')::int)/1024.0/1024) AS vac_mb |
||||
, (100 * p.heap_blks_scanned / nullif(p.heap_blks_total,0)) AS scan_pct |
||||
, (100 * p.heap_blks_vacuumed / nullif(p.heap_blks_total,0)) AS vac_pct |
||||
, p.index_vacuum_count AS ind_vac_cnt |
||||
, round(p.num_dead_tuples * 100.0 / nullif(p.max_dead_tuples, 0),1) AS dead_pct |
||||
FROM pg_stat_progress_vacuum p JOIN pg_stat_activity a using (pid) ORDER BY dur DESC; |
||||
|
||||
Loading…
Reference in new issue