├── LICENSE ├── README.md ├── SQL ├── age_consume.sql ├── age_consume_dblvl.sql ├── age_consume_rel_lvl.sql ├── all_relation.sql ├── all_toast.sql ├── bgworker_checkpoint_state.sql ├── current_connection.sql ├── current_query.sql ├── database_status.sql ├── find_indexed_columns_high_null_frac.sql ├── find_unused_indexes.sql ├── get_all_privileges.sql ├── get_oldest_xact.sql ├── get_oldest_xmin.sql ├── index_bloat.sql ├── index_create.sql ├── index_duplicate.sql ├── index_lower_efficiency.sql ├── index_state.sql ├── index_state_further.sql ├── list_table_dependencies.sql ├── lock_tree.sql ├── lock_wait_queue.sql ├── lock_wait_state.sql ├── lock_wait_state_further.sql ├── long_transaction.sql ├── partition_info.sql ├── partition_inherit_info.sql ├── partition_size.sql ├── rel_constraint.sql ├── rel_multi_index.sql ├── relation_bloat.sql ├── relation_details.sql ├── replication_primary_state_10.sql ├── replication_primary_state_13.sql ├── replication_standby_state.sql ├── single_toast.sql ├── user_member.sql ├── vacuum_need.sql ├── vacuum_queue.sql ├── vacuum_state.sql ├── wait_event.sql ├── wal_archive_state.sql ├── wal_generate_speed.sql └── xmin_horizon.sql ├── pgcheck └── pgcheck.sh /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "[]" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright [yyyy] [name of copyright owner] 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## Star History 2 | 3 | [![Star History Chart](https://api.star-history.com/svg?repos=xiongcccc/pgcheck&type=Date)](https://star-history.com/#xiongcccc/pgcheck&Date) 4 | 5 | ## Introduce 6 | 7 | pgcheck is a one-click tool to get the running status of PostgreSQL, including stream replication/lock/wait events/partition/index/relation,etc., which makes the operation and maintenance more efficient. 8 | 9 | The script currently being refactored with golang, so stay tuned! 10 | 11 | ### Note 12 | 13 | The current supported versions include 11, 12, 13, 14, and 15. Other versions may be a little incompatible, and some of them report errors, but most of them can also be used. Currently supported platform is x86. 14 | 15 | ## Usage 16 | 17 | ~~~shell 18 | Description: The utility is used to collect specified information 19 | Current Version: 1.0.4 20 | Usage: 21 | ./pgcheck relation database schema : list information about tables and indexes in the specified schema 22 | ./pgcheck relconstraint database relname : list all constraint corresponding to the specified table 23 | ./pgcheck alltoast database schema : list all toasts and their corresponding tables 24 | ./pgcheck reltoast database relname : list the toast information of the specified table 25 | ./pgcheck dbstatus : list all database status and statistics 26 | ./pgcheck index_bloat database : index bloat information (estimated value) 27 | ./pgcheck index_duplicate database : index duplicate information 28 | ./pgcheck index_low database : index low efficiency information 29 | ./pgcheck index_state database : index detail information 30 | ./pgcheck lock database : lock wait queue and lock wait state 31 | ./pgcheck checkpoint : background and checkpointer state 32 | ./pgcheck freeze database : database transaction id consuming state and detail 33 | ./pgcheck replication : streaming replication (physical) state 34 | ./pgcheck connections database : database connections and current query 35 | ./pgcheck long_transaction database : long transaction detail 36 | ./pgcheck relation_bloat database : relation bloat information (estimated value) 37 | ./pgcheck vacuum_state database : current vacuum progress information 38 | ./pgcheck vacuum_need database : show tables that need vacuum 39 | ./pgcheck index_create database : index create progress information 40 | ./pgcheck wal_archive : wal archive progress information 41 | ./pgcheck wal_generate wal_path : wal generate speed (you should provide extra wal directory) 42 | ./pgcheck wait_event database : wait event and wait event type 43 | ./pgcheck partition database : native and inherit partition info (estimated value) 44 | ./pgcheck object database user : get the objects owned by the user in the specified database 45 | ./pgcheck --help or -h : print this help information 46 | 47 | Author: xiongcc@PostgreSQL学徒, github: https://github.com/xiongcccc. 48 | If you have any feedback or suggestions, feel free to contact with me. 49 | Email: xiongcc_1994@126.com/xiongcc_1994@outlook.com. Wechat: _xiongcc 50 | ~~~ 51 | Currently supported features include: 52 | 53 | - View the table status information in the specified schema 54 | - View the information of all toast tables in the specified schema and the toast information of a specified table 55 | - View the overall status information of the database, which will be different in different versions (please specify the exact version of the psql environment variable, because the system views of different versions will be different, and the judgment is made in the code, otherwise an error may be reported) 56 | - View index bloat ratio/redundant index/inefficient index/index overall information 57 | - View index information 58 | - View lock state and lock queue 59 | - View checkpoint and background writer process status 60 | - View age and transaction id consuming detail at database level 61 | - View streaming replication status 62 | - View the number of connections and queries currently being allowed 63 | - View long transactions 64 | - View table bloat, table bloat depends on statistical information, so in order to be more accurate, it is best to do an analysis before doing it, this query will take a little time 65 | - View tables that need to execute vacuum and retrieves the oldest value for each of the vacuum operation blockers 66 | - Check the index creation progress, only supported in versions after 12, and the previous version will prompt that the view does not exist and exit 67 | - View WAL archive status 68 | - View WAL generation speed 69 | - View wait event 70 | - View partition table information, including native partitions and inherited partitions 71 | - View objects owned by a user, and member relationship 72 | 73 | The default port used is 5432. If there are multiple instances on the server, you can specify environment variables before use, such as export PGPORT=5433。 74 | 75 | If you have any feedback or suggestions, feel free to contact with me. 76 | -------------------------------------------------------------------------------- /SQL/age_consume.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | datname, 3 | age(datfrozenxid) AS frozen_xid_age, 4 | ROUND(100 * (age(datfrozenxid) / 2000000000::float)) consumed_txid_pct, 5 | 2 * 1024 ^ 3 - 1 - age(datfrozenxid) AS remaining_txid, 6 | current_setting('autovacuum_freeze_max_age')::int - age(datfrozenxid) AS remaining_aggressive_vacuum 7 | FROM 8 | pg_database; 9 | -------------------------------------------------------------------------------- /SQL/age_consume_dblvl.sql: -------------------------------------------------------------------------------- 1 | WITH max_age AS ( 2 | SELECT 3 | 2000000000 AS max_old_txid, 4 | setting AS autovacuum_freeze_max_age 5 | FROM 6 | pg_catalog.pg_settings 7 | WHERE 8 | name = 'autovacuum_freeze_max_age' 9 | ), 10 | per_database_stats AS ( 11 | SELECT 12 | datname, 13 | m.max_old_txid::int, 14 | m.autovacuum_freeze_max_age::int, 15 | age(d.datfrozenxid) AS oldest_current_txid 16 | FROM 17 | pg_catalog.pg_database d 18 | JOIN max_age m ON (TRUE) 19 | WHERE 20 | d.datallowconn 21 | ) 22 | SELECT 23 | max(oldest_current_txid) AS oldest_current_txid, 24 | max(ROUND(100 * (oldest_current_txid / max_old_txid::float))) AS consumed_txid_pct, 25 | max(ROUND(100 * (oldest_current_txid / autovacuum_freeze_max_age::float))) AS consumed_autovac_max_age 26 | FROM 27 | per_database_stats; 28 | -------------------------------------------------------------------------------- /SQL/age_consume_rel_lvl.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | c.oid::regclass, 3 | age(c.relfrozenxid), 4 | pg_size_pretty(pg_total_relation_size(c.oid)) 5 | FROM 6 | pg_class c 7 | JOIN pg_namespace n ON c.relnamespace = n.oid 8 | WHERE 9 | relkind IN ('r', 't', 'm') 10 | AND n.nspname NOT IN ('pg_toast') 11 | ORDER BY 12 | 2 DESC 13 | LIMIT 50; 14 | -------------------------------------------------------------------------------- /SQL/all_relation.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | *, 3 | pg_size_pretty(table_bytes) AS table, 4 | pg_size_pretty(index_bytes) AS index, 5 | pg_size_pretty(total_bytes) AS total 6 | FROM ( 7 | SELECT 8 | *, 9 | total_bytes - index_bytes - COALESCE(toast_bytes, 0) AS table_bytes 10 | FROM ( 11 | SELECT 12 | c.oid, 13 | c.relfilenode, 14 | CASE WHEN c.oid = c.relfilenode THEN 15 | 'NO' 16 | ELSE 17 | 'YES' 18 | END AS has_been_rewrite, 19 | nspname AS table_schema, 20 | relname AS table_name, 21 | c.reltuples AS row_estimate, 22 | pg_total_relation_size(c.oid) AS total_bytes, 23 | pg_indexes_size(c.oid) AS index_bytes, 24 | pg_total_relation_size(reltoastrelid) AS toast_bytes 25 | FROM 26 | pg_class c 27 | LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 28 | WHERE 29 | relkind = 'r') a) a 30 | WHERE 31 | table_schema = 'public' 32 | ORDER BY 33 | total_bytes DESC; 34 | -------------------------------------------------------------------------------- /SQL/all_toast.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | n.nspname as schema, 3 | s.oid::regclass as relname, 4 | s.reltoastrelid::regclass as toast_name, 5 | pg_relation_size(s.reltoastrelid) AS toast_size 6 | FROM 7 | pg_class s join pg_namespace n 8 | on s.relnamespace = n.oid 9 | WHERE 10 | relkind = 'r' 11 | AND reltoastrelid <> 0 12 | AND n.nspname = 'public' 13 | ORDER BY 14 | 3 DESC; 15 | -------------------------------------------------------------------------------- /SQL/bgworker_checkpoint_state.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | checkpoints_timed + checkpoints_req AS total_checkpoints, 3 | pg_size_pretty(block_size * buffers_clean ) AS bgworker_total_writen, 4 | pg_size_pretty(block_size * buffers_checkpoint ) AS chkpointer_total_writen, 5 | pg_size_pretty(block_size * buffers_backend ) AS backend_total_writen, 6 | pg_size_pretty(block_size * buffers_checkpoint / (checkpoints_timed + checkpoints_req)) AS checkpoint_write_avg, 7 | EXTRACT(EPOCH FROM (now() - pg_postmaster_start_time())) / (checkpoints_timed + checkpoints_req) / 60 AS minutes_between_checkpoints, 8 | buffers_backend_fsync 9 | FROM 10 | pg_stat_bgwriter, 11 | ( 12 | SELECT current_setting('block_size')::int AS block_size) AS bs 13 | -------------------------------------------------------------------------------- /SQL/current_connection.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | datname, 3 | count(*) AS open, 4 | count(*) FILTER (WHERE state = 'active') AS active, 5 | count(*) FILTER (WHERE state = 'idle') AS idle, 6 | count(*) FILTER (WHERE state = 'idle in transaction') AS idle_in_trans 7 | FROM 8 | pg_stat_activity 9 | GROUP BY 10 | ROLLUP (1); 11 | -------------------------------------------------------------------------------- /SQL/current_query.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | pid, 3 | age(clock_timestamp(), query_start), 4 | usename, 5 | application_name, 6 | wait_event, 7 | wait_event_type, 8 | query 9 | FROM 10 | pg_stat_activity 11 | WHERE 12 | state != 'idle' 13 | AND 14 | query NOT ILIKE '%pg_stat_activity%' 15 | ORDER BY 16 | query_start DESC; 17 | -------------------------------------------------------------------------------- /SQL/database_status.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | datname AS database_name, 3 | pg_size_pretty(pg_database_size(datname)) AS database_size, 4 | 100 * blks_hit / (blks_hit + blks_read) || ' %' AS cache_hit_ratio, 5 | 100 * xact_commit / (xact_commit + xact_rollback) || ' %' AS commit_ratio, 6 | conflicts, 7 | temp_files, 8 | pg_size_pretty(temp_bytes) AS temp_bytes, 9 | deadlocks, 10 | checksum_failures, 11 | blk_read_time, 12 | blk_write_time, 13 | session_time, 14 | active_time, 15 | idle_in_transaction_time, 16 | sessions, 17 | sessions_abandoned, 18 | sessions_fatal, 19 | sessions_killed 20 | FROM 21 | pg_stat_database 22 | WHERE (blks_hit + blks_read) > 0 23 | AND datname NOT LIKE '%template%'; 24 | -------------------------------------------------------------------------------- /SQL/find_indexed_columns_high_null_frac.sql: -------------------------------------------------------------------------------- 1 | -- Credit: https://hakibenita.com/postgresql-unused-index-size#clearing-bloat-in-indexes 2 | -- Find indexed columns with high null_frac 3 | SELECT 4 | c.oid, 5 | c.relname AS index, 6 | pg_size_pretty(pg_relation_size(c.oid)) AS index_size, 7 | i.indisunique AS unique, 8 | a.attname AS indexed_column, 9 | CASE s.null_frac 10 | WHEN 0 THEN '' 11 | ELSE to_char(s.null_frac * 100, '999.00%') 12 | END AS null_frac, 13 | pg_size_pretty((pg_relation_size(c.oid) * s.null_frac)::bigint) AS expected_saving 14 | -- Uncomment to include the index definition 15 | --, ixs.indexdef 16 | 17 | FROM 18 | pg_class c 19 | JOIN pg_index i ON i.indexrelid = c.oid 20 | JOIN pg_attribute a ON a.attrelid = c.oid 21 | JOIN pg_class c_table ON c_table.oid = i.indrelid 22 | JOIN pg_indexes ixs ON c.relname = ixs.indexname 23 | LEFT JOIN pg_stats s ON s.tablename = c_table.relname AND a.attname = s.attname 24 | 25 | WHERE 26 | -- Primary key cannot be partial 27 | NOT i.indisprimary 28 | 29 | -- Exclude already partial indexes 30 | AND i.indpred IS NULL 31 | 32 | -- Exclude composite indexes 33 | AND array_length(i.indkey, 1) = 1 34 | 35 | -- Larger than 10MB 36 | AND pg_relation_size(c.oid) > 10 * 1024 ^ 2 37 | 38 | ORDER BY 39 | pg_relation_size(c.oid) * s.null_frac DESC; 40 | -------------------------------------------------------------------------------- /SQL/find_unused_indexes.sql: -------------------------------------------------------------------------------- 1 | -- Credit: http://www.databasesoup.com/2014/04/new-new-index-bloat-query.html 2 | -- Original: https://gist.github.com/jberkus/6b1bcaf7724dfc2a54f3 3 | 4 | -- NOTES: 5 | 6 | WITH table_scans as ( 7 | SELECT relid, 8 | tables.idx_scan + tables.seq_scan as all_scans, 9 | ( tables.n_tup_ins + tables.n_tup_upd + tables.n_tup_del ) as writes, 10 | pg_relation_size(relid) as table_size 11 | FROM pg_stat_user_tables as tables 12 | ), 13 | all_writes as ( 14 | SELECT sum(writes) as total_writes 15 | FROM table_scans 16 | ), 17 | indexes as ( 18 | SELECT idx_stat.relid, idx_stat.indexrelid, 19 | idx_stat.schemaname, idx_stat.relname as tablename, 20 | idx_stat.indexrelname as indexname, 21 | idx_stat.idx_scan, 22 | pg_relation_size(idx_stat.indexrelid) as index_bytes, 23 | indexdef ~* 'USING btree' AS idx_is_btree 24 | FROM pg_stat_user_indexes as idx_stat 25 | JOIN pg_index 26 | USING (indexrelid) 27 | JOIN pg_indexes as indexes 28 | ON idx_stat.schemaname = indexes.schemaname 29 | AND idx_stat.relname = indexes.tablename 30 | AND idx_stat.indexrelname = indexes.indexname 31 | WHERE pg_index.indisunique = FALSE 32 | ), 33 | index_ratios AS ( 34 | SELECT schemaname, tablename, indexname, 35 | idx_scan, all_scans, 36 | round(( CASE WHEN all_scans = 0 THEN 0.0::NUMERIC 37 | ELSE idx_scan::NUMERIC/all_scans * 100 END),2) as index_scan_pct, 38 | writes, 39 | round((CASE WHEN writes = 0 THEN idx_scan::NUMERIC ELSE idx_scan::NUMERIC/writes END),2) 40 | as scans_per_write, 41 | pg_size_pretty(index_bytes) as index_size, 42 | pg_size_pretty(table_size) as table_size, 43 | idx_is_btree, index_bytes 44 | FROM indexes 45 | JOIN table_scans 46 | USING (relid) 47 | ), 48 | index_groups AS ( 49 | SELECT 'Never Used Indexes' as reason, *, 1 as grp 50 | FROM index_ratios 51 | WHERE 52 | idx_scan = 0 53 | and idx_is_btree 54 | UNION ALL 55 | SELECT 'Low Scans, High Writes' as reason, *, 2 as grp 56 | FROM index_ratios 57 | WHERE 58 | scans_per_write <= 1 59 | and index_scan_pct < 10 60 | and idx_scan > 0 61 | and writes > 100 62 | and idx_is_btree 63 | UNION ALL 64 | SELECT 'Seldom Used Large Indexes' as reason, *, 3 as grp 65 | FROM index_ratios 66 | WHERE 67 | index_scan_pct < 5 68 | and scans_per_write > 1 69 | and idx_scan > 0 70 | and idx_is_btree 71 | and index_bytes > 100000000 72 | UNION ALL 73 | SELECT 'High-Write Large Non-Btree' as reason, index_ratios.*, 4 as grp 74 | FROM index_ratios, all_writes 75 | WHERE 76 | ( writes::NUMERIC / ( total_writes + 1 ) ) > 0.02 77 | AND NOT idx_is_btree 78 | AND index_bytes > 100000000 79 | ORDER BY grp, index_bytes DESC ) 80 | SELECT reason, schemaname, tablename, indexname, 81 | index_scan_pct, scans_per_write, index_size, table_size 82 | FROM index_groups; 83 | -------------------------------------------------------------------------------- /SQL/get_all_privileges.sql: -------------------------------------------------------------------------------- 1 | SELECT r.rolname AS user_name, 2 | c.oid::regclass AS table_name, 3 | p.perm AS privilege_type 4 | FROM pg_class c CROSS JOIN 5 | pg_roles r CROSS JOIN 6 | unnest(ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER']) p(perm) 7 | WHERE relkind = 'r' AND 8 | relnamespace NOT IN (SELECT oid FROM pg_namespace WHERE nspname in ('pg_catalog','information_schema')) AND 9 | has_table_privilege(rolname, c.oid, p.perm); 10 | -------------------------------------------------------------------------------- /SQL/get_oldest_xact.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | ( 3 | SELECT 4 | max(age(backend_xmin)) 5 | FROM 6 | pg_stat_activity) AS oldest_running_xact, 7 | ( 8 | SELECT 9 | max(age(TRANSACTION)) 10 | FROM 11 | pg_prepared_xacts) AS oldest_prepared_xact, 12 | ( 13 | SELECT 14 | max(age(xmin)) 15 | FROM 16 | pg_replication_slots) AS oldest_replication_slot, 17 | ( 18 | SELECT 19 | max(age(backend_xmin)) 20 | FROM 21 | pg_stat_replication) AS oldest_replica_xact; 22 | -------------------------------------------------------------------------------- /SQL/get_oldest_xmin.sql: -------------------------------------------------------------------------------- 1 | with a as ( 2 | (select 'pg_stat_activity' as src, xact_start, usename,datname, query, backend_xid, backend_xmin 3 | from pg_stat_activity 4 | where backend_xid = xid(pg_snapshot_xmin(pg_current_snapshot())) 5 | or backend_xmin = xid(pg_snapshot_xmin(pg_current_snapshot())) 6 | order by xact_start limit 1 ) 7 | union all 8 | (select '2pc' as src, prepared as xact_start, owner as usename, database as datname, gid as query, transaction as backend_xid, transaction as backend_xmin 9 | from pg_prepared_xacts 10 | where transaction = xid(pg_snapshot_xmin(pg_current_snapshot())) 11 | order by prepared limit 1 ) 12 | ) 13 | select * from a order by xact_start limit 1; 14 | -------------------------------------------------------------------------------- /SQL/index_bloat.sql: -------------------------------------------------------------------------------- 1 | WITH btree_index_atts AS ( 2 | SELECT pg_namespace.nspname, 3 | indexclass.relname AS index_name, 4 | indexclass.reltuples, 5 | indexclass.relpages, 6 | pg_index.indrelid, 7 | pg_index.indexrelid, 8 | indexclass.relam, 9 | tableclass.relname AS tablename, 10 | (regexp_split_to_table((pg_index.indkey)::text, ' '::text))::smallint AS attnum, 11 | pg_index.indexrelid AS index_oid 12 | FROM ((((pg_index 13 | JOIN pg_class indexclass ON ((pg_index.indexrelid = indexclass.oid))) 14 | JOIN pg_class tableclass ON ((pg_index.indrelid = tableclass.oid))) 15 | JOIN pg_namespace ON ((pg_namespace.oid = indexclass.relnamespace))) 16 | JOIN pg_am ON ((indexclass.relam = pg_am.oid))) 17 | WHERE ((pg_am.amname = 'btree'::name) AND (indexclass.relpages > 0)) 18 | ), index_item_sizes AS ( 19 | SELECT ind_atts.nspname, 20 | ind_atts.index_name, 21 | ind_atts.reltuples, 22 | ind_atts.relpages, 23 | ind_atts.relam, 24 | ind_atts.indrelid AS table_oid, 25 | ind_atts.index_oid, 26 | (current_setting('block_size'::text))::numeric AS bs, 27 | 8 AS maxalign, 28 | 24 AS pagehdr, 29 | CASE 30 | WHEN (max(COALESCE(pg_stats.null_frac, (0)::real)) = (0)::double precision) THEN 2 31 | ELSE 6 32 | END AS index_tuple_hdr, 33 | sum((((1)::double precision - COALESCE(pg_stats.null_frac, (0)::real)) * (COALESCE(pg_stats.avg_width, 1024))::double precision)) AS nulldatawidth 34 | FROM ((pg_attribute 35 | JOIN btree_index_atts ind_atts ON (((pg_attribute.attrelid = ind_atts.indexrelid) AND (pg_attribute.attnum = ind_atts.attnum)))) 36 | JOIN pg_stats ON (((pg_stats.schemaname = ind_atts.nspname) AND (((pg_stats.tablename = ind_atts.tablename) AND ((pg_stats.attname)::text = pg_get_indexdef(pg_attribute.attrelid, (pg_attribute.attnum)::integer, true))) OR ((pg_stats.tablename = ind_atts.index_name) AND (pg_stats.attname = pg_attribute.attname)))))) 37 | WHERE (pg_attribute.attnum > 0) 38 | GROUP BY ind_atts.nspname, ind_atts.index_name, ind_atts.reltuples, ind_atts.relpages, ind_atts.relam, ind_atts.indrelid, ind_atts.index_oid, (current_setting('block_size'::text))::numeric, 8::integer 39 | ), index_aligned_est AS ( 40 | SELECT index_item_sizes.maxalign, 41 | index_item_sizes.bs, 42 | index_item_sizes.nspname, 43 | index_item_sizes.index_name, 44 | index_item_sizes.reltuples, 45 | index_item_sizes.relpages, 46 | index_item_sizes.relam, 47 | index_item_sizes.table_oid, 48 | index_item_sizes.index_oid, 49 | COALESCE(ceil((((index_item_sizes.reltuples * ((((((((6 + index_item_sizes.maxalign) - 50 | CASE 51 | WHEN ((index_item_sizes.index_tuple_hdr % index_item_sizes.maxalign) = 0) THEN index_item_sizes.maxalign 52 | ELSE (index_item_sizes.index_tuple_hdr % index_item_sizes.maxalign) 53 | END))::double precision + index_item_sizes.nulldatawidth) + (index_item_sizes.maxalign)::double precision) - ( 54 | CASE 55 | WHEN (((index_item_sizes.nulldatawidth)::integer % index_item_sizes.maxalign) = 0) THEN index_item_sizes.maxalign 56 | ELSE ((index_item_sizes.nulldatawidth)::integer % index_item_sizes.maxalign) 57 | END)::double precision))::numeric)::double precision) / ((index_item_sizes.bs - (index_item_sizes.pagehdr)::numeric))::double precision) + (1)::double 58 | precision)), (0)::double precision) AS expected 59 | FROM index_item_sizes 60 | ), raw_bloat AS ( 61 | SELECT current_database() AS dbname, 62 | index_aligned_est.nspname, 63 | pg_class.relname AS table_name, 64 | index_aligned_est.index_name, 65 | (index_aligned_est.bs * ((index_aligned_est.relpages)::bigint)::numeric) AS totalbytes, 66 | index_aligned_est.expected, 67 | CASE 68 | WHEN ((index_aligned_est.relpages)::double precision <= index_aligned_est.expected) THEN (0)::numeric 69 | ELSE (index_aligned_est.bs * ((((index_aligned_est.relpages)::double precision - index_aligned_est.expected))::bigint)::numeric) 70 | END AS wastedbytes, 71 | CASE 72 | WHEN ((index_aligned_est.relpages)::double precision <= index_aligned_est.expected) THEN (0)::numeric 73 | ELSE (((index_aligned_est.bs * ((((index_aligned_est.relpages)::double precision - index_aligned_est.expected))::bigint)::numeric) * (100)::numeric) / (index_aligned_est.bs * ((index_aligned_est.relpages)::bigint)::numeric)) 74 | END AS realbloat, 75 | pg_relation_size((index_aligned_est.table_oid)::regclass) AS table_bytes, 76 | stat.idx_scan AS index_scans 77 | FROM ((index_aligned_est 78 | JOIN pg_class ON ((pg_class.oid = index_aligned_est.table_oid))) 79 | JOIN pg_stat_user_indexes stat ON ((index_aligned_est.index_oid = stat.indexrelid))) 80 | ), format_bloat AS ( 81 | SELECT raw_bloat.dbname AS database_name, 82 | raw_bloat.nspname AS schema_name, 83 | raw_bloat.table_name, 84 | raw_bloat.index_name, 85 | round(raw_bloat.realbloat) AS bloat_pct, 86 | round((raw_bloat.wastedbytes / (((1024)::double precision ^ (2)::double precision))::numeric)) AS bloat_mb, 87 | round((raw_bloat.totalbytes / (((1024)::double precision ^ (2)::double precision))::numeric), 3) AS index_mb, 88 | round(((raw_bloat.table_bytes)::numeric / (((1024)::double precision ^ (2)::double precision))::numeric), 3) AS table_mb, 89 | raw_bloat.index_scans 90 | FROM raw_bloat 91 | ) 92 | SELECT format_bloat.database_name AS datname, 93 | format_bloat.schema_name AS nspname, 94 | format_bloat.table_name AS relname, 95 | format_bloat.index_name AS idxname, 96 | format_bloat.index_scans AS idx_scans, 97 | format_bloat.bloat_pct, 98 | format_bloat.table_mb, 99 | (format_bloat.index_mb - format_bloat.bloat_mb) AS actual_mb, 100 | format_bloat.bloat_mb, 101 | format_bloat.index_mb AS total_mb 102 | FROM format_bloat 103 | ORDER BY format_bloat.bloat_mb DESC; 104 | -------------------------------------------------------------------------------- /SQL/index_create.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | now(), 3 | query_start AS started_at, 4 | now() - query_start AS query_duration, 5 | format('[%s] %s', a.pid, a.query) AS pid_and_query, 6 | index_relid::regclass AS index_name, 7 | relid::regclass AS table_name, 8 | (pg_size_pretty(pg_relation_size(relid))) AS table_size, 9 | phase, 10 | nullif (wait_event_type, '') || ': ' || wait_event AS wait_type_and_event, 11 | current_locker_pid, 12 | ( 13 | SELECT 14 | nullif ( 15 | LEFT (query, 150), '') || '...' 16 | FROM 17 | pg_stat_activity a 18 | WHERE 19 | a.pid = current_locker_pid) AS current_locker_query, 20 | format('%s (%s of %s)', coalesce((round(100 * lockers_done::numeric / nullif (lockers_total, 0), 2))::text || '%', 'N/A'), coalesce(lockers_done::text, '?'), coalesce(lockers_total::text, '?')) AS lockers_progress, 21 | format('%s (%s of %s)', coalesce((round(100 * blocks_done::numeric / nullif (blocks_total, 0), 2))::text || '%', 'N/A'), coalesce(blocks_done::text, '?'), coalesce(blocks_total::text, '?')) AS blocks_progress, 22 | format('%s (%s of %s)', coalesce((round(100 * tuples_done::numeric / nullif (tuples_total, 0), 2))::text || '%', 'N/A'), coalesce(tuples_done::text, '?'), coalesce(tuples_total::text, '?')) AS tuples_progress, 23 | format('%s (%s of %s)', coalesce((round(100 * partitions_done::numeric / nullif (partitions_total, 0), 2))::text || '%', 'N/A'), coalesce(partitions_done::text, '?'), coalesce(partitions_total::text, '?')) AS partitions_progress 24 | FROM 25 | pg_stat_progress_create_index p 26 | LEFT JOIN pg_stat_activity a ON a.pid = p.pid; 27 | -------------------------------------------------------------------------------- /SQL/index_duplicate.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_size_pretty(sum(pg_relation_size(idx))::bigint) as size, 2 | (array_agg(idx))[1] as idx1, (array_agg(idx))[2] as idx2, 3 | (array_agg(idx))[3] as idx3, (array_agg(idx))[4] as idx4 4 | FROM ( 5 | SELECT indexrelid::regclass as idx, (indrelid::text ||E'\n'|| indclass::text ||E'\n'|| indkey::text ||E'\n'|| 6 | coalesce(indexprs::text,'')||E'\n' || coalesce(indpred::text,'')) as key 7 | FROM pg_index) sub 8 | GROUP BY key HAVING count(*)>1 9 | ORDER BY sum(pg_relation_size(idx)) DESC; 10 | -------------------------------------------------------------------------------- /SQL/index_lower_efficiency.sql: -------------------------------------------------------------------------------- 1 | SELECT s.relname AS table_name, 2 | indexrelname AS index_name, 3 | i.indisunique, 4 | idx_scan AS idx_scans 5 | FROM pg_catalog.pg_stat_user_indexes s, 6 | pg_index i 7 | WHERE i.indexrelid = s.indexrelid; 8 | -------------------------------------------------------------------------------- /SQL/index_state.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | t.tablename, 3 | indexname, 4 | c.reltuples AS num_rows, 5 | pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, 6 | pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, 7 | CASE WHEN indisunique THEN 'Y' 8 | ELSE 'N' 9 | END AS UNIQUE, 10 | idx_scan AS number_of_scans, 11 | idx_tup_read AS tuples_read, 12 | idx_tup_fetch AS tuples_fetched 13 | FROM pg_tables t 14 | LEFT OUTER JOIN pg_class c ON t.tablename=c.relname 15 | LEFT OUTER JOIN 16 | ( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x 17 | JOIN pg_class c ON c.oid = x.indrelid 18 | JOIN pg_class ipg ON ipg.oid = x.indexrelid 19 | JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid ) 20 | AS foo 21 | ON t.tablename = foo.ctablename 22 | WHERE t.schemaname='public' 23 | ORDER BY 1,2; 24 | -------------------------------------------------------------------------------- /SQL/index_state_further.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | pg_class.relname, 3 | pg_size_pretty(pg_class.reltuples::bigint) AS rows_in_bytes, 4 | pg_class.reltuples AS num_rows, 5 | COUNT(*) AS total_indexes, 6 | COUNT(*) FILTER ( WHERE indisunique) AS unique_indexes, 7 | COUNT(*) FILTER ( WHERE indnatts = 1 ) AS single_column_indexes, 8 | COUNT(*) FILTER ( WHERE indnatts IS DISTINCT FROM 1 ) AS multi_column_indexes 9 | FROM 10 | pg_namespace 11 | LEFT JOIN pg_class ON pg_namespace.oid = pg_class.relnamespace 12 | LEFT JOIN pg_index ON pg_class.oid = pg_index.indrelid 13 | WHERE 14 | pg_namespace.nspname = 'public' AND 15 | pg_class.relkind = 'r' 16 | GROUP BY pg_class.relname, pg_class.reltuples 17 | ORDER BY pg_class.reltuples DESC; 18 | -------------------------------------------------------------------------------- /SQL/list_table_dependencies.sql: -------------------------------------------------------------------------------- 1 | -- Credit: https://stackoverflow.com/a/11773226/126688 2 | SELECT dependent_ns.nspname as dependent_schema 3 | , dependent_view.relname as dependent_view 4 | , source_ns.nspname as source_schema 5 | , source_table.relname as source_table 6 | , pg_attribute.attname as column_name 7 | FROM pg_depend 8 | JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid 9 | JOIN pg_class as dependent_view ON pg_rewrite.ev_class = dependent_view.oid 10 | JOIN pg_class as source_table ON pg_depend.refobjid = source_table.oid 11 | JOIN pg_attribute ON pg_depend.refobjid = pg_attribute.attrelid 12 | AND pg_depend.refobjsubid = pg_attribute.attnum 13 | JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace 14 | JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace 15 | WHERE 16 | source_ns.nspname = 'rideshare' -- yourschema 17 | AND source_table.relname = 'users' --yourtable 18 | AND pg_attribute.attnum > 0 19 | --AND pg_attribute.attname = 'my_column' 20 | ORDER BY 1,2; 21 | -------------------------------------------------------------------------------- /SQL/lock_tree.sql: -------------------------------------------------------------------------------- 1 | with recursive activity as ( 2 | select 3 | pg_blocking_pids(pid) blocked_by, 4 | *, 5 | age(clock_timestamp(), xact_start)::interval(0) as tx_age, 6 | age(clock_timestamp(), state_change)::interval(0) as state_age 7 | from pg_stat_activity 8 | where state is distinct from 'idle' 9 | ), blockers as ( 10 | select 11 | array_agg(distinct c order by c) as pids 12 | from ( 13 | select unnest(blocked_by) 14 | from activity 15 | ) as dt(c) 16 | ), tree as ( 17 | select 18 | activity.*, 19 | 1 as level, 20 | activity.pid as top_blocker_pid, 21 | array[activity.pid] as path, 22 | array[activity.pid]::int[] as all_blockers_above 23 | from activity, blockers 24 | where 25 | array[pid] <@ blockers.pids 26 | and blocked_by = '{}'::int[] 27 | union all 28 | select 29 | activity.*, 30 | tree.level + 1 as level, 31 | tree.top_blocker_pid, 32 | path || array[activity.pid] as path, 33 | tree.all_blockers_above || array_agg(activity.pid) over () as all_blockers_above 34 | from activity, tree 35 | where 36 | not array[activity.pid] <@ tree.all_blockers_above 37 | and activity.blocked_by <> '{}'::int[] 38 | and activity.blocked_by <@ tree.all_blockers_above 39 | ) 40 | select 41 | pid, 42 | blocked_by, 43 | tx_age, 44 | state_age, 45 | replace(state, 'idle in transaction', 'idletx') state, 46 | datname, 47 | usename, 48 | format('%s:%s', wait_event_type, wait_event) as wait, 49 | (select count(distinct t1.pid) from tree t1 where array[tree.pid] <@ t1.path and t1.pid <> tree.pid) as blkd, 50 | format( 51 | '%s %s%s', 52 | lpad('[' || pid::text || ']', 7, ' '), 53 | repeat('.', level - 1) || case when level > 1 then ' ' end, 54 | query 55 | ) 56 | from tree 57 | order by top_blocker_pid, level, pid; 58 | -------------------------------------------------------------------------------- /SQL/lock_wait_queue.sql: -------------------------------------------------------------------------------- 1 | WITH RECURSIVE t_wait AS ( 2 | SELECT 3 | a.locktype, 4 | a.database, 5 | a.relation, 6 | a.page, 7 | a.tuple, 8 | a.classid, 9 | a.objid, 10 | a.objsubid, 11 | a.pid, 12 | a.virtualtransaction, 13 | a.virtualxid, 14 | a.transactionid 15 | FROM 16 | pg_locks a 17 | WHERE 18 | NOT a.granted 19 | ), 20 | t_run AS ( 21 | SELECT 22 | a.mode, 23 | a.locktype, 24 | a.database, 25 | a.relation, 26 | a.page, 27 | a.tuple, 28 | a.classid, 29 | a.objid, 30 | a.objsubid, 31 | a.pid, 32 | a.virtualtransaction, 33 | a.virtualxid, 34 | a.transactionid, 35 | b.query, 36 | b.xact_start, 37 | b.query_start, 38 | b.usename, 39 | b.datname 40 | FROM 41 | pg_locks a, 42 | pg_stat_activity b 43 | WHERE 44 | a.pid = b.pid 45 | AND a.granted 46 | ), 47 | w AS ( 48 | SELECT 49 | r.pid r_pid, 50 | w.pid w_pid 51 | FROM 52 | t_wait w, 53 | t_run r 54 | WHERE 55 | r.locktype IS NOT DISTINCT FROM w.locktype 56 | AND r.database IS NOT DISTINCT FROM w.database 57 | AND r.relation IS NOT DISTINCT FROM w.relation 58 | AND r.page IS NOT DISTINCT FROM w.page 59 | AND r.tuple IS NOT DISTINCT FROM w.tuple 60 | AND r.classid IS NOT DISTINCT FROM w.classid 61 | AND r.objid IS NOT DISTINCT FROM w.objid 62 | AND r.objsubid IS NOT DISTINCT FROM w.objsubid 63 | AND r.transactionid IS NOT DISTINCT FROM w.transactionid 64 | AND r.virtualxid IS NOT DISTINCT FROM w.virtualxid 65 | ), 66 | c ( 67 | waiter, holder, root_holder, path, deep 68 | ) AS ( 69 | SELECT 70 | w_pid, 71 | r_pid, 72 | r_pid, 73 | w_pid || '->' || r_pid, 74 | 1 75 | FROM 76 | w 77 | UNION 78 | SELECT 79 | w_pid, 80 | r_pid, 81 | c.holder, 82 | w_pid || '->' || c.path, 83 | c.deep + 1 84 | FROM 85 | w t, 86 | c 87 | WHERE 88 | t.r_pid = c.waiter 89 | ) 90 | SELECT 91 | t1.waiter, 92 | t1.holder, 93 | t1.root_holder, 94 | path, 95 | t1.deep 96 | FROM 97 | c t1 98 | WHERE 99 | NOT EXISTS ( 100 | SELECT 101 | 1 102 | FROM 103 | c t2 104 | WHERE 105 | t2.path ~ t1.path 106 | AND t1.path <> t2.path) 107 | ORDER BY 108 | root_holder; 109 | -------------------------------------------------------------------------------- /SQL/lock_wait_state.sql: -------------------------------------------------------------------------------- 1 | WITH RECURSIVE 2 | lock_composite(requested, current) AS (VALUES 3 | ('AccessShareLock'::text, 'AccessExclusiveLock'::text), 4 | ('RowShareLock'::text, 'ExclusiveLock'::text), 5 | ('RowShareLock'::text, 'AccessExclusiveLock'::text), 6 | ('RowExclusiveLock'::text, 'ShareLock'::text), 7 | ('RowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 8 | ('RowExclusiveLock'::text, 'ExclusiveLock'::text), 9 | ('RowExclusiveLock'::text, 'AccessExclusiveLock'::text), 10 | ('ShareUpdateExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 11 | ('ShareUpdateExclusiveLock'::text, 'ShareLock'::text), 12 | ('ShareUpdateExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 13 | ('ShareUpdateExclusiveLock'::text, 'ExclusiveLock'::text), 14 | ('ShareUpdateExclusiveLock'::text, 'AccessExclusiveLock'::text), 15 | ('ShareLock'::text, 'RowExclusiveLock'::text), 16 | ('ShareLock'::text, 'ShareUpdateExclusiveLock'::text), 17 | ('ShareLock'::text, 'ShareRowExclusiveLock'::text), 18 | ('ShareLock'::text, 'ExclusiveLock'::text), 19 | ('ShareLock'::text, 'AccessExclusiveLock'::text), 20 | ('ShareRowExclusiveLock'::text, 'RowExclusiveLock'::text), 21 | ('ShareRowExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 22 | ('ShareRowExclusiveLock'::text, 'ShareLock'::text), 23 | ('ShareRowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 24 | ('ShareRowExclusiveLock'::text, 'ExclusiveLock'::text), 25 | ('ShareRowExclusiveLock'::text, 'AccessExclusiveLock'::text), 26 | ('ExclusiveLock'::text, 'RowShareLock'::text), 27 | ('ExclusiveLock'::text, 'RowExclusiveLock'::text), 28 | ('ExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 29 | ('ExclusiveLock'::text, 'ShareLock'::text), 30 | ('ExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 31 | ('ExclusiveLock'::text, 'ExclusiveLock'::text), 32 | ('ExclusiveLock'::text, 'AccessExclusiveLock'::text), 33 | ('AccessExclusiveLock'::text, 'AccessShareLock'::text), 34 | ('AccessExclusiveLock'::text, 'RowShareLock'::text), 35 | ('AccessExclusiveLock'::text, 'RowExclusiveLock'::text), 36 | ('AccessExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 37 | ('AccessExclusiveLock'::text, 'ShareLock'::text), 38 | ('AccessExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 39 | ('AccessExclusiveLock'::text, 'ExclusiveLock'::text), 40 | ('AccessExclusiveLock'::text, 'AccessExclusiveLock'::text) 41 | ) 42 | , lock AS ( 43 | SELECT pid, 44 | virtualtransaction, 45 | granted, 46 | mode, 47 | (locktype, 48 | CASE locktype 49 | WHEN 'relation' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text) 50 | WHEN 'extend' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text) 51 | WHEN 'page' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text, 'page#'||page::text) 52 | WHEN 'tuple' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text, 'page#'||page::text, 'tuple#'||tuple::text) 53 | WHEN 'transactionid' THEN transactionid::text 54 | WHEN 'virtualxid' THEN virtualxid::text 55 | WHEN 'object' THEN concat_ws(';', 'class:'||classid::regclass::text, 'objid:'||objid, 'col#'||objsubid) 56 | ELSE concat('db:'||datname) 57 | END::text) AS target 58 | FROM pg_catalog.pg_locks 59 | LEFT JOIN pg_catalog.pg_database ON (pg_database.oid = pg_locks.database) 60 | ) 61 | , waiting_lock AS ( 62 | SELECT 63 | blocker.pid AS blocker_pid, 64 | blocked.pid AS pid, 65 | concat(blocked.mode,blocked.target) AS lock_target 66 | FROM lock blocker 67 | JOIN lock blocked 68 | ON ( NOT blocked.granted 69 | AND blocker.granted 70 | AND blocked.pid != blocker.pid 71 | AND blocked.target IS NOT DISTINCT FROM blocker.target) 72 | JOIN lock_composite c ON (c.requested = blocked.mode AND c.current = blocker.mode) 73 | ) 74 | , acquired_lock AS ( 75 | WITH waiting AS ( 76 | SELECT lock_target, count(lock_target) AS wait_count FROM waiting_lock GROUP BY lock_target 77 | ) 78 | SELECT 79 | pid, 80 | array_agg(concat(mode,target,' + '||wait_count) ORDER BY wait_count DESC NULLS LAST) AS locks_acquired 81 | FROM lock 82 | LEFT JOIN waiting ON waiting.lock_target = concat(mode,target) 83 | WHERE granted 84 | GROUP BY pid 85 | ) 86 | , blocking_lock AS ( 87 | SELECT 88 | ARRAY[date_part('epoch', query_start)::int, pid] AS seq, 89 | 0::int AS depth, 90 | -1::int AS blocker_pid, 91 | pid, 92 | concat('Connect: ',usename,' ',datname,' ',coalesce(host(client_addr)||':'||client_port, 'local') 93 | , E'\nSQL: ',replace(substr(coalesce(query,'N/A'), 1, 60), E'\n', ' ') 94 | , E'\nAcquired:\n ' 95 | , array_to_string(locks_acquired[1:5] || 96 | CASE WHEN array_upper(locks_acquired,1) > 5 97 | THEN '... '||(array_upper(locks_acquired,1) - 5)::text||' more ...' 98 | END, 99 | E'\n ') 100 | ) AS lock_info, 101 | concat(to_char(query_start, CASE WHEN age(query_start) > '24h' THEN 'Day DD Mon' ELSE 'HH24:MI:SS' END),E' started\n' 102 | ,CASE WHEN wait_event IS NOT NULL THEN 'waiting' ELSE state END,E'\n' 103 | ,date_trunc('second',age(now(),query_start)),' ago' 104 | ) AS lock_state 105 | FROM acquired_lock blocker 106 | LEFT JOIN pg_stat_activity act USING (pid) 107 | WHERE EXISTS 108 | (SELECT 'x' FROM waiting_lock blocked WHERE blocked.blocker_pid = blocker.pid) 109 | AND NOT EXISTS 110 | (SELECT 'x' FROM waiting_lock blocked WHERE blocked.pid = blocker.pid) 111 | UNION ALL 112 | SELECT 113 | blocker.seq || blocked.pid, 114 | blocker.depth + 1, 115 | blocker.pid, 116 | blocked.pid, 117 | concat('Connect: ',usename,' ',datname,' ',coalesce(host(client_addr)||':'||client_port, 'local') 118 | , E'\nSQL: ',replace(substr(coalesce(query,'N/A'), 1, 60), E'\n', ' ') 119 | , E'\nWaiting: ',blocked.lock_target 120 | , CASE WHEN locks_acquired IS NOT NULL 121 | THEN E'\nAcquired:\n ' || 122 | array_to_string(locks_acquired[1:5] || 123 | CASE WHEN array_upper(locks_acquired,1) > 5 124 | THEN '... '||(array_upper(locks_acquired,1) - 5)::text||' more ...' 125 | END, 126 | E'\n ') 127 | END 128 | ) AS lock_info, 129 | concat(to_char(query_start, CASE WHEN age(query_start) > '24h' THEN 'Day DD Mon' ELSE 'HH24:MI:SS' END),E' started\n' 130 | ,CASE WHEN wait_event IS NOT NULL THEN 'waiting' ELSE state END,E'\n' 131 | ,date_trunc('second',age(now(),query_start)),' ago' 132 | ) AS lock_state 133 | FROM blocking_lock blocker 134 | JOIN waiting_lock blocked 135 | ON (blocked.blocker_pid = blocker.pid) 136 | LEFT JOIN pg_stat_activity act ON (act.pid = blocked.pid) 137 | LEFT JOIN acquired_lock acq ON (acq.pid = blocked.pid) 138 | WHERE blocker.depth < 5 139 | ) 140 | SELECT concat(lpad('=> ', 4*depth, ' '),pid::text) AS "PID" 141 | , lock_info AS "Lock Info" 142 | , lock_state AS "State" 143 | FROM blocking_lock 144 | ORDER BY seq; 145 | -------------------------------------------------------------------------------- /SQL/lock_wait_state_further.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | blocked_locks.pid AS blocked_pid, 3 | blocked_activity.usename AS blocked_user, 4 | now() - blocked_activity.query_start AS blocked_duration, 5 | blocking_locks.pid AS blocking_pid, 6 | blocking_activity.usename AS blocking_user, 7 | now() - blocking_activity.query_start AS blocking_duration, 8 | blocked_activity.query AS blocked_statement, 9 | blocking_activity.query AS blocking_statement 10 | FROM 11 | pg_catalog.pg_locks AS blocked_locks 12 | JOIN pg_catalog.pg_stat_activity AS blocked_activity ON blocked_activity.pid = blocked_locks.pid 13 | JOIN pg_catalog.pg_locks AS blocking_locks ON blocking_locks.locktype = blocked_locks.locktype 14 | AND blocking_locks.DATABASE IS NOT DISTINCT FROM blocked_locks.DATABASE 15 | AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation 16 | AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page 17 | AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple 18 | AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid 19 | AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid 20 | AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid 21 | AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid 22 | AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid 23 | AND blocking_locks.pid != blocked_locks.pid 24 | JOIN pg_catalog.pg_stat_activity AS blocking_activity ON blocking_activity.pid = blocking_locks.pid 25 | WHERE 26 | NOT blocked_locks.granted; 27 | -------------------------------------------------------------------------------- /SQL/long_transaction.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | state, 3 | wait_event, 4 | wait_event_type, 5 | client_addr, 6 | client_port, 7 | application_name, 8 | now() - xact_start as duration, 9 | query 10 | FROM 11 | pg_stat_activity 12 | WHERE 13 | state <> 'idle' 14 | AND (backend_xid IS NOT NULL 15 | OR backend_xmin IS NOT NULL) 16 | AND now() - xact_start > interval '5 min' 17 | ORDER BY 18 | xact_start; 19 | -------------------------------------------------------------------------------- /SQL/partition_info.sql: -------------------------------------------------------------------------------- 1 | WITH RECURSIVE inheritance_tree AS ( 2 | SELECT c.oid AS table_oid 3 | , c.relname AS table_name 4 | , n.nspname AS schema_name 5 | , NULL::name AS table_parent_name 6 | , c.relispartition AS is_partition 7 | FROM pg_class c 8 | JOIN pg_namespace n ON n.oid = c.relnamespace 9 | WHERE c.relkind = 'p' 10 | AND c.relispartition = false 11 | UNION ALL 12 | SELECT inh.inhrelid AS table_oid 13 | , c.relname AS table_name 14 | , n.nspname AS schema_name 15 | , cc.relname AS table_parent_name 16 | , c.relispartition AS is_partition 17 | FROM inheritance_tree it 18 | JOIN pg_inherits inh ON inh.inhparent = it.table_oid 19 | JOIN pg_class c ON inh.inhrelid = c.oid 20 | JOIN pg_class cc ON it.table_oid = cc.oid 21 | JOIN pg_namespace n ON c.relnamespace = n.oid 22 | ) 23 | SELECT 24 | it.table_name 25 | , it.schema_name 26 | , c.reltuples 27 | , c.relpages 28 | , CASE p.partstrat 29 | WHEN 'l' THEN 'BY LIST' 30 | WHEN 'r' THEN 'BY RANGE' 31 | ELSE 'not partitioned' 32 | END AS partitionin_type 33 | , it.table_parent_name 34 | , pg_get_expr( c.relpartbound, c.oid, true ) AS partitioning_values 35 | , pg_get_expr( p.partexprs, c.oid, true ) AS sub_partitioning_values 36 | FROM inheritance_tree it 37 | JOIN pg_class c ON c.oid = it.table_oid 38 | LEFT JOIN pg_partitioned_table p ON p.partrelid = it.table_oid 39 | ORDER BY 1,2; 40 | -------------------------------------------------------------------------------- /SQL/partition_inherit_info.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | nmsp_parent.nspname AS parent_schema, 3 | parent.relname AS parent, 4 | nmsp_child.nspname AS child_schema, 5 | child.relname AS child 6 | FROM 7 | pg_inherits 8 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 9 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 10 | JOIN pg_namespace nmsp_parent ON nmsp_parent.oid = parent.relnamespace 11 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 12 | WHERE 13 | child.relkind = 'r' 14 | ORDER BY 15 | child.relname; 16 | -------------------------------------------------------------------------------- /SQL/partition_size.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | pi.inhparent::regclass AS parent_table_name, 3 | pg_size_pretty(sum(pg_total_relation_size(psu.relid))) AS total, 4 | pg_size_pretty(sum(pg_relation_size(psu.relid))) AS internal, 5 | pg_size_pretty(sum(pg_table_size(psu.relid) - pg_relation_size(psu.relid))) AS external, -- toast 6 | pg_size_pretty(sum(pg_indexes_size(psu.relid))) AS indexes 7 | FROM pg_catalog.pg_statio_user_tables psu 8 | JOIN pg_class pc ON psu.relname = pc.relname 9 | JOIN pg_database pd ON pc.relowner = pd.datdba 10 | JOIN pg_inherits pi ON pi.inhrelid = pc.oid 11 | WHERE pd.datname = 'postgres' 12 | GROUP BY pi.inhparent 13 | ORDER BY sum(pg_total_relation_size(psu.relid)) DESC; 14 | -------------------------------------------------------------------------------- /SQL/rel_constraint.sql: -------------------------------------------------------------------------------- 1 | select pgc.conname as constraint_name, 2 | ccu.table_schema as table_schema, 3 | ccu.table_name, 4 | ccu.column_name, 5 | pg_get_constraintdef(pgc.oid) as cons_def 6 | from pg_constraint pgc 7 | join pg_namespace nsp on nsp.oid = pgc.connamespace 8 | join pg_class cls on pgc.conrelid = cls.oid 9 | left join information_schema.constraint_column_usage ccu 10 | on pgc.conname = ccu.constraint_name 11 | and nsp.nspname = ccu.constraint_schema 12 | where 13 | nsp.nspname not in ('pg_catalog','information_schema','pg_toast') 14 | and ccu.table_name = 'test' 15 | order by pgc.conname; 16 | -------------------------------------------------------------------------------- /SQL/rel_multi_index.sql: -------------------------------------------------------------------------------- 1 | select 2 | t.relnamespace::regnamespace as table_schema, 3 | t.relname as table_name, 4 | i.relname as index_name, 5 | array_to_string(array_agg(a.attname), ', ') as column_names 6 | from 7 | pg_class t, 8 | pg_class i, 9 | pg_index ix, 10 | pg_attribute a 11 | where 12 | t.oid = ix.indrelid 13 | and i.oid = ix.indexrelid 14 | and a.attrelid = t.oid 15 | and a.attnum = ANY(ix.indkey) 16 | and t.relkind = 'r' 17 | and t.relname like 'test%' 18 | group by 19 | table_schema, 20 | t.relname, 21 | i.relname 22 | order by 23 | t.relname, 24 | i.relname; 25 | -------------------------------------------------------------------------------- /SQL/relation_bloat.sql: -------------------------------------------------------------------------------- 1 | -- new table bloat query 2 | -- still needs work; is often off by +/- 20% 3 | WITH constants AS ( 4 | -- define some constants for sizes of things 5 | -- for reference down the query and easy maintenance 6 | SELECT 7 | current_setting('block_size')::numeric AS bs, 8 | 23 AS hdr, 9 | 8 AS ma 10 | ), 11 | no_stats AS ( 12 | -- screen out table who have attributes 13 | -- which dont have stats, such as JSON 14 | SELECT 15 | table_schema, 16 | table_name, 17 | n_live_tup::numeric AS est_rows, 18 | pg_table_size(relid)::numeric AS table_size 19 | FROM 20 | information_schema.columns 21 | JOIN pg_stat_user_tables AS psut ON table_schema = psut.schemaname 22 | AND table_name = psut.relname 23 | LEFT OUTER JOIN pg_stats ON table_schema = pg_stats.schemaname 24 | AND table_name = pg_stats.tablename 25 | AND column_name = attname 26 | WHERE 27 | attname IS NULL 28 | AND table_schema NOT IN ('pg_catalog', 'information_schema') 29 | GROUP BY 30 | table_schema, 31 | table_name, 32 | relid, 33 | n_live_tup 34 | ), 35 | null_headers AS ( 36 | -- calculate null header sizes 37 | -- omitting tables which dont have complete stats 38 | -- and attributes which aren't visible 39 | SELECT 40 | hdr + 1 + (sum( 41 | CASE WHEN null_frac <> 0 THEN 42 | 1 43 | ELSE 44 | 0 45 | END) / 8) AS nullhdr, 46 | SUM((1 - null_frac) * avg_width) AS datawidth, 47 | MAX(null_frac) AS maxfracsum, 48 | schemaname, 49 | tablename, 50 | hdr, 51 | ma, 52 | bs 53 | FROM 54 | pg_stats 55 | CROSS JOIN constants 56 | LEFT OUTER JOIN no_stats ON schemaname = no_stats.table_schema 57 | AND tablename = no_stats.table_name 58 | WHERE 59 | schemaname NOT IN ('pg_catalog', 'information_schema') 60 | AND no_stats.table_name IS NULL 61 | AND EXISTS ( 62 | SELECT 63 | 1 64 | FROM 65 | information_schema.columns 66 | WHERE 67 | schemaname = columns.table_schema 68 | AND tablename = columns.table_name) 69 | GROUP BY 70 | schemaname, 71 | tablename, 72 | hdr, 73 | ma, 74 | bs 75 | ), 76 | data_headers AS ( 77 | -- estimate header and row size 78 | SELECT 79 | ma, 80 | bs, 81 | hdr, 82 | schemaname, 83 | tablename, 84 | (datawidth + (hdr + ma - ( 85 | CASE WHEN hdr % ma = 0 THEN 86 | ma 87 | ELSE 88 | hdr % ma 89 | END)))::numeric AS datahdr, 90 | (maxfracsum * (nullhdr + ma - ( 91 | CASE WHEN nullhdr % ma = 0 THEN 92 | ma 93 | ELSE 94 | nullhdr % ma 95 | END))) AS nullhdr2 96 | FROM 97 | null_headers 98 | ), 99 | table_estimates AS ( 100 | -- make estimates of how large the table should be 101 | -- based on row and page size 102 | SELECT 103 | schemaname, 104 | tablename, 105 | bs, 106 | reltuples::numeric AS est_rows, 107 | relpages * bs AS table_bytes, 108 | CEIL((reltuples * (datahdr + nullhdr2 + 4 + ma - ( 109 | CASE WHEN datahdr % ma = 0 THEN 110 | ma 111 | ELSE 112 | datahdr % ma 113 | END)) / (bs - 20))) * bs AS expected_bytes, 114 | reltoastrelid 115 | FROM 116 | data_headers 117 | JOIN pg_class ON tablename = relname 118 | JOIN pg_namespace ON relnamespace = pg_namespace.oid 119 | AND schemaname = nspname 120 | WHERE 121 | pg_class.relkind = 'r' 122 | ), 123 | estimates_with_toast AS ( 124 | -- add in estimated TOAST table sizes 125 | -- estimate based on 4 toast tuples per page because we dont have 126 | -- anything better. also append the no_data tables 127 | SELECT 128 | schemaname, 129 | tablename, 130 | TRUE AS can_estimate, 131 | est_rows, 132 | table_bytes + (coalesce(toast.relpages, 0) * bs) AS table_bytes, 133 | expected_bytes + (ceil(coalesce(toast.reltuples, 0) / 4) * bs) AS expected_bytes 134 | FROM 135 | table_estimates 136 | LEFT OUTER JOIN pg_class AS toast ON table_estimates.reltoastrelid = toast.oid 137 | AND toast.relkind = 't' 138 | ), 139 | table_estimates_plus AS ( 140 | -- add some extra metadata to the table data 141 | -- and calculations to be reused 142 | -- including whether we cant estimate it 143 | -- or whether we think it might be compressed 144 | SELECT 145 | current_database() AS databasename, 146 | schemaname, 147 | tablename, 148 | can_estimate, 149 | est_rows, 150 | CASE WHEN table_bytes > 0 THEN 151 | table_bytes::numeric 152 | ELSE 153 | NULL::numeric 154 | END AS table_bytes, 155 | CASE WHEN expected_bytes > 0 THEN 156 | expected_bytes::numeric 157 | ELSE 158 | NULL::numeric 159 | END AS expected_bytes, 160 | CASE WHEN expected_bytes > 0 161 | AND table_bytes > 0 162 | AND expected_bytes <= table_bytes THEN 163 | (table_bytes - expected_bytes)::numeric 164 | ELSE 165 | 0::numeric 166 | END AS bloat_bytes 167 | FROM 168 | estimates_with_toast 169 | UNION ALL 170 | SELECT 171 | current_database() AS databasename, 172 | table_schema, 173 | table_name, 174 | FALSE, 175 | est_rows, 176 | table_size, 177 | NULL::numeric, 178 | NULL::numeric 179 | FROM 180 | no_stats 181 | ), 182 | bloat_data AS ( 183 | -- do final math calculations and formatting 184 | SELECT 185 | current_database() AS databasename, 186 | schemaname, 187 | tablename, 188 | can_estimate, 189 | table_bytes, 190 | round(table_bytes / (1024 ^ 2)::numeric, 3) AS table_mb, 191 | expected_bytes, 192 | round(expected_bytes / (1024 ^ 2)::numeric, 3) AS expected_mb, 193 | round(bloat_bytes * 100 / table_bytes) AS pct_bloat, 194 | round(bloat_bytes / (1024::numeric ^ 2), 2) AS mb_bloat, 195 | table_bytes, 196 | expected_bytes, 197 | est_rows 198 | FROM 199 | table_estimates_plus) 200 | -- filter output for bloated tables 201 | SELECT 202 | databasename, 203 | schemaname, 204 | tablename, 205 | can_estimate, 206 | est_rows, 207 | pct_bloat, 208 | mb_bloat, 209 | table_mb 210 | FROM 211 | bloat_data 212 | -- this where clause defines which tables actually appear 213 | -- in the bloat chart 214 | -- example below filters for tables which are either 50% 215 | -- bloated and more than 20mb in size, or more than 25% 216 | -- bloated and more than 4GB in size 217 | WHERE (pct_bloat >= 50 218 | AND mb_bloat >= 10) 219 | OR (pct_bloat >= 25 220 | AND mb_bloat >= 1000) 221 | ORDER BY 222 | pct_bloat DESC; 223 | -------------------------------------------------------------------------------- /SQL/relation_details.sql: -------------------------------------------------------------------------------- 1 | WITH cteTableInfo AS 2 | ( 3 | SELECT 4 | COUNT(1) AS ct 5 | ,SUM(length(t::text)) AS TextLength 6 | ,'public.t1'::regclass AS TableName 7 | FROM public.t1 AS t 8 | ) 9 | ,cteRowSize AS 10 | ( 11 | SELECT ARRAY [pg_relation_size(TableName) 12 | , pg_relation_size(TableName, 'vm') 13 | , pg_relation_size(TableName, 'fsm') 14 | , pg_table_size(TableName) 15 | , pg_indexes_size(TableName) 16 | , pg_total_relation_size(TableName) 17 | , TextLength 18 | ] AS val 19 | , ARRAY ['Relation Size' 20 | , 'Visibility Map' 21 | , 'Free Space Map' 22 | , 'Table Included Toast Size' 23 | , 'Indexes Size' 24 | , 'Total Relation Size' 25 | , 'Live Row Byte Size' 26 | ] AS Name 27 | FROM cteTableInfo 28 | ) 29 | SELECT 30 | unnest(name) AS Description 31 | ,unnest(val) AS Bytes 32 | ,pg_size_pretty(unnest(val)) AS BytesPretty 33 | ,unnest(val) / ct AS bytes_per_row 34 | FROM cteTableInfo, cteRowSize 35 | UNION ALL SELECT '------------------------------', NULL, NULL, NULL 36 | UNION ALL SELECT 'TotalRows', ct, NULL, NULL FROM cteTableInfo 37 | UNION ALL SELECT 'LiveTuples', pg_stat_get_live_tuples(TableName), NULL, NULL FROM cteTableInfo 38 | UNION ALL SELECT 'DeadTuples', pg_stat_get_dead_tuples(TableName), NULL, NULL FROM cteTableInfo; 39 | -------------------------------------------------------------------------------- /SQL/replication_primary_state_10.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | client_addr AS client, 3 | usename AS user, 4 | application_name AS name, 5 | state, 6 | sync_state AS mode, 7 | (pg_xlog_location_diff(pg_current_xlog_location(), sent_location) / 1024)::bigint AS pending, 8 | (pg_xlog_location_diff(sent_location, write_location) / 1024)::bigint AS write, 9 | (pg_xlog_location_diff(write_location, flush_location) / 1024)::bigint AS flush, 10 | (pg_xlog_location_diff(flush_location, replay_location) / 1024)::bigint AS replay, 11 | (pg_xlog_location_diff(pg_current_xlog_location(), replay_location))::bigint / 1024 AS total_lag 12 | FROM 13 | pg_stat_replication; 14 | -------------------------------------------------------------------------------- /SQL/replication_primary_state_13.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | client_addr AS client, 3 | usename AS user, 4 | application_name AS name, 5 | state, 6 | sync_state AS mode, 7 | write_lag, 8 | flush_lag, 9 | replay_lag 10 | FROM 11 | pg_stat_replication; 12 | -------------------------------------------------------------------------------- /SQL/replication_standby_state.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | pg_is_in_recovery() AS is_slave, 3 | pg_last_wal_receive_lsn() AS receive, 4 | pg_last_wal_replay_lsn() AS replay, 5 | pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() AS synced, 6 | ( 7 | EXTRACT(EPOCH FROM now()) - 8 | EXTRACT(EPOCH FROM pg_last_xact_replay_timestamp()) 9 | )::int AS lag; 10 | -------------------------------------------------------------------------------- /SQL/single_toast.sql: -------------------------------------------------------------------------------- 1 | SELECT attr.attname, 2 | t.typname, 3 | CASE 4 | WHEN attstorage = 'p' THEN 'plain' 5 | WHEN attstorage = 'x' THEN 'extended' 6 | WHEN attstorage = 'e' THEN 'external' 7 | WHEN attstorage = 'm' THEN 'main' 8 | END AS attstorage 9 | FROM pg_attribute attr INNER JOIN 10 | pg_type t ON t.OID = attr.atttypid 11 | WHERE attrelid = 'test'::regclass 12 | ORDER BY attr.attnum; 13 | -------------------------------------------------------------------------------- /SQL/user_member.sql: -------------------------------------------------------------------------------- 1 | WITH RECURSIVE x AS 2 | ( 3 | SELECT member::regrole, 4 | roleid::regrole AS role, 5 | member::regrole || ' -> ' || roleid::regrole AS path 6 | FROM pg_auth_members AS m 7 | WHERE roleid > 16384 8 | UNION ALL 9 | SELECT x.member::regrole, 10 | m.roleid::regrole, 11 | x.path || ' -> ' || m.roleid::regrole 12 | FROM pg_auth_members AS m 13 | JOIN x ON m.member = x.role 14 | ) 15 | SELECT member, role, path 16 | FROM x 17 | ORDER BY member::text, role::text; 18 | -------------------------------------------------------------------------------- /SQL/vacuum_need.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | pg_stat_user_tables.relname, 3 | pg_stat_user_tables.n_dead_tup, 4 | 50 + 0.1 * pg_class.reltuples as vacuum_threshold, 5 | pg_stat_user_tables.n_live_tup, 6 | pg_stat_user_tables.n_tup_del, 7 | pg_stat_user_tables.n_tup_upd, 8 | pg_stat_user_tables.autovacuum_count, 9 | pg_stat_user_tables.last_vacuum, 10 | pg_stat_user_tables.last_autovacuum, 11 | now() as now, 12 | pg_class.reltuples, 13 | pg_stat_user_tables.n_dead_tup > (50 + 0.1 * pg_class.reltuples) as is_vacuum 14 | FROM 15 | pg_stat_user_tables INNER JOIN pg_class ON pg_stat_user_tables.relname = pg_class.relname 16 | ORDER BY 17 | pg_stat_user_tables.n_dead_tup > (50 + 0.1 * pg_class.reltuples) DESC; 18 | -------------------------------------------------------------------------------- /SQL/vacuum_queue.sql: -------------------------------------------------------------------------------- 1 | with table_opts as ( 2 | select 3 | pg_class.oid, 4 | relname, 5 | nspname, 6 | array_to_string(reloptions, '') as relopts 7 | from pg_class 8 | join pg_namespace ns on relnamespace = ns.oid 9 | ), vacuum_settings as ( 10 | select 11 | oid, 12 | relname, 13 | nspname, 14 | case 15 | when relopts like '%autovacuum_vacuum_threshold%' then 16 | regexp_replace(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*', e'\\1')::int8 17 | else current_setting('autovacuum_vacuum_threshold')::int8 18 | end as autovacuum_vacuum_threshold, 19 | case 20 | when relopts like '%autovacuum_vacuum_scale_factor%' 21 | then regexp_replace(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*', e'\\1')::numeric 22 | else current_setting('autovacuum_vacuum_scale_factor')::numeric 23 | end as autovacuum_vacuum_scale_factor, 24 | case 25 | when relopts ~ 'autovacuum_enabled=(false|off)' then false 26 | else true 27 | end as autovacuum_enabled 28 | from table_opts 29 | ), p as ( 30 | select * 31 | from pg_stat_progress_vacuum 32 | ) 33 | select 34 | coalesce( 35 | coalesce(nullif(vacuum_settings.nspname, 'public') || '.', '') || vacuum_settings.relname, -- current DB 36 | format('[something in "%I"]', p.datname) -- another DB 37 | ) as relation, 38 | round((100 * psat.n_dead_tup::numeric / nullif(pg_class.reltuples, 0))::numeric, 2) as dead_tup_pct, 39 | pg_class.reltuples::numeric, 40 | psat.n_dead_tup, 41 | format ( 42 | 'vt: %s, vsf: %s, %s', -- 'vt' – vacuum_threshold, 'vsf' - vacuum_scale_factor 43 | vacuum_settings.autovacuum_vacuum_threshold, 44 | vacuum_settings.autovacuum_vacuum_scale_factor, 45 | (case when autovacuum_enabled then 'DISABLED' else 'enabled' end) 46 | ) as effective_settings, 47 | case 48 | when last_autovacuum > coalesce(last_vacuum, '0001-01-01') then left(last_autovacuum::text, 19) || ' (auto)' 49 | when last_vacuum is not null then left(last_vacuum::text, 19) || ' (manual)' 50 | else null 51 | end as last_vacuumed, 52 | coalesce(p.phase, '~~~ in queue ~~~') as status, 53 | p.pid as pid, 54 | case 55 | when a.query ~ '^autovacuum.*to prevent wraparound' then 'wraparound' 56 | when a.query ~ '^vacuum' then 'user' 57 | when a.pid is null then null 58 | else 'regular' 59 | end as mode, 60 | case 61 | when a.pid is null then null 62 | else coalesce(wait_event_type || '.' || wait_event, 'f') 63 | end as waiting, 64 | round(100.0 * p.heap_blks_scanned / nullif(p.heap_blks_total, 0), 1) as scanned_pct, 65 | round(100.0 * p.heap_blks_vacuumed / nullif(p.heap_blks_total, 0), 1) as vacuumed_pct, 66 | p.index_vacuum_count, 67 | case 68 | when psat.relid is not null and p.relid is not null then 69 | (select count(*) from pg_index where indrelid = psat.relid) 70 | else null 71 | end as index_count 72 | from pg_stat_all_tables psat 73 | join pg_class on psat.relid = pg_class.oid 74 | left join vacuum_settings on pg_class.oid = vacuum_settings.oid 75 | full outer join p on p.relid = psat.relid and p.datname = current_database() 76 | left join pg_stat_activity a using (pid) 77 | where 78 | psat.relid is null 79 | or p.phase is not null 80 | or ( 81 | autovacuum_vacuum_threshold 82 | + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) 83 | < psat.n_dead_tup 84 | ) 85 | order by status, relation 86 | -------------------------------------------------------------------------------- /SQL/vacuum_state.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | p.pid, 3 | now() - a.xact_start AS duration, 4 | coalesce(wait_event_type || '.' || wait_event, 'f') AS waiting, 5 | CASE WHEN a.query ~* '^autovacuum.*to prevent wraparound' THEN 6 | 'wraparound' 7 | WHEN a.query ~* '^vacuum' THEN 8 | 'user' 9 | ELSE 10 | 'regular' 11 | END AS mode, 12 | p.datname AS database, 13 | p.relid::regclass AS table, 14 | p.phase, 15 | pg_size_pretty(p.heap_blks_total * current_setting('block_size')::int) AS table_size, 16 | pg_size_pretty(pg_total_relation_size(relid)) AS total_size, 17 | pg_size_pretty(p.heap_blks_scanned * current_setting('block_size')::int) AS scanned, 18 | pg_size_pretty(p.heap_blks_vacuumed * current_setting('block_size')::int) AS vacuumed, 19 | round(100.0 * p.heap_blks_scanned / p.heap_blks_total, 1) AS scanned_pct, 20 | round(100.0 * p.heap_blks_vacuumed / p.heap_blks_total, 1) AS vacuumed_pct, 21 | p.index_vacuum_count, 22 | round(100.0 * p.num_dead_tuples / p.max_dead_tuples, 1) AS dead_pct 23 | FROM 24 | pg_stat_progress_vacuum p 25 | JOIN pg_stat_activity a USING (pid) 26 | ORDER BY 27 | now() - a.xact_start DESC; 28 | -------------------------------------------------------------------------------- /SQL/wait_event.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | wait_event, 3 | wait_event_type, 4 | count(*) 5 | FROM 6 | pg_stat_activity 7 | GROUP BY 8 | 1, 9 | 2; 10 | -------------------------------------------------------------------------------- /SQL/wal_archive_state.sql: -------------------------------------------------------------------------------- 1 | SELECT *, 2 | current_setting('archive_mode')::BOOLEAN 3 | AND (last_failed_wal IS NULL 4 | OR last_failed_wal <= last_archived_wal) 5 | AS is_archiving, 6 | CAST (archived_count AS NUMERIC) 7 | / EXTRACT (EPOCH FROM age(now(), stats_reset)) 8 | AS current_archived_wals_per_second 9 | FROM pg_stat_archiver; 10 | -------------------------------------------------------------------------------- /SQL/wal_generate_speed.sql: -------------------------------------------------------------------------------- 1 | with tmp_file as ( 2 | select t1.file, 3 | t1.file_ls, 4 | (pg_stat_file(t1.file)).size as size, 5 | (pg_stat_file(t1.file)).access as access, 6 | (pg_stat_file(t1.file)).modification as last_update_time, 7 | (pg_stat_file(t1.file)).change as change, 8 | (pg_stat_file(t1.file)).creation as creation, 9 | (pg_stat_file(t1.file)).isdir as isdir 10 | from (select dir||'/'||pg_ls_dir(t0.dir) as file, 11 | pg_ls_dir(t0.dir) as file_ls 12 | from ( select '/home/postgres/15data/pg_wal'::text as dir 13 | --需要修改这个物理路径 14 | ) t0 15 | ) t1 16 | where 1=1 17 | order by (pg_stat_file(file)).modification desc 18 | ) 19 | select to_char(date_trunc('day',tf0.last_update_time),'yyyymmdd') as day_id, 20 | sum(case when date_part('hour',tf0.last_update_time) >=0 and date_part('hour',tf0.last_update_time) <24 then 1 else 0 end) as wal_num_all, 21 | sum(case when date_part('hour',tf0.last_update_time) >=0 and date_part('hour',tf0.last_update_time) <1 then 1 else 0 end) as wal_num_00_01, 22 | sum(case when date_part('hour',tf0.last_update_time) >=1 and date_part('hour',tf0.last_update_time) <2 then 1 else 0 end) as wal_num_01_02, 23 | sum(case when date_part('hour',tf0.last_update_time) >=2 and date_part('hour',tf0.last_update_time) <3 then 1 else 0 end) as wal_num_02_03, 24 | sum(case when date_part('hour',tf0.last_update_time) >=3 and date_part('hour',tf0.last_update_time) <4 then 1 else 0 end) as wal_num_03_04, 25 | sum(case when date_part('hour',tf0.last_update_time) >=4 and date_part('hour',tf0.last_update_time) <5 then 1 else 0 end) as wal_num_04_05, 26 | sum(case when date_part('hour',tf0.last_update_time) >=5 and date_part('hour',tf0.last_update_time) <6 then 1 else 0 end) as wal_num_05_06, 27 | sum(case when date_part('hour',tf0.last_update_time) >=6 and date_part('hour',tf0.last_update_time) <7 then 1 else 0 end) as wal_num_06_07, 28 | sum(case when date_part('hour',tf0.last_update_time) >=7 and date_part('hour',tf0.last_update_time) <8 then 1 else 0 end) as wal_num_07_08, 29 | sum(case when date_part('hour',tf0.last_update_time) >=8 and date_part('hour',tf0.last_update_time) <9 then 1 else 0 end) as wal_num_08_09, 30 | sum(case when date_part('hour',tf0.last_update_time) >=9 and date_part('hour',tf0.last_update_time) <10 then 1 else 0 end) as wal_num_09_10, 31 | sum(case when date_part('hour',tf0.last_update_time) >=10 and date_part('hour',tf0.last_update_time) <11 then 1 else 0 end) as wal_num_10_11, 32 | sum(case when date_part('hour',tf0.last_update_time) >=11 and date_part('hour',tf0.last_update_time) <12 then 1 else 0 end) as wal_num_11_12, 33 | sum(case when date_part('hour',tf0.last_update_time) >=12 and date_part('hour',tf0.last_update_time) <13 then 1 else 0 end) as wal_num_12_13, 34 | sum(case when date_part('hour',tf0.last_update_time) >=13 and date_part('hour',tf0.last_update_time) <14 then 1 else 0 end) as wal_num_13_14, 35 | sum(case when date_part('hour',tf0.last_update_time) >=14 and date_part('hour',tf0.last_update_time) <15 then 1 else 0 end) as wal_num_14_15, 36 | sum(case when date_part('hour',tf0.last_update_time) >=15 and date_part('hour',tf0.last_update_time) <16 then 1 else 0 end) as wal_num_15_16, 37 | sum(case when date_part('hour',tf0.last_update_time) >=16 and date_part('hour',tf0.last_update_time) <17 then 1 else 0 end) as wal_num_16_17, 38 | sum(case when date_part('hour',tf0.last_update_time) >=17 and date_part('hour',tf0.last_update_time) <18 then 1 else 0 end) as wal_num_17_18, 39 | sum(case when date_part('hour',tf0.last_update_time) >=18 and date_part('hour',tf0.last_update_time) <19 then 1 else 0 end) as wal_num_18_19, 40 | sum(case when date_part('hour',tf0.last_update_time) >=19 and date_part('hour',tf0.last_update_time) <20 then 1 else 0 end) as wal_num_19_20, 41 | sum(case when date_part('hour',tf0.last_update_time) >=20 and date_part('hour',tf0.last_update_time) <21 then 1 else 0 end) as wal_num_20_21, 42 | sum(case when date_part('hour',tf0.last_update_time) >=21 and date_part('hour',tf0.last_update_time) <22 then 1 else 0 end) as wal_num_21_22, 43 | sum(case when date_part('hour',tf0.last_update_time) >=22 and date_part('hour',tf0.last_update_time) <23 then 1 else 0 end) as wal_num_22_23, 44 | sum(case when date_part('hour',tf0.last_update_time) >=23 and date_part('hour',tf0.last_update_time) <24 then 1 else 0 end) as wal_num_23_24 45 | from tmp_file tf0 46 | where 1=1 47 | and tf0.file_ls not in ('archive_status') 48 | group by to_char(date_trunc('day',tf0.last_update_time),'yyyymmdd') 49 | order by to_char(date_trunc('day',tf0.last_update_time),'yyyymmdd') desc; 50 | -------------------------------------------------------------------------------- /SQL/xmin_horizon.sql: -------------------------------------------------------------------------------- 1 | with bits as ( 2 | select 3 | ( 4 | select backend_xmin 5 | from pg_stat_activity 6 | order by age(backend_xmin) desc nulls last 7 | limit 1 8 | ) as xmin_pg_stat_activity, 9 | ( 10 | select xmin 11 | from pg_replication_slots 12 | order by age(xmin) desc nulls last 13 | limit 1 14 | ) as xmin_pg_replication_slots, 15 | ( 16 | select backend_xmin 17 | from pg_stat_replication 18 | order by age(backend_xmin) desc nulls last 19 | limit 1 20 | ) as xmin_pg_stat_replication, 21 | ( 22 | select transaction 23 | from pg_prepared_xacts 24 | order by age(transaction) desc nulls last 25 | limit 1 26 | ) as xmin_pg_prepared_xacts 27 | ) 28 | select 29 | *, 30 | age(xmin_pg_stat_activity) as xmin_pgsa_age, 31 | age(xmin_pg_replication_slots) as xmin_pgrs_age, 32 | age(xmin_pg_stat_replication) as xmin_pgsr_age, 33 | age(xmin_pg_prepared_xacts) as xmin_pgpx_age, 34 | greatest( 35 | age(xmin_pg_stat_activity), 36 | age(xmin_pg_replication_slots), 37 | age(xmin_pg_stat_replication), 38 | age(xmin_pg_prepared_xacts) 39 | ) as xmin_horizon_age 40 | from bits; 41 | 42 | -------------------------------------------------------------------------------- /pgcheck: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/xiongcccc/pgcheck/42cdf69d3f6f21bb1c50973f62ff8fff4aa9c555/pgcheck -------------------------------------------------------------------------------- /pgcheck.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # Author: xiongcc 3 | # Date: 2024/04/03 4 | 5 | # environment check 6 | which psql > /dev/null 2>/dev/null 7 | if [ $? -ne 0 ]; then 8 | echo "Fatal! please check your environment variables!" 9 | exit 1 10 | fi 11 | 12 | # current directory 13 | current_dir=$(cd $(dirname $0); pwd) 14 | 15 | # PostgreSQL current major version 16 | current_version=$(psql --version | awk -F " " '{print $3}' | cut -d '.' -f 1 | head -n 1) 17 | 18 | # utility usage info 19 | function print_help_info() { 20 | echo "Description: The utility is used to collect specified information" 21 | echo "Current Version: 1.0.4" 22 | echo "Usage:" 23 | echo " ./pgcheck relation database schema : list information about tables and indexes in the specified schema" 24 | echo " ./pgcheck relconstraint database relname : list all constraint corresponding to the specified table" 25 | echo " ./pgcheck alltoast database schema : list all toasts and their corresponding tables" 26 | echo " ./pgcheck reltoast database relname : list the toast information of the specified table" 27 | echo " ./pgcheck dbstatus : list all database status and statistics" 28 | echo " ./pgcheck index_bloat database : index bloat information (estimated value)" 29 | echo " ./pgcheck index_duplicate database : index duplicate information" 30 | echo " ./pgcheck index_low database : index low efficiency information" 31 | echo " ./pgcheck index_state database : index detail information" 32 | echo " ./pgcheck lock database : lock wait queue and lock wait state" 33 | echo " ./pgcheck checkpoint : background and checkpointer state" 34 | echo " ./pgcheck freeze database : database transaction id consuming state and detail" 35 | echo " ./pgcheck replication : streaming replication (physical) state" 36 | echo " ./pgcheck connections database : database connections and current query" 37 | echo " ./pgcheck long_transaction database : long transaction detail" 38 | echo " ./pgcheck relation_bloat database : relation bloat information (estimated value)" 39 | echo " ./pgcheck vacuum_state database : current vacuum progress information" 40 | echo " ./pgcheck vacuum_need database : show tables that need vacuum" 41 | echo " ./pgcheck index_create database : index create progress information" 42 | echo " ./pgcheck wal_archive : wal archive progress information" 43 | echo " ./pgcheck wal_generate wal_path : wal generate speed (you should provide extra wal directory)" 44 | echo " ./pgcheck wait_event database : wait event and wait event type" 45 | echo " ./pgcheck partition database : native and inherit partition info (estimated value)" 46 | echo " ./pgcheck object database user : get the objects owned by the user in the specified database" 47 | echo " ./pgcheck --help or -h : print this help information" 48 | 49 | echo "" 50 | echo " Author: xiongcc@PostgreSQL学徒, github: https://github.com/xiongcccc." 51 | echo " If you have any feedback or suggestions, feel free to contact with me." 52 | echo " Email: xiongcc_1994@126.com/xiongcc_1994@outlook.com. Wechat: _xiongcc" 53 | echo "" 54 | } 55 | 56 | # get database name 57 | if [ "$1" = '--help' -o "$1" = '-h' -o "$1" = 'help' -o "$1" = 'h' -o $# -lt 1 ];then 58 | print_help_info 59 | exit 1 60 | elif [ "$1" = 'checkpoint' -o "$1" = 'dbstatus' -o "$1" = 'replication' -o "$1" = 'wal_archive' -o "$1" = 'wal_generate' ];then 61 | : 62 | else 63 | if [ $# -lt 2 ];then 64 | echo "please provide an extra database name." 65 | echo -e "Usage: ./pgcheck $1 database\n" 66 | echo -e "\U1F625 take it slow, try again ~ \U1F625" 67 | exit 1 68 | fi 69 | fi 70 | dbname=$2 71 | 72 | # ------------------------------------------------------- query here ------------------------------------------------------- 73 | # all relation info 74 | relation_info="SELECT 75 | *, 76 | pg_size_pretty(table_bytes) AS table, 77 | pg_size_pretty(index_bytes) AS index, 78 | pg_size_pretty(total_bytes) AS total 79 | FROM ( 80 | SELECT 81 | *, total_bytes - index_bytes - COALESCE(toast_bytes, 0) AS table_bytes 82 | FROM ( 83 | SELECT 84 | c.oid, 85 | c.relfilenode, 86 | case when c.oid=c.relfilenode then 'NO' else 'YES' end as has_been_rewrite, 87 | nspname AS table_schema, 88 | relname AS table_name, 89 | c.reltuples AS row_estimate, 90 | pg_total_relation_size(c.oid) AS total_bytes, 91 | pg_indexes_size(c.oid) AS index_bytes, 92 | pg_total_relation_size(reltoastrelid) AS toast_bytes 93 | FROM 94 | pg_class c 95 | LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 96 | WHERE relkind = 'r' 97 | ) a 98 | ) a 99 | WHERE table_schema = '$3' 100 | ORDER BY total_bytes DESC;" 101 | 102 | # relation all constraint 103 | relation_constraint="SELECT 104 | pgc.conname AS constraint_name, 105 | ccu.table_schema AS table_schema, 106 | ccu.table_name, 107 | ccu.column_name, 108 | pg_get_constraintdef(pgc.oid) AS cons_def 109 | FROM 110 | pg_constraint pgc 111 | JOIN pg_namespace nsp ON nsp.oid = pgc.connamespace 112 | JOIN pg_class cls ON pgc.conrelid = cls.oid 113 | LEFT JOIN information_schema.constraint_column_usage ccu ON pgc.conname = ccu.constraint_name 114 | AND nsp.nspname = ccu.constraint_schema 115 | WHERE 116 | nsp.nspname NOT IN ('pg_catalog', 'information_schema', 'pg_toast') 117 | AND ccu.table_name = '$3' 118 | ORDER BY 119 | pgc.conname;" 120 | 121 | # relation multi index 122 | relation_multi_idx="select 123 | t.relnamespace::regnamespace as table_schema, 124 | t.relname as table_name, 125 | i.relname as index_name, 126 | array_to_string(array_agg(a.attname), ', ') as column_names 127 | from 128 | pg_class t, 129 | pg_class i, 130 | pg_index ix, 131 | pg_attribute a 132 | where 133 | t.oid = ix.indrelid 134 | and i.oid = ix.indexrelid 135 | and a.attrelid = t.oid 136 | and a.attnum = ANY(ix.indkey) 137 | and t.relkind = 'r' 138 | and t.relname ='$3' 139 | group by 140 | table_schema, 141 | t.relname, 142 | i.relname 143 | order by 144 | t.relname, 145 | i.relname;" 146 | 147 | # all toast info 148 | toast_info="SELECT 149 | n.nspname as schema, 150 | s.oid::regclass as relname, 151 | s.reltoastrelid::regclass as toast_name, 152 | pg_relation_size(s.reltoastrelid) AS toast_size 153 | FROM 154 | pg_class s join pg_namespace n 155 | on s.relnamespace = n.oid 156 | WHERE 157 | relkind = 'r' 158 | AND reltoastrelid <> 0 159 | AND n.nspname = '$3' 160 | ORDER BY 161 | 3 DESC;" 162 | 163 | # specified toast info 164 | spe_toast_info="SELECT attr.attname, 165 | t.typname, 166 | CASE 167 | WHEN attstorage = 'p' THEN 'plain' 168 | WHEN attstorage = 'x' THEN 'extended' 169 | WHEN attstorage = 'e' THEN 'external' 170 | WHEN attstorage = 'm' THEN 'main' 171 | END AS attstorage 172 | FROM pg_attribute attr INNER JOIN 173 | pg_type t ON t.OID = attr.atttypid 174 | WHERE attrelid = '$3'::regclass 175 | ORDER BY attr.attnum;" 176 | 177 | # specified toast info 178 | spe_toast_info_fur="SELECT 179 | n.nspname as schema, 180 | s.oid::regclass as relname, 181 | s.reltoastrelid::regclass as toast_name, 182 | pg_relation_size(s.reltoastrelid) AS toast_size 183 | FROM 184 | pg_class s join pg_namespace n 185 | on s.relnamespace = n.oid 186 | WHERE 187 | relname = '$3' 188 | AND reltoastrelid <> 0 189 | ORDER BY 190 | 3 DESC;" 191 | 192 | # database status 193 | if [ $current_version -eq 15 ] ;then 194 | database_status="SELECT 195 | datname AS database_name, 196 | pg_size_pretty(pg_database_size(datname)) AS database_size, 197 | 100 * blks_hit / (blks_hit + blks_read) || ' %' AS cache_hit_ratio, 198 | 100 * xact_commit / (xact_commit + xact_rollback) || ' %' AS commit_ratio, 199 | conflicts, 200 | temp_files, 201 | pg_size_pretty(temp_bytes) as temp_bytes, 202 | deadlocks, 203 | checksum_failures, 204 | blk_read_time, 205 | blk_write_time, 206 | session_time, 207 | active_time, 208 | idle_in_transaction_time, 209 | sessions, 210 | sessions_abandoned, 211 | sessions_fatal, 212 | sessions_killed 213 | FROM 214 | pg_stat_database 215 | WHERE (blks_hit + blks_read) > 0 216 | AND datname NOT LIKE '%template%';" 217 | elif [ $current_version -eq 13 -o $current_version -eq 12 ];then 218 | database_status="SELECT 219 | datname AS database_name, 220 | pg_size_pretty(pg_database_size(datname)) AS database_size, 221 | 100 * blks_hit / (blks_hit + blks_read) || '%' AS cache_hit_ratio, 222 | 100 * xact_commit / (xact_commit + xact_rollback) || '%' AS commit_ratio, 223 | conflicts, 224 | temp_files, 225 | pg_size_pretty(temp_bytes) as temp_bytes, 226 | deadlocks, 227 | checksum_failures, 228 | blk_read_time, 229 | blk_write_time 230 | FROM 231 | pg_stat_database 232 | WHERE (blks_hit + blks_read) > 0 233 | AND datname NOT LIKE '%template%';" 234 | else 235 | database_status="SELECT 236 | datname AS database_name, 237 | pg_size_pretty(pg_database_size(datname)) AS database_size, 238 | 100 * blks_hit / (blks_hit + blks_read) || '%' AS cache_hit_ratio, 239 | 100 * xact_commit / (xact_commit + xact_rollback) || '%' AS commit_ratio, 240 | conflicts, 241 | temp_files, 242 | pg_size_pretty(temp_bytes) as temp_bytes, 243 | deadlocks, 244 | blk_read_time, 245 | blk_write_time 246 | FROM 247 | pg_stat_database 248 | WHERE (blks_hit + blks_read) > 0 249 | AND datname NOT LIKE '%template%';" 250 | fi 251 | 252 | 253 | # lock wait queue 254 | lock_wait_queue="WITH RECURSIVE t_wait AS ( 255 | SELECT 256 | a.locktype, 257 | a.database, 258 | a.relation, 259 | a.page, 260 | a.tuple, 261 | a.classid, 262 | a.objid, 263 | a.objsubid, 264 | a.pid, 265 | a.virtualtransaction, 266 | a.virtualxid, 267 | a.transactionid 268 | FROM 269 | pg_locks a 270 | WHERE 271 | NOT a.granted 272 | ), 273 | t_run AS ( 274 | SELECT 275 | a.mode, 276 | a.locktype, 277 | a.database, 278 | a.relation, 279 | a.page, 280 | a.tuple, 281 | a.classid, 282 | a.objid, 283 | a.objsubid, 284 | a.pid, 285 | a.virtualtransaction, 286 | a.virtualxid, 287 | a.transactionid, 288 | b.query, 289 | b.xact_start, 290 | b.query_start, 291 | b.usename, 292 | b.datname 293 | FROM 294 | pg_locks a, 295 | pg_stat_activity b 296 | WHERE 297 | a.pid = b.pid 298 | AND a.granted 299 | ), 300 | w AS ( 301 | SELECT 302 | r.pid r_pid, 303 | w.pid w_pid 304 | FROM 305 | t_wait w, 306 | t_run r 307 | WHERE 308 | r.locktype IS NOT DISTINCT FROM w.locktype 309 | AND r.database IS NOT DISTINCT FROM w.database 310 | AND r.relation IS NOT DISTINCT FROM w.relation 311 | AND r.page IS NOT DISTINCT FROM w.page 312 | AND r.tuple IS NOT DISTINCT FROM w.tuple 313 | AND r.classid IS NOT DISTINCT FROM w.classid 314 | AND r.objid IS NOT DISTINCT FROM w.objid 315 | AND r.objsubid IS NOT DISTINCT FROM w.objsubid 316 | AND r.transactionid IS NOT DISTINCT FROM w.transactionid 317 | AND r.virtualxid IS NOT DISTINCT FROM w.virtualxid 318 | ), 319 | c ( 320 | waiter, holder, root_holder, path, deep 321 | ) AS ( 322 | SELECT 323 | w_pid, 324 | r_pid, 325 | r_pid, 326 | w_pid || '->' || r_pid, 327 | 1 328 | FROM 329 | w 330 | UNION 331 | SELECT 332 | w_pid, 333 | r_pid, 334 | c.holder, 335 | w_pid || '->' || c.path, 336 | c.deep + 1 337 | FROM 338 | w t, 339 | c 340 | WHERE 341 | t.r_pid = c.waiter 342 | ) 343 | SELECT 344 | t1.waiter, 345 | t1.holder, 346 | t1.root_holder, 347 | path, 348 | t1.deep 349 | FROM 350 | c t1 351 | WHERE 352 | NOT EXISTS ( 353 | SELECT 354 | 1 355 | FROM 356 | c t2 357 | WHERE 358 | t2.path ~ t1.path 359 | AND t1.path <> t2.path) 360 | ORDER BY 361 | root_holder;" 362 | 363 | # lock wait state 364 | lock_wait_state_further="SELECT 365 | blocked_locks.pid AS blocked_pid, 366 | blocked_activity.usename AS blocked_user, 367 | now() - blocked_activity.query_start AS blocked_duration, 368 | blocking_locks.pid AS blocking_pid, 369 | blocking_activity.usename AS blocking_user, 370 | now() - blocking_activity.query_start AS blocking_duration, 371 | blocked_activity.query AS blocked_statement, 372 | blocking_activity.query AS blocking_statement 373 | FROM 374 | pg_catalog.pg_locks AS blocked_locks 375 | JOIN pg_catalog.pg_stat_activity AS blocked_activity ON blocked_activity.pid = blocked_locks.pid 376 | JOIN pg_catalog.pg_locks AS blocking_locks ON blocking_locks.locktype = blocked_locks.locktype 377 | AND blocking_locks.DATABASE IS NOT DISTINCT FROM blocked_locks.DATABASE 378 | AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation 379 | AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page 380 | AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple 381 | AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid 382 | AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid 383 | AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid 384 | AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid 385 | AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid 386 | AND blocking_locks.pid != blocked_locks.pid 387 | JOIN pg_catalog.pg_stat_activity AS blocking_activity ON blocking_activity.pid = blocking_locks.pid 388 | WHERE 389 | NOT blocked_locks.granted;" 390 | 391 | # lock wait state 392 | lock_wait_state="WITH RECURSIVE 393 | lock_composite(requested, current) AS (VALUES 394 | ('AccessShareLock'::text, 'AccessExclusiveLock'::text), 395 | ('RowShareLock'::text, 'ExclusiveLock'::text), 396 | ('RowShareLock'::text, 'AccessExclusiveLock'::text), 397 | ('RowExclusiveLock'::text, 'ShareLock'::text), 398 | ('RowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 399 | ('RowExclusiveLock'::text, 'ExclusiveLock'::text), 400 | ('RowExclusiveLock'::text, 'AccessExclusiveLock'::text), 401 | ('ShareUpdateExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 402 | ('ShareUpdateExclusiveLock'::text, 'ShareLock'::text), 403 | ('ShareUpdateExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 404 | ('ShareUpdateExclusiveLock'::text, 'ExclusiveLock'::text), 405 | ('ShareUpdateExclusiveLock'::text, 'AccessExclusiveLock'::text), 406 | ('ShareLock'::text, 'RowExclusiveLock'::text), 407 | ('ShareLock'::text, 'ShareUpdateExclusiveLock'::text), 408 | ('ShareLock'::text, 'ShareRowExclusiveLock'::text), 409 | ('ShareLock'::text, 'ExclusiveLock'::text), 410 | ('ShareLock'::text, 'AccessExclusiveLock'::text), 411 | ('ShareRowExclusiveLock'::text, 'RowExclusiveLock'::text), 412 | ('ShareRowExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 413 | ('ShareRowExclusiveLock'::text, 'ShareLock'::text), 414 | ('ShareRowExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 415 | ('ShareRowExclusiveLock'::text, 'ExclusiveLock'::text), 416 | ('ShareRowExclusiveLock'::text, 'AccessExclusiveLock'::text), 417 | ('ExclusiveLock'::text, 'RowShareLock'::text), 418 | ('ExclusiveLock'::text, 'RowExclusiveLock'::text), 419 | ('ExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 420 | ('ExclusiveLock'::text, 'ShareLock'::text), 421 | ('ExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 422 | ('ExclusiveLock'::text, 'ExclusiveLock'::text), 423 | ('ExclusiveLock'::text, 'AccessExclusiveLock'::text), 424 | ('AccessExclusiveLock'::text, 'AccessShareLock'::text), 425 | ('AccessExclusiveLock'::text, 'RowShareLock'::text), 426 | ('AccessExclusiveLock'::text, 'RowExclusiveLock'::text), 427 | ('AccessExclusiveLock'::text, 'ShareUpdateExclusiveLock'::text), 428 | ('AccessExclusiveLock'::text, 'ShareLock'::text), 429 | ('AccessExclusiveLock'::text, 'ShareRowExclusiveLock'::text), 430 | ('AccessExclusiveLock'::text, 'ExclusiveLock'::text), 431 | ('AccessExclusiveLock'::text, 'AccessExclusiveLock'::text) 432 | ) 433 | , lock AS ( 434 | SELECT pid, 435 | virtualtransaction, 436 | granted, 437 | mode, 438 | (locktype, 439 | CASE locktype 440 | WHEN 'relation' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text) 441 | WHEN 'extend' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text) 442 | WHEN 'page' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text, 'page#'||page::text) 443 | WHEN 'tuple' THEN concat_ws(';', 'db:'||datname, 'rel:'||relation::regclass::text, 'page#'||page::text, 'tuple#'||tuple::text) 444 | WHEN 'transactionid' THEN transactionid::text 445 | WHEN 'virtualxid' THEN virtualxid::text 446 | WHEN 'object' THEN concat_ws(';', 'class:'||classid::regclass::text, 'objid:'||objid, 'col#'||objsubid) 447 | ELSE concat('db:'||datname) 448 | END::text) AS target 449 | FROM pg_catalog.pg_locks 450 | LEFT JOIN pg_catalog.pg_database ON (pg_database.oid = pg_locks.database) 451 | ) 452 | , waiting_lock AS ( 453 | SELECT 454 | blocker.pid AS blocker_pid, 455 | blocked.pid AS pid, 456 | concat(blocked.mode,blocked.target) AS lock_target 457 | FROM lock blocker 458 | JOIN lock blocked 459 | ON ( NOT blocked.granted 460 | AND blocker.granted 461 | AND blocked.pid != blocker.pid 462 | AND blocked.target IS NOT DISTINCT FROM blocker.target) 463 | JOIN lock_composite c ON (c.requested = blocked.mode AND c.current = blocker.mode) 464 | ) 465 | , acquired_lock AS ( 466 | WITH waiting AS ( 467 | SELECT lock_target, count(lock_target) AS wait_count FROM waiting_lock GROUP BY lock_target 468 | ) 469 | SELECT 470 | pid, 471 | array_agg(concat(mode,target,' + '||wait_count) ORDER BY wait_count DESC NULLS LAST) AS locks_acquired 472 | FROM lock 473 | LEFT JOIN waiting ON waiting.lock_target = concat(mode,target) 474 | WHERE granted 475 | GROUP BY pid 476 | ) 477 | , blocking_lock AS ( 478 | SELECT 479 | ARRAY[date_part('epoch', query_start)::int, pid] AS seq, 480 | 0::int AS depth, 481 | -1::int AS blocker_pid, 482 | pid, 483 | concat('Connect: ',usename,' ',datname,' ',coalesce(host(client_addr)||':'||client_port, 'local') 484 | , E'\nSQL: ',replace(substr(coalesce(query,'N/A'), 1, 60), E'\n', ' ') 485 | , E'\nAcquired:\n ' 486 | , array_to_string(locks_acquired[1:5] || 487 | CASE WHEN array_upper(locks_acquired,1) > 5 488 | THEN '... '||(array_upper(locks_acquired,1) - 5)::text||' more ...' 489 | END, 490 | E'\n ') 491 | ) AS lock_info, 492 | concat(to_char(query_start, CASE WHEN age(query_start) > '24h' THEN 'Day DD Mon' ELSE 'HH24:MI:SS' END),E' started\n' 493 | ,CASE WHEN wait_event IS NOT NULL THEN 'waiting' ELSE state END,E'\n' 494 | ,date_trunc('second',age(now(),query_start)),' ago' 495 | ) AS lock_state 496 | FROM acquired_lock blocker 497 | LEFT JOIN pg_stat_activity act USING (pid) 498 | WHERE EXISTS 499 | (SELECT 'x' FROM waiting_lock blocked WHERE blocked.blocker_pid = blocker.pid) 500 | AND NOT EXISTS 501 | (SELECT 'x' FROM waiting_lock blocked WHERE blocked.pid = blocker.pid) 502 | UNION ALL 503 | SELECT 504 | blocker.seq || blocked.pid, 505 | blocker.depth + 1, 506 | blocker.pid, 507 | blocked.pid, 508 | concat('Connect: ',usename,' ',datname,' ',coalesce(host(client_addr)||':'||client_port, 'local') 509 | , E'\nSQL: ',replace(substr(coalesce(query,'N/A'), 1, 60), E'\n', ' ') 510 | , E'\nWaiting: ',blocked.lock_target 511 | , CASE WHEN locks_acquired IS NOT NULL 512 | THEN E'\nAcquired:\n ' || 513 | array_to_string(locks_acquired[1:5] || 514 | CASE WHEN array_upper(locks_acquired,1) > 5 515 | THEN '... '||(array_upper(locks_acquired,1) - 5)::text||' more ...' 516 | END, 517 | E'\n ') 518 | END 519 | ) AS lock_info, 520 | concat(to_char(query_start, CASE WHEN age(query_start) > '24h' THEN 'Day DD Mon' ELSE 'HH24:MI:SS' END),E' started\n' 521 | ,CASE WHEN wait_event IS NOT NULL THEN 'waiting' ELSE state END,E'\n' 522 | ,date_trunc('second',age(now(),query_start)),' ago' 523 | ) AS lock_state 524 | FROM blocking_lock blocker 525 | JOIN waiting_lock blocked 526 | ON (blocked.blocker_pid = blocker.pid) 527 | LEFT JOIN pg_stat_activity act ON (act.pid = blocked.pid) 528 | LEFT JOIN acquired_lock acq ON (acq.pid = blocked.pid) 529 | WHERE blocker.depth < 5 530 | ) 531 | SELECT concat(lpad('=> ', 4*depth, ' '),pid::text) AS PID 532 | , lock_info AS Lock_Info 533 | , lock_state AS State 534 | FROM blocking_lock 535 | ORDER BY seq;" 536 | 537 | # checkpoint and background writer 538 | bgworker_checkpoint_state="SELECT 539 | checkpoints_timed + checkpoints_req AS total_checkpoints, 540 | pg_size_pretty(block_size * buffers_clean ) AS bgworker_total_writen, 541 | pg_size_pretty(block_size * buffers_checkpoint ) AS chkpointer_total_writen, 542 | pg_size_pretty(block_size * buffers_backend ) AS backend_total_writen, 543 | pg_size_pretty(block_size * buffers_checkpoint / (checkpoints_timed + checkpoints_req)) AS checkpoint_write_avg, 544 | EXTRACT(EPOCH FROM (now() - pg_postmaster_start_time())) / (checkpoints_timed + checkpoints_req) / 60 AS minutes_between_checkpoints, 545 | buffers_backend_fsync 546 | FROM 547 | pg_stat_bgwriter, 548 | ( 549 | SELECT current_setting('block_size')::int AS block_size) AS bs" 550 | 551 | # transaction id consume 552 | age_consume="SELECT 553 | datname, 554 | age(datfrozenxid) AS frozen_xid_age, 555 | ROUND(100 * (age(datfrozenxid) / 2000000000::float)) consumed_txid_pct, 556 | 2 * 1024 ^ 3 - 1 - age(datfrozenxid) AS remaining_txid, 557 | current_setting('autovacuum_freeze_max_age')::int - age(datfrozenxid) AS remaining_aggressive_vacuum 558 | FROM 559 | pg_database;" 560 | 561 | 562 | # transaction id at database level 563 | age_consume_dblvl="WITH max_age AS ( 564 | SELECT 565 | 2000000000 AS max_old_txid, 566 | setting AS autovacuum_freeze_max_age 567 | FROM 568 | pg_catalog.pg_settings 569 | WHERE 570 | name = 'autovacuum_freeze_max_age' 571 | ), 572 | per_database_stats AS ( 573 | SELECT 574 | datname, 575 | m.max_old_txid::int, 576 | m.autovacuum_freeze_max_age::int, 577 | age(d.datfrozenxid) AS oldest_current_txid 578 | FROM 579 | pg_catalog.pg_database d 580 | JOIN max_age m ON (TRUE) 581 | WHERE 582 | d.datallowconn 583 | ) 584 | SELECT 585 | max(oldest_current_txid) AS oldest_current_txid, 586 | max(ROUND(100 * (oldest_current_txid / max_old_txid::float))) AS consumed_txid_pct, 587 | max(ROUND(100 * (oldest_current_txid / autovacuum_freeze_max_age::float))) AS consumed_autovac_max_age 588 | FROM 589 | per_database_stats; 590 | " 591 | 592 | # transaction id as relation level 593 | age_consume_rel_lvl="SELECT 594 | c.oid::regclass, 595 | age(c.relfrozenxid), 596 | pg_size_pretty(pg_total_relation_size(c.oid)) 597 | FROM 598 | pg_class c 599 | JOIN pg_namespace n ON c.relnamespace = n.oid 600 | WHERE 601 | relkind IN ('r', 't', 'm') 602 | AND n.nspname NOT IN ('pg_toast') 603 | ORDER BY 604 | 2 DESC 605 | LIMIT 50;" 606 | 607 | # replication query 608 | if [ $current_version -ge 10 ] ;then 609 | replication_qry=" 610 | SELECT 611 | client_addr AS client, 612 | usename AS user, 613 | application_name AS name, 614 | state, 615 | sync_state AS mode, 616 | write_lag, 617 | flush_lag, 618 | replay_lag 619 | FROM 620 | pg_stat_replication;" 621 | else 622 | replication_qry=" 623 | SELECT 624 | client_addr AS client, 625 | usename AS user, 626 | application_name AS name, 627 | state, 628 | sync_state AS mode, 629 | (pg_xlog_location_diff(pg_current_xlog_location(), sent_location) / 1024)::bigint AS pending, 630 | (pg_xlog_location_diff(sent_location, write_location) / 1024)::bigint AS write, 631 | (pg_xlog_location_diff(write_location, flush_location) / 1024)::bigint AS flush, 632 | (pg_xlog_location_diff(flush_location, replay_location) / 1024)::bigint AS replay, 633 | (pg_xlog_location_diff(pg_current_xlog_location(), replay_location))::bigint / 1024 AS total_lag 634 | FROM 635 | pg_stat_replication;" 636 | fi 637 | 638 | # current connection 639 | current_connection="SELECT 640 | datname, 641 | count(*) AS open, 642 | count(*) FILTER (WHERE state = 'active') AS active, 643 | count(*) FILTER (WHERE state = 'idle') AS idle, 644 | count(*) FILTER (WHERE state = 'idle in transaction') AS idle_in_trans 645 | FROM 646 | pg_stat_activity 647 | GROUP BY 648 | ROLLUP (1);" 649 | 650 | # current query 651 | current_query="SELECT 652 | datname, 653 | pid, 654 | age(clock_timestamp(), query_start), 655 | usename, 656 | application_name, 657 | wait_event, 658 | wait_event_type, 659 | query 660 | FROM 661 | pg_stat_activity 662 | WHERE 663 | state != 'idle' 664 | AND 665 | query NOT ILIKE '%pg_stat_activity%' 666 | ORDER BY 667 | query_start DESC;" 668 | 669 | # index bloat 670 | index_bloat="WITH btree_index_atts AS ( 671 | SELECT pg_namespace.nspname, 672 | indexclass.relname AS index_name, 673 | indexclass.reltuples, 674 | indexclass.relpages, 675 | pg_index.indrelid, 676 | pg_index.indexrelid, 677 | indexclass.relam, 678 | tableclass.relname AS tablename, 679 | (regexp_split_to_table((pg_index.indkey)::text, ' '::text))::smallint AS attnum, 680 | pg_index.indexrelid AS index_oid 681 | FROM ((((pg_index 682 | JOIN pg_class indexclass ON ((pg_index.indexrelid = indexclass.oid))) 683 | JOIN pg_class tableclass ON ((pg_index.indrelid = tableclass.oid))) 684 | JOIN pg_namespace ON ((pg_namespace.oid = indexclass.relnamespace))) 685 | JOIN pg_am ON ((indexclass.relam = pg_am.oid))) 686 | WHERE ((pg_am.amname = 'btree'::name) AND (indexclass.relpages > 0)) 687 | ), index_item_sizes AS ( 688 | SELECT ind_atts.nspname, 689 | ind_atts.index_name, 690 | ind_atts.reltuples, 691 | ind_atts.relpages, 692 | ind_atts.relam, 693 | ind_atts.indrelid AS table_oid, 694 | ind_atts.index_oid, 695 | (current_setting('block_size'::text))::numeric AS bs, 696 | 8 AS maxalign, 697 | 24 AS pagehdr, 698 | CASE 699 | WHEN (max(COALESCE(pg_stats.null_frac, (0)::real)) = (0)::double precision) THEN 2 700 | ELSE 6 701 | END AS index_tuple_hdr, 702 | sum((((1)::double precision - COALESCE(pg_stats.null_frac, (0)::real)) * (COALESCE(pg_stats.avg_width, 1024))::double precision)) AS nulldatawidth 703 | FROM ((pg_attribute 704 | JOIN btree_index_atts ind_atts ON (((pg_attribute.attrelid = ind_atts.indexrelid) AND (pg_attribute.attnum = ind_atts.attnum)))) 705 | JOIN pg_stats ON (((pg_stats.schemaname = ind_atts.nspname) AND (((pg_stats.tablename = ind_atts.tablename) AND ((pg_stats.attname)::text = pg_get_indexdef(pg_attribute.attrelid, (pg_attribute.attnum)::integer, true))) OR ((pg_stats.tablename = ind_atts.index_name) AND (pg_stats.attname = pg_attribute.attname)))))) 706 | WHERE (pg_attribute.attnum > 0) 707 | GROUP BY ind_atts.nspname, ind_atts.index_name, ind_atts.reltuples, ind_atts.relpages, ind_atts.relam, ind_atts.indrelid, ind_atts.index_oid, (current_setting('block_size'::text))::numeric, 8::integer 708 | ), index_aligned_est AS ( 709 | SELECT index_item_sizes.maxalign, 710 | index_item_sizes.bs, 711 | index_item_sizes.nspname, 712 | index_item_sizes.index_name, 713 | index_item_sizes.reltuples, 714 | index_item_sizes.relpages, 715 | index_item_sizes.relam, 716 | index_item_sizes.table_oid, 717 | index_item_sizes.index_oid, 718 | COALESCE(ceil((((index_item_sizes.reltuples * ((((((((6 + index_item_sizes.maxalign) - 719 | CASE 720 | WHEN ((index_item_sizes.index_tuple_hdr % index_item_sizes.maxalign) = 0) THEN index_item_sizes.maxalign 721 | ELSE (index_item_sizes.index_tuple_hdr % index_item_sizes.maxalign) 722 | END))::double precision + index_item_sizes.nulldatawidth) + (index_item_sizes.maxalign)::double precision) - ( 723 | CASE 724 | WHEN (((index_item_sizes.nulldatawidth)::integer % index_item_sizes.maxalign) = 0) THEN index_item_sizes.maxalign 725 | ELSE ((index_item_sizes.nulldatawidth)::integer % index_item_sizes.maxalign) 726 | END)::double precision))::numeric)::double precision) / ((index_item_sizes.bs - (index_item_sizes.pagehdr)::numeric))::double precision) + (1)::double 727 | precision)), (0)::double precision) AS expected 728 | FROM index_item_sizes 729 | ), raw_bloat AS ( 730 | SELECT current_database() AS dbname, 731 | index_aligned_est.nspname, 732 | pg_class.relname AS table_name, 733 | index_aligned_est.index_name, 734 | (index_aligned_est.bs * ((index_aligned_est.relpages)::bigint)::numeric) AS totalbytes, 735 | index_aligned_est.expected, 736 | CASE 737 | WHEN ((index_aligned_est.relpages)::double precision <= index_aligned_est.expected) THEN (0)::numeric 738 | ELSE (index_aligned_est.bs * ((((index_aligned_est.relpages)::double precision - index_aligned_est.expected))::bigint)::numeric) 739 | END AS wastedbytes, 740 | CASE 741 | WHEN ((index_aligned_est.relpages)::double precision <= index_aligned_est.expected) THEN (0)::numeric 742 | ELSE (((index_aligned_est.bs * ((((index_aligned_est.relpages)::double precision - index_aligned_est.expected))::bigint)::numeric) * (100)::numeric) / (index_aligned_est.bs * ((index_aligned_est.relpages)::bigint)::numeric)) 743 | END AS realbloat, 744 | pg_relation_size((index_aligned_est.table_oid)::regclass) AS table_bytes, 745 | stat.idx_scan AS index_scans 746 | FROM ((index_aligned_est 747 | JOIN pg_class ON ((pg_class.oid = index_aligned_est.table_oid))) 748 | JOIN pg_stat_user_indexes stat ON ((index_aligned_est.index_oid = stat.indexrelid))) 749 | ), format_bloat AS ( 750 | SELECT raw_bloat.dbname AS database_name, 751 | raw_bloat.nspname AS schema_name, 752 | raw_bloat.table_name, 753 | raw_bloat.index_name, 754 | round(raw_bloat.realbloat) AS bloat_pct, 755 | round((raw_bloat.wastedbytes / (((1024)::double precision ^ (2)::double precision))::numeric)) AS bloat_mb, 756 | round((raw_bloat.totalbytes / (((1024)::double precision ^ (2)::double precision))::numeric), 3) AS index_mb, 757 | round(((raw_bloat.table_bytes)::numeric / (((1024)::double precision ^ (2)::double precision))::numeric), 3) AS table_mb, 758 | raw_bloat.index_scans 759 | FROM raw_bloat 760 | ) 761 | SELECT format_bloat.database_name AS datname, 762 | format_bloat.schema_name AS nspname, 763 | format_bloat.table_name AS relname, 764 | format_bloat.index_name AS idxname, 765 | format_bloat.index_scans AS idx_scans, 766 | format_bloat.bloat_pct, 767 | format_bloat.table_mb, 768 | (format_bloat.index_mb - format_bloat.bloat_mb) AS actual_mb, 769 | format_bloat.bloat_mb, 770 | format_bloat.index_mb AS total_mb 771 | FROM format_bloat 772 | ORDER BY format_bloat.bloat_mb DESC;" 773 | 774 | # index duplicate 775 | index_duplicate="SELECT sub.table, 776 | pg_size_pretty(sum(pg_relation_size(idx))::bigint) as size, 777 | (array_agg(idx))[1] as idx1, (array_agg(idx))[2] as idx2, 778 | (array_agg(idx))[3] as idx3, (array_agg(idx))[4] as idx4 779 | FROM ( 780 | SELECT s.schemaname||'.'||s.relname as table,i.indexrelid::regclass as idx, (i.indrelid::text ||E'\n'|| i.indclass::text ||E'\n'|| i.indkey::text ||E'\n'|| 781 | coalesce(i.indexprs::text,'')||E'\n' || coalesce(i.indpred::text,'')) as key 782 | FROM pg_index i join pg_stat_all_indexes s on i.indexrelid = s.indexrelid) sub 783 | GROUP BY sub.table,key HAVING count(*)>1 784 | ORDER BY sum(pg_relation_size(idx)) DESC;" 785 | 786 | # index low efficiency 787 | index_low_efficiency="SELECT 788 | s.schemaname AS schema, 789 | s.relname AS table, 790 | indexrelname AS index, 791 | i.indisunique, 792 | idx_scan AS idx_scans 793 | FROM pg_catalog.pg_stat_user_indexes s, 794 | pg_index i 795 | WHERE i.indexrelid = s.indexrelid 796 | ORDER BY idx_scan" 797 | 798 | # index state 799 | index_state="SELECT 800 | CONCAT(n.nspname, '.', c.relname) AS table, 801 | i.relname AS index_name, 802 | pg_size_pretty(pg_relation_size(x.indrelid)) AS table_size, 803 | pg_size_pretty(pg_relation_size(x.indexrelid)) AS index_size, 804 | pg_size_pretty(pg_total_relation_size(x.indrelid)) AS total_size, 805 | c.reltuples AS num_rows, 806 | c.relpages AS num_pages, 807 | c.reltuples / nullif (c.relpages, 0) AS num_per_page, 808 | CASE WHEN indisunique THEN 809 | 'Y' 810 | ELSE 811 | 'N' 812 | END AS UNIQUE, 813 | idx_scan AS number_of_scans, 814 | idx_tup_read AS tuples_read, 815 | idx_tup_fetch AS tuples_fetched 816 | FROM 817 | pg_class c 818 | JOIN pg_index x ON c.oid = x.indrelid 819 | JOIN pg_class i ON i.oid = x.indexrelid 820 | JOIN pg_stat_all_indexes s ON s.indexrelid = x.indexrelid 821 | LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 822 | WHERE 823 | c.relkind = ANY (ARRAY['r', 't', 'i']) 824 | AND n.nspname NOT IN ('pg_toast', 'pg_catalog', 'information_schema') 825 | ORDER BY 826 | 1, 827 | 2;" 828 | 829 | # index state 830 | index_state_further="SELECT 831 | pg_namespace.nspname as schema, 832 | pg_class.relname as table, 833 | pg_size_pretty(pg_class.reltuples::bigint) AS rows_in_bytes, 834 | pg_class.reltuples AS num_rows, 835 | COUNT(*) AS total_indexes, 836 | COUNT(*) FILTER ( WHERE indisunique) AS unique_indexes, 837 | COUNT(*) FILTER ( WHERE indnatts = 1 ) AS single_column_indexes, 838 | COUNT(*) FILTER ( WHERE indnatts IS DISTINCT FROM 1 ) AS multi_column_indexes 839 | FROM 840 | pg_namespace 841 | LEFT JOIN pg_class ON pg_namespace.oid = pg_class.relnamespace 842 | LEFT JOIN pg_index ON pg_class.oid = pg_index.indrelid 843 | WHERE 844 | pg_class.relkind = 'r' 845 | AND pg_namespace.nspname NOT IN ('pg_toast', 'pg_catalog', 'information_schema') 846 | GROUP BY pg_class.relname, pg_class.reltuples,pg_namespace.nspname 847 | ORDER BY 1,2 DESC;" 848 | 849 | # long transaction 850 | long_transaction="SELECT 851 | state, 852 | wait_event, 853 | wait_event_type, 854 | client_addr, 855 | client_port, 856 | application_name, 857 | now() - xact_start as duration, 858 | query 859 | FROM 860 | pg_stat_activity 861 | WHERE 862 | state <> 'idle' 863 | AND (backend_xid IS NOT NULL 864 | OR backend_xmin IS NOT NULL) 865 | AND now() - xact_start > interval '5 min' 866 | ORDER BY 867 | xact_start;" 868 | 869 | # relation bloat 870 | relation_bloat="-- new table bloat query 871 | -- still needs work; is often off by +/- 20% 872 | WITH constants AS ( 873 | -- define some constants for sizes of things 874 | -- for reference down the query and easy maintenance 875 | SELECT 876 | current_setting('block_size')::numeric AS bs, 877 | 23 AS hdr, 878 | 8 AS ma 879 | ), 880 | no_stats AS ( 881 | -- screen out table who have attributes 882 | -- which dont have stats, such as JSON 883 | SELECT 884 | table_schema, 885 | table_name, 886 | n_live_tup::numeric AS est_rows, 887 | pg_table_size(relid)::numeric AS table_size 888 | FROM 889 | information_schema.columns 890 | JOIN pg_stat_user_tables AS psut ON table_schema = psut.schemaname 891 | AND table_name = psut.relname 892 | LEFT OUTER JOIN pg_stats ON table_schema = pg_stats.schemaname 893 | AND table_name = pg_stats.tablename 894 | AND column_name = attname 895 | WHERE 896 | attname IS NULL 897 | AND table_schema NOT IN ('pg_catalog', 'information_schema') 898 | GROUP BY 899 | table_schema, 900 | table_name, 901 | relid, 902 | n_live_tup 903 | ), 904 | null_headers AS ( 905 | -- calculate null header sizes 906 | -- omitting tables which dont have complete stats 907 | -- and attributes which aren't visible 908 | SELECT 909 | hdr + 1 + (sum( 910 | CASE WHEN null_frac <> 0 THEN 911 | 1 912 | ELSE 913 | 0 914 | END) / 8) AS nullhdr, 915 | SUM((1 - null_frac) * avg_width) AS datawidth, 916 | MAX(null_frac) AS maxfracsum, 917 | schemaname, 918 | tablename, 919 | hdr, 920 | ma, 921 | bs 922 | FROM 923 | pg_stats 924 | CROSS JOIN constants 925 | LEFT OUTER JOIN no_stats ON schemaname = no_stats.table_schema 926 | AND tablename = no_stats.table_name 927 | WHERE 928 | schemaname NOT IN ('pg_catalog', 'information_schema') 929 | AND no_stats.table_name IS NULL 930 | AND EXISTS ( 931 | SELECT 932 | 1 933 | FROM 934 | information_schema.columns 935 | WHERE 936 | schemaname = columns.table_schema 937 | AND tablename = columns.table_name) 938 | GROUP BY 939 | schemaname, 940 | tablename, 941 | hdr, 942 | ma, 943 | bs 944 | ), 945 | data_headers AS ( 946 | -- estimate header and row size 947 | SELECT 948 | ma, 949 | bs, 950 | hdr, 951 | schemaname, 952 | tablename, 953 | (datawidth + (hdr + ma - ( 954 | CASE WHEN hdr % ma = 0 THEN 955 | ma 956 | ELSE 957 | hdr % ma 958 | END)))::numeric AS datahdr, 959 | (maxfracsum * (nullhdr + ma - ( 960 | CASE WHEN nullhdr % ma = 0 THEN 961 | ma 962 | ELSE 963 | nullhdr % ma 964 | END))) AS nullhdr2 965 | FROM 966 | null_headers 967 | ), 968 | table_estimates AS ( 969 | -- make estimates of how large the table should be 970 | -- based on row and page size 971 | SELECT 972 | schemaname, 973 | tablename, 974 | bs, 975 | reltuples::numeric AS est_rows, 976 | relpages * bs AS table_bytes, 977 | CEIL((reltuples * (datahdr + nullhdr2 + 4 + ma - ( 978 | CASE WHEN datahdr % ma = 0 THEN 979 | ma 980 | ELSE 981 | datahdr % ma 982 | END)) / (bs - 20))) * bs AS expected_bytes, 983 | reltoastrelid 984 | FROM 985 | data_headers 986 | JOIN pg_class ON tablename = relname 987 | JOIN pg_namespace ON relnamespace = pg_namespace.oid 988 | AND schemaname = nspname 989 | WHERE 990 | pg_class.relkind = 'r' 991 | ), 992 | estimates_with_toast AS ( 993 | -- add in estimated TOAST table sizes 994 | -- estimate based on 4 toast tuples per page because we dont have 995 | -- anything better. also append the no_data tables 996 | SELECT 997 | schemaname, 998 | tablename, 999 | TRUE AS can_estimate, 1000 | est_rows, 1001 | table_bytes + (coalesce(toast.relpages, 0) * bs) AS table_bytes, 1002 | expected_bytes + (ceil(coalesce(toast.reltuples, 0) / 4) * bs) AS expected_bytes 1003 | FROM 1004 | table_estimates 1005 | LEFT OUTER JOIN pg_class AS toast ON table_estimates.reltoastrelid = toast.oid 1006 | AND toast.relkind = 't' 1007 | ), 1008 | table_estimates_plus AS ( 1009 | -- add some extra metadata to the table data 1010 | -- and calculations to be reused 1011 | -- including whether we cant estimate it 1012 | -- or whether we think it might be compressed 1013 | SELECT 1014 | current_database() AS databasename, 1015 | schemaname, 1016 | tablename, 1017 | can_estimate, 1018 | est_rows, 1019 | CASE WHEN table_bytes > 0 THEN 1020 | table_bytes::numeric 1021 | ELSE 1022 | NULL::numeric 1023 | END AS table_bytes, 1024 | CASE WHEN expected_bytes > 0 THEN 1025 | expected_bytes::numeric 1026 | ELSE 1027 | NULL::numeric 1028 | END AS expected_bytes, 1029 | CASE WHEN expected_bytes > 0 1030 | AND table_bytes > 0 1031 | AND expected_bytes <= table_bytes THEN 1032 | (table_bytes - expected_bytes)::numeric 1033 | ELSE 1034 | 0::numeric 1035 | END AS bloat_bytes 1036 | FROM 1037 | estimates_with_toast 1038 | UNION ALL 1039 | SELECT 1040 | current_database() AS databasename, 1041 | table_schema, 1042 | table_name, 1043 | FALSE, 1044 | est_rows, 1045 | table_size, 1046 | NULL::numeric, 1047 | NULL::numeric 1048 | FROM 1049 | no_stats 1050 | ), 1051 | bloat_data AS ( 1052 | -- do final math calculations and formatting 1053 | SELECT 1054 | current_database() AS databasename, 1055 | schemaname, 1056 | tablename, 1057 | can_estimate, 1058 | table_bytes, 1059 | round(table_bytes / (1024 ^ 2)::numeric, 3) AS table_mb, 1060 | expected_bytes, 1061 | round(expected_bytes / (1024 ^ 2)::numeric, 3) AS expected_mb, 1062 | round(bloat_bytes * 100 / table_bytes) AS pct_bloat, 1063 | round(bloat_bytes / (1024::numeric ^ 2), 2) AS mb_bloat, 1064 | table_bytes, 1065 | expected_bytes, 1066 | est_rows 1067 | FROM 1068 | table_estimates_plus) 1069 | -- filter output for bloated tables 1070 | SELECT 1071 | databasename, 1072 | schemaname, 1073 | tablename, 1074 | can_estimate, 1075 | est_rows, 1076 | pct_bloat, 1077 | mb_bloat, 1078 | table_mb 1079 | FROM 1080 | bloat_data 1081 | -- this where clause defines which tables actually appear 1082 | -- in the bloat chart 1083 | -- example below filters for tables which are either 50% 1084 | -- bloated and more than 20mb in size, or more than 25% 1085 | -- bloated and more than 4GB in size 1086 | WHERE (pct_bloat >= 50 1087 | AND mb_bloat >= 10) 1088 | OR (pct_bloat >= 25 1089 | AND mb_bloat >= 1000) 1090 | ORDER BY 1091 | pct_bloat DESC;" 1092 | 1093 | # oldest xmin 1094 | <