@@ -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,102 @@ 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 } = stmt ) do
319+ sp = "sp_#{ random_id ( ) } "
320+ { :ok , _ } = db_exec ( db , "SAVEPOINT #{ sp } " )
321+
322+ case returning_query_in_savepoint ( sp , stmt ) do
323+ { :error , _ } = error ->
324+ rollback ( db , sp )
325+ error
326+ result ->
327+ { :ok , _ } = db_exec ( db , "RELEASE #{ sp } " )
328+ result
329+ end
330+ end
331+
332+ defp returning_query_in_savepoint ( sp , % __MODULE__ { database: db ,
333+ statement: statement ,
334+ returning: { table , cols , cmd , ref } } )
335+ do
336+ temp_table = "t_#{ random_id ( ) } "
337+ temp_fields = Enum . join ( cols , ", " )
338+
339+ trigger_name = "tr_#{ random_id ( ) } "
340+ trigger_fields = Enum . map_join ( cols , ", " , & "#{ ref } .#{ & 1 } " )
341+ trigger = """
342+ CREATE TEMP TRIGGER #{ trigger_name } AFTER #{ cmd } ON main.#{ table } BEGIN
343+ INSERT INTO #{ temp_table } SELECT #{ trigger_fields } ;
344+ END;
345+ """
346+
347+ column_names = Enum . join ( cols , ", " )
348+
349+ with { :ok , _ } = db_exec ( db , "CREATE TEMP TABLE #{ temp_table } (#{ temp_fields } )" ) ,
350+ { :ok , _ } = db_exec ( db , trigger ) ,
351+ _ = :esqlite3 . fetchall ( statement ) ,
352+ { :ok , rows } = db_exec ( db , "SELECT #{ column_names } FROM #{ temp_table } " ) ,
353+ { :ok , _ } = db_exec ( db , "DROP TRIGGER IF EXISTS #{ trigger_name } " ) ,
354+ { :ok , _ } = db_exec ( db , "DROP TABLE IF EXISTS #{ temp_table } " )
355+ do
356+ rows
357+ end
358+ catch
359+ e ->
360+ rollback ( db , sp )
361+ raise e
362+ end
363+
364+ defp rollback ( db , sp ) do
365+ { :ok , _ } = db_exec ( db , "ROLLBACK TO SAVEPOINT #{ sp } " )
366+ { :ok , _ } = db_exec ( db , "RELEASE #{ sp } " )
367+ end
368+
369+ defp db_exec ( db , sql ) do
370+ case :esqlite3 . q ( sql , db ) do
371+ { :error , _ } = error ->
372+ error
373+ result ->
374+ { :ok , result }
375+ end
376+ end
377+
378+ defp random_id , do: :rand . uniform |> Float . to_string |> String . slice ( 2 .. 10 )
234379end
0 commit comments