├── .gitignore ├── setup.py ├── LICENSE ├── README.md └── pgh.py /.gitignore: -------------------------------------------------------------------------------- 1 | pgh.egg-info 2 | __pycache__ 3 | venv 4 | build 5 | dist 6 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup 2 | 3 | setup( 4 | name='PGH', 5 | description='PGH is a command line tool to help you monitor and debug your PostgreSQL database.', 6 | long_description='PGH is a command line tool to help you monitor and debug your PostgreSQL database.', 7 | author='André Barbosa', 8 | author_email = "albmail88@gmail.com", 9 | license = "MIT", 10 | keywords = "pg postgres postgresql", 11 | url = "https://github.com/nata79/pgh", 12 | version='0.1', 13 | py_modules=['pgh'], 14 | install_requires=[ 15 | 'click', 16 | 'tabulate', 17 | 'psycopg2' 18 | ], 19 | entry_points=''' 20 | [console_scripts] 21 | pgh=pgh:cli 22 | ''', 23 | ) 24 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright © André Barbosa 2016 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining 6 | a copy of this software and associated documentation files (the 7 | "Software"), to deal in the Software without restriction, including 8 | without limitation the rights to use, copy, modify, merge, publish, 9 | distribute, sublicense, and/or sell copies of the Software, and to 10 | permit persons to whom the Software is furnished to do so, subject to 11 | the following conditions: 12 | 13 | The above copyright notice and this permission notice shall be 14 | included in all copies or substantial portions of the Software. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 19 | IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY 20 | CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, 21 | TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE 22 | SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 23 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PGH 2 | 3 | [![PyPI version](https://badge.fury.io/py/pgh.svg)](https://badge.fury.io/py/pgh) 4 | 5 | PGH is a CLI tool to help you manage your PostgreSQL database. It provides a list of utility commands to help you keep track of what's going on. 6 | 7 | ``` 8 | pgh $DATABASE_URL total_table_size 9 | +-----------------------------+------------+ 10 | | name | size | 11 | |-----------------------------+------------| 12 | | posts | 99 GB | 13 | | media | 99 GB | 14 | | comments | 11 GB | 15 | | users | 4511 MB | 16 | | oauth_access_tokens | 4359 MB | 17 | | followers | 3403 MB | 18 | | devices | 2645 MB | 19 | | notifications | 1821 MB | 20 | +-----------------------------+------------+ 21 | ``` 22 | 23 | *Example calculates the size of each table including indexes.* 24 | 25 | ## Instalation 26 | 27 | ``` 28 | pip install pgh 29 | ``` 30 | 31 | ## Usage 32 | 33 | ``` 34 | pgh DATABASE_URL COMMAND 35 | ``` 36 | 37 | Where `DATABASE_URL` should be a valid Postgres connection URI with the format: 38 | 39 | ``` 40 | postgresql://[user[:password]@][netloc][:port][/dbname][?param1=value1&...] 41 | ``` 42 | 43 | Example: 44 | 45 | ``` 46 | pgh postgres://andre@localhost/test index_sizes 47 | 48 | +---------------------------+---------+ 49 | | name | size | 50 | |---------------------------+---------| 51 | | h_table_id_index | 4096 MB | 52 | | b_table_id_index | 3873 MB | 53 | +---------------------------+---------+ 54 | ``` 55 | 56 | ## Commands 57 | 58 | | Command | Description | 59 | | --- | --- | 60 | | bloat | show table and index bloat in your database ordered by most wasteful | 61 | | blocking | display queries holding locks other queries are waiting to be released | 62 | | cache\_hit | calculates your cache hit rate (effective databases are at 99% and up) | 63 | | calls | show 10 most frequently called queries | 64 | | index\_size | show the size of indexes, descending by size | 65 | | index\_usage | calculates your index hit rate (effective databases are at 99% and up) | 66 | | locks | display queries with active locks | 67 | | long\_running\_queries | show all queries longer than five minutes by descending duration | 68 | | outliers | show 10 queries that have longest execution time in aggregate | 69 | | ps | view active queries with execution time | 70 | | records\_rank | show all tables and the number of rows in each ordered by number of rows descending | 71 | | seq\_scans | show the count of sequential scans by table descending by order | 72 | | table\_size | show the size of the tables (excluding indexes), descending by size | 73 | | total\_table\_size | show the size of the tables (including indexes), descending by size | 74 | | unused\_indexes | show unused and almost unused indexes | 75 | 76 | ## Roadmap 77 | 78 | - Integrate with AWS to to get the connection string from RDS (something like `pgh --rds command`); 79 | - Integrate with Heroku API to get the connection string (something like `pgh --heroku command`); 80 | - Implement `pull` command to copy data from a remote database to a target; 81 | - - Implement `diagnose` command to generate a report of the general health of the database; 82 | - Support connection parameters as specified [here](http://www.postgresql.org/docs/current/static/libpq-connect.html#LIBPQ-PARAMKEYWORDS). 83 | 84 | ## Acknowledgements 85 | 86 | This tool is heavily based on the command tools built by [Heroku](http://heroku.com/). A lot of the commands and database queries present here are either inspired or directly taken from commands and database queries from [heroku cli](https://github.com/heroku/heroku) and [heroku pg extras](https://github.com/heroku/heroku-pg-extras). 87 | -------------------------------------------------------------------------------- /pgh.py: -------------------------------------------------------------------------------- 1 | import psycopg2 2 | import click 3 | import getpass 4 | from tabulate import tabulate 5 | 6 | def print_results(cursor): 7 | headers = map(lambda column: column.name, cursor.description) 8 | 9 | def truncate_row(row): 10 | return map(truncate_column, row) 11 | 12 | def truncate_column(column): 13 | column = str(column) 14 | return (column[:90] + '..') if len(column) > 75 else column 15 | 16 | click.echo(tabulate(map(truncate_row, cursor), headers=headers, tablefmt="psql")) 17 | 18 | def pg_stat_statement_available(cursor): 19 | sql = """ 20 | SELECT exists( 21 | SELECT 1 FROM pg_extension e LEFT JOIN pg_namespace n ON n.oid = e.extnamespace 22 | WHERE e.extname='pg_stat_statements' AND n.nspname = 'public' 23 | ) AS available 24 | """ 25 | cursor.execute(sql) 26 | return cursor.fetchone()[0] 27 | 28 | def database_command(fn): 29 | @click.command(fn.__name__) 30 | @click.pass_context 31 | def wrapper(ctx): 32 | connection = psycopg2.connect(ctx.obj) 33 | cursor = connection.cursor() 34 | 35 | results = fn(cursor) 36 | 37 | if results: 38 | print_results(results) 39 | 40 | cursor.close() 41 | connection.close() 42 | 43 | return wrapper 44 | 45 | @database_command 46 | def index_sizes(cursor): 47 | sql = """ 48 | SELECT c.relname AS name, 49 | pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size 50 | FROM pg_class c 51 | LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) 52 | WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') 53 | AND n.nspname !~ '^pg_toast' 54 | AND c.relkind = 'i' 55 | GROUP BY c.relname 56 | ORDER BY sum(c.relpages) DESC; 57 | """ 58 | 59 | cursor.execute(sql) 60 | 61 | return cursor 62 | 63 | @database_command 64 | def bloat(cursor): 65 | sql = """ 66 | WITH constants AS ( 67 | SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma 68 | ), bloat_info AS ( 69 | SELECT ma,bs,schemaname,tablename, 70 | (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, 71 | (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 72 | FROM ( 73 | SELECT schemaname, tablename, hdr, ma, bs, 74 | SUM((1-null_frac)*avg_width) AS datawidth, 75 | MAX(null_frac) AS maxfracsum, 76 | hdr+( 77 | SELECT 1+count(*)/8 FROM pg_stats s2 78 | WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename 79 | ) AS nullhdr 80 | FROM pg_stats s, constants 81 | GROUP BY 1,2,3,4,5 82 | ) AS foo 83 | ), table_bloat AS ( 84 | SELECT schemaname, tablename, cc.relpages, bs, 85 | CEIL((cc.reltuples*((datahdr+ma- 86 | (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta 87 | FROM bloat_info 88 | JOIN pg_class cc ON cc.relname = bloat_info.tablename 89 | JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' 90 | ), index_bloat AS ( 91 | SELECT schemaname, tablename, bs, 92 | COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, 93 | COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols 94 | FROM bloat_info 95 | JOIN pg_class cc ON cc.relname = bloat_info.tablename 96 | JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' 97 | JOIN pg_index i ON indrelid = cc.oid 98 | JOIN pg_class c2 ON c2.oid = i.indexrelid 99 | ) SELECT 100 | type, schemaname, object_name, bloat, pg_size_pretty(raw_waste) as waste 101 | FROM 102 | ( 103 | SELECT 'table' as type, schemaname, tablename as object_name, 104 | ROUND(CASE WHEN otta=0 THEN 0.0 ELSE table_bloat.relpages/otta::numeric END,1) AS bloat, 105 | CASE WHEN relpages < otta THEN '0' ELSE (bs*(table_bloat.relpages-otta)::bigint)::bigint END AS raw_waste 106 | FROM table_bloat 107 | UNION SELECT 'index' as type, schemaname, tablename || '::' || iname as object_name, 108 | ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS bloat, 109 | CASE WHEN ipages < iotta THEN '0' ELSE (bs*(ipages-iotta))::bigint END AS raw_waste 110 | FROM index_bloat 111 | ) bloat_summary 112 | ORDER BY raw_waste DESC, bloat DESC 113 | """ 114 | 115 | cursor.execute(sql) 116 | 117 | return cursor 118 | 119 | @database_command 120 | def blocking(cursor): 121 | sql = """ 122 | SELECT bl.pid AS blocked_pid, 123 | ka.query AS blocking_statement, 124 | now() - ka.query_start AS blocking_duration, 125 | kl.pid AS blocking_pid, 126 | a.query AS blocked_statement, 127 | now() - a.query_start AS blocked_duration 128 | FROM pg_catalog.pg_locks bl 129 | JOIN pg_catalog.pg_stat_activity a ON bl.pid = a.pid 130 | JOIN pg_catalog.pg_locks kl 131 | JOIN pg_catalog.pg_stat_activity ka ON kl.pid = ka.pid 132 | ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid 133 | WHERE NOT bl.granted 134 | """ 135 | 136 | cursor.execute(sql) 137 | 138 | return cursor 139 | 140 | @database_command 141 | def cache_hit(cursor): 142 | sql = """ 143 | SELECT 'index hit rate' AS name, 144 | (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio 145 | FROM pg_statio_user_indexes 146 | UNION ALL 147 | SELECT 'table hit rate' AS name, 148 | sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio 149 | FROM pg_statio_user_tables 150 | """ 151 | 152 | cursor.execute(sql) 153 | 154 | return cursor 155 | 156 | @database_command 157 | def calls(cursor): 158 | if pg_stat_statement_available(cursor): 159 | sql = """ 160 | SELECT query AS qry, 161 | interval '1 millisecond' * total_time AS exec_time, 162 | to_char((total_time/sum(total_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, 163 | to_char(calls, 'FM999G999G990') AS ncalls, 164 | interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time 165 | FROM pg_stat_statements WHERE userid = (SELECT usesysid FROM pg_user WHERE usename = current_user LIMIT 1) 166 | ORDER BY calls DESC LIMIT 10 167 | """ 168 | cursor.execute(sql) 169 | 170 | return cursor 171 | else: 172 | click.echo("pg_stat_statements extension need to be installed in the public schema first.") 173 | click.echo("This extension is only available on Postgres versions 9.2 or greater. You can install it by running:") 174 | click.echo("\n\tCREATE EXTENSION pg_stat_statements;\n\n") 175 | 176 | @database_command 177 | def index_usage(cursor): 178 | sql = """ 179 | SELECT relname, 180 | CASE idx_scan 181 | WHEN 0 THEN 'Insufficient data' 182 | ELSE (100 * idx_scan / (seq_scan + idx_scan))::text 183 | END percent_of_times_index_used 184 | FROM pg_stat_user_tables 185 | ORDER BY percent_of_times_index_used ASC 186 | """ 187 | 188 | cursor.execute(sql) 189 | 190 | return cursor 191 | 192 | @database_command 193 | def locks(cursor): 194 | sql = """ 195 | SELECT pg_stat_activity.pid, pg_class.relname, pg_locks.transactionid, 196 | pg_locks.granted, pg_stat_activity.query AS query_snippet, 197 | age(now(),pg_stat_activity.query_start) AS "age" 198 | FROM pg_stat_activity,pg_locks 199 | LEFT OUTER JOIN pg_class ON (pg_locks.relation = pg_class.oid) 200 | WHERE pg_stat_activity.query <> '' 201 | AND pg_locks.pid = pg_stat_activity.pid 202 | AND pg_locks.mode = 'ExclusiveLock' 203 | AND pg_stat_activity.pid <> pg_backend_pid() order by query_start 204 | """ 205 | 206 | cursor.execute(sql) 207 | 208 | return cursor 209 | 210 | @database_command 211 | def long_running_queries(cursor): 212 | sql = """ 213 | SELECT 214 | pid, now() - pg_stat_activity.query_start AS duration, query 215 | FROM 216 | pg_stat_activity 217 | WHERE pg_stat_activity.query <> ''::text 218 | AND state <> 'idle' 219 | AND now() - pg_stat_activity.query_start > interval '5 minutes' 220 | ORDER BY now() - pg_stat_activity.query_start DESC 221 | """ 222 | 223 | cursor.execute(sql) 224 | 225 | return cursor 226 | 227 | @database_command 228 | def outliers(cursor): 229 | if pg_stat_statement_available(cursor): 230 | sql = """ 231 | SELECT interval '1 millisecond' * total_time AS total_exec_time, 232 | to_char((total_time/sum(total_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, 233 | to_char(calls, 'FM999G999G999G990') AS ncalls, 234 | interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time, query 235 | FROM pg_stat_statements 236 | WHERE userid = (SELECT usesysid FROM pg_user WHERE usename = current_user LIMIT 1) 237 | ORDER BY total_time DESC LIMIT 10 238 | """ 239 | 240 | cursor.execute(sql) 241 | 242 | return cursor 243 | else: 244 | click.echo("pg_stat_statements extension need to be installed in the public schema first.") 245 | click.echo("This extension is only available on Postgres versions 9.2 or greater. You can install it by running:") 246 | click.echo("\n\tCREATE EXTENSION pg_stat_statements;\n\n") 247 | 248 | @database_command 249 | def ps(cursor): 250 | sql = """ 251 | SELECT pid, state, application_name AS source, 252 | age(now(),xact_start) AS running_for, waiting, query 253 | FROM pg_stat_activity 254 | WHERE query <> '' AND state <> 'idle' 255 | AND pid <> pg_backend_pid() 256 | ORDER BY query_start DESC 257 | """ 258 | 259 | cursor.execute(sql) 260 | 261 | return cursor 262 | 263 | @database_command 264 | def records_rank(cursor): 265 | sql = """ 266 | SELECT relname AS name, n_live_tup AS estimated_count 267 | FROM pg_stat_user_tables 268 | ORDER BY n_live_tup DESC 269 | """ 270 | 271 | cursor.execute(sql) 272 | 273 | return cursor 274 | 275 | @database_command 276 | def seq_scans(cursor): 277 | sql = """ 278 | SELECT relname AS name, seq_scan as count 279 | FROM pg_stat_user_tables 280 | ORDER BY seq_scan DESC 281 | """ 282 | 283 | cursor.execute(sql) 284 | 285 | return cursor 286 | 287 | @database_command 288 | def table_size(cursor): 289 | sql = """ 290 | SELECT c.relname AS name, 291 | pg_size_pretty(pg_table_size(c.oid)) AS size 292 | FROM pg_class c 293 | LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) 294 | WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') 295 | AND n.nspname !~ '^pg_toast' 296 | AND c.relkind='r' 297 | ORDER BY pg_table_size(c.oid) DESC 298 | """ 299 | 300 | cursor.execute(sql) 301 | 302 | return cursor 303 | 304 | @database_command 305 | def total_table_size(cursor): 306 | sql = """ 307 | SELECT c.relname AS name, 308 | pg_size_pretty(pg_total_relation_size(c.oid)) AS size 309 | FROM pg_class c 310 | LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) 311 | WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') 312 | AND n.nspname !~ '^pg_toast' 313 | AND c.relkind='r' 314 | ORDER BY pg_total_relation_size(c.oid) DESC 315 | """ 316 | 317 | cursor.execute(sql) 318 | 319 | return cursor 320 | 321 | @database_command 322 | def unused_indexes(cursor): 323 | sql = """ 324 | SELECT schemaname || '.' || relname AS table, indexrelname AS index, 325 | pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, 326 | idx_scan as index_scans 327 | FROM pg_stat_user_indexes ui 328 | JOIN pg_index i ON ui.indexrelid = i.indexrelid 329 | WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 330 | ORDER BY 331 | pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, 332 | pg_relation_size(i.indexrelid) DESC 333 | """ 334 | 335 | cursor.execute(sql) 336 | 337 | return cursor 338 | 339 | @click.group() 340 | @click.pass_context 341 | @click.argument('database_url') 342 | def cli(ctx, database_url): 343 | ctx.obj = database_url 344 | 345 | cli.add_command(index_sizes) 346 | cli.add_command(bloat) 347 | cli.add_command(blocking) 348 | cli.add_command(cache_hit) 349 | cli.add_command(calls) 350 | cli.add_command(index_usage) 351 | cli.add_command(locks) 352 | cli.add_command(long_running_queries) 353 | cli.add_command(outliers) 354 | cli.add_command(ps) 355 | cli.add_command(records_rank) 356 | cli.add_command(seq_scans) 357 | cli.add_command(table_size) 358 | cli.add_command(total_table_size) 359 | cli.add_command(unused_indexes) 360 | --------------------------------------------------------------------------------