Skip to content

Commit ecc8981

Browse files
Support materialized CTEs (#466)
1 parent 3ddc521 commit ecc8981

File tree

5 files changed

+84
-5
lines changed

5 files changed

+84
-5
lines changed

lib/ecto/adapters/myxql/connection.ex

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -313,7 +313,11 @@ if Code.ensure_loaded?(MyXQL) do
313313

314314
defp cte(%{with_ctes: _}, _), do: []
315315

316-
defp cte_expr({name, cte}, sources, query) do
316+
defp cte_expr({_name, materialized, _cte}, _sources, query) when is_boolean(materialized) do
317+
error!(query, "MySQL adapter does not support materialized CTEs")
318+
end
319+
320+
defp cte_expr({name, nil, cte}, sources, query) do
317321
[quote_name(name), " AS ", cte_query(cte, sources, query)]
318322
end
319323

lib/ecto/adapters/postgres/connection.ex

Lines changed: 9 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -409,8 +409,15 @@ if Code.ensure_loaded?(Postgrex) do
409409

410410
defp cte(%{with_ctes: _}, _), do: []
411411

412-
defp cte_expr({name, cte}, sources, query) do
413-
[quote_name(name), " AS ", cte_query(cte, sources, query)]
412+
defp cte_expr({name, materialized, cte}, sources, query) do
413+
materialized_opt =
414+
case materialized do
415+
nil -> ""
416+
true -> "MATERIALIZED"
417+
false -> "NOT MATERIALIZED"
418+
end
419+
420+
[quote_name(name), " AS ", materialized_opt, cte_query(cte, sources, query)]
414421
end
415422

416423
defp cte_query(%Ecto.Query{} = query, sources, parent_query) do

lib/ecto/adapters/tds/connection.ex

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -434,7 +434,11 @@ if Code.ensure_loaded?(Tds) do
434434

435435
defp cte(%{with_ctes: _}, _), do: []
436436

437-
defp cte_expr({name, cte}, sources, query) do
437+
defp cte_expr({_name, materialized, _cte}, _sources, query) when is_boolean(materialized) do
438+
error!(query, "Tds adapter does not support materialized CTEs")
439+
end
440+
441+
defp cte_expr({name, nil, cte}, sources, query) do
438442
[quote_name(name), cte_header(cte, query), " AS ", cte_query(cte, sources, query)]
439443
end
440444

mix.lock

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -6,7 +6,7 @@
66
"decimal": {:hex, :decimal, "2.0.0", "a78296e617b0f5dd4c6caf57c714431347912ffb1d0842e998e9792b5642d697", [:mix], [], "hexpm", "34666e9c55dea81013e77d9d87370fe6cb6291d1ef32f46a1600230b1d44f577"},
77
"deep_merge": {:hex, :deep_merge, "0.2.0", "c1050fa2edf4848b9f556fba1b75afc66608a4219659e3311d9c9427b5b680b3", [:mix], [], "hexpm", "e3bf435a54ed27b0ba3a01eb117ae017988804e136edcbe8a6a14c310daa966e"},
88
"earmark_parser": {:hex, :earmark_parser, "1.4.29", "149d50dcb3a93d9f3d6f3ecf18c918fb5a2d3c001b5d3305c926cddfbd33355b", [:mix], [], "hexpm", "4902af1b3eb139016aed210888748db8070b8125c2342ce3dcae4f38dcc63503"},
9-
"ecto": {:git, "https://github.com/elixir-ecto/ecto.git", "96d4920339d5d645dedaed1ef2ce7428683f529d", []},
9+
"ecto": {:git, "https://github.com/elixir-ecto/ecto.git", "954eda40ce768adb0e840a454c843126c9637794", []},
1010
"ex_doc": {:hex, :ex_doc, "0.29.0", "4a1cb903ce746aceef9c1f9ae8a6c12b742a5461e6959b9d3b24d813ffbea146", [:mix], [{:earmark_parser, "~> 1.4.19", [hex: :earmark_parser, repo: "hexpm", optional: false]}, {:makeup_elixir, "~> 0.14", [hex: :makeup_elixir, repo: "hexpm", optional: false]}, {:makeup_erlang, "~> 0.1", [hex: :makeup_erlang, repo: "hexpm", optional: false]}], "hexpm", "f096adb8bbca677d35d278223361c7792d496b3fc0d0224c9d4bc2f651af5db1"},
1111
"jason": {:hex, :jason, "1.4.0", "e855647bc964a44e2f67df589ccf49105ae039d4179db7f6271dfd3843dc27e6", [:mix], [{:decimal, "~> 1.0 or ~> 2.0", [hex: :decimal, repo: "hexpm", optional: true]}], "hexpm", "79a3791085b2a0f743ca04cec0f7be26443738779d09302e01318f97bdb82121"},
1212
"makeup": {:hex, :makeup, "1.1.0", "6b67c8bc2882a6b6a445859952a602afc1a41c2e08379ca057c0f525366fc3ca", [:mix], [{:nimble_parsec, "~> 1.2.2 or ~> 1.3", [hex: :nimble_parsec, repo: "hexpm", optional: false]}], "hexpm", "0a45ed501f4a8897f580eabf99a2e5234ea3e75a4373c8a52824f6e873be57a6"},

test/ecto/adapters/postgres_test.exs

Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -156,6 +156,70 @@ defmodule Ecto.Adapters.PostgresTest do
156156
~s{INNER JOIN "tree" AS t1 ON t1."id" = s0."category_id"}
157157
end
158158

159+
test "materialized CTE" do
160+
initial_query =
161+
"categories"
162+
|> where([c], is_nil(c.parent_id))
163+
|> select([c], %{id: c.id, depth: fragment("1")})
164+
165+
iteration_query =
166+
"categories"
167+
|> join(:inner, [c], t in "tree", on: t.id == c.parent_id)
168+
|> select([c, t], %{id: c.id, depth: fragment("? + 1", t.depth)})
169+
170+
cte_query = initial_query |> union_all(^iteration_query)
171+
172+
query =
173+
Schema
174+
|> recursive_ctes(true)
175+
|> with_cte("tree", as: ^cte_query, materialized: true)
176+
|> join(:inner, [r], t in "tree", on: t.id == r.category_id)
177+
|> select([r, t], %{x: r.x, category_id: t.id, depth: type(t.depth, :integer)})
178+
|> plan()
179+
180+
assert all(query) ==
181+
~s{WITH RECURSIVE "tree" AS MATERIALIZED} <>
182+
~s{(SELECT sc0."id" AS "id", 1 AS "depth" FROM "categories" AS sc0 WHERE (sc0."parent_id" IS NULL) } <>
183+
~s{UNION ALL } <>
184+
~s{(SELECT c0."id", t1."depth" + 1 FROM "categories" AS c0 } <>
185+
~s{INNER JOIN "tree" AS t1 ON t1."id" = c0."parent_id")) } <>
186+
~s{SELECT s0."x", t1."id", t1."depth"::bigint } <>
187+
~s{FROM "schema" AS s0 } <>
188+
~s{INNER JOIN "tree" AS t1 ON t1."id" = s0."category_id"}
189+
end
190+
191+
test "not materialized CTE" do
192+
initial_query =
193+
"categories"
194+
|> where([c], is_nil(c.parent_id))
195+
|> select([c], %{id: c.id, depth: fragment("1")})
196+
197+
iteration_query =
198+
"categories"
199+
|> join(:inner, [c], t in "tree", on: t.id == c.parent_id)
200+
|> select([c, t], %{id: c.id, depth: fragment("? + 1", t.depth)})
201+
202+
cte_query = initial_query |> union_all(^iteration_query)
203+
204+
query =
205+
Schema
206+
|> recursive_ctes(true)
207+
|> with_cte("tree", as: ^cte_query, materialized: false)
208+
|> join(:inner, [r], t in "tree", on: t.id == r.category_id)
209+
|> select([r, t], %{x: r.x, category_id: t.id, depth: type(t.depth, :integer)})
210+
|> plan()
211+
212+
assert all(query) ==
213+
~s{WITH RECURSIVE "tree" AS NOT MATERIALIZED} <>
214+
~s{(SELECT sc0."id" AS "id", 1 AS "depth" FROM "categories" AS sc0 WHERE (sc0."parent_id" IS NULL) } <>
215+
~s{UNION ALL } <>
216+
~s{(SELECT c0."id", t1."depth" + 1 FROM "categories" AS c0 } <>
217+
~s{INNER JOIN "tree" AS t1 ON t1."id" = c0."parent_id")) } <>
218+
~s{SELECT s0."x", t1."id", t1."depth"::bigint } <>
219+
~s{FROM "schema" AS s0 } <>
220+
~s{INNER JOIN "tree" AS t1 ON t1."id" = s0."category_id"}
221+
end
222+
159223
@raw_sql_cte """
160224
SELECT * FROM categories WHERE c.parent_id IS NULL
161225
UNION ALL

0 commit comments

Comments
 (0)