Skip to content

Commit

Permalink
Added index bloat
Browse files Browse the repository at this point in the history
  • Loading branch information
ankane committed Aug 6, 2017
1 parent 94b785d commit 8925557
Show file tree
Hide file tree
Showing 5 changed files with 174 additions and 0 deletions.
5 changes: 5 additions & 0 deletions app/controllers/pg_hero/home_controller.rb
Original file line number Diff line number Diff line change
Expand Up @@ -89,6 +89,11 @@ def relation_space
@chart_data = [{name: "Value", data: relation_space_stats.map { |r| [r[:captured_at], (r[:size_bytes].to_f / 1.megabyte).round(1)] }, library: chart_library_options}]
end

def index_bloat
@title = "Index Bloat"
@index_bloat = @database.index_bloat.select { |i| i[:bloat_bytes] > 0 }
end

def live_queries
@title = "Live Queries"
@running_queries = @database.running_queries
Expand Down
34 changes: 34 additions & 0 deletions app/views/pg_hero/home/index_bloat.html.erb
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
<div class="content">
<h1>Index Bloat</h1>

<p>Indexes can become bloated over time. Recreate them to remove bloat.</p>

<p>For each index, run:</p>
<code><pre>CREATE INDEX CONCURRENTLY new_index ...;
ANALYZE table;
DROP INDEX CONCURRENTLY index;
ANALYZE table;
ALTER INDEX new_index RENAME TO index;
</pre></code>

<table class="table">
<thead>
<tr>
<th>Index</th>
<th style="width: 15%;">Bloat</th>
<th style="width: 15%;">Size</th>
</tr>
</thead>
<tbody>
<% @index_bloat.each do |index| %>
<tr>
<td>
<span style="word-break: break-all;"><%= index[:index] %></span>
</td>
<td><%= PgHero.pretty_size(index[:bloat_bytes]) %></td>
<td><%= PgHero.pretty_size(index[:index_bytes]) %></td>
</tr>
<% end %>
</tbody>
</table>
</div>
2 changes: 2 additions & 0 deletions app/views/pg_hero/home/space.html.erb
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,8 @@
</script>
<% end %>

<p>Check out <%= link_to "index bloat", index_bloat_path %> for an easy way to reclaim space.</p>

<% if @unused_indexes.any? %>
<p>
<%= pluralize(@unused_indexes.size, "unused index") %>. Remove them
Expand Down
1 change: 1 addition & 0 deletions config/routes.rb
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@
scope "(:database)", constraints: proc { |req| (PgHero.config["databases"].keys + [nil]).include?(req.params[:database]) } do
get "space", to: "home#space"
get "space/:relation", to: "home#relation_space", as: :relation_space
get "index_bloat", to: "home#index_bloat"
get "live_queries", to: "home#live_queries"
get "queries", to: "home#queries"
get "queries/:query_hash", to: "home#show_query", as: :show_query
Expand Down
132 changes: 132 additions & 0 deletions lib/pghero/methods/indexes.rb
Original file line number Diff line number Diff line change
Expand Up @@ -170,6 +170,138 @@ def duplicate_indexes(indexes: nil)

dup_indexes.sort_by { |i| ui = i[:unneeded_index]; [ui[:table], ui[:columns]] }
end

# https://gist.github.com/mbanck/9976015/71888a24e464e2f772182a7eb54f15a125edf398
# thanks @jberkus and @mbanck
def index_bloat
select_all <<-SQL
WITH btree_index_atts AS (
SELECT
nspname, relname, reltuples, relpages, indrelid, relam,
regexp_split_to_table(indkey::text, ' ')::smallint AS attnum,
indexrelid as index_oid
FROM
pg_index
JOIN
pg_class ON pg_class.oid=pg_index.indexrelid
JOIN
pg_namespace ON pg_namespace.oid = pg_class.relnamespace
JOIN
pg_am ON pg_class.relam = pg_am.oid
WHERE
pg_am.amname = 'btree'
),
index_item_sizes AS (
SELECT
i.nspname,
i.relname,
i.reltuples,
i.relpages,
i.relam,
(quote_ident(s.schemaname) || '.' || quote_ident(s.tablename))::regclass AS starelid,
a.attrelid AS table_oid, index_oid,
current_setting('block_size')::numeric AS bs,
/* MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) */
CASE
WHEN version() ~ 'mingw32' OR version() ~ '64-bit' THEN 8
ELSE 4
END AS maxalign,
24 AS pagehdr,
/* per tuple header: add index_attribute_bm if some cols are null-able */
CASE WHEN max(coalesce(s.null_frac,0)) = 0
THEN 2
ELSE 6
END AS index_tuple_hdr,
/* data len: we remove null values save space using it fractionnal part from stats */
sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 2048) ) AS nulldatawidth
FROM
pg_attribute AS a
JOIN
pg_stats AS s ON (quote_ident(s.schemaname) || '.' || quote_ident(s.tablename))::regclass=a.attrelid AND s.attname = a.attname
JOIN
btree_index_atts AS i ON i.indrelid = a.attrelid AND a.attnum = i.attnum
WHERE
a.attnum > 0
GROUP BY
1, 2, 3, 4, 5, 6, 7, 8, 9
),
index_aligned AS (
SELECT
maxalign,
bs,
nspname,
relname AS index_name,
reltuples,
relpages,
relam,
table_oid,
index_oid,
( 2 +
maxalign - CASE /* Add padding to the index tuple header to align on MAXALIGN */
WHEN index_tuple_hdr%maxalign = 0 THEN maxalign
ELSE index_tuple_hdr%maxalign
END
+ nulldatawidth + maxalign - CASE /* Add padding to the data to align on MAXALIGN */
WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign
ELSE nulldatawidth::integer%maxalign
END
)::numeric AS nulldatahdrwidth, pagehdr
FROM
index_item_sizes AS s1
),
otta_calc AS (
SELECT
bs,
nspname,
table_oid,
index_oid,
index_name,
relpages,
coalesce(
ceil((reltuples*(4+nulldatahdrwidth))/(bs-pagehdr::float)) +
CASE WHEN am.amname IN ('hash','btree') THEN 1 ELSE 0 END , 0 /* btree and hash have a metadata reserved block */
) AS otta
FROM
index_aligned AS s2
LEFT JOIN
pg_am am ON s2.relam = am.oid
),
raw_bloat AS (
SELECT
nspname,
c.relname AS table_name,
index_name,
bs*(sub.relpages)::bigint AS totalbytes,
CASE
WHEN sub.relpages <= otta THEN 0
ELSE bs*(sub.relpages-otta)::bigint END
AS wastedbytes,
CASE
WHEN sub.relpages <= otta
THEN 0 ELSE bs*(sub.relpages-otta)::bigint * 100 / (bs*(sub.relpages)::bigint) END
AS realbloat,
pg_relation_size(sub.table_oid) as table_bytes,
stat.idx_scan as index_scans
FROM
otta_calc AS sub
JOIN
pg_class AS c ON c.oid=sub.table_oid
JOIN
pg_stat_user_indexes AS stat ON sub.index_oid = stat.indexrelid
)
SELECT
nspname AS schema,
table_name AS table,
index_name AS index,
wastedbytes AS bloat_bytes,
totalbytes AS index_bytes
FROM
raw_bloat
ORDER BY
wastedbytes DESC,
index_name
SQL
end
end
end
end

0 comments on commit 8925557

Please sign in to comment.