Table 4-14 shows the available functions for date/time value processing. The basic arithmetic operators (+, *, etc.) are also available. For formatting functions, refer to Section 4.6. You should be familiar with the background information on date/time data types (see Section 3.4).
Table 4-14. Date/Time Functions
Name | Return Type | Description | Example | Result |
---|---|---|---|---|
current_date | date | returns current date; see also below | ||
current_time | time | returns current time (of day); see also below | ||
current_timestamp | timestamp | returns current date and time; see also below | ||
date_part(text, timestamp) | double precision | extract subfield from date/time value (equivalent to extract); see also below | date_part('hour', timestamp '2001-02-16 20:38:40') | 20 |
date_part(text, interval) | double precision | extract subfield from interval value (equivalent to extract); see also below | date_part('month', interval '2 years 3 months') | 3 |
date_trunc(text, timestamp) | timestamp | truncate date to specified precision; see also below | date_trunc('hour', timestamp '2001-02-16 20:38:40') | 2001-02-16 20:00:00+00 |
extract(identifier from timestamp) | double precision | extract subfield from date/time value; see also below | extract(hour from timestamp '2001-02-16 20:38:40') | 20 |
extract(identifier from interval) | double precision | extract subfield from interval value; see also below | extract(month from interval '2 years 3 months') | 3 |
isfinite(timestamp) | boolean | Returns true if the time stamp is finite (neither invalid nor infinity) | isfinite(timestamp '2001-02-16 21:28:30') | true |
isfinite(interval) | boolean | Returns true if the interval is finite in length | isfinite(interval '4 hours') | true |
now() | timestamp | returns current date and time (equivalent to current_timestamp); see also below | ||
timeofday() | text | returns high-precision date and time; see also below | timeofday() | Wed Feb 21 17:01:13.000126 2001 EST |
timestamp(date) | timestamp | convert date to timestamp | timestamp(date '2000-12-25') | 2000-12-25 00:00:00 |
timestamp(date, time) | timestamp | combine date and time into a timestamp | timestamp(date '1998-02-24',time '23:07') | 1998-02-24 23:07:00 |
EXTRACT (field FROM source)
The extract function retrieves sub-fields 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 (not a 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:
The year field divided by 100
Note that this is not really the century that the date is in.
The day (of the month) field (1 - 31)
The year field divided by 10
The day of the week (0 - 6; Sunday is 0) (for timestamp values only)
The day of the year (1 - 365/366) (for timestamp values only)
For date and timestamp values, the number of seconds since 1970-01-01 00:00:00 (Result may be negative.); for interval values, the total number of seconds in the interval
The hour field (0 - 23)
The seconds field, including fractional parts, multiplied by 1 000 000. Note that this includes full seconds.
The year field divided by 1000
Note that this is not really the millennium that the date is in.
The seconds field, including fractional parts, multiplied by 1000. Note that this includes full seconds.
The minutes field (0 - 59)
For timestamp values, the number of the month within the year (1 - 12) ; for interval values the number of months, modulo 12 (0 - 11)
The quarter of the year (1 - 4) that the day is in (for timestamp values only)
The seconds field, including fractional parts (0 - 59[1])
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.
The year field
The extract function is primarily intended for computational processing. For formatting date/time values for display, see Section 4.6.
The date_part function is the traditional Postgres equivalent to the SQL-function extract:
date_part('field', source)Note that here the field value needs to be a string. The valid field values for date_part are the same as for extract.
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 |
The following functions are available to obtain the current date and/or time:
CURRENT_TIME CURRENT_DATE CURRENT_TIMESTAMPNote that because of the requirements of the SQL standard, these functions must not be called with trailing parentheses.
SELECT CURRENT_TIME; 19:07:32 SELECT CURRENT_DATE; 2001-02-17 SELECT CURRENT_TIMESTAMP; 2001-02-17 19:07:32-05
The function now() is the traditional Postgres equivalent to CURRENT_TIMESTAMP.
There is also timeofday(), which returns current time to higher precision than the CURRENT_TIMESTAMP family does:
timeofday() uses the operating system call gettimeofday(2), which may have resolution as good as microseconds (depending on your platform); the other functions rely on time(2) which is restricted to one-second resolution. For historical reasons, timeofday() returns its result as a text string rather than a timestamp value.
It is quite important to realize that CURRENT_TIMESTAMP and related functions all return the time as of the start of the current transaction; their values do not increment while a transaction is running. But timeofday() returns the actual current time.
All the date/time datatypes 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 value 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 |