mirror of
https://github.com/django/django.git
synced 2024-12-22 17:16:24 +00:00
04eb1b4567
Per deprecation timeline.
923 lines
29 KiB
Plaintext
923 lines
29 KiB
Plaintext
================================
|
|
PostgreSQL specific model fields
|
|
================================
|
|
|
|
All of these fields are available from the ``django.contrib.postgres.fields``
|
|
module.
|
|
|
|
.. currentmodule:: django.contrib.postgres.fields
|
|
|
|
Indexing these fields
|
|
=====================
|
|
|
|
:class:`~django.db.models.Index` and :attr:`.Field.db_index` both create a
|
|
B-tree index, which isn't particularly helpful when querying complex data types.
|
|
Indexes such as :class:`~django.contrib.postgres.indexes.GinIndex` and
|
|
:class:`~django.contrib.postgres.indexes.GistIndex` are better suited, though
|
|
the index choice is dependent on the queries that you're using. Generally, GiST
|
|
may be a good choice for the :ref:`range fields <range-fields>` and
|
|
:class:`HStoreField`, and GIN may be helpful for :class:`ArrayField`.
|
|
|
|
``ArrayField``
|
|
==============
|
|
|
|
.. class:: ArrayField(base_field, size=None, **options)
|
|
|
|
A field for storing lists of data. Most field types can be used, and you
|
|
pass another field instance as the :attr:`base_field
|
|
<ArrayField.base_field>`. You may also specify a :attr:`size
|
|
<ArrayField.size>`. ``ArrayField`` can be nested to store multi-dimensional
|
|
arrays.
|
|
|
|
If you give the field a :attr:`~django.db.models.Field.default`, ensure
|
|
it's a callable such as ``list`` (for an empty default) or a callable that
|
|
returns a list (such as a function). Incorrectly using ``default=[]``
|
|
creates a mutable default that is shared between all instances of
|
|
``ArrayField``.
|
|
|
|
.. attribute:: base_field
|
|
|
|
This is a required argument.
|
|
|
|
Specifies the underlying data type and behavior for the array. It
|
|
should be an instance of a subclass of
|
|
:class:`~django.db.models.Field`. For example, it could be an
|
|
:class:`~django.db.models.IntegerField` or a
|
|
:class:`~django.db.models.CharField`. Most field types are permitted,
|
|
with the exception of those handling relational data
|
|
(:class:`~django.db.models.ForeignKey`,
|
|
:class:`~django.db.models.OneToOneField` and
|
|
:class:`~django.db.models.ManyToManyField`) and file fields (
|
|
:class:`~django.db.models.FileField` and
|
|
:class:`~django.db.models.ImageField`).
|
|
|
|
It is possible to nest array fields - you can specify an instance of
|
|
``ArrayField`` as the ``base_field``. For example::
|
|
|
|
from django.contrib.postgres.fields import ArrayField
|
|
from django.db import models
|
|
|
|
|
|
class ChessBoard(models.Model):
|
|
board = ArrayField(
|
|
ArrayField(
|
|
models.CharField(max_length=10, blank=True),
|
|
size=8,
|
|
),
|
|
size=8,
|
|
)
|
|
|
|
Transformation of values between the database and the model, validation
|
|
of data and configuration, and serialization are all delegated to the
|
|
underlying base field.
|
|
|
|
.. attribute:: size
|
|
|
|
This is an optional argument.
|
|
|
|
If passed, the array will have a maximum size as specified. This will
|
|
be passed to the database, although PostgreSQL at present does not
|
|
enforce the restriction.
|
|
|
|
.. note::
|
|
|
|
When nesting ``ArrayField``, whether you use the ``size`` parameter or not,
|
|
PostgreSQL requires that the arrays are rectangular::
|
|
|
|
from django.contrib.postgres.fields import ArrayField
|
|
from django.db import models
|
|
|
|
|
|
class Board(models.Model):
|
|
pieces = ArrayField(ArrayField(models.IntegerField()))
|
|
|
|
|
|
# Valid
|
|
Board(
|
|
pieces=[
|
|
[2, 3],
|
|
[2, 1],
|
|
]
|
|
)
|
|
|
|
# Not valid
|
|
Board(
|
|
pieces=[
|
|
[2, 3],
|
|
[2],
|
|
]
|
|
)
|
|
|
|
If irregular shapes are required, then the underlying field should be made
|
|
nullable and the values padded with ``None``.
|
|
|
|
Querying ``ArrayField``
|
|
-----------------------
|
|
|
|
There are a number of custom lookups and transforms for :class:`ArrayField`.
|
|
We will use the following example model::
|
|
|
|
from django.contrib.postgres.fields import ArrayField
|
|
from django.db import models
|
|
|
|
|
|
class Post(models.Model):
|
|
name = models.CharField(max_length=200)
|
|
tags = ArrayField(models.CharField(max_length=200), blank=True)
|
|
|
|
def __str__(self):
|
|
return self.name
|
|
|
|
.. fieldlookup:: arrayfield.contains
|
|
|
|
``contains``
|
|
~~~~~~~~~~~~
|
|
|
|
The :lookup:`contains` lookup is overridden on :class:`ArrayField`. The
|
|
returned objects will be those where the values passed are a subset of the
|
|
data. It uses the SQL operator ``@>``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts"])
|
|
>>> Post.objects.create(name="Third post", tags=["tutorial", "django"])
|
|
|
|
>>> Post.objects.filter(tags__contains=["thoughts"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
>>> Post.objects.filter(tags__contains=["django"])
|
|
<QuerySet [<Post: First post>, <Post: Third post>]>
|
|
|
|
>>> Post.objects.filter(tags__contains=["django", "thoughts"])
|
|
<QuerySet [<Post: First post>]>
|
|
|
|
.. fieldlookup:: arrayfield.contained_by
|
|
|
|
``contained_by``
|
|
~~~~~~~~~~~~~~~~
|
|
|
|
This is the inverse of the :lookup:`contains <arrayfield.contains>` lookup -
|
|
the objects returned will be those where the data is a subset of the values
|
|
passed. It uses the SQL operator ``<@``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts"])
|
|
>>> Post.objects.create(name="Third post", tags=["tutorial", "django"])
|
|
|
|
>>> Post.objects.filter(tags__contained_by=["thoughts", "django"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
>>> Post.objects.filter(tags__contained_by=["thoughts", "django", "tutorial"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>, <Post: Third post>]>
|
|
|
|
.. fieldlookup:: arrayfield.overlap
|
|
|
|
``overlap``
|
|
~~~~~~~~~~~
|
|
|
|
Returns objects where the data shares any results with the values passed. Uses
|
|
the SQL operator ``&&``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts", "tutorial"])
|
|
>>> Post.objects.create(name="Third post", tags=["tutorial", "django"])
|
|
|
|
>>> Post.objects.filter(tags__overlap=["thoughts"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
>>> Post.objects.filter(tags__overlap=["thoughts", "tutorial"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>, <Post: Third post>]>
|
|
|
|
>>> Post.objects.filter(tags__overlap=Post.objects.values_list("tags"))
|
|
<QuerySet [<Post: First post>, <Post: Second post>, <Post: Third post>]>
|
|
|
|
.. fieldlookup:: arrayfield.len
|
|
|
|
``len``
|
|
~~~~~~~
|
|
|
|
Returns the length of the array. The lookups available afterward are those
|
|
available for :class:`~django.db.models.IntegerField`. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts"])
|
|
|
|
>>> Post.objects.filter(tags__len=1)
|
|
<QuerySet [<Post: Second post>]>
|
|
|
|
.. fieldlookup:: arrayfield.index
|
|
|
|
Index transforms
|
|
~~~~~~~~~~~~~~~~
|
|
|
|
Index transforms index into the array. Any non-negative integer can be used.
|
|
There are no errors if it exceeds the :attr:`size <ArrayField.size>` of the
|
|
array. The lookups available after the transform are those from the
|
|
:attr:`base_field <ArrayField.base_field>`. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts"])
|
|
|
|
>>> Post.objects.filter(tags__0="thoughts")
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
>>> Post.objects.filter(tags__1__iexact="Django")
|
|
<QuerySet [<Post: First post>]>
|
|
|
|
>>> Post.objects.filter(tags__276="javascript")
|
|
<QuerySet []>
|
|
|
|
.. note::
|
|
|
|
PostgreSQL uses 1-based indexing for array fields when writing raw SQL.
|
|
However these indexes and those used in :lookup:`slices <arrayfield.slice>`
|
|
use 0-based indexing to be consistent with Python.
|
|
|
|
.. fieldlookup:: arrayfield.slice
|
|
|
|
Slice transforms
|
|
~~~~~~~~~~~~~~~~
|
|
|
|
Slice transforms take a slice of the array. Any two non-negative integers can
|
|
be used, separated by a single underscore. The lookups available after the
|
|
transform do not change. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Post.objects.create(name="First post", tags=["thoughts", "django"])
|
|
>>> Post.objects.create(name="Second post", tags=["thoughts"])
|
|
>>> Post.objects.create(name="Third post", tags=["django", "python", "thoughts"])
|
|
|
|
>>> Post.objects.filter(tags__0_1=["thoughts"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
>>> Post.objects.filter(tags__0_2__contains=["thoughts"])
|
|
<QuerySet [<Post: First post>, <Post: Second post>]>
|
|
|
|
.. note::
|
|
|
|
PostgreSQL uses 1-based indexing for array fields when writing raw SQL.
|
|
However these slices and those used in :lookup:`indexes <arrayfield.index>`
|
|
use 0-based indexing to be consistent with Python.
|
|
|
|
.. admonition:: Multidimensional arrays with indexes and slices
|
|
|
|
PostgreSQL has some rather esoteric behavior when using indexes and slices
|
|
on multidimensional arrays. It will always work to use indexes to reach
|
|
down to the final underlying data, but most other slices behave strangely
|
|
at the database level and cannot be supported in a logical, consistent
|
|
fashion by Django.
|
|
|
|
``HStoreField``
|
|
===============
|
|
|
|
.. class:: HStoreField(**options)
|
|
|
|
A field for storing key-value pairs. The Python data type used is a
|
|
``dict``. Keys must be strings, and values may be either strings or nulls
|
|
(``None`` in Python).
|
|
|
|
To use this field, you'll need to:
|
|
|
|
#. Add ``'django.contrib.postgres'`` in your :setting:`INSTALLED_APPS`.
|
|
#. :ref:`Set up the hstore extension <create-postgresql-extensions>` in
|
|
PostgreSQL.
|
|
|
|
You'll see an error like ``can't adapt type 'dict'`` if you skip the first
|
|
step, or ``type "hstore" does not exist`` if you skip the second.
|
|
|
|
.. note::
|
|
|
|
On occasions it may be useful to require or restrict the keys which are
|
|
valid for a given field. This can be done using the
|
|
:class:`~django.contrib.postgres.validators.KeysValidator`.
|
|
|
|
Querying ``HStoreField``
|
|
------------------------
|
|
|
|
In addition to the ability to query by key, there are a number of custom
|
|
lookups available for ``HStoreField``.
|
|
|
|
We will use the following example model::
|
|
|
|
from django.contrib.postgres.fields import HStoreField
|
|
from django.db import models
|
|
|
|
|
|
class Dog(models.Model):
|
|
name = models.CharField(max_length=200)
|
|
data = HStoreField()
|
|
|
|
def __str__(self):
|
|
return self.name
|
|
|
|
.. fieldlookup:: hstorefield.key
|
|
|
|
Key lookups
|
|
~~~~~~~~~~~
|
|
|
|
To query based on a given key, you can use that key as the lookup name:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie"})
|
|
|
|
>>> Dog.objects.filter(data__breed="collie")
|
|
<QuerySet [<Dog: Meg>]>
|
|
|
|
You can chain other lookups after key lookups:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.filter(data__breed__contains="l")
|
|
<QuerySet [<Dog: Rufus>, <Dog: Meg>]>
|
|
|
|
or use ``F()`` expressions to annotate a key value. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> from django.db.models import F
|
|
>>> rufus = Dog.objects.annotate(breed=F("data__breed"))[0]
|
|
>>> rufus.breed
|
|
'labrador'
|
|
|
|
If the key you wish to query by clashes with the name of another lookup, you
|
|
need to use the :lookup:`hstorefield.contains` lookup instead.
|
|
|
|
.. note::
|
|
|
|
Key transforms can also be chained with: :lookup:`contains`,
|
|
:lookup:`icontains`, :lookup:`endswith`, :lookup:`iendswith`,
|
|
:lookup:`iexact`, :lookup:`regex`, :lookup:`iregex`, :lookup:`startswith`,
|
|
and :lookup:`istartswith` lookups.
|
|
|
|
.. warning::
|
|
|
|
Since any string could be a key in a hstore value, any lookup other than
|
|
those listed below will be interpreted as a key lookup. No errors are
|
|
raised. Be extra careful for typing mistakes, and always check your queries
|
|
work as you intend.
|
|
|
|
.. fieldlookup:: hstorefield.contains
|
|
|
|
``contains``
|
|
~~~~~~~~~~~~
|
|
|
|
The :lookup:`contains` lookup is overridden on
|
|
:class:`~django.contrib.postgres.fields.HStoreField`. The returned objects are
|
|
those where the given ``dict`` of key-value pairs are all contained in the
|
|
field. It uses the SQL operator ``@>``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador", "owner": "Bob"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
>>> Dog.objects.create(name="Fred", data={})
|
|
|
|
>>> Dog.objects.filter(data__contains={"owner": "Bob"})
|
|
<QuerySet [<Dog: Rufus>, <Dog: Meg>]>
|
|
|
|
>>> Dog.objects.filter(data__contains={"breed": "collie"})
|
|
<QuerySet [<Dog: Meg>]>
|
|
|
|
.. fieldlookup:: hstorefield.contained_by
|
|
|
|
``contained_by``
|
|
~~~~~~~~~~~~~~~~
|
|
|
|
This is the inverse of the :lookup:`contains <hstorefield.contains>` lookup -
|
|
the objects returned will be those where the key-value pairs on the object are
|
|
a subset of those in the value passed. It uses the SQL operator ``<@``. For
|
|
example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador", "owner": "Bob"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
>>> Dog.objects.create(name="Fred", data={})
|
|
|
|
>>> Dog.objects.filter(data__contained_by={"breed": "collie", "owner": "Bob"})
|
|
<QuerySet [<Dog: Meg>, <Dog: Fred>]>
|
|
|
|
>>> Dog.objects.filter(data__contained_by={"breed": "collie"})
|
|
<QuerySet [<Dog: Fred>]>
|
|
|
|
.. fieldlookup:: hstorefield.has_key
|
|
|
|
``has_key``
|
|
~~~~~~~~~~~
|
|
|
|
Returns objects where the given key is in the data. Uses the SQL operator
|
|
``?``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
|
|
>>> Dog.objects.filter(data__has_key="owner")
|
|
<QuerySet [<Dog: Meg>]>
|
|
|
|
.. fieldlookup:: hstorefield.has_any_keys
|
|
|
|
``has_any_keys``
|
|
~~~~~~~~~~~~~~~~
|
|
|
|
Returns objects where any of the given keys are in the data. Uses the SQL
|
|
operator ``?|``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador"})
|
|
>>> Dog.objects.create(name="Meg", data={"owner": "Bob"})
|
|
>>> Dog.objects.create(name="Fred", data={})
|
|
|
|
>>> Dog.objects.filter(data__has_any_keys=["owner", "breed"])
|
|
<QuerySet [<Dog: Rufus>, <Dog: Meg>]>
|
|
|
|
.. fieldlookup:: hstorefield.has_keys
|
|
|
|
``has_keys``
|
|
~~~~~~~~~~~~
|
|
|
|
Returns objects where all of the given keys are in the data. Uses the SQL operator
|
|
``?&``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
|
|
>>> Dog.objects.filter(data__has_keys=["breed", "owner"])
|
|
<QuerySet [<Dog: Meg>]>
|
|
|
|
.. fieldlookup:: hstorefield.keys
|
|
|
|
``keys``
|
|
~~~~~~~~
|
|
|
|
Returns objects where the array of keys is the given value. Note that the order
|
|
is not guaranteed to be reliable, so this transform is mainly useful for using
|
|
in conjunction with lookups on
|
|
:class:`~django.contrib.postgres.fields.ArrayField`. Uses the SQL function
|
|
``akeys()``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"toy": "bone"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
|
|
>>> Dog.objects.filter(data__keys__overlap=["breed", "toy"])
|
|
<QuerySet [<Dog: Rufus>, <Dog: Meg>]>
|
|
|
|
.. fieldlookup:: hstorefield.values
|
|
|
|
``values``
|
|
~~~~~~~~~~
|
|
|
|
Returns objects where the array of values is the given value. Note that the
|
|
order is not guaranteed to be reliable, so this transform is mainly useful for
|
|
using in conjunction with lookups on
|
|
:class:`~django.contrib.postgres.fields.ArrayField`. Uses the SQL function
|
|
``avals()``. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> Dog.objects.create(name="Rufus", data={"breed": "labrador"})
|
|
>>> Dog.objects.create(name="Meg", data={"breed": "collie", "owner": "Bob"})
|
|
|
|
>>> Dog.objects.filter(data__values__contains=["collie"])
|
|
<QuerySet [<Dog: Meg>]>
|
|
|
|
.. _range-fields:
|
|
|
|
Range Fields
|
|
============
|
|
|
|
There are five range field types, corresponding to the built-in range types in
|
|
PostgreSQL. These fields are used to store a range of values; for example the
|
|
start and end timestamps of an event, or the range of ages an activity is
|
|
suitable for.
|
|
|
|
All of the range fields translate to :ref:`psycopg Range objects
|
|
<psycopg:adapt-range>` in Python, but also accept tuples as input if no bounds
|
|
information is necessary. The default is lower bound included, upper bound
|
|
excluded, that is ``[)`` (see the PostgreSQL documentation for details about
|
|
`different bounds`_). The default bounds can be changed for non-discrete range
|
|
fields (:class:`.DateTimeRangeField` and :class:`.DecimalRangeField`) by using
|
|
the ``default_bounds`` argument.
|
|
|
|
``IntegerRangeField``
|
|
---------------------
|
|
|
|
.. class:: IntegerRangeField(**options)
|
|
|
|
Stores a range of integers. Based on an
|
|
:class:`~django.db.models.IntegerField`. Represented by an ``int4range`` in
|
|
the database and a
|
|
``django.db.backends.postgresql.psycopg_any.NumericRange`` in Python.
|
|
|
|
Regardless of the bounds specified when saving the data, PostgreSQL always
|
|
returns a range in a canonical form that includes the lower bound and
|
|
excludes the upper bound, that is ``[)``.
|
|
|
|
``BigIntegerRangeField``
|
|
------------------------
|
|
|
|
.. class:: BigIntegerRangeField(**options)
|
|
|
|
Stores a range of large integers. Based on a
|
|
:class:`~django.db.models.BigIntegerField`. Represented by an ``int8range``
|
|
in the database and a
|
|
``django.db.backends.postgresql.psycopg_any.NumericRange`` in Python.
|
|
|
|
Regardless of the bounds specified when saving the data, PostgreSQL always
|
|
returns a range in a canonical form that includes the lower bound and
|
|
excludes the upper bound, that is ``[)``.
|
|
|
|
``DecimalRangeField``
|
|
---------------------
|
|
|
|
.. class:: DecimalRangeField(default_bounds='[)', **options)
|
|
|
|
Stores a range of floating point values. Based on a
|
|
:class:`~django.db.models.DecimalField`. Represented by a ``numrange`` in
|
|
the database and a
|
|
``django.db.backends.postgresql.psycopg_any.NumericRange`` in Python.
|
|
|
|
.. attribute:: DecimalRangeField.default_bounds
|
|
|
|
Optional. The value of ``bounds`` for list and tuple inputs. The
|
|
default is lower bound included, upper bound excluded, that is ``[)``
|
|
(see the PostgreSQL documentation for details about
|
|
`different bounds`_). ``default_bounds`` is not used for
|
|
``django.db.backends.postgresql.psycopg_any.NumericRange`` inputs.
|
|
|
|
``DateTimeRangeField``
|
|
----------------------
|
|
|
|
.. class:: DateTimeRangeField(default_bounds='[)', **options)
|
|
|
|
Stores a range of timestamps. Based on a
|
|
:class:`~django.db.models.DateTimeField`. Represented by a ``tstzrange`` in
|
|
the database and a
|
|
``django.db.backends.postgresql.psycopg_any.DateTimeTZRange`` in Python.
|
|
|
|
.. attribute:: DateTimeRangeField.default_bounds
|
|
|
|
Optional. The value of ``bounds`` for list and tuple inputs. The
|
|
default is lower bound included, upper bound excluded, that is ``[)``
|
|
(see the PostgreSQL documentation for details about
|
|
`different bounds`_). ``default_bounds`` is not used for
|
|
``django.db.backends.postgresql.psycopg_any.DateTimeTZRange`` inputs.
|
|
|
|
``DateRangeField``
|
|
------------------
|
|
|
|
.. class:: DateRangeField(**options)
|
|
|
|
Stores a range of dates. Based on a
|
|
:class:`~django.db.models.DateField`. Represented by a ``daterange`` in the
|
|
database and a ``django.db.backends.postgresql.psycopg_any.DateRange`` in
|
|
Python.
|
|
|
|
Regardless of the bounds specified when saving the data, PostgreSQL always
|
|
returns a range in a canonical form that includes the lower bound and
|
|
excludes the upper bound, that is ``[)``.
|
|
|
|
Querying Range Fields
|
|
---------------------
|
|
|
|
There are a number of custom lookups and transforms for range fields. They are
|
|
available on all the above fields, but we will use the following example
|
|
model::
|
|
|
|
from django.contrib.postgres.fields import IntegerRangeField
|
|
from django.db import models
|
|
|
|
|
|
class Event(models.Model):
|
|
name = models.CharField(max_length=200)
|
|
ages = IntegerRangeField()
|
|
start = models.DateTimeField()
|
|
|
|
def __str__(self):
|
|
return self.name
|
|
|
|
We will also use the following example objects:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> import datetime
|
|
>>> from django.utils import timezone
|
|
>>> now = timezone.now()
|
|
>>> Event.objects.create(name="Soft play", ages=(0, 10), start=now)
|
|
>>> Event.objects.create(
|
|
... name="Pub trip", ages=(21, None), start=now - datetime.timedelta(days=1)
|
|
... )
|
|
|
|
and ``NumericRange``:
|
|
|
|
>>> from django.db.backends.postgresql.psycopg_any import NumericRange
|
|
|
|
Containment functions
|
|
~~~~~~~~~~~~~~~~~~~~~
|
|
|
|
As with other PostgreSQL fields, there are three standard containment
|
|
operators: ``contains``, ``contained_by`` and ``overlap``, using the SQL
|
|
operators ``@>``, ``<@``, and ``&&`` respectively.
|
|
|
|
.. fieldlookup:: rangefield.contains
|
|
|
|
``contains``
|
|
^^^^^^^^^^^^
|
|
|
|
>>> Event.objects.filter(ages__contains=NumericRange(4, 5))
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
.. fieldlookup:: rangefield.contained_by
|
|
|
|
``contained_by``
|
|
^^^^^^^^^^^^^^^^
|
|
|
|
>>> Event.objects.filter(ages__contained_by=NumericRange(0, 15))
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
The ``contained_by`` lookup is also available on the non-range field types:
|
|
:class:`~django.db.models.SmallAutoField`,
|
|
:class:`~django.db.models.AutoField`, :class:`~django.db.models.BigAutoField`,
|
|
:class:`~django.db.models.SmallIntegerField`,
|
|
:class:`~django.db.models.IntegerField`,
|
|
:class:`~django.db.models.BigIntegerField`,
|
|
:class:`~django.db.models.DecimalField`, :class:`~django.db.models.FloatField`,
|
|
:class:`~django.db.models.DateField`, and
|
|
:class:`~django.db.models.DateTimeField`. For example:
|
|
|
|
.. code-block:: pycon
|
|
|
|
>>> from django.db.backends.postgresql.psycopg_any import DateTimeTZRange
|
|
>>> Event.objects.filter(
|
|
... start__contained_by=DateTimeTZRange(
|
|
... timezone.now() - datetime.timedelta(hours=1),
|
|
... timezone.now() + datetime.timedelta(hours=1),
|
|
... ),
|
|
... )
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
.. fieldlookup:: rangefield.overlap
|
|
|
|
``overlap``
|
|
^^^^^^^^^^^
|
|
|
|
>>> Event.objects.filter(ages__overlap=NumericRange(8, 12))
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
Comparison functions
|
|
~~~~~~~~~~~~~~~~~~~~
|
|
|
|
Range fields support the standard lookups: :lookup:`lt`, :lookup:`gt`,
|
|
:lookup:`lte` and :lookup:`gte`. These are not particularly helpful - they
|
|
compare the lower bounds first and then the upper bounds only if necessary.
|
|
This is also the strategy used to order by a range field. It is better to use
|
|
the specific range comparison operators.
|
|
|
|
.. fieldlookup:: rangefield.fully_lt
|
|
|
|
``fully_lt``
|
|
^^^^^^^^^^^^
|
|
|
|
The returned ranges are strictly less than the passed range. In other words,
|
|
all the points in the returned range are less than all those in the passed
|
|
range.
|
|
|
|
>>> Event.objects.filter(ages__fully_lt=NumericRange(11, 15))
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
.. fieldlookup:: rangefield.fully_gt
|
|
|
|
``fully_gt``
|
|
^^^^^^^^^^^^
|
|
|
|
The returned ranges are strictly greater than the passed range. In other words,
|
|
the all the points in the returned range are greater than all those in the
|
|
passed range.
|
|
|
|
>>> Event.objects.filter(ages__fully_gt=NumericRange(11, 15))
|
|
<QuerySet [<Event: Pub trip>]>
|
|
|
|
.. fieldlookup:: rangefield.not_lt
|
|
|
|
``not_lt``
|
|
^^^^^^^^^^
|
|
|
|
The returned ranges do not contain any points less than the passed range, that
|
|
is the lower bound of the returned range is at least the lower bound of the
|
|
passed range.
|
|
|
|
>>> Event.objects.filter(ages__not_lt=NumericRange(0, 15))
|
|
<QuerySet [<Event: Soft play>, <Event: Pub trip>]>
|
|
|
|
.. fieldlookup:: rangefield.not_gt
|
|
|
|
``not_gt``
|
|
^^^^^^^^^^
|
|
|
|
The returned ranges do not contain any points greater than the passed range, that
|
|
is the upper bound of the returned range is at most the upper bound of the
|
|
passed range.
|
|
|
|
>>> Event.objects.filter(ages__not_gt=NumericRange(3, 10))
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
.. fieldlookup:: rangefield.adjacent_to
|
|
|
|
``adjacent_to``
|
|
^^^^^^^^^^^^^^^
|
|
|
|
The returned ranges share a bound with the passed range.
|
|
|
|
>>> Event.objects.filter(ages__adjacent_to=NumericRange(10, 21))
|
|
<QuerySet [<Event: Soft play>, <Event: Pub trip>]>
|
|
|
|
Querying using the bounds
|
|
~~~~~~~~~~~~~~~~~~~~~~~~~
|
|
|
|
Range fields support several extra lookups.
|
|
|
|
.. fieldlookup:: rangefield.startswith
|
|
|
|
``startswith``
|
|
^^^^^^^^^^^^^^
|
|
|
|
Returned objects have the given lower bound. Can be chained to valid lookups
|
|
for the base field.
|
|
|
|
>>> Event.objects.filter(ages__startswith=21)
|
|
<QuerySet [<Event: Pub trip>]>
|
|
|
|
.. fieldlookup:: rangefield.endswith
|
|
|
|
``endswith``
|
|
^^^^^^^^^^^^
|
|
|
|
Returned objects have the given upper bound. Can be chained to valid lookups
|
|
for the base field.
|
|
|
|
>>> Event.objects.filter(ages__endswith=10)
|
|
<QuerySet [<Event: Soft play>]>
|
|
|
|
.. fieldlookup:: rangefield.isempty
|
|
|
|
``isempty``
|
|
^^^^^^^^^^^
|
|
|
|
Returned objects are empty ranges. Can be chained to valid lookups for a
|
|
:class:`~django.db.models.BooleanField`.
|
|
|
|
>>> Event.objects.filter(ages__isempty=True)
|
|
<QuerySet []>
|
|
|
|
.. fieldlookup:: rangefield.lower_inc
|
|
|
|
``lower_inc``
|
|
^^^^^^^^^^^^^
|
|
|
|
Returns objects that have inclusive or exclusive lower bounds, depending on the
|
|
boolean value passed. Can be chained to valid lookups for a
|
|
:class:`~django.db.models.BooleanField`.
|
|
|
|
>>> Event.objects.filter(ages__lower_inc=True)
|
|
<QuerySet [<Event: Soft play>, <Event: Pub trip>]>
|
|
|
|
.. fieldlookup:: rangefield.lower_inf
|
|
|
|
``lower_inf``
|
|
^^^^^^^^^^^^^
|
|
|
|
Returns objects that have unbounded (infinite) or bounded lower bound,
|
|
depending on the boolean value passed. Can be chained to valid lookups for a
|
|
:class:`~django.db.models.BooleanField`.
|
|
|
|
>>> Event.objects.filter(ages__lower_inf=True)
|
|
<QuerySet []>
|
|
|
|
.. fieldlookup:: rangefield.upper_inc
|
|
|
|
``upper_inc``
|
|
^^^^^^^^^^^^^
|
|
|
|
Returns objects that have inclusive or exclusive upper bounds, depending on the
|
|
boolean value passed. Can be chained to valid lookups for a
|
|
:class:`~django.db.models.BooleanField`.
|
|
|
|
>>> Event.objects.filter(ages__upper_inc=True)
|
|
<QuerySet []>
|
|
|
|
.. fieldlookup:: rangefield.upper_inf
|
|
|
|
``upper_inf``
|
|
^^^^^^^^^^^^^
|
|
|
|
Returns objects that have unbounded (infinite) or bounded upper bound,
|
|
depending on the boolean value passed. Can be chained to valid lookups for a
|
|
:class:`~django.db.models.BooleanField`.
|
|
|
|
>>> Event.objects.filter(ages__upper_inf=True)
|
|
<QuerySet [<Event: Pub trip>]>
|
|
|
|
Defining your own range types
|
|
-----------------------------
|
|
|
|
PostgreSQL allows the definition of custom range types. Django's model and form
|
|
field implementations use base classes below, and ``psycopg`` provides a
|
|
:func:`~psycopg:psycopg.types.range.register_range` to allow use of custom
|
|
range types.
|
|
|
|
.. class:: RangeField(**options)
|
|
|
|
Base class for model range fields.
|
|
|
|
.. attribute:: base_field
|
|
|
|
The model field class to use.
|
|
|
|
.. attribute:: range_type
|
|
|
|
The range type to use.
|
|
|
|
.. attribute:: form_field
|
|
|
|
The form field class to use. Should be a subclass of
|
|
:class:`django.contrib.postgres.forms.BaseRangeField`.
|
|
|
|
.. class:: django.contrib.postgres.forms.BaseRangeField
|
|
|
|
Base class for form range fields.
|
|
|
|
.. attribute:: base_field
|
|
|
|
The form field to use.
|
|
|
|
.. attribute:: range_type
|
|
|
|
The range type to use.
|
|
|
|
Range operators
|
|
---------------
|
|
|
|
.. class:: RangeOperators
|
|
|
|
PostgreSQL provides a set of SQL operators that can be used together with the
|
|
range data types (see `the PostgreSQL documentation for the full details of
|
|
range operators <https://www.postgresql.org/docs/current/
|
|
functions-range.html#RANGE-OPERATORS-TABLE>`_). This class is meant as a
|
|
convenient method to avoid typos. The operator names overlap with the names of
|
|
corresponding lookups.
|
|
|
|
.. code-block:: python
|
|
|
|
class RangeOperators:
|
|
EQUAL = "="
|
|
NOT_EQUAL = "<>"
|
|
CONTAINS = "@>"
|
|
CONTAINED_BY = "<@"
|
|
OVERLAPS = "&&"
|
|
FULLY_LT = "<<"
|
|
FULLY_GT = ">>"
|
|
NOT_LT = "&>"
|
|
NOT_GT = "&<"
|
|
ADJACENT_TO = "-|-"
|
|
|
|
RangeBoundary() expressions
|
|
---------------------------
|
|
|
|
.. class:: RangeBoundary(inclusive_lower=True, inclusive_upper=False)
|
|
|
|
.. attribute:: inclusive_lower
|
|
|
|
If ``True`` (default), the lower bound is inclusive ``'['``, otherwise
|
|
it's exclusive ``'('``.
|
|
|
|
.. attribute:: inclusive_upper
|
|
|
|
If ``False`` (default), the upper bound is exclusive ``')'``, otherwise
|
|
it's inclusive ``']'``.
|
|
|
|
A ``RangeBoundary()`` expression represents the range boundaries. It can be
|
|
used with a custom range functions that expected boundaries, for example to
|
|
define :class:`~django.contrib.postgres.constraints.ExclusionConstraint`. See
|
|
`the PostgreSQL documentation for the full details <https://www.postgresql.org/
|
|
docs/current/rangetypes.html#RANGETYPES-INCLUSIVITY>`_.
|
|
|
|
.. _different bounds: https://www.postgresql.org/docs/current/rangetypes.html#RANGETYPES-IO
|