Add explain support for methods like last, pluck and count

`explain` can be called on a relation to explain how the database would
execute a query. Currently `explain` doesn't work for queries using
`last`, `pluck` or `count`, as these return the actual result instead of
a relation. This makes it difficult to optimize these queries.

By letting `explain` return a proxy instead, we can support these
methods.

```ruby
User.all.explain.count
\# => "EXPLAIN SELECT COUNT(*) FROM `users`"

User.all.explain.maximum(:id)
\# => "EXPLAIN SELECT MAX(`users`.`id`) FROM `users`"
```

This breaks the existing behaviour in that it requires calling inspect
after explain.

```ruby
User.all.explain.inspect
\# => "EXPLAIN SELECT `users`.* FROM `users`"
```

However, as `explain` is mostly used from the commandline, this won't be a
problem as inspect is called automatically in IRB.

Co-authored-by: Rafael Mendonça França <rafael@rubyonrails.org>
This commit is contained in:
Petrik 2023-12-21 20:45:50 +01:00
parent f6f6b0542f
commit 1f83af3890
8 changed files with 188 additions and 17 deletions

@ -1,3 +1,19 @@
* Add `explain` support for `last`, `pluck` and `count`
Let `explain` return a proxy that delegates these methods:
```ruby
User.all.explain.count
# EXPLAIN SELECT COUNT(*) FROM `users`
# ...
User.all.explain.maximum(:id)
# EXPLAIN SELECT MAX(`users`.`id`) FROM `users`
# ...
```
*Petrik de Heus*
* Validate using `:on` option when using `validates_associated`
Fixes an issue where `validates_associated` `:on` option wasn't respected

@ -3,6 +3,54 @@
module ActiveRecord
# = Active Record \Relation
class Relation
class ExplainProxy # :nodoc:
def initialize(relation, options)
@relation = relation
@options = options
end
def inspect
exec_explain { @relation.send(:exec_queries) }
end
def average(column_name)
exec_explain { @relation.average(column_name) }
end
def count(column_name = nil)
exec_explain { @relation.count(column_name) }
end
def first(limit = nil)
exec_explain { @relation.first(limit) }
end
def last(limit = nil)
exec_explain { @relation.last(limit) }
end
def maximum(column_name)
exec_explain { @relation.maximum(column_name) }
end
def minimum(column_name)
exec_explain { @relation.minimum(column_name) }
end
def pluck(*column_names)
exec_explain { @relation.pluck(*column_names) }
end
def sum(identity_or_column = nil)
exec_explain { @relation.sum(identity_or_column) }
end
private
def exec_explain(&block)
@relation.exec_explain(@relation.collecting_queries_for_explain { block.call }, @options)
end
end
MULTI_VALUE_METHODS = [:includes, :eager_load, :preload, :select, :group,
:order, :joins, :left_outer_joins, :references,
:extending, :unscope, :optimizer_hints, :annotate,
@ -245,13 +293,30 @@ def find_or_initialize_by(attributes, &block)
# returns the result as a string. The string is formatted imitating the
# ones printed by the database shell.
#
# User.all.explain
# # EXPLAIN SELECT `cars`.* FROM `cars`
# # ...
#
# Note that this method actually runs the queries, since the results of some
# are needed by the next ones when eager loading is going on.
#
# To run EXPLAIN on queries created by `first`, `pluck` and `count`, call
# these methods on `explain`:
#
# User.all.explain.count
# # EXPLAIN SELECT COUNT(*) FROM `users`
# # ...
#
# The column name can be passed if required:
#
# User.all.explain.maximum(:id)
# # EXPLAIN SELECT MAX(`users`.`id`) FROM `users`
# # ...
#
# Please see further details in the
# {Active Record Query Interface guide}[https://guides.rubyonrails.org/active_record_querying.html#running-explain].
def explain(*options)
exec_explain(collecting_queries_for_explain { exec_queries }, options)
ExplainProxy.new(self, options)
end
# Converts relation objects to Array.

@ -8,13 +8,13 @@ class MySQLExplainTest < ActiveRecord::AbstractMysqlTestCase
fixtures :authors, :author_addresses
def test_explain_for_one_query
explain = Author.where(id: 1).explain
explain = Author.where(id: 1).explain.inspect
assert_match %(EXPLAIN SELECT `authors`.* FROM `authors` WHERE `authors`.`id` = 1), explain
assert_match %r(authors |.* const), explain
end
def test_explain_with_eager_loading
explain = Author.where(id: 1).includes(:posts).explain
explain = Author.where(id: 1).includes(:posts).explain.inspect
assert_match %(EXPLAIN SELECT `authors`.* FROM `authors` WHERE `authors`.`id` = 1), explain
assert_match %r(authors |.* const), explain
assert_match %(EXPLAIN SELECT `posts`.* FROM `posts` WHERE `posts`.`author_id` = 1), explain
@ -22,17 +22,17 @@ def test_explain_with_eager_loading
end
def test_explain_with_options_as_symbol
explain = Author.where(id: 1).explain(explain_option)
explain = Author.where(id: 1).explain(explain_option).inspect
assert_match %(#{expected_analyze_clause} SELECT `authors`.* FROM `authors` WHERE `authors`.`id` = 1), explain
end
def test_explain_with_options_as_strings
explain = Author.where(id: 1).explain(explain_option.to_s.upcase)
explain = Author.where(id: 1).explain(explain_option.to_s.upcase).inspect
assert_match %(#{expected_analyze_clause} SELECT `authors`.* FROM `authors` WHERE `authors`.`id` = 1), explain
end
def test_explain_options_with_eager_loading
explain = Author.where(id: 1).includes(:posts).explain(explain_option)
explain = Author.where(id: 1).includes(:posts).explain(explain_option).inspect
assert_match %(#{expected_analyze_clause} SELECT `authors`.* FROM `authors` WHERE `authors`.`id` = 1), explain
assert_match %(#{expected_analyze_clause} SELECT `posts`.* FROM `posts` WHERE `posts`.`author_id` = 1), explain
end

@ -11,7 +11,7 @@ def test_optimizer_hints
assert_queries_match(%r{\ASELECT /\*\+ NO_RANGE_OPTIMIZATION\(posts index_posts_on_author_id\) \*/}) do
posts = Post.optimizer_hints("NO_RANGE_OPTIMIZATION(posts index_posts_on_author_id)")
posts = posts.select(:id).where(author_id: [0, 1])
assert_includes posts.explain, "| index | index_posts_on_author_id | index_posts_on_author_id |"
assert_includes posts.explain.inspect, "| index | index_posts_on_author_id | index_posts_on_author_id |"
end
end
@ -27,7 +27,7 @@ def test_optimizer_hints_is_sanitized
assert_queries_match(%r{\ASELECT /\*\+ NO_RANGE_OPTIMIZATION\(posts index_posts_on_author_id\) \*/}) do
posts = Post.optimizer_hints("/*+ NO_RANGE_OPTIMIZATION(posts index_posts_on_author_id) */")
posts = posts.select(:id).where(author_id: [0, 1])
assert_includes posts.explain, "| index | index_posts_on_author_id | index_posts_on_author_id |"
assert_includes posts.explain.inspect, "| index | index_posts_on_author_id | index_posts_on_author_id |"
end
assert_queries_match(%r{\ASELECT /\*\+ \*\* // `posts`\.\*, // \*\* \*/}) do

@ -8,32 +8,32 @@ class PostgreSQLExplainTest < ActiveRecord::PostgreSQLTestCase
fixtures :authors, :author_addresses
def test_explain_for_one_query
explain = Author.where(id: 1).explain
explain = Author.where(id: 1).explain.inspect
assert_match %r(EXPLAIN SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\$1 \[\["id", 1\]\]|1)), explain
assert_match %(QUERY PLAN), explain
end
def test_explain_with_eager_loading
explain = Author.where(id: 1).includes(:posts).explain
explain = Author.where(id: 1).includes(:posts).explain.inspect
assert_match %(QUERY PLAN), explain
assert_match %r(EXPLAIN SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\$1 \[\["id", 1\]\]|1)), explain
assert_match %r(EXPLAIN SELECT "posts"\.\* FROM "posts" WHERE "posts"\."author_id" = (?:\$1 \[\["author_id", 1\]\]|1)), explain
end
def test_explain_with_options_as_symbols
explain = Author.where(id: 1).explain(:analyze, :buffers)
explain = Author.where(id: 1).explain(:analyze, :buffers).inspect
assert_match %r(EXPLAIN \(ANALYZE, BUFFERS\) SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\$1 \[\["id", 1\]\]|1)), explain
assert_match %(QUERY PLAN), explain
end
def test_explain_with_options_as_strings
explain = Author.where(id: 1).explain("VERBOSE", "ANALYZE", "FORMAT JSON")
explain = Author.where(id: 1).explain("VERBOSE", "ANALYZE", "FORMAT JSON").inspect
assert_match %r(EXPLAIN \(VERBOSE, ANALYZE, FORMAT JSON\) SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\$1 \[\["id", 1\]\]|1)), explain
assert_match %(QUERY PLAN), explain
end
def test_explain_options_with_eager_loading
explain = Author.where(id: 1).includes(:posts).explain(:analyze)
explain = Author.where(id: 1).includes(:posts).explain(:analyze).inspect
assert_match %(QUERY PLAN), explain
assert_match %r(EXPLAIN \(ANALYZE\) SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\$1 \[\["id", 1\]\]|1)), explain
assert_match %r(EXPLAIN \(ANALYZE\) SELECT "posts"\.\* FROM "posts" WHERE "posts"\."author_id" = (?:\$1 \[\["author_id", 1\]\]|1)), explain

@ -8,13 +8,13 @@ class SQLite3ExplainTest < ActiveRecord::SQLite3TestCase
fixtures :authors, :author_addresses
def test_explain_for_one_query
explain = Author.where(id: 1).explain
explain = Author.where(id: 1).explain.inspect
assert_match %r(EXPLAIN for: SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\? \[\["id", 1\]\]|1)), explain
assert_match(/(SEARCH )?(TABLE )?authors USING (INTEGER )?PRIMARY KEY/, explain)
end
def test_explain_with_eager_loading
explain = Author.where(id: 1).includes(:posts).explain
explain = Author.where(id: 1).includes(:posts).explain.inspect
assert_match %r(EXPLAIN for: SELECT "authors"\.\* FROM "authors" WHERE "authors"\."id" = (?:\? \[\["id", 1\]\]|1)), explain
assert_match(/(SEARCH )?(TABLE )?authors USING (INTEGER )?PRIMARY KEY/, explain)
assert_match %r(EXPLAIN for: SELECT "posts"\.\* FROM "posts" WHERE "posts"\."author_id" = (?:\? \[\["author_id", 1\]\]|1)), explain

@ -51,7 +51,7 @@ class BasePreventWritesTest < ActiveRecord::TestCase
Bird.create!(name: "Bluejay")
ActiveRecord::Base.while_preventing_writes do
assert_queries_count(2) { Bird.where(name: "Bluejay").explain }
assert_queries_count(2) { Bird.where(name: "Bluejay").explain.inspect }
end
end

@ -16,7 +16,7 @@ def connection
end
def test_relation_explain
message = Car.where(name: "honda").explain
message = Car.where(name: "honda").explain.inspect
assert_match(/^EXPLAIN/, message)
end
@ -35,6 +35,96 @@ def test_collecting_queries_for_explain
end
end
def test_relation_explain_with_average
expected_query = capture_sql {
Car.average(:id)
}.first
message = Car.all.explain.average(:id)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_count
expected_query = capture_sql {
Car.count
}.first
message = Car.all.explain.count
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_count_and_argument
expected_query = capture_sql {
Car.count(:id)
}.first
message = Car.all.explain.count(:id)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_minimum
expected_query = capture_sql {
Car.minimum(:id)
}.first
message = Car.all.explain.minimum(:id)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_maximum
expected_query = capture_sql {
Car.maximum(:id)
}.first
message = Car.all.explain.maximum(:id)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_sum
expected_query = capture_sql {
Car.sum(:id)
}.first
message = Car.all.explain.sum(:id)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_first
expected_query = capture_sql {
Car.all.first
}.first
message = Car.all.explain.first
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_last
expected_query = capture_sql {
Car.all.last
}.first
message = Car.all.explain.last
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_pluck
expected_query = capture_sql {
Car.all.pluck
}.first
message = Car.all.explain.pluck
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_relation_explain_with_pluck_with_args
expected_query = capture_sql {
Car.all.pluck(:id, :name)
}.first
message = Car.all.explain.pluck(:id, :name)
assert_match(/^EXPLAIN/, message)
assert_match(expected_query, message)
end
def test_exec_explain_with_no_binds
sqls = %w(foo bar)
binds = [[], []]