DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH PRINT BOOK
 

8.5. Date/Time Types

PostgreSQL supports the full set of SQL date and time types, shown in Table 8-9. The operations available on these data types are described in Section 9.9.

Table 8-9. Date/Time Types

NameStorage SizeDescriptionLow ValueHigh ValueResolution
timestamp [ (p) ] [ without time zone ]8 bytesboth date and time4713 BC5874897 AD1 microsecond / 14 digits
timestamp [ (p) ] with time zone8 bytesboth date and time, with time zone4713 BC5874897 AD1 microsecond / 14 digits
interval [ (p) ]12 bytestime intervals-178000000 years178000000 years1 microsecond / 14 digits
date4 bytesdates only4713 BC5874897 AD1 day
time [ (p) ] [ without time zone ]8 bytestimes of day only00:00:0024:00:001 microsecond / 14 digits
time [ (p) ] with time zone12 bytestimes of day only, with time zone00:00:00+135924:00:00-13591 microsecond / 14 digits

Note: Prior to PostgreSQL 7.3, writing just timestamp was equivalent to timestamp with time zone. This was changed for SQL compliance.

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 allowed range of p is from 0 to 6 for the timestamp and interval types.

Note: When timestamp values are stored as double precision floating-point numbers (currently the default), the effective limit of precision may be less than 6. timestamp values are stored as seconds before or after midnight 2000-01-01. Microsecond precision is achieved for dates within a few years of 2000-01-01, but the precision degrades for dates further away. When timestamp values are stored as eight-byte integers (a compile-time option), microsecond precision is available over the full range of values. However eight-byte integer timestamps have a more limited range of dates than shown above: from 4713 BC up to 294276 AD. The same compile-time option also determines whether time and interval values are stored as floating-point or eight-byte integers. In the floating-point case, large interval values degrade in precision as the size of the interval increases.

For the time types, the allowed range of p is from 0 to 6 when eight-byte integer storage is used, or from 0 to 10 when floating-point storage is used.

The type time with time zone is defined by the SQL standard, 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 types abstime and reltime are lower precision types which are used internally. You are discouraged from using 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.

8.5.1. Date/Time Input

Date and time input is accepted in almost any reasonable format, including ISO 8601, SQL-compatible, traditional POSTGRES, and others. For some formats, ordering of month, day, and year in date input is ambiguous and there is support for specifying the expected ordering of these fields. Set the DateStyle parameter to MDY to select month-day-year interpretation, DMY to select day-month-year interpretation, or YMD to select year-month-day interpretation.

PostgreSQL is more flexible in handling date/time input than the SQL standard requires. See Appendix B 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 4.1.2.5 for more information. SQL 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 allowed values are mentioned above. If no precision is specified in a constant specification, it defaults to the precision of the literal value.

8.5.1.1. Dates

Table 8-10 shows some possible inputs for the date type.

Table 8-10. Date Input

ExampleDescription
January 8, 1999unambiguous in any datestyle input mode
1999-01-08ISO 8601; January 8 in any mode (recommended format)
1/8/1999January 8 in MDY mode; August 1 in DMY mode
1/18/1999January 18 in MDY mode; rejected in other modes
01/02/03January 2, 2003 in MDY mode; February 1, 2003 in DMY mode; February 3, 2001 in YMD mode
1999-Jan-08January 8 in any mode
Jan-08-1999January 8 in any mode
08-Jan-1999January 8 in any mode
99-Jan-08January 8 in YMD mode, else error
08-Jan-99January 8, except error in YMD mode
Jan-08-99January 8, except error in YMD mode
19990108ISO 8601; January 8, 1999 in any mode
990108ISO 8601; January 8, 1999 in any mode
1999.008year and day of year
J2451187Julian day
January 8, 99 BCyear 99 before the Common Era

8.5.1.2. Times

The time-of-day types are time [ (p) ] without time zone and time [ (p) ] with time zone. Writing just time is equivalent to time without time zone.

Valid input for these types consists of a time of day followed by an optional time zone. (See Table 8-11 and Table 8-12.) If a time zone is specified in the input for time without time zone, it is silently ignored.

Table 8-11. Time Input

ExampleDescription
04:05:06.789ISO 8601
04:05:06ISO 8601
04:05ISO 8601
040506ISO 8601
04:05 AMsame as 04:05; AM does not affect value
04:05 PMsame as 16:05; input hour must be <= 12
04:05:06.789-8ISO 8601
04:05:06-08:00ISO 8601
04:05-08:00ISO 8601
040506-08ISO 8601
04:05:06 PSTtime zone specified by name

Table 8-12. Time Zone Input

ExampleDescription
PSTPacific Standard Time
-8:00ISO-8601 offset for PST
-800ISO-8601 offset for PST
-8ISO-8601 offset for PST
zuluMilitary abbreviation for UTC
zShort form of zulu

Refer to Appendix B for a list of time zone names that are recognized for input.

8.5.1.3. Time Stamps

Valid input for the time stamp types consists of a concatenation of a date and a time, followed by an optional time zone, followed by an optional AD or BC. (Alternatively, AD/BC can appear before the time zone, but this is not the preferred ordering.) Thus

1999-01-08 04:05:06

and

1999-01-08 04:05:06 -8:00

are valid values, which follow the ISO 8601 standard. In addition, the wide-spread format

January 8 04:05:06 1999 PST

is supported.

The SQL standard differentiates timestamp without time zone and timestamp with time zone literals by the presence of a "+" or "-". Hence, according to the standard,

TIMESTAMP '2004-10-19 10:23:54'

is a timestamp without time zone, while

TIMESTAMP '2004-10-19 10:23:54+02'

is a timestamp with time zone. PostgreSQL never examines the content of a literal string before determining its type, and therefore will treat both of the above as timestamp without time zone. To ensure that a literal is treated as timestamp with time zone, give it the correct explicit type:

TIMESTAMP WITH TIME ZONE '2004-10-19 10:23:54+02'

In a literal that has been decided to be timestamp without time zone, PostgreSQL will silently ignore any time zone indication. That is, the resulting value is derived from the date/time fields in the input value, and is not adjusted for time zone.

For timestamp with time zone, the internally stored value is always in UTC (Universal Coordinated Time, traditionally known as Greenwich Mean Time, GMT). An input value that has an explicit time zone specified is converted to UTC using the appropriate offset for that time zone. If no time zone is stated in the input string, then it is assumed to be in the time zone indicated by the system's timezone parameter, and is converted to UTC using the offset for the timezone zone.

When a timestamp with time zone value is output, it is always converted from UTC to the current timezone zone, and displayed as local time in that zone. To see the time in another time zone, either change timezone or use the AT TIME ZONE construct (see Section 9.9.3).

Conversions between timestamp without time zone and timestamp with time zone normally assume that the timestamp without time zone value should be taken or given as timezone local time. A different zone reference can be specified for the conversion using AT TIME ZONE.

8.5.1.4. Intervals

interval values can be written with the following syntax:

[@] 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 subsecond precision p should be between 0 and 6, and defaults to the precision of the input literal.

Internally interval values are stored as months, days, and seconds. This is done because the number of days in a month varies, and a day can have 23 or 25 hours if a daylight savings time adjustment is involved. Because intervals are usually created from constant strings or timestamp subtraction, this storage method works well in most cases. Functions justify_days and justify_hours are available for adjusting days and hours that overflow their normal periods.

8.5.1.5. Special Values

PostgreSQL supports several special date/time input values for convenience, as shown in Table 8-13. The values infinity and -infinity are specially represented inside the system and will be displayed the same way; but the others are simply notational shorthands that will be converted to ordinary date/time values when read. (In particular, now and related strings are converted to a specific time value as soon as they are read.) All of these values need to be written in single quotes when used as constants in SQL commands.

Table 8-13. Special Date/Time Inputs

Input StringValid TypesDescription
epochdate, timestamp1970-01-01 00:00:00+00 (Unix system time zero)
infinitytimestamplater than all other time stamps
-infinitytimestampearlier than all other time stamps
nowdate, time, timestampcurrent transaction's start time
todaydate, timestampmidnight today
tomorrowdate, timestampmidnight tomorrow
yesterdaydate, timestampmidnight yesterday
allballstime00:00:00.00 UTC

The following SQL-compatible functions can also be used to obtain the current time value for the corresponding data type: CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, LOCALTIME, LOCALTIMESTAMP. The latter four accept an optional subsecond precision specification. (See Section 9.9.4.) Note however that these are SQL functions and are not recognized as data input strings.

8.5.2. Date/Time Output

The output format of the date/time types can be set to one of the four styles ISO 8601, SQL (Ingres), traditional POSTGRES, and German, using the command SET datestyle. The default is the ISO format. (The SQL standard requires the use of the ISO 8601 format. The name of the "SQL" output format is a historical accident.) Table 8-14 shows examples of each output style. The output of the date and time types is of course only the date or time part in accordance with the given examples.

Table 8-14. Date/Time Output Styles

Style SpecificationDescriptionExample
ISOISO 8601/SQL standard1997-12-17 07:37:16-08
SQLtraditional style12/17/1997 07:37:16.00 PST
POSTGRESoriginal styleWed Dec 17 07:37:16 1997 PST
Germanregional style17.12.1997 07:37:16.00 PST

In the SQL and POSTGRES styles, day appears before month if DMY field ordering has been specified, otherwise month appears before day. (See Section 8.5.1 for how this setting also affects interpretation of input values.) Table 8-15 shows an example.

Table 8-15. Date Order Conventions

datestyle SettingInput OrderingExample Output
SQL, DMYday/month/year17/12/1997 15:37:16.00 CET
SQL, MDYmonth/day/year12/17/1997 07:37:16.00 PST
Postgres, DMYday/month/yearWed 17 Dec 07:37:16 1997 PST

interval output looks like the input format, except that units like century or week are converted to years and days and ago is converted to an appropriate sign. In ISO mode the output looks like

[ quantity unit [ ... ] ] [ days ] [ hours:minutes:seconds ]

The date/time styles can be selected by the user using the SET datestyle command, the DateStyle parameter in the postgresql.conf configuration file, or the PGDATESTYLE environment variable on the server or client. The formatting function to_char (see Section 9.8) is also available as a more flexible way to format the date/time output.

8.5.3. Time Zones

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, particularly with respect to daylight-savings rules. PostgreSQL currently supports daylight-savings rules over the time period 1902 through 2038 (corresponding to the full range of conventional Unix system time). Times outside that range are taken to be in "standard time" for the selected time zone, no matter what part of the year they fall in.

PostgreSQL endeavors to be compatible with the SQL standard definitions for typical usage. However, the SQL standard has an odd mix of date and time types and capabilities. Two obvious problems are:

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 type time with time zone (though it is supported by PostgreSQL for legacy applications and for compliance with the SQL standard). PostgreSQL assumes your local time zone for any type containing only date or time.

All timezone-aware dates and times are stored internally in UTC. They are converted to local time in the zone specified by the timezone configuration parameter before being displayed to the client.

The timezone configuration parameter can be set in the file postgresql.conf, or in any of the other standard ways described in Chapter 17. There are also several special ways to set it:

Refer to Appendix B for a list of available time zones.

8.5.4. Internals

PostgreSQL uses Julian dates for all date/time calculations. They have the nice property of correctly predicting/calculating any date more recent than 4713 BC 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.