├── LICENSE ├── README.md ├── btree ├── btree_bloat-7.4.sql ├── btree_bloat-8.0-8.1.sql ├── btree_bloat-superuser.sql └── btree_bloat.sql └── table ├── table_bloat-74-81.sql ├── table_bloat-82-84.sql └── table_bloat.sql /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2015-2019, Jehan-Guillaume (ioguix) de Rorthais 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | 10 | * Redistributions in binary form must reproduce the above copyright notice, 11 | this list of conditions and the following disclaimer in the documentation 12 | and/or other materials provided with the distribution. 13 | 14 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 15 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 16 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 17 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 18 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 19 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 20 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 21 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 22 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 23 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 24 | 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pgsql-bloat-estimation 2 | 3 | Queries to mesure statistical bloat in btree indexes and tables for PostgreSQL. 4 | 5 | Three different kind of non used space should be considered: 6 | 7 | * the alignment padding: depending on the type, PostgreSQL adds some padding 8 | to your fields to align them correctly in the row. This is related to some 9 | CPU manipulation optimisation. 10 | * the fillfactor: this allows you to set up a ratio of free space to keep 11 | in your tables or indexes. See 12 | [the PostgreSQL documentation](http://www.postgresql.org/docs/9.4/static/sql-createtable.html#SQL-CREATETABLE-STORAGE-PARAMETERS) 13 | for more information 14 | * the bloat itself: this is the extra space not needed by the table or the 15 | index to keep your rows. This should be mapped and under control by 16 | autovacuum and/or your vacuum maintenance procedure. 17 | 18 | ToC: 19 | 20 | * [Bloat in Tables](#bloat-in-tables) 21 | * [Bloat in btree indexes](#bloat-in-btree-indexes) 22 | * [Caveats](#caveats) 23 | * [The ``is_na`` column](#the-is_na-column) 24 | * [Toasted fields](#toasted-fields) 25 | * [Alignment padding](#alignment-padding) 26 | * [Size of tables/indexes](#size-of-tablesindexes) 27 | 28 | ## Bloat in Tables 29 | 30 | The queries from the "table" folder estimate the bloat for tables. They expose 31 | these fields: 32 | 33 | * ``current_database``: name of the current database. 34 | * ``schemaname``: schema of the table. 35 | * ``tblname``: the table name. 36 | * ``real_size``: real size of the table. 37 | * ``extra_size``: estimated extra size not used/needed in the table. This 38 | extra size is composed by the fillfactor, bloat and alignment padding 39 | spaces. 40 | * ``extra_pct``: estimated percentage of the real size used by ``extra_size``. 41 | * ``fillfactor``: the fillfactor of the table. 42 | * ``bloat_size``: estimated size of the bloat without the extra space kept 43 | for the fillfactor. 44 | * ``bloat_pct``: estimated percentage of the real size used by ``bloat_size``. 45 | * ``is_na``: is the estimation "Not Applicable" ? If true, do not trust the 46 | stats. 47 | 48 | AS 7.4, 8.0 and 8.1 do not have fillfactor, ``extra_size``, ``extra_pct`` 49 | and ``bloat_size`` are not reported. 50 | 51 | 52 | ## Bloat in btree indexes 53 | 54 | The queries from the "btree" folder estimate the bloat for btree indexes. They 55 | expose these fields: 56 | 57 | * ``current_database``: name of the current database 58 | * ``schemaname``: schema of the table 59 | * ``tblname``: the table name 60 | * ``idxname``: the index name 61 | * ``real_size``: real size of the index 62 | * ``extra_size``: estimated extra size not used/needed by the index. This 63 | extra size is composed by the fillfactor, bloat and alignment padding 64 | spaces. 65 | * ``extra_pct``: estimated percentage of the real size used by ``extra_size``. 66 | * ``fillfactor``: the fillfactor of the index. 67 | * ``bloat_size``: estimated size of the bloat without the extra space kept 68 | for the fillfactor. 69 | * ``bloat_pct``: estimated percentage of the real size used by ``bloat_size``. 70 | * ``is_na``: is the estimation "Not Applicable" ? If true, do not trust the 71 | stats. 72 | 73 | The query in file `btree_bloat-superuser.sql` is much faster than other one. 74 | However, it must be executed by a superuser role only. 75 | 76 | ## Caveats 77 | 78 | ### The ``is_na`` column 79 | 80 | This field allows you to filter out statistics considered wrong by the query 81 | itself. Just uncomment the ``WHERE`` clause. 82 | 83 | This excludes: 84 | 85 | * any table or index using the ``name`` type. Statistics 86 | for this type are not correlated to its space use, leading to wrong 87 | statistics. A lot of relations from ``pg_catalog`` reports negative 88 | stats because of this. 89 | * any table which lacks some statistics. For example, the json type had 90 | no statistics available before 9.5 91 | 92 | ### Toasted fields 93 | 94 | PostgreSQL has an internal mechanism to compress/slice large values from large 95 | rows outside of the heap space in a relation called ``TOAST``. See the 96 | following page for more informations: 97 | [https://www.postgresql.org/docs/current/storage-toast.html](https://www.postgresql.org/docs/current/storage-toast.html) 98 | 99 | Depending on your values, some fields might be toasted and some other not among 100 | the same table. Unfortunately, there's no statistics available about how much 101 | data has been toasted away from the heap, how much has been compressed inside 102 | the heap, their real size, etc. In short, the average field statistics in heap 103 | do not consider if the value is a toast pointer or a real value. 104 | 105 | Because of this, statistics on variable length fields might be largely 106 | underestimated, even leading to negative bloat for some tables. 107 | 108 | There's no way to include such situation in the existing ``is_na`` column. 109 | 110 | ### Alignment padding 111 | 112 | Unfortunately, as it is not possible to compute the space wasted by the 113 | alignment paddings, it is always reported in the bloat fields. Sometime, this 114 | space can takes up to 10% or more of the table size. See the chapter "The 115 | alignment deviation" [from this page](http://blog.ioguix.net/postgresql/2014/09/10/Bloat-estimation-for-tables.html) 116 | for more information. 117 | 118 | This means you can estimate this space by running the query on non-bloated 119 | table. The bloat fields will then only report this alignment padding space. For 120 | large table, you can sample it in a smaller table of 100 pages or so, keeping 121 | the same field order. The bloat estimation query will report the same average 122 | space wasted by alignment padding from this table. 123 | 124 | 125 | ### Size of tables/indexes 126 | 127 | Small table or indexes (few pages) will certainly reports high bloat percentage. 128 | Each pages beeing 8kB, the less you have rows to fill them, the smaller they 129 | are, the more you will have natural spaces in there. 130 | 131 | As example, if you need 100 rows to fill one page and your table have 150 rows, 132 | your table will be on 2 pages, 16kB. The second page having only 50 rows, You'll 133 | have a natural bloat of 4kB, 25% of your table. 134 | 135 | -------------------------------------------------------------------------------- /btree/btree_bloat-7.4.sql: -------------------------------------------------------------------------------- 1 | -- WARNING: executed with a non-superuser role, the query inspect only index on tables you are granted to read. 2 | -- WARNING: rows with is_na = 't' are known to have bad statistics (index on expression and "name" type are not supported). 3 | -- This query is compatible with PostgreSQL 7.4 only 4 | SELECT current_database(), nspname AS schemaname, tblname, idxname, bs*(sub.relpages)::bigint AS real_size, 5 | bs*est_pages::bigint as estimated_size, 6 | bs*(sub.relpages-est_pages)::bigint AS bloat_size, 7 | 100 * (sub.relpages-est_pages)::float / sub.relpages AS bloat_pct, is_na 8 | -- , est_pages, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, sub.reltuples, sub.relpages -- (DEBUG INFO) 9 | FROM ( 10 | SELECT bs, nspname, table_oid, tblname, idxname, relpages, coalesce( 11 | 1+ceil(reltuples/floor((bs-pageopqdata-pagehdr)/(4+nulldatahdrwidth)::float)), 0 -- ItemIdData size + computed avg size of a tuple (nulldatahdrwidth) 12 | ) AS est_pages, is_na 13 | -- , index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples -- (DEBUG INFO) 14 | FROM ( 15 | SELECT maxalign, bs, nspname, tblname, idxname, reltuples, relpages, relam, table_oid, 16 | ( index_tuple_hdr_bm + 17 | maxalign - CASE -- Add padding to the index tuple header to align on MAXALIGN 18 | WHEN index_tuple_hdr_bm%maxalign = 0 THEN maxalign 19 | ELSE index_tuple_hdr_bm%maxalign 20 | END 21 | + nulldatawidth + maxalign - CASE -- Add padding to the data to align on MAXALIGN 22 | WHEN nulldatawidth = 0 THEN 0 23 | WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign 24 | ELSE nulldatawidth::integer%maxalign 25 | END 26 | )::numeric AS nulldatahdrwidth, pagehdr, pageopqdata, is_na 27 | -- , index_tuple_hdr_bm, nulldatawidth -- (DEBUG INFO) 28 | FROM ( 29 | SELECT 30 | i.nspname, i.tblname, i.idxname, i.reltuples, i.relpages, i.relam, a.attrelid AS table_oid, 31 | 8192::numeric AS bs, 32 | CASE -- MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) 33 | WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 34 | ELSE 4 35 | END AS maxalign, 36 | /* per page header, fixed size: 20 for 7.X, 24 for others */ 37 | 20 AS pagehdr, 38 | /* per page btree opaque data */ 39 | 16 AS pageopqdata, 40 | /* per tuple header: add IndexAttributeBitMapData if some cols are null-able */ 41 | CASE WHEN max(coalesce(s.null_frac,0)) = 0 42 | THEN 8 -- IndexTupleData size 43 | ELSE 8 + (( 32 + 8 - 1 ) / 8) -- IndexTupleData size + IndexAttributeBitMapData size ( max num filed per index + 8 - 1 /8) 44 | END AS index_tuple_hdr_bm, 45 | /* data len: we remove null values save space using it fractionnal part from stats */ 46 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024)) AS nulldatawidth, 47 | max( CASE WHEN a.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 48 | OR count(1) <> i.indnatts AS is_na 49 | FROM pg_attribute AS a 50 | JOIN ( 51 | SELECT nspname, tbl.relname AS tblname, idx.relname AS idxname, idx.reltuples, idx.relpages, idx.relam, 52 | indrelid, indexrelid, string_to_array(pg_catalog.textin(pg_catalog.int2vectorout(indkey)), ' ')::smallint[] AS attnum, indnatts 53 | FROM pg_index 54 | JOIN pg_class idx ON idx.oid=pg_index.indexrelid 55 | JOIN pg_class tbl ON tbl.oid=pg_index.indrelid 56 | JOIN pg_namespace ON pg_namespace.oid = idx.relnamespace 57 | WHERE tbl.relkind = 'r' AND idx.relpages > 0 58 | ) AS i ON a.attrelid = i.indexrelid 59 | JOIN pg_stats AS s ON s.schemaname = i.nspname 60 | AND s.tablename = i.tblname AND s.attname = pg_catalog.pg_get_indexdef(a.attrelid, a.attnum, TRUE) 61 | JOIN pg_type AS t ON a.atttypid = t.oid 62 | WHERE a.attnum > 0 63 | GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, i.indnatts 64 | ) AS s1 65 | ) AS s2 66 | JOIN pg_am am ON s2.relam = am.oid WHERE am.amname = 'btree' 67 | ) AS sub 68 | -- WHERE NOT is_na 69 | ORDER BY 2,3,4; 70 | -------------------------------------------------------------------------------- /btree/btree_bloat-8.0-8.1.sql: -------------------------------------------------------------------------------- 1 | -- WARNING: executed with a non-superuser role, the query inspect only index on tables you are granted to read. 2 | -- WARNING: rows with is_na = 't' are known to have bad statistics ("name" type is not supported). 3 | -- This query is compatible with PostgreSQL 8.0 to 8.1 4 | SELECT current_database(), nspname AS schemaname, tblname, idxname, bs*(sub.relpages)::bigint AS real_size, 5 | bs*est_pages::bigint as estimated_size, 6 | bs*(sub.relpages-est_pages)::bigint AS bloat_size, 7 | 100 * (sub.relpages-est_pages)::float / sub.relpages AS bloat_pct, is_na 8 | -- , est_pages, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, sub.reltuples, sub.relpages -- (DEBUG INFO) 9 | FROM ( 10 | SELECT bs, nspname, table_oid, tblname, idxname, relpages, coalesce( 11 | 1+ceil(reltuples/floor((bs-pageopqdata-pagehdr)/(4+nulldatahdrwidth)::float)), 0 -- ItemIdData size + computed avg size of a tuple (nulldatahdrwidth) 12 | ) AS est_pages, is_na 13 | -- , index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples -- (DEBUG INFO) 14 | FROM ( 15 | SELECT maxalign, bs, nspname, tblname, idxname, reltuples, relpages, relam, table_oid, 16 | ( index_tuple_hdr_bm + 17 | maxalign - CASE -- Add padding to the index tuple header to align on MAXALIGN 18 | WHEN index_tuple_hdr_bm%maxalign = 0 THEN maxalign 19 | ELSE index_tuple_hdr_bm%maxalign 20 | END 21 | + nulldatawidth + maxalign - CASE -- Add padding to the data to align on MAXALIGN 22 | WHEN nulldatawidth = 0 THEN 0 23 | WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign 24 | ELSE nulldatawidth::integer%maxalign 25 | END 26 | )::numeric AS nulldatahdrwidth, pagehdr, pageopqdata, is_na 27 | -- , index_tuple_hdr_bm, nulldatawidth -- (DEBUG INFO) 28 | FROM ( 29 | SELECT 30 | i.nspname, i.tblname, i.idxname, i.reltuples, i.relpages, i.relam, a.attrelid AS table_oid, 31 | current_setting('block_size')::numeric AS bs, 32 | CASE -- MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) 33 | WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 34 | ELSE 4 35 | END AS maxalign, 36 | /* per page header, fixed size: 20 for 7.X, 24 for others */ 37 | 24 AS pagehdr, 38 | /* per page btree opaque data */ 39 | 16 AS pageopqdata, 40 | /* per tuple header: add IndexAttributeBitMapData if some cols are null-able */ 41 | CASE WHEN max(coalesce(s.null_frac,0)) = 0 42 | THEN 8 -- IndexTupleData size 43 | ELSE 8 + (( 32 + 8 - 1 ) / 8) -- IndexTupleData size + IndexAttributeBitMapData size ( max num filed per index + 8 - 1 /8) 44 | END AS index_tuple_hdr_bm, 45 | /* data len: we remove null values save space using it fractionnal part from stats */ 46 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024)) AS nulldatawidth, 47 | max( CASE WHEN a.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 AS is_na 48 | FROM pg_attribute AS a 49 | JOIN ( 50 | SELECT nspname, tbl.relname AS tblname, idx.relname AS idxname, idx.reltuples, idx.relpages, idx.relam, 51 | indrelid, indexrelid, string_to_array(pg_catalog.textin(pg_catalog.int2vectorout(indkey)), ' ')::smallint[] AS attnum 52 | FROM pg_index 53 | JOIN pg_class idx ON idx.oid=pg_index.indexrelid 54 | JOIN pg_class tbl ON tbl.oid=pg_index.indrelid 55 | JOIN pg_namespace ON pg_namespace.oid = idx.relnamespace 56 | WHERE tbl.relkind = 'r' AND idx.relpages > 0 57 | ) AS i ON a.attrelid = i.indexrelid 58 | JOIN pg_stats AS s ON s.schemaname = i.nspname 59 | AND ((s.tablename = i.tblname AND s.attname = pg_catalog.pg_get_indexdef(a.attrelid, a.attnum, TRUE)) -- stats from tbl 60 | OR (s.tablename = i.idxname AND s.attname = a.attname))-- stats from functionnal cols 61 | JOIN pg_type AS t ON a.atttypid = t.oid 62 | WHERE a.attnum > 0 63 | GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9 64 | ) AS s1 65 | ) AS s2 66 | JOIN pg_am am ON s2.relam = am.oid WHERE am.amname = 'btree' 67 | ) AS sub 68 | -- WHERE NOT is_na 69 | ORDER BY 2,3,4; 70 | -------------------------------------------------------------------------------- /btree/btree_bloat-superuser.sql: -------------------------------------------------------------------------------- 1 | -- This query must be exected by a superuser because it relies on the 2 | -- pg_statistic table. 3 | -- This query run much faster than btree_bloat.sql, about 1000x faster. 4 | -- 5 | -- This query is compatible with PostgreSQL 8.2 and after. 6 | SELECT current_database(), nspname AS schemaname, tblname, idxname, bs*(relpages)::bigint AS real_size, 7 | bs*(relpages-est_pages)::bigint AS extra_size, 8 | 100 * (relpages-est_pages)::float / relpages AS extra_pct, 9 | fillfactor, 10 | CASE WHEN relpages > est_pages_ff 11 | THEN bs*(relpages-est_pages_ff) 12 | ELSE 0 13 | END AS bloat_size, 14 | 100 * (relpages-est_pages_ff)::float / relpages AS bloat_pct, 15 | is_na 16 | -- , 100-(pst).avg_leaf_density AS pst_avg_bloat, est_pages, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples, relpages -- (DEBUG INFO) 17 | FROM ( 18 | SELECT coalesce(1 + 19 | ceil(reltuples/floor((bs-pageopqdata-pagehdr)/(4+nulldatahdrwidth)::float)), 0 -- ItemIdData size + computed avg size of a tuple (nulldatahdrwidth) 20 | ) AS est_pages, 21 | coalesce(1 + 22 | ceil(reltuples/floor((bs-pageopqdata-pagehdr)*fillfactor/(100*(4+nulldatahdrwidth)::float))), 0 23 | ) AS est_pages_ff, 24 | bs, nspname, tblname, idxname, relpages, fillfactor, is_na 25 | -- , pgstatindex(idxoid) AS pst, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples -- (DEBUG INFO) 26 | FROM ( 27 | SELECT maxalign, bs, nspname, tblname, idxname, reltuples, relpages, idxoid, fillfactor, 28 | ( index_tuple_hdr_bm + 29 | maxalign - CASE -- Add padding to the index tuple header to align on MAXALIGN 30 | WHEN index_tuple_hdr_bm%maxalign = 0 THEN maxalign 31 | ELSE index_tuple_hdr_bm%maxalign 32 | END 33 | + nulldatawidth + maxalign - CASE -- Add padding to the data to align on MAXALIGN 34 | WHEN nulldatawidth = 0 THEN 0 35 | WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign 36 | ELSE nulldatawidth::integer%maxalign 37 | END 38 | )::numeric AS nulldatahdrwidth, pagehdr, pageopqdata, is_na 39 | -- , index_tuple_hdr_bm, nulldatawidth -- (DEBUG INFO) 40 | FROM ( 41 | SELECT n.nspname, ct.relname AS tblname, i.idxname, i.reltuples, i.relpages, 42 | i.idxoid, i.fillfactor, current_setting('block_size')::numeric AS bs, 43 | CASE -- MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) 44 | WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 45 | ELSE 4 46 | END AS maxalign, 47 | /* per page header, fixed size: 20 for 7.X, 24 for others */ 48 | 24 AS pagehdr, 49 | /* per page btree opaque data */ 50 | 16 AS pageopqdata, 51 | /* per tuple header: add IndexAttributeBitMapData if some cols are null-able */ 52 | CASE WHEN max(coalesce(s.stanullfrac,0)) = 0 53 | THEN 8 -- IndexTupleData size 54 | ELSE 8 + (( 32 + 8 - 1 ) / 8) -- IndexTupleData size + IndexAttributeBitMapData size ( max num filed per index + 8 - 1 /8) 55 | END AS index_tuple_hdr_bm, 56 | /* data len: we remove null values save space using it fractionnal part from stats */ 57 | sum( (1-coalesce(s.stanullfrac, 0)) * coalesce(s.stawidth, 1024)) AS nulldatawidth, 58 | max( CASE WHEN a.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 AS is_na 59 | FROM ( 60 | SELECT idxname, reltuples, relpages, tbloid, idxoid, fillfactor, 61 | CASE WHEN indkey[i]=0 THEN idxoid ELSE tbloid END AS att_rel, 62 | CASE WHEN indkey[i]=0 THEN i ELSE indkey[i] END AS att_pos 63 | FROM ( 64 | SELECT idxname, reltuples, relpages, tbloid, idxoid, fillfactor, indkey, generate_series(1,indnatts) AS i 65 | FROM ( 66 | SELECT ci.relname AS idxname, ci.reltuples, ci.relpages, i.indrelid AS tbloid, 67 | i.indexrelid AS idxoid, 68 | coalesce(substring( 69 | array_to_string(ci.reloptions, ' ') 70 | from 'fillfactor=([0-9]+)')::smallint, 90) AS fillfactor, 71 | i.indnatts, 72 | string_to_array(textin(int2vectorout(i.indkey)),' ')::int[] AS indkey 73 | FROM pg_index i 74 | JOIN pg_class ci ON ci.oid=i.indexrelid 75 | WHERE ci.relam=(SELECT oid FROM pg_am WHERE amname = 'btree') 76 | AND ci.relpages > 0 77 | ) AS idx_data 78 | ) AS idx_data_cross 79 | ) i 80 | JOIN pg_attribute a ON a.attrelid = i.att_rel 81 | AND a.attnum = i.att_pos 82 | JOIN pg_statistic s ON s.starelid = i.att_rel 83 | AND s.staattnum = i.att_pos 84 | JOIN pg_class ct ON ct.oid = i.tbloid 85 | JOIN pg_namespace n ON ct.relnamespace = n.oid 86 | GROUP BY 1,2,3,4,5,6,7,8,9,10 87 | ) AS rows_data_stats 88 | ) AS rows_hdr_pdg_stats 89 | ) AS relation_stats 90 | ORDER BY nspname, tblname, idxname; 91 | -------------------------------------------------------------------------------- /btree/btree_bloat.sql: -------------------------------------------------------------------------------- 1 | -- WARNING: executed with a non-superuser role, the query inspect only index on tables you are granted to read. 2 | -- WARNING: rows with is_na = 't' are known to have bad statistics ("name" type is not supported). 3 | -- This query is compatible with PostgreSQL 8.2 and after 4 | SELECT current_database(), nspname AS schemaname, tblname, idxname, bs*(relpages)::bigint AS real_size, 5 | bs*(relpages-est_pages)::bigint AS extra_size, 6 | 100 * (relpages-est_pages)::float / relpages AS extra_pct, 7 | fillfactor, 8 | CASE WHEN relpages > est_pages_ff 9 | THEN bs*(relpages-est_pages_ff) 10 | ELSE 0 11 | END AS bloat_size, 12 | 100 * (relpages-est_pages_ff)::float / relpages AS bloat_pct, 13 | is_na 14 | -- , 100-(pst).avg_leaf_density AS pst_avg_bloat, est_pages, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples, relpages -- (DEBUG INFO) 15 | FROM ( 16 | SELECT coalesce(1 + 17 | ceil(reltuples/floor((bs-pageopqdata-pagehdr)/(4+nulldatahdrwidth)::float)), 0 -- ItemIdData size + computed avg size of a tuple (nulldatahdrwidth) 18 | ) AS est_pages, 19 | coalesce(1 + 20 | ceil(reltuples/floor((bs-pageopqdata-pagehdr)*fillfactor/(100*(4+nulldatahdrwidth)::float))), 0 21 | ) AS est_pages_ff, 22 | bs, nspname, tblname, idxname, relpages, fillfactor, is_na 23 | -- , pgstatindex(idxoid) AS pst, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples -- (DEBUG INFO) 24 | FROM ( 25 | SELECT maxalign, bs, nspname, tblname, idxname, reltuples, relpages, idxoid, fillfactor, 26 | ( index_tuple_hdr_bm + 27 | maxalign - CASE -- Add padding to the index tuple header to align on MAXALIGN 28 | WHEN index_tuple_hdr_bm%maxalign = 0 THEN maxalign 29 | ELSE index_tuple_hdr_bm%maxalign 30 | END 31 | + nulldatawidth + maxalign - CASE -- Add padding to the data to align on MAXALIGN 32 | WHEN nulldatawidth = 0 THEN 0 33 | WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign 34 | ELSE nulldatawidth::integer%maxalign 35 | END 36 | )::numeric AS nulldatahdrwidth, pagehdr, pageopqdata, is_na 37 | -- , index_tuple_hdr_bm, nulldatawidth -- (DEBUG INFO) 38 | FROM ( 39 | SELECT n.nspname, i.tblname, i.idxname, i.reltuples, i.relpages, 40 | i.idxoid, i.fillfactor, current_setting('block_size')::numeric AS bs, 41 | CASE -- MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) 42 | WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 43 | ELSE 4 44 | END AS maxalign, 45 | /* per page header, fixed size: 20 for 7.X, 24 for others */ 46 | 24 AS pagehdr, 47 | /* per page btree opaque data */ 48 | 16 AS pageopqdata, 49 | /* per tuple header: add IndexAttributeBitMapData if some cols are null-able */ 50 | CASE WHEN max(coalesce(s.null_frac,0)) = 0 51 | THEN 8 -- IndexTupleData size 52 | ELSE 8 + (( 32 + 8 - 1 ) / 8) -- IndexTupleData size + IndexAttributeBitMapData size ( max num filed per index + 8 - 1 /8) 53 | END AS index_tuple_hdr_bm, 54 | /* data len: we remove null values save space using it fractionnal part from stats */ 55 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024)) AS nulldatawidth, 56 | max( CASE WHEN i.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 AS is_na 57 | FROM ( 58 | SELECT ct.relname AS tblname, ct.relnamespace, ic.idxname, ic.attpos, ic.indkey, ic.indkey[ic.attpos], ic.reltuples, ic.relpages, ic.tbloid, ic.idxoid, ic.fillfactor, 59 | coalesce(a1.attnum, a2.attnum) AS attnum, coalesce(a1.attname, a2.attname) AS attname, coalesce(a1.atttypid, a2.atttypid) AS atttypid, 60 | CASE WHEN a1.attnum IS NULL 61 | THEN ic.idxname 62 | ELSE ct.relname 63 | END AS attrelname 64 | FROM ( 65 | SELECT idxname, reltuples, relpages, tbloid, idxoid, fillfactor, indkey, 66 | pg_catalog.generate_series(1,indnatts) AS attpos 67 | FROM ( 68 | SELECT ci.relname AS idxname, ci.reltuples, ci.relpages, i.indrelid AS tbloid, 69 | i.indexrelid AS idxoid, 70 | coalesce(substring( 71 | array_to_string(ci.reloptions, ' ') 72 | from 'fillfactor=([0-9]+)')::smallint, 90) AS fillfactor, 73 | i.indnatts, 74 | pg_catalog.string_to_array(pg_catalog.textin( 75 | pg_catalog.int2vectorout(i.indkey)),' ')::int[] AS indkey 76 | FROM pg_catalog.pg_index i 77 | JOIN pg_catalog.pg_class ci ON ci.oid = i.indexrelid 78 | WHERE ci.relam=(SELECT oid FROM pg_am WHERE amname = 'btree') 79 | AND ci.relpages > 0 80 | ) AS idx_data 81 | ) AS ic 82 | JOIN pg_catalog.pg_class ct ON ct.oid = ic.tbloid 83 | LEFT JOIN pg_catalog.pg_attribute a1 ON 84 | ic.indkey[ic.attpos] <> 0 85 | AND a1.attrelid = ic.tbloid 86 | AND a1.attnum = ic.indkey[ic.attpos] 87 | LEFT JOIN pg_catalog.pg_attribute a2 ON 88 | ic.indkey[ic.attpos] = 0 89 | AND a2.attrelid = ic.idxoid 90 | AND a2.attnum = ic.attpos 91 | ) i 92 | JOIN pg_catalog.pg_namespace n ON n.oid = i.relnamespace 93 | JOIN pg_catalog.pg_stats s ON s.schemaname = n.nspname 94 | AND s.tablename = i.attrelname 95 | AND s.attname = i.attname 96 | GROUP BY 1,2,3,4,5,6,7,8,9,10,11 97 | ) AS rows_data_stats 98 | ) AS rows_hdr_pdg_stats 99 | ) AS relation_stats 100 | ORDER BY nspname, tblname, idxname; 101 | -------------------------------------------------------------------------------- /table/table_bloat-74-81.sql: -------------------------------------------------------------------------------- 1 | /* WARNING: executed with a non-superuser role, the query inspect only tables you are granted to read. 2 | * This query is compatible with PostgreSQL 7.4 to 8.1 3 | */ 4 | SELECT current_database(), schemaname, tblname, bs*tblpages AS real_size, 5 | (tblpages-est_num_pages)*bs AS bloat_size, tblpages, is_na, 6 | CASE WHEN tblpages - est_num_pages > 0 7 | THEN 100 * (tblpages - est_num_pages)/tblpages::float 8 | ELSE 0 9 | END AS bloat_pct 10 | FROM ( 11 | SELECT 12 | ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_num_pages, tblpages, 13 | bs, tblid, schemaname, tblname, heappages, toastpages, is_na 14 | FROM ( 15 | SELECT 16 | ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) 17 | - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END 18 | - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END 19 | ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, 20 | toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, is_na 21 | FROM ( 22 | SELECT 23 | tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, 24 | tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, 25 | coalesce(toast.reltuples, 0) AS toasttuples, 26 | CASE WHEN cluster_version.v > 7 27 | THEN current_setting('block_size')::numeric 28 | ELSE 8192::numeric 29 | END AS bs, 30 | CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, 31 | CASE WHEN cluster_version.v > 7 32 | THEN 24 33 | ELSE 20 34 | END AS page_hdr, 35 | CASE WHEN cluster_version.v > 7 THEN 27 ELSE 23 END 36 | + CASE WHEN MAX(coalesce(null_frac,0)) > 0 THEN ( 7 + count(*) ) / 8 ELSE 0::int END 37 | + CASE WHEN tbl.relhasoids THEN 4 ELSE 0 END AS tpl_hdr_size, 38 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024) ) AS tpl_data_size, 39 | max( CASE WHEN att.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 40 | OR count(att.attname) <> count(s.attname) AS is_na 41 | FROM pg_attribute att 42 | JOIN pg_class tbl ON att.attrelid = tbl.oid 43 | JOIN pg_namespace ns ON ns.oid = tbl.relnamespace 44 | LEFT JOIN pg_stats s ON s.schemaname=ns.nspname 45 | AND s.tablename = tbl.relname 46 | AND s.attname=att.attname 47 | LEFT JOIN pg_class toast ON tbl.reltoastrelid = toast.oid, 48 | ( SELECT substring(current_setting('server_version') FROM '#"[0-9]+#"%' FOR '#')::integer ) AS cluster_version(v) 49 | WHERE att.attnum > 0 AND NOT att.attisdropped 50 | AND tbl.relkind = 'r' 51 | GROUP BY 1,2,3,4,5,6,7,8,9,10, cluster_version.v, tbl.relhasoids 52 | ORDER BY 2,3 53 | ) as s 54 | ) as s2 55 | ) AS s3 56 | -- WHERE NOT is_na; 57 | -------------------------------------------------------------------------------- /table/table_bloat-82-84.sql: -------------------------------------------------------------------------------- 1 | /* WARNING: executed with a non-superuser role, the query inspect only tables you are granted to read. 2 | * This query is compatible with PostgreSQL 8.2 to 8.4 3 | */ 4 | SELECT current_database(), schemaname, tblname, bs*tblpages AS real_size, 5 | (tblpages-est_tblpages)*bs AS extra_size, 6 | CASE WHEN tblpages - est_tblpages > 0 7 | THEN 100 * (tblpages - est_tblpages)/tblpages::float 8 | ELSE 0 9 | END AS extra_pct, fillfactor, (tblpages-est_tblpages_ff)*bs AS bloat_size, 10 | CASE WHEN tblpages - est_tblpages_ff > 0 11 | THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float 12 | ELSE 0 13 | END AS bloat_pct, is_na 14 | -- , (pst).free_percent + (pst).dead_tuple_percent AS real_frag 15 | FROM ( 16 | SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages, 17 | ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, 18 | tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na 19 | -- , stattuple.pgstattuple(tblid) AS pst 20 | FROM ( 21 | SELECT 22 | ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) 23 | - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END 24 | - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END 25 | ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, 26 | toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na 27 | FROM ( 28 | SELECT 29 | tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, 30 | tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, 31 | coalesce(toast.reltuples, 0) AS toasttuples, 32 | coalesce(substring( 33 | array_to_string(tbl.reloptions, ' ') 34 | FROM 'fillfactor=([0-9]+)')::smallint, 100) AS fillfactor, 35 | current_setting('block_size')::numeric AS bs, 36 | CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, 37 | 24 AS page_hdr, 38 | CASE WHEN current_setting('server_version_num')::integer < 80300 THEN 27 ELSE 23 END 39 | + CASE WHEN MAX(coalesce(null_frac,0)) > 0 THEN ( 7 + count(*) ) / 8 ELSE 0::int END 40 | + CASE WHEN tbl.relhasoids THEN 4 ELSE 0 END AS tpl_hdr_size, 41 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024) ) AS tpl_data_size, 42 | bool_or(att.atttypid = 'pg_catalog.name'::regtype) 43 | OR count(att.attname) <> count(s.attname) AS is_na 44 | FROM pg_attribute AS att 45 | JOIN pg_class AS tbl ON att.attrelid = tbl.oid 46 | JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace 47 | LEFT JOIN pg_stats AS s ON s.schemaname=ns.nspname 48 | AND s.tablename = tbl.relname AND s.attname=att.attname 49 | LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid 50 | WHERE att.attnum > 0 AND NOT att.attisdropped 51 | AND tbl.relkind = 'r' 52 | GROUP BY 1,2,3,4,5,6,7,8,9,10, tbl.relhasoids 53 | ORDER BY 2,3 54 | ) AS s 55 | ) AS s2 56 | ) AS s3 57 | -- WHERE NOT is_na 58 | -- AND tblpages*((pst).free_percent + (pst).dead_tuple_percent)::float4/100 >= 1 59 | -------------------------------------------------------------------------------- /table/table_bloat.sql: -------------------------------------------------------------------------------- 1 | /* WARNING: executed with a non-superuser role, the query inspect only tables and materialized view (9.3+) you are granted to read. 2 | * This query is compatible with PostgreSQL 9.0 and more 3 | */ 4 | SELECT current_database(), schemaname, tblname, bs*tblpages AS real_size, 5 | (tblpages-est_tblpages)*bs AS extra_size, 6 | CASE WHEN tblpages > 0 AND tblpages - est_tblpages > 0 7 | THEN 100 * (tblpages - est_tblpages)/tblpages::float 8 | ELSE 0 9 | END AS extra_pct, fillfactor, 10 | CASE WHEN tblpages - est_tblpages_ff > 0 11 | THEN (tblpages-est_tblpages_ff)*bs 12 | ELSE 0 13 | END AS bloat_size, 14 | CASE WHEN tblpages > 0 AND tblpages - est_tblpages_ff > 0 15 | THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float 16 | ELSE 0 17 | END AS bloat_pct, is_na 18 | -- , tpl_hdr_size, tpl_data_size, (pst).free_percent + (pst).dead_tuple_percent AS real_frag -- (DEBUG INFO) 19 | FROM ( 20 | SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages, 21 | ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, 22 | tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na 23 | -- , tpl_hdr_size, tpl_data_size, pgstattuple(tblid) AS pst -- (DEBUG INFO) 24 | FROM ( 25 | SELECT 26 | ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) 27 | - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END 28 | - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END 29 | ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, 30 | toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na 31 | -- , tpl_hdr_size, tpl_data_size 32 | FROM ( 33 | SELECT 34 | tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, 35 | tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, 36 | coalesce(toast.reltuples, 0) AS toasttuples, 37 | coalesce(substring( 38 | array_to_string(tbl.reloptions, ' ') 39 | FROM 'fillfactor=([0-9]+)')::smallint, 100) AS fillfactor, 40 | current_setting('block_size')::numeric AS bs, 41 | CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, 42 | 24 AS page_hdr, 43 | 23 + CASE WHEN MAX(coalesce(s.null_frac,0)) > 0 THEN ( 7 + count(s.attname) ) / 8 ELSE 0::int END 44 | + CASE WHEN bool_or(att.attname = 'oid' and att.attnum < 0) THEN 4 ELSE 0 END AS tpl_hdr_size, 45 | sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0) ) AS tpl_data_size, 46 | bool_or(att.atttypid = 'pg_catalog.name'::regtype) 47 | OR sum(CASE WHEN att.attnum > 0 THEN 1 ELSE 0 END) <> count(s.attname) AS is_na 48 | FROM pg_attribute AS att 49 | JOIN pg_class AS tbl ON att.attrelid = tbl.oid 50 | JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace 51 | LEFT JOIN pg_stats AS s ON s.schemaname=ns.nspname 52 | AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname 53 | LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid 54 | WHERE NOT att.attisdropped 55 | AND tbl.relkind in ('r','m') 56 | GROUP BY 1,2,3,4,5,6,7,8,9,10 57 | ORDER BY 2,3 58 | ) AS s 59 | ) AS s2 60 | ) AS s3 61 | -- WHERE NOT is_na 62 | -- AND tblpages*((pst).free_percent + (pst).dead_tuple_percent)::float4/100 >= 1 63 | ORDER BY schemaname, tblname; 64 | --------------------------------------------------------------------------------