Skip to content

Commit

Permalink
implements automatic EXPLAIN logging for slow queries
Browse files Browse the repository at this point in the history
  • Loading branch information
fxn committed Dec 2, 2011
1 parent 4d20de8 commit 0306f82
Show file tree
Hide file tree
Showing 18 changed files with 354 additions and 96 deletions.
11 changes: 11 additions & 0 deletions activerecord/CHANGELOG.md
@@ -1,5 +1,16 @@
## Rails 3.2.0 (unreleased) ##

* Implements automatic EXPLAIN logging for slow queries.

A new configuration parameter `config.active_record.auto_explain_threshold_in_seconds`
determines what's to be considered a slow query. Setting that to `nil` disables
this feature. Defaults are 0.5 in development mode, and `nil` in test and production
modes.

As of this writing there's support for SQLite, MySQL (mysql2 adapter), and
PostgreSQL.

*fxn*

* Implemented ActiveRecord::Relation#pluck method

Expand Down
2 changes: 2 additions & 0 deletions activerecord/lib/active_record.rb
Expand Up @@ -50,6 +50,7 @@ module ActiveRecord
autoload :PredicateBuilder
autoload :SpawnMethods
autoload :Batches
autoload :Explain
end

autoload :Base
Expand All @@ -75,6 +76,7 @@ module ActiveRecord
autoload :Transactions
autoload :Validations
autoload :IdentityMap
autoload :Explain
end

module Coders
Expand Down
10 changes: 9 additions & 1 deletion activerecord/lib/active_record/base.rb
Expand Up @@ -433,6 +433,11 @@ class Base
class_attribute :default_scopes, :instance_writer => false
self.default_scopes = []

# If a query takes longer than these many seconds we log its query plan
# automatically. nil disables this feature.
class_attribute :auto_explain_threshold_in_seconds, :instance_writer => false
self.auto_explain_threshold_in_seconds = nil

class_attribute :_attr_readonly, :instance_writer => false
self._attr_readonly = []

Expand Down Expand Up @@ -484,7 +489,9 @@ def generated_feature_methods
# Post.find_by_sql ["SELECT title FROM posts WHERE author = ? AND created > ?", author_id, start_date]
# > [#<Post:0x36bff9c @attributes={"title"=>"The Cheap Man Buys Twice"}>, ...]
def find_by_sql(sql, binds = [])
connection.select_all(sanitize_sql(sql), "#{name} Load", binds).collect! { |record| instantiate(record) }
logging_query_plan do
connection.select_all(sanitize_sql(sql), "#{name} Load", binds).collect! { |record| instantiate(record) }
end
end

# Creates an object (or multiple objects) and saves it to the database, if validations pass.
Expand Down Expand Up @@ -2206,6 +2213,7 @@ def populate_with_current_scope_attributes
include Associations, NamedScope
include IdentityMap
include ActiveModel::SecurePassword
extend Explain

# AutosaveAssociation needs to be included before Transactions, because we want
# #save_with_autosave_associations to be wrapped inside a transaction.
Expand Down
Expand Up @@ -142,6 +142,12 @@ def supports_index_sort_order?
false
end

# Does this adapter support explain? As of this writing sqlite3,
# mysql2, and postgresql are the only ones that do.
def supports_explain?
false
end

# QUOTING ==================================================

# Override to return the quoted table name. Defaults to column quoting.
Expand Down
Expand Up @@ -225,80 +225,6 @@ def disable_referential_integrity(&block) #:nodoc:

# DATABASE STATEMENTS ======================================

def explain(arel)
sql = "EXPLAIN #{to_sql(arel)}"
start = Time.now
result = exec_query(sql, 'EXPLAIN')
elapsed = Time.now - start

ExplainPrettyPrinter.new.pp(result, elapsed)
end

class ExplainPrettyPrinter # :nodoc:
# Pretty prints the result of a EXPLAIN in a way that resembles the output of the
# MySQL shell:
#
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# | 1 | SIMPLE | users | const | PRIMARY | PRIMARY | 4 | const | 1 | |
# | 1 | SIMPLE | posts | ALL | NULL | NULL | NULL | NULL | 1 | Using where |
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# 2 rows in set (0.00 sec)
#
# This is an exercise in Ruby hyperrealism :).
def pp(result, elapsed)
widths = compute_column_widths(result)
separator = build_separator(widths)

pp = []

pp << separator
pp << build_cells(result.columns, widths)
pp << separator

result.rows.each do |row|
pp << build_cells(row, widths)
end

pp << separator
pp << build_footer(result.rows.length, elapsed)

pp.join("\n") + "\n"
end

private

def compute_column_widths(result)
[].tap do |widths|
result.columns.each_with_index do |column, i|
cells_in_column = [column] + result.rows.map {|r| r[i].nil? ? 'NULL' : r[i].to_s}
widths << cells_in_column.map(&:length).max
end
end
end

def build_separator(widths)
padding = 1
'+' + widths.map {|w| '-' * (w + (padding*2))}.join('+') + '+'
end

def build_cells(items, widths)
cells = []
items.each_with_index do |item, i|
item = 'NULL' if item.nil?
justifier = item.is_a?(Numeric) ? 'rjust' : 'ljust'
cells << item.to_s.send(justifier, widths[i])
end
'| ' + cells.join(' | ') + ' |'
end

def build_footer(nrows, elapsed)
rows_label = nrows == 1 ? 'row' : 'rows'
"#{nrows} #{rows_label} in set (%.2f sec)" % elapsed
end
end

# Executes the SQL statement in the context of this connection.
def execute(sql, name = nil)
if name == :skip_logging
Expand Down
Expand Up @@ -35,6 +35,10 @@ def initialize(connection, logger, connection_options, config)
configure_connection
end

def supports_explain?
true
end

# HELPER METHODS ===========================================

def each_hash(result) # :nodoc:
Expand Down Expand Up @@ -93,6 +97,80 @@ def reset!

# DATABASE STATEMENTS ======================================

def explain(arel, binds = [])
sql = "EXPLAIN #{to_sql(arel)}"
start = Time.now
result = exec_query(sql, 'EXPLAIN', binds)
elapsed = Time.now - start

ExplainPrettyPrinter.new.pp(result, elapsed)
end

class ExplainPrettyPrinter # :nodoc:
# Pretty prints the result of a EXPLAIN in a way that resembles the output of the
# MySQL shell:
#
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# | 1 | SIMPLE | users | const | PRIMARY | PRIMARY | 4 | const | 1 | |
# | 1 | SIMPLE | posts | ALL | NULL | NULL | NULL | NULL | 1 | Using where |
# +----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
# 2 rows in set (0.00 sec)
#
# This is an exercise in Ruby hyperrealism :).
def pp(result, elapsed)
widths = compute_column_widths(result)
separator = build_separator(widths)

pp = []

pp << separator
pp << build_cells(result.columns, widths)
pp << separator

result.rows.each do |row|
pp << build_cells(row, widths)
end

pp << separator
pp << build_footer(result.rows.length, elapsed)

pp.join("\n") + "\n"
end

private

def compute_column_widths(result)
[].tap do |widths|
result.columns.each_with_index do |column, i|
cells_in_column = [column] + result.rows.map {|r| r[i].nil? ? 'NULL' : r[i].to_s}
widths << cells_in_column.map(&:length).max
end
end
end

def build_separator(widths)
padding = 1
'+' + widths.map {|w| '-' * (w + (padding*2))}.join('+') + '+'
end

def build_cells(items, widths)
cells = []
items.each_with_index do |item, i|
item = 'NULL' if item.nil?
justifier = item.is_a?(Numeric) ? 'rjust' : 'ljust'
cells << item.to_s.send(justifier, widths[i])
end
'| ' + cells.join(' | ') + ' |'
end

def build_footer(nrows, elapsed)
rows_label = nrows == 1 ? 'row' : 'rows'
"#{nrows} #{rows_label} in set (%.2f sec)" % elapsed
end
end

# FIXME: re-enable the following once a "better" query_cache solution is in core
#
# The overrides below perform much better than the originals in AbstractAdapter
Expand Down
Expand Up @@ -390,6 +390,11 @@ def supports_savepoints?
true
end

# Returns true.
def supports_explain?
true
end

# Returns the configured supported identifier length supported by PostgreSQL
def table_alias_length
@table_alias_length ||= query('SHOW max_identifier_length')[0][0].to_i
Expand Down Expand Up @@ -514,9 +519,9 @@ def disable_referential_integrity #:nodoc:

# DATABASE STATEMENTS ======================================

def explain(arel)
def explain(arel, binds = [])
sql = "EXPLAIN #{to_sql(arel)}"
ExplainPrettyPrinter.new.pp(exec_query(sql))
ExplainPrettyPrinter.new.pp(exec_query(sql, 'EXPLAIN', binds))
end

class ExplainPrettyPrinter # :nodoc:
Expand Down
Expand Up @@ -122,6 +122,11 @@ def supports_primary_key? #:nodoc:
true
end

# Returns true.
def supports_explain?
true
end

def requires_reloading?
true
end
Expand Down Expand Up @@ -219,9 +224,9 @@ def type_cast(value, column) # :nodoc:

# DATABASE STATEMENTS ======================================

def explain(arel)
def explain(arel, binds = [])
sql = "EXPLAIN QUERY PLAN #{to_sql(arel)}"
ExplainPrettyPrinter.new.pp(exec_query(sql, 'EXPLAIN'))
ExplainPrettyPrinter.new.pp(exec_query(sql, 'EXPLAIN', binds))
end

class ExplainPrettyPrinter
Expand Down
76 changes: 76 additions & 0 deletions activerecord/lib/active_record/explain.rb
@@ -0,0 +1,76 @@
module ActiveRecord
module Explain # :nodoc
# logging_query_plan calls could appear nested in the call stack. In
# particular this happens when a relation fetches its records, since
# that results in find_by_sql calls downwards.
#
# This flag allows nested calls to detect this situation and bypass
# it, thus preventing repeated EXPLAINs.
LOGGING_QUERY_PLAN = :logging_query_plan

# If auto explain is enabled, this method triggers EXPLAIN logging for the
# queries triggered by the block if it takes more than the threshold as a
# whole. That is, the threshold is not checked against each individual
# query, but against the duration of the entire block. This approach is
# convenient for relations.
def logging_query_plan(&block)
if (t = auto_explain_threshold_in_seconds) && !Thread.current[LOGGING_QUERY_PLAN]
begin
Thread.current[LOGGING_QUERY_PLAN] = true
start = Time.now
result, sqls, binds = collecting_sqls_for_explain(&block)
logger.warn(exec_explain(sqls, binds)) if Time.now - start > t
result
ensure
Thread.current[LOGGING_QUERY_PLAN] = false
end
else
block.call

This comment has been minimized.

Copy link
@mikekelly

mikekelly Jan 1, 2012

out of interest - is there a specific reason you prefer block.call over yield here?

This comment has been minimized.

Copy link
@fxn

fxn Jan 1, 2012

Author Member

Hi Mike. The code suffered some changes while it took shape and that block.call was an overlook in the last refactors (it made sense in earlier implementations). I updated it later: 3a96780.

If you are interested in the implementation, please have a look also at cfeac38 and 7f3ce35.

end
end

# SCHEMA queries cannot be EXPLAINed, also we do not want to run EXPLAIN on
# our own EXPLAINs now matter how loopingly beautiful that would be.
SKIP_EXPLAIN_FOR = %(SCHEMA EXPLAIN)
def ignore_explain_notification?(payload)
payload[:exception] || SKIP_EXPLAIN_FOR.include?(payload[:name])
end

# Collects all queries executed while the passed block runs. Returns an
# array with three elements, the result of the block, the strings with the
# queries, and their respective bindings.
def collecting_sqls_for_explain(&block)
sqls = []
binds = []
callback = lambda do |*args|
payload = args.last
unless ignore_explain_notification?(payload)
sqls << payload[:sql]
binds << payload[:binds]
end
end

result = nil
ActiveSupport::Notifications.subscribed(callback, "sql.active_record") do
result = block.call
end

[result, sqls, binds]
end

# Makes the adapter execute EXPLAIN for the given queries and bindings.
# Returns a formatted string ready to be logged.
def exec_explain(sqls, binds)
sqls.zip(binds).map do |sql, bind|
[].tap do |msg|
msg << "EXPLAIN for: #{sql}"
unless bind.empty?
bind_msg = bind.map {|col, val| [col.name, val]}.inspect
msg.last << " #{bind_msg}"
end
msg << connection.explain(sql, bind)
end.join("\n")
end.join("\n")
end
end
end

37 comments on commit 0306f82

@josevalim
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

AWESOME! I have been recommending tools to achieve the same result to almost every single team I coach.

@sardaukar
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Kudos! Awesome++

@dipth
Copy link

@dipth dipth commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Most awesome! 👍

@erithmetic
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Feature bloat alert! Why not put this in a gem?

@nicolasblanco
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

🍺 !

@Locke23rus
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

👍

@zolzaya
Copy link
Contributor

@zolzaya zolzaya commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+++++++++++++++++++++++++++++1. Awesome commit.

@jonpaul
Copy link

@jonpaul jonpaul commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

While I tend to agree this is pretty badass, I also tend to agree with @dkastner that this feature smells like bloat. Interested to see what Core team decides is good for everyone, +1.

@dhh
Copy link
Member

@dhh dhh commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@dkastner, this is at the core of what "most people would need most of the time". All Active Record backed apps need to pay attention to their query times and this helps them find problems early as well as making it easy. A perfect fit for core.

@shaliko
Copy link
Contributor

@shaliko shaliko commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@ikbear
Copy link

@ikbear ikbear commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@bltavares
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@josespinal
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Gracias Xavier!

@bsodmike
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1 very nice...

@elhu
Copy link

@elhu elhu commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Brilliant, can't wait to try it on a "real" project!

@erlingur
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Awesome!

@mattmacleod
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1. Reasonable to put in core due to essentially ubiquitous requirement!

@fsvehla
Copy link

@fsvehla fsvehla commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1 Great!

@adambair
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Excellent, glad to see this as a default. Will be nice to have early warnings -- especially helpful for new folks.

@cthree
Copy link

@cthree cthree commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@alvin2ye
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@rdlugosz
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

radical.

@kennyj
Copy link
Contributor

@kennyj kennyj commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@arunagw
Copy link
Member

@arunagw arunagw commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

❤️

@joeycarmello
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@oreoshake
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

👍

Also 👍 to the Timespan class if it doesn't exist

@aantix
Copy link
Contributor

@aantix aantix commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@aantix
Copy link
Contributor

@aantix aantix commented on 0306f82 Dec 2, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Would it be beneficial to show a (condensed) stack trace along with the explain output? It's not always apparent as to which of my app's ActiveRecord queries generated the associated raw query.

@tom2cjp
Copy link

@tom2cjp tom2cjp commented on 0306f82 Dec 3, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@RobinWu
Copy link

@RobinWu RobinWu commented on 0306f82 Dec 3, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@judearasu
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@marcbowes
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What an entertaining read. Nice!

@muellerj
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1 :)

@czj
Copy link

@czj czj commented on 0306f82 Dec 5, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@dgilperez
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

+1

@arkan
Copy link

@arkan arkan commented on 0306f82 Dec 7, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Awesome ! :)

@jglass
Copy link

@jglass jglass commented on 0306f82 Dec 9, 2011

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Just drooled on myself

Please sign in to comment.