Skip to content
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

Add option to generate generic explain plans for Postgres #604

Merged
merged 19 commits into from
May 2, 2024
Merged
2 changes: 1 addition & 1 deletion Earthfile
Original file line number Diff line number Diff line change
Expand Up @@ -103,7 +103,7 @@ integration-test-mysql:


integration-test-mssql:
ARG TARGETARCH
ARG TARGETARCH
FROM +setup-base

RUN apk add --no-cache curl gnupg --virtual .build-dependencies -- && \
Expand Down
55 changes: 52 additions & 3 deletions integration_test/pg/explain_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -27,16 +27,65 @@ defmodule Ecto.Integration.ExplainTest do
end)
end

@tag :plan_cache_mode
test "explain with fallback generic plan" do
# when using fallback generic plan , placeholders are used instead of values. i.e. $1 instead of 1
query = from p in Post, where: p.visits == ^1 and p.title == ^"title"

explain =
TestRepo.explain(:all, query, plan: :fallback_generic, verbose: true, timeout: 20000)

assert explain =~ "p0.visits = $1"
assert explain =~ "(p0.title)::text = $2"
end

test "explain with fallback generic plan cannot use analyze" do
msg = ~r/analyze cannot be used with a `:fallback_generic` explain plan/

assert_raise ArgumentError, msg, fn ->
TestRepo.explain(:all, Post, plan: :fallback_generic, analyze: true)
end
end

test "explain with custom plan" do
# when using custom plan, values are used instead of placeholders. i.e. 1 instead of $1
query = from p in Post, where: p.visits == ^1 and p.title == ^"title"

explain =
TestRepo.explain(:all, query, plan: :custom, analyze: true, verbose: true, timeout: 20000)

refute explain =~ "$1"
refute explain =~ "$2"
assert explain =~ "p0.visits = 1"
assert explain =~ "(p0.title)::text = 'title'"
end

@tag :explain_generic
test "explain with generic plan" do
# when using generic plan, placeholders are used instead of values. i.e. $1 instead of 1
query = from p in Post, where: p.visits == ^1 and p.title == ^"title"

explain =
TestRepo.explain(:all, query, plan: :generic, analyze: true, verbose: true, timeout: 20000)

assert explain =~ "p0.visits = $1"
assert explain =~ "(p0.title)::text = $2"
end

test "explain MAP format" do
[explain] = TestRepo.explain(:all, Post, analyze: true, verbose: true, timeout: 20000, format: :map)
keys = explain["Plan"] |> Map.keys
[explain] =
TestRepo.explain(:all, Post, analyze: true, verbose: true, timeout: 20000, format: :map)

keys = explain["Plan"] |> Map.keys()
assert Enum.member?(keys, "Actual Loops")
assert Enum.member?(keys, "Actual Rows")
assert Enum.member?(keys, "Actual Startup Time")
end

test "explain YAML format" do
explain = TestRepo.explain(:all, Post, analyze: true, verbose: true, timeout: 20000, format: :yaml)
explain =
TestRepo.explain(:all, Post, analyze: true, verbose: true, timeout: 20000, format: :yaml)

assert explain =~ ~r/Plan:/
assert explain =~ ~r/Node Type:/
assert explain =~ ~r/Relation Name:/
Expand Down
12 changes: 10 additions & 2 deletions integration_test/pg/test_helper.exs
Original file line number Diff line number Diff line change
Expand Up @@ -100,16 +100,24 @@ version =
excludes = [:selected_as_with_having, :selected_as_with_order_by_expression]
excludes_above_9_5 = [:without_conflict_target]
excludes_below_9_6 = [:add_column_if_not_exists, :no_error_on_conditional_column_migration]
excludes_below_12_0 = [:plan_cache_mode]
excludes_below_15_0 = [:on_delete_nilify_column_list]
excludes_below_16_0 = [:explain_generic]

exclude_list = excludes ++ excludes_above_9_5

cond do
Version.match?(version, "< 9.6.0") ->
ExUnit.configure(exclude: exclude_list ++ excludes_below_9_6 ++ excludes_below_15_0)
ExUnit.configure(exclude: exclude_list ++ excludes_below_9_6 ++ excludes_below_12_0 ++ excludes_below_15_0 ++ excludes_below_16_0)

Version.match?(version, "< 12.0.0") ->
ExUnit.configure(exclude: exclude_list ++ excludes_below_12_0 ++ excludes_below_15_0 ++ excludes_below_16_0)

Version.match?(version, "< 15.0.0") ->
ExUnit.configure(exclude: exclude_list ++ excludes_below_15_0)
ExUnit.configure(exclude: exclude_list ++ excludes_below_15_0 ++ excludes_below_16_0)

Version.match?(version, "< 16.0.0") ->
ExUnit.configure(exclude: exclude_list ++ excludes_below_16_0)

true ->
ExUnit.configure(exclude: exclude_list)
Expand Down
92 changes: 81 additions & 11 deletions lib/ecto/adapters/postgres/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ if Code.ensure_loaded?(Postgrex) do

@default_port 5432
@behaviour Ecto.Adapters.SQL.Connection
@explain_prepared_statement_name "ecto_explain_statement"

## Module and Options

Expand Down Expand Up @@ -357,11 +358,33 @@ if Code.ensure_loaded?(Postgrex) do
@impl true
def explain_query(conn, query, params, opts) do
{explain_opts, opts} =
Keyword.split(opts, ~w[analyze verbose costs settings buffers timing summary format]a)
Keyword.split(
opts,
~w[analyze verbose costs settings buffers timing summary format plan]a
)

fallback_generic? = explain_opts[:plan] == :fallback_generic

map_format? = {:format, :map} in explain_opts
result =
cond do
fallback_generic? and explain_opts[:analyze] ->
raise ArgumentError,
"analyze cannot be used with a `:fallback_generic` explain plan " <>
"as the actual parameter values are ignored under this plan type." <>
"You may either change the plan type to `:custom` or remove the `:analyze` option."

fallback_generic? ->
explain_opts = Keyword.delete(explain_opts, :plan)
explain_queries = build_fallback_generic_queries(query, length(params), explain_opts)
fallback_generic_query(conn, explain_queries, opts)

true ->
query(conn, build_explain_query(query, explain_opts), params, opts)
end

case query(conn, build_explain_query(query, explain_opts), params, opts) do
map_format? = explain_opts[:format] == :map

case result do
{:ok, %Postgrex.Result{rows: rows}} when map_format? ->
{:ok, List.flatten(rows)}

Expand All @@ -373,12 +396,45 @@ if Code.ensure_loaded?(Postgrex) do
end
end

def build_explain_query(query, []) do
["EXPLAIN ", query]
|> IO.iodata_to_binary()
def build_fallback_generic_queries(query, num_params, opts) do
prepare =
[
"PREPARE ",
@explain_prepared_statement_name,
"(",
Enum.map_intersperse(1..num_params, ", ", fn _ -> "unknown" end),
") AS ",
query
]
|> IO.iodata_to_binary()

set = "SET LOCAL plan_cache_mode = force_generic_plan"

execute =
[
"EXPLAIN ",
build_explain_opts(opts),
"EXECUTE ",
@explain_prepared_statement_name,
"(",
Enum.map_intersperse(1..num_params, ", ", fn _ -> "NULL" end),
")"
]
|> IO.iodata_to_binary()

deallocate = "DEALLOCATE #{@explain_prepared_statement_name}"

{prepare, set, execute, deallocate}
end

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

defp build_explain_opts([]), do: []

defp build_explain_opts(opts) do
{analyze, opts} = Keyword.pop(opts, :analyze)
{verbose, opts} = Keyword.pop(opts, :verbose)

Expand All @@ -388,10 +444,8 @@ if Code.ensure_loaded?(Postgrex) do
case opts do
[] ->
[
"EXPLAIN ",
if_do(quote_boolean(analyze) == "TRUE", "ANALYZE "),
if_do(quote_boolean(verbose) == "TRUE", "VERBOSE "),
query
if_do(quote_boolean(verbose) == "TRUE", "VERBOSE ")
]

opts ->
Expand All @@ -404,15 +458,31 @@ if Code.ensure_loaded?(Postgrex) do
{:format, value}, acc ->
[String.upcase("#{format_to_sql(value)}") | acc]

{:plan, :generic}, acc ->
["GENERIC" | acc]

{:plan, _}, acc ->
acc

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

["EXPLAIN ( ", opts, " ) ", query]
["( ", opts, " ) "]
end
end

defp fallback_generic_query(conn, queries, opts) do
{prepare, set, execute, deallocate} = queries

with {:ok, _} <- query(conn, prepare, [], opts),
{:ok, _} <- query(conn, set, [], opts),
{:ok, result} <- query(conn, execute, [], opts),
{:ok, _} <- query(conn, deallocate, [], opts) do
{:ok, result}
end
|> IO.iodata_to_binary()
end

## Query generation
Expand Down
9 changes: 8 additions & 1 deletion lib/ecto/adapters/sql.ex
Original file line number Diff line number Diff line change
Expand Up @@ -387,7 +387,7 @@ defmodule Ecto.Adapters.SQL do

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

All options except `format` are boolean valued and default to `false`.
Expand All @@ -400,6 +400,13 @@ defmodule Ecto.Adapters.SQL do
* Postgrex: `:map`, `:yaml` and `:text`
* MyXQL: `:map` and `:text`

The `:plan` option in Postgres can take the values `:custom`, `:generic` or `:fallback_generic`.
When `:custom` is specified, the explain plan generated by Postgres will consider the specific values
of the query parameters that are supplied. When using `:generic` or `:fallback_generic`, the specific
values of the query parameters will be ignored. The difference between the two is that `:generic`
utilizes Postgres's built-in functionality (available since Postgres 16) and `:fallback_generic` is
a special implementation for earlier Postgres versions. Defaults to `:custom`.

Any other value passed to `opts` will be forwarded to the underlying adapter query function, including
shared Repo options such as `:timeout`. Non built-in adapters may have specific behaviour and you should
consult their documentation for more details.
Expand Down
Loading