aggregates.txt 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399
  1. =========================================
  2. PostgreSQL specific aggregation functions
  3. =========================================
  4. .. module:: django.contrib.postgres.aggregates
  5. :synopsis: PostgreSQL specific aggregation functions
  6. These functions are available from the ``django.contrib.postgres.aggregates``
  7. module. They are described in more detail in the `PostgreSQL docs
  8. <https://www.postgresql.org/docs/current/functions-aggregate.html>`_.
  9. .. note::
  10. All functions come without default aliases, so you must explicitly provide
  11. one. For example:
  12. .. code-block:: pycon
  13. >>> SomeModel.objects.aggregate(arr=ArrayAgg("somefield"))
  14. {'arr': [0, 1, 2]}
  15. .. admonition:: Common aggregate options
  16. All aggregates have the :ref:`filter <aggregate-filter>` keyword argument
  17. and most also have the :ref:`default <aggregate-default>` keyword argument.
  18. General-purpose aggregation functions
  19. =====================================
  20. ``ArrayAgg``
  21. ------------
  22. .. class:: ArrayAgg(expression, distinct=False, filter=None, default=None, order_by=(), **extra)
  23. Returns a list of values, including nulls, concatenated into an array, or
  24. ``default`` if there are no values.
  25. .. attribute:: distinct
  26. An optional boolean argument that determines if array values
  27. will be distinct. Defaults to ``False``.
  28. .. attribute:: order_by
  29. .. versionadded:: 5.2
  30. An optional string of a field name (with an optional ``"-"`` prefix
  31. which indicates descending order) or an expression (or a tuple or list
  32. of strings and/or expressions) that specifies the ordering of the
  33. elements in the result list.
  34. Examples::
  35. from django.db.models import F
  36. ArrayAgg("a_field", order_by="-some_field")
  37. ArrayAgg("a_field", order_by=F("some_field").desc())
  38. .. deprecated:: 5.2
  39. The ``ordering`` keyword argument is deprecated. Use
  40. :attr:`ArrayAgg.order_by` instead.
  41. ``BitAnd``
  42. ----------
  43. .. class:: BitAnd(expression, filter=None, default=None, **extra)
  44. Returns an ``int`` of the bitwise ``AND`` of all non-null input values, or
  45. ``default`` if all values are null.
  46. ``BitOr``
  47. ---------
  48. .. class:: BitOr(expression, filter=None, default=None, **extra)
  49. Returns an ``int`` of the bitwise ``OR`` of all non-null input values, or
  50. ``default`` if all values are null.
  51. ``BitXor``
  52. ----------
  53. .. class:: BitXor(expression, filter=None, default=None, **extra)
  54. Returns an ``int`` of the bitwise ``XOR`` of all non-null input values, or
  55. ``default`` if all values are null. It requires PostgreSQL 14+.
  56. ``BoolAnd``
  57. -----------
  58. .. class:: BoolAnd(expression, filter=None, default=None, **extra)
  59. Returns ``True``, if all input values are true, ``default`` if all values
  60. are null or if there are no values, otherwise ``False``.
  61. Usage example::
  62. class Comment(models.Model):
  63. body = models.TextField()
  64. published = models.BooleanField()
  65. rank = models.IntegerField()
  66. .. code-block:: pycon
  67. >>> from django.db.models import Q
  68. >>> from django.contrib.postgres.aggregates import BoolAnd
  69. >>> Comment.objects.aggregate(booland=BoolAnd("published"))
  70. {'booland': False}
  71. >>> Comment.objects.aggregate(booland=BoolAnd(Q(rank__lt=100)))
  72. {'booland': True}
  73. ``BoolOr``
  74. ----------
  75. .. class:: BoolOr(expression, filter=None, default=None, **extra)
  76. Returns ``True`` if at least one input value is true, ``default`` if all
  77. values are null or if there are no values, otherwise ``False``.
  78. Usage example::
  79. class Comment(models.Model):
  80. body = models.TextField()
  81. published = models.BooleanField()
  82. rank = models.IntegerField()
  83. .. code-block:: pycon
  84. >>> from django.db.models import Q
  85. >>> from django.contrib.postgres.aggregates import BoolOr
  86. >>> Comment.objects.aggregate(boolor=BoolOr("published"))
  87. {'boolor': True}
  88. >>> Comment.objects.aggregate(boolor=BoolOr(Q(rank__gt=2)))
  89. {'boolor': False}
  90. ``JSONBAgg``
  91. ------------
  92. .. class:: JSONBAgg(expressions, distinct=False, filter=None, default=None, order_by=(), **extra)
  93. Returns the input values as a ``JSON`` array, or ``default`` if there are
  94. no values. You can query the result using :lookup:`key and index lookups
  95. <jsonfield.key>`.
  96. .. attribute:: distinct
  97. An optional boolean argument that determines if array values will be
  98. distinct. Defaults to ``False``.
  99. .. attribute:: order_by
  100. .. versionadded:: 5.2
  101. An optional string of a field name (with an optional ``"-"`` prefix
  102. which indicates descending order) or an expression (or a tuple or list
  103. of strings and/or expressions) that specifies the ordering of the
  104. elements in the result list.
  105. Examples are the same as for :attr:`ArrayAgg.order_by`.
  106. Usage example::
  107. class Room(models.Model):
  108. number = models.IntegerField(unique=True)
  109. class HotelReservation(models.Model):
  110. room = models.ForeignKey("Room", on_delete=models.CASCADE)
  111. start = models.DateTimeField()
  112. end = models.DateTimeField()
  113. requirements = models.JSONField(blank=True, null=True)
  114. .. code-block:: pycon
  115. >>> from django.contrib.postgres.aggregates import JSONBAgg
  116. >>> Room.objects.annotate(
  117. ... requirements=JSONBAgg(
  118. ... "hotelreservation__requirements",
  119. ... order_by="-hotelreservation__start",
  120. ... )
  121. ... ).filter(requirements__0__sea_view=True).values("number", "requirements")
  122. <QuerySet [{'number': 102, 'requirements': [
  123. {'parking': False, 'sea_view': True, 'double_bed': False},
  124. {'parking': True, 'double_bed': True}
  125. ]}]>
  126. .. deprecated:: 5.2
  127. The ``ordering`` keyword argument is deprecated. Use
  128. :attr:`JSONBAgg.order_by` instead.
  129. ``StringAgg``
  130. -------------
  131. .. class:: StringAgg(expression, delimiter, distinct=False, filter=None, default=None, order_by=())
  132. Returns the input values concatenated into a string, separated by
  133. the ``delimiter`` string, or ``default`` if there are no values.
  134. .. attribute:: delimiter
  135. Required argument. Needs to be a string.
  136. .. attribute:: distinct
  137. An optional boolean argument that determines if concatenated values
  138. will be distinct. Defaults to ``False``.
  139. .. attribute:: order_by
  140. .. versionadded:: 5.2
  141. An optional string of a field name (with an optional ``"-"`` prefix
  142. which indicates descending order) or an expression (or a tuple or list
  143. of strings and/or expressions) that specifies the ordering of the
  144. elements in the result string.
  145. Examples are the same as for :attr:`ArrayAgg.order_by`.
  146. Usage example::
  147. class Publication(models.Model):
  148. title = models.CharField(max_length=30)
  149. class Article(models.Model):
  150. headline = models.CharField(max_length=100)
  151. publications = models.ManyToManyField(Publication)
  152. .. code-block:: pycon
  153. >>> article = Article.objects.create(headline="NASA uses Python")
  154. >>> article.publications.create(title="The Python Journal")
  155. <Publication: Publication object (1)>
  156. >>> article.publications.create(title="Science News")
  157. <Publication: Publication object (2)>
  158. >>> from django.contrib.postgres.aggregates import StringAgg
  159. >>> Article.objects.annotate(
  160. ... publication_names=StringAgg(
  161. ... "publications__title",
  162. ... delimiter=", ",
  163. ... order_by="publications__title",
  164. ... )
  165. ... ).values("headline", "publication_names")
  166. <QuerySet [{
  167. 'headline': 'NASA uses Python', 'publication_names': 'Science News, The Python Journal'
  168. }]>
  169. .. deprecated:: 5.2
  170. The ``ordering`` keyword argument is deprecated. Use
  171. :attr:`StringAgg.order_by` instead.
  172. Aggregate functions for statistics
  173. ==================================
  174. ``y`` and ``x``
  175. ---------------
  176. The arguments ``y`` and ``x`` for all these functions can be the name of a
  177. field or an expression returning a numeric data. Both are required.
  178. ``Corr``
  179. --------
  180. .. class:: Corr(y, x, filter=None, default=None)
  181. Returns the correlation coefficient as a ``float``, or ``default`` if there
  182. aren't any matching rows.
  183. ``CovarPop``
  184. ------------
  185. .. class:: CovarPop(y, x, sample=False, filter=None, default=None)
  186. Returns the population covariance as a ``float``, or ``default`` if there
  187. aren't any matching rows.
  188. .. attribute:: sample
  189. Optional. By default ``CovarPop`` returns the general population
  190. covariance. However, if ``sample=True``, the return value will be the
  191. sample population covariance.
  192. ``RegrAvgX``
  193. ------------
  194. .. class:: RegrAvgX(y, x, filter=None, default=None)
  195. Returns the average of the independent variable (``sum(x)/N``) as a
  196. ``float``, or ``default`` if there aren't any matching rows.
  197. ``RegrAvgY``
  198. ------------
  199. .. class:: RegrAvgY(y, x, filter=None, default=None)
  200. Returns the average of the dependent variable (``sum(y)/N``) as a
  201. ``float``, or ``default`` if there aren't any matching rows.
  202. ``RegrCount``
  203. -------------
  204. .. class:: RegrCount(y, x, filter=None)
  205. Returns an ``int`` of the number of input rows in which both expressions
  206. are not null.
  207. .. note::
  208. The ``default`` argument is not supported.
  209. ``RegrIntercept``
  210. -----------------
  211. .. class:: RegrIntercept(y, x, filter=None, default=None)
  212. Returns the y-intercept of the least-squares-fit linear equation determined
  213. by the ``(x, y)`` pairs as a ``float``, or ``default`` if there aren't any
  214. matching rows.
  215. ``RegrR2``
  216. ----------
  217. .. class:: RegrR2(y, x, filter=None, default=None)
  218. Returns the square of the correlation coefficient as a ``float``, or
  219. ``default`` if there aren't any matching rows.
  220. ``RegrSlope``
  221. -------------
  222. .. class:: RegrSlope(y, x, filter=None, default=None)
  223. Returns the slope of the least-squares-fit linear equation determined
  224. by the ``(x, y)`` pairs as a ``float``, or ``default`` if there aren't any
  225. matching rows.
  226. ``RegrSXX``
  227. -----------
  228. .. class:: RegrSXX(y, x, filter=None, default=None)
  229. Returns ``sum(x^2) - sum(x)^2/N`` ("sum of squares" of the independent
  230. variable) as a ``float``, or ``default`` if there aren't any matching rows.
  231. ``RegrSXY``
  232. -----------
  233. .. class:: RegrSXY(y, x, filter=None, default=None)
  234. Returns ``sum(x*y) - sum(x) * sum(y)/N`` ("sum of products" of independent
  235. times dependent variable) as a ``float``, or ``default`` if there aren't
  236. any matching rows.
  237. ``RegrSYY``
  238. -----------
  239. .. class:: RegrSYY(y, x, filter=None, default=None)
  240. Returns ``sum(y^2) - sum(y)^2/N`` ("sum of squares" of the dependent
  241. variable) as a ``float``, or ``default`` if there aren't any matching rows.
  242. Usage examples
  243. ==============
  244. We will use this example table:
  245. .. code-block:: text
  246. | FIELD1 | FIELD2 | FIELD3 |
  247. |--------|--------|--------|
  248. | foo | 1 | 13 |
  249. | bar | 2 | (null) |
  250. | test | 3 | 13 |
  251. Here's some examples of some of the general-purpose aggregation functions:
  252. .. code-block:: pycon
  253. >>> TestModel.objects.aggregate(result=StringAgg("field1", delimiter=";"))
  254. {'result': 'foo;bar;test'}
  255. >>> TestModel.objects.aggregate(result=ArrayAgg("field2"))
  256. {'result': [1, 2, 3]}
  257. >>> TestModel.objects.aggregate(result=ArrayAgg("field1"))
  258. {'result': ['foo', 'bar', 'test']}
  259. The next example shows the usage of statistical aggregate functions. The
  260. underlying math will be not described (you can read about this, for example, at
  261. `wikipedia <https://en.wikipedia.org/wiki/Regression_analysis>`_):
  262. .. code-block:: pycon
  263. >>> TestModel.objects.aggregate(count=RegrCount(y="field3", x="field2"))
  264. {'count': 2}
  265. >>> TestModel.objects.aggregate(
  266. ... avgx=RegrAvgX(y="field3", x="field2"), avgy=RegrAvgY(y="field3", x="field2")
  267. ... )
  268. {'avgx': 2, 'avgy': 13}