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.
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.8
. 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.
Also, the
+
and
*
operators come in commutative pairs (for example
both date + integer and integer + date); we show only one of each
such pair.
timestamp with time zone
Current date and time (equivalent to
current_timestamp
); see
Section
9.9.4
If you are using both
justify_hours
and
justify_days
, it is best to use
justify_hours
first so any additional days will
be included in the
justify_days
calculation.
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
When adding an
interval
value to (or
subtracting an
interval
value from) a
timestamp with time zone
value, the days
component advances (or decrements) the date of the
timestamp with time zone
by the indicated number of
days. Across daylight saving time changes (with the session time
zone set to a time zone that recognizes DST), this means
interval '1 day'
does not necessarily
equal
interval '24 hours'
. For example,
with the session time zone set to
CST7CDT
,
timestamp with time
zone '2005-04-02 12:00-07' + interval '1 day'
will produce
timestamp with time zone '2005-04-03
12:00-06'
, while adding
interval '24
hours'
to the same initial
timestamp with
time zone
produces
timestamp with time
zone '2005-04-03 13:00-06'
, as there is a change in daylight
saving time at
2005-04-03 02:00
in time
zone
CST7CDT
.
EXTRACT(
field
FROM
source
)
The
extract
function retrieves
subfields such as year or hour from date/time values.
source
must be a value
expression of type
timestamp
,
time
, or
interval
.
(Expressions of type
date
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:
century
The century
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
Result:
20
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
Result:
21
The first century starts at 0001-01-01 00:00:00 AD,
although they did not know it at the time. This
definition applies to all Gregorian calendar countries.
There is no century number 0, you go from -1 to 1. If you
disagree with this, please write your complaint to: Pope,
Cathedral Saint-Peter of Roma, Vatican.
PostgreSQL
releases
before 8.0 did not follow the conventional numbering of
centuries, but just returned the year field divided by
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
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
Note that
extract
's day
of the week numbering is different from that of the
to_char
function.
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 WITH TIME ZONE '2001-02-16 20:38:40-08');
Result:
982384720
SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
Result:
442800
Here is how you can convert an epoch value back to a
time stamp:
SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
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 millennium
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
Result:
3
Years in the 1900s are in the second millennium. The
third millennium starts January 1, 2001.
PostgreSQL
releases
before 8.0 did not follow the conventional numbering of
millennia, but just returned the year field divided by
1000.
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
)
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
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.
timezone_hour
The hour component of the time zone offset
timezone_minute
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)
Because of this, it is possible for early January
dates to be part of the 52nd or 53rd week of the previous
year. For example,
2005-01-01
is
part of the 53rd week of year 2004, and
2006-01-01
is part of the 52nd week of
year 2005.
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
Result:
7
The year field. Keep in mind there is no
0 AD
, so subtracting
BC
years from
AD
years should be done with care.
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.8
.
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
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
The
AT TIME ZONE
construct allows
conversions of time stamps to different time zones.
Table
9-27
shows its variants.
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'
). In the text
case, the available zone names are those shown in either
Table
B-6
or
Table
B-4
.
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 time stamp without time zone and
interprets it as MST time (UTC-7), which is then converted 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
.
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.
Note:
Other database systems may advance these
values more frequently.
There is also the function
timeofday()
which returns the wall-clock time
and advances during transactions. For historical reasons
timeofday()
returns a
text
string rather than a
timestamp
value:
SELECT timeofday();
Result:
Sat Feb 17 19:07:32.000126 2001 EST
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'; -- incorrect for use with DEFAULT
Tip:
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.