Supported Versions: Current (16) / 15 / 14 / 13 / 12
Development Versions: devel
Unsupported versions: 11 / 10 / 9.6 / 9.5 / 9.4 / 9.3 / 9.2 / 9.1 / 9.0 / 8.4 / 8.3 / 8.2 / 8.1 / 8.0 / 7.4 / 7.3 / 7.2 / 7.1
This documentation is for an unsupported version of PostgreSQL.
You may want to view the same page for the current version, or one of the other supported versions listed above instead.

6.8. Date/Time Functions and Operators

Table 6-18 shows the available functions for date/time value processing, with details appearing in the following subsections. Table 6-17 illustrates the behaviors of the basic arithmetic operators (+, *, etc.). For formatting functions, refer to Section 6.7. You should be familiar with the background information on date/time data types (see Section 5.5).

All the functions and operators described below that take time or timestamp inputs actually come in two variants: one that takes time or timestamp with time zone, and one that takes time or timestamp without time zone. For brevity, these variants are not shown separately.

Table 6-17. Date/Time Operators

Name Example Result
+ timestamp '2001-09-28 01:00' + interval '23 hours' timestamp '2001-09-29 00:00'
+ date '2001-09-28' + interval '1 hour' timestamp '2001-09-28 01:00'
+ time '01:00' + interval '3 hours' time '04:00'
- timestamp '2001-09-28 23:00' - interval '23 hours' timestamp '2001-09-28'
- date '2001-09-28' - interval '1 hour' timestamp '2001-09-27 23:00'
- time '05:00' - interval '2 hours' time '03:00'
- interval '2 hours' - time '05:00' time '03:00:00'
* interval '1 hour' * int '3' interval '03:00'
/ interval '1 hour' / int '3' interval '00:20'

Table 6-18. Date/Time Functions

Name Return Type Description Example Result
age(timestamp) interval Subtract from today age(timestamp '1957-06-13') 43 years 8 mons 3 days
age(timestamp, timestamp) interval Subtract arguments age('2001-04-10', timestamp '1957-06-13') 43 years 9 mons 27 days
current_date date Today's date; see Section 6.8.4    
current_time time with time zone Time of day; see Section 6.8.4    
current_timestamp timestamp with time zone Date and time; see Section 6.8.4    
date_part(text, timestamp) double precision Get subfield (equivalent to extract); see also below date_part('hour', timestamp '2001-02-16 20:38:40') 20
date_part(text, interval) double precision Get subfield (equivalent to extract); see also below date_part('month', interval '2 years 3 months') 3
date_trunc(text, timestamp) timestamp Truncate to specified precision; see also Section 6.8.2 date_trunc('hour', timestamp '2001-02-16 20:38:40') 2001-02-16 20:00:00+00
extract(field from timestamp) double precision Get subfield; see also Section 6.8.1 extract(hour from timestamp '2001-02-16 20:38:40') 20
extract(field from interval) double precision Get subfield; see also Section 6.8.1 extract(month from interval '2 years 3 months') 3
isfinite(timestamp) boolean Test for finite time stamp (neither invalid nor infinity) isfinite(timestamp '2001-02-16 21:28:30') true
isfinite(interval) boolean Test for finite interval isfinite(interval '4 hours') true
localtime time Time of day; see Section 6.8.4    
localtimestamp timestamp Date and time; see Section 6.8.4    
now() timestamp with time zone Current date and time (equivalent to current_timestamp); see Section 6.8.4    
timeofday() text Current date and time; see Section 6.8.4 timeofday() Wed Feb 21 17:01:13.000126 2001 EST

6.8.1. EXTRACT, date_part

EXTRACT (field FROM source)

The extract function retrieves subfields from date/time values, such as year or hour. source is a value expression that evaluates to type timestamp or interval. (Expressions of type date or time will be cast to timestamp and can therefore be used as well.) field is an identifier or string that selects what field to extract from the source value. The extract function returns values of type double precision. The following are valid values:

century

The year field divided by 100

SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 20

Note that the result for the century field is simply the year field divided by 100, and not the conventional definition which puts most years in the 1900's in the twentieth century.

day

The day (of the month) field (1 - 31)

SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 16
decade

The year field divided by 10

SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 200
dow

The day of the week (0 - 6; Sunday is 0) (for timestamp values only)

SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 5
doy

The day of the year (1 - 365/366) (for timestamp values only)

SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 47
epoch

For date and timestamp values, the number of seconds since 1970-01-01 00:00:00-00 (can be negative); for interval values, the total number of seconds in the interval

SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 982352320

SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
Result: 442800
hour

The hour field (0 - 23)

SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 20
microseconds

The seconds field, including fractional parts, multiplied by 1 000 000. Note that this includes full seconds.

SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
Result: 28500000
millennium

The year field divided by 1000

SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 2

Note that the result for the millennium field is simply the year field divided by 1000, and not the conventional definition which puts years in the 1900's in the second millennium.

milliseconds

The seconds field, including fractional parts, multiplied by 1000. Note that this includes full seconds.

SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
Result: 28500
minute

The minutes field (0 - 59)

SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 38
month

For timestamp values, the number of the month within the year (1 - 12) ; for interval values the number of months, modulo 12 (0 - 11)

SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 2

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
Result: 3

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
Result: 1
quarter

The quarter of the year (1 - 4) that the day is in (for timestamp values only)

SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 1
second

The seconds field, including fractional parts (0 - 59[1])

SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 40

SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
Result: 28.5
timezone_hour

The hour component of the time zone offset.

timezone_minute

The minute component of the time zone offset.

week

From a timestamp value, calculate the number of the week of the year that the day is in. By definition (ISO 8601), the first week of a year contains January 4 of that year. (The ISO week starts on Monday.) In other words, the first Thursday of a year is in week 1 of that year.

SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 7
year

The year field

SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
Result: 2001

The extract function is primarily intended for computational processing. For formatting date/time values for display, see Section 6.7.

The date_part function is modeled on the traditional Ingres equivalent to the SQL-standard function extract:

date_part('field', source)

Note that here the field parameter needs to be a string value, not a name. The valid field values for date_part are the same as for extract.

SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
Result: 16

SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
Result: 4

6.8.2. date_trunc

The function date_trunc is conceptually similar to the trunc function for numbers.

date_trunc('field', source)

source is a value expression of type timestamp (values of type date and time are cast automatically). field selects to which precision to truncate the time stamp value. The return value is of type timestamp with all fields that are less than the selected one set to zero (or one, for day and month).

Valid values for field are:

microseconds
milliseconds
second
minute
hour
day
month
year
decade
century
millennium

Examples:

SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
Result: 2001-02-16 20:00:00+00

SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
Result: 2001-01-01 00:00:00+00

6.8.3. AT TIME ZONE

The AT TIME ZONE construct allows conversions of timestamps to different timezones.

Table 6-19. AT TIME ZONE Variants

Expression Returns Description
timestamp without time zone AT TIME ZONE zone timestamp with time zone Convert local time in given timezone to UTC
timestamp with time zone AT TIME ZONE zone timestamp without time zone Convert UTC to local time in given timezone
time with time zone AT TIME ZONE zone time with time zone Convert local time across timezones

In these expressions, the desired time zone can be specified either as a text string (e.g., 'PST') or as an interval (e.g., INTERVAL '-08:00').

Examples (supposing that TimeZone is PST8PDT):

SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
Result: 2001-02-16 19:38:40-08

SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
Result: 2001-02-16 18:38:40

The first example takes a zone-less timestamp and interprets it as MST time (GMT-7) to produce a UTC timestamp, which is then rotated to PST (GMT-8) for display. The second example takes a timestamp specified in EST (GMT-5) and converts it to local time in MST (GMT-7).

The function timezone(zone, timestamp) is equivalent to the SQL-compliant construct timestamp AT TIME ZONE zone.

6.8.4. Current Date/Time

The following functions are available to obtain the current date and/or time:

CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_TIME ( precision )
CURRENT_TIMESTAMP ( precision )
LOCALTIME
LOCALTIMESTAMP
LOCALTIME ( precision )
LOCALTIMESTAMP ( precision )

CURRENT_TIME and CURRENT_TIMESTAMP deliver values with time zone; LOCALTIME and LOCALTIMESTAMP deliver values without time zone.

CURRENT_TIME, CURRENT_TIMESTAMP, LOCALTIME, and LOCALTIMESTAMP can optionally be given a precision parameter, which causes the result to be rounded to that many fractional digits. Without a precision parameter, the result is given to the full available precision.

Note: Prior to PostgreSQL 7.2, the precision parameters were unimplemented, and the result was always given in integer seconds.

Some examples:

SELECT CURRENT_TIME;
14:39:53.662522-05

SELECT CURRENT_DATE;
2001-12-23

SELECT CURRENT_TIMESTAMP;
2001-12-23 14:39:53.662522-05

SELECT CURRENT_TIMESTAMP(2);
2001-12-23 14:39:53.66-05

SELECT LOCALTIMESTAMP;
2001-12-23 14:39:53.662522

The function now() is the traditional PostgreSQL equivalent to CURRENT_TIMESTAMP.

There is also timeofday(), which for historical reasons returns a text string rather than a timestamp value:

SELECT timeofday();
 Sat Feb 17 19:07:32.000126 2001 EST

It is important to realize that CURRENT_TIMESTAMP and related functions return the start time of the current transaction; their values do not change during the transaction. timeofday() returns the wall clock time and does advance during transactions.

Note: Many other database systems advance these values more frequently.

All the date/time data types also accept the special literal value now to specify the current date and time. Thus, the following three all return the same result:

SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';

Note: You do not want to use the third form when specifying a DEFAULT clause while creating a table. The system will convert now to a timestamp as soon as the constant is parsed, so that when the default value is needed, the time of the table creation would be used! The first two forms will not be evaluated until the default value is used, because they are function calls. Thus they will give the desired behavior of defaulting to the time of row insertion.

Notes

[1]

60 if leap seconds are implemented by the operating system