Date/Time Support
PostgreSQL uses an internal heuristic
parser for all date/time input support. Dates and times are input as
strings, and are broken up into distinct fields with a preliminary
determination of what kind of information can be in the
field. Each field is interpreted and either assigned a numeric
value, ignored, or rejected.
The parser contains internal lookup tables for all textual fields,
including months, days of the week, and time zones.
This appendix includes information on the content of these
lookup tables and describes the steps used by the parser to decode
dates and times.
Date/Time Input Interpretation
The date/time type inputs are all decoded using the following procedure.
Break the input string into tokens and categorize each token as
a string, time, time zone, or number.
If the numeric token contains a colon (:>), this is
a time string. Include all subsequent digits and colons.
If the numeric token contains a dash (->), slash
(/>), or two or more dots (.>), this is
a date string which might have a text month. If a date token has
already been seen, it is instead interpreted as a time zone
name (e.g., America/New_York>).
If the token is numeric only, then it is either a single field
or an ISO 8601 concatenated date (e.g.,
19990113 for January 13, 1999) or time
(e.g., 141516 for 14:15:16).
If the token starts with a plus (+>) or minus
(->), then it is either a numeric time zone or a special
field.
If the token is a text string, match up with possible strings:
Do a binary-search table lookup for the token as a time zone
abbreviation.
If not found, do a similar binary-search table lookup to match
the token as either a special string (e.g., today),
day (e.g., Thursday),
month (e.g., January),
or noise word (e.g., at, on).
If still not found, throw an error.
When the token is a number or number field:
If there are eight or six digits,
and if no other date fields have been previously read, then interpret
as a concatenated date
(e.g.,
19990118 or 990118).
The interpretation is YYYYMMDD> or YYMMDD>.
If the token is three digits
and a year has already been read, then interpret as day of year.
If four or six digits and a year has already been read, then
interpret as a time (HHMM> or HHMMSS>).
If three or more digits and no date fields have yet been found,
interpret as a year (this forces yy-mm-dd ordering of the remaining
date fields).
Otherwise the date field ordering is assumed to follow the
DateStyle> setting: mm-dd-yy, dd-mm-yy, or yy-mm-dd.
Throw an error if a month or day field is found to be out of range.
If BC has been specified, negate the year and add one for
internal storage. (There is no year zero in the Gregorian
calendar, so numerically 1 BC becomes year zero.)
If BC was not specified, and if the year field was two digits in length,
then adjust the year to four digits. If the field is less than 70, then
add 2000, otherwise add 1900.
Gregorian years AD 1-99 can be entered by using 4 digits with leading
zeros (e.g., 0099> is AD 99).
Date/Time Key Words
shows the tokens that are
recognized as names of months.
Month Names
Month
Abbreviations
January
Jan
February
Feb
March
Mar
April
Apr
May
June
Jun
July
Jul
August
Aug
September
Sep, Sept
October
Oct
November
Nov
December
Dec
shows the tokens that are
recognized as names of days of the week.
Day of the Week Names
Day
Abbreviations
Sunday
Sun
Monday
Mon
Tuesday
Tue, Tues
Wednesday
Wed, Weds
Thursday
Thu, Thur, Thurs
Friday
Fri
Saturday
Sat
shows the tokens that serve
various modifier purposes.
Date/Time Field Modifiers
Identifier
Description
AM
Time is before 12:00
AT
Ignored
JULIAN>, JD>, J>
Next field is Julian Date
ON
Ignored
PM
Time is on or after 12:00
T
Next field is time
Date/Time Configuration Files
time zone
input abbreviations
Since timezone abbreviations are not well standardized,
PostgreSQL provides a means to customize
the set of abbreviations accepted by the server. The
run-time parameter
determines the active set of abbreviations. While this parameter
can be altered by any database user, the possible values for it
are under the control of the database administrator — they
are in fact names of configuration files stored in
.../share/timezonesets/> of the installation directory.
By adding or altering files in that directory, the administrator
can set local policy for timezone abbreviations.
timezone_abbreviations> can be set to any file name
found in .../share/timezonesets/>, if the file's name
is entirely alphabetic. (The prohibition against non-alphabetic
characters in timezone_abbreviations> prevents reading
files outside the intended directory, as well as reading editor
backup files and other extraneous files.)
A timezone abbreviation file can contain blank lines and comments
beginning with #>. Non-comment lines must have one of
these formats:
time_zone_name offset
time_zone_name offset D
@INCLUDE file_name
@OVERRIDE
A time_zone_name is just the abbreviation
being defined. The offset is the zone's
offset in seconds from UTC, positive being east from Greenwich and
negative being west. For example, -18000 would be five hours west
of Greenwich, or North American east coast standard time. D>
indicates that the zone name represents local daylight-savings time
rather than standard time. Since all known time zone offsets are on
15 minute boundaries, the number of seconds has to be a multiple of 900.
The @INCLUDE> syntax allows inclusion of another file in the
.../share/timezonesets/> directory. Inclusion can be nested,
to a limited depth.
The @OVERRIDE> syntax indicates that subsequent entries in the
file can override previous entries (i.e., entries obtained from included
files). Without this, conflicting definitions of the same timezone
abbreviation are considered an error.
In an unmodified installation, the file Default> contains
all the non-conflicting time zone abbreviations for most of the world.
Additional files Australia> and India> are
provided for those regions: these files first include the
Default> file and then add or modify timezones as needed.
For reference purposes, a standard installation also contains files
Africa.txt>, America.txt>, etc, containing
information about every time zone abbreviation known to be in use
according to the zoneinfo> timezone database. The zone name
definitions found in these files can be copied and pasted into a custom
configuration file as needed. Note that these files cannot be directly
referenced as timezone_abbreviations> settings, because of
the dot embedded in their names.
If an error occurs while reading the time zone data sets, no new value is
applied but the old set is kept. If the error occurs while starting the
database, startup fails.
Time zone abbreviations defined in the configuration file override
non-timezone meanings built into PostgreSQL.
For example, the Australia> configuration file defines
SAT> (for South Australian Standard Time). When this
file is active, SAT> will not be recognized as an abbreviation
for Saturday.
If you modify files in .../share/timezonesets/>,
it is up to you to make backups — a normal database dump
will not include this directory.
History of Units
Gregorian calendar
Julian date
The SQL standard states that Within the definition of a
datetime literal
, the datetime
values
are constrained by the natural rules for dates and
times according to the Gregorian calendar
.
PostgreSQL> follows the SQL
standard's lead by counting dates exclusively in the Gregorian
calendar, even for years before that calendar was in use.
This rule is known as the proleptic Gregorian calendar>.
The Julian calendar was introduced by Julius Caesar in 45 BC.
It was in common use in the Western world
until the year 1582, when countries started changing to the Gregorian
calendar. In the Julian calendar, the tropical year is
approximated as 365 1/4 days = 365.25 days. This gives an error of
about 1 day in 128 years.
The accumulating calendar error prompted
Pope Gregory XIII to reform the calendar in accordance with
instructions from the Council of Trent.
In the Gregorian calendar, the tropical year is approximated as
365 + 97 / 400 days = 365.2425 days. Thus it takes approximately 3300
years for the tropical year to shift one day with respect to the
Gregorian calendar.
The approximation 365+97/400 is achieved by having 97 leap years
every 400 years, using the following rules:
Every year divisible by 4 is a leap year.
However, every year divisible by 100 is not a leap year.
However, every year divisible by 400 is a leap year after all.
So, 1700, 1800, 1900, 2100, and 2200 are not leap years. But 1600,
2000, and 2400 are leap years.
By contrast, in the older Julian calendar all years divisible by 4 are leap
years.
The papal bull of February 1582 decreed that 10 days should be dropped
from October 1582 so that 15 October should follow immediately after
4 October.
This was observed in Italy, Poland, Portugal, and Spain. Other Catholic
countries followed shortly after, but Protestant countries were
reluctant to change, and the Greek Orthodox countries didn't change
until the start of the 20th century.
The reform was observed by Great Britain and its dominions (including what
is now the USA) in 1752.
Thus 2 September 1752 was followed by 14 September 1752.
This is why Unix systems have the cal program
produce the following:
$ cal 9 1752
September 1752
S M Tu W Th F S
1 2 14 15 16
17 18 19 20 21 22 23
24 25 26 27 28 29 30
But, of course, this calendar is only valid for Great Britain and
dominions, not other places.
Since it would be difficult and confusing to try to track the actual
calendars that were in use in various places at various times,
PostgreSQL> does not try, but rather follows the Gregorian
calendar rules for all dates, even though this method is not historically
accurate.
Different calendars have been developed in various parts of the
world, many predating the Gregorian system.
For example,
the beginnings of the Chinese calendar can be traced back to the 14th
century BC. Legend has it that the Emperor Huangdi invented that
calendar in 2637 BC.
The People's Republic of China uses the Gregorian calendar
for civil purposes. The Chinese calendar is used for determining
festivals.
The Julian Date system is another type of
calendar, unrelated to the Julian calendar though it is confusingly
named similarly to that calendar.
The Julian Date system was invented by the French scholar
Joseph Justus Scaliger (1540-1609)
and probably takes its name from Scaliger's father,
the Italian scholar Julius Caesar Scaliger (1484-1558).
In the Julian Date system, each day has a sequential number, starting
from JD 0 (which is sometimes called the> Julian Date).
JD 0 corresponds to 1 January 4713 BC in the Julian calendar, or
24 November 4714 BC in the Gregorian calendar. Julian Date counting
is most often used by astronomers for labeling their nightly observations,
and therefore a date runs from noon UTC to the next noon UTC, rather than
from midnight to midnight: JD 0 designates the 24 hours from noon UTC on
24 November 4714 BC to noon UTC on 25 November 4714 BC.
Although PostgreSQL> supports Julian Date notation for
input and output of dates (and also uses Julian dates for some internal
datetime calculations), it does not observe the nicety of having dates
run from noon to noon. PostgreSQL> treats a Julian Date
as running from midnight to midnight.