Files
Server.Config-Deploy-Data/home-rc/dot-files/.psqlrc
2024-10-08 17:58:44 +09:00

98 lines
26 KiB
Plaintext

\set HISTFILE ~/.psql_history-:DBNAME
--\set HISTSIZE 5000
--\set FETCH_COUNT 1000
\set HISTCONTROL ignoredups
\set COMP_KEYWORD_CASE upper
\set ON_ERROR_STOP on
\set ON_ERROR_ROLLBACK interactive
\set VERBOSITY verbose
\set version 'SELECT version();'
\set extensions 'select * from pg_available_extensions;'
\timing
-- alt char ¤
--\set null NULL
--\pset null 'Ø'
\pset null '∅'
-- set line type ascii or unicde
--\pset linestyle unicode
\pset linestyle ascii
-- from 0-2--
\pset border 1
-- turn off pager (more like)
--\pset pager off
-- wrap long lines
\set format wrapped
\setenv PAGER 'pspg -bX --no-mouse'
-- PROMPT
-- [ USER (%n) @ DATABASE (%/) % HOST(full) (%M) : PORT (%>) ] { :ENCODING: } [transaction %x (4)] PROMPT %R SUPERUSER %#
-- * one line color
--\set PROMPT1 '[%[%033[1;32m%]%n%[%033[0m%]@%[%033[1;35m%]%/%[%033[0m%]%%%[%033[1;31m%]%M%[%033[0m%]:%[%033[1;33m%]%>%[%033[0m%]]{%[%033[0;36m%]%:ENCODING:%[%033[0m%]}%x%x%x%R%# '
--\set PROMPT2 '(%[%033[1;35m%]%/%[%033[0m%])%x%x%x%[%033[1;36m%]%R%[%033[0m%]%# '
-- * two line color
\set PROMPT1 '[%[%033[1;32m%]%n%[%033[0m%]@%[%033[1;35m%]%/%[%033[0m%]%%%[%033[1;31m%]%M%[%033[0m%]:%[%033[1;33m%]%>%[%033[0m%]]{%[%033[0;36m%]%:ENCODING:%[%033[0m%]}\n%x%x%x%[%033[1;34m%]%R%[%033[0m%]%# '
\set PROMPT2 '%x%x%x%[%033[1;36m%]%R%[%033[0m%]%# '
-- * one line no color
--\set PROMPT1 '[%n@%/%%%M:%>]{%:ENCODING:}%x%x%x%R%# '
-- switch linestyle
\set la '\\pset linestyle ascii'
\set lu '\\pset linestyle unicode'
-- switch pagers
\set x '\\setenv PAGER less'
\set xx '\\setenv PAGER \'pspg -bX --no-mouse\''
-- like tsize below, but without converting data into bytes
\set rtsize '(select table_schema, table_name, pg_relation_size( quote_ident( table_schema ) || \'.\' || quote_ident( table_name ) ) as size, pg_indexes_size( quote_ident( table_schema ) || \'.\' || quote_ident( table_name ) ) as index_size, pg_total_relation_size( quote_ident( table_schema ) || \'.\' || quote_ident( table_name ) ) as total_size from information_schema.tables where table_type = \'BASE TABLE\' and table_schema not in (\'information_schema\', \'pg_catalog\') order by pg_relation_size( quote_ident( table_schema ) || \'.\' || quote_ident( table_name ) ) desc, table_schema, table_name)'
-- compact size output for tables + indexes
\set tsize '(select table_schema, table_name, pg_size_pretty(size) as size, pg_size_pretty(index_size) as index_size, pg_size_pretty(total_size) as total_size from (:rtsize) x order by x.size desc, x.total_size desc, table_schema, table_name)'
-- extended size output for tables and indexes
\set etsize 'SELECT pgn.nspname, relname, pg_size_pretty(relpages::bigint * 8 * 1024) AS size, CASE WHEN relkind = \'t\' THEN (SELECT pgd.relname FROM pg_class pgd WHERE pgd.reltoastrelid = pg.oid) WHEN nspname = \'pg_toast\' AND relkind = \'i\' THEN (SELECT pgt.relname FROM pg_class pgt WHERE SUBSTRING(pgt.relname FROM 10) = REPLACE(SUBSTRING(pg.relname FROM 10), \'_index\', \'\')) ELSE (SELECT pgc.relname FROM pg_class pgc WHERE pg.reltoastrelid = pgc.oid) END::varchar AS refrelname, CASE WHEN nspname = \'pg_toast\' AND relkind = \'i\' THEN (SELECT pgts.relname FROM pg_class pgts WHERE pgts.reltoastrelid = (SELECT pgt.oid FROM pg_class pgt WHERE SUBSTRING(pgt.relname FROM 10) = REPLACE(SUBSTRING(pg.relname FROM 10), \'_index\', \'\'))) END AS relidxrefrelname, relfilenode, relkind, reltuples::bigint, relpages FROM pg_class pg, pg_namespace pgn WHERE pg.relnamespace = pgn.oid AND pgn.nspname NOT IN (\'information_schema\', \'pg_catalog\') ORDER BY relpages DESC'
-- get useless indexes
\set trashindexes '( select s.schemaname as sch, s.relname as rel, s.indexrelname as idx, s.idx_scan as scans, pg_size_pretty(pg_relation_size(s.relid)) as ts, pg_size_pretty(pg_relation_size(s.indexrelid)) as "is" from pg_stat_user_indexes s join pg_index i on i.indexrelid=s.indexrelid left join pg_constraint c on i.indrelid=c.conrelid and array_to_string(i.indkey, '' '') = array_to_string(c.conkey, '' '') where i.indisunique is false and pg_relation_size(s.relid) > 1000000 and s.idx_scan < 100000 and c.confrelid is null order by s.idx_scan asc, pg_relation_size(s.indexrelid) desc, pg_relation_size(s.relid) desc )'
-- get useless indexes (full read)
\set trashindexesall '( select s.schemaname as sch, s.relname as rel, s.indexrelname as idx, s.idx_scan as scans, pg_size_pretty(pg_relation_size(s.relid)) as ts, pg_size_pretty(pg_relation_size(s.indexrelid)) as "is", c.confrelid, c.conkey from pg_stat_user_indexes s join pg_index i on i.indexrelid=s.indexrelid left join pg_constraint c on i.indrelid=c.conrelid and array_to_string(i.indkey, '' '') = array_to_string(c.conkey, '' '') where i.indisunique is false and pg_relation_size(s.relid) > 1000000 and s.idx_scan < 100000 order by s.idx_scan asc, pg_relation_size(s.indexrelid) desc, pg_relation_size(s.relid) desc )'
-- get all indexes for a relation ('table')
\set getindexes 'select s.schemaname as sch, s.relname as rel, s.indexrelname as idx, s.idx_scan as scans, pg_size_pretty(pg_relation_size(s.relid)) as ts, pg_size_pretty(pg_relation_size(s.indexrelid)) as "is", c.confrelid, c.conkey from pg_stat_user_indexes s join pg_index i on i.indexrelid=s.indexrelid left join pg_constraint c on i.indrelid=c.conrelid and array_to_string(i.indkey, '' '') = array_to_string(c.conkey, '' '') where s.relname = '
-- possible missing indexes
\set missingindexes '( select src_table, dst_table, fk_name, pg_size_pretty(s_size) as s_size, pg_size_pretty(d_size) as d_size, d from ( select distinct on (1,2,3,4,5) textin(regclassout(c.conrelid)) as src_table, textin(regclassout(c.confrelid)) as dst_table, c.conname as fk_name, pg_relation_size(c.conrelid) as s_size, pg_relation_size(c.confrelid) as d_size, array_upper(di.indkey::int[], 1) + 1 - array_upper(c.conkey::int[], 1) as d from pg_constraint c left join pg_index di on di.indrelid = c.conrelid and array_to_string(di.indkey, '' '') ~ (''^'' || array_to_string(c.conkey, '' '') || ''( |$)'') join pg_stat_user_tables st on st.relid = c.conrelid where c.contype = ''f'' order by 1,2,3,4,5,6 asc) mfk where mfk.d is distinct from 0 and mfk.s_size > 1000000 order by mfk.s_size desc, mfk.d desc )'
-- overal percentage of index hits for a table
\set percentindexes 'SELECT relname, 100 * idx_scan / (seq_scan + idx_scan) percent_of_times_index_used, n_live_tup rows_in_table FROM pg_stat_user_tables ORDER BY n_live_tup DESC'
-- current running queries
\set running 'SELECT datname, client_addr, pid, now() - query_start AS runtime, state, wait_event_type, wait_event, query FROM pg_stat_activity WHERE query <> ''<IDLE>'' AND state <> ''idle'' ORDER BY 1, 5, 4 DESC;'
\set runningidle 'SELECT datname, client_addr, pid, now() - query_start AS runtime, state, wait_event_type, wait_event, query FROM pg_stat_activity WHERE query <> ''<IDLE>'' ORDER BY 1, 5, 4 DESC;'
\set runningold 'SELECT datname, client_addr, pid, now() - query_start AS runtime, state, case when waiting then ''WAIT'' else '''' end AS wait, query FROM pg_stat_activity WHERE query <> ''<IDLE>'' AND state <> ''idle'' ORDER BY 1, 5, 4 DESC;'
\set runningidleold 'SELECT datname, client_addr, pid, now() - query_start AS runtime, state, case when waiting then ''WAIT'' else '''' end AS wait, query FROM pg_stat_activity WHERE query <> ''<IDLE>'' ORDER BY 1, 5, 4 DESC;'
-- misses primary key
\set missingpk 'SELECT table_catalog, table_schema, table_name FROM information_schema.tables WHERE (table_catalog, table_schema, table_name) NOT IN (SELECT table_catalog, table_schema, table_name FROM information_schema.table_constraints WHERE constraint_type = ''PRIMARY KEY'') AND table_schema NOT IN (''information_schema'', ''pg_catalog'')'
-- chance of hitting the cache
\set cachehit 'SELECT sum(heap_blks_read) as heap_read, sum(heap_blks_hit) as heap_hit, (sum(heap_blks_hit) - sum(heap_blks_read)) / sum(heap_blks_hit) as ratio;'
-- chance of hitting the index during a read
\set indexhit 'SELECT sum(idx_blks_read) as idx_read, sum(idx_blks_hit) as idx_hit, (sum(idx_blks_hit) - sum(idx_blks_read)) / sum(idx_blks_hit) as ratio FROM pg_statio_user_indexes;'
-- show slow queries
\set show_slow_queries 'SELECT (total_time / 1000 / 60) as total_minutes, (total_time/calls) as average_time, query FROM pg_stat_statements ORDER BY 1 DESC LIMIT 100;'
-- show current search path
\set shsp 'SHOW search_path;'
-- set new search path
\set setsp 'SET search_path TO'
-- INDEX BLOAT read
\set indexbloat 'WITH btree_index_atts AS ( SELECT nspname, relname, reltuples, relpages, indrelid, relam, regexp_split_to_table(indkey::text, '' '')::smallint AS attnum, indexrelid as index_oid FROM pg_index JOIN pg_class ON pg_class.oid=pg_index.indexrelid JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace JOIN pg_am ON pg_class.relam = pg_am.oid WHERE pg_am.amname = ''btree''), index_item_sizes AS ( SELECT i.nspname, i.relname, i.reltuples, i.relpages, i.relam, (quote_ident(s.schemaname) || ''.'' || quote_ident(s.tablename))::regclass AS starelid, a.attrelid AS table_oid, index_oid, current_setting(''block_size'')::numeric AS bs, CASE WHEN version() ~ ''mingw32'' OR version() ~ ''64-bit'' THEN 8 ELSE 4 END AS maxalign, 24 AS pagehdr, CASE WHEN max(coalesce(s.null_frac,0)) = 0 THEN 2 ELSE 6 END AS index_tuple_hdr, sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 2048) ) AS nulldatawidth FROM pg_attribute AS a JOIN pg_stats AS s ON (quote_ident(s.schemaname) || ''.'' || quote_ident(s.tablename))::regclass=a.attrelid AND s.attname = a.attname JOIN btree_index_atts AS i ON i.indrelid = a.attrelid AND a.attnum = i.attnum WHERE a.attnum > 0 GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9), index_aligned AS ( SELECT maxalign, bs, nspname, relname AS index_name, reltuples, relpages, relam, table_oid, index_oid, ( 2 + maxalign - CASE WHEN 2%maxalign = 0 THEN maxalign ELSE 2%maxalign END + nulldatawidth + maxalign - CASE WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign ELSE nulldatawidth::integer%maxalign END)::numeric AS nulldatahdrwidth, pagehdr FROM index_item_sizes AS s1), otta_calc AS ( SELECT bs, nspname, table_oid, index_oid, index_name, relpages, coalesce( ceil((reltuples*(4+nulldatahdrwidth))/(bs-pagehdr::float)) + CASE WHEN am.amname IN (''hash'',''btree'') THEN 1 ELSE 0 END , 0 ) AS otta FROM index_aligned AS s2 LEFT JOIN pg_am am ON s2.relam = am.oid), raw_bloat AS ( SELECT current_database() as dbname, nspname, c.relname AS table_name, index_name, bs*(sub.relpages)::bigint AS totalbytes, CASE WHEN sub.relpages <= otta THEN 0 ELSE bs*(sub.relpages-otta)::bigint END AS wastedbytes, CASE WHEN sub.relpages <= otta THEN 0 ELSE bs*(sub.relpages-otta)::bigint * 100 / (bs*(sub.relpages)::bigint) END AS realbloat, pg_relation_size(sub.table_oid) as table_bytes, stat.idx_scan as index_scans FROM otta_calc AS sub JOIN pg_class AS c ON c.oid=sub.table_oid JOIN pg_stat_user_indexes AS stat ON sub.index_oid = stat.indexrelid) SELECT dbname as database_name, nspname as schema_name, table_name, index_name, round(realbloat, 1) as bloat_pct, wastedbytes as bloat_bytes, pg_size_pretty(wastedbytes) as bloat_size, totalbytes as index_bytes, pg_size_pretty(totalbytes) as index_size, table_bytes, pg_size_pretty(table_bytes) as table_size, index_scans FROM raw_bloat WHERE ( ( realbloat > 50 and wastedbytes > 50000000 ) or wastedbytes > 50000000 ) ORDER BY wastedbytes DESC;'
-- never used index check
\set indexusage 'WITH table_scans as (SELECT relid, tables.idx_scan + tables.seq_scan as all_scans, ( tables.n_tup_ins + tables.n_tup_upd + tables.n_tup_del ) as writes, pg_relation_size(relid) as table_size FROM pg_stat_user_tables as tables), all_writes as (SELECT sum(writes) as total_writes FROM table_scans), indexes as (SELECT idx_stat.relid, idx_stat.indexrelid, idx_stat.schemaname, idx_stat.relname as tablename, idx_stat.indexrelname as indexname, idx_stat.idx_scan, pg_relation_size(idx_stat.indexrelid) as index_bytes, indexdef ~* ''USING btree'' AS idx_is_btree FROM pg_stat_user_indexes as idx_stat JOIN pg_index USING (indexrelid) JOIN pg_indexes as indexes ON idx_stat.schemaname = indexes.schemaname AND idx_stat.relname = indexes.tablename AND idx_stat.indexrelname = indexes.indexname WHERE pg_index.indisunique = FALSE), index_ratios AS (SELECT schemaname, tablename, indexname, idx_scan, all_scans, round(( CASE WHEN all_scans = 0 THEN 0.0::NUMERIC ELSE idx_scan::NUMERIC/all_scans * 100 END),2) as index_scan_pct, writes, round((CASE WHEN writes = 0 THEN idx_scan::NUMERIC ELSE idx_scan::NUMERIC/writes END),2) as scans_per_write, pg_size_pretty(index_bytes) as index_size, pg_size_pretty(table_size) as table_size, idx_is_btree, index_bytes FROM indexes JOIN table_scans USING (relid)), index_groups AS (SELECT ''Never Used Indexes'' as reason, *, 1 as grp FROM index_ratios WHERE idx_scan = 0 and idx_is_btree UNION ALL SELECT ''Low Scans, High Writes'' as reason, *, 2 as grp FROM index_ratios WHERE scans_per_write <= 1 and index_scan_pct < 10 and idx_scan > 0 and writes > 100 and idx_is_btree UNION ALL SELECT ''Seldom Used Large Indexes'' as reason, *, 3 as grp FROM index_ratios WHERE index_scan_pct < 5 and scans_per_write > 1 and idx_scan > 0 and idx_is_btree and index_bytes > 100000000 UNION ALL SELECT ''High-Write Large Non-Btree'' as reason, index_ratios.*, 4 as grp FROM index_ratios, all_writes WHERE ( writes::NUMERIC / ( total_writes + 1 ) ) > 0.02 AND NOT idx_is_btree AND index_bytes > 100000000 ORDER BY grp, index_bytes DESC ) SELECT reason, schemaname, tablename, indexname, index_scan_pct, scans_per_write, index_size, table_size FROM index_groups;'
-- foreign key count for all tables in database
\set foreignkeycount 'SELECT t.oid::regclass::text AS table_name, count(1) AS total FROM pg_constraint c JOIN pg_class t ON (t.oid = c.confrelid) GROUP BY table_name ORDER BY total DESC;'
-- ALSO from view 'bloat': SELECT * from bloat
-- bloat for tables and indexes
\set tablebloat 'SELECT sml.schemaname, sml.tablename, sml.reltuples::bigint AS reltuples, sml.relpages::bigint AS relpages, sml.otta, round( CASE WHEN sml.otta = 0::double precision THEN 0.0 ELSE sml.relpages::numeric / sml.otta::numeric END, 1) AS tbloat, sml.relpages::bigint::double precision - sml.otta AS wastedpages, sml.bs * (sml.relpages::double precision - sml.otta)::bigint::numeric AS wastedbytes, pg_size_pretty((sml.bs::double precision * (sml.relpages::double precision - sml.otta))::bigint) AS wastedsize, sml.iname, sml.ituples::bigint AS ituples, sml.ipages::bigint AS ipages, sml.iotta, round( CASE WHEN sml.iotta = 0::double precision OR sml.ipages = 0 THEN 0.0 ELSE sml.ipages::numeric / sml.iotta::numeric END, 1) AS ibloat, CASE WHEN sml.ipages::double precision < sml.iotta THEN 0::double precision ELSE sml.ipages::bigint::double precision - sml.iotta END AS wastedipages, CASE WHEN sml.ipages::double precision < sml.iotta THEN 0::double precision ELSE sml.bs::double precision * (sml.ipages::double precision - sml.iotta) END AS wastedibytes, CASE WHEN sml.ipages::double precision < sml.iotta THEN pg_size_pretty(0::bigint) ELSE pg_size_pretty((sml.bs::double precision * (sml.ipages::double precision - sml.iotta))::bigint) END AS wastedisize FROM ( SELECT rs.schemaname, rs.tablename, cc.reltuples, cc.relpages, rs.bs, ceil(cc.reltuples * ((rs.datahdr + rs.ma::numeric - CASE WHEN (rs.datahdr % rs.ma::numeric) = 0::numeric THEN rs.ma::numeric ELSE rs.datahdr % rs.ma::numeric END)::double precision + rs.nullhdr2 + 4::double precision) / (rs.bs::double precision - 20::double precision)) AS otta, COALESCE(c2.relname, ''?''::name) AS iname, COALESCE(c2.reltuples, 0::real) AS ituples, COALESCE(c2.relpages, 0) AS ipages, COALESCE(ceil(c2.reltuples * (rs.datahdr - 12::numeric)::double precision / (rs.bs::double precision - 20::double precision)), 0::double precision) AS iotta FROM ( SELECT foo.ma, foo.bs, foo.schemaname, foo.tablename, (foo.datawidth + (foo.hdr + foo.ma - CASE WHEN (foo.hdr % foo.ma) = 0 THEN foo.ma ELSE foo.hdr % foo.ma END)::double precision)::numeric AS datahdr, foo.maxfracsum * (foo.nullhdr + foo.ma - CASE WHEN (foo.nullhdr % foo.ma::bigint) = 0 THEN foo.ma::bigint ELSE foo.nullhdr % foo.ma::bigint END)::double precision AS nullhdr2 FROM ( SELECT s.schemaname, s.tablename, constants.hdr, constants.ma, constants.bs, sum((1::double precision - s.null_frac) * s.avg_width::double precision) AS datawidth, max(s.null_frac) AS maxfracsum, constants.hdr + (( SELECT 1 + count(*) / 8 FROM pg_stats s2 WHERE s2.null_frac <> 0::double precision AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename)) AS nullhdr FROM pg_stats s, ( SELECT ( SELECT current_setting(''block_size''::text)::numeric AS current_setting) AS bs, CASE WHEN "substring"(foo_1.v, 12, 3) = ANY (ARRAY[''8.0''::text, ''8.1''::text, ''8.2''::text]) THEN 27 ELSE 23 END AS hdr, CASE WHEN foo_1.v ~ ''mingw32''::text THEN 8 ELSE 4 END AS ma FROM ( SELECT version() AS v) foo_1) constants GROUP BY s.schemaname, s.tablename, constants.hdr, constants.ma, constants.bs) foo) rs JOIN pg_class cc ON cc.relname = rs.tablename JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname LEFT JOIN pg_index i ON i.indrelid = cc.oid LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid) sml WHERE (sml.relpages::double precision - sml.otta) > 0::double precision OR (sml.ipages::double precision - sml.iotta) > 10::double precision ORDER BY sml.bs * (sml.relpages::double precision - sml.otta)::bigint::numeric DESC, CASE WHEN sml.ipages::double precision < sml.iotta THEN 0::double precision ELSE sml.bs::double precision * (sml.ipages::double precision - sml.iotta) END DESC;'
-- view locks
\set viewlockedquery 'SELECT COALESCE(blockingl.relation::regclass::text,blockingl.locktype) as locked_item, now() - blockeda.query_start AS waiting_duration, blockeda.pid AS blocked_pid, blockeda.query as blocked_query, blockedl.mode as blocked_mode, blockinga.pid AS blocking_pid, blockinga.query as blocking_query, blockingl.mode as blocking_mode FROM pg_catalog.pg_locks blockedl JOIN pg_stat_activity blockeda ON blockedl.pid = blockeda.pid JOIN pg_catalog.pg_locks blockingl ON( ( (blockingl.transactionid=blockedl.transactionid) OR (blockingl.relation=blockedl.relation AND blockingl.locktype=blockedl.locktype)) AND blockedl.pid != blockingl.pid) JOIN pg_stat_activity blockinga ON blockingl.pid = blockinga.pid AND blockinga.datid = blockeda.datid WHERE NOT blockedl.granted AND blockinga.datname = current_database();'
\set viewlocks 'select (SELECT datname FROM pg_stat_database WHERE datid = database) AS database, pid, locktype, relation::regclass AS relation, mode, virtualxid AS vtid, transactionid AS tid, classid, objid, objsubid, virtualtransaction AS vtrans, granted, fastpath FROM pg_locks ORDER BY pid;'
-- tables that need vacuum
\set vacuumneed 'WITH table_opts AS ( SELECT c.oid, c.relname, c.relfrozenxid, c.relminmxid, n.nspname, array_to_string(c.reloptions, '''') AS relopts FROM pg_class c INNER JOIN pg_namespace n ON c.relnamespace = n.oid WHERE c.relkind IN (''r'', ''t'') AND n.nspname NOT IN (''pg_catalog'', ''information_schema'') AND n.nspname !~ ''^pg_temp''), vacuum_settings AS ( SELECT oid, relname, nspname, relfrozenxid, relminmxid, CASE WHEN relopts LIKE ''%autovacuum_vacuum_threshold%'' THEN regexp_replace(relopts, ''.*autovacuum_vacuum_threshold=([0-9.]+).*'', E''\\1'')::integer ELSE current_setting(''autovacuum_vacuum_threshold'')::integer END AS autovacuum_vacuum_threshold, CASE WHEN relopts LIKE ''%autovacuum_vacuum_scale_factor%'' THEN regexp_replace(relopts, ''.*autovacuum_vacuum_scale_factor=([0-9.]+).*'', E''\\1'')::real ELSE current_setting(''autovacuum_vacuum_scale_factor'')::real END AS autovacuum_vacuum_scale_factor, CASE WHEN relopts LIKE ''%autovacuum_analyze_threshold%'' THEN regexp_replace(relopts, ''.*autovacuum_analyze_threshold=([0-9.]+).*'', E''\\1'')::integer ELSE current_setting(''autovacuum_analyze_threshold'')::integer END AS autovacuum_analyze_threshold, CASE WHEN relopts LIKE ''%autovacuum_analyze_scale_factor%'' THEN regexp_replace(relopts, ''.*autovacuum_analyze_scale_factor=([0-9.]+).*'', E''\\1'')::real ELSE current_setting(''autovacuum_analyze_scale_factor'')::real END AS autovacuum_analyze_scale_factor, CASE WHEN relopts LIKE ''%autovacuum_freeze_max_age%'' THEN least(regexp_replace(relopts, ''.*autovacuum_freeze_max_age=([0-9.]+).*'', E''\\1'')::bigint,current_setting(''autovacuum_freeze_max_age'')::bigint) ELSE current_setting(''autovacuum_freeze_max_age'')::bigint END AS autovacuum_freeze_max_age, CASE WHEN relopts LIKE ''%autovacuum_multixact_freeze_max_age%'' THEN least(regexp_replace(relopts, ''.*autovacuum_multixact_freeze_max_age=([0-9.]+).*'', E''\\1'')::bigint,current_setting(''autovacuum_multixact_freeze_max_age'')::bigint) ELSE current_setting(''autovacuum_multixact_freeze_max_age'')::bigint END AS autovacuum_multixact_freeze_max_age FROM table_opts) SELECT s.schemaname ||''.''|| s.relname, CASE WHEN v.autovacuum_vacuum_threshold + (v.autovacuum_vacuum_scale_factor::numeric * c.reltuples) < s.n_dead_tup THEN true ELSE false END AS need_vacuum, CASE WHEN v.autovacuum_analyze_threshold + (v.autovacuum_analyze_scale_factor::numeric * c.reltuples) < s.n_mod_since_analyze THEN true ELSE false END AS need_analyze, CASE WHEN (age(v.relfrozenxid)::bigint > v.autovacuum_freeze_max_age) OR (mxid_age(v.relminmxid)::bigint > v.autovacuum_multixact_freeze_max_age) THEN true ELSE false END AS need_wraparound FROM pg_stat_user_tables s INNER JOIN pg_class c ON s.relid = c.oid INNER JOIN vacuum_settings v ON c.oid = v.oid WHERE (v.autovacuum_vacuum_threshold + (v.autovacuum_vacuum_scale_factor::numeric * c.reltuples) < s.n_dead_tup) OR (v.autovacuum_analyze_threshold + (v.autovacuum_analyze_scale_factor::numeric * c.reltuples) < s.n_mod_since_analyze) OR (age(v.relfrozenxid)::bigint > v.autovacuum_freeze_max_age) OR (mxid_age(v.relminmxid)::bigint > v.autovacuum_multixact_freeze_max_age)'
\set tablebloatscan 'WITH constants AS (SELECT current_setting(''block_size'')::numeric AS bs, 23 AS hdr, 8 AS ma), no_stats AS (SELECT table_schema, table_name, n_live_tup::numeric as est_rows, pg_table_size(relid)::numeric as table_size FROM information_schema.columns JOIN pg_stat_user_tables as psut ON table_schema = psut.schemaname AND table_name = psut.relname LEFT OUTER JOIN pg_stats ON table_schema = pg_stats.schemaname AND table_name = pg_stats.tablename AND column_name = attname WHERE attname IS NULL AND table_schema NOT IN (''pg_catalog'', ''information_schema'') GROUP BY table_schema, table_name, relid, n_live_tup), null_headers AS (SELECT hdr+1+(sum(case when null_frac <> 0 THEN 1 else 0 END)/8) as nullhdr, SUM((1-null_frac)*avg_width) as datawidth, MAX(null_frac) as maxfracsum, schemaname, tablename, hdr, ma, bs FROM pg_stats CROSS JOIN constants LEFT OUTER JOIN no_stats ON schemaname = no_stats.table_schema AND tablename = no_stats.table_name WHERE schemaname NOT IN (''pg_catalog'', ''information_schema'') AND no_stats.table_name IS NULL AND EXISTS ( SELECT 1 FROM information_schema.columns WHERE schemaname = columns.table_schema AND tablename = columns.table_name ) GROUP BY schemaname, tablename, hdr, ma, bs), data_headers AS (SELECT ma, bs, hdr, schemaname, tablename, (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 FROM null_headers), table_estimates AS (SELECT schemaname, tablename, bs, reltuples::numeric as est_rows, relpages * bs as table_bytes, CEIL((reltuples*(datahdr + nullhdr2 + 4 + ma - (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))/(bs-20))) * bs AS expected_bytes, reltoastrelid FROM data_headers JOIN pg_class ON tablename = relname JOIN pg_namespace ON relnamespace = pg_namespace.oid AND schemaname = nspname WHERE pg_class.relkind = ''r''), estimates_with_toast AS (SELECT schemaname, tablename, TRUE as can_estimate, est_rows, table_bytes + ( coalesce(toast.relpages, 0) * bs ) as table_bytes, expected_bytes + ( ceil( coalesce(toast.reltuples, 0) / 4 ) * bs ) as expected_bytes FROM table_estimates LEFT OUTER JOIN pg_class as toast ON table_estimates.reltoastrelid = toast.oid AND toast.relkind = ''t''), table_estimates_plus AS (SELECT current_database() as databasename, schemaname, tablename, can_estimate, est_rows, CASE WHEN table_bytes > 0 THEN table_bytes::NUMERIC ELSE NULL::NUMERIC END AS table_bytes, CASE WHEN expected_bytes > 0 THEN expected_bytes::NUMERIC ELSE NULL::NUMERIC END AS expected_bytes, CASE WHEN expected_bytes > 0 AND table_bytes > 0 AND expected_bytes <= table_bytes THEN (table_bytes - expected_bytes)::NUMERIC ELSE 0::NUMERIC END AS bloat_bytes FROM estimates_with_toast UNION ALL SELECT current_database() as databasename, table_schema, table_name, FALSE, est_rows, table_size, NULL::NUMERIC, NULL::NUMERIC FROM no_stats), bloat_data AS (select current_database() as databasename, schemaname, tablename, can_estimate, table_bytes, round(table_bytes/(1024^2)::NUMERIC,3) as table_mb, expected_bytes, round(expected_bytes/(1024^2)::NUMERIC,3) as expected_mb, round(bloat_bytes*100/table_bytes) as pct_bloat, round(bloat_bytes/(1024::NUMERIC^2),2) as mb_bloat, table_bytes, expected_bytes, est_rows FROM table_estimates_plus) SELECT databasename, schemaname, tablename, can_estimate, est_rows, pct_bloat, mb_bloat, table_mb FROM bloat_data WHERE ( pct_bloat >= 50 AND mb_bloat >= 20 ) OR ( pct_bloat >= 25 AND mb_bloat >= 1000 ) ORDER BY pct_bloat DESC;'
-- current vacuum status
\set vacuumstatus 'SELECT p.pid, now() - a.xact_start AS duration, coalesce(wait_event_type ||''.''|| wait_event, ''f'') AS waiting, CASE WHEN a.query ~ ''^autovacuum.*to prevent wraparound'' THEN ''wraparound'' WHEN a.query ~ ''^vacuum'' THEN ''user'' ELSE ''regular'' END AS mode, p.datname AS database, p.relid::regclass AS table, p.phase, pg_size_pretty(p.heap_blks_total * current_setting(''block_size'')::int) AS table_size, pg_size_pretty(pg_total_relation_size(relid)) AS total_size, pg_size_pretty(p.heap_blks_scanned * current_setting(''block_size'')::int) AS scanned, pg_size_pretty(p.heap_blks_vacuumed * current_setting(''block_size'')::int) AS vacuumed, round(100.0 * p.heap_blks_scanned / p.heap_blks_total, 1) AS scanned_pct, round(100.0 * p.heap_blks_vacuumed / p.heap_blks_total, 1) AS vacuumed_pct, p.index_vacuum_count, round(100.0 * p.num_dead_tuples / p.max_dead_tuples,1) AS dead_pct FROM pg_stat_progress_vacuum p JOIN pg_stat_activity a using (pid) ORDER BY now() - a.xact_start DESC;'