database-functions.txt 58 KB

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