2 9.9. Date/Time Functions and Operators #
4 9.9.1. EXTRACT, date_part
7 9.9.4. AT TIME ZONE and AT LOCAL
8 9.9.5. Current Date/Time
9 9.9.6. Delaying Execution
11 Table 9.33 shows the available functions for date/time value
12 processing, with details appearing in the following subsections.
13 Table 9.32 illustrates the behaviors of the basic arithmetic operators
14 (+, *, etc.). For formatting functions, refer to Section 9.8. You
15 should be familiar with the background information on date/time data
16 types from Section 8.5.
18 In addition, the usual comparison operators shown in Table 9.1 are
19 available for the date/time types. Dates and timestamps (with or
20 without time zone) are all comparable, while times (with or without
21 time zone) and intervals can only be compared to other values of the
22 same data type. When comparing a timestamp without time zone to a
23 timestamp with time zone, the former value is assumed to be given in
24 the time zone specified by the TimeZone configuration parameter, and is
25 rotated to UTC for comparison to the latter value (which is already in
26 UTC internally). Similarly, a date value is assumed to represent
27 midnight in the TimeZone zone when comparing it to a timestamp.
29 All the functions and operators described below that take time or
30 timestamp inputs actually come in two variants: one that takes time
31 with time zone or timestamp with time zone, and one that takes time
32 without time zone or timestamp without time zone. For brevity, these
33 variants are not shown separately. Also, the + and * operators come in
34 commutative pairs (for example both date + integer and integer + date);
35 we show only one of each such pair.
37 Table 9.32. Date/Time Operators
47 Add a number of days to a date
49 date '2001-09-28' + 7 → 2001-10-05
51 date + interval → timestamp
53 Add an interval to a date
55 date '2001-09-28' + interval '1 hour' → 2001-09-28 01:00:00
57 date + time → timestamp
59 Add a time-of-day to a date
61 date '2001-09-28' + time '03:00' → 2001-09-28 03:00:00
63 interval + interval → interval
67 interval '1 day' + interval '1 hour' → 1 day 01:00:00
69 timestamp + interval → timestamp
71 Add an interval to a timestamp
73 timestamp '2001-09-28 01:00' + interval '23 hours' → 2001-09-29
76 time + interval → time
78 Add an interval to a time
80 time '01:00' + interval '3 hours' → 04:00:00
86 - interval '23 hours' → -23:00:00
90 Subtract dates, producing the number of days elapsed
92 date '2001-10-01' - date '2001-09-28' → 3
96 Subtract a number of days from a date
98 date '2001-10-01' - 7 → 2001-09-24
100 date - interval → timestamp
102 Subtract an interval from a date
104 date '2001-09-28' - interval '1 hour' → 2001-09-27 23:00:00
106 time - time → interval
110 time '05:00' - time '03:00' → 02:00:00
112 time - interval → time
114 Subtract an interval from a time
116 time '05:00' - interval '2 hours' → 03:00:00
118 timestamp - interval → timestamp
120 Subtract an interval from a timestamp
122 timestamp '2001-09-28 23:00' - interval '23 hours' → 2001-09-28
125 interval - interval → interval
129 interval '1 day' - interval '1 hour' → 1 day -01:00:00
131 timestamp - timestamp → interval
133 Subtract timestamps (converting 24-hour intervals into days, similarly
136 timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00' → 63 days
139 interval * double precision → interval
141 Multiply an interval by a scalar
143 interval '1 second' * 900 → 00:15:00
145 interval '1 day' * 21 → 21 days
147 interval '1 hour' * 3.5 → 03:30:00
149 interval / double precision → interval
151 Divide an interval by a scalar
153 interval '1 hour' / 1.5 → 00:40:00
155 Table 9.33. Date/Time Functions
163 age ( timestamp, timestamp ) → interval
165 Subtract arguments, producing a “symbolic” result that uses years and
166 months, rather than just days
168 age(timestamp '2001-04-10', timestamp '1957-06-13') → 43 years 9 mons
171 age ( timestamp ) → interval
173 Subtract argument from current_date (at midnight)
175 age(timestamp '1957-06-13') → 62 years 6 mons 10 days
177 clock_timestamp ( ) → timestamp with time zone
179 Current date and time (changes during statement execution); see
182 clock_timestamp() → 2019-12-23 14:39:53.662522-05
186 Current date; see Section 9.9.5
188 current_date → 2019-12-23
190 current_time → time with time zone
192 Current time of day; see Section 9.9.5
194 current_time → 14:39:53.662522-05
196 current_time ( integer ) → time with time zone
198 Current time of day, with limited precision; see Section 9.9.5
200 current_time(2) → 14:39:53.66-05
202 current_timestamp → timestamp with time zone
204 Current date and time (start of current transaction); see Section 9.9.5
206 current_timestamp → 2019-12-23 14:39:53.662522-05
208 current_timestamp ( integer ) → timestamp with time zone
210 Current date and time (start of current transaction), with limited
211 precision; see Section 9.9.5
213 current_timestamp(0) → 2019-12-23 14:39:53-05
215 date_add ( timestamp with time zone, interval [, text ] ) → timestamp
218 Add an interval to a timestamp with time zone, computing times of day
219 and daylight-savings adjustments according to the time zone named by
220 the third argument, or the current TimeZone setting if that is omitted.
221 The form with two arguments is equivalent to the timestamp with time
222 zone + interval operator.
224 date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval,
225 'Europe/Warsaw') → 2021-10-31 23:00:00+00
227 date_bin ( interval, timestamp, timestamp ) → timestamp
229 Bin input into specified interval aligned with specified origin; see
232 date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp
233 '2001-02-16 20:05:00') → 2001-02-16 20:35:00
235 date_part ( text, timestamp ) → double precision
237 Get timestamp subfield (equivalent to extract); see Section 9.9.1
239 date_part('hour', timestamp '2001-02-16 20:38:40') → 20
241 date_part ( text, interval ) → double precision
243 Get interval subfield (equivalent to extract); see Section 9.9.1
245 date_part('month', interval '2 years 3 months') → 3
247 date_subtract ( timestamp with time zone, interval [, text ] ) →
248 timestamp with time zone
250 Subtract an interval from a timestamp with time zone, computing times
251 of day and daylight-savings adjustments according to the time zone
252 named by the third argument, or the current TimeZone setting if that is
253 omitted. The form with two arguments is equivalent to the timestamp
254 with time zone - interval operator.
256 date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval,
257 'Europe/Warsaw') → 2021-10-30 22:00:00+00
259 date_trunc ( text, timestamp ) → timestamp
261 Truncate to specified precision; see Section 9.9.2
263 date_trunc('hour', timestamp '2001-02-16 20:38:40') → 2001-02-16
266 date_trunc ( text, timestamp with time zone, text ) → timestamp with
269 Truncate to specified precision in the specified time zone; see
272 date_trunc('day', timestamptz '2001-02-16 20:38:40+00',
273 'Australia/Sydney') → 2001-02-16 13:00:00+00
275 date_trunc ( text, interval ) → interval
277 Truncate to specified precision; see Section 9.9.2
279 date_trunc('hour', interval '2 days 3 hours 40 minutes') → 2 days
282 extract ( field from timestamp ) → numeric
284 Get timestamp subfield; see Section 9.9.1
286 extract(hour from timestamp '2001-02-16 20:38:40') → 20
288 extract ( field from interval ) → numeric
290 Get interval subfield; see Section 9.9.1
292 extract(month from interval '2 years 3 months') → 3
294 isfinite ( date ) → boolean
296 Test for finite date (not +/-infinity)
298 isfinite(date '2001-02-16') → true
300 isfinite ( timestamp ) → boolean
302 Test for finite timestamp (not +/-infinity)
304 isfinite(timestamp 'infinity') → false
306 isfinite ( interval ) → boolean
308 Test for finite interval (not +/-infinity)
310 isfinite(interval '4 hours') → true
312 justify_days ( interval ) → interval
314 Adjust interval, converting 30-day time periods to months
316 justify_days(interval '1 year 65 days') → 1 year 2 mons 5 days
318 justify_hours ( interval ) → interval
320 Adjust interval, converting 24-hour time periods to days
322 justify_hours(interval '50 hours 10 minutes') → 2 days 02:10:00
324 justify_interval ( interval ) → interval
326 Adjust interval using justify_days and justify_hours, with additional
329 justify_interval(interval '1 mon -1 hour') → 29 days 23:00:00
333 Current time of day; see Section 9.9.5
335 localtime → 14:39:53.662522
337 localtime ( integer ) → time
339 Current time of day, with limited precision; see Section 9.9.5
341 localtime(0) → 14:39:53
343 localtimestamp → timestamp
345 Current date and time (start of current transaction); see Section 9.9.5
347 localtimestamp → 2019-12-23 14:39:53.662522
349 localtimestamp ( integer ) → timestamp
351 Current date and time (start of current transaction), with limited
352 precision; see Section 9.9.5
354 localtimestamp(2) → 2019-12-23 14:39:53.66
356 make_date ( year int, month int, day int ) → date
358 Create date from year, month and day fields (negative years signify BC)
360 make_date(2013, 7, 15) → 2013-07-15
362 make_interval ( [ years int [, months int [, weeks int [, days int [,
363 hours int [, mins int [, secs double precision ]]]]]]] ) → interval
365 Create interval from years, months, weeks, days, hours, minutes and
366 seconds fields, each of which can default to zero
368 make_interval(days => 10) → 10 days
370 make_time ( hour int, min int, sec double precision ) → time
372 Create time from hour, minute and seconds fields
374 make_time(8, 15, 23.5) → 08:15:23.5
376 make_timestamp ( year int, month int, day int, hour int, min int, sec
377 double precision ) → timestamp
379 Create timestamp from year, month, day, hour, minute and seconds fields
380 (negative years signify BC)
382 make_timestamp(2013, 7, 15, 8, 15, 23.5) → 2013-07-15 08:15:23.5
384 make_timestamptz ( year int, month int, day int, hour int, min int, sec
385 double precision [, timezone text ] ) → timestamp with time zone
387 Create timestamp with time zone from year, month, day, hour, minute and
388 seconds fields (negative years signify BC). If timezone is not
389 specified, the current time zone is used; the examples assume the
390 session time zone is Europe/London
392 make_timestamptz(2013, 7, 15, 8, 15, 23.5) → 2013-07-15 08:15:23.5+01
394 make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York') →
395 2013-07-15 13:15:23.5+01
397 now ( ) → timestamp with time zone
399 Current date and time (start of current transaction); see Section 9.9.5
401 now() → 2019-12-23 14:39:53.662522-05
403 statement_timestamp ( ) → timestamp with time zone
405 Current date and time (start of current statement); see Section 9.9.5
407 statement_timestamp() → 2019-12-23 14:39:53.662522-05
411 Current date and time (like clock_timestamp, but as a text string); see
414 timeofday() → Mon Dec 23 14:39:53.662522 2019 EST
416 transaction_timestamp ( ) → timestamp with time zone
418 Current date and time (start of current transaction); see Section 9.9.5
420 transaction_timestamp() → 2019-12-23 14:39:53.662522-05
422 to_timestamp ( double precision ) → timestamp with time zone
424 Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to timestamp
427 to_timestamp(1284352323) → 2010-09-13 04:32:03+00
429 In addition to these functions, the SQL OVERLAPS operator is supported:
430 (start1, end1) OVERLAPS (start2, end2)
431 (start1, length1) OVERLAPS (start2, length2)
433 This expression yields true when two time periods (defined by their
434 endpoints) overlap, false when they do not overlap. The endpoints can
435 be specified as pairs of dates, times, or time stamps; or as a date,
436 time, or time stamp followed by an interval. When a pair of values is
437 provided, either the start or the end can be written first; OVERLAPS
438 automatically takes the earlier value of the pair as the start. Each
439 time period is considered to represent the half-open interval start <=
440 time < end, unless start and end are equal in which case it represents
441 that single time instant. This means for instance that two time periods
442 with only an endpoint in common do not overlap.
443 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
444 (DATE '2001-10-30', DATE '2002-10-30');
446 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
447 (DATE '2001-10-30', DATE '2002-10-30');
449 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
450 (DATE '2001-10-30', DATE '2001-10-31');
452 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
453 (DATE '2001-10-30', DATE '2001-10-31');
456 When adding an interval value to (or subtracting an interval value
457 from) a timestamp or timestamp with time zone value, the months, days,
458 and microseconds fields of the interval value are handled in turn.
459 First, a nonzero months field advances or decrements the date of the
460 timestamp by the indicated number of months, keeping the day of month
461 the same unless it would be past the end of the new month, in which
462 case the last day of that month is used. (For example, March 31 plus 1
463 month becomes April 30, but March 31 plus 2 months becomes May 31.)
464 Then the days field advances or decrements the date of the timestamp by
465 the indicated number of days. In both these steps the local time of day
466 is kept the same. Finally, if there is a nonzero microseconds field, it
467 is added or subtracted literally. When doing arithmetic on a timestamp
468 with time zone value in a time zone that recognizes DST, this means
469 that adding or subtracting (say) interval '1 day' does not necessarily
470 have the same result as adding or subtracting interval '24 hours'. For
471 example, with the session time zone set to America/Denver:
472 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
473 Result: 2005-04-03 12:00:00-06
474 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
475 Result: 2005-04-03 13:00:00-06
477 This happens because an hour was skipped due to a change in daylight
478 saving time at 2005-04-03 02:00:00 in time zone America/Denver.
480 Note there can be ambiguity in the months field returned by age because
481 different months have different numbers of days. PostgreSQL's approach
482 uses the month from the earlier of the two dates when calculating
483 partial months. For example, age('2004-06-01', '2004-04-30') uses April
484 to yield 1 mon 1 day, while using May would yield 1 mon 2 days because
485 May has 31 days, while April has only 30.
487 Subtraction of dates and timestamps can also be complex. One
488 conceptually simple way to perform subtraction is to convert each value
489 to a number of seconds using EXTRACT(EPOCH FROM ...), then subtract the
490 results; this produces the number of seconds between the two values.
491 This will adjust for the number of days in each month, timezone
492 changes, and daylight saving time adjustments. Subtraction of date or
493 timestamp values with the “-” operator returns the number of days
494 (24-hours) and hours/minutes/seconds between the values, making the
495 same adjustments. The age function returns years, months, days, and
496 hours/minutes/seconds, performing field-by-field subtraction and then
497 adjusting for negative field values. The following queries illustrate
498 the differences in these approaches. The sample results were produced
499 with timezone = 'US/Eastern'; there is a daylight saving time change
500 between the two dates used:
501 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
502 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
503 Result: 10537200.000000
504 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
505 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
507 Result: 121.9583333333333333
508 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
509 Result: 121 days 23:00:00
510 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00')
514 9.9.1. EXTRACT, date_part #
516 EXTRACT(field FROM source)
518 The extract function retrieves subfields such as year or hour from
519 date/time values. source must be a value expression of type timestamp,
520 date, time, or interval. (Timestamps and times can be with or without
521 time zone.) field is an identifier or string that selects what field to
522 extract from the source value. Not all fields are valid for every input
523 data type; for example, fields smaller than a day cannot be extracted
524 from a date, while fields of a day or more cannot be extracted from a
525 time. The extract function returns values of type numeric.
527 The following are valid field names:
530 The century; for interval values, the year field divided by 100
532 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
534 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
536 SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD');
538 SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC');
540 SELECT EXTRACT(CENTURY FROM INTERVAL '2001 years');
544 The day of the month (1–31); for interval values, the number of
547 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
549 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
553 The year field divided by 10
555 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
559 The day of the week as Sunday (0) to Saturday (6)
561 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
564 Note that extract's day of the week numbering differs from that
565 of the to_char(..., 'D') function.
568 The day of the year (1–365/366)
570 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
574 For timestamp with time zone values, the number of seconds since
575 1970-01-01 00:00:00 UTC (negative for timestamps before that);
576 for date and timestamp values, the nominal number of seconds
577 since 1970-01-01 00:00:00, without regard to timezone or
578 daylight-savings rules; for interval values, the total number of
579 seconds in the interval
581 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
582 Result: 982384720.120000
583 SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
584 Result: 982355920.120000
585 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
586 Result: 442800.000000
588 You can convert an epoch value back to a timestamp with time
589 zone with to_timestamp:
591 SELECT to_timestamp(982384720.12);
592 Result: 2001-02-17 04:38:40.12+00
594 Beware that applying to_timestamp to an epoch extracted from a
595 date or timestamp value could produce a misleading result: the
596 result will effectively assume that the original value had been
597 given in UTC, which might not be the case.
600 The hour field (0–23 in timestamps, unrestricted in intervals)
602 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
606 The day of the week as Monday (1) to Sunday (7)
608 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
611 This is identical to dow except for Sunday. This matches the ISO
612 8601 day of the week numbering.
615 The ISO 8601 week-numbering year that the date falls in
617 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
619 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
622 Each ISO 8601 week-numbering year begins with the Monday of the
623 week containing the 4th of January, so in early January or late
624 December the ISO year may be different from the Gregorian year.
625 See the week field for more information.
628 The Julian Date corresponding to the date or timestamp.
629 Timestamps that are not local midnight result in a fractional
630 value. See Section B.7 for more information.
632 SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
634 SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
635 Result: 2453737.50000000000000000000
638 The seconds field, including fractional parts, multiplied by 1
639 000 000; note that this includes full seconds
641 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
645 The millennium; for interval values, the year field divided by
648 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
650 SELECT EXTRACT(MILLENNIUM FROM INTERVAL '2001 years');
653 Years in the 1900s are in the second millennium. The third
654 millennium started January 1, 2001.
657 The seconds field, including fractional parts, multiplied by
658 1000. Note that this includes full seconds.
660 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
664 The minutes field (0–59)
666 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
670 The number of the month within the year (1–12); for interval
671 values, the number of months modulo 12 (0–11)
673 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
675 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
677 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
681 The quarter of the year (1–4) that the date is in; for interval
682 values, the month field divided by 3 plus 1
684 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
686 SELECT EXTRACT(QUARTER FROM INTERVAL '1 year 6 months');
690 The seconds field, including any fractional seconds
692 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
694 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
698 The time zone offset from UTC, measured in seconds. Positive
699 values correspond to time zones east of UTC, negative values to
700 zones west of UTC. (Technically, PostgreSQL does not use UTC
701 because leap seconds are not handled.)
704 The hour component of the time zone offset
707 The minute component of the time zone offset
710 The number of the ISO 8601 week-numbering week of the year. By
711 definition, ISO weeks start on Mondays and the first week of a
712 year contains January 4 of that year. In other words, the first
713 Thursday of a year is in week 1 of that year.
715 In the ISO week-numbering system, it is possible for
716 early-January dates to be part of the 52nd or 53rd week of the
717 previous year, and for late-December dates to be part of the
718 first week of the next year. For example, 2005-01-01 is part of
719 the 53rd week of year 2004, and 2006-01-01 is part of the 52nd
720 week of year 2005, while 2012-12-31 is part of the first week of
721 2013. It's recommended to use the isoyear field together with
722 week to get consistent results.
724 For interval values, the week field is simply the number of
725 integral days divided by 7.
727 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
729 SELECT EXTRACT(WEEK FROM INTERVAL '13 days 24 hours');
733 The year field. Keep in mind there is no 0 AD, so subtracting BC
734 years from AD years should be done with care.
736 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
739 When processing an interval value, the extract function produces field
740 values that match the interpretation used by the interval output
741 function. This can produce surprising results if one starts with a
742 non-normalized interval representation, for example:
743 SELECT INTERVAL '80 minutes';
745 SELECT EXTRACT(MINUTES FROM INTERVAL '80 minutes');
750 When the input value is +/-Infinity, extract returns +/-Infinity for
751 monotonically-increasing fields (epoch, julian, year, isoyear, decade,
752 century, and millennium for timestamp inputs; epoch, hour, day, year,
753 decade, century, and millennium for interval inputs). For other fields,
754 NULL is returned. PostgreSQL versions before 9.6 returned zero for all
755 cases of infinite input.
757 The extract function is primarily intended for computational
758 processing. For formatting date/time values for display, see
761 The date_part function is modeled on the traditional Ingres equivalent
762 to the SQL-standard function extract:
763 date_part('field', source)
765 Note that here the field parameter needs to be a string value, not a
766 name. The valid field names for date_part are the same as for extract.
767 For historical reasons, the date_part function returns values of type
768 double precision. This can result in a loss of precision in certain
769 uses. Using extract is recommended instead.
770 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
772 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
777 The function date_trunc is conceptually similar to the trunc function
780 date_trunc(field, source [, time_zone ])
782 source is a value expression of type timestamp, timestamp with time
783 zone, or interval. (Values of type date and time are cast automatically
784 to timestamp or interval, respectively.) field selects to which
785 precision to truncate the input value. The return value is likewise of
786 type timestamp, timestamp with time zone, or interval, and it has all
787 fields that are less significant than the selected one set to zero (or
788 one, for day and month).
790 Valid values for field are:
805 When the input value is of type timestamp with time zone, the
806 truncation is performed with respect to a particular time zone; for
807 example, truncation to day produces a value that is midnight in that
808 zone. By default, truncation is done with respect to the current
809 TimeZone setting, but the optional time_zone argument can be provided
810 to specify a different time zone. The time zone name can be specified
811 in any of the ways described in Section 8.5.3.
813 A time zone cannot be specified when processing timestamp without time
814 zone or interval inputs. These are always taken at face value.
816 Examples (assuming the local time zone is America/New_York):
817 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
818 Result: 2001-02-16 20:00:00
819 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
820 Result: 2001-01-01 00:00:00
821 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
822 Result: 2001-02-16 00:00:00-05
823 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Aus
825 Result: 2001-02-16 08:00:00-05
826 SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
827 Result: 3 days 02:00:00
831 The function date_bin “bins” the input timestamp into the specified
832 interval (the stride) aligned with a specified origin.
834 date_bin(stride, source, origin)
836 source is a value expression of type timestamp or timestamp with time
837 zone. (Values of type date are cast automatically to timestamp.) stride
838 is a value expression of type interval. The return value is likewise of
839 type timestamp or timestamp with time zone, and it marks the beginning
840 of the bin into which the source is placed.
843 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0
845 Result: 2020-02-11 15:30:00
846 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0
848 Result: 2020-02-11 15:32:30
850 In the case of full units (1 minute, 1 hour, etc.), it gives the same
851 result as the analogous date_trunc call, but the difference is that
852 date_bin can truncate to an arbitrary interval.
854 The stride interval must be greater than zero and cannot contain units
857 9.9.4. AT TIME ZONE and AT LOCAL #
859 The AT TIME ZONE operator converts time stamp without time zone to/from
860 time stamp with time zone, and time with time zone values to different
861 time zones. Table 9.34 shows its variants.
863 Table 9.34. AT TIME ZONE and AT LOCAL Variants
871 timestamp without time zone AT TIME ZONE zone → timestamp with time
874 Converts given time stamp without time zone to time stamp with time
875 zone, assuming the given value is in the named time zone.
877 timestamp '2001-02-16 20:38:40' at time zone 'America/Denver' →
878 2001-02-17 03:38:40+00
880 timestamp without time zone AT LOCAL → timestamp with time zone
882 Converts given time stamp without time zone to time stamp with the
883 session's TimeZone value as time zone.
885 timestamp '2001-02-16 20:38:40' at local → 2001-02-17 03:38:40+00
887 timestamp with time zone AT TIME ZONE zone → timestamp without time
890 Converts given time stamp with time zone to time stamp without time
891 zone, as the time would appear in that zone.
893 timestamp with time zone '2001-02-16 20:38:40-05' at time zone
894 'America/Denver' → 2001-02-16 18:38:40
896 timestamp with time zone AT LOCAL → timestamp without time zone
898 Converts given time stamp with time zone to time stamp without time
899 zone, as the time would appear with the session's TimeZone value as
902 timestamp with time zone '2001-02-16 20:38:40-05' at local → 2001-02-16
905 time with time zone AT TIME ZONE zone → time with time zone
907 Converts given time with time zone to a new time zone. Since no date is
908 supplied, this uses the currently active UTC offset for the named
911 time with time zone '05:34:17-05' at time zone 'UTC' → 10:34:17+00
913 time with time zone AT LOCAL → time with time zone
915 Converts given time with time zone to a new time zone. Since no date is
916 supplied, this uses the currently active UTC offset for the session's
919 Assuming the session's TimeZone is set to UTC:
921 time with time zone '05:34:17-05' at local → 10:34:17+00
923 In these expressions, the desired time zone zone can be specified
924 either as a text value (e.g., 'America/Los_Angeles') or as an interval
925 (e.g., INTERVAL '-08:00'). In the text case, a time zone name can be
926 specified in any of the ways described in Section 8.5.3. The interval
927 case is only useful for zones that have fixed offsets from UTC, so it
928 is not very common in practice.
930 The syntax AT LOCAL may be used as shorthand for AT TIME ZONE local,
931 where local is the session's TimeZone value.
933 Examples (assuming the current TimeZone setting is
934 America/Los_Angeles):
935 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
936 Result: 2001-02-16 19:38:40-08
937 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/D
939 Result: 2001-02-16 18:38:40
940 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'A
942 Result: 2001-02-16 05:38:40
943 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT LOCAL;
944 Result: 2001-02-16 17:38:40
945 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE '+05';
946 Result: 2001-02-16 20:38:40
947 SELECT TIME WITH TIME ZONE '20:38:40-05' AT LOCAL;
950 The first example adds a time zone to a value that lacks it, and
951 displays the value using the current TimeZone setting. The second
952 example shifts the time stamp with time zone value to the specified
953 time zone, and returns the value without a time zone. This allows
954 storage and display of values different from the current TimeZone
955 setting. The third example converts Tokyo time to Chicago time. The
956 fourth example shifts the time stamp with time zone value to the time
957 zone currently specified by the TimeZone setting and returns the value
958 without a time zone. The fifth example demonstrates that the sign in a
959 POSIX-style time zone specification has the opposite meaning of the
960 sign in an ISO-8601 datetime literal, as described in Section 8.5.3 and
963 The sixth example is a cautionary tale. Due to the fact that there is
964 no date associated with the input value, the conversion is made using
965 the current date of the session. Therefore, this static example may
966 show a wrong result depending on the time of the year it is viewed
967 because 'America/Los_Angeles' observes Daylight Savings Time.
969 The function timezone(zone, timestamp) is equivalent to the
970 SQL-conforming construct timestamp AT TIME ZONE zone.
972 The function timezone(zone, time) is equivalent to the SQL-conforming
973 construct time AT TIME ZONE zone.
975 The function timezone(timestamp) is equivalent to the SQL-conforming
976 construct timestamp AT LOCAL.
978 The function timezone(time) is equivalent to the SQL-conforming
979 construct time AT LOCAL.
981 9.9.5. Current Date/Time #
983 PostgreSQL provides a number of functions that return values related to
984 the current date and time. These SQL-standard functions all return
985 values based on the start time of the current transaction:
989 CURRENT_TIME(precision)
990 CURRENT_TIMESTAMP(precision)
994 LOCALTIMESTAMP(precision)
996 CURRENT_TIME and CURRENT_TIMESTAMP deliver values with time zone;
997 LOCALTIME and LOCALTIMESTAMP deliver values without time zone.
999 CURRENT_TIME, CURRENT_TIMESTAMP, LOCALTIME, and LOCALTIMESTAMP can
1000 optionally take a precision parameter, which causes the result to be
1001 rounded to that many fractional digits in the seconds field. Without a
1002 precision parameter, the result is given to the full available
1006 SELECT CURRENT_TIME;
1007 Result: 14:39:53.662522-05
1008 SELECT CURRENT_DATE;
1010 SELECT CURRENT_TIMESTAMP;
1011 Result: 2019-12-23 14:39:53.662522-05
1012 SELECT CURRENT_TIMESTAMP(2);
1013 Result: 2019-12-23 14:39:53.66-05
1014 SELECT LOCALTIMESTAMP;
1015 Result: 2019-12-23 14:39:53.662522
1017 Since these functions return the start time of the current transaction,
1018 their values do not change during the transaction. This is considered a
1019 feature: the intent is to allow a single transaction to have a
1020 consistent notion of the “current” time, so that multiple modifications
1021 within the same transaction bear the same time stamp.
1025 Other database systems might advance these values more frequently.
1027 PostgreSQL also provides functions that return the start time of the
1028 current statement, as well as the actual current time at the instant
1029 the function is called. The complete list of non-SQL-standard time
1031 transaction_timestamp()
1032 statement_timestamp()
1037 transaction_timestamp() is equivalent to CURRENT_TIMESTAMP, but is
1038 named to clearly reflect what it returns. statement_timestamp() returns
1039 the start time of the current statement (more specifically, the time of
1040 receipt of the latest command message from the client).
1041 statement_timestamp() and transaction_timestamp() return the same value
1042 during the first statement of a transaction, but might differ during
1043 subsequent statements. clock_timestamp() returns the actual current
1044 time, and therefore its value changes even within a single SQL
1045 statement. timeofday() is a historical PostgreSQL function. Like
1046 clock_timestamp(), it returns the actual current time, but as a
1047 formatted text string rather than a timestamp with time zone value.
1048 now() is a traditional PostgreSQL equivalent to
1049 transaction_timestamp().
1051 All the date/time data types also accept the special literal value now
1052 to specify the current date and time (again, interpreted as the
1053 transaction start time). Thus, the following three all return the same
1055 SELECT CURRENT_TIMESTAMP;
1057 SELECT TIMESTAMP 'now'; -- but see tip below
1061 Do not use the third form when specifying a value to be evaluated
1062 later, for example in a DEFAULT clause for a table column. The system
1063 will convert now to a timestamp as soon as the constant is parsed, so
1064 that when the default value is needed, the time of the table creation
1065 would be used! The first two forms will not be evaluated until the
1066 default value is used, because they are function calls. Thus they will
1067 give the desired behavior of defaulting to the time of row insertion.
1068 (See also Section 8.5.1.4.)
1070 9.9.6. Delaying Execution #
1072 The following functions are available to delay execution of the server
1074 pg_sleep ( double precision )
1075 pg_sleep_for ( interval )
1076 pg_sleep_until ( timestamp with time zone )
1078 pg_sleep makes the current session's process sleep until the given
1079 number of seconds have elapsed. Fractional-second delays can be
1080 specified. pg_sleep_for is a convenience function to allow the sleep
1081 time to be specified as an interval. pg_sleep_until is a convenience
1082 function for when a specific wake-up time is desired. For example:
1083 SELECT pg_sleep(1.5);
1084 SELECT pg_sleep_for('5 minutes');
1085 SELECT pg_sleep_until('tomorrow 03:00');
1089 The effective resolution of the sleep interval is platform-specific;
1090 0.01 seconds is a common value. The sleep delay will be at least as
1091 long as specified. It might be longer depending on factors such as
1092 server load. In particular, pg_sleep_until is not guaranteed to wake up
1093 exactly at the specified time, but it will not wake up any earlier.
1097 Make sure that your session does not hold more locks than necessary
1098 when calling pg_sleep or its variants. Otherwise other sessions might
1099 have to wait for your sleeping process, slowing down the entire system.