|
| 1 | +defmodule Ecto.Adapters.SQLite3.Connection.CteTest do |
| 2 | + use ExUnit.Case, async: true |
| 3 | + |
| 4 | + import Ecto.Query |
| 5 | + import Ecto.Adapters.SQLite3.TestHelpers |
| 6 | + |
| 7 | + alias EctoSQLite3.Schemas.Schema |
| 8 | + alias EctoSQLite3.Schemas.Schema2 |
| 9 | + |
| 10 | + test "CTE" do |
| 11 | + initial_query = |
| 12 | + "categories" |
| 13 | + |> where([c], is_nil(c.parent_id)) |
| 14 | + |> select([c], %{id: c.id, depth: fragment("1")}) |
| 15 | + |
| 16 | + iteration_query = |
| 17 | + "categories" |
| 18 | + |> join(:inner, [c], t in "tree", on: t.id == c.parent_id) |
| 19 | + |> select([c, t], %{id: c.id, depth: fragment("? + 1", t.depth)}) |
| 20 | + |
| 21 | + cte_query = initial_query |> union_all(^iteration_query) |
| 22 | + |
| 23 | + query = |
| 24 | + Schema |
| 25 | + |> recursive_ctes(true) |
| 26 | + |> with_cte("tree", as: ^cte_query) |
| 27 | + |> join(:inner, [r], t in "tree", on: t.id == r.category_id) |
| 28 | + |> select([r, t], %{x: r.x, category_id: t.id, depth: type(t.depth, :integer)}) |
| 29 | + |> plan() |
| 30 | + |
| 31 | + assert all(query) == |
| 32 | + ~s{WITH RECURSIVE "tree" AS } <> |
| 33 | + ~s{(SELECT sc0."id" AS "id", 1 AS "depth" FROM "categories" AS sc0 WHERE (sc0."parent_id" IS NULL) } <> |
| 34 | + ~s{UNION ALL } <> |
| 35 | + ~s{SELECT c0."id", t1."depth" + 1 FROM "categories" AS c0 } <> |
| 36 | + ~s{INNER JOIN "tree" AS t1 ON t1."id" = c0."parent_id") } <> |
| 37 | + ~s{SELECT s0."x", t1."id", CAST(t1."depth" AS INTEGER) } <> |
| 38 | + ~s{FROM "schema" AS s0 } <> |
| 39 | + ~s{INNER JOIN "tree" AS t1 ON t1."id" = s0."category_id"} |
| 40 | + end |
| 41 | + |
| 42 | + @raw_sql_cte """ |
| 43 | + SELECT * FROM categories WHERE c.parent_id IS NULL |
| 44 | + UNION ALL |
| 45 | + SELECT * FROM categories AS c, category_tree AS ct WHERE ct.id = c.parent_id |
| 46 | + """ |
| 47 | + |
| 48 | + test "reference CTE in union" do |
| 49 | + comments_scope_query = |
| 50 | + "comments" |
| 51 | + |> where([c], is_nil(c.deleted_at)) |
| 52 | + |> select([c], %{entity_id: c.entity_id, text: c.text}) |
| 53 | + |
| 54 | + posts_query = |
| 55 | + "posts" |
| 56 | + |> join(:inner, [p], c in "comments_scope", on: c.entity_id == p.guid) |
| 57 | + |> select([p, c], [p.title, c.text]) |
| 58 | + |
| 59 | + videos_query = |
| 60 | + "videos" |
| 61 | + |> join(:inner, [v], c in "comments_scope", on: c.entity_id == v.guid) |
| 62 | + |> select([v, c], [v.title, c.text]) |
| 63 | + |
| 64 | + query = |
| 65 | + posts_query |
| 66 | + |> union_all(^videos_query) |
| 67 | + |> with_cte("comments_scope", as: ^comments_scope_query) |
| 68 | + |> plan() |
| 69 | + |
| 70 | + assert all(query) == |
| 71 | + ~s{WITH "comments_scope" AS (} <> |
| 72 | + ~s{SELECT sc0."entity_id" AS "entity_id", sc0."text" AS "text" } <> |
| 73 | + ~s{FROM "comments" AS sc0 WHERE (sc0."deleted_at" IS NULL)) } <> |
| 74 | + ~s{SELECT p0."title", c1."text" } <> |
| 75 | + ~s{FROM "posts" AS p0 } <> |
| 76 | + ~s{INNER JOIN "comments_scope" AS c1 ON c1."entity_id" = p0."guid" } <> |
| 77 | + ~s{UNION ALL } <> |
| 78 | + ~s{SELECT v0."title", c1."text" } <> |
| 79 | + ~s{FROM "videos" AS v0 } <> |
| 80 | + ~s{INNER JOIN "comments_scope" AS c1 ON c1."entity_id" = v0."guid"} |
| 81 | + end |
| 82 | + |
| 83 | + test "fragment CTE" do |
| 84 | + query = |
| 85 | + Schema |
| 86 | + |> recursive_ctes(true) |
| 87 | + |> with_cte("tree", as: fragment(@raw_sql_cte)) |
| 88 | + |> join(:inner, [p], c in "tree", on: c.id == p.category_id) |
| 89 | + |> select([r], r.x) |
| 90 | + |> plan() |
| 91 | + |
| 92 | + assert all(query) == |
| 93 | + ~s{WITH RECURSIVE "tree" AS (#{@raw_sql_cte}) } <> |
| 94 | + ~s{SELECT s0."x" } <> |
| 95 | + ~s{FROM "schema" AS s0 } <> |
| 96 | + ~s{INNER JOIN "tree" AS t1 ON t1."id" = s0."category_id"} |
| 97 | + end |
| 98 | + |
| 99 | + # TODO should error on lock |
| 100 | + test "CTE update_all" do |
| 101 | + cte_query = |
| 102 | + from(x in Schema, |
| 103 | + order_by: [asc: :id], |
| 104 | + limit: 10, |
| 105 | + lock: "FOR UPDATE SKIP LOCKED", |
| 106 | + select: %{id: x.id} |
| 107 | + ) |
| 108 | + |
| 109 | + query = |
| 110 | + Schema |
| 111 | + |> with_cte("target_rows", as: ^cte_query) |
| 112 | + |> join(:inner, [row], target in "target_rows", on: target.id == row.id) |
| 113 | + |> select([r, t], r) |
| 114 | + |> update(set: [x: 123]) |
| 115 | + |> plan(:update_all) |
| 116 | + |
| 117 | + assert update_all(query) == |
| 118 | + ~s{WITH "target_rows" AS } <> |
| 119 | + ~s{(SELECT ss0."id" AS "id" FROM "schema" AS ss0 ORDER BY ss0."id" LIMIT 10) } <> |
| 120 | + ~s{UPDATE "schema" AS s0 } <> |
| 121 | + ~s{SET "x" = 123 } <> |
| 122 | + ~s{FROM "target_rows" AS t1 } <> |
| 123 | + ~s{WHERE (t1."id" = s0."id") } <> |
| 124 | + ~s{RETURNING "id", "x", "y", "z", "w", "meta"} |
| 125 | + end |
| 126 | + |
| 127 | + test "CTE delete_all" do |
| 128 | + cte_query = |
| 129 | + from(x in Schema, |
| 130 | + order_by: [asc: :id], |
| 131 | + limit: 10, |
| 132 | + inner_join: q in Schema2, |
| 133 | + on: x.x == q.z, |
| 134 | + select: %{id: x.id} |
| 135 | + ) |
| 136 | + |
| 137 | + query = |
| 138 | + Schema |
| 139 | + |> with_cte("target_rows", as: ^cte_query) |
| 140 | + |> select([r, t], r) |
| 141 | + |> plan(:delete_all) |
| 142 | + |
| 143 | + assert delete_all(query) == |
| 144 | + ~s{WITH "target_rows" AS } <> |
| 145 | + ~s{(SELECT ss0."id" AS "id" FROM "schema" AS ss0 INNER JOIN "schema2" AS ss1 ON ss0."x" = ss1."z" ORDER BY ss0."id" LIMIT 10) } <> |
| 146 | + ~s{DELETE FROM "schema" AS s0 } <> |
| 147 | + ~s{RETURNING "id", "x", "y", "z", "w", "meta"} |
| 148 | + end |
| 149 | + |
| 150 | + test "parent binding subquery and CTE" do |
| 151 | + initial_query = |
| 152 | + "categories" |
| 153 | + |> where([c], c.id == parent_as(:parent_category).id) |
| 154 | + |> select([:id, :parent_id]) |
| 155 | + |
| 156 | + iteration_query = |
| 157 | + "categories" |
| 158 | + |> join(:inner, [c], t in "tree", on: t.parent_id == c.id) |
| 159 | + |> select([:id, :parent_id]) |
| 160 | + |
| 161 | + cte_query = initial_query |> union_all(^iteration_query) |
| 162 | + |
| 163 | + breadcrumbs_query = |
| 164 | + "tree" |
| 165 | + |> recursive_ctes(true) |
| 166 | + |> with_cte("tree", as: ^cte_query) |
| 167 | + |> select([t], %{breadcrumbs: fragment("STRING_AGG(?, ' / ')", t.id)}) |
| 168 | + |
| 169 | + query = |
| 170 | + from(c in "categories", |
| 171 | + as: :parent_category, |
| 172 | + left_lateral_join: b in subquery(breadcrumbs_query), |
| 173 | + on: true, |
| 174 | + select: %{id: c.id, breadcrumbs: b.breadcrumbs} |
| 175 | + ) |
| 176 | + |> plan() |
| 177 | + |
| 178 | + assert_raise Ecto.QueryError, |
| 179 | + ~r/join `:left_lateral` not supported by SQLite3/, |
| 180 | + fn -> |
| 181 | + all(query) |
| 182 | + end |
| 183 | + end |
| 184 | + |
| 185 | + test "interpolated values" do |
| 186 | + cte1 = |
| 187 | + "schema1" |
| 188 | + |> select([m], %{id: m.id, smth: ^true}) |
| 189 | + |> where([], fragment("?", ^1)) |
| 190 | + |
| 191 | + union = |
| 192 | + "schema1" |
| 193 | + |> select([m], {m.id, ^true}) |
| 194 | + |> where([], fragment("?", ^5)) |
| 195 | + |
| 196 | + union_all = |
| 197 | + "schema2" |
| 198 | + |> select([m], {m.id, ^false}) |
| 199 | + |> where([], fragment("?", ^6)) |
| 200 | + |
| 201 | + query = |
| 202 | + "schema" |
| 203 | + |> with_cte("cte1", as: ^cte1) |
| 204 | + |> with_cte("cte2", as: fragment("SELECT * FROM schema WHERE ?", ^2)) |
| 205 | + |> select([m], {m.id, ^true}) |
| 206 | + |> join(:inner, [], Schema2, on: fragment("?", ^true)) |
| 207 | + |> join(:inner, [], Schema2, on: fragment("?", ^false)) |
| 208 | + |> where([], fragment("?", ^true)) |
| 209 | + |> where([], fragment("?", ^false)) |
| 210 | + |> having([], fragment("?", ^true)) |
| 211 | + |> having([], fragment("?", ^false)) |
| 212 | + |> group_by([], fragment("?", ^3)) |
| 213 | + |> group_by([], fragment("?", ^4)) |
| 214 | + |> union(^union) |
| 215 | + |> union_all(^union_all) |
| 216 | + |> order_by([], fragment("?", ^7)) |
| 217 | + |> limit([], ^8) |
| 218 | + |> offset([], ^9) |
| 219 | + |> plan() |
| 220 | + |
| 221 | + result = """ |
| 222 | + WITH "cte1" AS (SELECT ss0."id" AS "id", ? AS "smth" FROM "schema1" AS ss0 WHERE (?)), \ |
| 223 | + "cte2" AS (SELECT * FROM schema WHERE ?) \ |
| 224 | + SELECT s0."id", ? FROM "schema" AS s0 INNER JOIN "schema2" AS s1 ON ? \ |
| 225 | + INNER JOIN "schema2" AS s2 ON ? WHERE (?) AND (?) \ |
| 226 | + GROUP BY ?, ? HAVING (?) AND (?) \ |
| 227 | + UNION SELECT s0."id", ? FROM "schema1" AS s0 WHERE (?) \ |
| 228 | + UNION ALL SELECT s0."id", ? FROM "schema2" AS s0 WHERE (?) \ |
| 229 | + ORDER BY ? LIMIT ? OFFSET ?\ |
| 230 | + """ |
| 231 | + |
| 232 | + assert all(query) == String.trim(result) |
| 233 | + end |
| 234 | +end |
0 commit comments