You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

323 lines
14 KiB
Plaintext

5 years ago
--
-- Author: Hari Sekhon
-- Date: 2020-03-16 10:14:28 +0000 (Mon, 16 Mar 2020)
--
4 years ago
-- vim:ts=4:sts=4:sw=4:et:filetype=sql
--
5 years ago
-- 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
--
4 years ago
-- ========================================================================== --
4 years ago
-- 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
4 years ago
-- ========================================================================== --
4 years ago
-- See also:
--
-- https://github.com/HariSekhon/SQL-scripts
4 years ago
-- PSQL docs:
--
-- https://www.postgresql.org/docs/12/app-psql.html
4 years ago
--\! echo; echo .psqlrc loaded; echo
\echo
\echo .psqlrc loaded
\echo
4 years ago
4 years ago
--\set QUIET ON
-- then later set
--\set QUIET OFF
4 years ago
-- ========================================================================== --
-- P r o m p t
-- ========================================================================== --
4 years ago
-- %M fqdn
-- %m hostname / local for socket
-- %> port
4 years ago
-- %n username
-- %x transaction status - * in transaction, ! when transaction failed, ? when indeterminate
4 years ago
-- %/ current database
-- %~ like %/ but ~ for default database
-- %R = for connected
-- ! for disconnected
-- ^ for single line mode
-- %# '#' if superuser, '>' otherwise
--
-- %:myvar: replaced with variable myvar
4 years ago
-- %`command` output of shell command
4 years ago
-- %[%...%] terminal colour control sequences
4 years ago
------------------
-- default prompt:
--
-- db=#
--\set PROMPT1 '%/%R%# '
---------------------------
4 years ago
-- fancy prompt colorized:
-- time hostname serverhost/local user transaction database = #
4 years ago
\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%# '
4 years ago
-------------------------------------------------------------
4 years ago
-- fancy prompt non-colorized (for PostgreSQL 9.0 - 9.2 environments where colors aren't working - probably a term/env issue):
4 years ago
--
4 years ago
--\set PROMPT1 '%`date "+%T"` %`hostname -s` %m:%n %x>%/%R%# '
-------------------------------
4 years ago
\set PROMPT2 '[continue] %R > '
4 years ago
4 years ago
-- ========================================================================== --
4 years ago
4 years ago
-- 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
4 years ago
-- number of EOF (ctrl-D) to ignore before terminating
\set IGNOREEOF 0
4 years ago
-- tab-complete SQL keywords to uppercase
\set COMP_KEYWORD_CASE upper
4 years ago
-- 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
4 years ago
-- display NULLs literally instead of as blanks which is confusing
\pset null 'NULL'
4 years ago
-- ascii art tables
\pset border 2
4 years ago
-- ========================================================================== --
4 years ago
4 years ago
-- set to 'off' if inside a terminal multiplexer (screen, tmux)
4 years ago
--\pset pager on
4 years ago
-- leave wrapping to inherit \$COLUMNS
--\pset columns 80
-- enforce vertical results instead of horizontal columns (default: auto - vertical when width > columns)
4 years ago
--\x auto
--\pset expanded auto
4 years ago
-- 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
4 years ago
-- ========================================================================== --
4 years ago
4 years ago
-- 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
4 years ago
-- display context messages from the server - always, errors (default) or never
--\set SHOW_CONTEXT errors
4 years ago
-- debug SQL errors: default, verbose or terse
4 years ago
--\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'
5 years ago
4 years ago
---------------------------------
5 years ago
-- enable timings for every query
4 years ago
\timing on
5 years ago
4 years ago
-- \! echo
\echo
4 years ago
---------
4 years ago
-- doesn't work on PostgreSQL < 9.1, but doesn't error out so it's fine
4 years ago
\conninfo
--\! echo
\echo
4 years ago
-- 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;
--
4 years ago
-- single quote the value to treat as an SQL literal :'select'
-- double quote the value to treat as a SQL identifier :"tablename"
4 years ago
-- ========================================================================== --
-- Q u e r y A l i a s e s
-- ========================================================================== --
4 years ago
-- can use be encased in single quotes. otherwise syntax error at the first double quote
4 years ago
\echo 'Query Aliases & Shortcuts:'
\echo
4 years ago
4 years ago
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_backends_per_database.sql
\echo '\t' ':backends' '\t' 'Show 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' 'Show 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' 'Show running queries'
\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;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_locks.sql
\echo '\t' ':locks' '\t' 'Show 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_tables_row_estimates.sql
\echo '\t' ':rowcounts' '\t' 'Show 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' 'Show 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' 'Show sessions (9.2+)'
\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;'
-- 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' ':sessioncounts ' 'Show session counts (grouped by state desc)'
\set sessioncounts 'SELECT count(1), state FROM pg_stat_activity GROUP BY state ORDER BY 1 DESC;'
-- https://github.com/HariSekhon/SQL-scripts/blob/master/postgres_tables_by_size.sql
\echo '\t' ':tables' '\t' 'Show 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' 'Show 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' 'Show 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' 'Show 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' 'Show 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' 'Show 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' 'Show 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' 'Show 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' 'Print PostgreSQL settings (running + from config file)'
\set settings 'SELECT name, setting, unit, context FROM pg_settings; select * from pg_file_settings;'
4 years ago
\echo '\t' ':uptime' '\t' 'Print postmaster uptime in seconds'
\set uptime 'select date_trunc(\'second\', current_timestamp - pg_postmaster_start_time() ) as uptime;'
4 years ago
\echo
4 years ago
\echo '\t' ':ls' '\t\t' 'Lists files in $PWD'
\echo '\t' ':ll' '\t\t' 'Lists files in $PWD with timestamps'
\echo '\t' ':lt' '\t\t' 'Lists files in $PWD by timestamps ascending'
\set ls '\\! ls;'
\set ll '\\! ls -l;'
\set lt '\\! ls -ltr;'
4 years ago
\echo
\echo '\t' ':help' '\t\t' 'Reload ~/.psqlrc (which prints this helps)'
\set help '\\i ~/.psqlrc'
4 years ago
\echo '\t' ':reload' '\t' 'Reload ~/.psqlrc'
4 years ago
\set reload '\\i ~/.psqlrc'
\echo '\t' ':r' '\t\t' 'Reload ~/.psqlrc'
\set r '\\i ~/.psqlrc'
4 years ago
\echo
4 years ago
\echo 'Many more excellent PostgreSQL queries are available at:'
4 years ago
\echo
\echo '\t' 'https://github.com/HariSekhon/SQL-scripts'
\echo
\echo