forked from HariSekhon/DevOps-Bash-tools
-
Notifications
You must be signed in to change notification settings - Fork 0
/
.psqlrc
executable file
·341 lines (254 loc) · 15.1 KB
/
.psqlrc
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
--
-- Author: Hari Sekhon
-- Date: 2020-03-16 10:14:28 +0000 (Mon, 16 Mar 2020)
--
-- vim:ts=4:sts=4:sw=4:et:filetype=sql
--
-- https://github.com/harisekhon/bash-tools
--
-- License: see accompanying Hari Sekhon LICENSE file
--
-- If you're using my code you're welcome to connect with me on LinkedIn and optionally send me feedback to help steer this or other code I publish
--
-- https://www.linkedin.com/in/harisekhon
--
-- ========================================================================== --
-- A d v a n c e d P o s t g r e S Q L U s e r C o n f i g
-- ========================================================================== --
-- See also:
--
-- https://github.com/HariSekhon/SQL-scripts
-- PSQL docs:
--
-- https://www.postgresql.org/docs/12/app-psql.html
--\! echo; echo .psqlrc loaded; echo
\echo
\echo '.psqlrc loaded'
\echo
--\set QUIET ON
-- then later set
--\set QUIET OFF
-- ========================================================================== --
-- P r o m p t
-- ========================================================================== --
-- %M fqdn
-- %m hostname / local for socket
-- %> port
-- %n username
-- %x transaction status - * in transaction, ! when transaction failed, ? when indeterminate
-- %/ current database
-- %~ like %/ but ~ for default database
-- %R = for connected
-- ! for disconnected
-- ^ for single line mode
-- %# '#' if superuser, '>' otherwise
--
-- %:myvar: replaced with variable myvar
-- %`command` output of shell command
-- %[%...%] terminal colour control sequences
------------------
-- default prompt:
--
-- db=#
--\set PROMPT1 '%/%R%# '
---------------------------
-- fancy prompt colorized:
-- time hostname serverhost/local user transaction database = #
\set PROMPT1 '%[%033[32m%]%`date "+%T"` %`hostname -s` %[%033[35;1m%]%m:%[%033[36;1m%]%n %[%033[33;1m%]%x%[%033[;1m%]>%/%[%033[0m%]%R%# '
-------------------------------------------------------------
-- fancy prompt non-colorized (for PostgreSQL 9.0 - 9.2 environments where colors aren't working - probably a term/env issue):
--
--\set PROMPT1 '%`date "+%T"` %`hostname -s` %m:%n %x>%/%R%# '
-------------------------------
\set PROMPT2 '[continue] %R > '
-- ========================================================================== --
-- jump to your SQL scripts directory (this is done in postgres.sh)
--\cd ~/github/sql
-- separate history files per DB
\set HISTFILE ~/.psql_history- :DBNAME
-- default: 500
\set HISTSIZE 5000
-- same as in Bash, don't record duplicate commands
\set HISTCONTROL ignoredups
-- number of EOF (ctrl-D) to ignore before terminating
\set IGNOREEOF 0
-- tab-complete SQL keywords to uppercase
\set COMP_KEYWORD_CASE upper
-- args:
-- default: none
-- all all input lines are printed
-- queries queries are printed as they are sent to server
-- errors only failed queries are printed
--
-- useful to set in scripts
--\set ECHO queries
-- echo the hidden queries for things like \d
\set ECHO_HIDDEN ON
-- display NULLs literally instead of as blanks which is confusing
\pset null 'NULL'
-- ascii art tables
\pset border 2
-- ========================================================================== --
-- set to 'off' if inside a terminal multiplexer (screen, tmux)
--\pset pager on
-- leave wrapping to inherit \$COLUMNS
--\pset columns 80
-- enforce vertical results instead of horizontal columns (default: auto - vertical when width > columns)
--\x auto
--\pset expanded auto
-- replace | with \t or , to create TSV/CSV output
--\pset fieldsep
-- don't align columns for human readability (use when creating TSV/CSV output), default is 'aligned'
--\pset unaligned
-- line separator for unaligned output (default: \n)
--\pset recordsep
-- show (N row) count after each query
\pset footer on
-- show the encoding
\! printf "Encoding: "
\encoding
-- ========================================================================== --
-- interactively disables transaction rollbacks to fix things interactively, change of default behaviour might confuse though
--\set ON_ERROR_ROLLBACK interactive
-- exit SQL script or return to interactive prompt upon first error - use this in production scripts
--\set ON_ERROR_STOP on
-- same as -s / --single-step - use this to debug SQL scripts by prompting between executing each line
--\set SINGLESTEP on
-- same as -S / --single-line - use newlines as SQL statement terminators so you don't need semicolons
--\set SINGLELINE on
-- display context messages from the server - always, errors (default) or never
--\set SHOW_CONTEXT errors
-- debug SQL errors: default, verbose or terse
--\set VERBOSITY verbose
-- run after an error to get print the last error in verbose format as though VERBOSITY verbose was always set
--\errverbose
-- shortcut alias
\set eav 'EXPLAIN ANALYZE VERBOSE'
---------------------------------
-- enable timings for every query
\timing on
-- \! echo
\echo
---------
-- doesn't work on PostgreSQL < 9.1, but doesn't error out so it's fine
\conninfo
--\! echo
\echo
-- for local settings
-- XXX: see if there is a way to check for existence and source only then
--\i ~/.psqlrc.local
-- =========
-- Variables
--
-- \set myvar literal
--
-- call like
--
-- :myvar
--
-- or interpolate them into queries eg.
--
-- SELECT * FROM :tablename;
--
-- single quote the value to treat as an SQL literal :'select'
-- double quote the value to treat as a SQL identifier :"tablename"
-- ========================================================================== --
-- Q u e r y A l i a s e s
-- ========================================================================== --
-- can use be encased in single quotes. otherwise syntax error at the first double quote
\echo 'Query Aliases & Shortcuts:'
\echo
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_backends_per_database.sql
\echo '\t' ':backends' '\t' 'Number of connected backends per database'
\set backends 'SELECT datname,numbackends FROM pg_catalog.pg_stat_database ORDER BY numbackends DESC, datname ASC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_databases_by_size.sql
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_databases_by_size_if_accessible.sql
\echo '\t' ':databases' '\t' 'Databases by size desc (only ones you can access)'
--\set databases 'SELECT datname, pg_size_pretty(pg_database_size(datname)) FROM pg_database ORDER BY pg_database_size(datname) DESC;'
\set databases 'SELECT d.datname AS Name, pg_catalog.pg_get_userbyid(d.datdba) AS Owner, CASE WHEN pg_catalog.has_database_privilege(d.datname, \'CONNECT\') THEN pg_catalog.pg_size_pretty(pg_catalog.pg_database_size(d.datname)) ELSE \'No Access\' END AS SIZE FROM pg_catalog.pg_database d ORDER BY CASE WHEN pg_catalog.has_database_privilege(d.datname, \'CONNECT\') THEN pg_catalog.pg_database_size(d.datname) ELSE NULL END DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_running_queries.sql
\echo '\t' ':queries' '\t' 'Running queries and their age'
--\set queries 'SELECT pid, age(clock_timestamp(), query_start), usename, application_name, query FROM pg_stat_activity WHERE state != \'idle\' AND query NOT ILIKE \'%pg_stat_activity%\' ORDER BY query_start DESC;'
\set queries 'SELECT pid, age(clock_timestamp(), query_start), datname, usename, application_name, query FROM pg_stat_activity WHERE state != \'idle\' ORDER BY query_start DESC;'
\echo '\t' ':activity' '\t' 'All clients and queries'
\set activity 'select pid, datname, usename, application_name,client_addr, client_hostname, client_port, query, state from pg_stat_activity;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_locks.sql
\echo '\t' ':locks' '\t' 'Locks'
\set locks 'SELECT t.schemaname, t.relname, l.locktype, page, virtualtransaction, pid, mode, granted FROM pg_locks l, pg_stat_all_tables t WHERE l.relation = t.relid ORDER BY relation ASC; SELECT relation::regclass AS relation_regclass, * FROM pg_locks WHERE NOT granted;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_locks_blocked.sql
-- https://opensourcedbms.com/dbms/psqlrc-psql-startup-file-for-postgres/
\echo '\t' ':blocked' '\t' 'Blocked locks'
\set blocked 'SELECT bl.pid AS blocked_pid, a.usename AS blocked_user, kl.pid AS blocking_pid, ka.usename AS blocking_user, a.query AS blocked_statement FROM pg_catalog.pg_locks bl JOIN pg_catalog.pg_stat_activity a ON bl.pid = a.pid JOIN pg_catalog.pg_locks kl JOIN pg_catalog.pg_stat_activity ka ON kl.pid = ka.pid ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid WHERE NOT bl.granted;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_tables_row_estimates.sql
\echo '\t' ':rowcounts' '\t' 'Row count estimates per table'
\set rowcounts 'SELECT schemaname, relname, n_live_tup FROM pg_stat_user_tables ORDER BY n_live_tup DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_queries_slow.sql
\echo '\t' ':slowqueries' '\t' 'Slow queries (runtime > 30 secs)'
\set slowqueries 'SELECT now() - query_start as "runtime", usename, datname, wait_event, state, query FROM pg_stat_activity WHERE now() - query_start > \'30 seconds\'::interval ORDER BY runtime DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_sessions.sql
\echo '\t' ':sessions' '\t' 'Sessions (9.2+)'
-- backend_type requires PostgreSQL 10+
--\set sessions 'SELECT pid, usename, client_addr, client_hostname, client_port, backend_start, query_start, state, backend_type FROM pg_stat_activity ORDER BY backend_type;'
\set sessions 'SELECT pid, usename, client_addr, client_hostname, client_port, backend_start, query_start, state FROM pg_stat_activity;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_session_state_count.sql
-- using extra space because the tab pushes description to the next tab stop and misaligns help
\echo '\t' ':sessionstates ' 'Session counts grouped by state'
\set sessionstates 'SELECT count(1), state FROM pg_stat_activity GROUP BY state ORDER BY 1 DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_session_state_count.sql
\echo '\t' ':sessionusers' '\t' 'Session counts grouped by user'
\set sessionusers 'SELECT count(1), usename FROM pg_stat_activity GROUP BY usename ORDER BY 1 DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_tables_by_size.sql
\echo '\t' ':tables' '\t' 'Tables by size ascending'
\set tables 'SELECT nspname, relname, pg_size_pretty(pg_total_relation_size(C.oid)) AS total_size FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) WHERE nspname NOT IN (\'pg_catalog\', \'information_schema\') AND C.relkind <> \'i\' AND nspname !~ \'^pg_toast\' ORDER BY pg_total_relation_size(C.oid) DESC;'
\echo
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_query_cache_hit_ratio.sql
\echo '\t' ':qryhits' '\t' 'Query cache-hit ratio desc'
\set qryhits 'CREATE EXTENSION IF NOT EXISTS pg_stat_statements; SELECT calls, rows, shared_blks_hit, shared_blks_read, shared_blks_hit / GREATEST(shared_blks_hit + shared_blks_read, 1)::float AS shared_blks_hit_ratio, local_blks_hit, local_blks_read, local_blks_hit / GREATEST(local_blks_hit + local_blks_read, 1)::float AS local_blks_hit_ratio, query FROM pg_stat_statements ORDER BY shared_blks_hit_ratio DESC, local_blks_hit_ratio DESC, rows DESC LIMIT 100;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_indexes_cache_hit_ratio.sql
\echo '\t' ':idxhits' '\t' 'Index cache-hit ratio'
\set idxhits 'SELECT SUM(idx_blks_read) AS idx_blks_read, SUM(idx_blks_hit) AS idx_blks_hit, SUM(idx_blks_hit) / GREATEST(SUM(idx_blks_hit) + SUM(idx_blks_read), 1)::float AS ratio FROM pg_statio_user_indexes;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_tables_cache_hit_ratio.sql
\echo '\t' ':tblhits' '\t' 'Table cache-hit ratio'
\set tblhits 'SELECT SUM(heap_blks_read) AS heap_blks_read, SUM(heap_blks_hit) AS heap_blks_hit, SUM(heap_blks_hit) / GREATEST(SUM(heap_blks_hit) + SUM(heap_blks_read), 1)::float AS ratio FROM pg_statio_user_tables;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_tables_index_usage.sql
\echo '\t' ':tblidxuse' '\t' 'Table index usage % desc'
\set tblidxuse 'SELECT relname AS table, idx_scan / GREATEST(seq_scan + idx_scan, 1) * 100 AS percent_of_times_index_used, n_live_tup AS rows_in_table FROM pg_stat_user_tables WHERE seq_scan + idx_scan > 0 ORDER BY rows_in_table DESC, percent_of_times_index_used DESC;'
\echo
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_last_analyze.sql
\echo '\t' ':analyzed' '\t' 'Last analyzed stats (9.3+)'
\set analyzed 'SELECT schemaname, relname, n_mod_since_analyze, last_analyze, last_autoanalyze, analyze_count, autoanalyze_count FROM pg_stat_user_tables ORDER BY n_mod_since_analyze DESC, last_analyze DESC, last_autoanalyze DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_last_vacuum.sql
\echo '\t' ':vacuumed' '\t' 'Last vaccumed stats (9.1+)'
\set vacuumed 'SELECT schemaname, relname, n_live_tup, n_dead_tup, n_dead_tup / GREATEST(n_live_tup + n_dead_tup, 1)::float * 100 AS dead_percentage, last_vacuum, last_autovacuum, vacuum_count, autovacuum_count FROM pg_stat_user_tables WHERE n_dead_tup > 0 ORDER BY n_dead_tup DESC, last_vacuum DESC, last_autovacuum DESC;'
\echo
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_dirs.sql
\echo '\t' ':dirs' '\t\t' 'PostgreSQL config files, data and socket directory locations'
\set dirs 'SELECT current_setting(\'config_file\') AS "config_file", current_setting(\'hba_file\') AS "hba_file", current_setting(\'ident_file\') AS "ident_file"; SELECT current_setting(\'data_directory\') AS "data_directory", current_setting(\'external_pid_file\') AS "external_pid_file"; SELECT current_setting(\'unix_socket_directories\') AS "unix_socket_directories", current_setting(\'unix_socket_permissions\') AS "unix_socket_permissions", current_setting(\'unix_socket_group\') AS "unix_socket_group";'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_settings.sql
\echo '\t' ':settings' '\t' 'PostgreSQL settings (running + from config file)'
\set settings 'SELECT name, setting, unit, context FROM pg_settings; select * from pg_file_settings;'
\echo '\t' ':uptime' '\t' 'PostgreSQL postmaster uptime in seconds'
\set uptime 'select date_trunc(\'second\', current_timestamp - pg_postmaster_start_time() ) as uptime;'
\echo
\echo '\t' ':ls' '\t\t' 'List files in $PWD'
\echo '\t' ':ll' '\t\t' 'List files in $PWD with timestamps'
\echo '\t' ':lt' '\t\t' 'List files in $PWD by timestamps ascending'
\set ls '\\! ls;'
\set ll '\\! ls -l;'
\set lt '\\! ls -ltr;'
\echo
\echo '\t' ':clear' '\t' 'Clear the screen'
\set clear '\\! clear;'
\echo
\echo '\t' ':help' '\t\t' 'Reload ~/.psqlrc (which prints this helps)'
\set help '\\i ~/.psqlrc'
\echo '\t' ':reload' '\t' 'Reload ~/.psqlrc'
\set reload '\\i ~/.psqlrc'
\echo '\t' ':r' '\t\t' 'Reload ~/.psqlrc'
\set r '\\i ~/.psqlrc'
\echo
\echo 'Many more excellent PostgreSQL queries are available at:'
\echo
\echo '\t' 'https://github.com/HariSekhon/SQL-scripts'
\echo
\echo