diff --git a/app/controllers/pg_hero/home_controller.rb b/app/controllers/pg_hero/home_controller.rb
index 42a6b52b8..a29d8ab1a 100644
--- a/app/controllers/pg_hero/home_controller.rb
+++ b/app/controllers/pg_hero/home_controller.rb
@@ -387,6 +387,7 @@ def maintenance
@maintenance_info = @database.maintenance_info
@time_zone = PgHero.time_zone
@show_dead_rows = params[:dead_rows]
+ @max_dead_tuples = @database.autovacuum_max_dead_tuples
end
def kill
diff --git a/app/views/pg_hero/home/maintenance.html.erb b/app/views/pg_hero/home/maintenance.html.erb
index dc7c8a714..ea87be465 100644
--- a/app/views/pg_hero/home/maintenance.html.erb
+++ b/app/views/pg_hero/home/maintenance.html.erb
@@ -7,6 +7,7 @@
Table |
Live Tuples |
Dead Tuples |
+ Vacuum Threshold |
Last Vacuum |
Last Analyze |
<% if @show_dead_rows %>
@@ -24,7 +25,7 @@
<% end %>
<% if table[:options] %>
- <% table[:options].gsub(/\A\{|\}\z/, "").split(",").each do |option| %>
+ <% table[:options].each do |option| %>
<%= option %>
<% end %>
@@ -44,6 +45,21 @@
0
<% end %>
+
+ <% if table[:vacuum_threshold] > @max_dead_tuples %>
+
+ <%= number_with_delimiter(table[:vacuum_threshold]) %>
+
+
+ > max_dead_tuples=<%= number_with_delimiter(@max_dead_tuples) %>
+
+
+ <% else %>
+
+ <%= number_with_delimiter(table[:vacuum_threshold]) %>
+
+ <% end %>
+ |
<% time = [table[:last_autovacuum], table[:last_vacuum]].compact.max %>
<% if time %>
diff --git a/lib/pghero/methods/basic.rb b/lib/pghero/methods/basic.rb
index a17bca635..1d83aaad5 100644
--- a/lib/pghero/methods/basic.rb
+++ b/lib/pghero/methods/basic.rb
@@ -36,16 +36,22 @@ def quote_ident(value)
private
- def select_all(sql, conn: nil, query_columns: [])
+ def select_all(sql, conn: nil, query_columns: [], cast_values: false)
conn ||= connection
# squish for logs
retries = 0
begin
- result = conn.select_all(add_source(squish(sql)))
+ result = uncast_result = conn.select_all(add_source(squish(sql)))
+ if cast_values
+ # ActiveRecord::Result#cast_values turns PostgreSQL arrays into Ruby arrays, etc.
+ # But it turns ActiveRecord::Result into Array of results, which is why we keep
+ # an `uncast_result` copy of `result`.
+ result = result.cast_values.map { |row| result.columns.zip(row).to_h }
+ end
if ActiveRecord::VERSION::STRING.to_f >= 6.1
result = result.map(&:symbolize_keys)
else
- result = result.map { |row| row.to_h { |col, val| [col.to_sym, result.column_types[col].send(:cast_value, val)] } }
+ result = result.map { |row| row.to_h { |col, val| [col.to_sym, uncast_result.column_types[col].send(:cast_value, val)] } }
end
if filter_data
query_columns.each do |column|
diff --git a/lib/pghero/methods/maintenance.rb b/lib/pghero/methods/maintenance.rb
index 7f5bf22e8..3b0d58e50 100644
--- a/lib/pghero/methods/maintenance.rb
+++ b/lib/pghero/methods/maintenance.rb
@@ -88,7 +88,7 @@ def create_index_progress
end
def maintenance_info
- select_all <<~SQL
+ info = select_all(<<~SQL, cast_values: true)
SELECT
schemaname AS schema,
pg_stat_user_tables.relname AS table,
@@ -106,6 +106,26 @@ def maintenance_info
ORDER BY
1, 2
SQL
+
+ runtime_parameters = autovacuum_settings
+
+ info.each do |row|
+ table_options = row[:options]&.map { |opt| opt.split("=", 2) }.to_h || {}
+
+ # look up a table storage parameter, defaulting to the globally set value
+ find_param = ->(key) { table_options[key.to_s] || runtime_parameters[key] }
+
+ # vacuum_threshold = autovacuum_vacuum_threshold + autovacuum_vacuum_scale_factor * pg_class.reltuples
+ # — https://www.postgresql.org/docs/13/routine-vacuuming.html#AUTOVACUUM
+ threshold = find_param.(:autovacuum_vacuum_threshold).to_i
+ scale_factor = find_param.(:autovacuum_vacuum_scale_factor).to_f
+ reltuples = row[:live_rows].to_i
+
+ row[:vacuum_threshold] = (threshold + scale_factor * reltuples).to_i
+ row[:vacuum_threshold_calc] = "#{threshold} + #{scale_factor} * #{reltuples}"
+ end
+
+ info
end
def analyze(table, verbose: false)
diff --git a/lib/pghero/methods/settings.rb b/lib/pghero/methods/settings.rb
index 1b8982a0d..e0978cc98 100644
--- a/lib/pghero/methods/settings.rb
+++ b/lib/pghero/methods/settings.rb
@@ -20,13 +20,42 @@ def settings
end
def autovacuum_settings
- fetch_settings %i(autovacuum autovacuum_max_workers autovacuum_vacuum_cost_limit autovacuum_vacuum_scale_factor autovacuum_analyze_scale_factor)
+ fetch_settings %i(autovacuum autovacuum_max_workers autovacuum_vacuum_cost_limit autovacuum_vacuum_scale_factor autovacuum_vacuum_threshold autovacuum_analyze_scale_factor)
end
def vacuum_settings
fetch_settings %i(vacuum_cost_limit)
end
+ # The number of dead tuples that an autovacuum phase can track.
+ # https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAINTENANCE-WORK-MEM
+ def autovacuum_max_dead_tuples
+ # SHOW … returns the value as a string like "64MB" which would require parsing the units.
+ # PostgreSQL stores this as kB (KiB) internally, which is simpler / less ambiguous.
+ show_setting_kb = ->(key) {
+ select_one("SELECT setting FROM pg_settings WHERE name = '#{key}' AND unit = 'kB'")
+ }
+
+ # autovacuum_work_mem (integer):
+ # Specifies the maximum amount of memory to be used by each autovacuum worker process.
+ work_mem_kib = show_setting_kb.(:autovacuum_work_mem).to_i
+
+ # It defaults to -1, indicating that maintenance_work_mem should be used instead.
+ if work_mem_kib == -1
+ work_mem_kib = show_setting_kb.(:maintenance_work_mem).to_i
+ end
+
+ # For the collection of dead tuple identifiers, VACUUM is only able to utilize up to a
+ # maximum of 1GB of memory.
+ work_mem = [work_mem_kib * 1024, 1024*1024*1024].min
+
+ # I can't remember why this is 6 bytes, but it is.
+ bytes_per_tuple_ref = 6
+
+ # This maxes out at 178,956,969 for work_mem >= 1 GiB
+ (work_mem / bytes_per_tuple_ref) - 1
+ end
+
private
def fetch_settings(names)
|