Skip to content
This repository was archived by the owner on Mar 19, 2021. It is now read-only.

Commit 8f1dcd4

Browse files
committed
Implement returning clause support.
Adapted from jazzyb/sqlite_ecto.
1 parent 42655f6 commit 8f1dcd4

File tree

2 files changed

+208
-1
lines changed

2 files changed

+208
-1
lines changed

lib/sqlitex/statement.ex

Lines changed: 158 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -27,10 +27,49 @@ defmodule Sqlitex.Statement do
2727
:ok
2828
2929
```
30+
31+
## RETURNING Clause Support
32+
33+
SQLite does not support the RETURNING extension to INSERT, DELETE, and UPDATE
34+
commands. (See https://www.postgresql.org/docs/9.6/static/sql-insert.html for
35+
a description of the Postgres implementation of this clause.)
36+
37+
Ecto 2.0 relies on being able to capture this information, so have invented our
38+
own implementation with the following syntax:
39+
40+
```
41+
;--RETURNING ON [INSERT | UPDATE | DELETE] <table>,<col>,<col>,...
42+
```
43+
44+
When the `prepare/2` and `prepare!/2` functions are given a query that contains
45+
the above returning clause, they separate this clause from the end of the query
46+
and store it separately in the `Statement` struct. Only the portion of the query
47+
preceding the returning clause is passed to SQLite's prepare function.
48+
49+
Later, when such a statement struct is passed to `fetch_all/2` or `fetch_all!/2`
50+
the returning clause is parsed and the query is performed with the following
51+
additional logic:
52+
53+
```
54+
SAVEPOINT sp_<random>;
55+
CREATE TEMP TABLE temp.t_<random> (<returning>);
56+
CREATE TEMP TRIGGER tr_<random> AFTER UPDATE ON main.<table> BEGIN
57+
INSERT INTO t_<random> SELECT NEW.<returning>;
58+
END;
59+
UPDATE ...; -- whatever the original statement was
60+
DROP TRIGGER tr_<random>;
61+
SELECT <returning> FROM temp.t_<random>;
62+
DROP TABLE temp.t_<random>;
63+
RELEASE sp_<random>;
64+
```
65+
66+
A more detailed description of the motivations for making this change is here:
67+
https://github.com/jazzyb/sqlite_ecto/wiki/Sqlite.Ecto's-Pseudo-Returning-Clause
3068
"""
3169

3270
defstruct database: nil,
3371
statement: nil,
72+
returning: nil,
3473
column_names: [],
3574
column_types: []
3675

@@ -51,6 +90,7 @@ defmodule Sqlitex.Statement do
5190
with {:ok, stmt} <- do_prepare(db, sql),
5291
{:ok, stmt} <- get_column_names(stmt),
5392
{:ok, stmt} <- get_column_types(stmt),
93+
{:ok, stmt} <- extract_returning_clause(stmt, sql),
5494
do: {:ok, stmt}
5595
end
5696

@@ -124,13 +164,20 @@ defmodule Sqlitex.Statement do
124164
* `{:error, error}`
125165
"""
126166
def fetch_all(statement, into \\ []) do
127-
case :esqlite3.fetchall(statement.statement) do
167+
case raw_fetch_all(statement) do
128168
{:error, _} = other -> other
129169
raw_data ->
130170
{:ok, Row.from(statement.column_types, statement.column_names, raw_data, into)}
131171
end
132172
end
133173

174+
defp raw_fetch_all(%__MODULE__{returning: nil, statement: statement}) do
175+
:esqlite3.fetchall(statement)
176+
end
177+
defp raw_fetch_all(statement) do
178+
returning_query(statement)
179+
end
180+
134181
@doc """
135182
Same as `fetch_all/2` but raises a Sqlitex.Statement.FetchAllError on error.
136183
@@ -231,4 +278,114 @@ defmodule Sqlitex.Statement do
231278
str = Integer.to_string num
232279
String.duplicate("0", len - String.length(str)) <> str
233280
end
281+
282+
# --- Returning clause support
283+
284+
@pseudo_returning_statement ~r(\s*;--RETURNING\s+ON\s+)i
285+
286+
defp extract_returning_clause(statement, sql) do
287+
if Regex.match?(@pseudo_returning_statement, sql) do
288+
[_, returning_clause] = Regex.split(@pseudo_returning_statement, sql, parts: 2)
289+
case parse_return_contents(returning_clause) do
290+
{_table, cols, _command, _ref} = info ->
291+
{:ok, %{statement | returning: info,
292+
column_names: Enum.map(cols, &String.to_atom/1),
293+
column_types: Enum.map(cols, fn _ -> nil end)}}
294+
err ->
295+
err
296+
end
297+
else
298+
{:ok, statement}
299+
end
300+
end
301+
302+
defp parse_return_contents(<<"INSERT ", values::binary>>) do
303+
[table | cols] = String.split(values, ",")
304+
{table, cols, "INSERT", "NEW"}
305+
end
306+
defp parse_return_contents(<<"UPDATE ", values::binary>>) do
307+
[table | cols] = String.split(values, ",")
308+
{table, cols, "UPDATE", "NEW"}
309+
end
310+
defp parse_return_contents(<<"DELETE ", values::binary>>) do
311+
[table | cols] = String.split(values, ",")
312+
{table, cols, "DELETE", "OLD"}
313+
end
314+
defp parse_return_contents(_) do
315+
{:error, :invalid_returning_clause}
316+
end
317+
318+
defp returning_query(%__MODULE__{database: db,
319+
statement: statement,
320+
returning: {table, cols, command, ref}})
321+
do
322+
with_savepoint(db, fn ->
323+
with_temp_table(db, cols, fn tmp_tbl ->
324+
err = with_temp_trigger(db, table, tmp_tbl, cols, command, ref, fn ->
325+
:esqlite3.fetchall(statement)
326+
end)
327+
328+
case err do
329+
{:error, _} -> err
330+
_ ->
331+
fields = Enum.join(cols, ", ")
332+
:esqlite3.q("SELECT #{fields} FROM #{tmp_tbl}", db)
333+
end
334+
end)
335+
end)
336+
end
337+
338+
defp with_savepoint(db, func) do
339+
sp = "sp_#{random_id()}"
340+
[] = :esqlite3.q("SAVEPOINT #{sp}", db)
341+
case safe_call(db, func, sp) do
342+
{:error, _} = error ->
343+
[] = :esqlite3.q("ROLLBACK TO SAVEPOINT #{sp}", db)
344+
[] = :esqlite3.q("RELEASE #{sp}", db)
345+
error
346+
result ->
347+
[] = :esqlite3.q("RELEASE #{sp}", db)
348+
result
349+
end
350+
end
351+
352+
defp safe_call(db, func, sp) do
353+
try do
354+
func.()
355+
rescue
356+
e in RuntimeError ->
357+
[] = :esqlite3.q("ROLLBACK TO SAVEPOINT #{sp}", db)
358+
[] = :esqlite3.q("RELEASE #{sp}", db)
359+
raise e
360+
end
361+
end
362+
363+
defp with_temp_table(db, returning, func) do
364+
tmp = "t_#{random_id()}"
365+
fields = Enum.join(returning, ", ")
366+
results = case :esqlite3.q("CREATE TEMP TABLE #{tmp} (#{fields})", db) do
367+
{:error, _} = err -> err
368+
_ -> func.(tmp)
369+
end
370+
:esqlite3.q("DROP TABLE IF EXISTS #{tmp}", db)
371+
results
372+
end
373+
374+
defp with_temp_trigger(db, table, tmp_tbl, returning, command, ref, func) do
375+
tmp = "tr_" <> random_id()
376+
fields = Enum.map_join(returning, ", ", &"#{ref}.#{&1}")
377+
sql = """
378+
CREATE TEMP TRIGGER #{tmp} AFTER #{command} ON main.#{table} BEGIN
379+
INSERT INTO #{tmp_tbl} SELECT #{fields};
380+
END;
381+
"""
382+
results = case :esqlite3.q(sql, db) do
383+
{:error, _} = err -> err
384+
_ -> func.()
385+
end
386+
:esqlite3.q("DROP TRIGGER IF EXISTS #{tmp}", db)
387+
results
388+
end
389+
390+
defp random_id, do: :rand.uniform |> Float.to_string |> String.slice(2..10)
234391
end

test/statement_test.exs

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -11,4 +11,54 @@ defmodule StatementTest do
1111

1212
assert result == [[user_version: 0]]
1313
end
14+
15+
describe "RETURNING pseudo-syntax" do
16+
test "returns id from a single row insert" do
17+
{:ok, db} = Sqlitex.open(":memory:")
18+
19+
Sqlitex.exec(db, "CREATE TABLE x(id INTEGER PRIMARY KEY AUTOINCREMENT, str)")
20+
21+
stmt = Sqlitex.Statement.prepare!(db, "INSERT INTO x(str) VALUES (?1) "
22+
<> ";--RETURNING ON INSERT x,id")
23+
24+
rows = Sqlitex.Statement.fetch_all!(stmt)
25+
assert rows == [[id: 1]]
26+
end
27+
28+
test "returns id from a single row insert as a raw list" do
29+
{:ok, db} = Sqlitex.open(":memory:")
30+
31+
Sqlitex.exec(db, "CREATE TABLE x(id INTEGER PRIMARY KEY AUTOINCREMENT, str)")
32+
33+
stmt = Sqlitex.Statement.prepare!(db, "INSERT INTO x(str) VALUES (?1) "
34+
<> ";--RETURNING ON INSERT x,id")
35+
36+
rows = Sqlitex.Statement.fetch_all!(stmt, :raw_list)
37+
assert rows == [[1]]
38+
end
39+
40+
test "returns id from a multi-row insert" do
41+
{:ok, db} = Sqlitex.open(":memory:")
42+
43+
Sqlitex.exec(db, "CREATE TABLE x(id INTEGER PRIMARY KEY AUTOINCREMENT, str)")
44+
45+
stmt = Sqlitex.Statement.prepare!(db, "INSERT INTO x(str) VALUES ('x'),('y'),('z') "
46+
<> ";--RETURNING ON INSERT x,id")
47+
48+
rows = Sqlitex.Statement.fetch_all!(stmt)
49+
assert rows == [[id: 1], [id: 2], [id: 3]]
50+
end
51+
52+
test "returns id from a multi-row insert as a raw list" do
53+
{:ok, db} = Sqlitex.open(":memory:")
54+
55+
Sqlitex.exec(db, "CREATE TABLE x(id INTEGER PRIMARY KEY AUTOINCREMENT, str)")
56+
57+
stmt = Sqlitex.Statement.prepare!(db, "INSERT INTO x(str) VALUES ('x'),('y'),('z') "
58+
<> ";--RETURNING ON INSERT x,id")
59+
60+
rows = Sqlitex.Statement.fetch_all!(stmt, :raw_list)
61+
assert rows == [[1], [2], [3]]
62+
end
63+
end
1464
end

0 commit comments

Comments
 (0)