PostgreSQL supports the full set of SQL date and time types.
Table 3-10. Date/Time Types
Type | Description | Storage | Earliest | Latest | Resolution |
---|---|---|---|---|---|
timestamp [ (p) ] without time zone | both date and time | 8 bytes | 4713 BC | AD 1465001 | 1 microsecond / 14 digits |
timestamp [ (p) ] [ with time zone ] | both date and time | 8 bytes | 4713 BC | AD 1465001 | 1 microsecond / 14 digits |
interval [ (p) ] | for time intervals | 12 bytes | -178000000 years | 178000000 years | 1 microsecond |
date | dates only | 4 bytes | 4713 BC | 32767 AD | 1 day |
time [ (p) ] [ without time zone ] | times of day only | 8 bytes | 00:00:00.00 | 23:59:59.99 | 1 microsecond |
time [ (p) ] with time zone | times of day only | 12 bytes | 00:00:00.00+12 | 23:59:59.99-12 | 1 microsecond |
time, timestamp, and interval accept an optional precision value p which specifies the number of fractional digits retained in the seconds field. By default, there is no explicit bound on precision. The effective limit of precision is determined by the underlying double precision floating-point number used to store values (in seconds for interval and in seconds since 2000-01-01 for timestamp). The useful range of p is from 0 to about 6 for timestamp, but may be more for interval. The system will accept p ranging from 0 to 13.
Time zones, and time-zone conventions, are influenced by political decisions, not just earth geometry. Time zones around the world became somewhat standardized during the 1900's, but continue to be prone to arbitrary changes. PostgreSQL uses your operating system's underlying features to provide output time-zone support, and these systems usually contain information for only the time period 1902 through 2038 (corresponding to the full range of conventional Unix system time). timestamp with time zone and time with time zone will use time zone information only within that year range, and assume that times outside that range are in UTC.
To ensure an upgrade path from versions of PostgreSQL earlier than 7.0, we recognize datetime (equivalent to timestamp) and timespan (equivalent to interval). These types are now restricted to having an implicit translation to timestamp and interval, and support for these will be removed in the next release of PostgreSQL (likely named 7.3).
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 PostgreSQL, and others. For some formats, ordering of month and day in date input can be ambiguous and there is support for specifying the expected ordering of these fields. 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.
PostgreSQL is more flexible in handling date/time than the SQL standard requires. See Appendix A for the exact parsing rules of date/time input and for the recognized text fields including months, days of the week, and time zones.
Remember that any date or time literal input needs to be enclosed in single quotes, like text strings. Refer to Section 1.1.2.5 for more information. SQL9x requires the following syntax
type [ (p) ] 'value'
where p in the optional precision specification is an integer corresponding to the number of fractional digits in the seconds field. Precision can be specified for time, timestamp, and interval types.
The following are some possible inputs for the date type.
Table 3-11. Date Input
Example | Description |
---|---|
January 8, 1999 | Unambiguous |
1999-01-08 | ISO-8601 format, preferred |
1/8/1999 | U.S.; read as August 1 in European mode |
8/1/1999 | European; read as August 1 in U.S. mode |
1/18/1999 | U.S.; 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 |
J2451187 | Julian day |
January 8, 99 BC | Year 99 before the Common Era |
Per SQL99, this type can be specified as time or as time without time zone. The optional precision p should be between 0 and 13, and defaults to the precision of the input time literal.
The following are valid time inputs.
This type is defined by SQL92, but the definition exhibits properties which lead to questionable usefulness. In most cases, a combination of date, time, timestamp without time zone and timestamp with time zone should provide a complete range of date/time functionality required by any application.
The optional precision p should be between 0 and 13, and defaults to the precision of the input time literal.
time with time zone accepts all input also legal for the time type, appended with a legal time zone, as follows:
Table 3-13. 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 Table 3-14 for more examples of time zones.
Valid input for the timestamp [ (p) ] without time zone 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
is a valid timestamp without time zone value that is ISO-compliant. In addition, the wide-spread format
January 8 04:05:06 1999 PST
is supported.
The optional precision p should be between 0 and 13, and defaults to the precision of the input timestamp literal.
For timestamp without time zone, any explicit time zone specified in the input is silently swallowed. That is, the resulting date/time value is derived from the explicit date/time fields in the input value, and is not adjusted for time zone.
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:00
is a valid timestamp value that is ISO-compliant. In addition, the wide-spread format
January 8 04:05:06 1999 PST
is supported.
The optional precision p should be between 0 and 13, and defaults to the precision of the input timestamp literal.
interval values can be written with the following syntax:
Quantity Unit [Quantity Unit...] [Direction] @ Quantity Unit [Quantity Unit...] [Direction]
where: Quantity is a number (possibly signed), 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 at sign (@) is optional noise. The amounts of different units are implicitly added up with appropriate sign accounting.
Quantities of days, hours, minutes, and seconds can be specified without explicit unit markings. For example, '1 12:59:10' is read the same as '1 day 12 hours 59 min 10 sec'.
The optional precision p should be between 0 and 13, and defaults to the precision of the input literal.
The following SQL-compatible functions can be used as date or time input for the corresponding data type: CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP. The latter two accept an optional precision specification.
PostgreSQL also supports several special constants for convenience.
Table 3-15. Special Date/Time Constants
Constant | Description |
---|---|
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 |
zulu, allballs, z | 00:00:00.00 GMT |
Note: As of PostgreSQL version 7.2, 'current' is no longer supported as a date/time constant. Previously, 'current' was stored as a special value, and evaluated to 'now' only when used in an expression or type conversion.
Output formats can be set to one of the four styles ISO 8601, SQL (Ingres), traditional PostgreSQL, and German, using the SET DateStyle. The default is the ISO format.
Table 3-16. 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 |
'PostgreSQL' | 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 (U.S.) variants, which determines whether month follows day or vice versa. (See also Section 3.5.1 for how this setting affects interpretation of input values.)
Table 3-17. 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 start-up.
The PGDATESTYLE environment variable used by the frontend libpq on session start-up.
SET DATESTYLE SQL command.
PostgreSQL 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. Time zones in the real world can have no meaning unless associated with a date as well as a time since the offset may vary through the year with daylight-saving time boundaries.
The default time zone is specified as a constant integer offset from GMT/UTC. It is not possible to adapt to daylight-saving time when doing date/time arithmetic across DST boundaries.
To address these difficulties, we recommend using date/time types that contain both date and time when using time zones. We recommend not using the SQL92 type time with time zone (though it is supported by PostgreSQL for legacy applications and for compatibility with other RDBMS implementations). PostgreSQL assumes your local time zone 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-saving time and other expected behavior.
PostgreSQL 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 UTC, traditionally 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 is used by the backend directly on postmaster start-up as the default time zone.
The PGTZ environment variable, if set at the client, is used by libpq to send a SET TIME ZONE command to the backend upon connection.
The SQL command SET TIME ZONE sets the time zone for the session.
The SQL92 qualifier on
timestamp AT TIME ZONE 'zone'
where zone can be specified as a text time zone (e.g. 'PST') or as an interval (e.g. INTERVAL '-08:00').
Note: If an invalid time zone is specified, the time zone becomes GMT (on most systems anyway).
Note: If the runtime option AUSTRALIAN_TIMEZONES is set then CST and EST refer to Australian time zones, not American ones.
PostgreSQL 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 consistent enough to warrant coding into a date/time handler.