Postgres supports the full set of SQL date and time types.
Table 3-7. Postgres Date/Time Types
Type | Description | Storage | Earliest | Latest | Resolution |
---|---|---|---|---|---|
timestamp | both date and time | 8 bytes | 4713 BC | AD 1465001 | 1 microsec / 14 digits |
timestamp with time zone | date and time with time zone | 8 bytes | 1903 AD | 2037 AD | 1 microsec / 14 digits |
interval | for time intervals | 12 bytes | -178000000 years | 178000000 years | 1 mircosecond |
date | dates only | 4 bytes | 4713 BC | 32767 AD | 1 day |
time | times of day only | 4 bytes | 00:00:00.00 | 23:59:59.99 | 1 microsecond |
time with time zone | times of day only | 4 bytes | 00:00:00.00+12 | 23:59:59.99-12 | 1 microsecond |
Note: To ensure compatibility to earlier versions of Postgres we also continue to provide datetime (equivalent to timestamp) and timespan (equivalent to interval), however support for these is now restricted to having an implicit translation to timestamp and interval. The types abstime and reltime are lower precision types which are used internally. You are discouraged from using any of these types in new applications and are encouraged to move any old ones over when appropriate. Any or all of these internal types might disappear in a future release.
Date and time input is accepted in almost any reasonable format, including ISO-8601, SQL-compatible, traditional Postgres, and others. The ordering of month and day in date input can be ambiguous, therefore a setting exists to specify how it should be interpreted in ambiguous cases. The command SET DateStyle TO 'US' or SET DateStyle TO 'NonEuropean' specifies the variant "month before day", the command SET DateStyle TO 'European' sets the variant "day before month". The ISO style is the default but this default can be changed at compile time or at run time.
See Date/Time Support for the exact parsing rules of date/time input and for the recognized time zones.
Remember that any date or time input needs to be enclosed into single quotes, like text strings.
The following are possible inputs for the date type.
Table 3-8. Postgres Date Input
Example | Description |
---|---|
January 8, 1999 | Unambiguous |
1999-01-08 | ISO-8601 format, preferred |
1/8/1999 | US; read as August 1 in European mode |
8/1/1999 | European; read as August 1 in US mode |
1/18/1999 | US; read as January 18 in any mode |
19990108 | ISO-8601 year, month, day |
990108 | ISO-8601 year, month, day |
1999.008 | Year and day of year |
99008 | Year and day of year |
January 8, 99 BC | Year 99 before the Common Era |
Table 3-9. Postgres Month Abbreviations
Month | Abbreviations |
---|---|
April | Apr |
August | Aug |
December | Dec |
February | Feb |
January | Jan |
July | Jul |
June | Jun |
March | Mar |
November | Nov |
October | Oct |
September | Sep, Sept |
Note: The month May has no explicit abbreviation, for obvious reasons.
Table 3-10. Postgres Day of Week Abbreviations
Day | Abbreviation |
---|---|
Sunday | Sun |
Monday | Mon |
Tuesday | Tue, Tues |
Wednesday | Wed, Weds |
Thursday | Thu, Thur, Thurs |
Friday | Fri |
Saturday | Sat |
The following are valid time inputs.
Table 3-11. Postgres Time Input
Example | Description |
---|---|
04:05:06.789 | ISO-8601 |
04:05:06 | ISO-8601 |
04:05 | ISO-8601 |
040506 | ISO-8601 |
04:05 AM | Same as 04:05; AM does not affect value |
04:05 PM | Same as 16:05; input hour must be <= 12 |
z | Same as 00:00:00 |
zulu | Same as 00:00:00 |
allballs | Same as 00:00:00 |
This type is defined by SQL92, but the definition exhibits fundamental deficiencies which renders the type nearly useless. In most cases, a combination of date, time, and timestamp should provide a complete range of date/time functionality required by any application.
time with time zone accepts all input also legal for the time type, appended with a legal time zone, as follows:
Table 3-12. Postgres Time With Time Zone Input
Example | Description |
---|---|
04:05:06.789-8 | ISO-8601 |
04:05:06-08:00 | ISO-8601 |
04:05-08:00 | ISO-8601 |
040506-08 | ISO-8601 |
Refer to Postgres Time Zone Input for more examples of time zones.
Valid input for the timestamp type consists of a concatenation of a date and a time, followed by an optional AD or BC, followed by an optional time zone. (See below.) Thus
1999-01-08 04:05:06 -8:00is a valid timestamp value, which is ISO-compliant. In addition, the wide-spread format
January 8 04:05:06 1999 PSTis supported.
Table 3-13. Postgres Time Zone Input
Time Zone | Description |
---|---|
PST | Pacific Standard Time |
-8:00 | ISO-8601 offset for PST |
-800 | ISO-8601 offset for PST |
-8 | ISO-8601 offset for PST |
intervals can be specified with the following syntax:
Quantity Unit [Quantity Unit...] [Direction] @ Quantity Unit [Direction]where: Quantity is ..., -1, 0, 1, 2, ...; Unit is second, minute, hour, day, week, month, year, decade, century, millennium, or abbreviations or plurals of these units; Direction can be ago or empty.
The following SQL-compatible functions can be used as date or time input for the corresponding datatype: CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP.
Postgres also supports several special constants for convenience.
Table 3-14. Postgres Special Date/Time Constants
Constant | Description |
---|---|
current | Current transaction time, deferred |
epoch | 1970-01-01 00:00:00+00 (Unix system time zero) |
infinity | Later than other valid times |
-infinity | Earlier than other valid times |
invalid | Illegal entry |
now | Current transaction time |
today | Midnight today |
tomorrow | Midnight tomorrow |
yesterday | Midnight yesterday |
Output formats can be set to one of the four styles ISO-8601, SQL (Ingres), traditional Postgres, and German, using the SET DateStyle. The default is the ISO format.
Table 3-15. Postgres Date/Time Output Styles
Style Specification | Description | Example |
---|---|---|
'ISO' | ISO-8601 standard | 1997-12-17 07:37:16-08 |
'SQL' | Traditional style | 12/17/1997 07:37:16.00 PST |
'Postgres' | Original style | Wed Dec 17 07:37:16 1997 PST |
'German' | Regional style | 17.12.1997 07:37:16.00 PST |
The output of the date and time styles is of course only the date or time part in accordance with the above examples.
The SQL style has European and non-European (US) variants, which determines whether month follows day or vica versa. (See also above at Date/Time Input, how this setting affects interpretation of input values.)
Table 3-16. Postgres Date Order Conventions
Style Specification | Description | Example |
---|---|---|
European | day/month/year | 17/12/1997 15:37:16.00 MET |
US | month/day/year | 12/17/1997 07:37:16.00 PST |
interval output looks like the input format, except that units like week or century are converted to years and days. In ISO mode the output looks like
[ Quantity Units [ ... ] ] [ Days ] Hours:Minutes [ ago ]
There are several ways to affect the appearance of date/time types:
The PGDATESTYLE environment variable used by the backend directly on postmaster startup.
The PGDATESTYLE environment variable used by the frontend libpq on session startup.
SET DATESTYLE SQL command.
Postgres endeavors to be compatible with SQL92 definitions for typical usage. However, the SQL92 standard has an odd mix of date and time types and capabilities. Two obvious problems are:
Although the date type does not have an associated time zone, the time type can or does.
The default time zone is specified as a constant integer offset from GMT/UTC.
To address these difficulties, Postgres associates time zones only with date and time types which contain both date and time, and assumes local time for any type containing only date or time. Further, time zone support is derived from the underlying operating system time zone capabilities, and hence can handle daylight savings time and other expected behavior.
Postgres obtains time zone support from the underlying operating system for dates between 1902 and 2038 (near the typical date limits for Unix-style systems). Outside of this range, all dates are assumed to be specified and used in Universal Coordinated Time (UTC).
All dates and times are stored internally in Universal UTC, alternately known as Greenwich Mean Time (GMT). Times are converted to local time on the database server before being sent to the client frontend, hence by default are in the server time zone.
There are several ways to affect the time zone behavior:
The TZ environment variable used by the backend directly on postmaster startup as the default time zone.
The PGTZ environment variable set at the client used by libpq to send time zone information to the backend upon connection.
The SQL command SET TIME ZONE sets the time zone for the session.
If an invalid time zone is specified, the time zone becomes GMT (on most systems anyway).
Note: If the compiler option USE_AUSTRALIAN_RULES is set then EST refers to Australia Eastern Std Time, which has an offset of +10:00 hours from UTC.
Postgres uses Julian dates for all date/time calculations. They have the nice property of correctly predicting/calculating any date more recent than 4713BC to far into the future, using the assumption that the length of the year is 365.2425 days.
Date conventions before the 19th century make for interesting reading, but are not consistant enough to warrant coding into a date/time handler.