├── README.md └── monitor.sql /README.md: -------------------------------------------------------------------------------- 1 | # Queries to monitor your PostgreSQL database 2 | 3 | These have been compiled from multiple sources like the [postgresql wiki](https://wiki.postgresql.org/wiki/Main_Page), and [check_postgres](https://bucardo.org/wiki/Check_postgres). 4 | 5 | ## Usage 6 | These `PREPARE`d statements are essentially queries with names (and 0 arguments) for convenience. Once you have executed a `PREPARE`, you can run it using `EXECUTE` like so: 7 | 8 | ```sql 9 | EXECUTE query_stats; 10 | ``` 11 | 12 | You can either copy/paste these in selectively, or use the [full list of queries](./monitor.sql). 13 | 14 | ## Cost 15 | These queries can be run periodically to send data to your monitoring system. They are all cheap enough to be run every few seconds even during heavy load. 16 | 17 | 18 | ## Queries 19 | ### current_queries_status (pg9.x) 20 | ```sql 21 | PREPARE current_queries_status AS 22 | SELECT count(pid), query, waiting from pg_stat_activity group by query, waiting; 23 | ``` 24 | 25 | ### current_queries_status_with_locks (pg9.x) 26 | ```sql 27 | PREPARE current_queries_status_with_locks AS 28 | SELECT count(pg_stat_activity.pid) AS number_of_queries, 29 | substring(trim(LEADING 30 | FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, 31 | ' '::text, 'g'::text)) 32 | FROM 0 33 | FOR 200) AS query_name, 34 | max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, 35 | waiting, 36 | usename, 37 | locktype, 38 | mode, 39 | granted 40 | FROM pg_stat_activity 41 | LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid 42 | WHERE query != '' 43 | AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' 44 | AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval 45 | GROUP BY query_name, 46 | waiting, 47 | usename, 48 | locktype, 49 | mode, 50 | granted 51 | ORDER BY max_wait_time DESC; 52 | ``` 53 | 54 | ### current_queries_status_with_locks (pg10) 55 | ```sql 56 | PREPARE current_queries_status_with_locks AS 57 | SELECT count(pg_stat_activity.pid) AS number_of_queries, 58 | substring(trim(LEADING 59 | FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, 60 | ' '::text, 'g'::text)) 61 | FROM 0 62 | FOR 200) AS query_name, 63 | max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, 64 | wait_event, 65 | usename, 66 | locktype, 67 | mode, 68 | granted 69 | FROM pg_stat_activity 70 | LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid 71 | WHERE query != '' 72 | AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' 73 | AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval 74 | GROUP BY query_name, 75 | wait_event, 76 | usename, 77 | locktype, 78 | mode, 79 | granted 80 | ORDER BY max_wait_time DESC; 81 | ``` 82 | 83 | ### query_stats 84 | ```sql 85 | PREPARE query_stats AS 86 | SELECT LEFT(query,50) AS query, 87 | calls, total_time, rows, shared_blks_hit, 88 | local_blks_hit, blk_read_time, blk_write_time 89 | FROM pg_stat_statements 90 | WHERE EXISTS(SELECT * FROM pg_available_extensions 91 | WHERE name = 'pg_stat_statements') 92 | ORDER BY calls DESC; 93 | ``` 94 | 95 | - This requires [pg_stat_statements](http://www.postgresql.org/docs/current/static/pgstatstatements.html) to be set up. It's a part of the contrib package, and needs to be added to `shared_preload_libraries` in `postgresql.conf`. 96 | 97 | ## Long Running Queries 98 | ``` 99 | sql 100 | SELECT 101 | pid, 102 | user, 103 | pg_stat_activity.query_start, 104 | now() - pg_stat_activity.query_start AS query_time, 105 | query, 106 | state, 107 | wait_event_type, 108 | wait_event 109 | FROM pg_stat_activity 110 | WHERE (now() - pg_stat_activity.query_start) > interval '5 minutes'; 111 | ``` 112 | 113 | This enables you to know the queries running for more than x Minutes (5 here). This gives you visibility as what might be hogging up your CPU and network pool. 114 | Crucial in determining what might take your DB down in high traffic. 115 | 116 | ## Cache 117 | ### cache_tables 118 | ```sql 119 | PREPARE cache_tables AS 120 | SELECT relname AS "relation", 121 | heap_blks_read AS heap_read, 122 | heap_blks_hit AS heap_hit, 123 | ( (heap_blks_hit*100) / NULLIF((heap_blks_hit + heap_blks_read), 0)) AS ratio 124 | FROM pg_statio_user_tables; 125 | ``` 126 | 127 | ### cache_total 128 | ```sql 129 | PREPARE cache_total AS 130 | SELECT sum(heap_blks_read) AS heap_read, 131 | sum(heap_blks_hit) AS heap_hit, 132 | (sum(heap_blks_hit)*100 / NULLIF((sum(heap_blks_hit) + sum(heap_blks_read)),0)) AS ratio 133 | FROM pg_statio_user_tables; 134 | ``` 135 | 136 | ## Disk usage 137 | ### table_sizes 138 | ```sql 139 | PREPARE table_sizes AS 140 | SELECT relname AS "relation", 141 | pg_size_pretty(pg_total_relation_size(C.oid)) AS "total_size" 142 | FROM pg_class C 143 | LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 144 | WHERE nspname NOT IN ('pg_catalog', 'information_schema') 145 | AND C.relkind <> 'i' 146 | AND nspname ='public' 147 | ORDER BY pg_total_relation_size(C.oid) DESC; 148 | ``` 149 | 150 | ### relation_sizes 151 | ```sql 152 | PREPARE relation_sizes AS 153 | SELECT relname AS "relation", 154 | pg_size_pretty(pg_relation_size(C.oid)) AS "size" 155 | FROM pg_class C 156 | LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 157 | WHERE nspname = 'public' 158 | ORDER BY pg_relation_size(C.oid) DESC; 159 | ``` 160 | 161 | ### db_size 162 | ```sql 163 | PREPARE db_size AS 164 | SELECT pg_size_pretty(pg_database_size(current_database())); 165 | ``` 166 | 167 | ## Bloat 168 | ### table_bloat 169 | ```sql 170 | PREPARE table_bloat AS 171 | SELECT tblname as "relation", pg_size_pretty((bs*tblpages)::bigint) AS real_size, 172 | pg_size_pretty(((tblpages-est_tblpages)*bs)::bigint) AS extra_size, 173 | CASE WHEN tblpages - est_tblpages > 0 174 | THEN 100 * (tblpages - est_tblpages)/tblpages::float 175 | ELSE 0 176 | END AS extra_ratio, fillfactor, pg_size_pretty(((tblpages-est_tblpages_ff)*bs)::bigint) AS bloat_size, 177 | CASE WHEN tblpages - est_tblpages_ff > 0 178 | THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float 179 | ELSE 0 180 | END AS bloat_ratio, is_na::varchar 181 | -- , (pst).free_percent + (pst).dead_tuple_percent AS real_frag 182 | FROM ( 183 | SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages, 184 | ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, 185 | tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na 186 | -- , stattuple.pgstattuple(tblid) AS pst 187 | FROM ( 188 | SELECT 189 | ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) 190 | - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END 191 | - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END 192 | ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, 193 | toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na 194 | FROM ( 195 | SELECT 196 | tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, 197 | tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, 198 | coalesce(toast.reltuples, 0) AS toasttuples, 199 | coalesce(substring( 200 | array_to_string(tbl.reloptions, ' ') 201 | FROM '%fillfactor=#"__#"%' FOR '#')::smallint, 100) AS fillfactor, 202 | current_setting('block_size')::numeric AS bs, 203 | CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, 204 | 24 AS page_hdr, 205 | 23 + CASE WHEN MAX(coalesce(null_frac,0)) > 0 THEN ( 7 + count(*) ) / 8 ELSE 0::int END 206 | + CASE WHEN tbl.relhasoids THEN 4 ELSE 0 END AS tpl_hdr_size, 207 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024) ) AS tpl_data_size, 208 | bool_or(att.atttypid = 'pg_catalog.name'::regtype) AS is_na 209 | FROM pg_attribute AS att 210 | JOIN pg_class AS tbl ON att.attrelid = tbl.oid 211 | JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace 212 | JOIN pg_stats AS s ON s.schemaname=ns.nspname AND ns.nspname = 'public' 213 | AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname 214 | LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid 215 | WHERE att.attnum > 0 AND NOT att.attisdropped 216 | AND tbl.relkind = 'r' 217 | GROUP BY 1,2,3,4,5,6,7,8,9,10, tbl.relhasoids 218 | ORDER BY 2,3 219 | ) AS s 220 | ) AS s2 221 | ) AS s3; 222 | ``` 223 | 224 | ### table_and_index_bloat 225 | ```sql 226 | PREPARE table_and_index_bloat AS 227 | SELECT 228 | tablename AS "relation", reltuples::bigint AS tups, relpages::bigint AS pages, otta, 229 | ROUND(CASE WHEN otta=0 OR sml.relpages=0 OR sml.relpages=otta THEN 0.0 ELSE sml.relpages/otta::numeric END,1) AS tbloat, 230 | CASE WHEN relpages < otta THEN 0 ELSE relpages::bigint - otta END AS wastedpages, 231 | CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::bigint END AS wastedbytes, 232 | CASE WHEN relpages < otta THEN 0 ELSE (bs*(relpages-otta))::bigint END AS wastedsize, 233 | iname, ituples::bigint AS itups, ipages::bigint AS ipages, iotta, 234 | ROUND(CASE WHEN iotta=0 OR ipages=0 OR ipages=iotta THEN 0.0 ELSE ipages/iotta::numeric END,1) AS ibloat, 235 | CASE WHEN ipages < iotta THEN 0 ELSE ipages::bigint - iotta END AS wastedipages, 236 | CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes, 237 | CASE WHEN ipages < iotta THEN 0 ELSE (bs*(ipages-iotta))::bigint END AS wastedisize, 238 | CASE WHEN relpages < otta THEN 239 | CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta::bigint) END 240 | ELSE CASE WHEN ipages < iotta THEN bs*(relpages-otta::bigint) 241 | ELSE bs*(relpages-otta::bigint + ipages-iotta::bigint) END 242 | END AS totalwastedbytes 243 | FROM ( 244 | SELECT 245 | nn.nspname AS schemaname, 246 | cc.relname AS tablename, 247 | COALESCE(cc.reltuples,0) AS reltuples, 248 | COALESCE(cc.relpages,0) AS relpages, 249 | COALESCE(bs,0) AS bs, 250 | COALESCE(CEIL((cc.reltuples*((datahdr+ma- 251 | (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)),0) AS otta, 252 | COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, 253 | COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols 254 | FROM 255 | pg_class cc 256 | JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = 'public' 257 | LEFT JOIN 258 | ( 259 | SELECT 260 | ma,bs,foo.nspname,foo.relname, 261 | (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, 262 | (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 263 | FROM ( 264 | SELECT 265 | ns.nspname, tbl.relname, hdr, ma, bs, 266 | SUM((1-coalesce(null_frac,0))*coalesce(avg_width, 2048)) AS datawidth, 267 | MAX(coalesce(null_frac,0)) AS maxfracsum, 268 | hdr+( 269 | SELECT 1+count(*)/8 270 | FROM pg_stats s2 271 | WHERE null_frac<>0 AND s2.schemaname = ns.nspname AND s2.tablename = tbl.relname 272 | ) AS nullhdr 273 | FROM pg_attribute att 274 | JOIN pg_class tbl ON att.attrelid = tbl.oid 275 | JOIN pg_namespace ns ON ns.oid = tbl.relnamespace 276 | LEFT JOIN pg_stats s ON s.schemaname=ns.nspname 277 | AND s.tablename = tbl.relname 278 | AND s.inherited=false 279 | AND s.attname=att.attname, 280 | ( 281 | SELECT 282 | (SELECT current_setting('block_size')::numeric) AS bs, 283 | CASE WHEN SUBSTRING(SPLIT_PART(v, ' ', 2) FROM '#"[0-9]+.[0-9]+#"%' for '#') 284 | IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, 285 | CASE WHEN v ~ 'mingw32' OR v ~ '64-bit' THEN 8 ELSE 4 END AS ma 286 | FROM (SELECT version() AS v) AS foo 287 | ) AS constants 288 | WHERE att.attnum > 0 AND tbl.relkind='r' 289 | GROUP BY 1,2,3,4,5 290 | ) AS foo 291 | ) AS rs 292 | ON cc.relname = rs.relname AND nn.nspname = rs.nspname AND nn.nspname = 'public' 293 | LEFT JOIN pg_index i ON indrelid = cc.oid 294 | LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid 295 | ) AS sml; 296 | ``` 297 | 298 | ## Indexes 299 | ### index_usage 300 | ```sql 301 | PREPARE index_usage AS 302 | SELECT 303 | t.tablename AS "relation", 304 | indexname, 305 | c.reltuples AS num_rows, 306 | pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, 307 | pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, 308 | idx_scan AS number_of_scans, 309 | idx_tup_read AS tuples_read, 310 | idx_tup_fetch AS tuples_fetched 311 | FROM pg_tables t 312 | LEFT OUTER JOIN pg_class c ON t.tablename=c.relname 313 | LEFT OUTER JOIN 314 | ( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x 315 | JOIN pg_class c ON c.oid = x.indrelid 316 | JOIN pg_class ipg ON ipg.oid = x.indexrelid 317 | JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid ) 318 | AS foo 319 | ON t.tablename = foo.ctablename 320 | WHERE t.schemaname='public' 321 | ORDER BY 1,2; 322 | ``` 323 | 324 | ## Tuples and Autovacuum 325 | ### tuple_info 326 | ```sql 327 | PREPARE tuple_info AS 328 | SELECT relname as "relation", EXTRACT (EPOCH FROM current_timestamp-last_autovacuum) as since_last_av, 329 | autovacuum_count as av_count, n_tup_ins, n_tup_upd, n_tup_del, n_live_tup, n_dead_tup 330 | FROM pg_stat_all_tables 331 | WHERE schemaname = 'public' 332 | ORDER BY relname; 333 | ``` 334 | 335 | 336 | ## Replication 337 | ### replication_status (pg9.x) 338 | ```sql 339 | PREPARE replication_status AS 340 | SELECT application_name,client_addr,state,sent_location,write_location,replay_location, 341 | (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag 342 | FROM (SELECT 343 | application_name,client_addr,state,sync_state,sent_location,write_location,replay_location, 344 | ('x' || lpad(split_part(sent_location::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, 345 | ('x' || lpad(split_part(replay_location::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, 346 | ('x' || lpad(split_part(sent_location::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, 347 | ('x' || lpad(split_part(replay_location::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset 348 | FROM pg_stat_replication) 349 | AS s; 350 | ``` 351 | ### replication_status (pg10) 352 | ```sql 353 | PREPARE replication_status AS 354 | SELECT application_name,client_addr,state, \\ 355 | (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag \\ 356 | FROM (SELECT \\ 357 | application_name,client_addr,state,sync_state,sent_lsn,write_lsn,replay_lsn, \\ 358 | ('x' || lpad(split_part(sent_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, \\ 359 | ('x' || lpad(split_part(replay_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, \\ 360 | ('x' || lpad(split_part(sent_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, \\ 361 | ('x' || lpad(split_part(replay_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset \\ 362 | FROM pg_stat_replication) \\ 363 | AS s; 364 | ``` 365 | 366 | -------------------------------------------------------------------------------- /monitor.sql: -------------------------------------------------------------------------------- 1 | -- Cache 2 | PREPARE cache_tables AS 3 | SELECT relname AS "relation", 4 | heap_blks_read AS heap_read, 5 | heap_blks_hit AS heap_hit, 6 | ( (heap_blks_hit*100) / NULLIF((heap_blks_hit + heap_blks_read), 0)) AS ratio 7 | FROM pg_statio_user_tables; 8 | 9 | PREPARE cache_total AS 10 | SELECT sum(heap_blks_read) AS heap_read, 11 | sum(heap_blks_hit) AS heap_hit, 12 | (sum(heap_blks_hit)*100 / NULLIF((sum(heap_blks_hit) + sum(heap_blks_read)),0)) AS ratio 13 | FROM pg_statio_user_tables; 14 | 15 | -- Disk usage 16 | PREPARE table_sizes AS 17 | SELECT relname AS "relation", 18 | pg_size_pretty(pg_total_relation_size(C.oid)) AS "total_size" 19 | FROM pg_class C 20 | LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 21 | WHERE nspname NOT IN ('pg_catalog', 'information_schema') 22 | AND C.relkind <> 'i' 23 | AND nspname ='public' 24 | ORDER BY pg_total_relation_size(C.oid) DESC; 25 | 26 | PREPARE relation_sizes AS 27 | SELECT relname AS "relation", 28 | pg_size_pretty(pg_relation_size(C.oid)) AS "size" 29 | FROM pg_class C 30 | LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) 31 | WHERE nspname = 'public' 32 | ORDER BY pg_relation_size(C.oid) DESC; 33 | 34 | PREPARE db_size AS 35 | SELECT pg_size_pretty(pg_database_size(current_database())); 36 | 37 | -- Bloat 38 | PREPARE table_bloat AS 39 | SELECT tblname as "relation", pg_size_pretty((bs*tblpages)::bigint) AS real_size, 40 | pg_size_pretty(((tblpages-est_tblpages)*bs)::bigint) AS extra_size, 41 | CASE WHEN tblpages - est_tblpages > 0 42 | THEN 100 * (tblpages - est_tblpages)/tblpages::float 43 | ELSE 0 44 | END AS extra_ratio, fillfactor, pg_size_pretty(((tblpages-est_tblpages_ff)*bs)::bigint) AS bloat_size, 45 | CASE WHEN tblpages - est_tblpages_ff > 0 46 | THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float 47 | ELSE 0 48 | END AS bloat_ratio, is_na::varchar 49 | -- , (pst).free_percent + (pst).dead_tuple_percent AS real_frag 50 | FROM ( 51 | SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages, 52 | ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, 53 | tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na 54 | -- , stattuple.pgstattuple(tblid) AS pst 55 | FROM ( 56 | SELECT 57 | ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) 58 | - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END 59 | - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END 60 | ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, 61 | toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na 62 | FROM ( 63 | SELECT 64 | tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, 65 | tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, 66 | coalesce(toast.reltuples, 0) AS toasttuples, 67 | coalesce(substring( 68 | array_to_string(tbl.reloptions, ' ') 69 | FROM '%fillfactor=#"__#"%' FOR '#')::smallint, 100) AS fillfactor, 70 | current_setting('block_size')::numeric AS bs, 71 | CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, 72 | 24 AS page_hdr, 73 | 23 + CASE WHEN MAX(coalesce(null_frac,0)) > 0 THEN ( 7 + count(*) ) / 8 ELSE 0::int END 74 | + CASE WHEN tbl.relhasoids THEN 4 ELSE 0 END AS tpl_hdr_size, 75 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024) ) AS tpl_data_size, 76 | bool_or(att.atttypid = 'pg_catalog.name'::regtype) AS is_na 77 | FROM pg_attribute AS att 78 | JOIN pg_class AS tbl ON att.attrelid = tbl.oid 79 | JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace 80 | JOIN pg_stats AS s ON s.schemaname=ns.nspname AND ns.nspname = 'public' 81 | AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname 82 | LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid 83 | WHERE att.attnum > 0 AND NOT att.attisdropped 84 | AND tbl.relkind = 'r' 85 | GROUP BY 1,2,3,4,5,6,7,8,9,10, tbl.relhasoids 86 | ORDER BY 2,3 87 | ) AS s 88 | ) AS s2 89 | ) AS s3; 90 | 91 | PREPARE table_and_index_bloat AS 92 | SELECT 93 | tablename AS "relation", reltuples::bigint AS tups, relpages::bigint AS pages, otta, 94 | ROUND(CASE WHEN otta=0 OR sml.relpages=0 OR sml.relpages=otta THEN 0.0 ELSE sml.relpages/otta::numeric END,1) AS tbloat, 95 | CASE WHEN relpages < otta THEN 0 ELSE relpages::bigint - otta END AS wastedpages, 96 | CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::bigint END AS wastedbytes, 97 | CASE WHEN relpages < otta THEN 0 ELSE (bs*(relpages-otta))::bigint END AS wastedsize, 98 | iname, ituples::bigint AS itups, ipages::bigint AS ipages, iotta, 99 | ROUND(CASE WHEN iotta=0 OR ipages=0 OR ipages=iotta THEN 0.0 ELSE ipages/iotta::numeric END,1) AS ibloat, 100 | CASE WHEN ipages < iotta THEN 0 ELSE ipages::bigint - iotta END AS wastedipages, 101 | CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes, 102 | CASE WHEN ipages < iotta THEN 0 ELSE (bs*(ipages-iotta))::bigint END AS wastedisize, 103 | CASE WHEN relpages < otta THEN 104 | CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta::bigint) END 105 | ELSE CASE WHEN ipages < iotta THEN bs*(relpages-otta::bigint) 106 | ELSE bs*(relpages-otta::bigint + ipages-iotta::bigint) END 107 | END AS totalwastedbytes 108 | FROM ( 109 | SELECT 110 | nn.nspname AS schemaname, 111 | cc.relname AS tablename, 112 | COALESCE(cc.reltuples,0) AS reltuples, 113 | COALESCE(cc.relpages,0) AS relpages, 114 | COALESCE(bs,0) AS bs, 115 | COALESCE(CEIL((cc.reltuples*((datahdr+ma- 116 | (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)),0) AS otta, 117 | COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, 118 | COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols 119 | FROM 120 | pg_class cc 121 | JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = 'public' 122 | LEFT JOIN 123 | ( 124 | SELECT 125 | ma,bs,foo.nspname,foo.relname, 126 | (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, 127 | (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 128 | FROM ( 129 | SELECT 130 | ns.nspname, tbl.relname, hdr, ma, bs, 131 | SUM((1-coalesce(null_frac,0))*coalesce(avg_width, 2048)) AS datawidth, 132 | MAX(coalesce(null_frac,0)) AS maxfracsum, 133 | hdr+( 134 | SELECT 1+count(*)/8 135 | FROM pg_stats s2 136 | WHERE null_frac<>0 AND s2.schemaname = ns.nspname AND s2.tablename = tbl.relname 137 | ) AS nullhdr 138 | FROM pg_attribute att 139 | JOIN pg_class tbl ON att.attrelid = tbl.oid 140 | JOIN pg_namespace ns ON ns.oid = tbl.relnamespace 141 | LEFT JOIN pg_stats s ON s.schemaname=ns.nspname 142 | AND s.tablename = tbl.relname 143 | AND s.inherited=false 144 | AND s.attname=att.attname, 145 | ( 146 | SELECT 147 | (SELECT current_setting('block_size')::numeric) AS bs, 148 | CASE WHEN SUBSTRING(SPLIT_PART(v, ' ', 2) FROM '#"[0-9]+.[0-9]+#"%' for '#') 149 | IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, 150 | CASE WHEN v ~ 'mingw32' OR v ~ '64-bit' THEN 8 ELSE 4 END AS ma 151 | FROM (SELECT version() AS v) AS foo 152 | ) AS constants 153 | WHERE att.attnum > 0 AND tbl.relkind='r' 154 | GROUP BY 1,2,3,4,5 155 | ) AS foo 156 | ) AS rs 157 | ON cc.relname = rs.relname AND nn.nspname = rs.nspname AND nn.nspname = 'public' 158 | LEFT JOIN pg_index i ON indrelid = cc.oid 159 | LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid 160 | ) AS sml; 161 | 162 | -- Indexes 163 | PREPARE index_usage AS 164 | SELECT 165 | t.tablename AS "relation", 166 | indexname, 167 | c.reltuples AS num_rows, 168 | pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, 169 | pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, 170 | idx_scan AS number_of_scans, 171 | idx_tup_read AS tuples_read, 172 | idx_tup_fetch AS tuples_fetched 173 | FROM pg_tables t 174 | LEFT OUTER JOIN pg_class c ON t.tablename=c.relname 175 | LEFT OUTER JOIN 176 | ( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x 177 | JOIN pg_class c ON c.oid = x.indrelid 178 | JOIN pg_class ipg ON ipg.oid = x.indexrelid 179 | JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid ) 180 | AS foo 181 | ON t.tablename = foo.ctablename 182 | WHERE t.schemaname='public' 183 | ORDER BY 1,2; 184 | 185 | -- Tuples 186 | PREPARE tuple_info AS 187 | SELECT relname as "relation", EXTRACT (EPOCH FROM current_timestamp-last_autovacuum) as since_last_av, 188 | autovacuum_count as av_count, n_tup_ins, n_tup_upd, n_tup_del, n_live_tup, n_dead_tup 189 | FROM pg_stat_all_tables 190 | WHERE schemaname = 'public' 191 | ORDER BY relname; 192 | 193 | 194 | -- queries 195 | PREPARE current_queries_status AS 196 | SELECT count(pid), query, waiting from pg_stat_activity group by query, waiting; 197 | 198 | PREPARE queries AS 199 | SELECT LEFT(query,50) AS query, 200 | calls, total_time, rows, shared_blks_hit, 201 | local_blks_hit, blk_read_time, blk_write_time 202 | FROM pg_stat_statements 203 | WHERE EXISTS(SELECT * FROM pg_available_extensions 204 | WHERE name = 'pg_stat_statements') 205 | ORDER BY calls DESC; 206 | 207 | PREPARE current_queries_status_with_locks AS 208 | SELECT count(pg_stat_activity.pid) AS number_of_queries, 209 | substring(trim(LEADING 210 | FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, 211 | ' '::text, 'g'::text)) 212 | FROM 0 213 | FOR 200) AS query_name, 214 | max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, 215 | waiting, 216 | usename, 217 | locktype, 218 | mode, 219 | granted 220 | FROM pg_stat_activity 221 | LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid 222 | WHERE query != '' 223 | AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' 224 | AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval 225 | GROUP BY query_name, 226 | waiting, 227 | usename, 228 | locktype, 229 | mode, 230 | granted 231 | ORDER BY max_wait_time DESC; 232 | 233 | 234 | PREPARE current_queries_status_with_locks_pg10 AS 235 | SELECT count(pg_stat_activity.pid) AS number_of_queries, 236 | substring(trim(LEADING 237 | FROM regexp_replace(pg_stat_activity.query, '[\n\r]+'::text, 238 | ' '::text, 'g'::text)) 239 | FROM 0 240 | FOR 200) AS query_name, 241 | max(age(CURRENT_TIMESTAMP, query_start)) AS max_wait_time, 242 | wait_event, 243 | usename, 244 | locktype, 245 | mode, 246 | granted 247 | FROM pg_stat_activity 248 | LEFT JOIN pg_locks ON pg_stat_activity.pid = pg_locks.pid 249 | WHERE query != '' 250 | AND query NOT ILIKE '%pg_%' AND query NOT ILIKE '%application_name%' AND query NOT ILIKE '%inet%' 251 | AND age(CURRENT_TIMESTAMP, query_start) > '5 milliseconds'::interval 252 | GROUP BY query_name, 253 | wait_event, 254 | usename, 255 | locktype, 256 | mode, 257 | granted 258 | ORDER BY max_wait_time DESC; 259 | 260 | -- replication 261 | PREPARE replication_status_9 AS 262 | SELECT application_name,client_addr,state,sent_location,write_location,replay_location, 263 | (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag 264 | FROM (SELECT 265 | application_name,client_addr,state,sync_state,sent_location,write_location,replay_location, 266 | ('x' || lpad(split_part(sent_location::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, 267 | ('x' || lpad(split_part(replay_location::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, 268 | ('x' || lpad(split_part(sent_location::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, 269 | ('x' || lpad(split_part(replay_location::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset 270 | FROM pg_stat_replication) 271 | AS s; 272 | 273 | PREPARE replication_status_10 AS 274 | SELECT application_name,client_addr,state, \\ 275 | (sent_offset - (replay_offset - (sent_xlog - replay_xlog) * 255 * 16 ^ 6 ))::text AS byte_lag \\ 276 | FROM (SELECT \\ 277 | application_name,client_addr,state,sync_state,sent_lsn,write_lsn,replay_lsn, \\ 278 | ('x' || lpad(split_part(sent_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS sent_xlog, \\ 279 | ('x' || lpad(split_part(replay_lsn::text, '/', 1), 8, '0'))::bit(32)::bigint AS replay_xlog, \\ 280 | ('x' || lpad(split_part(sent_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS sent_offset, \\ 281 | ('x' || lpad(split_part(replay_lsn::text, '/', 2), 8, '0'))::bit(32)::bigint AS replay_offset \\ 282 | FROM pg_stat_replication) \\ 283 | AS s; 284 | --------------------------------------------------------------------------------