Commit 124261f6 authored by Simon Chabot's avatar Simon Chabot
Browse files

fix(rql2sql): properly handle date and datetime operations with SQLite

Different DB backends are used by CW, mainly postgresql and sqlite.
According to RQL's documentation:

    Any N WHERE N is Note, N written_on D, D day> (today -10), N written_by P, P name 'jphc' or P name 'ocy'

should return all the notes less than 10 days old written by jphc or ocy.

but, as described in #109, it only works with postgresql, which is *not*
mentioned in the documentation.

TODAY is working well in sqlite, but not the operations with TODAY.
TODAY is translated to 'CURRENT_DATE' in sqlite, and `SELECT CURRENT_DATE - 3`
return the current year minus three, and *not the current date minus 3 days* as
expected according to the documentation.

A lot of tests in CW are performed with SQLite (because it's fast to set up!),
so… let's make it work !

This patch suggests to adapt the 'visit_mathexpression' method, to write the
expected SQL when were are dealing with:

- sqlite
- a date(time) on the left (left-hand-side, lhs)
- a integer (treated as an amount of days) on the right (right-hand-side, rhs)


The tests have been updated to check that the conversion rql to sql is the
expected one, according to the backend.


close #109
parent 11b15e467082
......@@ -1461,7 +1461,7 @@ class SQLGenerator(object):
return ''
def visit_mathexpression(self, mexpr):
"""generate SQL for a mathematic expression"""
"""generate SQL for a mathematical expression"""
lhs, rhs = mexpr.get_parts()
# check for string concatenation
operator = mexpr.operator
......@@ -1474,6 +1474,28 @@ class SQLGenerator(object):
rhs.accept(self))
except CoercionError:
pass
try:
lhs_type = str(lhs.get_type(self._state.solution, self._args)).lower()
rhs_type = str(rhs.get_type(self._state.solution, self._args)).lower()
except CoercionError:
pass
else:
if (
self.dbhelper.backend_name == 'sqlite'
and operator in '+-'
and lhs_type in (
'date', 'datetime', 'tzdatetime', 'tzdate'
)
and rhs_type == 'int'
):
cast_func = 'DATETIME' if 'datetime' in lhs_type else 'DATE'
return '({:s}({:s}, "{:s}{:d} days"))'.format(
cast_func,
lhs.accept(self),
operator,
int(rhs.accept(self)),
)
return '(%s %s %s)' % (lhs.accept(self), operator, rhs.accept(self))
def visit_unaryexpression(self, uexpr):
......
......@@ -1405,6 +1405,10 @@ WHERE DATE(_X.cw_creation_date)=CAST(clock_timestamp() AS DATE)'''),
'''SELECT _P.cw_eid
FROM cw_Personne AS _P
WHERE NOT (DATE(_P.cw_datenaiss)=CAST(clock_timestamp() AS DATE))'''),
("Any X WHERE X is Affaire, X creation_date > (TODAY - 10)",
'''SELECT _X.cw_eid
FROM cw_Affaire AS _X
WHERE DATE(_X.cw_creation_date)>(CAST(clock_timestamp() AS DATE) - 10)'''),
]:
with self.subTest(rql=rql):
self._check(rql, sql)
......@@ -2184,6 +2188,15 @@ WHERE DATE(_X.cw_creation_date)=CURRENT_DATE'''),
'''SELECT _P.cw_eid
FROM cw_Personne AS _P
WHERE NOT (DATE(_P.cw_datenaiss)=CURRENT_DATE)'''),
("Any X WHERE X is Affaire, X creation_date > (TODAY - 10)",
'''SELECT _X.cw_eid
FROM cw_Affaire AS _X
WHERE DATE(_X.cw_creation_date)>(DATE(CURRENT_DATE, "-10 days"))'''),
("Any Y WHERE X is Affaire, Y is Affaire, "
"X creation_date D, Y creation_date > (D + 10)",
'''SELECT _Y.cw_eid
FROM cw_Affaire AS _X, cw_Affaire AS _Y
WHERE _Y.cw_creation_date>(DATETIME(_X.cw_creation_date, "+10 days"))'''),
]:
with self.subTest(rql=rql):
self._check(rql, sql)
......
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment