database-functions.txt 55 KB

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