Fixed #23753 -- Added a suite of SQL Functions

Added functions and tests
Added docs and more tests
Added TextField converter to mysql backend
Aliased Value as V in example docs and tests
Removed unicode_compatible in example
Fixed console emulation in examples
This commit is contained in:
Josh Smeaton 2014-11-22 14:14:43 +11:00
parent 7c07612e90
commit 4718296546
11 changed files with 550 additions and 3 deletions

View File

@ -396,6 +396,8 @@ class DatabaseOperations(BaseDatabaseOperations):
converters.append(self.convert_booleanfield_value) converters.append(self.convert_booleanfield_value)
if internal_type == 'UUIDField': if internal_type == 'UUIDField':
converters.append(self.convert_uuidfield_value) converters.append(self.convert_uuidfield_value)
if internal_type == 'TextField':
converters.append(self.convert_textfield_value)
return converters return converters
def convert_booleanfield_value(self, value, field): def convert_booleanfield_value(self, value, field):
@ -408,6 +410,11 @@ class DatabaseOperations(BaseDatabaseOperations):
value = uuid.UUID(value) value = uuid.UUID(value)
return value return value
def convert_textfield_value(self, value, field):
if value is not None:
value = force_text(value)
return value
class DatabaseWrapper(BaseDatabaseWrapper): class DatabaseWrapper(BaseDatabaseWrapper):
vendor = 'mysql' vendor = 'mysql'

View File

@ -0,0 +1,125 @@
"""
Classes that represent database functions.
"""
from django.db.models import IntegerField
from django.db.models.expressions import Func, Value
class Coalesce(Func):
"""
Chooses, from left to right, the first non-null expression and returns it.
"""
function = 'COALESCE'
def __init__(self, *expressions, **extra):
if len(expressions) < 2:
raise ValueError('Coalesce must take at least two expressions')
super(Coalesce, self).__init__(*expressions, **extra)
class ConcatPair(Func):
"""
A helper class that concatenates two arguments together. This is used
by `Concat` because not all backend databases support more than two
arguments.
"""
function = 'CONCAT'
def __init__(self, left, right, **extra):
super(ConcatPair, self).__init__(left, right, **extra)
def as_sqlite(self, compiler, connection):
self.arg_joiner = ' || '
self.template = '%(expressions)s'
self.coalesce()
return super(ConcatPair, self).as_sql(compiler, connection)
def as_mysql(self, compiler, connection):
self.coalesce()
return super(ConcatPair, self).as_sql(compiler, connection)
def coalesce(self):
# null on either side results in null for expression, wrap with coalesce
expressions = [
Coalesce(expression, Value('')) for expression in self.get_source_expressions()]
self.set_source_expressions(expressions)
class Concat(Func):
"""
Concatenates text fields together. Backends that result in an entire
null expression when any arguments are null will wrap each argument in
coalesce functions to ensure we always get a non-null result.
"""
function = None
template = "%(expressions)s"
def __init__(self, *expressions, **extra):
if len(expressions) < 2:
raise ValueError('Concat must take at least two expressions')
paired = self._paired(expressions)
super(Concat, self).__init__(paired, **extra)
def _paired(self, expressions):
# wrap pairs of expressions in successive concat functions
# exp = [a, b, c, d]
# -> ConcatPair(a, ConcatPair(b, ConcatPair(c, d))))
if len(expressions) == 2:
return ConcatPair(*expressions)
return ConcatPair(expressions[0], self._paired(expressions[1:]))
class Length(Func):
"""Returns the number of characters in the expression"""
function = 'LENGTH'
def __init__(self, expression, **extra):
output_field = extra.pop('output_field', IntegerField())
super(Length, self).__init__(expression, output_field=output_field, **extra)
def as_mysql(self, compiler, connection):
self.function = 'CHAR_LENGTH'
return super(Length, self).as_sql(compiler, connection)
class Lower(Func):
function = 'LOWER'
def __init__(self, expression, **extra):
super(Lower, self).__init__(expression, **extra)
class Substr(Func):
function = 'SUBSTRING'
def __init__(self, expression, pos, length=None, **extra):
"""
expression: the name of a field, or an expression returning a string
pos: an integer > 0, or an expression returning an integer
length: an optional number of characters to return
"""
if not hasattr('pos', 'resolve_expression'):
if pos < 1:
raise ValueError("'pos' must be greater than 0")
pos = Value(pos)
expressions = [expression, pos]
if length is not None:
if not hasattr('length', 'resolve_expression'):
length = Value(length)
expressions.append(length)
super(Substr, self).__init__(*expressions, **extra)
def as_sqlite(self, compiler, connection):
self.function = 'SUBSTR'
return super(Substr, self).as_sql(compiler, connection)
def as_oracle(self, compiler, connection):
self.function = 'SUBSTR'
return super(Substr, self).as_sql(compiler, connection)
class Upper(Func):
function = 'UPPER'
def __init__(self, expression, **extra):
super(Upper, self).__init__(expression, **extra)

View File

@ -87,7 +87,8 @@ manipulating the data of your Web application. Learn more about it below:
:doc:`Custom fields <howto/custom-model-fields>` | :doc:`Custom fields <howto/custom-model-fields>` |
:doc:`Multiple databases <topics/db/multi-db>` | :doc:`Multiple databases <topics/db/multi-db>` |
:doc:`Custom lookups <howto/custom-lookups>` | :doc:`Custom lookups <howto/custom-lookups>` |
:doc:`Query Expressions <ref/models/expressions>` :doc:`Query Expressions <ref/models/expressions>` |
:doc:`Database Functions <ref/models/database-functions>`
* **Other:** * **Other:**
:doc:`Supported databases <ref/databases>` | :doc:`Supported databases <ref/databases>` |

View File

@ -0,0 +1,153 @@
==================
Database Functions
==================
.. module:: django.db.models.functions
:synopsis: Database Functions
.. versionadded:: 1.8
The classes documented below provide a way for users to use functions provided
by the underlying database as annotations, aggregations, or filters in Django.
Functions are also :doc:`expressions <expressions>`, so they can be used and
combined with other expressions like :ref:`aggregate functions
<aggregation-functions>`.
We'll be using the following model in examples of each function::
class Author(models.Model):
name = models.CharField(max_length=50)
age = models.PositiveIntegerField(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)
We don't usually recommend allowing ``null=True`` for ``CharField`` since this
allows the field to have two "empty values", but it's important for the
``Coalesce`` example below.
Coalesce
--------
.. class:: Coalesce(*expressions, **extra)
Accepts a list of at least two field names or expressions and returns the
first non-null value (note that an empty string is not considered a null
value). Each argument must be of a similar type, so mixing text and numbers
will result in a database error.
Usage examples::
>>> # Get a screen name from least to most public
>>> from django.db.models import Sum, Value as V
>>> from django.db.models.functions import Coalesce
>>> Author.objects.create(name='Margaret Smith', goes_by='Maggie')
>>> author = Author.objects.annotate(
... screen_name=Coalesce('alias', 'goes_by', 'name')).get()
>>> print(author.screen_name)
Maggie
>>> # Prevent an aggregate Sum() from returning None
>>> aggregated = Author.objects.aggregate(
... combined_age=Coalesce(Sum('age'), V(0)),
... combined_age_default=Sum('age'))
>>> print(aggregated['combined_age'])
0
>>> print(aggregated['combined_age_default'])
None
Concat
------
.. class:: Concat(*expressions, **extra)
Accepts a list of at least two text fields or expressions and returns the
concatenated text. Each argument must be of a text or char type. If you want
to concatenate a ``TextField()`` with a ``CharField()``, then be sure to tell
Django that the ``output_field`` should be a ``TextField()``. This is also
required when concatenating a ``Value`` as in the example below.
This function will never have a null result. On backends where a null argument
results in the entire expression being null, Django will ensure that each null
part is converted to an empty string first.
Usage example::
>>> # Get the display name as "name (goes_by)"
>>> from django.db.models import CharField, Value as V
>>> from django.db.models.functions import Concat
>>> Author.objects.create(name='Margaret Smith', goes_by='Maggie')
>>> author = Author.objects.annotate(
... screen_name=Concat('name', V(' ('), 'goes_by', V(')'),
... output_field=CharField())).get()
>>> print(author.screen_name)
Margaret Smith (Maggie)
Length
------
.. class:: Length(expression, **extra)
Accepts a single text field or expression and returns the number of characters
the value has. If the expression is null, then the length will also be null.
Usage example::
>>> # Get the length of the name and goes_by fields
>>> from django.db.models.functions import Length
>>> Author.objects.create(name='Margaret Smith')
>>> author = Author.objects.annotate(
... name_length=Length('name'),
... goes_by_length=Length('goes_by')).get()
>>> print(author.name_length, author.goes_by_length)
(14, None)
Lower
------
.. class:: Lower(expression, **extra)
Accepts a single text field or expression and returns the lowercase
representation.
Usage example::
>>> from django.db.models.functions import Lower
>>> Author.objects.create(name='Margaret Smith')
>>> author = Author.objects.annotate(name_lower=Lower('name')).get()
>>> print(author.name_lower)
margaret smith
Substr
------
.. class:: Substr(expression, pos, length=None, **extra)
Returns a substring of length ``length`` from the field or expression starting
at position ``pos``. The position is 1-indexed, so the position must be greater
than 0. If ``length`` is ``None``, then the rest of the string will be returned.
Usage example::
>>> # Set the alias to the first 5 characters of the name as lowercase
>>> from django.db.models.functions import Substr, Lower
>>> Author.objects.create(name='Margaret Smith')
>>> Author.objects.update(alias=Lower(Substr('name', 1, 5)))
1
>>> print(Author.objects.get(name='Margaret Smith').alias)
marga
Upper
------
.. class:: Upper(expression, **extra)
Accepts a single text field or expression and returns the uppercase
representation.
Usage example::
>>> from django.db.models.functions import Upper
>>> Author.objects.create(name='Margaret Smith')
>>> author = Author.objects.annotate(name_upper=Upper('name')).get()
>>> print(author.name_upper)
MARGARET SMITH

View File

@ -189,6 +189,8 @@ extra attribute ``field_lower`` produced, roughly, from the following SQL::
... ...
LOWER("app_label"."field") as "field_lower" LOWER("app_label"."field") as "field_lower"
See :doc:`database-functions` for a list of built-in database functions.
The ``Func`` API is as follows: The ``Func`` API is as follows:
.. class:: Func(*expressions, **extra) .. class:: Func(*expressions, **extra)

View File

@ -16,3 +16,4 @@ Model API reference. For introductory material, see :doc:`/topics/db/models`.
queries queries
lookups lookups
expressions expressions
database-functions

View File

@ -66,8 +66,8 @@ New data types
backends. There is a corresponding :class:`form field backends. There is a corresponding :class:`form field
<django.forms.DurationField>`. <django.forms.DurationField>`.
Query Expressions Query Expressions and Database Functions
~~~~~~~~~~~~~~~~~ ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
:doc:`Query Expressions </ref/models/expressions>` allow users to create, :doc:`Query Expressions </ref/models/expressions>` allow users to create,
customize, and compose complex SQL expressions. This has enabled annotate customize, and compose complex SQL expressions. This has enabled annotate
@ -75,6 +75,12 @@ to accept expressions other than aggregates. Aggregates are now able to
reference multiple fields, as well as perform arithmetic, similar to ``F()`` reference multiple fields, as well as perform arithmetic, similar to ``F()``
objects. objects.
A collection of :doc:`database functions </ref/models/database-functions>` is
also included with functionality such as
:class:`~django.db.models.functions.Coalesce`,
:class:`~django.db.models.functions.Concat`, and
:class:`~django.db.models.functions.Substr`.
``TestCase`` data setup ``TestCase`` data setup
~~~~~~~~~~~~~~~~~~~~~~~ ~~~~~~~~~~~~~~~~~~~~~~~

View File

@ -616,6 +616,7 @@ subpackages
subqueries subqueries
subquery subquery
subselect subselect
substr
subtemplate subtemplate
subtemplates subtemplates
subviews subviews

View File

View File

@ -0,0 +1,31 @@
"""
Tests for built in Function expressions.
"""
from __future__ import unicode_literals
from django.db import models
from django.utils.encoding import python_2_unicode_compatible
@python_2_unicode_compatible
class Author(models.Model):
name = models.CharField(max_length=50)
alias = models.CharField(max_length=50, null=True, blank=True)
goes_by = models.CharField(max_length=50, null=True, blank=True)
def __str__(self):
return self.name
@python_2_unicode_compatible
class Article(models.Model):
authors = models.ManyToManyField(Author, related_name='articles')
title = models.CharField(max_length=50)
summary = models.CharField(max_length=200, null=True, blank=True)
text = models.TextField()
written = models.DateTimeField()
published = models.DateTimeField(null=True, blank=True)
views = models.PositiveIntegerField(default=0)
def __str__(self):
return self.title

220
tests/db_functions/tests.py Normal file
View File

@ -0,0 +1,220 @@
from __future__ import unicode_literals
from django.db.models import TextField, CharField, Value as V
from django.db.models.functions import (
Coalesce, Concat, Lower, Upper, Length, Substr,
)
from django.test import TestCase
from django.utils import six, timezone
from .models import Author, Article
lorem_ipsum = """
Lorem ipsum dolor sit amet, consectetur adipiscing elit, sed do eiusmod
tempor incididunt ut labore et dolore magna aliqua."""
class FunctionTests(TestCase):
def test_coalesce(self):
Author.objects.create(name='John Smith', alias='smithj')
Author.objects.create(name='Rhonda')
authors = Author.objects.annotate(display_name=Coalesce('alias', 'name'))
self.assertQuerysetEqual(
authors.order_by('name'), [
'smithj',
'Rhonda',
],
lambda a: a.display_name
)
with self.assertRaisesMessage(ValueError, 'Coalesce must take at least two expressions'):
Author.objects.annotate(display_name=Coalesce('alias'))
def test_coalesce_mixed_values(self):
a1 = Author.objects.create(name='John Smith', alias='smithj')
a2 = Author.objects.create(name='Rhonda')
ar1 = Article.objects.create(
title="How to Django",
text=lorem_ipsum,
written=timezone.now(),
)
ar1.authors.add(a1)
ar1.authors.add(a2)
# mixed Text and Char
article = Article.objects.annotate(
headline=Coalesce('summary', 'text', output_field=TextField()),
)
self.assertQuerysetEqual(
article.order_by('title'), [
lorem_ipsum,
],
lambda a: a.headline
)
def test_concat(self):
Author.objects.create(name='Jayden')
Author.objects.create(name='John Smith', alias='smithj', goes_by='John')
Author.objects.create(name='Margaret', goes_by='Maggie')
Author.objects.create(name='Rhonda', alias='adnohR')
authors = Author.objects.annotate(joined=Concat('alias', 'goes_by'))
self.assertQuerysetEqual(
authors.order_by('name'), [
'',
'smithjJohn',
'Maggie',
'adnohR',
],
lambda a: a.joined
)
with self.assertRaisesMessage(ValueError, 'Concat must take at least two expressions'):
Author.objects.annotate(joined=Concat('alias'))
def test_concat_many(self):
Author.objects.create(name='Jayden')
Author.objects.create(name='John Smith', alias='smithj', goes_by='John')
Author.objects.create(name='Margaret', goes_by='Maggie')
Author.objects.create(name='Rhonda', alias='adnohR')
authors = Author.objects.annotate(
joined=Concat('name', V(' ('), 'goes_by', V(')'), output_field=CharField()),
)
self.assertQuerysetEqual(
authors.order_by('name'), [
'Jayden ()',
'John Smith (John)',
'Margaret (Maggie)',
'Rhonda ()',
],
lambda a: a.joined
)
def test_concat_mixed_char_text(self):
Article.objects.create(title='The Title', text=lorem_ipsum, written=timezone.now())
article = Article.objects.annotate(
title_text=Concat('title', V(' - '), 'text', output_field=TextField()),
).get(title='The Title')
self.assertEqual(article.title + ' - ' + article.text, article.title_text)
# wrap the concat in something else to ensure that we're still
# getting text rather than bytes
article = Article.objects.annotate(
title_text=Upper(Concat('title', V(' - '), 'text', output_field=TextField())),
).get(title='The Title')
expected = article.title + ' - ' + article.text
self.assertEqual(expected.upper(), article.title_text)
def test_lower(self):
Author.objects.create(name='John Smith', alias='smithj')
Author.objects.create(name='Rhonda')
authors = Author.objects.annotate(lower_name=Lower('name'))
self.assertQuerysetEqual(
authors.order_by('name'), [
'john smith',
'rhonda',
],
lambda a: a.lower_name
)
Author.objects.update(name=Lower('name'))
self.assertQuerysetEqual(
authors.order_by('name'), [
('john smith', 'john smith'),
('rhonda', 'rhonda'),
],
lambda a: (a.lower_name, a.name)
)
def test_upper(self):
Author.objects.create(name='John Smith', alias='smithj')
Author.objects.create(name='Rhonda')
authors = Author.objects.annotate(upper_name=Upper('name'))
self.assertQuerysetEqual(
authors.order_by('name'), [
'JOHN SMITH',
'RHONDA',
],
lambda a: a.upper_name
)
Author.objects.update(name=Upper('name'))
self.assertQuerysetEqual(
authors.order_by('name'), [
('JOHN SMITH', 'JOHN SMITH'),
('RHONDA', 'RHONDA'),
],
lambda a: (a.upper_name, a.name)
)
def test_length(self):
Author.objects.create(name='John Smith', alias='smithj')
Author.objects.create(name='Rhonda')
authors = Author.objects.annotate(
name_length=Length('name'),
alias_length=Length('alias'))
self.assertQuerysetEqual(
authors.order_by('name'), [
(10, 6),
(6, None),
],
lambda a: (a.name_length, a.alias_length)
)
self.assertEqual(authors.filter(alias_length__lte=Length('name')).count(), 1)
def test_substr(self):
Author.objects.create(name='John Smith', alias='smithj')
Author.objects.create(name='Rhonda')
authors = Author.objects.annotate(name_part=Substr('name', 5, 3))
self.assertQuerysetEqual(
authors.order_by('name'), [
' Sm',
'da',
],
lambda a: a.name_part
)
authors = Author.objects.annotate(name_part=Substr('name', 2))
self.assertQuerysetEqual(
authors.order_by('name'), [
'ohn Smith',
'honda',
],
lambda a: a.name_part
)
# if alias is null, set to first 5 lower characters of the name
Author.objects.filter(alias__isnull=True).update(
alias=Lower(Substr('name', 1, 5)),
)
self.assertQuerysetEqual(
authors.order_by('name'), [
'smithj',
'rhond',
],
lambda a: a.alias
)
def test_substr_start(self):
Author.objects.create(name='John Smith', alias='smithj')
a = Author.objects.annotate(
name_part_1=Substr('name', 1),
name_part_2=Substr('name', 2),
).get(alias='smithj')
self.assertEqual(a.name_part_1[1:], a.name_part_2)
with six.assertRaisesRegex(self, ValueError, "'pos' must be greater than 0"):
Author.objects.annotate(raises=Substr('name', 0))