Skip to content

Commit

Permalink
Fixed #10154: Allow combining F expressions with timedelta values.
Browse files Browse the repository at this point in the history
git-svn-id: http://code.djangoproject.com/svn/django/trunk@15018 bcc190cf-cafb-0310-a4f2-bffc1f526a37
  • Loading branch information
kmtracey committed Dec 22, 2010
1 parent f0cd656 commit b1f6a4d
Show file tree
Hide file tree
Showing 11 changed files with 360 additions and 4 deletions.
9 changes: 9 additions & 0 deletions django/db/backends/__init__.py
Expand Up @@ -154,6 +154,9 @@ class BaseDatabaseFeatures(object):
# deferred # deferred
can_defer_constraint_checks = False can_defer_constraint_checks = False


# date_interval_sql can properly handle mixed Date/DateTime fields and timedeltas
supports_mixed_date_datetime_comparisons = True

# Features that need to be confirmed at runtime # Features that need to be confirmed at runtime
# Cache whether the confirmation has been performed. # Cache whether the confirmation has been performed.
_confirmed = False _confirmed = False
Expand Down Expand Up @@ -220,6 +223,12 @@ def date_extract_sql(self, lookup_type, field_name):
""" """
raise NotImplementedError() raise NotImplementedError()


def date_interval_sql(self, sql, connector, timedelta):
"""
Implements the date interval functionality for expressions
"""
raise NotImplementedError()

def date_trunc_sql(self, lookup_type, field_name): def date_trunc_sql(self, lookup_type, field_name):
""" """
Given a lookup_type of 'year', 'month' or 'day', returns the SQL that Given a lookup_type of 'year', 'month' or 'day', returns the SQL that
Expand Down
4 changes: 4 additions & 0 deletions django/db/backends/mysql/base.py
Expand Up @@ -158,6 +158,10 @@ def date_trunc_sql(self, lookup_type, field_name):
sql = "CAST(DATE_FORMAT(%s, '%s') AS DATETIME)" % (field_name, format_str) sql = "CAST(DATE_FORMAT(%s, '%s') AS DATETIME)" % (field_name, format_str)
return sql return sql


def date_interval_sql(self, sql, connector, timedelta):
return "(%s %s INTERVAL '%d 0:0:%d:%d' DAY_MICROSECOND)" % (sql, connector,
timedelta.days, timedelta.seconds, timedelta.microseconds)

def drop_foreignkey_sql(self): def drop_foreignkey_sql(self):
return "DROP FOREIGN KEY" return "DROP FOREIGN KEY"


Expand Down
14 changes: 14 additions & 0 deletions django/db/backends/oracle/base.py
Expand Up @@ -118,6 +118,20 @@ def date_extract_sql(self, lookup_type, field_name):
else: else:
return "EXTRACT(%s FROM %s)" % (lookup_type, field_name) return "EXTRACT(%s FROM %s)" % (lookup_type, field_name)


def date_interval_sql(self, sql, connector, timedelta):
"""
Implements the interval functionality for expressions
format for Oracle:
(datefield + INTERVAL '3 00:03:20.000000' DAY(1) TO SECOND(6))
"""
minutes, seconds = divmod(timedelta.seconds, 60)
hours, minutes = divmod(minutes, 60)
days = str(timedelta.days)
day_precision = len(days)
fmt = "(%s %s INTERVAL '%s %02d:%02d:%02d.%06d' DAY(%d) TO SECOND(6))"
return fmt % (sql, connector, days, hours, minutes, seconds,
timedelta.microseconds, day_precision)

def date_trunc_sql(self, lookup_type, field_name): def date_trunc_sql(self, lookup_type, field_name):
# Oracle uses TRUNC() for both dates and numbers. # Oracle uses TRUNC() for both dates and numbers.
# http://download-east.oracle.com/docs/cd/B10501_01/server.920/a96540/functions155a.htm#SQLRF06151 # http://download-east.oracle.com/docs/cd/B10501_01/server.920/a96540/functions155a.htm#SQLRF06151
Expand Down
17 changes: 17 additions & 0 deletions django/db/backends/postgresql/operations.py
Expand Up @@ -27,6 +27,23 @@ def date_extract_sql(self, lookup_type, field_name):
else: else:
return "EXTRACT('%s' FROM %s)" % (lookup_type, field_name) return "EXTRACT('%s' FROM %s)" % (lookup_type, field_name)


def date_interval_sql(self, sql, connector, timedelta):
"""
implements the interval functionality for expressions
format for Postgres:
(datefield + interval '3 days 200 seconds 5 microseconds')
"""
modifiers = []
if timedelta.days:
modifiers.append(u'%s days' % timedelta.days)
if timedelta.seconds:
modifiers.append(u'%s seconds' % timedelta.seconds)
if timedelta.microseconds:
modifiers.append(u'%s microseconds' % timedelta.microseconds)
mods = u' '.join(modifiers)
conn = u' %s ' % connector
return u'(%s)' % conn.join([sql, u'interval \'%s\'' % mods])

def date_trunc_sql(self, lookup_type, field_name): def date_trunc_sql(self, lookup_type, field_name):
# http://www.postgresql.org/docs/8.0/static/functions-datetime.html#FUNCTIONS-DATETIME-TRUNC # http://www.postgresql.org/docs/8.0/static/functions-datetime.html#FUNCTIONS-DATETIME-TRUNC
return "DATE_TRUNC('%s', %s)" % (lookup_type, field_name) return "DATE_TRUNC('%s', %s)" % (lookup_type, field_name)
Expand Down
32 changes: 32 additions & 0 deletions django/db/backends/sqlite3/base.py
Expand Up @@ -9,6 +9,7 @@


import re import re
import sys import sys
import datetime


from django.db import utils from django.db import utils
from django.db.backends import * from django.db.backends import *
Expand Down Expand Up @@ -63,6 +64,7 @@ class DatabaseFeatures(BaseDatabaseFeatures):
test_db_allows_multiple_connections = False test_db_allows_multiple_connections = False
supports_unspecified_pk = True supports_unspecified_pk = True
supports_1000_query_parameters = False supports_1000_query_parameters = False
supports_mixed_date_datetime_comparisons = False


def _supports_stddev(self): def _supports_stddev(self):
"""Confirm support for STDDEV and related stats functions """Confirm support for STDDEV and related stats functions
Expand Down Expand Up @@ -90,6 +92,16 @@ def date_extract_sql(self, lookup_type, field_name):
# cause a collision with a field name). # cause a collision with a field name).
return "django_extract('%s', %s)" % (lookup_type.lower(), field_name) return "django_extract('%s', %s)" % (lookup_type.lower(), field_name)


def date_interval_sql(self, sql, connector, timedelta):
# It would be more straightforward if we could use the sqlite strftime
# function, but it does not allow for keeping six digits of fractional
# second information, nor does it allow for formatting date and datetime
# values differently. So instead we register our own function that
# formats the datetime combined with the delta in a manner suitable
# for comparisons.
return u'django_format_dtdelta(%s, "%s", "%d", "%d", "%d")' % (sql,
connector, timedelta.days, timedelta.seconds, timedelta.microseconds)

def date_trunc_sql(self, lookup_type, field_name): def date_trunc_sql(self, lookup_type, field_name):
# sqlite doesn't support DATE_TRUNC, so we fake it with a user-defined # sqlite doesn't support DATE_TRUNC, so we fake it with a user-defined
# function django_date_trunc that's registered in connect(). Note that # function django_date_trunc that's registered in connect(). Note that
Expand Down Expand Up @@ -197,6 +209,7 @@ def _cursor(self):
self.connection.create_function("django_extract", 2, _sqlite_extract) self.connection.create_function("django_extract", 2, _sqlite_extract)
self.connection.create_function("django_date_trunc", 2, _sqlite_date_trunc) self.connection.create_function("django_date_trunc", 2, _sqlite_date_trunc)
self.connection.create_function("regexp", 2, _sqlite_regexp) self.connection.create_function("regexp", 2, _sqlite_regexp)
self.connection.create_function("django_format_dtdelta", 5, _sqlite_format_dtdelta)
connection_created.send(sender=self.__class__, connection=self) connection_created.send(sender=self.__class__, connection=self)
return self.connection.cursor(factory=SQLiteCursorWrapper) return self.connection.cursor(factory=SQLiteCursorWrapper)


Expand Down Expand Up @@ -260,6 +273,25 @@ def _sqlite_date_trunc(lookup_type, dt):
elif lookup_type == 'day': elif lookup_type == 'day':
return "%i-%02i-%02i 00:00:00" % (dt.year, dt.month, dt.day) return "%i-%02i-%02i 00:00:00" % (dt.year, dt.month, dt.day)


def _sqlite_format_dtdelta(dt, conn, days, secs, usecs):
try:
dt = util.typecast_timestamp(dt)
delta = datetime.timedelta(int(days), int(secs), int(usecs))
if conn.strip() == '+':
dt = dt + delta
else:
dt = dt - delta
except (ValueError, TypeError):
return None

if isinstance(dt, datetime.datetime):
rv = dt.strftime("%Y-%m-%d %H:%M:%S")
if dt.microsecond:
rv = "%s.%0.6d" % (rv, dt.microsecond)
else:
rv = dt.strftime("%Y-%m-%d")
return rv

def _sqlite_regexp(re_pattern, re_string): def _sqlite_regexp(re_pattern, re_string):
import re import re
try: try:
Expand Down
43 changes: 42 additions & 1 deletion django/db/models/expressions.py
@@ -1,4 +1,4 @@
from datetime import datetime import datetime


from django.utils import tree from django.utils import tree
from django.utils.copycompat import deepcopy from django.utils.copycompat import deepcopy
Expand Down Expand Up @@ -26,6 +26,9 @@ def __init__(self, children=None, connector=None, negated=False):
super(ExpressionNode, self).__init__(children, connector, negated) super(ExpressionNode, self).__init__(children, connector, negated)


def _combine(self, other, connector, reversed, node=None): def _combine(self, other, connector, reversed, node=None):
if isinstance(other, datetime.timedelta):
return DateModifierNode([self, other], connector)

if reversed: if reversed:
obj = ExpressionNode([other], connector) obj = ExpressionNode([other], connector)
obj.add(node or self, connector) obj.add(node or self, connector)
Expand Down Expand Up @@ -111,3 +114,41 @@ def prepare(self, evaluator, query, allow_joins):


def evaluate(self, evaluator, qn, connection): def evaluate(self, evaluator, qn, connection):
return evaluator.evaluate_leaf(self, qn, connection) return evaluator.evaluate_leaf(self, qn, connection)

class DateModifierNode(ExpressionNode):
"""
Node that implements the following syntax:
filter(end_date__gt=F('start_date') + datetime.timedelta(days=3, seconds=200))
which translates into:
POSTGRES:
WHERE end_date > (start_date + INTERVAL '3 days 200 seconds')
MYSQL:
WHERE end_date > (start_date + INTERVAL '3 0:0:200:0' DAY_MICROSECOND)
ORACLE:
WHERE end_date > (start_date + INTERVAL '3 00:03:20.000000' DAY(1) TO SECOND(6))
SQLITE:
WHERE end_date > django_format_dtdelta(start_date, "+" "3", "200", "0")
(A custom function is used in order to preserve six digits of fractional
second information on sqlite, and to format both date and datetime values.)
Note that microsecond comparisons are not well supported with MySQL, since
MySQL does not store microsecond information.
Only adding and subtracting timedeltas is supported, attempts to use other
operations raise a TypeError.
"""
def __init__(self, children, connector, negated=False):
if len(children) != 2:
raise TypeError('Must specify a node and a timedelta.')
if not isinstance(children[1], datetime.timedelta):
raise TypeError('Second child must be a timedelta.')
if connector not in (self.ADD, self.SUB):
raise TypeError('Connector must be + or -, not %s' % connector)
super(DateModifierNode, self).__init__(children, connector, negated)

def evaluate(self, evaluator, qn, connection):
return evaluator.evaluate_date_modifier_node(self, qn, connection)
10 changes: 10 additions & 0 deletions django/db/models/sql/expressions.py
Expand Up @@ -85,3 +85,13 @@ def evaluate_leaf(self, node, qn, connection):
return col.as_sql(qn, connection), () return col.as_sql(qn, connection), ()
else: else:
return '%s.%s' % (qn(col[0]), qn(col[1])), () return '%s.%s' % (qn(col[0]), qn(col[1])), ()

def evaluate_date_modifier_node(self, node, qn, connection):
timedelta = node.children.pop()
sql, params = self.evaluate_node(node, qn, connection)

if timedelta.days == 0 and timedelta.seconds == 0 and \
timedelta.microseconds == 0:
return sql, params

return connection.ops.date_interval_sql(sql, node.connector, timedelta), params
3 changes: 3 additions & 0 deletions docs/releases/1.3.txt
Expand Up @@ -235,6 +235,9 @@ requests. These include:
providing a :class:`~django.template.RequestContext` by providing a :class:`~django.template.RequestContext` by
default. default.


* Support for combining :ref:`F() expressions <query-expressions>`
with timedelta values when retrieving or updating database values.

.. _HTTPOnly: http://www.owasp.org/index.php/HTTPOnly .. _HTTPOnly: http://www.owasp.org/index.php/HTTPOnly


.. _backwards-incompatible-changes-1.3: .. _backwards-incompatible-changes-1.3:
Expand Down
12 changes: 11 additions & 1 deletion docs/topics/db/queries.txt
Expand Up @@ -36,6 +36,7 @@ models, which comprise a Weblog application:
headline = models.CharField(max_length=255) headline = models.CharField(max_length=255)
body_text = models.TextField() body_text = models.TextField()
pub_date = models.DateTimeField() pub_date = models.DateTimeField()
mod_date = models.DateTimeField()
authors = models.ManyToManyField(Author) authors = models.ManyToManyField(Author)
n_comments = models.IntegerField() n_comments = models.IntegerField()
n_pingbacks = models.IntegerField() n_pingbacks = models.IntegerField()
Expand Down Expand Up @@ -566,10 +567,19 @@ You can also use the double underscore notation to span relationships in
an ``F()`` object. An ``F()`` object with a double underscore will introduce an ``F()`` object. An ``F()`` object with a double underscore will introduce
any joins needed to access the related object. For example, to retrieve all any joins needed to access the related object. For example, to retrieve all
the entries where the author's name is the same as the blog name, we could the entries where the author's name is the same as the blog name, we could
issue the query: issue the query::


>>> Entry.objects.filter(authors__name=F('blog__name')) >>> Entry.objects.filter(authors__name=F('blog__name'))


.. versionadded:: 1.3

For date and date/time fields, you can add or subtract a ``datetime.timedelta``
object. The following would return all entries that were modified more than 3 days
after they were published::

>>> from datetime import timedelta
>>> Entry.objects.filter(mod_date__gt=F('pub_date') + timedelta(days=3))

The pk lookup shortcut The pk lookup shortcut
---------------------- ----------------------


Expand Down
13 changes: 13 additions & 0 deletions tests/regressiontests/expressions_regress/models.py
Expand Up @@ -10,3 +10,16 @@ class Number(models.Model):
def __unicode__(self): def __unicode__(self):
return u'%i, %.3f' % (self.integer, self.float) return u'%i, %.3f' % (self.integer, self.float)


class Experiment(models.Model):
name = models.CharField(max_length=24)
assigned = models.DateField()
completed = models.DateField()
start = models.DateTimeField()
end = models.DateTimeField()

class Meta:
ordering = ('name',)

def duration(self):
return self.end - self.start

0 comments on commit b1f6a4d

Please sign in to comment.