Skip to content

Commit

Permalink
Updates to psqlrc to run queries
Browse files Browse the repository at this point in the history
  • Loading branch information
Collin Peters committed Apr 7, 2015
1 parent da4bc23 commit 3947f30
Showing 1 changed file with 6 additions and 4 deletions.
10 changes: 6 additions & 4 deletions psql/psqlrc.symlink
Expand Up @@ -14,7 +14,12 @@
\pset linestyle unicode
\pset border 2

--helpful queries
--helpful queries. Run with :name in psql/vim(dbext)
-- pgadmin server status queries (9.1)
\set activity 'SELECT p.procpid AS pid, application_name, datname, usename, CASE WHEN client_port=-1 THEN ''local pipe'' WHEN length(client_hostname)>0 THEN client_hostname||'':''||client_port ELSE textin(inet_out(client_addr))||'':''||client_port END AS client, date_trunc(''second'', backend_start) AS backend_start, CASE WHEN current_query='''' OR current_query=''<IDLE>'' THEN '''' ELSE date_trunc(''second'', query_start)::text END AS query_start, date_trunc(''second'', xact_start) AS xact_start, (SELECT min(l1.pid) FROM pg_locks l1 WHERE GRANTED AND (relation IN (SELECT relation FROM pg_locks l2 WHERE l2.pid=p.procpid AND NOT granted) OR transactionid IN (SELECT transactionid FROM pg_locks l3 WHERE l3.pid=p.procpid AND NOT granted))) AS blockedby, current_query AS query, CASE WHEN query_start IS NULL OR current_query LIKE ''<IDLE>%'' THEN false ELSE query_start < now() - ''10 seconds''::interval END AS slowquery FROM pg_stat_activity p ORDER BY 1 ASC;'
\set locks 'SELECT pg_stat_get_backend_pid(svrid) AS pid, (SELECT datname FROM pg_database WHERE oid = pgl.database) AS dbname, coalesce(pgc.relname, pgl.relation::text) AS class, pg_get_userbyid(pg_stat_get_backend_userid(svrid)) as user, pgl.virtualxid::text, pgl.virtualtransaction::text AS transaction, pgl.mode, pgl.granted, date_trunc(''second'', pg_stat_get_backend_activity_start(svrid)) AS query_start, pg_stat_get_backend_activity(svrid) AS query FROM pg_stat_get_backend_idset() svrid, pg_locks pgl LEFT JOIN pg_class pgc ON pgl.relation=pgc.oid WHERE pgl.pid = pg_stat_get_backend_pid(svrid) ORDER BY 1 ASC;'
\set transactions 'SELECT transaction::text, gid, prepared, owner, database FROM pg_prepared_xacts ORDER BY 2 ASC;'

-- note: for pg9.1 (procpid instead of pid, current_query instead of query, etc...)
\set uptime 'select now() - backend_start as uptime from pg_stat_activity where procpid = pg_backend_pid();'
\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;'
Expand All @@ -33,7 +38,6 @@
\set rtsize '(select table_schema, table_name, pg_relation_size( quote_ident( table_schema ) || \'.\' || quote_ident( table_name ) ) as 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)'
\set tsize '(select table_schema, table_name, pg_size_pretty(size) as 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)'


-- Taken from https://github.com/heroku/heroku-pg-extras
-- via https://github.com/dlamotte/dotfiles/blob/master/psqlrc
\set bloat 'SELECT tablename as table_name, ROUND(CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages/otta::numeric END,1) AS table_bloat, CASE WHEN relpages < otta THEN ''0'' ELSE pg_size_pretty((bs*(sml.relpages-otta)::bigint)::bigint) END AS table_waste, iname as index_name, ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS index_bloat, CASE WHEN ipages < iotta THEN ''0'' ELSE pg_size_pretty((bs*(ipages-iotta))::bigint) END AS index_waste FROM ( SELECT schemaname, tablename, cc.reltuples, cc.relpages, bs, CEIL((cc.reltuples*((datahdr+ma- (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta, COALESCE(c2.relname,''?'') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta FROM ( SELECT ma,bs,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 ( SELECT schemaname, tablename, hdr, ma, bs, SUM((1-null_frac)*avg_width) AS datawidth, MAX(null_frac) AS maxfracsum, hdr+( SELECT 1+count(*)/8 FROM pg_stats s2 WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename) AS nullhdr FROM pg_stats s, ( SELECT (SELECT current_setting(''block_size'')::numeric) AS bs, CASE WHEN substring(v,12,3) IN (''8.0'',''8.1'',''8.2'') THEN 27 ELSE 23 END AS hdr, CASE WHEN v ~ ''mingw32'' THEN 8 ELSE 4 END AS ma FROM (SELECT version() AS v) AS foo) AS constants GROUP BY 1,2,3,4,5) AS foo) AS rs JOIN pg_class cc ON cc.relname = rs.tablename JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname AND nn.nspname <> ''information_schema'' LEFT JOIN pg_index i ON indrelid = cc.oid LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid) AS sml ORDER BY CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::bigint END DESC;'
Expand All @@ -51,7 +55,5 @@
\set missing_indexes 'SELECT relname, seq_scan-idx_scan AS too_much_seq, case when seq_scan-idx_scan > 0 THEN ''Missing Index?'' ELSE ''OK'' END, pg_relation_size(relname::regclass) AS rel_size, seq_scan, idx_scan FROM pg_stat_all_tables WHERE schemaname=''public'' AND pg_relation_size(relname::regclass) > 80000 ORDER BY too_much_seq DESC;'

-- Development queries

\set sp 'SHOW search_path;'

\set slaves 'select application_name, pg_xlog_location_diff(sent_location, flush_location) as replay_delta, sync_priority, sync_state from pg_stat_replication;'

0 comments on commit 3947f30

Please sign in to comment.