Skip to content

Commit

Permalink
Refs #25774, #26348 -- Allowed Trunc functions to operate with time f…
Browse files Browse the repository at this point in the history
…ields.

Thanks Josh for the amazing testing setup and Tim for the review.
  • Loading branch information
charettes committed Jul 8, 2016
1 parent 9046807 commit 082c52d
Show file tree
Hide file tree
Showing 11 changed files with 245 additions and 35 deletions.
8 changes: 8 additions & 0 deletions django/db/backends/base/operations.py
Expand Up @@ -113,6 +113,14 @@ def datetime_trunc_sql(self, lookup_type, field_name, tzname):
"""
raise NotImplementedError('subclasses of BaseDatabaseOperations may require a datetime_trunk_sql() method')

def time_trunc_sql(self, lookup_type, field_name):
"""
Given a lookup_type of 'hour', 'minute' or 'second', returns the SQL
that truncates the given time field field_name to a time object with
only the given specificity.
"""
raise NotImplementedError('subclasses of BaseDatabaseOperations may require a time_trunc_sql() method')

def time_extract_sql(self, lookup_type, field_name):
"""
Given a lookup_type of 'hour', 'minute' or 'second', returns the SQL
Expand Down
12 changes: 12 additions & 0 deletions django/db/backends/mysql/operations.py
Expand Up @@ -70,6 +70,18 @@ def datetime_trunc_sql(self, lookup_type, field_name, tzname):
sql = "CAST(DATE_FORMAT(%s, '%s') AS DATETIME)" % (field_name, format_str)
return sql, params

def time_trunc_sql(self, lookup_type, field_name):
fields = {
'hour': '%%H:00:00',
'minute': '%%H:%%i:00',
'second': '%%H:%%i:%%s',
} # Use double percents to escape.
if lookup_type in fields:
format_str = fields[lookup_type]
return "CAST(DATE_FORMAT(%s, '%s') AS TIME)" % (field_name, format_str)
else:
return "TIME(%s)" % (field_name)

def date_interval_sql(self, timedelta):
return "INTERVAL '%d 0:0:%d:%d' DAY_MICROSECOND" % (
timedelta.days, timedelta.seconds, timedelta.microseconds), []
Expand Down
12 changes: 12 additions & 0 deletions django/db/backends/oracle/operations.py
Expand Up @@ -148,6 +148,18 @@ def datetime_trunc_sql(self, lookup_type, field_name, tzname):
sql = "CAST(%s AS DATE)" % field_name # Cast to DATE removes sub-second precision.
return sql, []

def time_trunc_sql(self, lookup_type, field_name):
# The implementation is similar to `datetime_trunc_sql` as both
# `DateTimeField` and `TimeField` are stored as TIMESTAMP where
# the date part of the later is ignored.
if lookup_type == 'hour':
sql = "TRUNC(%s, 'HH24')" % field_name
elif lookup_type == 'minute':
sql = "TRUNC(%s, 'MI')" % field_name
elif lookup_type == 'second':
sql = "CAST(%s AS DATE)" % field_name # Cast to DATE removes sub-second precision.
return sql

def get_db_converters(self, expression):
converters = super(DatabaseOperations, self).get_db_converters(expression)
internal_type = expression.output_field.get_internal_type()
Expand Down
3 changes: 3 additions & 0 deletions django/db/backends/postgresql/operations.py
Expand Up @@ -56,6 +56,9 @@ def datetime_trunc_sql(self, lookup_type, field_name, tzname):
sql = "DATE_TRUNC('%s', %s)" % (lookup_type, field_name)
return sql, params

def time_trunc_sql(self, lookup_type, field_name):
return "DATE_TRUNC('%s', %s)::time" % (lookup_type, field_name)

def deferrable_sql(self):
return " DEFERRABLE INITIALLY DEFERRED"

Expand Down
14 changes: 14 additions & 0 deletions django/db/backends/sqlite3/base.py
Expand Up @@ -213,6 +213,7 @@ def get_new_connection(self, conn_params):
conn.create_function("django_datetime_extract", 3, _sqlite_datetime_extract)
conn.create_function("django_datetime_trunc", 3, _sqlite_datetime_trunc)
conn.create_function("django_time_extract", 2, _sqlite_time_extract)
conn.create_function("django_time_trunc", 2, _sqlite_time_trunc)
conn.create_function("django_time_diff", 2, _sqlite_time_diff)
conn.create_function("django_timestamp_diff", 2, _sqlite_timestamp_diff)
conn.create_function("regexp", 2, _sqlite_regexp)
Expand Down Expand Up @@ -370,6 +371,19 @@ def _sqlite_date_trunc(lookup_type, dt):
return "%i-%02i-%02i" % (dt.year, dt.month, dt.day)


def _sqlite_time_trunc(lookup_type, dt):
try:
dt = backend_utils.typecast_time(dt)
except (ValueError, TypeError):
return None
if lookup_type == 'hour':
return "%02i:00:00" % dt.hour
elif lookup_type == 'minute':
return "%02i:%02i:00" % (dt.hour, dt.minute)
elif lookup_type == 'second':
return "%02i:%02i:%02i" % (dt.hour, dt.minute, dt.second)


def _sqlite_datetime_parse(dt, tzname):
if dt is None:
return None
Expand Down
7 changes: 7 additions & 0 deletions django/db/backends/sqlite3/operations.py
Expand Up @@ -70,6 +70,13 @@ def date_trunc_sql(self, lookup_type, field_name):
# cause a collision with a field name).
return "django_date_trunc('%s', %s)" % (lookup_type.lower(), field_name)

def time_trunc_sql(self, lookup_type, field_name):
# 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
# single quotes are used because this is a string (and could otherwise
# cause a collision with a field name).
return "django_time_trunc('%s', %s)" % (lookup_type.lower(), field_name)

def _require_pytz(self):
if settings.USE_TZ and pytz is None:
raise ImproperlyConfigured("This query requires pytz, but it isn't installed.")
Expand Down
49 changes: 26 additions & 23 deletions django/db/models/functions/datetime.py
Expand Up @@ -151,26 +151,38 @@ def as_sql(self, compiler, connection):
elif isinstance(self.output_field, DateField):
sql = connection.ops.date_trunc_sql(self.kind, inner_sql)
params = []
elif isinstance(self.output_field, TimeField):
sql = connection.ops.time_trunc_sql(self.kind, inner_sql)
params = []
else:
raise ValueError('Trunc only valid on DateField or DateTimeField.')
raise ValueError('Trunc only valid on DateField, TimeField, or DateTimeField.')
return sql, inner_params + params

def resolve_expression(self, query=None, allow_joins=True, reuse=None, summarize=False, for_save=False):
copy = super(TruncBase, self).resolve_expression(query, allow_joins, reuse, summarize, for_save)
field = copy.lhs.output_field
# DateTimeField is a subclass of DateField so this works for both.
assert isinstance(field, DateField), (
"%r isn't a DateField or DateTimeField." % field.name
assert isinstance(field, (DateField, TimeField)), (
"%r isn't a DateField, TimeField, or DateTimeField." % field.name
)
# If self.output_field was None, then accessing the field will trigger
# the resolver to assign it to self.lhs.output_field.
if not isinstance(copy.output_field, (DateField, DateTimeField)):
raise ValueError('output_field must be either DateField or DateTimeField')
# Passing dates to functions expecting datetimes is most likely a
# mistake.
if not isinstance(copy.output_field, (DateField, DateTimeField, TimeField)):
raise ValueError('output_field must be either DateField, TimeField, or DateTimeField')
# Passing dates or times to functions expecting datetimes is most
# likely a mistake.
output_field = copy.output_field
explicit_output_field = field.__class__ != copy.output_field.__class__
if type(field) == DateField and (
isinstance(copy.output_field, DateTimeField) or copy.kind in ('hour', 'minute', 'second')):
raise ValueError("Cannot truncate DateField '%s' to DateTimeField. " % field.name)
isinstance(output_field, DateTimeField) or copy.kind in ('hour', 'minute', 'second', 'time')):
raise ValueError("Cannot truncate DateField '%s' to %s. " % (
field.name, output_field.__class__.__name__ if explicit_output_field else 'DateTimeField'
))
elif isinstance(field, TimeField) and (
isinstance(output_field, DateTimeField) or copy.kind in ('year', 'month', 'day', 'date')):
raise ValueError("Cannot truncate TimeField '%s' to %s. " % (
field.name, output_field.__class__.__name__ if explicit_output_field else 'DateTimeField'
))
return copy

def convert_value(self, value, expression, connection, context):
Expand All @@ -184,8 +196,10 @@ def convert_value(self, value, expression, connection, context):
value = value.replace(tzinfo=None)
value = timezone.make_aware(value, self.tzinfo)
elif isinstance(value, datetime):
# self.output_field is definitely a DateField here.
value = value.date()
if isinstance(self.output_field, DateField):
value = value.date()
elif isinstance(self.output_field, TimeField):
value = value.time()
return value


Expand All @@ -209,6 +223,7 @@ class TruncDay(TruncBase):


class TruncDate(TruncBase):
kind = 'date'
lookup_name = 'date'

@cached_property
Expand All @@ -227,25 +242,13 @@ def as_sql(self, compiler, connection):
class TruncHour(TruncBase):
kind = 'hour'

@cached_property
def output_field(self):
return DateTimeField()


class TruncMinute(TruncBase):
kind = 'minute'

@cached_property
def output_field(self):
return DateTimeField()


class TruncSecond(TruncBase):
kind = 'second'

@cached_property
def output_field(self):
return DateTimeField()


DateTimeField.register_lookup(TruncDate)
72 changes: 65 additions & 7 deletions docs/ref/models/database-functions.txt
Expand Up @@ -288,8 +288,10 @@ We'll be using the following model in examples of each function::
class Experiment(models.Model):
start_datetime = models.DateTimeField()
start_date = models.DateField(null=True, blank=True)
start_time = models.TimeField(null=True, blank=True)
end_datetime = models.DateTimeField(null=True, blank=True)
end_date = models.DateField(null=True, blank=True)
end_time = models.TimeField(null=True, blank=True)

``Extract``
-----------
Expand Down Expand Up @@ -500,13 +502,14 @@ but not the exact second, then ``Trunc`` (and its subclasses) can be useful to
filter or aggregate your data. For example, you can use ``Trunc`` to calculate
the number of sales per day.

``Trunc`` takes a single ``expression``, representing a ``DateField`` or
``DateTimeField``, a ``kind`` representing a date part, and an ``output_field``
that's either ``DateTimeField()`` or ``DateField()``. It returns a datetime or
date, depending on ``output_field``, with fields up to ``kind`` set to their
minimum value. If ``output_field`` is omitted, it will default to the
``output_field`` of ``expression``. A ``tzinfo`` subclass, usually provided by
``pytz``, can be passed to truncate a value in a specific timezone.
``Trunc`` takes a single ``expression``, representing a ``DateField``,
``TimeField``, or ``DateTimeField``, a ``kind`` representing a date or time
part, and an ``output_field`` that's either ``DateTimeField()``,
``TimeField()``, or ``DateField()``. It returns a datetime, date, or time
depending on ``output_field``, with fields up to ``kind`` set to their minimum
value. If ``output_field`` is omitted, it will default to the ``output_field``
of ``expression``. A ``tzinfo`` subclass, usually provided by ``pytz``, can be
passed to truncate a value in a specific timezone.

Given the datetime ``2015-06-15 14:30:50.000321+00:00``, the built-in ``kind``\s
return:
Expand Down Expand Up @@ -616,6 +619,61 @@ that deal with date-parts can be used with ``DateField``::
2016-01-01 00:00:00+11:00 1
2014-06-01 00:00:00+10:00 1

``TimeField`` truncation
~~~~~~~~~~~~~~~~~~~~~~~~

.. versionadded:: 1.11

.. class:: TruncHour(expression, output_field=None, tzinfo=None, **extra)

.. attribute:: kind = 'hour'

.. class:: TruncMinute(expression, output_field=None, tzinfo=None, **extra)

.. attribute:: kind = 'minute'

.. class:: TruncSecond(expression, output_field=None, tzinfo=None, **extra)

.. attribute:: kind = 'second'

These are logically equivalent to ``Trunc('time_field', kind)``. They truncate
all parts of the time up to ``kind`` which allows grouping or filtering times
with less precision. ``expression`` can have an ``output_field`` of either
``TimeField`` or ``DateTimeField``.

Since ``TimeField``\s don't have a date component, only ``Trunc`` subclasses
that deal with time-parts can be used with ``TimeField``::

>>> from datetime import datetime
>>> from django.db.models import Count, TimeField
>>> from django.db.models.functions import TruncHour
>>> from django.utils import timezone
>>> start1 = datetime(2014, 6, 15, 14, 30, 50, 321, tzinfo=timezone.utc)
>>> start2 = datetime(2014, 6, 15, 14, 40, 2, 123, tzinfo=timezone.utc)
>>> start3 = datetime(2015, 12, 31, 17, 5, 27, 999, tzinfo=timezone.utc)
>>> Experiment.objects.create(start_datetime=start1, start_time=start1.time())
>>> Experiment.objects.create(start_datetime=start2, start_time=start2.time())
>>> Experiment.objects.create(start_datetime=start3, start_time=start3.time())
>>> experiments_per_hour = Experiment.objects.annotate(
... hour=TruncHour('start_datetime', output_field=TimeField()),
... ).values('hour').annotate(experiments=Count('id'))
>>> for exp in experiments_per_hour:
... print(exp['hour'], exp['experiments'])
...
14:00:00 2
17:00:00 1

>>> import pytz
>>> melb = pytz.timezone('Australia/Melbourne')
>>> experiments_per_hour = Experiment.objects.annotate(
... hour=TruncHour('start_datetime', tzinfo=melb),
... ).values('hour').annotate(experiments=Count('id'))
>>> for exp in experiments_per_hour:
... print(exp['hour'], exp['experiments'])
...
2014-06-16 00:00:00+10:00 2
2016-01-01 04:00:00+11:00 1

``DateTimeField`` truncation
~~~~~~~~~~~~~~~~~~~~~~~~~~~~

Expand Down
10 changes: 9 additions & 1 deletion docs/releases/1.11.txt
Expand Up @@ -198,6 +198,9 @@ Models
* :class:`~django.db.models.ImageField` now has a default
:data:`~django.core.validators.validate_image_file_extension` validator.

* Added support for time truncation to
:class:`~django.db.models.functions.datetime.Trunc` functions.

Requests and Responses
~~~~~~~~~~~~~~~~~~~~~~

Expand Down Expand Up @@ -263,7 +266,12 @@ Backwards incompatible changes in 1.11
Database backend API
--------------------

* ...
* The ``DatabaseOperations.time_trunc_sql()`` method is added to support
``TimeField`` truncation. It accepts a ``lookup_type`` and ``field_name``
arguments and returns the appropriate SQL to truncate the given time field
``field_name`` to a time object with only the given specificity. The
``lookup_type`` argument can be either ``'hour'``, ``'minute'``, or
``'second'``.

Dropped support for PostgreSQL 9.2 and PostGIS 2.0
--------------------------------------------------
Expand Down

0 comments on commit 082c52d

Please sign in to comment.