├── README.md ├── media ├── db_activity_pgbench.png ├── db_activity_replogical.png ├── db_activity_repstream.png ├── db_activity_vacuumfull.png └── db_information.png └── scripts ├── pg_database_activity.sh ├── pg_database_activity_refresh.sh ├── pg_database_hugepages.sh ├── pg_database_information.sh ├── pg_database_logs.sh ├── pg_database_reload_conf.sh ├── pg_database_start.sh ├── pg_database_status.sh ├── pg_database_stop.sh └── settings.txt /README.md: -------------------------------------------------------------------------------- 1 | ## pg_dba_scripts - PostgreSQL DBA scripts 2 | 3 | A collection of shell scripts for PostgreSQL database administrator (DBA). Tested on PostgreSQL versions 9.6, 10, 11, 12, 13 under CentOS 7, Debian 10 and Ubuntu Server 20.04. 4 | 5 | #### [scripts/pg_database_activity.sh](#pg_database_activity). PostgreSQL monitoring script, all information is displayed on one page. 6 | - Displays PostgreSQL version and status (Master / Replica), hostname and IP address, CPU and Disks load. 7 | - Shows the sizes of the main PostgreSQL directories, archived logs and free disk space, swap usage. 8 | - Displays memory consumption by PostgreSQL processes, statistics on databases, waits and locks, archive and replication statuses. 9 | - When activities occur in PostgreSQL, the progress of operations is displayed: vacuum, vacuum full or cluster, index creation, analyze, pg_basebackup. 10 | - At the end, the last entries of the PostgreSQL log file are displayed. 11 | - For ease of perception, information is displayed in color. 12 | 13 | [scripts/pg_database_activity_refresh.sh](#pg_database_activity). Fast refresh of the **pg_database_activity.sh** script every 5 seconds. 14 | 15 | 16 | #### [scripts/pg_database_information.sh](#pg_database_information). PostgreSQL information script, single tape with the current status of a group of PostgreSQL servers. 17 | The script allows you to quickly find out what the servers are doing and see the exact data for logical replication and external tables. 18 | - Displays server time and lag time, hostname and IP address, PostgreSQL version and status (Master / Replica), data checksums. 19 | - Statistics are also displayed on databases, waits and locks, archive and replication statuses. 20 | - For logical replication, information about publications and subscriptions in the target databases is displayed. 21 | - Displays information about external servers, associated with them by users and tables. 22 | - Blocked sessions and a tree with their locks are displayed, as well as a list of long-running requests. 23 | - When activities occur in PostgreSQL, the progress of operations is displayed: vacuum, vacuum full or cluster, index creation, analyze, pg_basebackup. 24 | 25 | 26 | #### Small scripts to manage PostgreSQL: 27 | - [scripts/pg_database_hugepages.sh](#pg_database_hugepages). Shows free and used memory in the system, Transparent Huge Pages (THP) status, current usage of HugePages and recommended settings for PostgreSQL. 28 | - [scripts/pg_database_start.sh](#pg_database_start). Start PostgreSQL, confirmation is required. 29 | - [scripts/pg_database_stop.sh](#pg_database_stop). Stop PostgreSQL, confirmation is required. 30 | - [scripts/pg_database_status.sh](#pg_database_status). PostgreSQL status. Additionally, PostgreSQL processes and replication services are displayed. 31 | - [scripts/pg_database_reload_conf.sh](#pg_database_reload_conf). Reloads PostgreSQL configuration files (postgresql.conf, postgresql.auto.conf, pg_hba.conf, pg_ident.conf), displays records related to changes from the log file. If the changed parameter requires a restart, its characteristics are displayed. Operation confirmation is required. 32 | - [scripts/pg_database_logs.sh](#pg_database_logs). Shows the PostgreSQL log file with auto-update. The log file is selected automatically. 33 | - [scripts/settings.txt](#Setup). General settings for all scripts. Required before starting work. 34 | 35 | 36 | ## Installation 37 | 38 | As user **postgres**, download the latest version of the scripts collection (see [Releases](https://github.com/Azmodey/pg_dba_scripts/releases) page): 39 | ``` 40 | # sudo su - postgres 41 | $ wget https://github.com/Azmodey/pg_dba_scripts/archive/1.10.0.tar.gz 42 | ``` 43 | 44 | Extract script files to separate directory (for example **~scripts/**) and grant the necessary execution rights: 45 | ``` 46 | $ tar xvzf 1.10.0.tar.gz 47 | $ mv pg_dba_scripts-1.10.0/scripts ~/scripts 48 | $ chmod 700 ~/scripts/*.sh 49 | $ chmod 600 ~/scripts/settings.txt 50 | ``` 51 | 52 | 53 | ## Setup 54 | 55 | Modify file **settings.txt**. Uncomment and correct the entries for your current PostgreSQL version. 56 | ``` 57 | # PostgreSQL version 58 | PG_VER=12 # Supported PostgreSQL versions: 9.6, 10, 11, 12, 13 59 | 60 | 61 | # Red Hat / CentOS 62 | #PG_BIN=/usr/pgsql-$PG_VER/bin # Executables directory (by default, do not change!) 63 | 64 | #PG_DATA=/var/lib/pgsql/$PG_VER/data # Main data directory 65 | #PG_ARC=/var/lib/pgsql/$PG_VER/archive # Archive logs directory 66 | #PG_LOG_DIR=/var/lib/pgsql/$PG_VER/data/log # Directory for log files. For PostgreSQL 9.6 directory is /pg_log 67 | 68 | 69 | # Debian / Ubuntu 70 | #PG_BIN=/usr/lib/postgresql/$PG_VER/bin # Executables directory (by default, do not change!) 71 | 72 | #PG_DATA=/var/lib/postgresql/$PG_VER/data # Main data directory 73 | #PG_ARC=/var/lib/postgresql/$PG_VER/archive # Archive logs directory 74 | #PG_LOG_DIR=/var/lib/postgresql/$PG_VER/data/log # Directory for log files. For PostgreSQL 9.6 directory is /pg_log 75 | ``` 76 | 77 | --- 78 | ### pg_database_activity 79 | 80 | PostgreSQL monitoring script, all information is displayed on one page. Displays PostgreSQL version and status (Master / Replica), hostname and IP address, CPU and Disks load. Shows the sizes of the main PostgreSQL directories, archived logs and free disk space, swap usage. It also displays memory consumption by PostgreSQL processes, statistics on databases, waits and locks, archive and replication statuses. When activities occur in PostgreSQL, the progress of operations is displayed: vacuum, vacuum full or cluster, index creation, analyze, pg_basebackup. At the end, the last entries of the PostgreSQL log file are displayed. For ease of perception, information is displayed in color. 81 | 82 | #### Setup: 83 | 84 | Change the value of the PG_LOG_LINES parameter in the script, which is responsible for displaying the number of last lines of the PosgtreSQL log file. 85 | ``` 86 | PG_LOG_LINES=15 # Number of PostgreSQL log lines to display. 0 - disable output 87 | ``` 88 | 89 | #### Examples of work: 90 | 91 | Running pgbench, 10 backend connections. WALSync wait and Row Exclusive locks. WalSender background processes consumes 19.3% and 24.2% CPU. Total CPU load 6.34 %. 92 | 93 | ![pg_database_activity1](media/db_activity_pgbench.png) 94 | 95 | 96 | Vacuum full command executing with Access Exclusive lock. Replication lag appeared (total_lag 2721) on streaming and logical replication, archiving are not lagging behind (arc_diff 1). The size of Archive logs increased to 1.3 GB. WalSender background processes consumes 13.2% and 16.5% CPU, overall Disk load 9.73 %. The number of PostgreSQL log file entries has automatically decreased. 97 | 98 | ![pg_database_activity2](media/db_activity_vacuumfull.png) 99 | 100 | 101 | Streaming replication to replica server. The server status is highlighted in a separate color, the type of replication (streaming), the slot used (node1_slot) and the lag in replication are shown. 102 | 103 | ![pg_database_activity3](media/db_activity_repstream.png) 104 | 105 | 106 | Logical replication to the master PostgreSQL server 13.1. Subscription name (appdbsub) and replication lag (subscription_lag) are shown. Logical replication worker consumes 1.3% CPU. 107 | 108 | ![pg_database_activity4](media/db_activity_replogical.png) 109 | 110 | 111 | --- 112 | ### pg_database_information 113 | 114 | A script that provides a single tape with the current status of a group of PostgreSQL servers, allowing you to quickly find out what the servers are doing and see the exact data for logical replication and external tables. Server time and lag time, hostname and IP address, PostgreSQL version and status (Master / Replica), data checksums are displayed. It also displays statistics on databases, waits and locks, archive and replication statuses. For logical replication, information about publications and subscriptions in the target databases is displayed. Displays information about external servers, associated users and tables. Blocked sessions and a tree with their locks are displayed, as well as a list of long-running requests. When activities occur in PostgreSQL, the progress of operations is displayed: vacuum, vacuum full or cluster, index creation, analyze, pg_basebackup. 115 | 116 | #### Setup: 117 | 118 | Modify the list of current PostgreSQL hosts in the script, or use the setting only for the local server (localhost). 119 | ``` 120 | # Array of PosgtreSQL servers 121 | declare -a servers_list=("localhost") # Local server 122 | #declare -a servers_list=("pg_server_1" "pg_server_2" "pg_server_3") # Servers list, hostnames. Format: "pg_server_1" "pg_server_2" ... 123 | ``` 124 | 125 | #### Requirements: 126 | 127 | - All PostgreSQL hosts must be network accessible. Check with **ping** command (using three servers as an example): 128 | ``` 129 | $ ping pg_server_1 130 | $ ping pg_server_2 131 | $ ping pg_server_3 132 | ``` 133 | 134 | - The PostgreSQL server must be allowed passwordless user **postgres** access. To do this, create a **~/.pgpass** file from the **postgres** user with the following content, substituting the current password for "password": 135 | ``` 136 | *:*:*:postgres:password 137 | ``` 138 | 139 | - Grant the necessary rights to **~/.pgpass** file 140 | ``` 141 | $ chmod 600 ~/.pgpass 142 | ``` 143 | 144 | - Checking the connection to databases of other PostgreSQL servers: 145 | ``` 146 | $ psql -h pg_server_1 147 | $ psql -h pg_server_2 148 | $ psql -h pg_server_3 149 | ``` 150 | 151 | #### Example: 152 | 153 | A cluster of three PostgreSQL servers. The first server (c7postgresql) runs PostgreSQL 12.5 and is the master for the second server. Logical replication is carried out from it, the publication of appdbpub in the appdb database with a dedicated slot is created. It also has access to external data of the third server, foreign server to host 192.168.1.198, appdb2 database, logs_fs.log_timeline table under the postgres user. The session blocking tree is visible when trying to update the same data. The second server (c7postgresql-1) is a replica, streaming replication from the first server is performed to it. There is a time lag of 2 seconds compared to the first server. The third server (c7postgresql-2) runs on PostgreSQL 13.1 and receives logical replication of the appdb database from the first server, the appdbsub subscription is configured. Two sessions with long running queries are displayed. 154 | 155 | ![pg_database_information1](media/db_information.png) 156 | 157 | 158 | --- 159 | ### pg_database_hugepages 160 | 161 | Shows free and used memory in the system, Transparent Huge Pages (THP) status, current usage of HugePages and recommended settings for PostgreSQL. 162 | 163 | ``` 164 | Free and used memory in the system: 165 | total used free shared buffers cache available 166 | Mem: 3.8G 1.3G 2.2G 12M 23M 291M 2.5G 167 | Swap: 1.9G 0B 1.9G 168 | 169 | ----------------------------------- 170 | Transparent Huge Pages (THP): 171 | On: [always] madvise never 172 | Off: always madvise [never] 173 | 174 | Status: 175 | always madvise [never] 176 | 177 | Tip: disable it 178 | 179 | ----------------------------------- 180 | Current Huge pages: 181 | 182 | AnonHugePages: 0 kB 183 | HugePages_Total: 536 184 | HugePages_Free: 507 185 | HugePages_Rsvd: 382 186 | HugePages_Surp: 0 187 | Hugepagesize: 2048 kB 188 | 189 | ----------------------------------- 190 | Number of Required HugePages: 191 | 192 | Pid: 976 193 | VmPeak: 1095752 kB 194 | Hugepagesize: 2048 kB 195 | Set Huge Pages: 535 196 | ``` 197 | 198 | --- 199 | ### pg_database_start 200 | 201 | Start PostgreSQL, confirmation is required. 202 | 203 | ``` 204 | Start PostgreSQL (Y/N)? y 205 | waiting for server to start....2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: starting PostgreSQL 12.5 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.8.5 20150623 (Red Hat 4.8.5-39), 64-bit 206 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: listening on IPv4 address "0.0.0.0", port 5432 207 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: could not create IPv6 socket for address "::": Address family not supported by protocol 208 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: listening on Unix socket "/var/run/postgresql/.s.PGSQL.5432" 209 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: listening on Unix socket "/tmp/.s.PGSQL.5432" 210 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= LOG: redirecting log output to logging collector process 211 | 2021-01-04 13:27:18 MSK [45734]: db=,user=,app=,client= HINT: Future log output will appear in directory "log". 212 | done 213 | server started 214 | ``` 215 | 216 | --- 217 | ### pg_database_stop 218 | 219 | Stop PostgreSQL, confirmation is required. 220 | 221 | ``` 222 | Stop PostgreSQL (Y/N)? y 223 | waiting for server to shut down.... done 224 | server stopped 225 | ``` 226 | 227 | --- 228 | ### pg_database_status 229 | 230 | PostgreSQL status. Additionally, PostgreSQL processes and replication services are displayed. 231 | 232 | ``` 233 | PostgreSQL processes: 234 | UID PID PPID C STIME TTY TIME CMD 235 | postgres 1030 1 0 17:29 ? 00:00:01 /usr/pgsql-12/bin/postmaster -D /var/lib/pgsql/12/data/ 236 | postgres 1101 1030 0 17:29 ? 00:00:00 \_ postgres: logger 237 | postgres 1105 1030 0 17:29 ? 00:00:00 \_ postgres: checkpointer 238 | postgres 1106 1030 0 17:29 ? 00:00:00 \_ postgres: background writer 239 | postgres 1107 1030 0 17:29 ? 00:00:00 \_ postgres: walwriter 240 | postgres 1108 1030 0 17:29 ? 00:00:00 \_ postgres: autovacuum launcher 241 | postgres 1109 1030 0 17:29 ? 00:00:00 \_ postgres: archiver 242 | postgres 1110 1030 0 17:29 ? 00:00:00 \_ postgres: stats collector 243 | postgres 1111 1030 0 17:29 ? 00:00:00 \_ postgres: logical replication launcher 244 | postgres 1375 1030 0 17:30 ? 00:00:00 \_ postgres: walsender rep_user 192.168.1.197(49190) streaming 6/67241080 245 | postgres 10636 1030 0 18:05 ? 00:00:00 \_ postgres: walsender postgres 192.168.1.198(53956) idle 246 | 247 | PostgreSQL network connection: 248 | (Not all processes could be identified, non-owned process info 249 | will not be shown, you would have to be root to see it all.) 250 | Proto Recv-Q Send-Q Local Address Foreign Address State PID/Program name 251 | tcp 0 0 0.0.0.0:5432 0.0.0.0:* LISTEN 1030/postmaster 252 | 253 | PostgreSQL status: 254 | pg_ctl: server is running (PID: 1030) 255 | /usr/pgsql-12/bin/postgres "-D" "/var/lib/pgsql/12/data/" 256 | 257 | PostgreSQL replication service (sender). Works on Master server: 258 | UID PID PPID C STIME TTY TIME CMD 259 | postgres 1375 1030 0 17:30 ? 00:00:00 postgres: walsender rep_user 192.168.1.197(49190) streaming 6/67241080 260 | postgres 10636 1030 0 18:05 ? 00:00:00 postgres: walsender postgres 192.168.1.198(53956) idle 261 | 262 | PostgreSQL replication service (receiver). Works on Replica server: 263 | UID PID PPID C STIME TTY TIME CMD 264 | 265 | PostgreSQL logical replication service (worker). Works on Replica server: 266 | UID PID PPID C STIME TTY TIME CMD 267 | ``` 268 | 269 | --- 270 | ### pg_database_reload_conf 271 | 272 | Reloads PostgreSQL configuration files (postgresql.conf, postgresql.auto.conf, pg_hba.conf, pg_ident.conf), displays records related to changes from the log file. If the changed parameter requires a restart, its characteristics are displayed. Operation confirmation is required. 273 | 274 | ``` 275 | Reload PostgreSQL configuration (Y/N)? y 276 | server signaled 277 | 278 | PostgreSQL log: /var/lib/pgsql/12/data/log/postgresql-2021-01.log 279 | 2021-01-04 13:29:00 MSK [45734]: db=,user=,app=,client= LOG: received SIGHUP, reloading configuration files 280 | 2021-01-04 13:29:00 MSK [45734]: db=,user=,app=,client= LOG: parameter "wal_level" cannot be changed without restarting the server 281 | 2021-01-04 13:29:00 MSK [45734]: db=,user=,app=,client= LOG: configuration file "/var/lib/pgsql/12/data/postgresql.conf" contains errors; unaffected changes were applied 282 | 283 | Pending restart parameters: 284 | -[ RECORD 1 ]---+------------------------------------------------- 285 | name | wal_level 286 | setting | replica 287 | unit | 288 | category | Write-Ahead Log / Settings 289 | short_desc | Set the level of information written to the WAL. 290 | extra_desc | 291 | context | postmaster 292 | vartype | enum 293 | source | configuration file 294 | min_val | 295 | max_val | 296 | enumvals | {minimal,replica,logical} 297 | boot_val | replica 298 | reset_val | replica 299 | sourcefile | /var/lib/pgsql/12/data/postgresql.conf 300 | sourceline | 194 301 | pending_restart | t 302 | ``` 303 | 304 | --- 305 | ### pg_database_logs 306 | 307 | Shows the PosgreSQL log file with auto-update. The log file is selected automatically. 308 | 309 | ``` 310 | PostgreSQL log: /var/lib/pgsql/12/data/log/postgresql-2021-01.log 311 | 2021-01-04 13:31:27 MSK [47339]: db=,user=,app=,client= LOG: database system was shut down at 2021-01-04 13:31:24 MSK 312 | 2021-01-04 13:31:27 MSK [47331]: db=,user=,app=,client= LOG: database system is ready to accept connections 313 | 2021-01-04 13:31:29 MSK [47348]: db=[unknown],user=rep_user,app=walreceiver,client=192.168.1.196 LOG: received replication command: IDENTIFY_SYSTEM 314 | 2021-01-04 13:31:29 MSK [47348]: db=[unknown],user=rep_user,app=walreceiver,client=192.168.1.196 LOG: received replication command: START_REPLICATION SLOT "node_a_slot" 5/1F000000 TIMELINE 5 315 | ``` 316 | -------------------------------------------------------------------------------- /media/db_activity_pgbench.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Azmodey/pg_dba_scripts/3ff7a9041e5a6a78a91bb222c962f76e30c1d3ab/media/db_activity_pgbench.png -------------------------------------------------------------------------------- /media/db_activity_replogical.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Azmodey/pg_dba_scripts/3ff7a9041e5a6a78a91bb222c962f76e30c1d3ab/media/db_activity_replogical.png -------------------------------------------------------------------------------- /media/db_activity_repstream.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Azmodey/pg_dba_scripts/3ff7a9041e5a6a78a91bb222c962f76e30c1d3ab/media/db_activity_repstream.png -------------------------------------------------------------------------------- /media/db_activity_vacuumfull.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Azmodey/pg_dba_scripts/3ff7a9041e5a6a78a91bb222c962f76e30c1d3ab/media/db_activity_vacuumfull.png -------------------------------------------------------------------------------- /media/db_information.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Azmodey/pg_dba_scripts/3ff7a9041e5a6a78a91bb222c962f76e30c1d3ab/media/db_information.png -------------------------------------------------------------------------------- /scripts/pg_database_activity.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # Show PostgreSQL database activity, connections memory consumption and more 4 | 5 | source ./settings.txt 6 | 7 | # Settings 8 | PG_LOG_LINES=15 # Number of PostgreSQL log lines to display. 0 - disable output 9 | 10 | PG_LOG_FILENAME=`ls -t $PG_LOG_DIR/postgresql-*.log | head -n1` # newest PostgreSQL log file in log_directory 11 | 12 | 13 | # ------------------------------------------------ 14 | 15 | # System 16 | PLATFORM=`awk -F= '/^NAME/{print $2}' /etc/os-release | tr -d '"'` # Red Hat Enterprise Linux Server / CentOS Linux / Debian GNU/Linux / Ubuntu 17 | 18 | # Title (1st line) 19 | DATE=$(date '+%d.%m.%Y %H:%M:%S') 20 | HOST=`hostname --short` 21 | HOSTIP=`hostname -I | xargs` 22 | UPTIME=`uptime` 23 | UPTIME=${UPTIME#*load average: } 24 | 25 | if [[ $PLATFORM == "Red Hat Enterprise Linux Server" || $PLATFORM == "CentOS Linux" ]]; then 26 | IOSTAT_AWAIT=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 11` 27 | IOSTAT_UTIL=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 15` 28 | fi 29 | if [[ $PLATFORM == "Debian GNU/Linux" ]]; then 30 | IOSTAT_R_AWAIT=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 11 | sed 's/,/./g'` 31 | IOSTAT_W_AWAIT=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 12 | sed 's/,/./g'` 32 | IOSTAT_UTIL=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 17 | sed 's/,/./g'` 33 | 34 | IOSTAT_AWAIT=`awk "BEGIN {print ($IOSTAT_R_AWAIT+$IOSTAT_W_AWAIT)/2}"` 35 | fi 36 | if [[ $PLATFORM == "Ubuntu" ]]; then 37 | IOSTAT_R_AWAIT=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 7 | sed 's/,/./g'` 38 | IOSTAT_W_AWAIT=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 13 | sed 's/,/./g'` 39 | IOSTAT_UTIL=`iostat -d -x -g ALL | grep ALL | tr -s " " | cut -d " " -f 22 | sed 's/,/./g'` 40 | 41 | IOSTAT_AWAIT=`awk "BEGIN {print ($IOSTAT_R_AWAIT+$IOSTAT_W_AWAIT)/2}"` 42 | fi 43 | 44 | POSTGRES_VER=`$PG_BIN/psql -t -c "select version();" | cut -d ' ' -f 3` 45 | POSTGRES_VER_GLOB=`echo $POSTGRES_VER | awk '{print int($0)}'` # Round PostgreSQL version (13.1 = 13) 46 | DB_STATUS=`$PG_BIN/psql -t -c "select pg_is_in_recovery();"` 47 | # echo "Status: ["$DB_STATUS"]" 48 | 49 | if [[ $DB_STATUS == " f" ]]; then 50 | STATUS="${GREENLIGHT}[$HOST ($HOSTIP) / PostgreSQL $POSTGRES_VER / Master]${YELLOW}" 51 | else 52 | STATUS="${PURPLELIGHT}[$HOST ($HOSTIP) / PostgreSQL $POSTGRES_VER / Replica]${YELLOW}" 53 | fi 54 | 55 | 56 | # ------------------------------------------------ 57 | 58 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 59 | 60 | # Backend Processes (Client connections) 61 | pid_clients=`$PG_BIN/psql -t -c "SELECT pid FROM pg_stat_activity where backend_type='client backend' and pid<>pg_backend_pid();"` 62 | 63 | total_clients_mem=0 64 | total_clients_count=0 65 | 66 | for pids in $pid_clients ; do 67 | mem=`ps -q $pids -eo rss | sed 1d` 68 | total_clients_mem=$((total_clients_mem+mem)) 69 | ((total_clients_count++)) 70 | done 71 | 72 | total_clients_mem_mb=$((total_clients_mem/1024)) 73 | 74 | 75 | # Background Processes (Server connections) 76 | pid_server=`$PG_BIN/psql -t -c "SELECT pid FROM pg_stat_activity where backend_type<>'client backend' and pid<>pg_backend_pid();"` 77 | 78 | echo "PID| Database| Username| Application name| Client address| Backend type| Wait event type| Wait event| Memory (KB)| CPU% " > pg_database_activity_tmp.txt 79 | 80 | total_server_mem=0 81 | total_server_count=0 82 | 83 | for pids in $pid_server ; do 84 | mem=`ps -q $pids -eo rss | sed 1d` 85 | cpu=`ps -q $pids -eo pcpu | sed 1d` 86 | 87 | pid_client_info=`$PG_BIN/psql -t -c "SELECT datname as database, usename as username, application_name, client_addr, backend_type, wait_event_type, wait_event FROM pg_stat_activity where pid=$pids;"` 88 | echo "$pids|$pid_client_info|$mem| $cpu" >> pg_database_activity_tmp.txt 89 | 90 | total_server_mem=$((total_server_mem+mem)) 91 | ((total_server_count++)) 92 | done 93 | 94 | total_server_mem_mb=$((total_server_mem/1024)) 95 | 96 | fi 97 | 98 | 99 | # ------------------------------------------------ 100 | 101 | 102 | # Title (1st line) 103 | echo -e "${YELLOW}[$DATE] $STATUS [CPU load (1/5/15 min): $UPTIME] [Disk load: util $IOSTAT_UTIL %, await $IOSTAT_AWAIT ms] ${NC}" 104 | 105 | 106 | 107 | # Title (2nd line). Disk usage & free 108 | DIR_DATA_FREE=`df -h $PG_DATA | sed 1d | grep -v used | awk '{ print $4 "\t" }' | tr -d '\t'` # free disk space for PG_DATA 109 | DIR_ARC_FREE=`df -h $PG_ARC | sed 1d | grep -v used | awk '{ print $4 "\t" }' | tr -d '\t'` # free disk space for PG_ARC 110 | DIR_BASE_SIZE=`du -sh $PG_DATA/base | awk '{print $1}'` # Base folder size 111 | 112 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 113 | DIR_WAL_SIZE=`du -sh $PG_DATA/pg_wal | awk '{print $1}'` # WAL folder size 114 | WAL_STR="pg_wal $DIR_WAL_SIZE" 115 | else 116 | DIR_WAL_SIZE=`du -sh $PG_DATA/pg_xlog | awk '{print $1}'` # WAL folder size (PostgreSQL 9.6) 117 | WAL_STR="pg_xlog $DIR_WAL_SIZE" 118 | fi 119 | 120 | DIR_ARC_SIZE=`du -sh $PG_ARC | awk '{print $1}'` # Archive logs folder size 121 | SWAP_USED=`free | grep Swap | awk '{ print $3 "\t" }' | tr -d '\t'` 122 | 123 | echo -e "${GREENLIGHT}Disk${NC} | ${GREENLIGHT}PGDATA${NC} ${UNDERLINE}$PG_DATA${NC} / base $DIR_BASE_SIZE / $WAL_STR / ${CYANLIGHT}disk free $DIR_DATA_FREE${NC} | ${GREENLIGHT}Archive logs${NC} ${UNDERLINE}$PG_ARC${NC} / size $DIR_ARC_SIZE / ${CYANLIGHT}disk free $DIR_ARC_FREE ${NC}| ${GREENLIGHT}Swap used:${NC} ${CYANLIGHT}$SWAP_USED${NC}" 124 | 125 | 126 | 127 | # Title (3rd line). Connections & memory totals 128 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 129 | total_mem=0 130 | total_mem=$((total_server_mem+total_clients_mem)) 131 | total_mem_mb=$((total_mem/1024)) 132 | total_count=0 133 | total_count=$((total_clients_count+total_server_count)) 134 | echo -e "${GREENLIGHT}Memory${NC} | PostgreSQL processes ($total_count) memory consumption: $total_mem_mb MB | ${YELLOW}Backend processes ($total_clients_count) $total_clients_mem_mb MB${NC} | ${YELLOW}Background processes ($total_server_count) $total_server_mem_mb MB${NC}" 135 | fi 136 | 137 | echo 138 | 139 | 140 | 141 | # ------------------------------------------------ 142 | 143 | # Background Processes (Server connections) 144 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 145 | 146 | echo -e "${GREENLIGHT}Background processes ($total_server_count) memory consumption: $total_server_mem_mb MB${NC}" 147 | echo "---------------------------------------------------------------------------------------------------------------------------------------------------------------" 148 | 149 | if [[ $PLATFORM == "Red Hat Enterprise Linux Server" || $PLATFORM == "CentOS Linux" ]]; then 150 | sort -t '|' -k9 -n pg_database_activity_tmp.txt | column -t -s '|' -o ' |' # sort file by memory column, then show like table 151 | fi 152 | 153 | if [[ $PLATFORM == "Debian GNU/Linux" || $PLATFORM == "Ubuntu" ]]; then 154 | sort -t '|' -k9 -n pg_database_activity_tmp.txt | column -t -s '|' # sort file by memory column 155 | fi 156 | 157 | echo "---------------------------------------------------------------------------------------------------------------------------------------------------------------" 158 | echo 159 | rm pg_database_activity_tmp.txt 160 | 161 | fi 162 | 163 | 164 | 165 | # Database statistics 166 | if [[ $POSTGRES_VER_GLOB -ge 9 && $POSTGRES_VER_GLOB -le 11 ]]; then # >= 9 and <= 11 167 | echo -e "${GREENLIGHT}Database statistics:${NC}" 168 | $PG_BIN/psql -c "select p.datid, p.datname, pg_size_pretty(pg_database_size(p.datname)) as size, p.numbackends as connections, p.xact_commit as commit, p.xact_rollback as rollback, p.blks_read, p.blks_hit, p.temp_files, round(p.temp_bytes/1024/1024) as temp_mb, p.deadlocks, TO_CHAR(p.stats_reset, 'dd.mm.yyyy') as stat_reset from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;" | grep -v ' row)' | grep -v ' rows)' 169 | fi 170 | 171 | if [[ $POSTGRES_VER_GLOB -ge 12 ]]; then # >= 12 172 | echo -e "${GREENLIGHT}Database statistics:${NC}" 173 | $PG_BIN/psql -c "select p.datid, p.datname, pg_size_pretty(pg_database_size(p.datname)) as size, p.numbackends as connections, p.xact_commit as commit, p.xact_rollback as rollback, p.blks_read, p.blks_hit, p.temp_files, round(p.temp_bytes/1024/1024) as temp_mb, p.deadlocks, p.checksum_failures as chksum_fail, TO_CHAR(p.checksum_last_failure, 'dd.mm.yyyy HH24:MI:SS') as chksum_f_date, TO_CHAR(p.stats_reset, 'dd.mm.yyyy') as stat_reset from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;" | grep -v ' row)' | grep -v ' rows)' 174 | fi 175 | 176 | 177 | 178 | # Wait events (1st column) & Lock events (2nd column) 179 | echo -e "${GREENLIGHT}Wait events: ${YELLOW}Lock events:${NC}" 180 | 181 | # Wait events 182 | $PG_BIN/psql -c "select wait_event_type, wait_event, count(*) as connections from pg_stat_activity where wait_event_type is not null and wait_event_type <> 'Activity' group by wait_event_type, wait_event order by 3 desc;" | grep -v ' row)' | grep -v ' rows)' > pg_database_activity_wait.txt 183 | 184 | # Lock events 185 | $PG_BIN/psql -c "select d.datname, l.locktype, l.mode, count(*) from pg_locks l, pg_database d where l.database=d.oid and l.database is not null and l.granted = true group by d.datname, l.locktype, l.mode order by 4 desc;" | grep -v ' row)' | grep -v ' rows)' > pg_database_activity_locks.txt 186 | 187 | paste pg_database_activity_wait.txt pg_database_activity_locks.txt | awk -F'\t' '{printf("%-60s %s\n",$1,$2)}' 188 | rm pg_database_activity_wait.txt 189 | rm pg_database_activity_locks.txt 190 | 191 | 192 | 193 | # Archiving status 194 | archiving_status=`$PG_BIN/psql -t -c "select * from pg_stat_archiver;"` 195 | if [[ ${#archiving_status} >0 ]]; then 196 | 197 | echo -e "${GREENLIGHT}Archiving status:${NC}" 198 | 199 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 200 | 201 | if [[ $DB_STATUS == " f" ]]; then 202 | # master 203 | $PG_BIN/psql -c " 204 | select archived_count as archived_cnt, pg_walfile_name(pg_current_wal_lsn()), last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, 205 | ('x'||substring(pg_walfile_name(pg_current_wal_lsn()),9,8))::bit(32)::int*256 + 206 | ('x'||substring(pg_walfile_name(pg_current_wal_lsn()),17))::bit(32)::int - 207 | ('x'||substring(last_archived_wal,9,8))::bit(32)::int*256 - 208 | ('x'||substring(last_archived_wal,17))::bit(32)::int as arc_diff 209 | --TO_CHAR(stats_reset, 'dd.mm.yyyy') as stats_reset 210 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 211 | else 212 | # replica 213 | $PG_BIN/psql -c " 214 | select archived_count, last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, TO_CHAR(stats_reset, 'dd.mm.yyyy HH24:MI:SS') as stats_reset 215 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 216 | fi 217 | 218 | fi 219 | 220 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 221 | $PG_BIN/psql -c " 222 | select archived_count, last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, TO_CHAR(stats_reset, 'dd.mm.yyyy HH24:MI:SS') as stats_reset 223 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 224 | fi 225 | 226 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 227 | 228 | fi 229 | 230 | 231 | 232 | # Replication status (Master) 233 | replication_status=`$PG_BIN/psql -t -c "select * from pg_stat_replication;"` 234 | if [[ ${#replication_status} >0 ]]; then 235 | 236 | echo -e "${GREENLIGHT}Replication status (Master):${NC}" 237 | 238 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 239 | $PG_BIN/psql -c " 240 | SELECT r.client_addr AS client_addr, r.usename AS username, r.application_name AS app_name, r.pid, s.slot_name, s.slot_type, r.state, r.sync_state AS MODE, 241 | (pg_wal_lsn_diff(pg_current_wal_lsn(), r.sent_lsn) / 1024)::int AS send_lag, -- sending_lag (network problems) 242 | (pg_wal_lsn_diff(r.sent_lsn, r.flush_lsn) / 1024)::int AS receive_lag, -- receiving_lag 243 | (pg_wal_lsn_diff(r.sent_lsn, r.write_lsn) / 1024)::int AS WRITE, -- disks problems 244 | (pg_wal_lsn_diff(r.write_lsn, r.flush_lsn) / 1024)::int AS FLUSH, -- disks problems 245 | (pg_wal_lsn_diff(r.flush_lsn, r.replay_lsn) / 1024)::int AS replay_lag, -- replaying_lag (disks/CPU problems) 246 | (pg_wal_lsn_diff(pg_current_wal_lsn(), r.replay_lsn))::int / 1024 AS total_lag 247 | FROM pg_stat_replication r LEFT JOIN pg_replication_slots s ON (r.pid = s.active_pid);" | grep -v ' row)' | grep -v ' rows)' 248 | fi 249 | 250 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 251 | $PG_BIN/psql -c " 252 | SELECT r.client_addr AS client_addr, r.usename AS username, r.application_name AS app_name, r.pid, s.slot_name, s.slot_type, r.state, r.sync_state AS MODE 253 | FROM pg_stat_replication r LEFT JOIN pg_replication_slots s ON (r.pid = s.active_pid);" | grep -v ' row)' | grep -v ' rows)' 254 | fi 255 | 256 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 257 | 258 | fi 259 | 260 | 261 | 262 | # Replication status (Replica) 263 | if [[ $DB_STATUS != " f" ]]; then 264 | 265 | echo -e "${GREENLIGHT}Replication status (Replica):${NC}" 266 | 267 | if [[ $POSTGRES_VER_GLOB -eq 13 ]]; then # = 13 268 | $PG_BIN/psql -c " 269 | SELECT sender_host, sender_port, pid, slot_name, status, flushed_lsn, received_tli, 270 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 271 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 272 | END AS log_delay 273 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 274 | fi 275 | 276 | if [[ $POSTGRES_VER_GLOB -ge 11 && $POSTGRES_VER_GLOB -le 12 ]]; then # >= 11 and <= 12 277 | $PG_BIN/psql -c " 278 | SELECT sender_host, sender_port, pid, slot_name, status, received_lsn, received_tli, 279 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 280 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 281 | END AS log_delay 282 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 283 | fi 284 | 285 | if [[ $POSTGRES_VER_GLOB -eq 10 ]]; then # = 10 286 | $PG_BIN/psql -c " 287 | SELECT pid, slot_name, status, received_lsn, received_tli, 288 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 289 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 290 | END AS log_delay 291 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 292 | fi 293 | 294 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 295 | $PG_BIN/psql -c " 296 | SELECT pid, slot_name, status, received_lsn, received_tli, 297 | TO_CHAR(last_msg_send_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_send_time, TO_CHAR(last_msg_receipt_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_receipt_time 298 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 299 | fi 300 | 301 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 302 | 303 | fi 304 | 305 | 306 | 307 | # Logical Replication status (Replica) 308 | if [[ $POSTGRES_VER_GLOB -gt 9 ]]; then # > 9 309 | 310 | logical_replication=`$PG_BIN/psql -t -c "select * from pg_stat_subscription;"` 311 | if [[ ${#logical_replication} >0 ]]; then 312 | 313 | echo -e "${GREENLIGHT}Logical Replication status (Replica):${NC}" 314 | 315 | $PG_BIN/psql -c " 316 | SELECT subid, subname, pid, relid, received_lsn, TO_CHAR(last_msg_send_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_send_time, 317 | TO_CHAR(last_msg_receipt_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_receipt_time, latest_end_lsn, TO_CHAR(latest_end_time, 'dd.mm.yyyy HH24:MI:SS') as latest_end_time, 318 | (pg_wal_lsn_diff(received_lsn, latest_end_lsn) / 1024)::int AS subscription_lag 319 | FROM pg_stat_subscription;" | grep -v ' row)' | grep -v ' rows)' 320 | 321 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 322 | 323 | fi 324 | 325 | fi 326 | 327 | 328 | 329 | # PostgreSQL system process activity progress 330 | 331 | # PostgreSQL 9.6 and higher 332 | progress_vacuum=`$PG_BIN/psql -t -c "select * from pg_stat_progress_vacuum;"` 333 | if [[ ${#progress_vacuum} >0 ]]; then 334 | echo -e "${YELLOW}VACUUM progress:${NC}" 335 | $PG_BIN/psql -c "select a.query, p.datname, p.phase, p.heap_blks_total, p.heap_blks_scanned, p.heap_blks_vacuumed, p.index_vacuum_count, p.max_dead_tuples, p.num_dead_tuples from pg_stat_progress_vacuum p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 336 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 337 | fi 338 | 339 | 340 | # PostgreSQL 12 and higher: pg_stat_progress_analyze, pg_stat_progress_basebackup 341 | if [[ $POSTGRES_VER_GLOB -ge 12 ]]; then # >= 12 342 | 343 | progress_create_index=`$PG_BIN/psql -t -c "select * from pg_stat_progress_create_index;"` 344 | if [[ ${#progress_create_index} >0 ]]; then 345 | echo -e "${YELLOW}CREATE INDEX progress:${NC}" 346 | $PG_BIN/psql -c "SELECT a.query, p.datname, p.command, p.phase, p.lockers_total, p.lockers_done, p.blocks_total, p.blocks_done, p.tuples_total, p.tuples_done FROM pg_stat_progress_create_index p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 347 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 348 | fi 349 | 350 | progress_cluster=`$PG_BIN/psql -t -c "select * from pg_stat_progress_cluster;"` 351 | if [[ ${#progress_cluster} >0 ]]; then 352 | echo -e "${YELLOW}VACUUM FULL or CLUSTER progress:${NC}" 353 | $PG_BIN/psql -c "select a.query, p.datname, p.command, p.phase, p.heap_tuples_scanned, p.heap_tuples_written, p.index_rebuild_count from pg_stat_progress_cluster p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 354 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 355 | fi 356 | 357 | fi 358 | 359 | 360 | # PostgreSQL 13 and higher: pg_stat_progress_analyze, pg_stat_progress_basebackup 361 | if [[ $POSTGRES_VER_GLOB -ge 13 ]]; then # >= 13 362 | 363 | progress_analyze=`$PG_BIN/psql -t -c "select * from pg_stat_progress_analyze;"` 364 | if [[ ${#progress_analyze} >0 ]]; then 365 | echo -e "${YELLOW}ANALYZE progress:${NC}" 366 | $PG_BIN/psql -c "SELECT a.query, p.datname, p.phase, p.sample_blks_total, p.sample_blks_scanned, p.ext_stats_total, p.ext_stats_computed, p.child_tables_total, p.child_tables_done FROM pg_stat_progress_analyze p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 367 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 368 | fi 369 | 370 | progress_basebackup=`$PG_BIN/psql -t -c "select * from pg_stat_progress_basebackup;"` 371 | if [[ ${#progress_basebackup} >0 ]]; then 372 | echo -e "${YELLOW}PG_BASEBACKUP progress:${NC}" 373 | $PG_BIN/psql -c "SELECT a.query, p.pid, p.phase, p.backup_total, p.backup_streamed, p.tablespaces_total, p.tablespaces_streamed FROM pg_stat_progress_basebackup p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 374 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 375 | fi 376 | 377 | fi 378 | 379 | 380 | 381 | # show PostgreSQL log 382 | if [[ $PG_LOG_LINES -gt 0 ]]; then 383 | 384 | echo -e "${GREENLIGHT}PostgreSQL log: $PG_LOG_FILENAME${NC}" 385 | tail --lines=$PG_LOG_LINES $PG_LOG_FILENAME 386 | 387 | fi 388 | -------------------------------------------------------------------------------- /scripts/pg_database_activity_refresh.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # Refresh pg_database_activity.sh script 4 | 5 | i=0 6 | while [ i==0 ] 7 | do 8 | ./pg_database_activity.sh > pg_database_activity.txt 9 | clear 10 | cat ./pg_database_activity.txt 11 | sleep 5 12 | done 13 | -------------------------------------------------------------------------------- /scripts/pg_database_hugepages.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # Get Number of Required HugePages 4 | # https://www.percona.com/blog/2018/08/29/tune-linux-kernel-parameters-for-postgresql-optimization/ 5 | 6 | echo "-----------------------------------" 7 | echo "Free and used memory in the system:" 8 | free -hw 9 | echo 10 | 11 | echo "-----------------------------------" 12 | echo "Transparent Huge Pages (THP):" 13 | echo " On: [always] madvise never" 14 | echo "Off: always madvise [never]" 15 | echo 16 | echo "Status:" 17 | cat /sys/kernel/mm/transparent_hugepage/enabled 18 | echo 19 | echo "Tip: disable it" 20 | echo 21 | 22 | echo "-----------------------------------" 23 | echo "Current Huge pages:" 24 | echo 25 | grep Huge /proc/meminfo 26 | echo 27 | echo "-----------------------------------" 28 | echo "Number of Required HugePages:" 29 | echo 30 | 31 | pid=`head -1 $PGDATA/postmaster.pid` 32 | echo "Pid: $pid" 33 | 34 | peak=`grep ^VmPeak /proc/$pid/status | awk '{ print $2 }'` 35 | echo "VmPeak: $peak kB" 36 | 37 | hps=`grep ^Hugepagesize /proc/meminfo | awk '{ print $2 }'` 38 | echo "Hugepagesize: $hps kB" 39 | 40 | hp=$((peak/hps)) 41 | echo Set Huge Pages: $hp 42 | 43 | echo 44 | echo "-----------------------------------" 45 | -------------------------------------------------------------------------------- /scripts/pg_database_information.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # PostgreSQL databases information 4 | 5 | source ./settings.txt 6 | 7 | # Array of PosgtreSQL servers 8 | declare -a servers_list=("localhost") # Local server 9 | #declare -a servers_list=("pg_server_1" "pg_server_2" "pg_server_3") # Servers list, hostnames. Format: "pg_server_1" "pg_server_2" ... 10 | 11 | 12 | # ------------------------------------------------ 13 | 14 | # Databases list 15 | datnames=`$PG_BIN/psql -t -c "SELECT p.datname from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;"` 16 | 17 | 18 | # ------------------------------------------------ 19 | 20 | for server in "${servers_list[@]}"; do 21 | 22 | echo 23 | echo -e "${CYANLIGHT}--- [$server] -----------------------------------------------------------------------------------------------------------------------------------------------${NC}" 24 | 25 | # Databases list 26 | datnames=`$PG_BIN/psql -t -h $server -c "SELECT p.datname from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;"` 27 | 28 | 29 | # Title (1st line) 30 | DATE=`$PG_BIN/psql -t -h $server -c "select TO_CHAR(now(), 'dd.mm.yyyy HH24:MI:SS');" | xargs` 31 | HOSTIP=`ping -c1 -n $server | head -n1 | sed "s/.*(\([0-9]*\.[0-9]*\.[0-9]*\.[0-9]*\)).*/\1/g"` 32 | POSTGRES_VER=`$PG_BIN/psql -t -h $server -c "select version();" | cut -d ' ' -f 3` 33 | POSTGRES_VER_GLOB=`echo $POSTGRES_VER | awk '{print int($0)}'` # Round PostgreSQL version (13.1 = 13) 34 | DB_STATUS=`$PG_BIN/psql -t -h $server -c "select pg_is_in_recovery();"` 35 | # echo "Status: ["$DB_STATUS"]" 36 | 37 | # Time lag 38 | if [[ -z "$TIME" ]]; then 39 | # init 40 | TIME=`$PG_BIN/psql -t -h $server -c "select now();" | xargs` 41 | else 42 | TIME_CURR=`$PG_BIN/psql -t -h $server -c "select now();" | xargs` 43 | TIME_LAG=`$PG_BIN/psql -t -h $server -c "select TO_CHAR(age('$TIME_CURR', '$TIME'), 'HH24:MI:SS');" | xargs` 44 | 45 | if [[ $TIME_LAG != '00:00:00' && $TIME_LAG != '00:00:01' ]]; then 46 | LAG=". ${REDLIGHT}Lag: $TIME_LAG${NC}${YELLOW}" 47 | else 48 | LAG="" 49 | fi 50 | fi 51 | 52 | # Data checksums 53 | CHECKSUM=`$PG_BIN/psql -t -h $server -c "SHOW data_checksums;" | xargs` 54 | if [[ $CHECKSUM == "on" ]]; then 55 | CHECKSUM_STR="${GREENLIGHT}[Data checksums: $CHECKSUM]${NC}" 56 | else 57 | CHECKSUM_STR="${REDLIGHT}[Data checksums: $CHECKSUM]${NC}" 58 | fi 59 | 60 | # 61 | if [[ $DB_STATUS == " f" ]]; then 62 | STATUS="${GREENLIGHT}[$server ($HOSTIP) / PostgreSQL $POSTGRES_VER / Master]${YELLOW}" 63 | else 64 | STATUS="${PURPLELIGHT}[$server ($HOSTIP) / PostgreSQL $POSTGRES_VER / Replica]${YELLOW}" 65 | fi 66 | 67 | echo -e "${YELLOW}[Server time: $DATE$LAG] $STATUS $CHECKSUM_STR ${NC}" 68 | 69 | 70 | 71 | # Database statistics 72 | echo 73 | if [[ $POSTGRES_VER_GLOB -ge 9 && $POSTGRES_VER_GLOB -le 11 ]]; then # >= 9 and <= 11 74 | echo -e "${GREENLIGHT}Database statistics:${NC}" 75 | $PG_BIN/psql -h $server -c "select p.datid, p.datname, pg_size_pretty(pg_database_size(p.datname)) as size, p.numbackends as connections, p.xact_commit as commit, p.xact_rollback as rollback, p.blks_read, p.blks_hit, p.temp_files, round(p.temp_bytes/1024/1024) as temp_mb, p.deadlocks, TO_CHAR(p.stats_reset, 'dd.mm.yyyy') as stat_reset from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;" | grep -v ' row)' | grep -v ' rows)' 76 | fi 77 | 78 | if [[ $POSTGRES_VER_GLOB -ge 12 ]]; then # >= 12 79 | echo -e "${GREENLIGHT}Database statistics:${NC}" 80 | $PG_BIN/psql -h $server -c "select p.datid, p.datname, pg_size_pretty(pg_database_size(p.datname)) as size, p.numbackends as connections, p.xact_commit as commit, p.xact_rollback as rollback, p.blks_read, p.blks_hit, p.temp_files, round(p.temp_bytes/1024/1024) as temp_mb, p.deadlocks, p.checksum_failures as chksum_fail, TO_CHAR(p.checksum_last_failure, 'dd.mm.yyyy HH24:MI:SS') as chksum_f_date, TO_CHAR(p.stats_reset, 'dd.mm.yyyy') as stat_reset from pg_stat_database p, pg_database d where p.datid=d.oid and d.datistemplate = false order by p.datid;" | grep -v ' row)' | grep -v ' rows)' 81 | fi 82 | 83 | 84 | 85 | # Wait events (1st column) & Lock events (2nd column) 86 | echo -e "${GREENLIGHT}Wait events: ${YELLOW}Lock events:${NC}" 87 | 88 | # Wait events 89 | $PG_BIN/psql -h $server -c "select wait_event_type, wait_event, count(*) as connections from pg_stat_activity where wait_event_type is not null and wait_event_type <> 'Activity' group by wait_event_type, wait_event order by 3 desc;" | grep -v ' row)' | grep -v ' rows)' > pg_database_activity_wait.txt 90 | 91 | # Lock events 92 | $PG_BIN/psql -h $server -c "select d.datname, l.locktype, l.mode, count(*) from pg_locks l, pg_database d where l.database=d.oid and l.database is not null and l.granted = true group by d.datname, l.locktype, l.mode order by 4 desc;" | grep -v ' row)' | grep -v ' rows)' > pg_database_activity_locks.txt 93 | 94 | paste pg_database_activity_wait.txt pg_database_activity_locks.txt | awk -F'\t' '{printf("%-60s %s\n",$1,$2)}' 95 | rm pg_database_activity_wait.txt 96 | rm pg_database_activity_locks.txt 97 | 98 | 99 | 100 | # Archiving status 101 | archiving_status=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_archiver;"` 102 | if [[ ${#archiving_status} >0 ]]; then 103 | 104 | echo -e "${GREENLIGHT}Archiving status:${NC}" 105 | 106 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 107 | 108 | if [[ $DB_STATUS == " f" ]]; then 109 | # master 110 | $PG_BIN/psql -h $server -c " 111 | select archived_count as archived_cnt, pg_walfile_name(pg_current_wal_lsn()), last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, 112 | ('x'||substring(pg_walfile_name(pg_current_wal_lsn()),9,8))::bit(32)::int*256 + 113 | ('x'||substring(pg_walfile_name(pg_current_wal_lsn()),17))::bit(32)::int - 114 | ('x'||substring(last_archived_wal,9,8))::bit(32)::int*256 - 115 | ('x'||substring(last_archived_wal,17))::bit(32)::int as arc_diff 116 | --TO_CHAR(stats_reset, 'dd.mm.yyyy') as stats_reset 117 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 118 | else 119 | # replica 120 | $PG_BIN/psql -h $server -c " 121 | select archived_count, last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, TO_CHAR(stats_reset, 'dd.mm.yyyy HH24:MI:SS') as stats_reset 122 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 123 | fi 124 | 125 | fi 126 | 127 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 128 | $PG_BIN/psql -h $server -c " 129 | select archived_count, last_archived_wal, TO_CHAR(last_archived_time, 'dd.mm.yyyy HH24:MI:SS') as last_archived_time, failed_count, last_failed_wal, TO_CHAR(last_failed_time, 'dd.mm.yyyy HH24:MI:SS') as last_failed_time, TO_CHAR(stats_reset, 'dd.mm.yyyy HH24:MI:SS') as stats_reset 130 | from pg_stat_archiver;" | grep -v ' row)' | grep -v ' rows)' 131 | fi 132 | 133 | fi 134 | 135 | 136 | 137 | # Replication status (Master) 138 | replication_status=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_replication;"` 139 | if [[ ${#replication_status} >0 ]]; then 140 | 141 | echo -e "${GREENLIGHT}Replication status (Master):${NC}" 142 | 143 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 144 | $PG_BIN/psql -h $server -c " 145 | SELECT r.client_addr AS client_addr, r.usename AS username, r.application_name AS app_name, r.pid, s.slot_name, s.slot_type, r.state, r.sync_state AS MODE, 146 | (pg_wal_lsn_diff(pg_current_wal_lsn(), r.sent_lsn) / 1024)::int AS send_lag, -- sending_lag (network problems) 147 | (pg_wal_lsn_diff(r.sent_lsn, r.flush_lsn) / 1024)::int AS receive_lag, -- receiving_lag 148 | (pg_wal_lsn_diff(r.sent_lsn, r.write_lsn) / 1024)::int AS WRITE, -- disks problems 149 | (pg_wal_lsn_diff(r.write_lsn, r.flush_lsn) / 1024)::int AS FLUSH, -- disks problems 150 | (pg_wal_lsn_diff(r.flush_lsn, r.replay_lsn) / 1024)::int AS replay_lag, -- replaying_lag (disks/CPU problems) 151 | (pg_wal_lsn_diff(pg_current_wal_lsn(), r.replay_lsn))::int / 1024 AS total_lag 152 | FROM pg_stat_replication r LEFT JOIN pg_replication_slots s ON (r.pid = s.active_pid);" | grep -v ' row)' | grep -v ' rows)' 153 | fi 154 | 155 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 156 | $PG_BIN/psql -h $server -c " 157 | SELECT r.client_addr AS client_addr, r.usename AS username, r.application_name AS app_name, r.pid, s.slot_name, s.slot_type, r.state, r.sync_state AS MODE 158 | FROM pg_stat_replication r LEFT JOIN pg_replication_slots s ON (r.pid = s.active_pid);" | grep -v ' row)' | grep -v ' rows)' 159 | fi 160 | 161 | fi 162 | 163 | 164 | 165 | # Replication status (Replica) 166 | if [[ $DB_STATUS != " f" ]]; then 167 | 168 | echo -e "${GREENLIGHT}Replication status (Replica):${NC}" 169 | 170 | if [[ $POSTGRES_VER_GLOB -eq 13 ]]; then # = 13 171 | $PG_BIN/psql -h $server -c " 172 | SELECT sender_host, sender_port, pid, slot_name, status, flushed_lsn, received_tli, 173 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 174 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 175 | END AS log_delay 176 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 177 | fi 178 | 179 | if [[ $POSTGRES_VER_GLOB -ge 11 && $POSTGRES_VER_GLOB -le 12 ]]; then # >= 11 and <= 12 180 | $PG_BIN/psql -h $server -c " 181 | SELECT sender_host, sender_port, pid, slot_name, status, received_lsn, received_tli, 182 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 183 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 184 | END AS log_delay 185 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 186 | fi 187 | 188 | if [[ $POSTGRES_VER_GLOB -eq 10 ]]; then # = 10 189 | $PG_BIN/psql -h $server -c " 190 | SELECT pid, slot_name, status, received_lsn, received_tli, 191 | CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() THEN 0 192 | ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) 193 | END AS log_delay 194 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 195 | fi 196 | 197 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 198 | $PG_BIN/psql -h $server -c " 199 | SELECT pid, slot_name, status, received_lsn, received_tli, 200 | TO_CHAR(last_msg_send_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_send_time, TO_CHAR(last_msg_receipt_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_receipt_time 201 | FROM pg_stat_wal_receiver;" | grep -v ' row)' | grep -v ' rows)' 202 | fi 203 | 204 | fi 205 | 206 | 207 | 208 | # Logical Replication status (Replica) 209 | if [[ $POSTGRES_VER_GLOB -gt 9 ]]; then # > 9 210 | 211 | logical_replication=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_subscription;"` 212 | if [[ ${#logical_replication} >0 ]]; then 213 | echo -e "${GREENLIGHT}Logical Replication status (Replica):${NC}" 214 | 215 | $PG_BIN/psql -h $server -c " 216 | SELECT subid, subname, pid, relid, received_lsn, TO_CHAR(last_msg_send_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_send_time, 217 | TO_CHAR(last_msg_receipt_time, 'dd.mm.yyyy HH24:MI:SS') as last_msg_receipt_time, latest_end_lsn, TO_CHAR(latest_end_time, 'dd.mm.yyyy HH24:MI:SS') as latest_end_time, 218 | (pg_wal_lsn_diff(received_lsn, latest_end_lsn) / 1024)::int AS subscription_lag 219 | FROM pg_stat_subscription;" | grep -v ' row)' | grep -v ' rows)' 220 | fi 221 | 222 | fi 223 | 224 | 225 | 226 | # --------------------------------------------------------------------------------------------------------------------------------- 227 | # (Added) 228 | 229 | # Replication - Publication status. Publishing to logical replication is only allowed from the master server (PostgreSQL 13) 230 | if [[ $DB_STATUS == " f" ]]; then 231 | 232 | for datname in $datnames ; do 233 | 234 | if [[ $POSTGRES_VER_GLOB -eq 10 ]]; then # = 10 235 | publication_status=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_publication;"` 236 | if [[ ${#publication_status} >0 ]]; then 237 | echo -e "${GREENLIGHT}Logical Replication - Publications. Dabatabase: ${UNDERLINE}$datname${NC}" 238 | $PG_BIN/psql --dbname=$datname -h $server -c "select p.oid, p.pubname, a.rolname as pubowner, p.puballtables, p.pubinsert, p.pubupdate, p.pubdelete from pg_publication p, pg_authid a where p.pubowner=a.oid;" | grep -v ' row)' | grep -v ' rows)' 239 | fi 240 | fi 241 | 242 | if [[ $POSTGRES_VER_GLOB -ge 11 ]]; then # >= 11 243 | publication_status=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_publication;"` 244 | if [[ ${#publication_status} >0 ]]; then 245 | echo -e "${GREENLIGHT}Logical Replication - Publications. Dabatabase: ${UNDERLINE}$datname${NC}" 246 | $PG_BIN/psql --dbname=$datname -h $server -c "select p.oid, p.pubname, a.rolname as pubowner, p.puballtables, p.pubinsert, p.pubupdate, p.pubdelete, p.pubtruncate from pg_publication p, pg_authid a where p.pubowner=a.oid;" | grep -v ' row)' | grep -v ' rows)' 247 | fi 248 | fi 249 | 250 | done 251 | 252 | fi 253 | 254 | 255 | # Replication - Subscription status 256 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 257 | 258 | subscription_status=`$PG_BIN/psql -t -h $server -c "select * from pg_subscription;"` 259 | if [[ ${#subscription_status} >0 ]]; then 260 | echo -e "${GREENLIGHT}Logical Replication - Subscriptions:${NC}" 261 | $PG_BIN/psql -h $server -c "select p.oid, d.datname as subdatname, p.subname, a.rolname as subowner, p.subenabled, p.subconninfo, p.subslotname, p.subsynccommit, p.subpublications from pg_subscription p, pg_database d, pg_authid a where p.subdbid = d.oid and p.subowner = a.oid;" | grep -v ' row)' | grep -v ' rows)' 262 | fi 263 | 264 | fi 265 | 266 | 267 | 268 | # --------------------------------------------------------------------------------------------------------------------------------- 269 | # (Added) 270 | 271 | 272 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 273 | 274 | for datname in $datnames ; do 275 | 276 | 277 | # Foreign Data Wrapper - access data stored in external PostgreSQL servers 278 | foreign_data_wrapper=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_foreign_data_wrapper;"` 279 | if [[ ${#foreign_data_wrapper} >0 ]]; then 280 | echo -e "${GREEN}Foreign Data Wrapper. Dabatabase: ${UNDERLINE}$datname${NC}" 281 | $PG_BIN/psql --dbname=$datname -h $server -c " 282 | SELECT fdw.oid, fdw.fdwname, fdw.fdwowner, a.rolname as fdwowner_role, fdw.fdwhandler, fdw.fdwvalidator, p1.proname, p2.proname, p1.proowner, p2.proowner, fdw.fdwacl, fdw.fdwoptions 283 | FROM pg_foreign_data_wrapper fdw 284 | JOIN pg_authid a ON fdw.fdwowner=a.oid 285 | LEFT JOIN pg_proc p1 ON fdw.fdwhandler = p1.oid 286 | LEFT JOIN pg_proc p2 ON fdw.fdwvalidator = p2.oid;" | grep -v ' row)' | grep -v ' rows)' 287 | fi 288 | 289 | 290 | # Foreign Servers 291 | foreign_server=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_foreign_server;"` 292 | if [[ ${#foreign_server} >0 ]]; then 293 | echo -e "${GREEN}Foreign Servers. Dabatabase: ${UNDERLINE}$datname${NC}" 294 | $PG_BIN/psql --dbname=$datname -h $server -c " 295 | SELECT s.oid, s.srvname, a.rolname as srvowner, s.srvoptions, b.fdwname, s.srvversion, s.srvtype 296 | FROM pg_foreign_server s, pg_foreign_data_wrapper b, pg_authid a 297 | WHERE b.oid=s.srvfdw AND s.srvowner=a.oid;" | grep -v ' row)' | grep -v ' rows)' 298 | fi 299 | 300 | 301 | # Foreign Users mappings 302 | foreign_users=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_user_mappings;"` 303 | if [[ ${#foreign_users} >0 ]]; then 304 | echo -e "${GREEN}Foreign Users mappings. Dabatabase: ${UNDERLINE}$datname${NC}" 305 | $PG_BIN/psql --dbname=$datname -h $server -c " 306 | SELECT um.umid, um.srvid, um.srvname, a.rolname as umuser, um.usename, um.umoptions 307 | FROM pg_user_mappings um 308 | LEFT JOIN pg_authid a ON um.umuser = a.oid;" | grep -v ' row)' | grep -v ' rows)' 309 | fi 310 | 311 | 312 | # Foreign tables list: 313 | foreign_tables=`$PG_BIN/psql -t --dbname=$datname -h $server -c "select * from pg_foreign_table;"` 314 | if [[ ${#foreign_tables} >0 ]]; then 315 | echo -e "${GREEN}Foreign tables list. Dabatabase: ${UNDERLINE}$datname${NC}" 316 | $PG_BIN/psql --dbname=$datname -h $server -c " 317 | SELECT n.nspname AS Schema, 318 | c.relname AS Table, 319 | s.srvname AS Server, 320 | CASE WHEN ftoptions IS NULL THEN '' ELSE '(' || pg_catalog.array_to_string(ARRAY(SELECT pg_catalog.quote_ident(option_name) || ' ' || pg_catalog.quote_literal(option_value) FROM pg_catalog.pg_options_to_table(ftoptions)), ', ') || ')' END AS FDW_options, 321 | d.description AS Description 322 | FROM pg_catalog.pg_foreign_table ft 323 | INNER JOIN pg_catalog.pg_class c ON c.oid = ft.ftrelid 324 | INNER JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 325 | INNER JOIN pg_catalog.pg_foreign_server s ON s.oid = ft.ftserver 326 | LEFT JOIN pg_catalog.pg_description d 327 | ON d.classoid = c.tableoid AND d.objoid = c.oid AND d.objsubid = 0 328 | ORDER BY 1, 2;" | grep -v ' row)' | grep -v ' rows)' 329 | fi 330 | 331 | 332 | done # for 333 | 334 | fi 335 | 336 | 337 | # --------------------------------------------------------------------------------------------------------------------------------- 338 | # (Added) 339 | 340 | # Locks. Wait sessions 341 | locks_wait_sessions=`$PG_BIN/psql -t -h $server -c " 342 | SELECT (clock_timestamp() - pg_stat_activity.xact_start) AS ts_age, pg_stat_activity.state, (clock_timestamp() - pg_stat_activity.query_start) as query_age, (clock_timestamp() - state_change) as change_age, pg_stat_activity.datname, pg_stat_activity.pid, pg_stat_activity.usename, coalesce(wait_event_type = 'Lock', 'f') waiting, pg_stat_activity.client_addr, pg_stat_activity.client_port, pg_stat_activity.query 343 | FROM pg_stat_activity WHERE 344 | ((clock_timestamp() - pg_stat_activity.xact_start > '00:00:00.1'::interval) OR (clock_timestamp() - pg_stat_activity.query_start > '00:00:00.1'::interval and state = 'idle in transaction (aborted)')) 345 | and pg_stat_activity.pid<>pg_backend_pid() ORDER BY coalesce(pg_stat_activity.xact_start, pg_stat_activity.query_start);"` 346 | if [[ ${#locks_wait_sessions} >0 ]]; then 347 | echo -e "${YELLOW}Locks. Wait sessions:${NC}" 348 | $PG_BIN/psql -h $server -c " 349 | SELECT (clock_timestamp() - pg_stat_activity.xact_start) AS ts_age, pg_stat_activity.state, (clock_timestamp() - pg_stat_activity.query_start) as query_age, (clock_timestamp() - state_change) as change_age, pg_stat_activity.datname, pg_stat_activity.pid, pg_stat_activity.usename, coalesce(wait_event_type = 'Lock', 'f') waiting, pg_stat_activity.client_addr, pg_stat_activity.client_port, pg_stat_activity.query 350 | FROM pg_stat_activity 351 | WHERE 352 | ((clock_timestamp() - pg_stat_activity.xact_start > '00:00:00.1'::interval) OR (clock_timestamp() - pg_stat_activity.query_start > '00:00:00.1'::interval and state = 'idle in transaction (aborted)')) 353 | and pg_stat_activity.pid<>pg_backend_pid() 354 | ORDER BY coalesce(pg_stat_activity.xact_start, pg_stat_activity.query_start);" | grep -v ' row)' | grep -v ' rows)' 355 | fi 356 | 357 | 358 | # Locks. Blocking tree 359 | locks_blocking_tree=`$PG_BIN/psql -t -h $server -c " 360 | WITH RECURSIVE l AS ( 361 | SELECT pid, locktype, granted, 362 | array_position(ARRAY['AccessShare','RowShare','RowExclusive','ShareUpdateExclusive','Share','ShareRowExclusive','Exclusive','AccessExclusive'], left(mode,-4)) m, 363 | ROW(locktype,database,relation,page,tuple,virtualxid,transactionid,classid,objid,objsubid) obj FROM pg_locks 364 | ), pairs AS ( 365 | SELECT w.pid waiter, l.pid locker, l.obj, l.m 366 | FROM l w JOIN l ON l.obj IS NOT DISTINCT FROM w.obj AND l.locktype=w.locktype AND NOT l.pid=w.pid AND l.granted 367 | WHERE NOT w.granted 368 | AND NOT EXISTS ( SELECT FROM l i WHERE i.pid=l.pid AND i.locktype=l.locktype AND i.obj IS NOT DISTINCT FROM l.obj AND i.m > l.m ) 369 | ), leads AS ( 370 | SELECT o.locker, 1::int lvl, count(*) q, ARRAY[locker] track, false AS cycle FROM pairs o GROUP BY o.locker 371 | UNION ALL 372 | SELECT i.locker, leads.lvl+1, (SELECT count(*) FROM pairs q WHERE q.locker=i.locker), leads.track||i.locker, i.locker=ANY(leads.track) 373 | FROM pairs i, leads WHERE i.waiter=leads.locker AND NOT cycle 374 | ), tree AS ( 375 | SELECT locker pid,locker dad,locker root,CASE WHEN cycle THEN track END dl, NULL::record obj,0 lvl,locker::text path,array_agg(locker) OVER () all_pids FROM leads o 376 | WHERE (cycle AND NOT EXISTS (SELECT FROM leads i WHERE i.locker=ANY(o.track) AND (i.lvl>o.lvl OR i.q' ELSE repeat(' .', lvl) END||' '||trim(left(regexp_replace(a.query, E'\\s+', ' ', 'g'),100)) query 389 | FROM tree 390 | LEFT JOIN pairs w ON w.waiter=tree.pid AND w.locker=tree.dad 391 | JOIN pg_stat_activity a USING (pid) 392 | JOIN pg_stat_activity r ON r.pid=tree.root 393 | ORDER BY (now() - r.xact_start), path;"` 394 | if [[ ${#locks_blocking_tree} >0 ]]; then 395 | echo -e "${YELLOW}Locks. Blocking tree:${NC}" 396 | $PG_BIN/psql -h $server -c " 397 | WITH RECURSIVE l AS ( 398 | SELECT pid, locktype, granted, 399 | array_position(ARRAY['AccessShare','RowShare','RowExclusive','ShareUpdateExclusive','Share','ShareRowExclusive','Exclusive','AccessExclusive'], left(mode,-4)) m, 400 | ROW(locktype,database,relation,page,tuple,virtualxid,transactionid,classid,objid,objsubid) obj FROM pg_locks 401 | ), pairs AS ( 402 | SELECT w.pid waiter, l.pid locker, l.obj, l.m 403 | FROM l w JOIN l ON l.obj IS NOT DISTINCT FROM w.obj AND l.locktype=w.locktype AND NOT l.pid=w.pid AND l.granted 404 | WHERE NOT w.granted 405 | AND NOT EXISTS ( SELECT FROM l i WHERE i.pid=l.pid AND i.locktype=l.locktype AND i.obj IS NOT DISTINCT FROM l.obj AND i.m > l.m ) 406 | ), leads AS ( 407 | SELECT o.locker, 1::int lvl, count(*) q, ARRAY[locker] track, false AS cycle FROM pairs o GROUP BY o.locker 408 | UNION ALL 409 | SELECT i.locker, leads.lvl+1, (SELECT count(*) FROM pairs q WHERE q.locker=i.locker), leads.track||i.locker, i.locker=ANY(leads.track) 410 | FROM pairs i, leads WHERE i.waiter=leads.locker AND NOT cycle 411 | ), tree AS ( 412 | SELECT locker pid,locker dad,locker root,CASE WHEN cycle THEN track END dl, NULL::record obj,0 lvl,locker::text path,array_agg(locker) OVER () all_pids FROM leads o 413 | WHERE (cycle AND NOT EXISTS (SELECT FROM leads i WHERE i.locker=ANY(o.track) AND (i.lvl>o.lvl OR i.q' ELSE repeat(' .', lvl) END||' '||trim(left(regexp_replace(a.query, E'\\s+', ' ', 'g'),100)) query 426 | FROM tree 427 | LEFT JOIN pairs w ON w.waiter=tree.pid AND w.locker=tree.dad 428 | JOIN pg_stat_activity a USING (pid) 429 | JOIN pg_stat_activity r ON r.pid=tree.root 430 | ORDER BY (now() - r.xact_start), path;" | grep -v ' row)' | grep -v ' rows)' 431 | fi 432 | # Locks. Blocking tree 433 | 434 | 435 | 436 | # --------------------------------------------------------------------------------------------------------------------------------- 437 | # (Added) 438 | 439 | # Long running queries (> 30 minutes) 440 | long_queries=`$PG_BIN/psql -t -h $server -c "SELECT pid FROM pg_stat_activity WHERE (now() - pg_stat_activity.query_start) > interval '\30 minute\';"` 441 | if [[ ${#long_queries} >0 ]]; then 442 | echo -e "${YELLOW}Long running queries (> 30 minutes):${NC}" 443 | 444 | if [[ $POSTGRES_VER_GLOB -ge 10 ]]; then # >= 10 445 | $PG_BIN/psql -h $server -c "SELECT datname, pid, TO_CHAR(now() - pg_stat_activity.query_start, 'HH24:MI:SS') AS duration, usename, application_name as app_name, client_addr, wait_event_type as wait_type, wait_event, backend_type, SUBSTRING(query, 1, 38) as query, state FROM pg_stat_activity WHERE (now() - pg_stat_activity.query_start) > interval '\30 minute\';" | grep -v ' row)' | grep -v ' rows)' 446 | fi 447 | 448 | if [[ $POSTGRES_VER_GLOB -eq 9 ]]; then # = 9 449 | $PG_BIN/psql -h $server -c "SELECT datname, pid, TO_CHAR(now() - pg_stat_activity.query_start, 'HH24:MI:SS') AS duration, usename, application_name as app_name, client_addr, wait_event_type as wait_type, wait_event, SUBSTRING(query, 1, 38) as query, state FROM pg_stat_activity WHERE (now() - pg_stat_activity.query_start) > interval '\30 minute\';" | grep -v ' row)' | grep -v ' rows)' 450 | fi 451 | 452 | fi 453 | 454 | 455 | 456 | # --------------------------------------------------------------------------------------------------------------------------------- 457 | 458 | # PostgreSQL system process activity progress 459 | 460 | # PostgreSQL 9.6 and higher 461 | progress_vacuum=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_progress_vacuum;"` 462 | if [[ ${#progress_vacuum} >0 ]]; then 463 | echo -e "${YELLOW}VACUUM progress:${NC}" 464 | $PG_BIN/psql -h $server -c "select a.query, p.datname, p.phase, p.heap_blks_total, p.heap_blks_scanned, p.heap_blks_vacuumed, p.index_vacuum_count, p.max_dead_tuples, p.num_dead_tuples from pg_stat_progress_vacuum p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 465 | fi 466 | 467 | 468 | # PostgreSQL 12 and higher: pg_stat_progress_analyze, pg_stat_progress_basebackup 469 | if [[ $POSTGRES_VER_GLOB -ge 12 ]]; then # >= 12 470 | 471 | progress_create_index=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_progress_create_index;"` 472 | if [[ ${#progress_create_index} >0 ]]; then 473 | echo -e "${YELLOW}CREATE INDEX progress:${NC}" 474 | $PG_BIN/psql -h $server -c "SELECT a.query, p.datname, p.command, p.phase, p.lockers_total, p.lockers_done, p.blocks_total, p.blocks_done, p.tuples_total, p.tuples_done FROM pg_stat_progress_create_index p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 475 | fi 476 | 477 | progress_cluster=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_progress_cluster;"` 478 | if [[ ${#progress_cluster} >0 ]]; then 479 | echo -e "${YELLOW}VACUUM FULL or CLUSTER progress:${NC}" 480 | $PG_BIN/psql -h $server -c "select a.query, p.datname, p.command, p.phase, p.heap_tuples_scanned, p.heap_tuples_written, p.index_rebuild_count from pg_stat_progress_cluster p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 481 | fi 482 | 483 | fi 484 | 485 | 486 | # PostgreSQL 13 and higher: pg_stat_progress_analyze, pg_stat_progress_basebackup 487 | if [[ $POSTGRES_VER_GLOB -ge 13 ]]; then # >= 13 488 | 489 | progress_analyze=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_progress_analyze;"` 490 | if [[ ${#progress_analyze} >0 ]]; then 491 | echo -e "${YELLOW}ANALYZE progress:${NC}" 492 | $PG_BIN/psql -h $server -c "SELECT a.query, p.datname, p.phase, p.sample_blks_total, p.sample_blks_scanned, p.ext_stats_total, p.ext_stats_computed, p.child_tables_total, p.child_tables_done FROM pg_stat_progress_analyze p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 493 | fi 494 | 495 | progress_basebackup=`$PG_BIN/psql -t -h $server -c "select * from pg_stat_progress_basebackup;"` 496 | if [[ ${#progress_basebackup} >0 ]]; then 497 | echo -e "${YELLOW}PG_BASEBACKUP progress:${NC}" 498 | $PG_BIN/psql -h $server -c "SELECT a.query, p.pid, p.phase, p.backup_total, p.backup_streamed, p.tablespaces_total, p.tablespaces_streamed FROM pg_stat_progress_basebackup p, pg_stat_activity a WHERE p.pid = a.pid;" | grep -v ' row)' | grep -v ' rows)' 499 | PG_LOG_LINES=$((PG_LOG_LINES-5)) 500 | fi 501 | 502 | fi 503 | 504 | 505 | # --------------------------------------------------------------------------------------------------------------------------------- 506 | 507 | 508 | done # Servers cycle 509 | 510 | -------------------------------------------------------------------------------- /scripts/pg_database_logs.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # Show PostgreSQL log file 4 | 5 | source ./settings.txt 6 | 7 | PG_LOG_LINES=100 # PostgreSQL log lines to show 8 | 9 | PG_LOG_FILENAME=`ls -t $PG_LOG_DIR/postgresql-*.log | head -n1` # newest PostgreSQL log file in log_directory 10 | 11 | # show PostgreSQL log 12 | echo -e "PostgreSQL log: $PG_LOG_FILENAME" 13 | tail -f --lines=$PG_LOG_LINES $PG_LOG_FILENAME 14 | -------------------------------------------------------------------------------- /scripts/pg_database_reload_conf.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # PostgreSQL reload configuration 4 | 5 | source ./settings.txt 6 | 7 | PG_LOG_LINES=500 # PostgreSQL log lines to grep 8 | 9 | PG_LOG_FILENAME=`ls -t $PG_LOG_DIR/postgresql-*.log | head -n1` # newest PostgreSQL log file in log_directory 10 | 11 | 12 | read -p "Reload PostgreSQL configuration (Y/N)? " -n 1 -r 13 | echo 14 | if [[ $REPLY =~ ^[Yy]$ ]] 15 | then 16 | $PG_BIN/pg_ctl reload -D $PG_DATA 17 | 18 | echo 19 | echo -e "PostgreSQL log: $PG_LOG_FILENAME" 20 | sleep 1 21 | 22 | # show PostgreSQL log 23 | tail --lines=$PG_LOG_LINES $PG_LOG_FILENAME | grep 'reloading\|parameter\|configuration' 24 | 25 | # show Pending restart parameters 26 | pending_restart=`$PG_BIN/psql -t -c "SELECT * FROM pg_settings WHERE pending_restart;"` 27 | if [[ ${#pending_restart} >0 ]]; then 28 | echo 29 | echo "Pending restart parameters:" 30 | $PG_BIN/psql -x -c "SELECT * FROM pg_settings WHERE pending_restart;" 31 | fi 32 | 33 | fi 34 | -------------------------------------------------------------------------------- /scripts/pg_database_start.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # PostgreSQL start 4 | 5 | source ./settings.txt 6 | 7 | read -p "Start PostgreSQL (Y/N)? " -n 1 -r 8 | echo 9 | if [[ $REPLY =~ ^[Yy]$ ]] 10 | then 11 | $PG_BIN/pg_ctl -D $PG_DATA start 12 | fi 13 | -------------------------------------------------------------------------------- /scripts/pg_database_status.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # PostgreSQL status 4 | 5 | source ./settings.txt 6 | 7 | echo "PostgreSQL processes:" 8 | ps -afH --forest -u postgres | grep -v sshd | grep -v bash | grep -v 'su - postgres' | grep -v 'ps -afH' | grep -v '/usr/bin/mc' | grep -v '\_ mc' | grep -v '/sbin/agetty' 9 | echo 10 | 11 | echo "PostgreSQL network connection:" 12 | netstat -tulnp | grep "PID\|postgres\|postmaster" 13 | echo 14 | 15 | echo "PostgreSQL status:" 16 | $PG_BIN/pg_ctl -D $PG_DATA status 17 | echo 18 | 19 | echo "PostgreSQL replication service (sender). Works on Master server:" 20 | ps -aef | grep -v grep | grep "PID\|sender" 21 | echo 22 | 23 | echo "PGDATA: $PGDATA" 24 | echo 25 | 26 | echo "PostgreSQL replication service (receiver). Works on Replica server:" 27 | ps -aef | grep -v grep | grep "PID\|receiver" 28 | echo 29 | 30 | echo "PostgreSQL logical replication service (worker). Works on Replica server:" 31 | ps -aef | grep -v grep | grep "PID\|logical replication worker" 32 | -------------------------------------------------------------------------------- /scripts/pg_database_stop.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # PostgreSQL stop 4 | 5 | source ./settings.txt 6 | 7 | read -p "Stop PostgreSQL (Y/N)? " -n 1 -r 8 | echo 9 | if [[ $REPLY =~ ^[Yy]$ ]] 10 | then 11 | $PG_BIN/pg_ctl -D $PG_DATA stop 12 | fi 13 | -------------------------------------------------------------------------------- /scripts/settings.txt: -------------------------------------------------------------------------------- 1 | 2 | # PostgreSQL version 3 | PG_VER=12 # Supported PostgreSQL versions: 9.6, 10, 11, 12, 13 4 | 5 | 6 | # Red Hat / CentOS 7 | #PG_BIN=/usr/pgsql-$PG_VER/bin # Executables directory (by default, do not change!) 8 | 9 | #PG_DATA=/var/lib/pgsql/$PG_VER/data # Main data directory 10 | #PG_ARC=/var/lib/pgsql/$PG_VER/archive # Archive logs directory 11 | #PG_LOG_DIR=/var/lib/pgsql/$PG_VER/data/log # Directory for log files. For PostgreSQL 9.6 directory is /pg_log 12 | 13 | 14 | # Debian / Ubuntu 15 | #PG_BIN=/usr/lib/postgresql/$PG_VER/bin # Executables directory (by default, do not change!) 16 | 17 | #PG_DATA=/var/lib/postgresql/$PG_VER/data # Main data directory 18 | #PG_ARC=/var/lib/postgresql/$PG_VER/archive # Archive logs directory 19 | #PG_LOG_DIR=/var/lib/postgresql/$PG_VER/data/log # Directory for log files. For PostgreSQL 9.6 directory is /pg_log 20 | 21 | 22 | # ------------------------------------------------ 23 | 24 | # Colors 25 | GREYDARK='\033[1;30m' 26 | RED='\033[0;31m' 27 | REDLIGHT='\033[1;31m' 28 | GREEN='\033[0;32m' 29 | GREENLIGHT='\033[1;32m' 30 | ORANGE='\033[0;33m' 31 | YELLOW='\033[1;33m' 32 | BLUE='\033[0;34m' 33 | BLUELIGHT='\033[1;34m' 34 | PURPLE='\033[0;35m' 35 | PURPLELIGHT='\033[1;35m' 36 | CYAN='\033[0;36m' 37 | CYANLIGHT='\033[1;36m' 38 | WHITE='\033[1;37m' 39 | # 40 | NC='\033[0m' # No Color 41 | BOLD='\033[1m' 42 | UNDERLINE='\033[4m' 43 | 44 | # ------------------------------------------------ 45 | --------------------------------------------------------------------------------