Ticket #10154: 10154_dateexpressions_4.diff

File 10154_dateexpressions_4.diff, 11.4 KB (added by Charlie DeTar, 15 years ago)

Updated for R12380. Support for mysql, postgres, sqlite, oracle. Includes tests and docs.

  • django/db/models/expressions.py

     
    1 from datetime import datetime
     1import datetime
    22
    33from django.utils import tree
    44from django.utils.copycompat import deepcopy
     
    2626        super(ExpressionNode, self).__init__(children, connector, negated)
    2727
    2828    def _combine(self, other, connector, reversed, node=None):
     29        if isinstance(other, datetime.timedelta):
     30            return DateModifierNode([self, other], connector)
     31
    2932        if reversed:
    3033            obj = ExpressionNode([other], connector)
    3134            obj.add(node or self, connector)
     
    111114
    112115    def evaluate(self, evaluator, qn, connection):
    113116        return evaluator.evaluate_leaf(self, qn, connection)
     117
     118class DateModifierNode(ExpressionNode):
     119    """
     120    Node that implements the following syntax:
     121    filter(end_date__gt=F('start_date') + datetime.timedelta(days=3, seconds=200))
     122
     123    which translates into:
     124    SQLITE:
     125        WHERE end_date > DATE(start_date, "+3 days", "+200 seconds")
     126
     127    POSTGRES:
     128        WHERE end_date > (start_date + INTERVAL '3 days 200 seconds')
     129
     130    MYSQL:
     131        WHERE end_date > (start_date + INTERVAL '3 0:0:200:0' DAY_MICROSECOND)
     132
     133    ORACLE:
     134        WHERE end_date > (start_date + INTERVAL '3 00:03:20.000000' DAY(1) TO SECOND(6))
     135
     136    Note that microsecond comparisons are not well supported with sqlite or
     137    mysql.
     138    """
     139    def __init__(self, children, connector, negated=False):
     140        if len(children) != 2:
     141            raise TypeError('Must specify a node and a timedelta.')
     142        if not isinstance(children[1], datetime.timedelta):
     143            raise TypeError('Second child must be a timedelta.')
     144        if connector is None:
     145            raise TypeError('Must specify a connector.')
     146        super(DateModifierNode, self).__init__(children, connector, negated)
     147
     148    def evaluate(self, evaluator, qn, connection):
     149        timedelta = self.children.pop()
     150        sql, params = evaluator.evaluate_node(self, qn, connection)
     151
     152        if timedelta.days == 0 and timedelta.seconds == 0 and \
     153                timedelta.microseconds == 0:
     154            return sql, params
     155
     156        return connection.ops.date_interval_sql(sql, self.connector, timedelta), params
  • django/db/backends/postgresql/operations.py

     
    2727        else:
    2828            return "EXTRACT('%s' FROM %s)" % (lookup_type, field_name)
    2929
     30    def date_interval_sql(self, sql, connector, timedelta):
     31        """
     32        implements the interval functionality for expressions
     33        format for Postgres:
     34            (datefield + interval '3 days 200 seconds 5 microseconds')
     35        """
     36        modifiers = []
     37        if timedelta.days:
     38            modifiers.append(u'%s days' % timedelta.days)
     39        if timedelta.seconds:
     40            modifiers.append(u'%s seconds' % timedelta.seconds)
     41        if timedelta.microseconds:
     42            modifiers.append(u'%s microseconds' % timedelta.microseconds)
     43        mods = u' '.join(modifiers)
     44        conn = u' %s ' % connector
     45        return u'(%s)' % conn.join([sql, u'interval \'%s\'' % mods])
     46
    3047    def date_trunc_sql(self, lookup_type, field_name):
    3148        # http://www.postgresql.org/docs/8.0/static/functions-datetime.html#FUNCTIONS-DATETIME-TRUNC
    3249        return "DATE_TRUNC('%s', %s)" % (lookup_type, field_name)
  • django/db/backends/sqlite3/base.py

     
    6666        # function django_extract that's registered in connect().
    6767        return 'django_extract("%s", %s)' % (lookup_type.lower(), field_name)
    6868
     69    def date_interval_sql(self, sql, connector, timedelta):
     70        """
     71        Implements the interval functionality for expressions
     72        format for sqlite: DATETIME(datefield, "+3 days", "+200 seconds")
     73        """
     74        modifiers = []
     75        if timedelta.days:
     76            modifiers.append(u'%s days' % timedelta.days)
     77        if timedelta.seconds:
     78            fs = timedelta.seconds + (timedelta.microseconds / 1000000.)
     79            modifiers.append(u'%s seconds' % fs)
     80        mods = u','.join([u'"%s%s"' % (connector, modifier) for modifier in modifiers])
     81        return u'DATETIME(%s, %s)' % (sql, mods)
     82
    6983    def date_trunc_sql(self, lookup_type, field_name):
    7084        # sqlite doesn't support DATE_TRUNC, so we fake it with a user-defined
    7185        # function django_date_trunc that's registered in connect().
  • django/db/backends/mysql/base.py

     
    147147            sql = "CAST(DATE_FORMAT(%s, '%s') AS DATETIME)" % (field_name, format_str)
    148148        return sql
    149149
     150    def date_interval_sql(self, sql, connector, timedelta):
     151        return "(%s %s INTERVAL '%d 0:0:%d:%d' DAY_MICROSECOND)" % (sql, connector,
     152                timedelta.days, timedelta.seconds, timedelta.microseconds)
     153
    150154    def drop_foreignkey_sql(self):
    151155        return "DROP FOREIGN KEY"
    152156
  • django/db/backends/oracle/base.py

     
    9595        else:
    9696            return "EXTRACT(%s FROM %s)" % (lookup_type, field_name)
    9797
     98    def date_interval_sql(self, sql, connector, timedelta):
     99        """
     100        Implements the interval functionality for expressions
     101        format for Oracle:
     102        (datefield + INTERVAL '3 00:03:20.000000' DAY(1) TO SECOND(6))
     103        """
     104        minutes, seconds = divmod(timedelta.seconds, 60)
     105        hours, minutes = divmod(minutes, 60)
     106        days = str(timedelta.days)
     107        day_precision = len(days)
     108        fmt = "(%s %s INTERVAL '%s %02d:%02d:%02d.%06d' DAY(%d) TO SECOND(6))"
     109        return fmt % (sql, connector, days, hours, minutes, seconds,
     110                timedelta.microseconds, day_precision)
     111
    98112    def date_trunc_sql(self, lookup_type, field_name):
    99113        # Oracle uses TRUNC() for both dates and numbers.
    100114        # http://download-east.oracle.com/docs/cd/B10501_01/server.920/a96540/functions155a.htm#SQLRF06151
  • django/db/backends/__init__.py

     
    123123        """
    124124        raise NotImplementedError()
    125125
     126    def date_interval_sql(self, sql, connector, timedelta):
     127        """
     128        Implements the date interval functionality for expressions
     129        """
     130        raise NotImplementedError()
     131
    126132    def date_trunc_sql(self, lookup_type, field_name):
    127133        """
    128134        Given a lookup_type of 'year', 'month' or 'day', returns the SQL that
  • tests/modeltests/expressions/models.py

     
    77class Employee(models.Model):
    88    firstname = models.CharField(max_length=50)
    99    lastname = models.CharField(max_length=50)
     10    contract_date = models.DateTimeField(null=True)
     11    start_date = models.DateTimeField(null=True)
    1012
    1113    def __unicode__(self):
    1214        return u'%s %s' % (self.firstname, self.lastname)
     
    2931
    3032__test__ = {'API_TESTS': """
    3133>>> from django.db.models import F
     34>>> import datetime
    3235
    3336>>> Company(name='Example Inc.', num_employees=2300, num_chairs=5,
    34 ...     ceo=Employee.objects.create(firstname='Joe', lastname='Smith')).save()
     37...     ceo=Employee.objects.create(firstname='Joe', lastname='Smith',
     38...             contract_date=datetime.datetime(2008,1,1),
     39...             start_date=datetime.datetime(2008,3,1))).save()
    3540>>> Company(name='Foobar Ltd.', num_employees=3, num_chairs=3,
    36 ...     ceo=Employee.objects.create(firstname='Frank', lastname='Meyer')).save()
     41...     ceo=Employee.objects.create(firstname='Frank', lastname='Meyer',
     42...             contract_date=datetime.datetime(2008,1,1),
     43...             start_date=datetime.datetime(2008,5,1))).save()
    3744>>> Company(name='Test GmbH', num_employees=32, num_chairs=1,
    38 ...     ceo=Employee.objects.create(firstname='Max', lastname='Mustermann')).save()
     45...     ceo=Employee.objects.create(firstname='Max', lastname='Mustermann',
     46...             contract_date=datetime.datetime(2008,1,1),
     47...             start_date=datetime.datetime(2008,7,1))).save()
    3948
    4049>>> company_query = Company.objects.values('name','num_employees','num_chairs').order_by('name','num_employees','num_chairs')
    4150
     
    5665>>> company_query
    5766[{'num_chairs': 2302, 'name': u'Example Inc.', 'num_employees': 2300}, {'num_chairs': 5, 'name': u'Foobar Ltd.', 'num_employees': 3}, {'num_chairs': 34, 'name': u'Test GmbH', 'num_employees': 32}]
    5867
     68# F expressions for dates may be combined with timedelta
     69# in filter:
     70>>> Employee.objects.filter(start_date__gt=F('contract_date')+datetime.timedelta(days=80))
     71[<Employee: Frank Meyer>, <Employee: Max Mustermann>]
     72
     73>>> Employee.objects.filter(contract_date__gt=F('start_date')-datetime.timedelta(days=80))
     74[<Employee: Joe Smith>]
     75
     76>>> Employee.objects.filter(start_date__gt=F('contract_date')+datetime.timedelta(days=80)+datetime.timedelta(seconds=500))
     77[<Employee: Frank Meyer>, <Employee: Max Mustermann>]
     78
     79# in update:
     80# move contract dates to 14 days before start date
     81>>> Employee.objects.update(contract_date=F('start_date') - datetime.timedelta(days=14))
     823
     83>>> [e.contract_date for e in Employee.objects.all()]
     84[datetime.datetime(2008, 2, 16, 0, 0), datetime.datetime(2008, 4, 17, 0, 0), datetime.datetime(2008, 6, 17, 0, 0)]
     85
     86# Zero timedeltas:
     87>>> Employee.objects.filter(start_date__gt=F('contract_date') + datetime.timedelta(days=0))
     88[<Employee: Joe Smith>, <Employee: Frank Meyer>, <Employee: Max Mustermann>]
     89
    5990# Law of order of operations is followed
    6091>>> _ =company_query.update(num_chairs=F('num_employees') + 2 * F('num_employees'))
    6192>>> company_query
  • docs/topics/db/queries.txt

     
    3838        headline = models.CharField(max_length=255)
    3939        body_text = models.TextField()
    4040        pub_date = models.DateTimeField()
     41        mod_date = models.DateTimeField()
    4142        authors = models.ManyToManyField(Author)
    4243        n_comments = models.IntegerField()
    4344        n_pingbacks = models.IntegerField()
     
    534535
    535536    >>> Entry.objects.filter(author__name=F('blog__name'))
    536537
     538For date fields, you can add or subtract a ``datetime.timedelta`` object.  The
     539following would return all entries that were modified more than 3 days after
     540they were published:
     541   
     542    >>> from datetime import timedelta
     543    >>> Entry.objects.filter(mod_date__gt=F('pub_date') + timedelta(days=3))
     544
    537545The pk lookup shortcut
    538546----------------------
    539547
Back to Top