PostgreSQL 7.4.30 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 9. Functions and Operators | Fast Forward | Next |
Table 9-26 shows the available functions for date/time value processing, with details appearing in the following subsections. Table 9-25 illustrates the behaviors of the basic arithmetic operators (+, *, etc.). For formatting functions, refer to Section 9.7. You should be familiar with the background information on date/time data types from Section 8.5.
All the functions and operators described below that take time or timestamp inputs actually come in two variants: one that takes time with time zone or timestamp with time zone, and one that takes time without time zone or timestamp without time zone. For brevity, these variants are not shown separately.
Table 9-25. Date/Time Operators
Operator | Example | Result |
---|---|---|
+ | date '2001-09-28' + integer '7' | date '2001-10-05' |
+ | date '2001-09-28' + interval '1 hour' | timestamp '2001-09-28 01:00' |
+ | date '2001-09-28' + time '03:00' | timestamp '2001-09-28 03:00' |
+ | time '03:00' + date '2001-09-28' | timestamp '2001-09-28 03:00' |
+ | interval '1 day' + interval '1 hour' | interval '1 day 01:00' |
+ | timestamp '2001-09-28 01:00' + interval '23 hours' | timestamp '2001-09-29 00:00' |
+ | time '01:00' + interval '3 hours' | time '04:00' |
+ | interval '3 hours' + time '01:00' | time '04:00' |
- | - interval '23 hours' | interval '-23:00' |
- | date '2001-10-01' - date '2001-09-28' | integer '3' |
- | date '2001-10-01' - integer '7' | date '2001-09-24' |
- | date '2001-09-28' - interval '1 hour' | timestamp '2001-09-27 23:00' |
- | time '05:00' - time '03:00' | interval '02:00' |
- | time '05:00' - interval '2 hours' | time '03:00' |
- | timestamp '2001-09-28 23:00' - interval '23 hours' | timestamp '2001-09-28 00:00' |
- | interval '1 day' - interval '1 hour' | interval '23:00' |
- | interval '2 hours' - time '05:00' | time '03:00' |
- | timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00' | interval '1 day 15:00' |
* | double precision '3.5' * interval '1 hour' | interval '03:30' |
* | interval '1 hour' * double precision '3.5' | interval '03:30' |
/ | interval '1 hour' / double precision '1.5' | interval '00:40' |
Table 9-26. Date/Time Functions
Function | 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 9.8.4 | ||
current_time |
time with time zone | Time of day; see Section 9.8.4 | ||
current_timestamp |
timestamp with time zone | Date and time; see Section 9.8.4 | ||
date_part (text,
timestamp) |
double precision | Get subfield (equivalent to extract ); see Section
9.8.1 |
date_part('hour', timestamp '2001-02-16 20:38:40') | 20 |
date_part (text,
interval) |
double precision | Get subfield (equivalent to extract ); see Section
9.8.1 |
date_part('month', interval '2 years 3 months') | 3 |
date_trunc (text,
timestamp) |
timestamp | Truncate to specified precision; see also Section 9.8.2 | date_trunc('hour', timestamp '2001-02-16 20:38:40') | 2001-02-16 20:00:00 |
extract (field from timestamp) |
double precision | Get subfield; see Section 9.8.1 | extract(hour from timestamp '2001-02-16 20:38:40') | 20 |
extract (field from interval) |
double precision | Get subfield; see Section 9.8.1 | extract(month from interval '2 years 3 months') | 3 |
isfinite (timestamp) |
boolean | Test for finite time stamp (not equal to 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 9.8.4 | ||
localtimestamp |
timestamp | Date and time; see Section 9.8.4 | ||
now () |
timestamp with time zone | Current date and time (equivalent to current_timestamp ); see Section
9.8.4 |
||
timeofday() |
text | Current date and time; see Section 9.8.4 |
In addition to these functions, the SQL OVERLAPS operator is supported:
( start1, end1 ) OVERLAPS ( start2, end2 ) ( start1, length1 ) OVERLAPS ( start2, length2 )
This expression yields true when two time periods (defined by their endpoints) overlap, false when they do not overlap. The endpoints can be specified as pairs of dates, times, or time stamps; or as a date, time, or time stamp followed by an interval.
SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS (DATE '2001-10-30', DATE '2002-10-30'); Result: true SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS (DATE '2001-10-30', DATE '2002-10-30'); Result: false
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 field names:
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.
The day (of the month) field (1 - 31)
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 16
The year field divided by 10
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 200
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
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
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 WITH TIME ZONE '2001-02-16 20:38:40-08'); Result: 982384720 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); Result: 442800
The hour field (0 - 23)
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 20
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
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.
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
The minutes field (0 - 59)
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 38
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
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
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
The time zone offset from UTC, measured in seconds. Positive values correspond to time zones east of UTC, negative values to zones west of UTC.
The hour component of the time zone offset
The minute component of the time zone offset
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-8601 week starts on Monday.) In other words, the first Thursday of a year is in week 1 of that year. (for timestamp values only)
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 7
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 9.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 names 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
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 or interval. (Values of type date and time are cast automatically, to timestamp or interval respectively.) field selects to which precision to truncate the input value. The return value is of type timestamp or interval with all fields that are less significant 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 |
quarter |
year |
decade |
century |
millennium |
Examples:
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40'); Result: 2001-02-16 20:00:00 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40'); Result: 2001-01-01 00:00:00
The AT TIME ZONE construct allows conversions of time stamps to different time zones. Table 9-27 shows its variants.
Table 9-27. AT TIME ZONE Variants
Expression | Return Type | Description |
---|---|---|
timestamp without time zone AT TIME ZONE zone | timestamp with time zone | Convert local time in given time zone to UTC |
timestamp with time zone AT TIME ZONE zone | timestamp without time zone | Convert UTC to local time in given time zone |
time with time zone AT TIME ZONE zone | time with time zone | Convert local time across time zones |
In these expressions, the desired time zone zone can be specified either as a text string (e.g., 'PST') or as an interval (e.g., INTERVAL '-08:00').
Examples (supposing that the local time zone 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 time stamp and interprets it as MST time (UTC-7) to produce a UTC time stamp, which is then rotated to PST (UTC-8) for display. The second example takes a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
The function timezone
(zone, timestamp) is equivalent to the
SQL-conforming construct timestamp AT TIME ZONE zone.
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 in the seconds field. 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; Result: 14:39:53.662522-05 SELECT CURRENT_DATE; Result: 2001-12-23 SELECT CURRENT_TIMESTAMP; Result: 2001-12-23 14:39:53.662522-05 SELECT CURRENT_TIMESTAMP(2); Result: 2001-12-23 14:39:53.66-05 SELECT LOCALTIMESTAMP; Result: 2001-12-23 14:39:53.662522
The function now()
is the
traditional PostgreSQL
equivalent to CURRENT_TIMESTAMP
.
There is also the function timeofday()
, which for historical reasons
returns a text string rather than a
timestamp value:
SELECT timeofday(); Result: Sat Feb 17 19:07:32.000126 2001 EST
It is important to know that CURRENT_TIMESTAMP
and related functions
return the start time of the current transaction; their values
do not change during the transaction. This is considered a
feature: the intent is to allow a single transaction to have a
consistent notion of the "current"
time, so that multiple modifications within the same
transaction bear the same time stamp. timeofday()
returns the wall-clock time and
does advance during transactions.
Note: Other database systems may 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.
[1] |
60 if leap seconds are implemented by the operating system |