Fixed #24767 -- Added Greatest and Least expressions

Greatest and Least are row-level Function versions of Min and Max.
This commit is contained in:
Ian Foote 2015-05-09 12:55:03 +01:00 committed by Marc Tamlyn
parent fe21fb810a
commit 4ab53a558a
7 changed files with 326 additions and 3 deletions

View File

@ -208,6 +208,10 @@ class BaseDatabaseFeatures(object):
# Does the backend support "select for update" queries with limit (and offset)? # Does the backend support "select for update" queries with limit (and offset)?
supports_select_for_update_with_limit = True supports_select_for_update_with_limit = True
# Does the backend ignore null expressions in GREATEST and LEAST queries unless
# every expression is null?
greatest_least_ignores_nulls = False
def __init__(self, connection): def __init__(self, connection):
self.connection = connection self.connection = connection

View File

@ -27,3 +27,4 @@ class DatabaseFeatures(BaseDatabaseFeatures):
closed_cursor_error_class = InterfaceError closed_cursor_error_class = InterfaceError
has_case_insensitive_like = False has_case_insensitive_like = False
requires_sqlparse_for_splitting = False requires_sqlparse_for_splitting = False
greatest_least_ignores_nulls = True

View File

@ -83,6 +83,48 @@ class Concat(Func):
return ConcatPair(expressions[0], self._paired(expressions[1:])) return ConcatPair(expressions[0], self._paired(expressions[1:]))
class Greatest(Func):
"""
Chooses the maximum expression and returns it.
If any expression is null the return value is database-specific:
On Postgres, the maximum not-null expression is returned.
On MySQL, Oracle and SQLite, if any expression is null, null is
returned.
"""
function = 'GREATEST'
def __init__(self, *expressions, **extra):
if len(expressions) < 2:
raise ValueError('Greatest must take at least two expressions')
super(Greatest, self).__init__(*expressions, **extra)
def as_sqlite(self, compiler, connection):
"""Use the MAX function on SQLite."""
return super(Greatest, self).as_sql(compiler, connection, function='MAX')
class Least(Func):
"""
Chooses the minimum expression and returns it.
If any expression is null the return value is database-specific:
On Postgres, the minimum not-null expression is returned.
On MySQL, Oracle and SQLite, if any expression is null, null is
returned.
"""
function = 'LEAST'
def __init__(self, *expressions, **extra):
if len(expressions) < 2:
raise ValueError('Least must take at least two expressions')
super(Least, self).__init__(*expressions, **extra)
def as_sqlite(self, compiler, connection):
"""Use the MIN function on SQLite."""
return super(Least, self).as_sql(compiler, connection, function='MIN')
class Length(Func): class Length(Func):
"""Returns the number of characters in the expression""" """Returns the number of characters in the expression"""
function = 'LENGTH' function = 'LENGTH'

View File

@ -82,6 +82,74 @@ Usage example::
>>> print(author.screen_name) >>> print(author.screen_name)
Margaret Smith (Maggie) Margaret Smith (Maggie)
Greatest
--------
.. versionadded:: 1.9
.. class:: Greatest(*expressions, **extra)
Accepts a list of at least two field names or expressions and returns the
greatest value. Each argument must be of a similar type, so mixing text and numbers
will result in a database error.
Usage example::
class Blog(models.Model):
body = models.TextField()
modified = models.DateTimeField(auto_now=True)
class Comment(models.Model):
body = models.TextField()
modified = models.DateTimeField(auto_now=True)
blog = models.ForeignKey(Blog)
>>> from django.db.models.functions import Greatest
>>> blog = Blog.objects.create(body='Greatest is the best.')
>>> comment = Comment.objects.create(body='No, Least is better.', blog=blog)
>>> comments = Comment.objects.annotate(last_updated=Greatest('modified', 'blog__modified'))
>>> annotated_comment = comments.get()
``annotated_comment.last_updated`` will be the most recent of
``blog.modified`` and ``comment.modified``.
.. warning::
The behavior of ``Greatest`` when one or more expression may be ``null``
varies between databases:
- PostgreSQL: ``Greatest`` will return the largest non-null expression,
or ``null`` if all expressions are ``null``.
- SQLite, Oracle and MySQL: If any expression is ``null``, ``Greatest``
will return ``null``.
The PostgreSQL behavior can be emulated using ``Coalesce`` if you know
a sensible minimum value to provide as a default.
Least
--------
.. versionadded:: 1.9
.. class:: Least(*expressions, **extra)
Accepts a list of at least two field names or expressions and returns the
least value. Each argument must be of a similar type, so mixing text and numbers
will result in a database error.
.. warning::
The behavior of ``Least`` when one or more expression may be ``null``
varies between databases:
- PostgreSQL: ``Least`` will return the smallest non-null expression,
or ``null`` if all expressions are ``null``.
- SQLite, Oracle and MySQL: If any expression is ``null``, ``Least``
will return ``null``.
The PostgreSQL behavior can be emulated using ``Coalesce`` if you know
a sensible maximum value to provide as a default.
Length Length
------ ------

View File

@ -256,6 +256,9 @@ Models
* Added the :lookup:`date` lookup to :class:`~django.db.models.DateTimeField` * Added the :lookup:`date` lookup to :class:`~django.db.models.DateTimeField`
to allow querying the field by only the date portion. to allow querying the field by only the date portion.
* Added the :class:`~django.db.models.functions.Greatest` and
:class:`~django.db.models.functions.Least` database functions.
* Added the :class:`~django.db.models.functions.Now` database function, which * Added the :class:`~django.db.models.functions.Now` database function, which
returns the current date and time. returns the current date and time.

View File

@ -12,6 +12,7 @@ class Author(models.Model):
name = models.CharField(max_length=50) name = models.CharField(max_length=50)
alias = models.CharField(max_length=50, null=True, blank=True) alias = models.CharField(max_length=50, null=True, blank=True)
goes_by = models.CharField(max_length=50, null=True, blank=True) goes_by = models.CharField(max_length=50, null=True, blank=True)
age = models.PositiveSmallIntegerField(default=30)
def __str__(self): def __str__(self):
return self.name return self.name
@ -25,7 +26,18 @@ class Article(models.Model):
text = models.TextField() text = models.TextField()
written = models.DateTimeField() written = models.DateTimeField()
published = models.DateTimeField(null=True, blank=True) published = models.DateTimeField(null=True, blank=True)
updated = models.DateTimeField(null=True, blank=True)
views = models.PositiveIntegerField(default=0) views = models.PositiveIntegerField(default=0)
def __str__(self): def __str__(self):
return self.title return self.title
@python_2_unicode_compatible
class Fan(models.Model):
name = models.CharField(max_length=50)
age = models.PositiveSmallIntegerField(default=30)
author = models.ForeignKey(Author, related_name='fans')
def __str__(self):
return self.name

View File

@ -1,15 +1,18 @@
from __future__ import unicode_literals from __future__ import unicode_literals
from datetime import datetime, timedelta from datetime import datetime, timedelta
from unittest import skipIf, skipUnless
from django.db import connection
from django.db.models import CharField, TextField, Value as V from django.db.models import CharField, TextField, Value as V
from django.db.models.expressions import RawSQL
from django.db.models.functions import ( from django.db.models.functions import (
Coalesce, Concat, Length, Lower, Now, Substr, Upper, Coalesce, Concat, Greatest, Least, Length, Lower, Now, Substr, Upper,
) )
from django.test import TestCase from django.test import TestCase, skipIfDBFeature, skipUnlessDBFeature
from django.utils import six, timezone from django.utils import six, timezone
from .models import Article, Author from .models import Article, Author, Fan
lorem_ipsum = """ lorem_ipsum = """
@ -101,6 +104,196 @@ class FunctionTests(TestCase):
lambda a: a.name lambda a: a.name
) )
def test_greatest(self):
now = timezone.now()
before = now - timedelta(hours=1)
Article.objects.create(
title="Testing with Django",
written=before,
published=now,
)
articles = Article.objects.annotate(
last_updated=Greatest('written', 'published'),
)
self.assertEqual(articles.first().last_updated, now)
@skipUnlessDBFeature('greatest_least_ignores_nulls')
def test_greatest_ignores_null(self):
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
last_updated=Greatest('written', 'published'),
)
self.assertEqual(articles.first().last_updated, now)
@skipIfDBFeature('greatest_least_ignores_nulls')
def test_greatest_propogates_null(self):
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
last_updated=Greatest('written', 'published'),
)
self.assertIsNone(articles.first().last_updated)
@skipIf(connection.vendor == 'mysql', "This doesn't work on MySQL")
def test_greatest_coalesce_workaround(self):
past = datetime(1900, 1, 1)
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
last_updated=Greatest(
Coalesce('written', past),
Coalesce('published', past),
),
)
self.assertEqual(articles.first().last_updated, now)
@skipUnless(connection.vendor == 'mysql', "MySQL-specific workaround")
def test_greatest_coalesce_workaround_mysql(self):
past = datetime(1900, 1, 1)
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
past_sql = RawSQL("cast(%s as datetime)", (past,))
articles = Article.objects.annotate(
last_updated=Greatest(
Coalesce('written', past_sql),
Coalesce('published', past_sql),
),
)
self.assertEqual(articles.first().last_updated, now)
def test_greatest_all_null(self):
Article.objects.create(title="Testing with Django", written=timezone.now())
articles = Article.objects.annotate(last_updated=Greatest('published', 'updated'))
self.assertIsNone(articles.first().last_updated)
def test_greatest_one_expressions(self):
with self.assertRaisesMessage(ValueError, 'Greatest must take at least two expressions'):
Greatest('written')
def test_greatest_related_field(self):
author = Author.objects.create(name='John Smith', age=45)
Fan.objects.create(name='Margaret', age=50, author=author)
authors = Author.objects.annotate(
highest_age=Greatest('age', 'fans__age'),
)
self.assertEqual(authors.first().highest_age, 50)
def test_greatest_update(self):
author = Author.objects.create(name='James Smith', goes_by='Jim')
Author.objects.update(alias=Greatest('name', 'goes_by'))
author.refresh_from_db()
self.assertEqual(author.alias, 'Jim')
def test_least(self):
now = timezone.now()
before = now - timedelta(hours=1)
Article.objects.create(
title="Testing with Django",
written=before,
published=now,
)
articles = Article.objects.annotate(
first_updated=Least('written', 'published'),
)
self.assertEqual(articles.first().first_updated, before)
@skipUnlessDBFeature('greatest_least_ignores_nulls')
def test_least_ignores_null(self):
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
first_updated=Least('written', 'published'),
)
self.assertEqual(articles.first().first_updated, now)
@skipIfDBFeature('greatest_least_ignores_nulls')
def test_least_propogates_null(self):
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
first_updated=Least('written', 'published'),
)
self.assertIsNone(articles.first().first_updated)
@skipIf(connection.vendor == 'mysql', "This doesn't work on MySQL")
def test_least_coalesce_workaround(self):
future = datetime(2100, 1, 1)
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
articles = Article.objects.annotate(
last_updated=Least(
Coalesce('written', future),
Coalesce('published', future),
),
)
self.assertEqual(articles.first().last_updated, now)
@skipUnless(connection.vendor == 'mysql', "MySQL-specific workaround")
def test_least_coalesce_workaround_mysql(self):
future = datetime(2100, 1, 1)
now = timezone.now()
Article.objects.create(title="Testing with Django", written=now)
future_sql = RawSQL("cast(%s as datetime)", (future,))
articles = Article.objects.annotate(
last_updated=Least(
Coalesce('written', future_sql),
Coalesce('published', future_sql),
),
)
self.assertEqual(articles.first().last_updated, now)
def test_least_all_null(self):
Article.objects.create(title="Testing with Django", written=timezone.now())
articles = Article.objects.annotate(first_updated=Least('published', 'updated'))
self.assertIsNone(articles.first().first_updated)
def test_least_one_expressions(self):
with self.assertRaisesMessage(ValueError, 'Least must take at least two expressions'):
Least('written')
def test_least_related_field(self):
author = Author.objects.create(name='John Smith', age=45)
Fan.objects.create(name='Margaret', age=50, author=author)
authors = Author.objects.annotate(
lowest_age=Least('age', 'fans__age'),
)
self.assertEqual(authors.first().lowest_age, 45)
def test_least_update(self):
author = Author.objects.create(name='James Smith', goes_by='Jim')
Author.objects.update(alias=Least('name', 'goes_by'))
author.refresh_from_db()
self.assertEqual(author.alias, 'James Smith')
def test_concat(self): def test_concat(self):
Author.objects.create(name='Jayden') Author.objects.create(name='Jayden')
Author.objects.create(name='John Smith', alias='smithj', goes_by='John') Author.objects.create(name='John Smith', alias='smithj', goes_by='John')