Skip to content

Add support for EXPLAIN statement #231

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 30 commits into from
Jun 7, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
30 commits
Select commit Hold shift + click to select a range
3b5145d
Add support for EXPLAIN statement
May 24, 2020
f28c842
Implement explain_query callback
May 26, 2020
6c0e844
Add all explain options for Postgres from v9 to v12
May 27, 2020
d46c264
Add support for all Postgres versions
May 29, 2020
941d2cb
Leverage Ecto.Multi to guarantee a rollback after EXPLAIN statement
May 29, 2020
d25ba1c
Leverage iodata on explain query and add explain output callback
May 29, 2020
15cd28f
Update lib/ecto/adapters/sql.ex
May 29, 2020
e62542d
Update lib/ecto/adapters/sql.ex
May 29, 2020
6d08ba7
Update lib/ecto/adapters/postgres/connection.ex
May 29, 2020
7451fd9
Update lib/ecto/adapters/sql.ex
May 29, 2020
d34b522
Address review comments:
May 29, 2020
03002f2
Format mysql explain output as a table
Jun 1, 2020
8fcf356
Raise for Tds because currently it lacks support for multiple sets
Jun 1, 2020
24fe371
Fix explain query for postgres > v9.0
Jun 1, 2020
0a22eac
Update lib/ecto/adapters/tds/connection.ex
Jun 2, 2020
a9ad09a
Improve docs and fix TDS raise message
Jun 2, 2020
a95bb00
Refactor so the adapter runs the query and format output
Jun 2, 2020
cee7a28
Revert to explain raising on invalid queries
Jun 3, 2020
9367b63
Add missing shared opts
Jun 6, 2020
4f360f5
Unify explain_opts and shared_opts
Jun 6, 2020
44f8b39
Split keywords to avoid passing unecessary opts downstream
Jun 6, 2020
507f782
typo
Jun 6, 2020
e881efa
Update lib/ecto/adapters/sql.ex
Jun 6, 2020
a0dc8e9
Update lib/ecto/adapters/sql.ex
Jun 6, 2020
9f958ea
Update lib/ecto/adapters/sql.ex
Jun 6, 2020
1efd817
improve docs
Jun 6, 2020
9943af6
typo
Jun 6, 2020
72f89d9
Update lib/ecto/adapters/sql.ex
Jun 7, 2020
d6d4c0a
Update lib/ecto/adapters/sql.ex
Jun 7, 2020
9d5ba8d
improve docs
Jun 7, 2020
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
30 changes: 30 additions & 0 deletions integration_test/myxql/explain_test.exs
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
defmodule Ecto.Integration.ExplainTest do
use Ecto.Integration.Case, async: true

alias Ecto.Integration.TestRepo
alias Ecto.Integration.Post
import Ecto.Query, only: [from: 2]

test "explain" do
explain = TestRepo.explain(:all, from(p in Post, where: p.title == "title"), timeout: 20000)

assert explain =~
"| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |"

assert explain =~ "p0"
assert explain =~ "SIMPLE"
assert explain =~ "Using where"

explain = TestRepo.explain(:delete_all, Post)
assert explain =~ "DELETE"
assert explain =~ "p0"

explain = TestRepo.explain(:update_all, from(p in Post, update: [set: [title: "new title"]]))
assert explain =~ "UPDATE"
assert explain =~ "p0"

assert_raise(MyXQL.Error, fn ->
TestRepo.explain(:all, from(p in "posts", select: p.invalid, where: p.invalid == "title"))
end)
end
end
29 changes: 29 additions & 0 deletions integration_test/pg/explain_test.exs
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
defmodule Ecto.Integration.ExplainTest do
use Ecto.Integration.Case, async: true

alias Ecto.Integration.TestRepo
alias Ecto.Integration.Post
import Ecto.Query, only: [from: 2]

test "explain" do
explain = TestRepo.explain(:all, Post, analyze: true, verbose: true, timeout: 20000)
assert explain =~ "cost="
assert explain =~ "actual time="
assert explain =~ "loops="
assert explain =~ "Output:"
assert explain =~ ~r/Planning [T|t]ime:/
assert explain =~ ~r/Execution [T|t]ime:/

explain = TestRepo.explain(:delete_all, Post)
assert explain =~ "Delete on posts p0"
assert explain =~ "cost="

explain = TestRepo.explain(:update_all, from(p in Post, update: [set: [title: "new title"]]))
assert explain =~ "Update on posts p0"
assert explain =~ "cost="

assert_raise(ArgumentError, "bad boolean value 1", fn ->
TestRepo.explain(:all, Post, analyze: "1")
end)
end
end
12 changes: 12 additions & 0 deletions integration_test/tds/explain_test.exs
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
defmodule Ecto.Integration.ExplainTest do
use Ecto.Integration.Case, async: true

alias Ecto.Integration.TestRepo
alias Ecto.Integration.Post

test "explain options" do
assert_raise(Tds.Error, "EXPLAIN is not supported by Ecto.Adapters.TDS at the moment", fn ->
TestRepo.explain(:all, Post)
end)
end
end
62 changes: 62 additions & 0 deletions lib/ecto/adapters/myxql/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -207,6 +207,68 @@ if Code.ensure_loaded?(MyXQL) do
["DELETE FROM ", quote_table(prefix, table), " WHERE " | filters]
end

@impl true
# DB explain opts are deprecated, so they aren't used to build the explain query.
# See Notes at https://dev.mysql.com/doc/refman/5.7/en/explain.html
def explain_query(conn, query, params, opts) do
case query(conn, build_explain_query(query), params, opts) do
{:ok, %MyXQL.Result{columns: columns, rows: rows}} ->
{:ok, format_result_as_table(columns, rows)}

error ->
error
end
end

def build_explain_query(query) do
["EXPLAIN ", query]
|> IO.iodata_to_binary()
end

defp format_result_as_table(columns, rows) do
column_widths =
[columns | rows]
|> List.zip()
|> Enum.map(&Tuple.to_list/1)
|> Enum.map(fn column_with_rows ->
column_with_rows |> Enum.map(&binary_length/1) |> Enum.max()
end)

[
separator(column_widths),
"\n",
cells(columns, column_widths),
"\n",
separator(column_widths),
"\n",
Enum.map(rows, &cells(&1, column_widths) ++ ["\n"]),
separator(column_widths)
]
|> IO.iodata_to_binary()
end

defp binary_length(nil), do: 4 # NULL
defp binary_length(binary) when is_binary(binary), do: String.length(binary)
defp binary_length(other), do: other |> inspect() |> String.length()

defp separator(widths) do
Enum.map(widths, & [?+, ?-, String.duplicate("-", &1), ?-]) ++ [?+]
end

defp cells(items, widths) do
cell =
[items, widths]
|> List.zip()
|> Enum.map(fn {item, width} -> [?|, " ", format_item(item, width) , " "] end)

[cell | [?|]]
end

defp format_item(nil, width), do: String.pad_trailing("NULL", width)
defp format_item(item, width) when is_binary(item), do: String.pad_trailing(item, width)
defp format_item(item, width) when is_number(item), do: item |> inspect() |> String.pad_leading(width)
defp format_item(item, width), do: item |> inspect() |> String.pad_trailing(width)

## Query generation

binary_ops =
Expand Down
56 changes: 56 additions & 0 deletions lib/ecto/adapters/postgres/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -250,6 +250,56 @@ if Code.ensure_loaded?(Postgrex) do
["DELETE FROM ", quote_table(prefix, table), " WHERE ", filters | returning(returning)]
end

@impl true
def explain_query(conn, query, params, opts) do
{explain_opts, opts} =
Keyword.split(opts, ~w[analyze verbose costs settings buffers timing summary]a)

case query(conn, build_explain_query(query, explain_opts), params, opts) do
{:ok, %Postgrex.Result{rows: rows}} -> {:ok, Enum.map_join(rows, "\n", & &1)}
error -> error
end
end

def build_explain_query(query, []) do
["EXPLAIN ", query]
|> IO.iodata_to_binary()
end

def build_explain_query(query, opts) do
{analyze, opts} = Keyword.pop(opts, :analyze)
{verbose, opts} = Keyword.pop(opts, :verbose)

# Given only ANALYZE or VERBOSE opts we assume the legacy format
# to support all Postgres versions, otherwise assume the new
# syntax supported since v9.0
case opts do
[] ->
[
"EXPLAIN ",
if_do(quote_boolean(analyze) == "TRUE", "ANALYZE "),
if_do(quote_boolean(verbose) == "TRUE", "VERBOSE "),
query
]

opts ->
opts =
([analyze: analyze, verbose: verbose] ++ opts)
|> Enum.reduce([], fn
{_, nil}, acc ->
acc

{opt, value}, acc ->
[String.upcase("#{opt} #{quote_boolean(value)}") | acc]
end)
|> Enum.reverse()
|> Enum.join(", ")

["EXPLAIN ( ", opts, " ) ", query]
end
|> IO.iodata_to_binary()
end

## Query generation

binary_ops =
Expand Down Expand Up @@ -1142,6 +1192,12 @@ if Code.ensure_loaded?(Postgrex) do
[?", name, ?"]
end

# TRUE, ON, or 1 to enable the option, and FALSE, OFF, or 0 to disable it
defp quote_boolean(nil), do: nil
defp quote_boolean(true), do: "TRUE"
defp quote_boolean(false), do: "FALSE"
defp quote_boolean(value), do: error!(nil, "bad boolean value #{value}")

defp single_quote(value), do: [?', escape_string(value), ?']

defp intersperse_map(list, separator, mapper, acc \\ [])
Expand Down
95 changes: 93 additions & 2 deletions lib/ecto/adapters/sql.ex
Original file line number Diff line number Diff line change
Expand Up @@ -217,10 +217,10 @@ defmodule Ecto.Adapters.SQL do
The examples below are meant for reference. Each adapter will
return a different result:

iex> Ecto.Adapters.SQL.to_sql(:all, repo, Post)
iex> Ecto.Adapters.SQL.to_sql(:all, Repo, Post)
{"SELECT p.id, p.title, p.inserted_at, p.created_at FROM posts as p", []}

iex> Ecto.Adapters.SQL.to_sql(:update_all, repo,
iex> Ecto.Adapters.SQL.to_sql(:update_all, Repo,
from(p in Post, update: [set: [title: ^"hello"]]))
{"UPDATE posts AS p SET title = $1", ["hello"]}

Expand All @@ -245,6 +245,87 @@ defmodule Ecto.Adapters.SQL do
end
end

@doc """
Executes an EXPLAIN statement or similar for the given query according to its kind and the
adapter in the given repository.

## Examples

# Postgres
iex> Ecto.Adapters.SQL.explain(:all, Repo, Post)
"Seq Scan on posts p0 (cost=0.00..12.12 rows=1 width=443)"

# MySQL
iex> Ecto.Adapters.SQL.explain(:all, from(p in Post, where: p.title == "title")) |> IO.puts()
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | p0 | NULL | ALL | NULL | NULL | NULL | NULL | 1 | 100.0 | Using where |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+

# Shared opts
iex> Ecto.Adapters.SQL.explain(:all, Repo, Post, analyze: true, timeout: 20_000)
"Seq Scan on posts p0 (cost=0.00..11.70 rows=170 width=443) (actual time=0.013..0.013 rows=0 loops=1)\\nPlanning Time: 0.031 ms\\nExecution Time: 0.021 ms"

It's safe to execute it for updates and deletes, no data change will be commited:

iex> Ecto.Adapters.SQL.explain(:update_all, Repo, from(p in Post, update: [set: [title: "new title"]]))
"Update on posts p0 (cost=0.00..11.70 rows=170 width=449)\\n -> Seq Scan on posts p0 (cost=0.00..11.70 rows=170 width=449)"

This function is also available under the repository with name `explain`:

iex> Repo.explain(:all, from(p in Post, where: p.title == "title"))
"Seq Scan on posts p0 (cost=0.00..12.12 rows=1 width=443)\\n Filter: ((title)::text = 'title'::text)"

### Options

Built-in adapters support passing `opts` to the EXPLAIN statement according to the following:

Adapter | Supported opts
---------------- | --------------
Postgrex | `analyze`, `verbose`, `costs`, `settings`, `buffers`, `timing`, `summary`
MyXQL | None

_Postgrex_: Check [PostgreSQL doc](https://www.postgresql.org/docs/current/sql-explain.html) for version compatibility.

_MyXQL_: `EXTENDED` and `PARTITIONS` opts were [deprecated](https://dev.mysql.com/doc/refman/5.7/en/explain.html) and are enabled by default.

Also note that:

* `FORMAT` isn't supported at the moment and the only possible output
is a textual format, so you may want to call `IO.puts/1` to display it;
* Any other value passed to `opts` will be forwarded to the underlying
adapter query function, including Repo shared options such as `:timeout`;
* Non built-in adapters may have specific behavior and you should consult
their own documentation.

"""
@spec explain(pid() | Ecto.Repo.t | Ecto.Adapter.adapter_meta,
:all | :update_all | :delete_all,
Ecto.Queryable.t, opts :: Keyword.t) :: String.t | Exception.t
def explain(repo, operation, queryable, opts \\ [])

def explain(repo, operation, queryable, opts) when is_atom(repo) or is_pid(repo) do
explain(Ecto.Adapter.lookup_meta(repo), operation, queryable, opts)
end

def explain(%{repo: repo} = adapter_meta, operation, queryable, opts) do
Ecto.Multi.new()
|> Ecto.Multi.run(:explain, fn _, _ ->
{prepared, prepared_params} = to_sql(operation, repo, queryable)
sql_call(adapter_meta, :explain_query, [prepared], prepared_params, opts)
end)
|> Ecto.Multi.run(:rollback, fn _, _ ->
{:error, :forced_rollback}
end)
|> repo.transaction()
|> case do
{:error, :rollback, :forced_rollback, %{explain: result}} -> result
{:error, :explain, error, _} -> raise error
_ -> raise "unable to execute explain"
end
end

@doc """
Returns a stream that runs a custom SQL query on given repo when reduced.

Expand Down Expand Up @@ -422,6 +503,16 @@ defmodule Ecto.Adapters.SQL do
def to_sql(operation, queryable) do
Ecto.Adapters.SQL.to_sql(operation, get_dynamic_repo(), queryable)
end

@doc """
A convenience function for SQL-based repositories that executes an EXPLAIN statement or similar
depending on the adapter to obtain statistics for the given query.

See `Ecto.Adapters.SQL.explain/4` for more information.
"""
def explain(operation, queryable, opts \\ []) do
Ecto.Adapters.SQL.explain(get_dynamic_repo(), operation, queryable, opts)
end
end
end

Expand Down
11 changes: 11 additions & 0 deletions lib/ecto/adapters/sql/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -98,6 +98,17 @@ defmodule Ecto.Adapters.SQL.Connection do
@callback delete(prefix :: String.t, table :: String.t,
filters :: [atom], returning :: [atom]) :: iodata

@doc """
Executes an EXPLAIN query or similar depending on the adapter to obtains statistics of the given query.

Receives the `connection`, `query`, `params` for the query,
and all `opts` including those related to the EXPLAIN statement and shared opts.

Must execute the explain query and return the result.
"""
@callback explain_query(connection, query :: String.t, params :: Keyword.t, opts :: Keyword.t) ::
{:ok, term} | {:error, Exception.t}

## DDL

@doc """
Expand Down
6 changes: 6 additions & 0 deletions lib/ecto/adapters/tds/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -299,6 +299,12 @@ if Code.ensure_loaded?(Tds) do
]
end

# TODO: see https://github.com/elixir-ecto/ecto_sql/pull/231#discussion_r433858288
@impl true
def explain_query(_conn, _query, _params, _opts) do
raise Tds.Error, "EXPLAIN is not supported by Ecto.Adapters.TDS at the moment"
end

## Query generation

binary_ops = [
Expand Down
4 changes: 4 additions & 0 deletions test/ecto/adapters/myxql_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -630,6 +630,10 @@ defmodule Ecto.Adapters.MyXQLTest do
assert all(query) == String.trim(result)
end

test "build_explain_query" do
assert SQL.build_explain_query("SELECT 1") == "EXPLAIN SELECT 1"
end

## *_all

test "update all" do
Expand Down
12 changes: 12 additions & 0 deletions test/ecto/adapters/postgres_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -707,6 +707,18 @@ defmodule Ecto.Adapters.PostgresTest do
assert all(query) == String.trim(result)
end

test "build_explain_query" do
assert_raise(ArgumentError, "bad boolean value T", fn ->
SQL.build_explain_query("SELECT 1", analyze: "T")
end)

assert SQL.build_explain_query("SELECT 1", []) == "EXPLAIN SELECT 1"
assert SQL.build_explain_query("SELECT 1", analyze: nil, verbose: nil) == "EXPLAIN SELECT 1"
assert SQL.build_explain_query("SELECT 1", analyze: true) == "EXPLAIN ANALYZE SELECT 1"
assert SQL.build_explain_query("SELECT 1", analyze: true, verbose: true) == "EXPLAIN ANALYZE VERBOSE SELECT 1"
assert SQL.build_explain_query("SELECT 1", analyze: true, costs: true) == "EXPLAIN ( ANALYZE TRUE, COSTS TRUE ) SELECT 1"
end

## *_all

test "update all" do
Expand Down