database-functions.txt 58 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053105410551056105710581059106010611062106310641065106610671068106910701071107210731074107510761077107810791080108110821083108410851086108710881089109010911092109310941095109610971098109911001101110211031104110511061107110811091110111111121113111411151116111711181119112011211122112311241125112611271128112911301131113211331134113511361137113811391140114111421143114411451146114711481149115011511152115311541155115611571158115911601161116211631164116511661167116811691170117111721173117411751176117711781179118011811182118311841185118611871188118911901191119211931194119511961197119811991200120112021203120412051206120712081209121012111212121312141215121612171218121912201221122212231224122512261227122812291230123112321233123412351236123712381239124012411242124312441245124612471248124912501251125212531254125512561257125812591260126112621263126412651266126712681269127012711272127312741275127612771278127912801281128212831284128512861287128812891290129112921293129412951296129712981299130013011302130313041305130613071308130913101311131213131314131513161317131813191320132113221323132413251326132713281329133013311332133313341335133613371338133913401341134213431344134513461347134813491350135113521353135413551356135713581359136013611362136313641365136613671368136913701371137213731374137513761377137813791380138113821383138413851386138713881389139013911392139313941395139613971398139914001401140214031404140514061407140814091410141114121413141414151416141714181419142014211422142314241425142614271428142914301431143214331434143514361437143814391440144114421443144414451446144714481449145014511452145314541455145614571458145914601461146214631464146514661467146814691470147114721473147414751476147714781479148014811482148314841485148614871488148914901491149214931494149514961497149814991500150115021503150415051506150715081509151015111512151315141515151615171518151915201521152215231524152515261527152815291530153115321533153415351536153715381539154015411542154315441545154615471548154915501551155215531554155515561557155815591560156115621563156415651566156715681569157015711572157315741575157615771578157915801581158215831584158515861587158815891590159115921593159415951596159715981599160016011602160316041605160616071608160916101611161216131614161516161617161816191620162116221623162416251626162716281629163016311632163316341635163616371638163916401641164216431644164516461647164816491650165116521653165416551656165716581659166016611662166316641665166616671668166916701671167216731674167516761677167816791680168116821683168416851686168716881689169016911692169316941695169616971698169917001701170217031704170517061707170817091710171117121713171417151716171717181719172017211722172317241725172617271728172917301731173217331734173517361737173817391740174117421743174417451746174717481749175017511752175317541755175617571758175917601761176217631764176517661767176817691770177117721773177417751776177717781779178017811782178317841785178617871788178917901791
  1. ==================
  2. Database Functions
  3. ==================
  4. .. module:: django.db.models.functions
  5. :synopsis: Database Functions
  6. The classes documented below provide a way for users to use functions provided
  7. by the underlying database as annotations, aggregations, or filters in Django.
  8. Functions are also :doc:`expressions <expressions>`, so they can be used and
  9. combined with other expressions like :ref:`aggregate functions
  10. <aggregation-functions>`.
  11. We'll be using the following model in examples of each function::
  12. class Author(models.Model):
  13. name = models.CharField(max_length=50)
  14. age = models.PositiveIntegerField(null=True, blank=True)
  15. alias = models.CharField(max_length=50, null=True, blank=True)
  16. goes_by = models.CharField(max_length=50, null=True, blank=True)
  17. We don't usually recommend allowing ``null=True`` for ``CharField`` since this
  18. allows the field to have two "empty values", but it's important for the
  19. ``Coalesce`` example below.
  20. .. _comparison-functions:
  21. Comparison and conversion functions
  22. ===================================
  23. ``Cast``
  24. --------
  25. .. class:: Cast(expression, output_field)
  26. Forces the result type of ``expression`` to be the one from ``output_field``.
  27. Usage example::
  28. >>> from django.db.models import FloatField
  29. >>> from django.db.models.functions import Cast
  30. >>> Author.objects.create(age=25, name='Margaret Smith')
  31. >>> author = Author.objects.annotate(
  32. ... age_as_float=Cast('age', output_field=FloatField()),
  33. ... ).get()
  34. >>> print(author.age_as_float)
  35. 25.0
  36. ``Coalesce``
  37. ------------
  38. .. class:: Coalesce(*expressions, **extra)
  39. Accepts a list of at least two field names or expressions and returns the
  40. first non-null value (note that an empty string is not considered a null
  41. value). Each argument must be of a similar type, so mixing text and numbers
  42. will result in a database error.
  43. Usage examples::
  44. >>> # Get a screen name from least to most public
  45. >>> from django.db.models import Sum, Value as V
  46. >>> from django.db.models.functions import Coalesce
  47. >>> Author.objects.create(name='Margaret Smith', goes_by='Maggie')
  48. >>> author = Author.objects.annotate(
  49. ... screen_name=Coalesce('alias', 'goes_by', 'name')).get()
  50. >>> print(author.screen_name)
  51. Maggie
  52. >>> # Prevent an aggregate Sum() from returning None
  53. >>> aggregated = Author.objects.aggregate(
  54. ... combined_age=Coalesce(Sum('age'), V(0)),
  55. ... combined_age_default=Sum('age'))
  56. >>> print(aggregated['combined_age'])
  57. 0
  58. >>> print(aggregated['combined_age_default'])
  59. None
  60. .. warning::
  61. A Python value passed to ``Coalesce`` on MySQL may be converted to an
  62. incorrect type unless explicitly cast to the correct database type:
  63. >>> from django.db.models import DateTimeField
  64. >>> from django.db.models.functions import Cast, Coalesce
  65. >>> from django.utils import timezone
  66. >>> now = timezone.now()
  67. >>> Coalesce('updated', Cast(now, DateTimeField()))
  68. ``Collate``
  69. -----------
  70. .. class:: Collate(expression, collation)
  71. .. versionadded:: 3.2
  72. Takes an expression and a collation name to query against.
  73. For example, to filter case-insensitively in SQLite::
  74. >>> Author.objects.filter(name=Collate(Value('john'), 'nocase'))
  75. <QuerySet [<Author: John>, <Author: john>]>
  76. It can also be used when ordering, for example with PostgreSQL::
  77. >>> Author.objects.order_by(Collate('name', 'et-x-icu'))
  78. <QuerySet [<Author: Ursula>, <Author: Veronika>, <Author: Ülle>]>
  79. ``Greatest``
  80. ------------
  81. .. class:: Greatest(*expressions, **extra)
  82. Accepts a list of at least two field names or expressions and returns the
  83. greatest value. Each argument must be of a similar type, so mixing text and
  84. numbers will result in a database error.
  85. Usage example::
  86. class Blog(models.Model):
  87. body = models.TextField()
  88. modified = models.DateTimeField(auto_now=True)
  89. class Comment(models.Model):
  90. body = models.TextField()
  91. modified = models.DateTimeField(auto_now=True)
  92. blog = models.ForeignKey(Blog, on_delete=models.CASCADE)
  93. >>> from django.db.models.functions import Greatest
  94. >>> blog = Blog.objects.create(body='Greatest is the best.')
  95. >>> comment = Comment.objects.create(body='No, Least is better.', blog=blog)
  96. >>> comments = Comment.objects.annotate(last_updated=Greatest('modified', 'blog__modified'))
  97. >>> annotated_comment = comments.get()
  98. ``annotated_comment.last_updated`` will be the most recent of ``blog.modified``
  99. and ``comment.modified``.
  100. .. warning::
  101. The behavior of ``Greatest`` when one or more expression may be ``null``
  102. varies between databases:
  103. - PostgreSQL: ``Greatest`` will return the largest non-null expression,
  104. or ``null`` if all expressions are ``null``.
  105. - SQLite, Oracle, and MySQL: If any expression is ``null``, ``Greatest``
  106. will return ``null``.
  107. The PostgreSQL behavior can be emulated using ``Coalesce`` if you know
  108. a sensible minimum value to provide as a default.
  109. ``JSONObject``
  110. --------------
  111. .. class:: JSONObject(**fields)
  112. .. versionadded:: 3.2
  113. Takes a list of key-value pairs and returns a JSON object containing those
  114. pairs.
  115. Usage example::
  116. >>> from django.db.models import F
  117. >>> from django.db.models.functions import JSONObject, Lower
  118. >>> Author.objects.create(name='Margaret Smith', alias='msmith', age=25)
  119. >>> author = Author.objects.annotate(json_object=JSONObject(
  120. ... name=Lower('name'),
  121. ... alias='alias',
  122. ... age=F('age') * 2,
  123. ... )).get()
  124. >>> author.json_object
  125. {'name': 'margaret smith', 'alias': 'msmith', 'age': 50}
  126. ``Least``
  127. ---------
  128. .. class:: Least(*expressions, **extra)
  129. Accepts a list of at least two field names or expressions and returns the
  130. least value. Each argument must be of a similar type, so mixing text and numbers
  131. will result in a database error.
  132. .. warning::
  133. The behavior of ``Least`` when one or more expression may be ``null``
  134. varies between databases:
  135. - PostgreSQL: ``Least`` will return the smallest non-null expression,
  136. or ``null`` if all expressions are ``null``.
  137. - SQLite, Oracle, and MySQL: If any expression is ``null``, ``Least``
  138. will return ``null``.
  139. The PostgreSQL behavior can be emulated using ``Coalesce`` if you know
  140. a sensible maximum value to provide as a default.
  141. ``NullIf``
  142. ----------
  143. .. class:: NullIf(expression1, expression2)
  144. Accepts two expressions and returns ``None`` if they are equal, otherwise
  145. returns ``expression1``.
  146. .. admonition:: Caveats on Oracle
  147. Due to an :ref:`Oracle convention<oracle-null-empty-strings>`, this
  148. function returns the empty string instead of ``None`` when the expressions
  149. are of type :class:`~django.db.models.CharField`.
  150. Passing ``Value(None)`` to ``expression1`` is prohibited on Oracle since
  151. Oracle doesn't accept ``NULL`` as the first argument.
  152. .. _date-functions:
  153. Date functions
  154. ==============
  155. We'll be using the following model in examples of each function::
  156. class Experiment(models.Model):
  157. start_datetime = models.DateTimeField()
  158. start_date = models.DateField(null=True, blank=True)
  159. start_time = models.TimeField(null=True, blank=True)
  160. end_datetime = models.DateTimeField(null=True, blank=True)
  161. end_date = models.DateField(null=True, blank=True)
  162. end_time = models.TimeField(null=True, blank=True)
  163. ``Extract``
  164. -----------
  165. .. class:: Extract(expression, lookup_name=None, tzinfo=None, **extra)
  166. Extracts a component of a date as a number.
  167. Takes an ``expression`` representing a ``DateField``, ``DateTimeField``,
  168. ``TimeField``, or ``DurationField`` and a ``lookup_name``, and returns the part
  169. of the date referenced by ``lookup_name`` as an ``IntegerField``.
  170. Django usually uses the databases' extract function, so you may use any
  171. ``lookup_name`` that your database supports. A ``tzinfo`` subclass, usually
  172. provided by ``pytz``, can be passed to extract a value in a specific timezone.
  173. Given the datetime ``2015-06-15 23:30:01.000321+00:00``, the built-in
  174. ``lookup_name``\s return:
  175. * "year": 2015
  176. * "iso_year": 2015
  177. * "quarter": 2
  178. * "month": 6
  179. * "day": 15
  180. * "week": 25
  181. * "week_day": 2
  182. * "iso_week_day": 1
  183. * "hour": 23
  184. * "minute": 30
  185. * "second": 1
  186. If a different timezone like ``Australia/Melbourne`` is active in Django, then
  187. the datetime is converted to the timezone before the value is extracted. The
  188. timezone offset for Melbourne in the example date above is +10:00. The values
  189. returned when this timezone is active will be the same as above except for:
  190. * "day": 16
  191. * "week_day": 3
  192. * "iso_week_day": 2
  193. * "hour": 9
  194. .. admonition:: ``week_day`` values
  195. The ``week_day`` ``lookup_type`` is calculated differently from most
  196. databases and from Python's standard functions. This function will return
  197. ``1`` for Sunday, ``2`` for Monday, through ``7`` for Saturday.
  198. The equivalent calculation in Python is::
  199. >>> from datetime import datetime
  200. >>> dt = datetime(2015, 6, 15)
  201. >>> (dt.isoweekday() % 7) + 1
  202. 2
  203. .. admonition:: ``week`` values
  204. The ``week`` ``lookup_type`` is calculated based on `ISO-8601
  205. <https://en.wikipedia.org/wiki/ISO-8601>`_, i.e.,
  206. a week starts on a Monday. The first week of a year is the one that
  207. contains the year's first Thursday, i.e. the first week has the majority
  208. (four or more) of its days in the year. The value returned is in the range
  209. 1 to 52 or 53.
  210. Each ``lookup_name`` above has a corresponding ``Extract`` subclass (listed
  211. below) that should typically be used instead of the more verbose equivalent,
  212. e.g. use ``ExtractYear(...)`` rather than ``Extract(..., lookup_name='year')``.
  213. Usage example::
  214. >>> from datetime import datetime
  215. >>> from django.db.models.functions import Extract
  216. >>> start = datetime(2015, 6, 15)
  217. >>> end = datetime(2015, 7, 2)
  218. >>> Experiment.objects.create(
  219. ... start_datetime=start, start_date=start.date(),
  220. ... end_datetime=end, end_date=end.date())
  221. >>> # Add the experiment start year as a field in the QuerySet.
  222. >>> experiment = Experiment.objects.annotate(
  223. ... start_year=Extract('start_datetime', 'year')).get()
  224. >>> experiment.start_year
  225. 2015
  226. >>> # How many experiments completed in the same year in which they started?
  227. >>> Experiment.objects.filter(
  228. ... start_datetime__year=Extract('end_datetime', 'year')).count()
  229. 1
  230. ``DateField`` extracts
  231. ~~~~~~~~~~~~~~~~~~~~~~
  232. .. class:: ExtractYear(expression, tzinfo=None, **extra)
  233. .. attribute:: lookup_name = 'year'
  234. .. class:: ExtractIsoYear(expression, tzinfo=None, **extra)
  235. Returns the ISO-8601 week-numbering year.
  236. .. attribute:: lookup_name = 'iso_year'
  237. .. class:: ExtractMonth(expression, tzinfo=None, **extra)
  238. .. attribute:: lookup_name = 'month'
  239. .. class:: ExtractDay(expression, tzinfo=None, **extra)
  240. .. attribute:: lookup_name = 'day'
  241. .. class:: ExtractWeekDay(expression, tzinfo=None, **extra)
  242. .. attribute:: lookup_name = 'week_day'
  243. .. class:: ExtractIsoWeekDay(expression, tzinfo=None, **extra)
  244. Returns the ISO-8601 week day with day 1 being Monday and day 7 being
  245. Sunday.
  246. .. attribute:: lookup_name = 'iso_week_day'
  247. .. class:: ExtractWeek(expression, tzinfo=None, **extra)
  248. .. attribute:: lookup_name = 'week'
  249. .. class:: ExtractQuarter(expression, tzinfo=None, **extra)
  250. .. attribute:: lookup_name = 'quarter'
  251. These are logically equivalent to ``Extract('date_field', lookup_name)``. Each
  252. class is also a ``Transform`` registered on ``DateField`` and ``DateTimeField``
  253. as ``__(lookup_name)``, e.g. ``__year``.
  254. Since ``DateField``\s don't have a time component, only ``Extract`` subclasses
  255. that deal with date-parts can be used with ``DateField``::
  256. >>> from datetime import datetime
  257. >>> from django.utils import timezone
  258. >>> from django.db.models.functions import (
  259. ... ExtractDay, ExtractMonth, ExtractQuarter, ExtractWeek,
  260. ... ExtractIsoWeekDay, ExtractWeekDay, ExtractIsoYear, ExtractYear,
  261. ... )
  262. >>> start_2015 = datetime(2015, 6, 15, 23, 30, 1, tzinfo=timezone.utc)
  263. >>> end_2015 = datetime(2015, 6, 16, 13, 11, 27, tzinfo=timezone.utc)
  264. >>> Experiment.objects.create(
  265. ... start_datetime=start_2015, start_date=start_2015.date(),
  266. ... end_datetime=end_2015, end_date=end_2015.date())
  267. >>> Experiment.objects.annotate(
  268. ... year=ExtractYear('start_date'),
  269. ... isoyear=ExtractIsoYear('start_date'),
  270. ... quarter=ExtractQuarter('start_date'),
  271. ... month=ExtractMonth('start_date'),
  272. ... week=ExtractWeek('start_date'),
  273. ... day=ExtractDay('start_date'),
  274. ... weekday=ExtractWeekDay('start_date'),
  275. ... isoweekday=ExtractIsoWeekDay('start_date'),
  276. ... ).values(
  277. ... 'year', 'isoyear', 'quarter', 'month', 'week', 'day', 'weekday',
  278. ... 'isoweekday',
  279. ... ).get(end_date__year=ExtractYear('start_date'))
  280. {'year': 2015, 'isoyear': 2015, 'quarter': 2, 'month': 6, 'week': 25,
  281. 'day': 15, 'weekday': 2, 'isoweekday': 1}
  282. ``DateTimeField`` extracts
  283. ~~~~~~~~~~~~~~~~~~~~~~~~~~
  284. In addition to the following, all extracts for ``DateField`` listed above may
  285. also be used on ``DateTimeField``\s .
  286. .. class:: ExtractHour(expression, tzinfo=None, **extra)
  287. .. attribute:: lookup_name = 'hour'
  288. .. class:: ExtractMinute(expression, tzinfo=None, **extra)
  289. .. attribute:: lookup_name = 'minute'
  290. .. class:: ExtractSecond(expression, tzinfo=None, **extra)
  291. .. attribute:: lookup_name = 'second'
  292. These are logically equivalent to ``Extract('datetime_field', lookup_name)``.
  293. Each class is also a ``Transform`` registered on ``DateTimeField`` as
  294. ``__(lookup_name)``, e.g. ``__minute``.
  295. ``DateTimeField`` examples::
  296. >>> from datetime import datetime
  297. >>> from django.utils import timezone
  298. >>> from django.db.models.functions import (
  299. ... ExtractDay, ExtractHour, ExtractMinute, ExtractMonth,
  300. ... ExtractQuarter, ExtractSecond, ExtractWeek, ExtractIsoWeekDay,
  301. ... ExtractWeekDay, ExtractIsoYear, ExtractYear,
  302. ... )
  303. >>> start_2015 = datetime(2015, 6, 15, 23, 30, 1, tzinfo=timezone.utc)
  304. >>> end_2015 = datetime(2015, 6, 16, 13, 11, 27, tzinfo=timezone.utc)
  305. >>> Experiment.objects.create(
  306. ... start_datetime=start_2015, start_date=start_2015.date(),
  307. ... end_datetime=end_2015, end_date=end_2015.date())
  308. >>> Experiment.objects.annotate(
  309. ... year=ExtractYear('start_datetime'),
  310. ... isoyear=ExtractIsoYear('start_datetime'),
  311. ... quarter=ExtractQuarter('start_datetime'),
  312. ... month=ExtractMonth('start_datetime'),
  313. ... week=ExtractWeek('start_datetime'),
  314. ... day=ExtractDay('start_datetime'),
  315. ... weekday=ExtractWeekDay('start_datetime'),
  316. ... isoweekday=ExtractIsoWeekDay('start_datetime'),
  317. ... hour=ExtractHour('start_datetime'),
  318. ... minute=ExtractMinute('start_datetime'),
  319. ... second=ExtractSecond('start_datetime'),
  320. ... ).values(
  321. ... 'year', 'isoyear', 'month', 'week', 'day',
  322. ... 'weekday', 'isoweekday', 'hour', 'minute', 'second',
  323. ... ).get(end_datetime__year=ExtractYear('start_datetime'))
  324. {'year': 2015, 'isoyear': 2015, 'quarter': 2, 'month': 6, 'week': 25,
  325. 'day': 15, 'weekday': 2, 'isoweekday': 1, 'hour': 23, 'minute': 30,
  326. 'second': 1}
  327. When :setting:`USE_TZ` is ``True`` then datetimes are stored in the database
  328. in UTC. If a different timezone is active in Django, the datetime is converted
  329. to that timezone before the value is extracted. The example below converts to
  330. the Melbourne timezone (UTC +10:00), which changes the day, weekday, and hour
  331. values that are returned::
  332. >>> import pytz
  333. >>> melb = pytz.timezone('Australia/Melbourne') # UTC+10:00
  334. >>> with timezone.override(melb):
  335. ... Experiment.objects.annotate(
  336. ... day=ExtractDay('start_datetime'),
  337. ... weekday=ExtractWeekDay('start_datetime'),
  338. ... isoweekday=ExtractIsoWeekDay('start_datetime'),
  339. ... hour=ExtractHour('start_datetime'),
  340. ... ).values('day', 'weekday', 'isoweekday', 'hour').get(
  341. ... end_datetime__year=ExtractYear('start_datetime'),
  342. ... )
  343. {'day': 16, 'weekday': 3, 'isoweekday': 2, 'hour': 9}
  344. Explicitly passing the timezone to the ``Extract`` function behaves in the same
  345. way, and takes priority over an active timezone::
  346. >>> import pytz
  347. >>> melb = pytz.timezone('Australia/Melbourne')
  348. >>> Experiment.objects.annotate(
  349. ... day=ExtractDay('start_datetime', tzinfo=melb),
  350. ... weekday=ExtractWeekDay('start_datetime', tzinfo=melb),
  351. ... isoweekday=ExtractIsoWeekDay('start_datetime', tzinfo=melb),
  352. ... hour=ExtractHour('start_datetime', tzinfo=melb),
  353. ... ).values('day', 'weekday', 'isoweekday', 'hour').get(
  354. ... end_datetime__year=ExtractYear('start_datetime'),
  355. ... )
  356. {'day': 16, 'weekday': 3, 'isoweekday': 2, 'hour': 9}
  357. ``Now``
  358. -------
  359. .. class:: Now()
  360. Returns the database server's current date and time when the query is executed,
  361. typically using the SQL ``CURRENT_TIMESTAMP``.
  362. Usage example::
  363. >>> from django.db.models.functions import Now
  364. >>> Article.objects.filter(published__lte=Now())
  365. <QuerySet [<Article: How to Django>]>
  366. .. admonition:: PostgreSQL considerations
  367. On PostgreSQL, the SQL ``CURRENT_TIMESTAMP`` returns the time that the
  368. current transaction started. Therefore for cross-database compatibility,
  369. ``Now()`` uses ``STATEMENT_TIMESTAMP`` instead. If you need the transaction
  370. timestamp, use :class:`django.contrib.postgres.functions.TransactionNow`.
  371. ``Trunc``
  372. ---------
  373. .. class:: Trunc(expression, kind, output_field=None, tzinfo=None, is_dst=None, **extra)
  374. Truncates a date up to a significant component.
  375. When you only care if something happened in a particular year, hour, or day,
  376. but not the exact second, then ``Trunc`` (and its subclasses) can be useful to
  377. filter or aggregate your data. For example, you can use ``Trunc`` to calculate
  378. the number of sales per day.
  379. ``Trunc`` takes a single ``expression``, representing a ``DateField``,
  380. ``TimeField``, or ``DateTimeField``, a ``kind`` representing a date or time
  381. part, and an ``output_field`` that's either ``DateTimeField()``,
  382. ``TimeField()``, or ``DateField()``. It returns a datetime, date, or time
  383. depending on ``output_field``, with fields up to ``kind`` set to their minimum
  384. value. If ``output_field`` is omitted, it will default to the ``output_field``
  385. of ``expression``. A ``tzinfo`` subclass, usually provided by ``pytz``, can be
  386. passed to truncate a value in a specific timezone.
  387. The ``is_dst`` parameter indicates whether or not ``pytz`` should interpret
  388. nonexistent and ambiguous datetimes in daylight saving time. By default (when
  389. ``is_dst=None``), ``pytz`` raises an exception for such datetimes.
  390. Given the datetime ``2015-06-15 14:30:50.000321+00:00``, the built-in ``kind``\s
  391. return:
  392. * "year": 2015-01-01 00:00:00+00:00
  393. * "quarter": 2015-04-01 00:00:00+00:00
  394. * "month": 2015-06-01 00:00:00+00:00
  395. * "week": 2015-06-15 00:00:00+00:00
  396. * "day": 2015-06-15 00:00:00+00:00
  397. * "hour": 2015-06-15 14:00:00+00:00
  398. * "minute": 2015-06-15 14:30:00+00:00
  399. * "second": 2015-06-15 14:30:50+00:00
  400. If a different timezone like ``Australia/Melbourne`` is active in Django, then
  401. the datetime is converted to the new timezone before the value is truncated.
  402. The timezone offset for Melbourne in the example date above is +10:00. The
  403. values returned when this timezone is active will be:
  404. * "year": 2015-01-01 00:00:00+11:00
  405. * "quarter": 2015-04-01 00:00:00+10:00
  406. * "month": 2015-06-01 00:00:00+10:00
  407. * "week": 2015-06-16 00:00:00+10:00
  408. * "day": 2015-06-16 00:00:00+10:00
  409. * "hour": 2015-06-16 00:00:00+10:00
  410. * "minute": 2015-06-16 00:30:00+10:00
  411. * "second": 2015-06-16 00:30:50+10:00
  412. The year has an offset of +11:00 because the result transitioned into daylight
  413. saving time.
  414. Each ``kind`` above has a corresponding ``Trunc`` subclass (listed below) that
  415. should typically be used instead of the more verbose equivalent,
  416. e.g. use ``TruncYear(...)`` rather than ``Trunc(..., kind='year')``.
  417. The subclasses are all defined as transforms, but they aren't registered with
  418. any fields, because the lookup names are already reserved by the ``Extract``
  419. subclasses.
  420. Usage example::
  421. >>> from datetime import datetime
  422. >>> from django.db.models import Count, DateTimeField
  423. >>> from django.db.models.functions import Trunc
  424. >>> Experiment.objects.create(start_datetime=datetime(2015, 6, 15, 14, 30, 50, 321))
  425. >>> Experiment.objects.create(start_datetime=datetime(2015, 6, 15, 14, 40, 2, 123))
  426. >>> Experiment.objects.create(start_datetime=datetime(2015, 12, 25, 10, 5, 27, 999))
  427. >>> experiments_per_day = Experiment.objects.annotate(
  428. ... start_day=Trunc('start_datetime', 'day', output_field=DateTimeField())
  429. ... ).values('start_day').annotate(experiments=Count('id'))
  430. >>> for exp in experiments_per_day:
  431. ... print(exp['start_day'], exp['experiments'])
  432. ...
  433. 2015-06-15 00:00:00 2
  434. 2015-12-25 00:00:00 1
  435. >>> experiments = Experiment.objects.annotate(
  436. ... start_day=Trunc('start_datetime', 'day', output_field=DateTimeField())
  437. ... ).filter(start_day=datetime(2015, 6, 15))
  438. >>> for exp in experiments:
  439. ... print(exp.start_datetime)
  440. ...
  441. 2015-06-15 14:30:50.000321
  442. 2015-06-15 14:40:02.000123
  443. ``DateField`` truncation
  444. ~~~~~~~~~~~~~~~~~~~~~~~~
  445. .. class:: TruncYear(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  446. .. attribute:: kind = 'year'
  447. .. class:: TruncMonth(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  448. .. attribute:: kind = 'month'
  449. .. class:: TruncWeek(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  450. Truncates to midnight on the Monday of the week.
  451. .. attribute:: kind = 'week'
  452. .. class:: TruncQuarter(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  453. .. attribute:: kind = 'quarter'
  454. These are logically equivalent to ``Trunc('date_field', kind)``. They truncate
  455. all parts of the date up to ``kind`` which allows grouping or filtering dates
  456. with less precision. ``expression`` can have an ``output_field`` of either
  457. ``DateField`` or ``DateTimeField``.
  458. Since ``DateField``\s don't have a time component, only ``Trunc`` subclasses
  459. that deal with date-parts can be used with ``DateField``::
  460. >>> from datetime import datetime
  461. >>> from django.db.models import Count
  462. >>> from django.db.models.functions import TruncMonth, TruncYear
  463. >>> from django.utils import timezone
  464. >>> start1 = datetime(2014, 6, 15, 14, 30, 50, 321, tzinfo=timezone.utc)
  465. >>> start2 = datetime(2015, 6, 15, 14, 40, 2, 123, tzinfo=timezone.utc)
  466. >>> start3 = datetime(2015, 12, 31, 17, 5, 27, 999, tzinfo=timezone.utc)
  467. >>> Experiment.objects.create(start_datetime=start1, start_date=start1.date())
  468. >>> Experiment.objects.create(start_datetime=start2, start_date=start2.date())
  469. >>> Experiment.objects.create(start_datetime=start3, start_date=start3.date())
  470. >>> experiments_per_year = Experiment.objects.annotate(
  471. ... year=TruncYear('start_date')).values('year').annotate(
  472. ... experiments=Count('id'))
  473. >>> for exp in experiments_per_year:
  474. ... print(exp['year'], exp['experiments'])
  475. ...
  476. 2014-01-01 1
  477. 2015-01-01 2
  478. >>> import pytz
  479. >>> melb = pytz.timezone('Australia/Melbourne')
  480. >>> experiments_per_month = Experiment.objects.annotate(
  481. ... month=TruncMonth('start_datetime', tzinfo=melb)).values('month').annotate(
  482. ... experiments=Count('id'))
  483. >>> for exp in experiments_per_month:
  484. ... print(exp['month'], exp['experiments'])
  485. ...
  486. 2015-06-01 00:00:00+10:00 1
  487. 2016-01-01 00:00:00+11:00 1
  488. 2014-06-01 00:00:00+10:00 1
  489. ``DateTimeField`` truncation
  490. ~~~~~~~~~~~~~~~~~~~~~~~~~~~~
  491. .. class:: TruncDate(expression, tzinfo=None, **extra)
  492. .. attribute:: lookup_name = 'date'
  493. .. attribute:: output_field = DateField()
  494. .. versionchanged:: 3.2
  495. The ``tzinfo`` parameter was added.
  496. ``TruncDate`` casts ``expression`` to a date rather than using the built-in SQL
  497. truncate function. It's also registered as a transform on ``DateTimeField`` as
  498. ``__date``.
  499. .. class:: TruncTime(expression, tzinfo=None, **extra)
  500. .. attribute:: lookup_name = 'time'
  501. .. attribute:: output_field = TimeField()
  502. .. versionchanged:: 3.2
  503. The ``tzinfo`` parameter was added.
  504. ``TruncTime`` casts ``expression`` to a time rather than using the built-in SQL
  505. truncate function. It's also registered as a transform on ``DateTimeField`` as
  506. ``__time``.
  507. .. class:: TruncDay(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  508. .. attribute:: kind = 'day'
  509. .. class:: TruncHour(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  510. .. attribute:: kind = 'hour'
  511. .. class:: TruncMinute(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  512. .. attribute:: kind = 'minute'
  513. .. class:: TruncSecond(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  514. .. attribute:: kind = 'second'
  515. These are logically equivalent to ``Trunc('datetime_field', kind)``. They
  516. truncate all parts of the date up to ``kind`` and allow grouping or filtering
  517. datetimes with less precision. ``expression`` must have an ``output_field`` of
  518. ``DateTimeField``.
  519. Usage example::
  520. >>> from datetime import date, datetime
  521. >>> from django.db.models import Count
  522. >>> from django.db.models.functions import (
  523. ... TruncDate, TruncDay, TruncHour, TruncMinute, TruncSecond,
  524. ... )
  525. >>> from django.utils import timezone
  526. >>> import pytz
  527. >>> start1 = datetime(2014, 6, 15, 14, 30, 50, 321, tzinfo=timezone.utc)
  528. >>> Experiment.objects.create(start_datetime=start1, start_date=start1.date())
  529. >>> melb = pytz.timezone('Australia/Melbourne')
  530. >>> Experiment.objects.annotate(
  531. ... date=TruncDate('start_datetime'),
  532. ... day=TruncDay('start_datetime', tzinfo=melb),
  533. ... hour=TruncHour('start_datetime', tzinfo=melb),
  534. ... minute=TruncMinute('start_datetime'),
  535. ... second=TruncSecond('start_datetime'),
  536. ... ).values('date', 'day', 'hour', 'minute', 'second').get()
  537. {'date': datetime.date(2014, 6, 15),
  538. 'day': datetime.datetime(2014, 6, 16, 0, 0, tzinfo=<DstTzInfo 'Australia/Melbourne' AEST+10:00:00 STD>),
  539. 'hour': datetime.datetime(2014, 6, 16, 0, 0, tzinfo=<DstTzInfo 'Australia/Melbourne' AEST+10:00:00 STD>),
  540. 'minute': 'minute': datetime.datetime(2014, 6, 15, 14, 30, tzinfo=<UTC>),
  541. 'second': datetime.datetime(2014, 6, 15, 14, 30, 50, tzinfo=<UTC>)
  542. }
  543. ``TimeField`` truncation
  544. ~~~~~~~~~~~~~~~~~~~~~~~~
  545. .. class:: TruncHour(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  546. :noindex:
  547. .. attribute:: kind = 'hour'
  548. .. class:: TruncMinute(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  549. :noindex:
  550. .. attribute:: kind = 'minute'
  551. .. class:: TruncSecond(expression, output_field=None, tzinfo=None, is_dst=None, **extra)
  552. :noindex:
  553. .. attribute:: kind = 'second'
  554. These are logically equivalent to ``Trunc('time_field', kind)``. They truncate
  555. all parts of the time up to ``kind`` which allows grouping or filtering times
  556. with less precision. ``expression`` can have an ``output_field`` of either
  557. ``TimeField`` or ``DateTimeField``.
  558. Since ``TimeField``\s don't have a date component, only ``Trunc`` subclasses
  559. that deal with time-parts can be used with ``TimeField``::
  560. >>> from datetime import datetime
  561. >>> from django.db.models import Count, TimeField
  562. >>> from django.db.models.functions import TruncHour
  563. >>> from django.utils import timezone
  564. >>> start1 = datetime(2014, 6, 15, 14, 30, 50, 321, tzinfo=timezone.utc)
  565. >>> start2 = datetime(2014, 6, 15, 14, 40, 2, 123, tzinfo=timezone.utc)
  566. >>> start3 = datetime(2015, 12, 31, 17, 5, 27, 999, tzinfo=timezone.utc)
  567. >>> Experiment.objects.create(start_datetime=start1, start_time=start1.time())
  568. >>> Experiment.objects.create(start_datetime=start2, start_time=start2.time())
  569. >>> Experiment.objects.create(start_datetime=start3, start_time=start3.time())
  570. >>> experiments_per_hour = Experiment.objects.annotate(
  571. ... hour=TruncHour('start_datetime', output_field=TimeField()),
  572. ... ).values('hour').annotate(experiments=Count('id'))
  573. >>> for exp in experiments_per_hour:
  574. ... print(exp['hour'], exp['experiments'])
  575. ...
  576. 14:00:00 2
  577. 17:00:00 1
  578. >>> import pytz
  579. >>> melb = pytz.timezone('Australia/Melbourne')
  580. >>> experiments_per_hour = Experiment.objects.annotate(
  581. ... hour=TruncHour('start_datetime', tzinfo=melb),
  582. ... ).values('hour').annotate(experiments=Count('id'))
  583. >>> for exp in experiments_per_hour:
  584. ... print(exp['hour'], exp['experiments'])
  585. ...
  586. 2014-06-16 00:00:00+10:00 2
  587. 2016-01-01 04:00:00+11:00 1
  588. .. _math-functions:
  589. Math Functions
  590. ==============
  591. We'll be using the following model in math function examples::
  592. class Vector(models.Model):
  593. x = models.FloatField()
  594. y = models.FloatField()
  595. ``Abs``
  596. -------
  597. .. class:: Abs(expression, **extra)
  598. Returns the absolute value of a numeric field or expression.
  599. Usage example::
  600. >>> from django.db.models.functions import Abs
  601. >>> Vector.objects.create(x=-0.5, y=1.1)
  602. >>> vector = Vector.objects.annotate(x_abs=Abs('x'), y_abs=Abs('y')).get()
  603. >>> vector.x_abs, vector.y_abs
  604. (0.5, 1.1)
  605. It can also be registered as a transform. For example::
  606. >>> from django.db.models import FloatField
  607. >>> from django.db.models.functions import Abs
  608. >>> FloatField.register_lookup(Abs)
  609. >>> # Get vectors inside the unit cube
  610. >>> vectors = Vector.objects.filter(x__abs__lt=1, y__abs__lt=1)
  611. ``ACos``
  612. --------
  613. .. class:: ACos(expression, **extra)
  614. Returns the arccosine of a numeric field or expression. The expression value
  615. must be within the range -1 to 1.
  616. Usage example::
  617. >>> from django.db.models.functions import ACos
  618. >>> Vector.objects.create(x=0.5, y=-0.9)
  619. >>> vector = Vector.objects.annotate(x_acos=ACos('x'), y_acos=ACos('y')).get()
  620. >>> vector.x_acos, vector.y_acos
  621. (1.0471975511965979, 2.6905658417935308)
  622. It can also be registered as a transform. For example::
  623. >>> from django.db.models import FloatField
  624. >>> from django.db.models.functions import ACos
  625. >>> FloatField.register_lookup(ACos)
  626. >>> # Get vectors whose arccosine is less than 1
  627. >>> vectors = Vector.objects.filter(x__acos__lt=1, y__acos__lt=1)
  628. ``ASin``
  629. --------
  630. .. class:: ASin(expression, **extra)
  631. Returns the arcsine of a numeric field or expression. The expression value must
  632. be in the range -1 to 1.
  633. Usage example::
  634. >>> from django.db.models.functions import ASin
  635. >>> Vector.objects.create(x=0, y=1)
  636. >>> vector = Vector.objects.annotate(x_asin=ASin('x'), y_asin=ASin('y')).get()
  637. >>> vector.x_asin, vector.y_asin
  638. (0.0, 1.5707963267948966)
  639. It can also be registered as a transform. For example::
  640. >>> from django.db.models import FloatField
  641. >>> from django.db.models.functions import ASin
  642. >>> FloatField.register_lookup(ASin)
  643. >>> # Get vectors whose arcsine is less than 1
  644. >>> vectors = Vector.objects.filter(x__asin__lt=1, y__asin__lt=1)
  645. ``ATan``
  646. --------
  647. .. class:: ATan(expression, **extra)
  648. Returns the arctangent of a numeric field or expression.
  649. Usage example::
  650. >>> from django.db.models.functions import ATan
  651. >>> Vector.objects.create(x=3.12, y=6.987)
  652. >>> vector = Vector.objects.annotate(x_atan=ATan('x'), y_atan=ATan('y')).get()
  653. >>> vector.x_atan, vector.y_atan
  654. (1.2606282660069106, 1.428638798133829)
  655. It can also be registered as a transform. For example::
  656. >>> from django.db.models import FloatField
  657. >>> from django.db.models.functions import ATan
  658. >>> FloatField.register_lookup(ATan)
  659. >>> # Get vectors whose arctangent is less than 2
  660. >>> vectors = Vector.objects.filter(x__atan__lt=2, y__atan__lt=2)
  661. ``ATan2``
  662. ---------
  663. .. class:: ATan2(expression1, expression2, **extra)
  664. Returns the arctangent of ``expression1 / expression2``.
  665. Usage example::
  666. >>> from django.db.models.functions import ATan2
  667. >>> Vector.objects.create(x=2.5, y=1.9)
  668. >>> vector = Vector.objects.annotate(atan2=ATan2('x', 'y')).get()
  669. >>> vector.atan2
  670. 0.9209258773829491
  671. ``Ceil``
  672. --------
  673. .. class:: Ceil(expression, **extra)
  674. Returns the smallest integer greater than or equal to a numeric field or
  675. expression.
  676. Usage example::
  677. >>> from django.db.models.functions import Ceil
  678. >>> Vector.objects.create(x=3.12, y=7.0)
  679. >>> vector = Vector.objects.annotate(x_ceil=Ceil('x'), y_ceil=Ceil('y')).get()
  680. >>> vector.x_ceil, vector.y_ceil
  681. (4.0, 7.0)
  682. It can also be registered as a transform. For example::
  683. >>> from django.db.models import FloatField
  684. >>> from django.db.models.functions import Ceil
  685. >>> FloatField.register_lookup(Ceil)
  686. >>> # Get vectors whose ceil is less than 10
  687. >>> vectors = Vector.objects.filter(x__ceil__lt=10, y__ceil__lt=10)
  688. ``Cos``
  689. -------
  690. .. class:: Cos(expression, **extra)
  691. Returns the cosine of a numeric field or expression.
  692. Usage example::
  693. >>> from django.db.models.functions import Cos
  694. >>> Vector.objects.create(x=-8.0, y=3.1415926)
  695. >>> vector = Vector.objects.annotate(x_cos=Cos('x'), y_cos=Cos('y')).get()
  696. >>> vector.x_cos, vector.y_cos
  697. (-0.14550003380861354, -0.9999999999999986)
  698. It can also be registered as a transform. For example::
  699. >>> from django.db.models import FloatField
  700. >>> from django.db.models.functions import Cos
  701. >>> FloatField.register_lookup(Cos)
  702. >>> # Get vectors whose cosine is less than 0.5
  703. >>> vectors = Vector.objects.filter(x__cos__lt=0.5, y__cos__lt=0.5)
  704. ``Cot``
  705. -------
  706. .. class:: Cot(expression, **extra)
  707. Returns the cotangent of a numeric field or expression.
  708. Usage example::
  709. >>> from django.db.models.functions import Cot
  710. >>> Vector.objects.create(x=12.0, y=1.0)
  711. >>> vector = Vector.objects.annotate(x_cot=Cot('x'), y_cot=Cot('y')).get()
  712. >>> vector.x_cot, vector.y_cot
  713. (-1.5726734063976826, 0.642092615934331)
  714. It can also be registered as a transform. For example::
  715. >>> from django.db.models import FloatField
  716. >>> from django.db.models.functions import Cot
  717. >>> FloatField.register_lookup(Cot)
  718. >>> # Get vectors whose cotangent is less than 1
  719. >>> vectors = Vector.objects.filter(x__cot__lt=1, y__cot__lt=1)
  720. ``Degrees``
  721. -----------
  722. .. class:: Degrees(expression, **extra)
  723. Converts a numeric field or expression from radians to degrees.
  724. Usage example::
  725. >>> from django.db.models.functions import Degrees
  726. >>> Vector.objects.create(x=-1.57, y=3.14)
  727. >>> vector = Vector.objects.annotate(x_d=Degrees('x'), y_d=Degrees('y')).get()
  728. >>> vector.x_d, vector.y_d
  729. (-89.95437383553924, 179.9087476710785)
  730. It can also be registered as a transform. For example::
  731. >>> from django.db.models import FloatField
  732. >>> from django.db.models.functions import Degrees
  733. >>> FloatField.register_lookup(Degrees)
  734. >>> # Get vectors whose degrees are less than 360
  735. >>> vectors = Vector.objects.filter(x__degrees__lt=360, y__degrees__lt=360)
  736. ``Exp``
  737. -------
  738. .. class:: Exp(expression, **extra)
  739. Returns the value of ``e`` (the natural logarithm base) raised to the power of
  740. a numeric field or expression.
  741. Usage example::
  742. >>> from django.db.models.functions import Exp
  743. >>> Vector.objects.create(x=5.4, y=-2.0)
  744. >>> vector = Vector.objects.annotate(x_exp=Exp('x'), y_exp=Exp('y')).get()
  745. >>> vector.x_exp, vector.y_exp
  746. (221.40641620418717, 0.1353352832366127)
  747. It can also be registered as a transform. For example::
  748. >>> from django.db.models import FloatField
  749. >>> from django.db.models.functions import Exp
  750. >>> FloatField.register_lookup(Exp)
  751. >>> # Get vectors whose exp() is greater than 10
  752. >>> vectors = Vector.objects.filter(x__exp__gt=10, y__exp__gt=10)
  753. ``Floor``
  754. ---------
  755. .. class:: Floor(expression, **extra)
  756. Returns the largest integer value not greater than a numeric field or
  757. expression.
  758. Usage example::
  759. >>> from django.db.models.functions import Floor
  760. >>> Vector.objects.create(x=5.4, y=-2.3)
  761. >>> vector = Vector.objects.annotate(x_floor=Floor('x'), y_floor=Floor('y')).get()
  762. >>> vector.x_floor, vector.y_floor
  763. (5.0, -3.0)
  764. It can also be registered as a transform. For example::
  765. >>> from django.db.models import FloatField
  766. >>> from django.db.models.functions import Floor
  767. >>> FloatField.register_lookup(Floor)
  768. >>> # Get vectors whose floor() is greater than 10
  769. >>> vectors = Vector.objects.filter(x__floor__gt=10, y__floor__gt=10)
  770. ``Ln``
  771. ------
  772. .. class:: Ln(expression, **extra)
  773. Returns the natural logarithm a numeric field or expression.
  774. Usage example::
  775. >>> from django.db.models.functions import Ln
  776. >>> Vector.objects.create(x=5.4, y=233.0)
  777. >>> vector = Vector.objects.annotate(x_ln=Ln('x'), y_ln=Ln('y')).get()
  778. >>> vector.x_ln, vector.y_ln
  779. (1.6863989535702288, 5.4510384535657)
  780. It can also be registered as a transform. For example::
  781. >>> from django.db.models import FloatField
  782. >>> from django.db.models.functions import Ln
  783. >>> FloatField.register_lookup(Ln)
  784. >>> # Get vectors whose value greater than e
  785. >>> vectors = Vector.objects.filter(x__ln__gt=1, y__ln__gt=1)
  786. ``Log``
  787. -------
  788. .. class:: Log(expression1, expression2, **extra)
  789. Accepts two numeric fields or expressions and returns the logarithm of
  790. the first to base of the second.
  791. Usage example::
  792. >>> from django.db.models.functions import Log
  793. >>> Vector.objects.create(x=2.0, y=4.0)
  794. >>> vector = Vector.objects.annotate(log=Log('x', 'y')).get()
  795. >>> vector.log
  796. 2.0
  797. ``Mod``
  798. -------
  799. .. class:: Mod(expression1, expression2, **extra)
  800. Accepts two numeric fields or expressions and returns the remainder of
  801. the first divided by the second (modulo operation).
  802. Usage example::
  803. >>> from django.db.models.functions import Mod
  804. >>> Vector.objects.create(x=5.4, y=2.3)
  805. >>> vector = Vector.objects.annotate(mod=Mod('x', 'y')).get()
  806. >>> vector.mod
  807. 0.8
  808. ``Pi``
  809. ------
  810. .. class:: Pi(**extra)
  811. Returns the value of the mathematical constant ``π``.
  812. ``Power``
  813. ---------
  814. .. class:: Power(expression1, expression2, **extra)
  815. Accepts two numeric fields or expressions and returns the value of the first
  816. raised to the power of the second.
  817. Usage example::
  818. >>> from django.db.models.functions import Power
  819. >>> Vector.objects.create(x=2, y=-2)
  820. >>> vector = Vector.objects.annotate(power=Power('x', 'y')).get()
  821. >>> vector.power
  822. 0.25
  823. ``Radians``
  824. -----------
  825. .. class:: Radians(expression, **extra)
  826. Converts a numeric field or expression from degrees to radians.
  827. Usage example::
  828. >>> from django.db.models.functions import Radians
  829. >>> Vector.objects.create(x=-90, y=180)
  830. >>> vector = Vector.objects.annotate(x_r=Radians('x'), y_r=Radians('y')).get()
  831. >>> vector.x_r, vector.y_r
  832. (-1.5707963267948966, 3.141592653589793)
  833. It can also be registered as a transform. For example::
  834. >>> from django.db.models import FloatField
  835. >>> from django.db.models.functions import Radians
  836. >>> FloatField.register_lookup(Radians)
  837. >>> # Get vectors whose radians are less than 1
  838. >>> vectors = Vector.objects.filter(x__radians__lt=1, y__radians__lt=1)
  839. ``Random``
  840. ----------
  841. .. class:: Random(**extra)
  842. .. versionadded:: 3.2
  843. Returns a random value in the range ``0.0 ≤ x < 1.0``.
  844. ``Round``
  845. ---------
  846. .. class:: Round(expression, precision=0, **extra)
  847. Rounds a numeric field or expression to ``precision`` (must be an integer)
  848. decimal places. By default, it rounds to the nearest integer. Whether half
  849. values are rounded up or down depends on the database.
  850. Usage example::
  851. >>> from django.db.models.functions import Round
  852. >>> Vector.objects.create(x=5.4, y=-2.37)
  853. >>> vector = Vector.objects.annotate(x_r=Round('x'), y_r=Round('y', precision=1)).get()
  854. >>> vector.x_r, vector.y_r
  855. (5.0, -2.4)
  856. It can also be registered as a transform. For example::
  857. >>> from django.db.models import FloatField
  858. >>> from django.db.models.functions import Round
  859. >>> FloatField.register_lookup(Round)
  860. >>> # Get vectors whose round() is less than 20
  861. >>> vectors = Vector.objects.filter(x__round__lt=20, y__round__lt=20)
  862. .. versionchanged:: 4.0
  863. The ``precision`` argument was added.
  864. ``Sign``
  865. --------
  866. .. class:: Sign(expression, **extra)
  867. Returns the sign (-1, 0, 1) of a numeric field or expression.
  868. Usage example::
  869. >>> from django.db.models.functions import Sign
  870. >>> Vector.objects.create(x=5.4, y=-2.3)
  871. >>> vector = Vector.objects.annotate(x_sign=Sign('x'), y_sign=Sign('y')).get()
  872. >>> vector.x_sign, vector.y_sign
  873. (1, -1)
  874. It can also be registered as a transform. For example::
  875. >>> from django.db.models import FloatField
  876. >>> from django.db.models.functions import Sign
  877. >>> FloatField.register_lookup(Sign)
  878. >>> # Get vectors whose signs of components are less than 0.
  879. >>> vectors = Vector.objects.filter(x__sign__lt=0, y__sign__lt=0)
  880. ``Sin``
  881. -------
  882. .. class:: Sin(expression, **extra)
  883. Returns the sine of a numeric field or expression.
  884. Usage example::
  885. >>> from django.db.models.functions import Sin
  886. >>> Vector.objects.create(x=5.4, y=-2.3)
  887. >>> vector = Vector.objects.annotate(x_sin=Sin('x'), y_sin=Sin('y')).get()
  888. >>> vector.x_sin, vector.y_sin
  889. (-0.7727644875559871, -0.7457052121767203)
  890. It can also be registered as a transform. For example::
  891. >>> from django.db.models import FloatField
  892. >>> from django.db.models.functions import Sin
  893. >>> FloatField.register_lookup(Sin)
  894. >>> # Get vectors whose sin() is less than 0
  895. >>> vectors = Vector.objects.filter(x__sin__lt=0, y__sin__lt=0)
  896. ``Sqrt``
  897. --------
  898. .. class:: Sqrt(expression, **extra)
  899. Returns the square root of a nonnegative numeric field or expression.
  900. Usage example::
  901. >>> from django.db.models.functions import Sqrt
  902. >>> Vector.objects.create(x=4.0, y=12.0)
  903. >>> vector = Vector.objects.annotate(x_sqrt=Sqrt('x'), y_sqrt=Sqrt('y')).get()
  904. >>> vector.x_sqrt, vector.y_sqrt
  905. (2.0, 3.46410)
  906. It can also be registered as a transform. For example::
  907. >>> from django.db.models import FloatField
  908. >>> from django.db.models.functions import Sqrt
  909. >>> FloatField.register_lookup(Sqrt)
  910. >>> # Get vectors whose sqrt() is less than 5
  911. >>> vectors = Vector.objects.filter(x__sqrt__lt=5, y__sqrt__lt=5)
  912. ``Tan``
  913. -------
  914. .. class:: Tan(expression, **extra)
  915. Returns the tangent of a numeric field or expression.
  916. Usage example::
  917. >>> from django.db.models.functions import Tan
  918. >>> Vector.objects.create(x=0, y=12)
  919. >>> vector = Vector.objects.annotate(x_tan=Tan('x'), y_tan=Tan('y')).get()
  920. >>> vector.x_tan, vector.y_tan
  921. (0.0, -0.6358599286615808)
  922. It can also be registered as a transform. For example::
  923. >>> from django.db.models import FloatField
  924. >>> from django.db.models.functions import Tan
  925. >>> FloatField.register_lookup(Tan)
  926. >>> # Get vectors whose tangent is less than 0
  927. >>> vectors = Vector.objects.filter(x__tan__lt=0, y__tan__lt=0)
  928. .. _text-functions:
  929. Text functions
  930. ==============
  931. ``Chr``
  932. -------
  933. .. class:: Chr(expression, **extra)
  934. Accepts a numeric field or expression and returns the text representation of
  935. the expression as a single character. It works the same as Python's :func:`chr`
  936. function.
  937. Like :class:`Length`, it can be registered as a transform on ``IntegerField``.
  938. The default lookup name is ``chr``.
  939. Usage example::
  940. >>> from django.db.models.functions import Chr
  941. >>> Author.objects.create(name='Margaret Smith')
  942. >>> author = Author.objects.filter(name__startswith=Chr(ord('M'))).get()
  943. >>> print(author.name)
  944. Margaret Smith
  945. ``Concat``
  946. ----------
  947. .. class:: Concat(*expressions, **extra)
  948. Accepts a list of at least two text fields or expressions and returns the
  949. concatenated text. Each argument must be of a text or char type. If you want
  950. to concatenate a ``TextField()`` with a ``CharField()``, then be sure to tell
  951. Django that the ``output_field`` should be a ``TextField()``. Specifying an
  952. ``output_field`` is also required when concatenating a ``Value`` as in the
  953. example below.
  954. This function will never have a null result. On backends where a null argument
  955. results in the entire expression being null, Django will ensure that each null
  956. part is converted to an empty string first.
  957. Usage example::
  958. >>> # Get the display name as "name (goes_by)"
  959. >>> from django.db.models import CharField, Value as V
  960. >>> from django.db.models.functions import Concat
  961. >>> Author.objects.create(name='Margaret Smith', goes_by='Maggie')
  962. >>> author = Author.objects.annotate(
  963. ... screen_name=Concat(
  964. ... 'name', V(' ('), 'goes_by', V(')'),
  965. ... output_field=CharField()
  966. ... )
  967. ... ).get()
  968. >>> print(author.screen_name)
  969. Margaret Smith (Maggie)
  970. ``Left``
  971. --------
  972. .. class:: Left(expression, length, **extra)
  973. Returns the first ``length`` characters of the given text field or expression.
  974. Usage example::
  975. >>> from django.db.models.functions import Left
  976. >>> Author.objects.create(name='Margaret Smith')
  977. >>> author = Author.objects.annotate(first_initial=Left('name', 1)).get()
  978. >>> print(author.first_initial)
  979. M
  980. ``Length``
  981. ----------
  982. .. class:: Length(expression, **extra)
  983. Accepts a single text field or expression and returns the number of characters
  984. the value has. If the expression is null, then the length will also be null.
  985. Usage example::
  986. >>> # Get the length of the name and goes_by fields
  987. >>> from django.db.models.functions import Length
  988. >>> Author.objects.create(name='Margaret Smith')
  989. >>> author = Author.objects.annotate(
  990. ... name_length=Length('name'),
  991. ... goes_by_length=Length('goes_by')).get()
  992. >>> print(author.name_length, author.goes_by_length)
  993. (14, None)
  994. It can also be registered as a transform. For example::
  995. >>> from django.db.models import CharField
  996. >>> from django.db.models.functions import Length
  997. >>> CharField.register_lookup(Length)
  998. >>> # Get authors whose name is longer than 7 characters
  999. >>> authors = Author.objects.filter(name__length__gt=7)
  1000. ``Lower``
  1001. ---------
  1002. .. class:: Lower(expression, **extra)
  1003. Accepts a single text field or expression and returns the lowercase
  1004. representation.
  1005. It can also be registered as a transform as described in :class:`Length`.
  1006. Usage example::
  1007. >>> from django.db.models.functions import Lower
  1008. >>> Author.objects.create(name='Margaret Smith')
  1009. >>> author = Author.objects.annotate(name_lower=Lower('name')).get()
  1010. >>> print(author.name_lower)
  1011. margaret smith
  1012. ``LPad``
  1013. --------
  1014. .. class:: LPad(expression, length, fill_text=Value(' '), **extra)
  1015. Returns the value of the given text field or expression padded on the left side
  1016. with ``fill_text`` so that the resulting value is ``length`` characters long.
  1017. The default ``fill_text`` is a space.
  1018. Usage example::
  1019. >>> from django.db.models import Value
  1020. >>> from django.db.models.functions import LPad
  1021. >>> Author.objects.create(name='John', alias='j')
  1022. >>> Author.objects.update(name=LPad('name', 8, Value('abc')))
  1023. 1
  1024. >>> print(Author.objects.get(alias='j').name)
  1025. abcaJohn
  1026. ``LTrim``
  1027. ---------
  1028. .. class:: LTrim(expression, **extra)
  1029. Similar to :class:`~django.db.models.functions.Trim`, but removes only leading
  1030. spaces.
  1031. ``MD5``
  1032. -------
  1033. .. class:: MD5(expression, **extra)
  1034. Accepts a single text field or expression and returns the MD5 hash of the
  1035. string.
  1036. It can also be registered as a transform as described in :class:`Length`.
  1037. Usage example::
  1038. >>> from django.db.models.functions import MD5
  1039. >>> Author.objects.create(name='Margaret Smith')
  1040. >>> author = Author.objects.annotate(name_md5=MD5('name')).get()
  1041. >>> print(author.name_md5)
  1042. 749fb689816b2db85f5b169c2055b247
  1043. ``Ord``
  1044. -------
  1045. .. class:: Ord(expression, **extra)
  1046. Accepts a single text field or expression and returns the Unicode code point
  1047. value for the first character of that expression. It works similar to Python's
  1048. :func:`ord` function, but an exception isn't raised if the expression is more
  1049. than one character long.
  1050. It can also be registered as a transform as described in :class:`Length`.
  1051. The default lookup name is ``ord``.
  1052. Usage example::
  1053. >>> from django.db.models.functions import Ord
  1054. >>> Author.objects.create(name='Margaret Smith')
  1055. >>> author = Author.objects.annotate(name_code_point=Ord('name')).get()
  1056. >>> print(author.name_code_point)
  1057. 77
  1058. ``Repeat``
  1059. ----------
  1060. .. class:: Repeat(expression, number, **extra)
  1061. Returns the value of the given text field or expression repeated ``number``
  1062. times.
  1063. Usage example::
  1064. >>> from django.db.models.functions import Repeat
  1065. >>> Author.objects.create(name='John', alias='j')
  1066. >>> Author.objects.update(name=Repeat('name', 3))
  1067. 1
  1068. >>> print(Author.objects.get(alias='j').name)
  1069. JohnJohnJohn
  1070. ``Replace``
  1071. -----------
  1072. .. class:: Replace(expression, text, replacement=Value(''), **extra)
  1073. Replaces all occurrences of ``text`` with ``replacement`` in ``expression``.
  1074. The default replacement text is the empty string. The arguments to the function
  1075. are case-sensitive.
  1076. Usage example::
  1077. >>> from django.db.models import Value
  1078. >>> from django.db.models.functions import Replace
  1079. >>> Author.objects.create(name='Margaret Johnson')
  1080. >>> Author.objects.create(name='Margaret Smith')
  1081. >>> Author.objects.update(name=Replace('name', Value('Margaret'), Value('Margareth')))
  1082. 2
  1083. >>> Author.objects.values('name')
  1084. <QuerySet [{'name': 'Margareth Johnson'}, {'name': 'Margareth Smith'}]>
  1085. ``Reverse``
  1086. -----------
  1087. .. class:: Reverse(expression, **extra)
  1088. Accepts a single text field or expression and returns the characters of that
  1089. expression in reverse order.
  1090. It can also be registered as a transform as described in :class:`Length`. The
  1091. default lookup name is ``reverse``.
  1092. Usage example::
  1093. >>> from django.db.models.functions import Reverse
  1094. >>> Author.objects.create(name='Margaret Smith')
  1095. >>> author = Author.objects.annotate(backward=Reverse('name')).get()
  1096. >>> print(author.backward)
  1097. htimS teragraM
  1098. ``Right``
  1099. ---------
  1100. .. class:: Right(expression, length, **extra)
  1101. Returns the last ``length`` characters of the given text field or expression.
  1102. Usage example::
  1103. >>> from django.db.models.functions import Right
  1104. >>> Author.objects.create(name='Margaret Smith')
  1105. >>> author = Author.objects.annotate(last_letter=Right('name', 1)).get()
  1106. >>> print(author.last_letter)
  1107. h
  1108. ``RPad``
  1109. --------
  1110. .. class:: RPad(expression, length, fill_text=Value(' '), **extra)
  1111. Similar to :class:`~django.db.models.functions.LPad`, but pads on the right
  1112. side.
  1113. ``RTrim``
  1114. ---------
  1115. .. class:: RTrim(expression, **extra)
  1116. Similar to :class:`~django.db.models.functions.Trim`, but removes only trailing
  1117. spaces.
  1118. ``SHA1``, ``SHA224``, ``SHA256``, ``SHA384``, and ``SHA512``
  1119. ------------------------------------------------------------
  1120. .. class:: SHA1(expression, **extra)
  1121. .. class:: SHA224(expression, **extra)
  1122. .. class:: SHA256(expression, **extra)
  1123. .. class:: SHA384(expression, **extra)
  1124. .. class:: SHA512(expression, **extra)
  1125. Accepts a single text field or expression and returns the particular hash of
  1126. the string.
  1127. They can also be registered as transforms as described in :class:`Length`.
  1128. Usage example::
  1129. >>> from django.db.models.functions import SHA1
  1130. >>> Author.objects.create(name='Margaret Smith')
  1131. >>> author = Author.objects.annotate(name_sha1=SHA1('name')).get()
  1132. >>> print(author.name_sha1)
  1133. b87efd8a6c991c390be5a68e8a7945a7851c7e5c
  1134. .. admonition:: PostgreSQL
  1135. The `pgcrypto extension <https://www.postgresql.org/docs/current/
  1136. pgcrypto.html>`_ must be installed. You can use the
  1137. :class:`~django.contrib.postgres.operations.CryptoExtension` migration
  1138. operation to install it.
  1139. .. admonition:: Oracle
  1140. Oracle doesn't support the ``SHA224`` function.
  1141. ``StrIndex``
  1142. ------------
  1143. .. class:: StrIndex(string, substring, **extra)
  1144. Returns a positive integer corresponding to the 1-indexed position of the first
  1145. occurrence of ``substring`` inside ``string``, or 0 if ``substring`` is not
  1146. found.
  1147. Usage example::
  1148. >>> from django.db.models import Value as V
  1149. >>> from django.db.models.functions import StrIndex
  1150. >>> Author.objects.create(name='Margaret Smith')
  1151. >>> Author.objects.create(name='Smith, Margaret')
  1152. >>> Author.objects.create(name='Margaret Jackson')
  1153. >>> Author.objects.filter(name='Margaret Jackson').annotate(
  1154. ... smith_index=StrIndex('name', V('Smith'))
  1155. ... ).get().smith_index
  1156. 0
  1157. >>> authors = Author.objects.annotate(
  1158. ... smith_index=StrIndex('name', V('Smith'))
  1159. ... ).filter(smith_index__gt=0)
  1160. <QuerySet [<Author: Margaret Smith>, <Author: Smith, Margaret>]>
  1161. .. warning::
  1162. In MySQL, a database table's :ref:`collation<mysql-collation>` determines
  1163. whether string comparisons (such as the ``expression`` and ``substring`` of
  1164. this function) are case-sensitive. Comparisons are case-insensitive by
  1165. default.
  1166. ``Substr``
  1167. ----------
  1168. .. class:: Substr(expression, pos, length=None, **extra)
  1169. Returns a substring of length ``length`` from the field or expression starting
  1170. at position ``pos``. The position is 1-indexed, so the position must be greater
  1171. than 0. If ``length`` is ``None``, then the rest of the string will be returned.
  1172. Usage example::
  1173. >>> # Set the alias to the first 5 characters of the name as lowercase
  1174. >>> from django.db.models.functions import Lower, Substr
  1175. >>> Author.objects.create(name='Margaret Smith')
  1176. >>> Author.objects.update(alias=Lower(Substr('name', 1, 5)))
  1177. 1
  1178. >>> print(Author.objects.get(name='Margaret Smith').alias)
  1179. marga
  1180. ``Trim``
  1181. --------
  1182. .. class:: Trim(expression, **extra)
  1183. Returns the value of the given text field or expression with leading and
  1184. trailing spaces removed.
  1185. Usage example::
  1186. >>> from django.db.models.functions import Trim
  1187. >>> Author.objects.create(name=' John ', alias='j')
  1188. >>> Author.objects.update(name=Trim('name'))
  1189. 1
  1190. >>> print(Author.objects.get(alias='j').name)
  1191. John
  1192. ``Upper``
  1193. ---------
  1194. .. class:: Upper(expression, **extra)
  1195. Accepts a single text field or expression and returns the uppercase
  1196. representation.
  1197. It can also be registered as a transform as described in :class:`Length`.
  1198. Usage example::
  1199. >>> from django.db.models.functions import Upper
  1200. >>> Author.objects.create(name='Margaret Smith')
  1201. >>> author = Author.objects.annotate(name_upper=Upper('name')).get()
  1202. >>> print(author.name_upper)
  1203. MARGARET SMITH
  1204. .. _window-functions:
  1205. Window functions
  1206. ================
  1207. There are a number of functions to use in a
  1208. :class:`~django.db.models.expressions.Window` expression for computing the rank
  1209. of elements or the :class:`Ntile` of some rows.
  1210. ``CumeDist``
  1211. ------------
  1212. .. class:: CumeDist(*expressions, **extra)
  1213. Calculates the cumulative distribution of a value within a window or partition.
  1214. The cumulative distribution is defined as the number of rows preceding or
  1215. peered with the current row divided by the total number of rows in the frame.
  1216. ``DenseRank``
  1217. -------------
  1218. .. class:: DenseRank(*expressions, **extra)
  1219. Equivalent to :class:`Rank` but does not have gaps.
  1220. ``FirstValue``
  1221. --------------
  1222. .. class:: FirstValue(expression, **extra)
  1223. Returns the value evaluated at the row that's the first row of the window
  1224. frame, or ``None`` if no such value exists.
  1225. ``Lag``
  1226. -------
  1227. .. class:: Lag(expression, offset=1, default=None, **extra)
  1228. Calculates the value offset by ``offset``, and if no row exists there, returns
  1229. ``default``.
  1230. ``default`` must have the same type as the ``expression``, however, this is
  1231. only validated by the database and not in Python.
  1232. .. admonition:: MariaDB and ``default``
  1233. MariaDB `doesn't support <https://jira.mariadb.org/browse/MDEV-12981>`_
  1234. the ``default`` parameter.
  1235. ``LastValue``
  1236. -------------
  1237. .. class:: LastValue(expression, **extra)
  1238. Comparable to :class:`FirstValue`, it calculates the last value in a given
  1239. frame clause.
  1240. ``Lead``
  1241. --------
  1242. .. class:: Lead(expression, offset=1, default=None, **extra)
  1243. Calculates the leading value in a given :ref:`frame <window-frames>`. Both
  1244. ``offset`` and ``default`` are evaluated with respect to the current row.
  1245. ``default`` must have the same type as the ``expression``, however, this is
  1246. only validated by the database and not in Python.
  1247. .. admonition:: MariaDB and ``default``
  1248. MariaDB `doesn't support <https://jira.mariadb.org/browse/MDEV-12981>`_
  1249. the ``default`` parameter.
  1250. ``NthValue``
  1251. ------------
  1252. .. class:: NthValue(expression, nth=1, **extra)
  1253. Computes the row relative to the offset ``nth`` (must be a positive value)
  1254. within the window. Returns ``None`` if no row exists.
  1255. Some databases may handle a nonexistent nth-value differently. For example,
  1256. Oracle returns an empty string rather than ``None`` for character-based
  1257. expressions. Django doesn't do any conversions in these cases.
  1258. ``Ntile``
  1259. ---------
  1260. .. class:: Ntile(num_buckets=1, **extra)
  1261. Calculates a partition for each of the rows in the frame clause, distributing
  1262. numbers as evenly as possible between 1 and ``num_buckets``. If the rows don't
  1263. divide evenly into a number of buckets, one or more buckets will be represented
  1264. more frequently.
  1265. ``PercentRank``
  1266. ---------------
  1267. .. class:: PercentRank(*expressions, **extra)
  1268. Computes the percentile rank of the rows in the frame clause. This
  1269. computation is equivalent to evaluating::
  1270. (rank - 1) / (total rows - 1)
  1271. The following table explains the calculation for the percentile rank of a row:
  1272. ===== ===== ==== ============ ============
  1273. Row # Value Rank Calculation Percent Rank
  1274. ===== ===== ==== ============ ============
  1275. 1 15 1 (1-1)/(7-1) 0.0000
  1276. 2 20 2 (2-1)/(7-1) 0.1666
  1277. 3 20 2 (2-1)/(7-1) 0.1666
  1278. 4 20 2 (2-1)/(7-1) 0.1666
  1279. 5 30 5 (5-1)/(7-1) 0.6666
  1280. 6 30 5 (5-1)/(7-1) 0.6666
  1281. 7 40 7 (7-1)/(7-1) 1.0000
  1282. ===== ===== ==== ============ ============
  1283. ``Rank``
  1284. --------
  1285. .. class:: Rank(*expressions, **extra)
  1286. Comparable to ``RowNumber``, this function ranks rows in the window. The
  1287. computed rank contains gaps. Use :class:`DenseRank` to compute rank without
  1288. gaps.
  1289. ``RowNumber``
  1290. -------------
  1291. .. class:: RowNumber(*expressions, **extra)
  1292. Computes the row number according to the ordering of either the frame clause
  1293. or the ordering of the whole query if there is no partitioning of the
  1294. :ref:`window frame <window-frames>`.