Skip to content

Implement values #174

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

Open
wants to merge 10 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
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
10 changes: 8 additions & 2 deletions integration_test/test_helper.exs
Original file line number Diff line number Diff line change
Expand Up @@ -127,8 +127,14 @@ excludes = [
# SQLite does not support anything except a single column in DISTINCT
:multicolumn_distinct,

# Values list
:values_list
# :location is not supported in elixir 1.15 and earlier, so we exclude all
if Version.match?(System.version(), "~> 1.16") do
# Run all with tag values_list, except for the "delete_all" test,
# as JOINS are not supported on DELETE statements by SQLite.
{:location, {"ecto/integration_test/cases/repo.exs", 2281}}
else
:values_list
end
]

ExUnit.configure(exclude: excludes)
Expand Down
91 changes: 91 additions & 0 deletions integration_test/values_test.exs
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
defmodule Ecto.Integration.ValuesTest do
use Ecto.Integration.Case, async: true

import Ecto.Query, only: [from: 2, with_cte: 3]

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

test "values works with datetime" do
TestRepo.insert!(%Post{inserted_at: ~N[2000-01-01 00:01:00]})
TestRepo.insert!(%Post{inserted_at: ~N[2000-01-01 00:02:00]})
TestRepo.insert!(%Post{inserted_at: ~N[2000-01-01 00:03:00]})

params = [
%{id: 1, date: ~N[2000-01-01 00:00:00]},
%{id: 2, date: ~N[2000-01-01 00:01:00]},
%{id: 3, date: ~N[2000-01-01 00:02:00]},
%{id: 4, date: ~N[2000-01-01 00:03:00]}
]

types = %{id: :integer, date: :naive_datetime}

results =
from(params in values(params, types),
left_join: p in Post,
on: p.inserted_at <= params.date,
group_by: params.id,
select: %{id: params.id, count: count(p.id)},
order_by: count(p.id)
)
|> TestRepo.all()

assert results == [
%{count: 0, id: 1},
%{count: 1, id: 2},
%{count: 2, id: 3},
%{count: 3, id: 4}
]
end

test "join to values works" do
TestRepo.insert!(%Post{id: 1})
TestRepo.insert!(%Comment{post_id: 1, text: "short"})
TestRepo.insert!(%Comment{post_id: 1, text: "much longer text"})

params = [%{id: 1, post_id: 1, n: 0}, %{id: 2, post_id: 1, n: 10}]
types = %{id: :integer, post_id: :integer, n: :integer}

results =
from(p in Post,
right_join: params in values(params, types),
on: params.post_id == p.id,
left_join: c in Comment,
on: c.post_id == p.id and fragment("LENGTH(?)", c.text) > params.n,
group_by: params.id,
select: {params.id, count(c.id)}
)
|> TestRepo.all()

assert [{1, 2}, {2, 1}] = results
end

test "values can be used together with CTE" do
TestRepo.insert!(%Post{id: 1, visits: 42})
TestRepo.insert!(%Comment{post_id: 1, text: "short"})
TestRepo.insert!(%Comment{post_id: 1, text: "much longer text"})

params = [%{id: 1, post_id: 1, n: 0}, %{id: 2, post_id: 1, n: 10}]
types = %{id: :integer, post_id: :integer, n: :integer}

cte_query = from(p in Post, select: %{id: p.id, visits: coalesce(p.visits, 0)})

q = Post |> with_cte("xxx", as: ^cte_query)

results =
from(p in q,
right_join: params in values(params, types),
on: params.post_id == p.id,
left_join: c in Comment,
on: c.post_id == p.id and fragment("LENGTH(?)", c.text) > params.n,
left_join: cte in "xxx",
on: cte.id == p.id,
group_by: params.id,
select: {params.id, count(c.id), cte.visits}
)
|> TestRepo.all()

assert [{1, 2, 42}, {2, 1, 42}] = results
end
end
37 changes: 29 additions & 8 deletions lib/ecto/adapters/sqlite3/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -1037,12 +1037,6 @@ defmodule Ecto.Adapters.SQLite3.Connection do
message: "join hints are not supported by SQLite3"
end

defp assert_valid_join(%JoinExpr{source: {:values, _, _}}, query) do
raise Ecto.QueryError,
query: query,
message: "SQLite3 adapter does not support values lists"
end

defp assert_valid_join(_join_expr, _query), do: :ok

defp join_on(:cross, true, _sources, _query), do: []
Expand Down Expand Up @@ -1368,8 +1362,8 @@ defmodule Ecto.Adapters.SQLite3.Connection do
|> parens_for_select
end

defp expr({:values, _, _}, _, _query) do
raise ArgumentError, "SQLite3 adapter does not support values lists"
defp expr({:values, _, [types, idx, num_rows]}, _, _query) do
[?(, values_list(types, idx + 1, num_rows), ?)]
end

defp expr({:identifier, _, [literal]}, _sources, _query) do
Expand Down Expand Up @@ -1560,6 +1554,30 @@ defmodule Ecto.Adapters.SQLite3.Connection do
message: "unsupported expression #{inspect(expr)}"
end

defp values_list(types, idx, num_rows) do
rows = :lists.seq(1, num_rows, 1)
col_names = Enum.map_join(types, ", ", &elem(&1, 0))
table_name = "temp_#{:rand.uniform(100_000)}"

[
"WITH #{table_name}(",
col_names,
") AS (VALUES ",
intersperse_reduce(rows, ?,, idx, fn _, idx ->
{value, idx} = values_expr(types, idx)
{[?(, value, ?)], idx}
end)
|> elem(0),
") SELECT * FROM #{table_name}"
]
end

defp values_expr(types, idx) do
intersperse_reduce(types, ?,, idx, fn {_field, type}, idx ->
{[?$, Integer.to_string(idx), ?:, ?: | column_type(type, nil)], idx + 1}
Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I've added the type casting as in the postgres version.
It's probably only needed in a couple of cases, so it might do some unnecessary casting, but I don't think this will hurt.

Without it we were completely ignoring the types that the user supplied, so I think it makes more sense to just always cast.

end)
end

def interval(_, "microsecond", _sources) do
raise ArgumentError,
"SQLite does not support microsecond precision in datetime intervals"
Expand Down Expand Up @@ -1618,6 +1636,9 @@ defmodule Ecto.Adapters.SQLite3.Connection do
{:fragment, _, _} ->
{nil, as_prefix ++ [?f | Integer.to_string(pos)], nil}

{:values, _, _} ->
{nil, as_prefix ++ [?v | Integer.to_string(pos)], nil}

{table, schema, prefix} ->
name = as_prefix ++ [create_alias(table) | Integer.to_string(pos)]
{quote_table(prefix, table), name, schema}
Expand Down
23 changes: 17 additions & 6 deletions test/ecto/adapters/sqlite3/connection/join_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -135,11 +135,14 @@ defmodule Ecto.Adapters.SQLite3.Connection.JoinTest do
end
end

test "join with values is not supported" do
assert_raise Ecto.QueryError, fn ->
rows = [%{x: 1, y: 1}, %{x: 2, y: 2}]
types = %{x: :integer, y: :integer}
test "join with values" do
rows = [%{x: 1, y: 1}, %{x: 2, y: 2}]
types = %{x: :integer, y: :integer}

# Seeding rand ensures we get temp_78027 as the CTE name
:rand.seed(:exsss, {1, 2, 3})

query =
Schema
|> join(
:inner,
Expand All @@ -149,8 +152,16 @@ defmodule Ecto.Adapters.SQLite3.Connection.JoinTest do
)
|> select([p, q], {p.id, q.x})
|> plan()
|> all()
end

# We can't hardcode the columns of the CTE here,
# as the order changes for different Map implementations for OTP 25 and later
col_names = Map.keys(types) |> Enum.join(", ")

assert ~s{SELECT s0."id", v1."x" FROM "schema" AS s0 } <>
~s{INNER JOIN (WITH temp_78027(#{col_names}) AS (VALUES ($1::INTEGER,$2::INTEGER),($3::INTEGER,$4::INTEGER)) } <>
~s{SELECT * FROM temp_78027) AS v1 } <>
~s{ON (v1."x" = s0."x") AND (v1."y" = s0."y")} ==
all(query)
end

test "join with fragment" do
Expand Down
Loading