conditional-expressions.txt 10 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276
  1. =======================
  2. Conditional Expressions
  3. =======================
  4. .. currentmodule:: django.db.models.expressions
  5. Conditional expressions let you use :keyword:`if` ... :keyword:`elif` ...
  6. :keyword:`else` logic within filters, annotations, aggregations, and updates. A
  7. conditional expression evaluates a series of conditions for each row of a
  8. table and returns the matching result expression. Conditional expressions can
  9. also be combined and nested like other :doc:`expressions <expressions>`.
  10. The conditional expression classes
  11. ==================================
  12. We'll be using the following model in the subsequent examples::
  13. from django.db import models
  14. class Client(models.Model):
  15. REGULAR = 'R'
  16. GOLD = 'G'
  17. PLATINUM = 'P'
  18. ACCOUNT_TYPE_CHOICES = [
  19. (REGULAR, 'Regular'),
  20. (GOLD, 'Gold'),
  21. (PLATINUM, 'Platinum'),
  22. ]
  23. name = models.CharField(max_length=50)
  24. registered_on = models.DateField()
  25. account_type = models.CharField(
  26. max_length=1,
  27. choices=ACCOUNT_TYPE_CHOICES,
  28. default=REGULAR,
  29. )
  30. ``When``
  31. --------
  32. .. class:: When(condition=None, then=None, **lookups)
  33. A ``When()`` object is used to encapsulate a condition and its result for use
  34. in the conditional expression. Using a ``When()`` object is similar to using
  35. the :meth:`~django.db.models.query.QuerySet.filter` method. The condition can
  36. be specified using :ref:`field lookups <field-lookups>`,
  37. :class:`~django.db.models.Q` objects, or :class:`~django.db.models.Expression`
  38. objects that have an ``output_field`` that is a
  39. :class:`~django.db.models.BooleanField`. The result is provided using the
  40. ``then`` keyword.
  41. .. versionchanged:: 3.0
  42. Support for boolean :class:`~django.db.models.Expression` was added.
  43. Some examples::
  44. >>> from django.db.models import F, Q, When
  45. >>> # String arguments refer to fields; the following two examples are equivalent:
  46. >>> When(account_type=Client.GOLD, then='name')
  47. >>> When(account_type=Client.GOLD, then=F('name'))
  48. >>> # You can use field lookups in the condition
  49. >>> from datetime import date
  50. >>> When(registered_on__gt=date(2014, 1, 1),
  51. ... registered_on__lt=date(2015, 1, 1),
  52. ... then='account_type')
  53. >>> # Complex conditions can be created using Q objects
  54. >>> When(Q(name__startswith="John") | Q(name__startswith="Paul"),
  55. ... then='name')
  56. >>> # Condition can be created using boolean expressions.
  57. >>> from django.db.models import Exists, OuterRef
  58. >>> non_unique_account_type = Client.objects.filter(
  59. ... account_type=OuterRef('account_type'),
  60. ... ).exclude(pk=OuterRef('pk')).values('pk')
  61. >>> When(Exists(non_unique_account_type), then=Value('non unique'))
  62. Keep in mind that each of these values can be an expression.
  63. .. note::
  64. Since the ``then`` keyword argument is reserved for the result of the
  65. ``When()``, there is a potential conflict if a
  66. :class:`~django.db.models.Model` has a field named ``then``. This can be
  67. resolved in two ways::
  68. >>> When(then__exact=0, then=1)
  69. >>> When(Q(then=0), then=1)
  70. ``Case``
  71. --------
  72. .. class:: Case(*cases, **extra)
  73. A ``Case()`` expression is like the :keyword:`if` ... :keyword:`elif` ...
  74. :keyword:`else` statement in ``Python``. Each ``condition`` in the provided
  75. ``When()`` objects is evaluated in order, until one evaluates to a
  76. truthful value. The ``result`` expression from the matching ``When()`` object
  77. is returned.
  78. An example::
  79. >>>
  80. >>> from datetime import date, timedelta
  81. >>> from django.db.models import Case, CharField, Value, When
  82. >>> Client.objects.create(
  83. ... name='Jane Doe',
  84. ... account_type=Client.REGULAR,
  85. ... registered_on=date.today() - timedelta(days=36))
  86. >>> Client.objects.create(
  87. ... name='James Smith',
  88. ... account_type=Client.GOLD,
  89. ... registered_on=date.today() - timedelta(days=5))
  90. >>> Client.objects.create(
  91. ... name='Jack Black',
  92. ... account_type=Client.PLATINUM,
  93. ... registered_on=date.today() - timedelta(days=10 * 365))
  94. >>> # Get the discount for each Client based on the account type
  95. >>> Client.objects.annotate(
  96. ... discount=Case(
  97. ... When(account_type=Client.GOLD, then=Value('5%')),
  98. ... When(account_type=Client.PLATINUM, then=Value('10%')),
  99. ... default=Value('0%'),
  100. ... output_field=CharField(),
  101. ... ),
  102. ... ).values_list('name', 'discount')
  103. <QuerySet [('Jane Doe', '0%'), ('James Smith', '5%'), ('Jack Black', '10%')]>
  104. ``Case()`` accepts any number of ``When()`` objects as individual arguments.
  105. Other options are provided using keyword arguments. If none of the conditions
  106. evaluate to ``TRUE``, then the expression given with the ``default`` keyword
  107. argument is returned. If a ``default`` argument isn't provided, ``None`` is
  108. used.
  109. If we wanted to change our previous query to get the discount based on how long
  110. the ``Client`` has been with us, we could do so using lookups::
  111. >>> a_month_ago = date.today() - timedelta(days=30)
  112. >>> a_year_ago = date.today() - timedelta(days=365)
  113. >>> # Get the discount for each Client based on the registration date
  114. >>> Client.objects.annotate(
  115. ... discount=Case(
  116. ... When(registered_on__lte=a_year_ago, then=Value('10%')),
  117. ... When(registered_on__lte=a_month_ago, then=Value('5%')),
  118. ... default=Value('0%'),
  119. ... output_field=CharField(),
  120. ... )
  121. ... ).values_list('name', 'discount')
  122. <QuerySet [('Jane Doe', '5%'), ('James Smith', '0%'), ('Jack Black', '10%')]>
  123. .. note::
  124. Remember that the conditions are evaluated in order, so in the above
  125. example we get the correct result even though the second condition matches
  126. both Jane Doe and Jack Black. This works just like an :keyword:`if` ...
  127. :keyword:`elif` ... :keyword:`else` statement in ``Python``.
  128. ``Case()`` also works in a ``filter()`` clause. For example, to find gold
  129. clients that registered more than a month ago and platinum clients that
  130. registered more than a year ago::
  131. >>> a_month_ago = date.today() - timedelta(days=30)
  132. >>> a_year_ago = date.today() - timedelta(days=365)
  133. >>> Client.objects.filter(
  134. ... registered_on__lte=Case(
  135. ... When(account_type=Client.GOLD, then=a_month_ago),
  136. ... When(account_type=Client.PLATINUM, then=a_year_ago),
  137. ... ),
  138. ... ).values_list('name', 'account_type')
  139. <QuerySet [('Jack Black', 'P')]>
  140. Advanced queries
  141. ================
  142. Conditional expressions can be used in annotations, aggregations, filters,
  143. lookups, and updates. They can also be combined and nested with other
  144. expressions. This allows you to make powerful conditional queries.
  145. Conditional update
  146. ------------------
  147. Let's say we want to change the ``account_type`` for our clients to match
  148. their registration dates. We can do this using a conditional expression and the
  149. :meth:`~django.db.models.query.QuerySet.update` method::
  150. >>> a_month_ago = date.today() - timedelta(days=30)
  151. >>> a_year_ago = date.today() - timedelta(days=365)
  152. >>> # Update the account_type for each Client from the registration date
  153. >>> Client.objects.update(
  154. ... account_type=Case(
  155. ... When(registered_on__lte=a_year_ago,
  156. ... then=Value(Client.PLATINUM)),
  157. ... When(registered_on__lte=a_month_ago,
  158. ... then=Value(Client.GOLD)),
  159. ... default=Value(Client.REGULAR)
  160. ... ),
  161. ... )
  162. >>> Client.objects.values_list('name', 'account_type')
  163. <QuerySet [('Jane Doe', 'G'), ('James Smith', 'R'), ('Jack Black', 'P')]>
  164. .. _conditional-aggregation:
  165. Conditional aggregation
  166. -----------------------
  167. What if we want to find out how many clients there are for each
  168. ``account_type``? We can use the ``filter`` argument of :ref:`aggregate
  169. functions <aggregation-functions>` to achieve this::
  170. >>> # Create some more Clients first so we can have something to count
  171. >>> Client.objects.create(
  172. ... name='Jean Grey',
  173. ... account_type=Client.REGULAR,
  174. ... registered_on=date.today())
  175. >>> Client.objects.create(
  176. ... name='James Bond',
  177. ... account_type=Client.PLATINUM,
  178. ... registered_on=date.today())
  179. >>> Client.objects.create(
  180. ... name='Jane Porter',
  181. ... account_type=Client.PLATINUM,
  182. ... registered_on=date.today())
  183. >>> # Get counts for each value of account_type
  184. >>> from django.db.models import Count
  185. >>> Client.objects.aggregate(
  186. ... regular=Count('pk', filter=Q(account_type=Client.REGULAR)),
  187. ... gold=Count('pk', filter=Q(account_type=Client.GOLD)),
  188. ... platinum=Count('pk', filter=Q(account_type=Client.PLATINUM)),
  189. ... )
  190. {'regular': 2, 'gold': 1, 'platinum': 3}
  191. This aggregate produces a query with the SQL 2003 ``FILTER WHERE`` syntax
  192. on databases that support it:
  193. .. code-block:: sql
  194. SELECT count('id') FILTER (WHERE account_type=1) as regular,
  195. count('id') FILTER (WHERE account_type=2) as gold,
  196. count('id') FILTER (WHERE account_type=3) as platinum
  197. FROM clients;
  198. On other databases, this is emulated using a ``CASE`` statement:
  199. .. code-block:: sql
  200. SELECT count(CASE WHEN account_type=1 THEN id ELSE null) as regular,
  201. count(CASE WHEN account_type=2 THEN id ELSE null) as gold,
  202. count(CASE WHEN account_type=3 THEN id ELSE null) as platinum
  203. FROM clients;
  204. The two SQL statements are functionally equivalent but the more explicit
  205. ``FILTER`` may perform better.
  206. Conditional filter
  207. ------------------
  208. .. versionadded:: 3.0
  209. When a conditional expression returns a boolean value, it is possible to use it
  210. directly in filters. This means that it will not be added to the ``SELECT``
  211. columns, but you can still use it to filter results::
  212. >>> non_unique_account_type = Client.objects.filter(
  213. ... account_type=OuterRef('account_type'),
  214. ... ).exclude(pk=OuterRef('pk')).values('pk')
  215. >>> Client.objects.filter(~Exists(non_unique_account_type))
  216. In SQL terms, that evaluates to:
  217. .. code-block:: sql
  218. SELECT ...
  219. FROM client c0
  220. WHERE NOT EXISTS (
  221. SELECT c1.id
  222. FROM client c1
  223. WHERE c1.account_type = c0.account_type AND NOT c1.id = c0.id
  224. )