├── README.md └── maintenance.sh /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL 2 | 3 | # PostgreSQL Maintenance Tool 4 | 5 | This shell script is designed to manage and monitor PostgreSQL databases. It includes 16 useful functions for database administration, monitoring, and optimization. 6 | 7 | ## Installation 8 | 1. Download file: https://github.com/rashidov9797/PostgreSQL/archive/refs/tags/v2.tar.gz 9 | 2. Make it executable: 10 | chmod +x maintenance.sh 11 | 12 | 3. Run the script: 13 | ./maintenance.sh 14 | 15 | 16 | 17 | Features 18 | 19 | 1. Version Info 20 | 2. Schema List 21 | 3. Active Sessions 22 | 4. Lock List 23 | 5. Dead Tuple List 24 | 6. Tablespace Info 25 | 7. Top 15 Queries 26 | 8. Vacuum Info 27 | 9. Commit & Hit Ratio 28 | 10. Replication Delay 29 | 11. Object Count by Schema 30 | 12. Index Usage Statistics 31 | 13. Unused Indexes 32 | 14. Long Running Queries 33 | 15. Vacuum Info 34 | 16. Switch Database/User 35 | 36 | ![image](https://github.com/user-attachments/assets/a36db033-a503-4f84-8067-ce2ba8b074a4) 37 | 38 | 39 | Usage 40 | 41 | When prompted with Select an option:, enter a number between 1 and 16. 42 | 43 | Use 99 to exit the script. 44 | 45 | Switch Database/User: Allows switching between databases and users. 46 | 47 | 48 | Contact 49 | For questions or feedback, reach out at: azikrashidov1103@gmail.com 50 | 51 | -------------------------------------------------------------------------------- /maintenance.sh: -------------------------------------------------------------------------------- 1 | 2 | #!/bin/bash 3 | 4 | # Define colors 5 | RED='\e[31m' 6 | GREEN='\e[32m' 7 | YELLOW='\e[33m' 8 | BLUE='\e[34m' 9 | BOLD='\e[1m' 10 | RESET='\e[0m' 11 | 12 | # Function to display the initial header 13 | Display_Header() { 14 | echo -e "${BLUE}========================================${RESET}" 15 | echo -e "${BLUE} PostgreSQL Maintenance Tool${RESET}" 16 | echo -e "${BLUE} Create Date: 2025-04-01${RESET}" 17 | echo -e "${BLUE} Owner: Azamat${RESET}" 18 | echo -e "${BLUE} My email: azikrashidov1103@gmail.com${RESET}" 19 | echo -e "${BLUE}========================================${RESET}" 20 | } 21 | 22 | # Function to display the initial info (only at startup) 23 | Display_Initial_Info() { 24 | echo -e "${BLUE}========================================${RESET}" 25 | echo -e "${BLUE} PostgreSQL Maintenance Tool${RESET}" 26 | echo -e "${BLUE} Date: $(date +%Y-%m-%d\ %H:%M:%S)${RESET}" 27 | echo -e "${BLUE}========================================${RESET}" 28 | } 29 | 30 | # Function to display the menu (only shown initially) 31 | Display_Menu() { 32 | echo -e "${BLUE}========================================${RESET}" 33 | echo -e "${BLUE} PostgreSQL Maintenance Tool${RESET}" 34 | echo -e "${BLUE} Date: $(date +%Y-%m-%d\ %H:%M:%S)${RESET}" 35 | echo -e "${BLUE}========================================${RESET}" 36 | echo -e "${YELLOW} 1. Version Info${RESET}" 37 | echo -e "${YELLOW} 2. Schema List${RESET}" 38 | echo -e "${YELLOW} 3. Active Sessions${RESET}" 39 | echo -e "${YELLOW} 4. Lock List${RESET}" 40 | echo -e "${YELLOW} 5. Dead Tuple List${RESET}" 41 | echo -e "${YELLOW} 6. Tablespace Info${RESET}" 42 | echo -e "${YELLOW} 7. Top 15 Queries${RESET}" 43 | echo -e "${YELLOW} 8. Vacuum Info (Basic)${RESET}" 44 | echo -e "${YELLOW} 9. Commit & Hit Ratio${RESET}" 45 | echo -e "${YELLOW} 10. Replication Delay${RESET}" 46 | echo -e "${YELLOW} 11. Object Count by Schema${RESET}" 47 | echo -e "${YELLOW} 12. Index Usage Statistics${RESET}" 48 | echo -e "${YELLOW} 13. Unused Indexes${RESET}" 49 | echo -e "${YELLOW} 14. Long Running Queries${RESET}" 50 | echo -e "${YELLOW} 15. Vacuum Info (Detailed)${RESET}" 51 | echo -e "${YELLOW} 16. Switch Database/User${RESET}" 52 | echo -e "${YELLOW} 99. Exit${RESET}" 53 | echo -e "${BLUE}========================================${RESET}" 54 | } 55 | 56 | # Function to show database, user, and schema info after selection 57 | Show_Context() { 58 | local schemas=$(psql -P pager=off -d "$D" -U "$U" -t -c "SHOW search_path;" | tr -d ' ') 59 | echo -e "${YELLOW}Database: $D | User: $U | Schema: $schemas${RESET}" 60 | echo -e "${BLUE}-------------------------------------${RESET}" 61 | } 62 | 63 | # Function to display function name with stars 64 | Show_Function_Name() { 65 | local func_name="$1" 66 | echo -e "${GREEN}=====================${RESET}" 67 | echo -e "${GREEN}${BOLD}$func_name${RESET}" 68 | echo -e "${GREEN}=====================${RESET}" 69 | } 70 | 71 | # Function to switch database and user 72 | Switch_Database_User() { 73 | echo -e "${YELLOW}Current Database: $D | Current User: $U${RESET}" 74 | echo -e "${BLUE}Available databases:${RESET}" 75 | psql -P pager=off -d "$INITIAL_DB" -U "$U" -c "SELECT datname AS database, pg_catalog.pg_get_userbyid(datdba) AS owner FROM pg_catalog.pg_database WHERE datname NOT IN ('template0', 'template1') ORDER BY 1;" 76 | echo -n -e "${BLUE}Enter new database name (or press Enter to keep '$D'): ${RESET}" 77 | read new_D 78 | echo -n -e "${BLUE}Enter new user name (or press Enter to keep '$U'): ${RESET}" 79 | read new_U 80 | 81 | D=${new_D:-$D} 82 | U=${new_U:-$U} 83 | echo -e "${GREEN}Switched to - Database: $D | User: $U${RESET}" 84 | } 85 | 86 | # Main function to handle user input and menu navigation 87 | main() { 88 | Display_Header 89 | echo " " 90 | Display_Initial_Info 91 | echo " " 92 | 93 | # Ask for initial username first 94 | echo -n -e "${BLUE}Enter username: ${RESET}" 95 | read U 96 | if [ -z "$U" ]; then 97 | echo -e "${RED}Error: Username cannot be empty. Exiting.${RESET}" 98 | exit 1 99 | fi 100 | 101 | # Set a default initial database for listing databases 102 | INITIAL_DB="postgres" 103 | 104 | # Check if the user exists and list databases 105 | psql -P pager=off -d "$INITIAL_DB" -U "$U" -c "SELECT datname AS database, pg_catalog.pg_get_userbyid(datdba) AS owner FROM pg_catalog.pg_database WHERE datname NOT IN ('template0', 'template1') ORDER BY 1;" 2>/dev/null 106 | if [ $? -ne 0 ]; then 107 | echo -e "${RED}Error: Could not connect with user '$U'. Please check the username and try again.${RESET}" 108 | exit 1 109 | fi 110 | 111 | echo -n -e "${BLUE}Enter database name: ${RESET}" 112 | read D 113 | 114 | D=${D:-$INITIAL_DB} # Default to 'postgres' if no input 115 | 116 | Display_Menu 117 | 118 | while true; do 119 | echo -n -e "${BLUE}Select an option: ${RESET}" 120 | read MENU 121 | case $MENU in 122 | 1) Show_Function_Name "Version_Info"; Show_Context; Version_Info ;; 123 | 2) Show_Function_Name "Schema_List"; Show_Context; Schema_List ;; 124 | 3) Show_Function_Name "Active_Sessions"; Show_Context; Active_Sessions ;; 125 | 4) Show_Function_Name "Lock_List"; Show_Context; Lock_List ;; 126 | 5) Show_Function_Name "Dead_Tuple_List"; Show_Context; Dead_Tuple_List ;; 127 | 6) Show_Function_Name "Tablespace_Info"; Show_Context; Tablespace_Info ;; 128 | 7) Show_Function_Name "Top_Queries"; Show_Context; Top_Queries ;; 129 | 8) Show_Function_Name "Vacuum_Info"; Show_Context; Vacuum_Info ;; 130 | 9) Show_Function_Name "Commit_Hit_Ratio"; Show_Context; Commit_Hit_Ratio ;; 131 | 10) Show_Function_Name "Replication_Delay"; Show_Context; Replication_Delay ;; 132 | 11) Show_Function_Name "Object_Count_by_Schema"; Show_Context; Object_Count_by_Schema ;; 133 | 12) Show_Function_Name "Index_Usage_Stats"; Show_Context; Index_Usage_Stats ;; 134 | 13) Show_Function_Name "Unused_Indexes"; Show_Context; Unused_Indexes ;; 135 | 14) Show_Function_Name "Long_Running_Queries"; Show_Context; Long_Running_Queries ;; 136 | 15) Show_Function_Name "Vacuum_Info_Detailed"; Show_Context; Vacuum_Info_Detailed ;; 137 | 16) Show_Function_Name "Switch_Database_User"; Switch_Database_User ;; 138 | 99) break ;; 139 | *) echo -e "${RED}Invalid option${RESET}" ;; 140 | esac 141 | done 142 | } 143 | 144 | # 1. Version Info - Displays PostgreSQL version and startup time 145 | Version_Info() { 146 | psql -P pager=off -d "$D" -U "$U" -c " 147 | SELECT 'Port: ' || setting AS port_info FROM pg_settings WHERE name = 'port' 148 | UNION ALL 149 | SELECT 'Version: ' || version() AS version_info 150 | UNION ALL 151 | SELECT 'Startup Time: ' || pg_postmaster_start_time() AS startup_time;" 152 | } 153 | 154 | # 2. Schema List - Lists all non-system schemas 155 | Schema_List() { 156 | psql -P pager=off -d "$D" -U "$U" -c " 157 | SELECT nspname AS schema_name, pg_catalog.pg_get_userbyid(nspowner) AS owner 158 | FROM pg_catalog.pg_namespace 159 | WHERE nspname !~ '^pg_' AND nspname <> 'information_schema' 160 | ORDER BY 1;" 161 | } 162 | 163 | # 3. Active Sessions - Shows currently active sessions 164 | Active_Sessions() { 165 | psql -P pager=off -d "$D" -U "$U" -c " 166 | SELECT pid AS process_id, usename AS username, datname AS database, 167 | client_addr AS client_address, state, 168 | to_char(now() - query_start, 'HH24:MI:SS') AS elapsed_time, 169 | substr(query, 1, 30) AS query 170 | FROM pg_stat_activity 171 | WHERE state = 'active' 172 | ORDER BY pid DESC;" 173 | } 174 | 175 | # 4. Lock List - Displays current locks 176 | Lock_List() { 177 | psql -P pager=off -d "$D" -U "$U" -c " 178 | SELECT k.datname AS database, k.usename AS username, t.relname AS relation, 179 | l.pid, l.mode, l.granted, substr(k.query, 1, 50) AS query 180 | FROM pg_locks l 181 | JOIN pg_stat_activity k ON l.pid = k.pid 182 | JOIN pg_stat_all_tables t ON l.relation = t.relid 183 | WHERE k.datname = '$D' 184 | ORDER BY l.pid DESC;" 185 | } 186 | 187 | # 5. Dead Tuple List - Shows tables with dead tuples 188 | Dead_Tuple_List() { 189 | psql -P pager=off -d "$D" -U "$U" -c " 190 | SELECT n.nspname AS schema_name, c.relname AS table_name, 191 | pg_stat_get_live_tuples(c.oid) AS live_tuples, 192 | pg_stat_get_dead_tuples(c.oid) AS dead_tuples, 193 | round(100.0 * pg_stat_get_dead_tuples(c.oid) / (pg_stat_get_live_tuples(c.oid) + pg_stat_get_dead_tuples(c.oid)), 2) AS dead_tuple_ratio 194 | FROM pg_class c 195 | JOIN pg_namespace n ON n.oid = c.relnamespace 196 | WHERE pg_stat_get_live_tuples(c.oid) > 0 AND c.relkind = 'r' 197 | ORDER BY dead_tuples DESC;" 198 | } 199 | 200 | # 6. Tablespace Info - Displays tablespace details 201 | Tablespace_Info() { 202 | psql -P pager=off -d "$D" -U "$U" -c " 203 | SELECT spcname AS tablespace_name, pg_catalog.pg_get_userbyid(spcowner) AS owner, 204 | pg_catalog.pg_tablespace_location(oid) AS location, 205 | pg_size_pretty(pg_tablespace_size(oid)) AS size 206 | FROM pg_tablespace 207 | ORDER BY 1;" 208 | } 209 | 210 | # 7. Top 15 Queries - Shows top 15 queries by execution time 211 | Top_Queries() { 212 | psql -P pager=off -d "$D" -U "$U" -c " 213 | DO \$\$ 214 | BEGIN 215 | IF NOT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements') THEN 216 | CREATE EXTENSION pg_stat_statements; 217 | RAISE NOTICE 'pg_stat_statements extension created'; 218 | END IF; 219 | END\$\$; 220 | SELECT queryid, calls, round(total_plan_time::numeric, 2) AS total_time_ms, 221 | round(mean_plan_time::numeric, 2) AS mean_time_ms, rows, query 222 | FROM pg_stat_statements 223 | WHERE dbid = (SELECT oid FROM pg_database WHERE datname = '$D') 224 | ORDER BY total_plan_time DESC 225 | LIMIT 15;" 226 | } 227 | 228 | # 8. Vacuum Info (Basic) - Displays basic vacuum-related statistics 229 | Vacuum_Info() { 230 | psql -P pager=off -d "$D" -U "$U" -c " 231 | SELECT n.nspname AS schema_name, c.relname AS table_name, 232 | pg_stat_get_live_tuples(c.oid) AS live_tuples, 233 | pg_stat_get_dead_tuples(c.oid) AS dead_tuples, 234 | pg_size_pretty(pg_total_relation_size(c.oid)) AS total_size 235 | FROM pg_class c 236 | JOIN pg_namespace n ON n.oid = c.relnamespace 237 | WHERE c.relkind = 'r' 238 | ORDER BY dead_tuples DESC;" 239 | } 240 | 241 | # 9. Commit & Hit Ratio - Shows commit and cache hit ratios 242 | Commit_Hit_Ratio() { 243 | psql -P pager=off -d "$D" -U "$U" -c " 244 | SELECT d.datname AS database, u.usename AS username, 245 | round(100.0 * sd.blks_hit / (sd.blks_read + sd.blks_hit), 2) AS cache_hit_ratio, 246 | round(100.0 * sd.xact_commit / (sd.xact_commit + sd.xact_rollback), 2) AS commit_ratio 247 | FROM pg_stat_database sd 248 | JOIN pg_database d ON d.oid = sd.datid 249 | JOIN pg_user u ON u.usesysid = d.datdba 250 | WHERE sd.blks_read + sd.blks_hit > 0 OR sd.xact_commit + sd.xact_rollback > 0;" 251 | } 252 | 253 | # 10. Replication Delay - Displays replication status and delay 254 | Replication_Delay() { 255 | psql -P pager=off -d "$D" -U "$U" -c " 256 | SELECT CASE WHEN pg_is_in_recovery() THEN 'Standby' ELSE 'Primary' END AS server_type; 257 | SELECT pg_current_wal_lsn() AS current_lsn, sent_lsn, 258 | pg_wal_lsn_diff(pg_current_wal_lsn(), sent_lsn) AS primary_lsn_diff 259 | FROM pg_stat_replication 260 | WHERE state = 'streaming' AND sent_lsn IS NOT NULL; 261 | SELECT pg_last_wal_receive_lsn() AS receive_lsn, pg_last_wal_replay_lsn() AS replay_lsn, 262 | COALESCE(round(extract(epoch FROM now() - pg_last_xact_replay_timestamp())), 0) AS delay_seconds 263 | FROM pg_stat_replication LIMIT 1;" 264 | } 265 | 266 | # 11. Object Count by Schema - Counts objects per schema 267 | Object_Count_by_Schema() { 268 | psql -P pager=off -d "$D" -U "$U" -c " 269 | SELECT n.nspname AS schema_name, 270 | COUNT(CASE WHEN c.relkind = 'r' THEN 1 END) AS tables, 271 | COUNT(CASE WHEN c.relkind = 'i' THEN 1 END) AS indexes, 272 | COUNT(CASE WHEN c.relkind = 'S' THEN 1 END) AS sequences, 273 | COUNT(CASE WHEN c.relkind = 'v' THEN 1 END) AS views 274 | FROM pg_class c 275 | JOIN pg_namespace n ON n.oid = c.relnamespace 276 | WHERE n.nspname !~ '^pg_' AND n.nspname <> 'information_schema' 277 | GROUP BY n.nspname 278 | ORDER BY n.nspname;" 279 | } 280 | 281 | # 12. Index Usage Statistics - Shows index usage and size 282 | Index_Usage_Stats() { 283 | psql -P pager=off -d "$D" -U "$U" -c " 284 | SELECT 285 | n.nspname AS schema_name, 286 | t.relname AS table_name, 287 | i.relname AS index_name, 288 | pg_size_pretty(pg_relation_size(i.oid)) AS index_size, 289 | idx_scan AS index_scans, 290 | CASE 291 | WHEN idx_scan = 0 THEN 'Unused' 292 | ELSE 'Used' 293 | END AS usage_status 294 | FROM pg_stat_all_indexes s 295 | JOIN pg_class t ON s.relid = t.oid 296 | JOIN pg_class i ON s.indexrelid = i.oid 297 | JOIN pg_namespace n ON n.oid = t.relnamespace 298 | WHERE n.nspname !~ '^pg_' AND n.nspname <> 'information_schema' 299 | ORDER BY idx_scan ASC, index_size DESC;" 300 | } 301 | 302 | # 13. Unused Indexes - Lists indexes with zero scans 303 | Unused_Indexes() { 304 | psql -P pager=off -d "$D" -U "$U" -c " 305 | SELECT 306 | n.nspname AS schema_name, 307 | t.relname AS table_name, 308 | i.relname AS index_name, 309 | pg_size_pretty(pg_relation_size(i.oid)) AS index_size, 310 | idx_scan AS index_scans 311 | FROM pg_stat_all_indexes s 312 | JOIN pg_class t ON s.relid = t.oid 313 | JOIN pg_class i ON s.indexrelid = i.oid 314 | JOIN pg_namespace n ON n.oid = t.relnamespace 315 | WHERE n.nspname !~ '^pg_' AND n.nspname <> 'information_schema' 316 | AND idx_scan = 0 317 | ORDER BY index_size DESC;" 318 | } 319 | 320 | # 14. Long Running Queries - Shows queries running longer than 1 minute 321 | Long_Running_Queries() { 322 | psql -P pager=off -d "$D" -U "$U" -c " 323 | SELECT 324 | pid AS process_id, 325 | usename AS username, 326 | datname AS database, 327 | to_char(now() - query_start, 'HH24:MI:SS') AS duration, 328 | state, 329 | substr(query, 1, 50) AS query 330 | FROM pg_stat_activity 331 | WHERE state = 'active' 332 | AND now() - query_start > interval '1 minute' 333 | ORDER BY duration DESC;" 334 | } 335 | 336 | # 15. Vacuum Info (Detailed) - Shows detailed vacuum and autovacuum stats 337 | Vacuum_Info_Detailed() { 338 | psql -P pager=off -d "$D" -U "$U" -c " 339 | SELECT 340 | n.nspname AS schema_name, 341 | c.relname AS table_name, 342 | pg_stat_get_live_tuples(c.oid) AS live_tuples, 343 | pg_stat_get_dead_tuples(c.oid) AS dead_tuples, 344 | to_char(last_vacuum, 'YYYY-MM-DD HH24:MI:SS') AS last_vacuum, 345 | to_char(last_autovacuum, 'YYYY-MM-DD HH24:MI:SS') AS last_autovacuum, 346 | vacuum_count AS manual_vacuum_count, 347 | autovacuum_count AS auto_vacuum_count, 348 | pg_size_pretty(pg_total_relation_size(c.oid)) AS total_size 349 | FROM pg_class c 350 | JOIN pg_namespace n ON n.oid = c.relnamespace 351 | JOIN pg_stat_all_tables s ON s.relid = c.oid 352 | WHERE c.relkind = 'r' 353 | ORDER BY dead_tuples DESC;" 354 | } 355 | 356 | # Start the script 357 | main $* 358 | --------------------------------------------------------------------------------