1<!-- doc/src/sgml/datetime.sgml --> 2 3 <appendix id="datetime-appendix"> 4 <title>Date/Time Support</title> 5 6 <para> 7 <productname>PostgreSQL</productname> uses an internal heuristic 8 parser for all date/time input support. Dates and times are input as 9 strings, and are broken up into distinct fields with a preliminary 10 determination of what kind of information can be in the 11 field. Each field is interpreted and either assigned a numeric 12 value, ignored, or rejected. 13 The parser contains internal lookup tables for all textual fields, 14 including months, days of the week, and time zones. 15 </para> 16 17 <para> 18 This appendix includes information on the content of these 19 lookup tables and describes the steps used by the parser to decode 20 dates and times. 21 </para> 22 23 <sect1 id="datetime-input-rules"> 24 <title>Date/Time Input Interpretation</title> 25 26 <para> 27 Date/time input strings are decoded using the following procedure. 28 </para> 29 30 <procedure> 31 <step> 32 <para> 33 Break the input string into tokens and categorize each token as 34 a string, time, time zone, or number. 35 </para> 36 37 <substeps> 38 <step> 39 <para> 40 If the numeric token contains a colon (<literal>:</literal>), this is 41 a time string. Include all subsequent digits and colons. 42 </para> 43 </step> 44 45 <step> 46 <para> 47 If the numeric token contains a dash (<literal>-</literal>), slash 48 (<literal>/</literal>), or two or more dots (<literal>.</literal>), this is 49 a date string which might have a text month. If a date token has 50 already been seen, it is instead interpreted as a time zone 51 name (e.g., <literal>America/New_York</literal>). 52 </para> 53 </step> 54 55 <step> 56 <para> 57 If the token is numeric only, then it is either a single field 58 or an ISO 8601 concatenated date (e.g., 59 <literal>19990113</literal> for January 13, 1999) or time 60 (e.g., <literal>141516</literal> for 14:15:16). 61 </para> 62 </step> 63 64 <step> 65 <para> 66 If the token starts with a plus (<literal>+</literal>) or minus 67 (<literal>-</literal>), then it is either a numeric time zone or a special 68 field. 69 </para> 70 </step> 71 </substeps> 72 </step> 73 74 <step> 75 <para> 76 If the token is an alphabetic string, match up with possible strings: 77 </para> 78 79 <substeps> 80 <step> 81 <para> 82 See if the token matches any known time zone abbreviation. 83 These abbreviations are supplied by the configuration file 84 described in <xref linkend="datetime-config-files"/>. 85 </para> 86 </step> 87 88 <step> 89 <para> 90 If not found, search an internal table to match 91 the token as either a special string (e.g., <literal>today</literal>), 92 day (e.g., <literal>Thursday</literal>), 93 month (e.g., <literal>January</literal>), 94 or noise word (e.g., <literal>at</literal>, <literal>on</literal>). 95 </para> 96 </step> 97 98 <step> 99 <para> 100 If still not found, throw an error. 101 </para> 102 </step> 103 </substeps> 104 </step> 105 106 <step> 107 <para> 108 When the token is a number or number field: 109 </para> 110 111 <substeps> 112 <step> 113 <para> 114 If there are eight or six digits, 115 and if no other date fields have been previously read, then interpret 116 as a <quote>concatenated date</quote> (e.g., 117 <literal>19990118</literal> or <literal>990118</literal>). 118 The interpretation is <literal>YYYYMMDD</literal> or <literal>YYMMDD</literal>. 119 </para> 120 </step> 121 122 <step> 123 <para> 124 If the token is three digits 125 and a year has already been read, then interpret as day of year. 126 </para> 127 </step> 128 129 <step> 130 <para> 131 If four or six digits and a year has already been read, then 132 interpret as a time (<literal>HHMM</literal> or <literal>HHMMSS</literal>). 133 </para> 134 </step> 135 136 <step> 137 <para> 138 If three or more digits and no date fields have yet been found, 139 interpret as a year (this forces yy-mm-dd ordering of the remaining 140 date fields). 141 </para> 142 </step> 143 144 <step> 145 <para> 146 Otherwise the date field ordering is assumed to follow the 147 <varname>DateStyle</varname> setting: mm-dd-yy, dd-mm-yy, or yy-mm-dd. 148 Throw an error if a month or day field is found to be out of range. 149 </para> 150 </step> 151 </substeps> 152 </step> 153 154 <step> 155 <para> 156 If BC has been specified, negate the year and add one for 157 internal storage. (There is no year zero in the Gregorian 158 calendar, so numerically 1 BC becomes year zero.) 159 </para> 160 </step> 161 162 <step> 163 <para> 164 If BC was not specified, and if the year field was two digits in length, 165 then adjust the year to four digits. If the field is less than 70, then 166 add 2000, otherwise add 1900. 167 168 <tip> 169 <para> 170 Gregorian years AD 1-99 can be entered by using 4 digits with leading 171 zeros (e.g., <literal>0099</literal> is AD 99). 172 </para> 173 </tip> 174 </para> 175 </step> 176 </procedure> 177 </sect1> 178 179 180 <sect1 id="datetime-invalid-input"> 181 <title>Handling of Invalid or Ambiguous Timestamps</title> 182 183 <para> 184 Ordinarily, if a date/time string is syntactically valid but contains 185 out-of-range field values, an error will be thrown. For example, input 186 specifying the 31st of February will be rejected. 187 </para> 188 189 <para> 190 During a daylight-savings-time transition, it is possible for a 191 seemingly valid timestamp string to represent a nonexistent or ambiguous 192 timestamp. Such cases are not rejected; the ambiguity is resolved by 193 determining which UTC offset to apply. For example, supposing that the 194 <xref linkend="guc-timezone"/> parameter is set 195 to <literal>America/New_York</literal>, consider 196<programlisting> 197=> SELECT '2018-03-11 02:30'::timestamptz; 198 timestamptz 199------------------------ 200 2018-03-11 03:30:00-04 201(1 row) 202</programlisting> 203 Because that day was a spring-forward transition date in that time zone, 204 there was no civil time instant 2:30AM; clocks jumped forward from 2AM 205 EST to 3AM EDT. <productname>PostgreSQL</productname> interprets the 206 given time as if it were standard time (UTC-5), which then renders as 207 3:30AM EDT (UTC-4). 208 </para> 209 210 <para> 211 Conversely, consider the behavior during a fall-back transition: 212<programlisting> 213=> SELECT '2018-11-04 02:30'::timestamptz; 214 timestamptz 215------------------------ 216 2018-11-04 02:30:00-05 217(1 row) 218</programlisting> 219 On that date, there were two possible interpretations of 2:30AM; there 220 was 2:30AM EDT, and then an hour later after the reversion to standard 221 time, there was 2:30AM EST. 222 Again, <productname>PostgreSQL</productname> interprets the given time 223 as if it were standard time (UTC-5). We can force the matter by 224 specifying daylight-savings time: 225<programlisting> 226=> SELECT '2018-11-04 02:30 EDT'::timestamptz; 227 timestamptz 228------------------------ 229 2018-11-04 01:30:00-05 230(1 row) 231</programlisting> 232 This timestamp could validly be rendered as either 2:30 UTC-4 or 233 1:30 UTC-5; the timestamp output code chooses the latter. 234 </para> 235 236 <para> 237 The precise rule that is applied in such cases is that an invalid 238 timestamp that appears to fall within a jump-forward daylight savings 239 transition is assigned the UTC offset that prevailed in the time zone 240 just before the transition, while an ambiguous timestamp that could fall 241 on either side of a jump-back transition is assigned the UTC offset that 242 prevailed just after the transition. In most time zones this is 243 equivalent to saying that <quote>the standard-time interpretation is 244 preferred when in doubt</quote>. 245 </para> 246 247 <para> 248 In all cases, the UTC offset associated with a timestamp can be 249 specified explicitly, using either a numeric UTC offset or a time zone 250 abbreviation that corresponds to a fixed UTC offset. The rule just 251 given applies only when it is necessary to infer a UTC offset for a time 252 zone in which the offset varies. 253 </para> 254 </sect1> 255 256 257 <sect1 id="datetime-keywords"> 258 <title>Date/Time Key Words</title> 259 260 <para> 261 <xref linkend="datetime-month-table"/> shows the tokens that are 262 recognized as names of months. 263 </para> 264 265 <table id="datetime-month-table"> 266 <title>Month Names</title> 267 <tgroup cols="2"> 268 <thead> 269 <row> 270 <entry>Month</entry> 271 <entry>Abbreviations</entry> 272 </row> 273 </thead> 274 <tbody> 275 <row> 276 <entry>January</entry> 277 <entry>Jan</entry> 278 </row> 279 <row> 280 <entry>February</entry> 281 <entry>Feb</entry> 282 </row> 283 <row> 284 <entry>March</entry> 285 <entry>Mar</entry> 286 </row> 287 <row> 288 <entry>April</entry> 289 <entry>Apr</entry> 290 </row> 291 <row> 292 <entry>May</entry> 293 <entry></entry> 294 </row> 295 <row> 296 <entry>June</entry> 297 <entry>Jun</entry> 298 </row> 299 <row> 300 <entry>July</entry> 301 <entry>Jul</entry> 302 </row> 303 <row> 304 <entry>August</entry> 305 <entry>Aug</entry> 306 </row> 307 <row> 308 <entry>September</entry> 309 <entry>Sep, Sept</entry> 310 </row> 311 <row> 312 <entry>October</entry> 313 <entry>Oct</entry> 314 </row> 315 <row> 316 <entry>November</entry> 317 <entry>Nov</entry> 318 </row> 319 <row> 320 <entry>December</entry> 321 <entry>Dec</entry> 322 </row> 323 </tbody> 324 </tgroup> 325 </table> 326 327 <para> 328 <xref linkend="datetime-dow-table"/> shows the tokens that are 329 recognized as names of days of the week. 330 </para> 331 332 <table id="datetime-dow-table"> 333 <title>Day of the Week Names</title> 334 <tgroup cols="2"> 335 <thead> 336 <row> 337 <entry>Day</entry> 338 <entry>Abbreviations</entry> 339 </row> 340 </thead> 341 <tbody> 342 <row> 343 <entry>Sunday</entry> 344 <entry>Sun</entry> 345 </row> 346 <row> 347 <entry>Monday</entry> 348 <entry>Mon</entry> 349 </row> 350 <row> 351 <entry>Tuesday</entry> 352 <entry>Tue, Tues</entry> 353 </row> 354 <row> 355 <entry>Wednesday</entry> 356 <entry>Wed, Weds</entry> 357 </row> 358 <row> 359 <entry>Thursday</entry> 360 <entry>Thu, Thur, Thurs</entry> 361 </row> 362 <row> 363 <entry>Friday</entry> 364 <entry>Fri</entry> 365 </row> 366 <row> 367 <entry>Saturday</entry> 368 <entry>Sat</entry> 369 </row> 370 </tbody> 371 </tgroup> 372 </table> 373 374 <para> 375 <xref linkend="datetime-mod-table"/> shows the tokens that serve 376 various modifier purposes. 377 </para> 378 379 <table id="datetime-mod-table"> 380 <title>Date/Time Field Modifiers</title> 381 <tgroup cols="2"> 382 <thead> 383 <row> 384 <entry>Identifier</entry> 385 <entry>Description</entry> 386 </row> 387 </thead> 388 <tbody> 389 <row> 390 <entry><literal>AM</literal></entry> 391 <entry>Time is before 12:00</entry> 392 </row> 393 <row> 394 <entry><literal>AT</literal></entry> 395 <entry>Ignored</entry> 396 </row> 397 <row> 398 <entry><literal>JULIAN</literal>, <literal>JD</literal>, <literal>J</literal></entry> 399 <entry>Next field is Julian Date</entry> 400 </row> 401 <row> 402 <entry><literal>ON</literal></entry> 403 <entry>Ignored</entry> 404 </row> 405 <row> 406 <entry><literal>PM</literal></entry> 407 <entry>Time is on or after 12:00</entry> 408 </row> 409 <row> 410 <entry><literal>T</literal></entry> 411 <entry>Next field is time</entry> 412 </row> 413 </tbody> 414 </tgroup> 415 </table> 416 </sect1> 417 418 <sect1 id="datetime-config-files"> 419 <title>Date/Time Configuration Files</title> 420 421 <indexterm> 422 <primary>time zone</primary> 423 <secondary>input abbreviations</secondary> 424 </indexterm> 425 426 <para> 427 Since timezone abbreviations are not well standardized, 428 <productname>PostgreSQL</productname> provides a means to customize 429 the set of abbreviations accepted by the server. The 430 <xref linkend="guc-timezone-abbreviations"/> run-time parameter 431 determines the active set of abbreviations. While this parameter 432 can be altered by any database user, the possible values for it 433 are under the control of the database administrator — they 434 are in fact names of configuration files stored in 435 <filename>.../share/timezonesets/</filename> of the installation directory. 436 By adding or altering files in that directory, the administrator 437 can set local policy for timezone abbreviations. 438 </para> 439 440 <para> 441 <varname>timezone_abbreviations</varname> can be set to any file name 442 found in <filename>.../share/timezonesets/</filename>, if the file's name 443 is entirely alphabetic. (The prohibition against non-alphabetic 444 characters in <varname>timezone_abbreviations</varname> prevents reading 445 files outside the intended directory, as well as reading editor 446 backup files and other extraneous files.) 447 </para> 448 449 <para> 450 A timezone abbreviation file can contain blank lines and comments 451 beginning with <literal>#</literal>. Non-comment lines must have one of 452 these formats: 453 454<synopsis> 455<replaceable>zone_abbreviation</replaceable> <replaceable>offset</replaceable> 456<replaceable>zone_abbreviation</replaceable> <replaceable>offset</replaceable> D 457<replaceable>zone_abbreviation</replaceable> <replaceable>time_zone_name</replaceable> 458@INCLUDE <replaceable>file_name</replaceable> 459@OVERRIDE 460</synopsis> 461 </para> 462 463 <para> 464 A <replaceable>zone_abbreviation</replaceable> is just the abbreviation 465 being defined. An <replaceable>offset</replaceable> is an integer giving 466 the equivalent offset in seconds from UTC, positive being east from 467 Greenwich and negative being west. For example, -18000 would be five 468 hours west of Greenwich, or North American east coast standard time. 469 <literal>D</literal> indicates that the zone name represents local 470 daylight-savings time rather than standard time. 471 </para> 472 473 <para> 474 Alternatively, a <replaceable>time_zone_name</replaceable> can be given, referencing 475 a zone name defined in the IANA timezone database. The zone's definition 476 is consulted to see whether the abbreviation is or has been in use in 477 that zone, and if so, the appropriate meaning is used — that is, 478 the meaning that was currently in use at the timestamp whose value is 479 being determined, or the meaning in use immediately before that if it 480 wasn't current at that time, or the oldest meaning if it was used only 481 after that time. This behavior is essential for dealing with 482 abbreviations whose meaning has historically varied. It is also allowed 483 to define an abbreviation in terms of a zone name in which that 484 abbreviation does not appear; then using the abbreviation is just 485 equivalent to writing out the zone name. 486 </para> 487 488 <tip> 489 <para> 490 Using a simple integer <replaceable>offset</replaceable> is preferred 491 when defining an abbreviation whose offset from UTC has never changed, 492 as such abbreviations are much cheaper to process than those that 493 require consulting a time zone definition. 494 </para> 495 </tip> 496 497 <para> 498 The <literal>@INCLUDE</literal> syntax allows inclusion of another file in the 499 <filename>.../share/timezonesets/</filename> directory. Inclusion can be nested, 500 to a limited depth. 501 </para> 502 503 <para> 504 The <literal>@OVERRIDE</literal> syntax indicates that subsequent entries in the 505 file can override previous entries (typically, entries obtained from 506 included files). Without this, conflicting definitions of the same 507 timezone abbreviation are considered an error. 508 </para> 509 510 <para> 511 In an unmodified installation, the file <filename>Default</filename> contains 512 all the non-conflicting time zone abbreviations for most of the world. 513 Additional files <filename>Australia</filename> and <filename>India</filename> are 514 provided for those regions: these files first include the 515 <literal>Default</literal> file and then add or modify abbreviations as needed. 516 </para> 517 518 <para> 519 For reference purposes, a standard installation also contains files 520 <filename>Africa.txt</filename>, <filename>America.txt</filename>, etc, containing 521 information about every time zone abbreviation known to be in use 522 according to the IANA timezone database. The zone name 523 definitions found in these files can be copied and pasted into a custom 524 configuration file as needed. Note that these files cannot be directly 525 referenced as <varname>timezone_abbreviations</varname> settings, because of 526 the dot embedded in their names. 527 </para> 528 529 <note> 530 <para> 531 If an error occurs while reading the time zone abbreviation set, no new 532 value is applied and the old set is kept. If the error occurs while 533 starting the database, startup fails. 534 </para> 535 </note> 536 537 <caution> 538 <para> 539 Time zone abbreviations defined in the configuration file override 540 non-timezone meanings built into <productname>PostgreSQL</productname>. 541 For example, the <filename>Australia</filename> configuration file defines 542 <literal>SAT</literal> (for South Australian Standard Time). When this 543 file is active, <literal>SAT</literal> will not be recognized as an abbreviation 544 for Saturday. 545 </para> 546 </caution> 547 548 <caution> 549 <para> 550 If you modify files in <filename>.../share/timezonesets/</filename>, 551 it is up to you to make backups — a normal database dump 552 will not include this directory. 553 </para> 554 </caution> 555 556 </sect1> 557 558 <sect1 id="datetime-posix-timezone-specs"> 559 <title><acronym>POSIX</acronym> Time Zone Specifications</title> 560 561 <indexterm zone="datetime-posix-timezone-specs"> 562 <primary>time zone</primary> 563 <secondary><acronym>POSIX</acronym>-style specification</secondary> 564 </indexterm> 565 566 <para> 567 <acronym>PostgreSQL</acronym> can accept time zone specifications that 568 are written according to the <acronym>POSIX</acronym> standard's rules 569 for the <varname>TZ</varname> environment 570 variable. <acronym>POSIX</acronym> time zone specifications are 571 inadequate to deal with the complexity of real-world time zone history, 572 but there are sometimes reasons to use them. 573 </para> 574 575 <para> 576 A POSIX time zone specification has the form 577<synopsis> 578<replaceable>STD</replaceable> <replaceable>offset</replaceable> <optional> <replaceable>DST</replaceable> <optional> <replaceable>dstoffset</replaceable> </optional> <optional> , <replaceable>rule</replaceable> </optional> </optional> 579</synopsis> 580 (For readability, we show spaces between the fields, but spaces should 581 not be used in practice.) The fields are: 582 <itemizedlist> 583 <listitem> 584 <para> 585 <replaceable>STD</replaceable> is the zone abbreviation to be used 586 for standard time. 587 </para> 588 </listitem> 589 <listitem> 590 <para> 591 <replaceable>offset</replaceable> is the zone's standard-time offset 592 from UTC. 593 </para> 594 </listitem> 595 <listitem> 596 <para> 597 <replaceable>DST</replaceable> is the zone abbreviation to be used 598 for daylight-savings time. If this field and the following ones are 599 omitted, the zone uses a fixed UTC offset with no daylight-savings 600 rule. 601 </para> 602 </listitem> 603 <listitem> 604 <para> 605 <replaceable>dstoffset</replaceable> is the daylight-savings offset 606 from UTC. This field is typically omitted, since it defaults to one 607 hour less than the standard-time <replaceable>offset</replaceable>, 608 which is usually the right thing. 609 </para> 610 </listitem> 611 <listitem> 612 <para> 613 <replaceable>rule</replaceable> defines the rule for when daylight 614 savings is in effect, as described below. 615 </para> 616 </listitem> 617 </itemizedlist> 618 </para> 619 620 <para> 621 In this syntax, a zone abbreviation can be a string of letters, such 622 as <literal>EST</literal>, or an arbitrary string surrounded by angle 623 brackets, such as <literal><UTC-05></literal>. 624 Note that the zone abbreviations given here are only used for output, 625 and even then only in some timestamp output formats. The zone 626 abbreviations recognized in timestamp input are determined as explained 627 in <xref linkend="datetime-config-files"/>. 628 </para> 629 630 <para> 631 The offset fields specify the hours, and optionally minutes and seconds, 632 difference from UTC. They have the format 633 <replaceable>hh</replaceable><optional><literal>:</literal><replaceable>mm</replaceable><optional><literal>:</literal><replaceable>ss</replaceable></optional></optional> 634 optionally with a leading sign (<literal>+</literal> 635 or <literal>-</literal>). The positive sign is used for 636 zones <emphasis>west</emphasis> of Greenwich. (Note that this is the 637 opposite of the ISO-8601 sign convention used elsewhere in 638 <acronym>PostgreSQL</acronym>.) <replaceable>hh</replaceable> can have 639 one or two digits; <replaceable>mm</replaceable> 640 and <replaceable>ss</replaceable> (if used) must have two. 641 </para> 642 643 <para> 644 The daylight-savings transition <replaceable>rule</replaceable> has the 645 format 646<synopsis> 647<replaceable>dstdate</replaceable> <optional> <literal>/</literal> <replaceable>dsttime</replaceable> </optional> <literal>,</literal> <replaceable>stddate</replaceable> <optional> <literal>/</literal> <replaceable>stdtime</replaceable> </optional> 648</synopsis> 649 (As before, spaces should not be included in practice.) 650 The <replaceable>dstdate</replaceable> 651 and <replaceable>dsttime</replaceable> fields define when daylight-savings 652 time starts, while <replaceable>stddate</replaceable> 653 and <replaceable>stdtime</replaceable> define when standard time 654 starts. (In some cases, notably in zones south of the equator, the 655 former might be later in the year than the latter.) The date fields 656 have one of these formats: 657 <variablelist> 658 <varlistentry> 659 <term><replaceable>n</replaceable></term> 660 <listitem> 661 <para> 662 A plain integer denotes a day of the year, counting from zero to 663 364, or to 365 in leap years. 664 </para> 665 </listitem> 666 </varlistentry> 667 <varlistentry> 668 <term><literal>J</literal><replaceable>n</replaceable></term> 669 <listitem> 670 <para> 671 In this form, <replaceable>n</replaceable> counts from 1 to 365, 672 and February 29 is not counted even if it is present. (Thus, a 673 transition occurring on February 29 could not be specified this 674 way. However, days after February have the same numbers whether 675 it's a leap year or not, so that this form is usually more useful 676 than the plain-integer form for transitions on fixed dates.) 677 </para> 678 </listitem> 679 </varlistentry> 680 <varlistentry> 681 <term><literal>M</literal><replaceable>m</replaceable><literal>.</literal><replaceable>n</replaceable><literal>.</literal><replaceable>d</replaceable></term> 682 <listitem> 683 <para> 684 This form specifies a transition that always happens during the same 685 month and on the same day of the week. <replaceable>m</replaceable> 686 identifies the month, from 1 to 12. <replaceable>n</replaceable> 687 specifies the <replaceable>n</replaceable>'th occurrence of the 688 weekday identified by <replaceable>d</replaceable>. 689 <replaceable>n</replaceable> is a number between 1 and 4, or 5 690 meaning the last occurrence of that weekday in the month (which 691 could be the fourth or the fifth). <replaceable>d</replaceable> is 692 a number between 0 and 6, with 0 indicating Sunday. 693 For example, <literal>M3.2.0</literal> means <quote>the second 694 Sunday in March</quote>. 695 </para> 696 </listitem> 697 </varlistentry> 698 </variablelist> 699 </para> 700 701 <note> 702 <para> 703 The <literal>M</literal> format is sufficient to describe many common 704 daylight-savings transition laws. But note that none of these variants 705 can deal with daylight-savings law changes, so in practice the 706 historical data stored for named time zones (in the IANA time zone 707 database) is necessary to interpret past time stamps correctly. 708 </para> 709 </note> 710 711 <para> 712 The time fields in a transition rule have the same format as the offset 713 fields described previously, except that they cannot contain signs. 714 They define the current local time at which the change to the other 715 time occurs. If omitted, they default to <literal>02:00:00</literal>. 716 </para> 717 718 <para> 719 If a daylight-savings abbreviation is given but the 720 transition <replaceable>rule</replaceable> field is omitted, 721 <productname>PostgreSQL</productname> attempts to determine the 722 transition times by consulting the <filename>posixrules</filename> file 723 in the IANA time zone database. This file has the same format as a 724 full time zone entry, but only its transition timing rules are used, 725 not its UTC offsets. Typically, this file has the same contents as the 726 <literal>US/Eastern</literal> file, so that POSIX-style time zone 727 specifications follow USA daylight-savings rules. If needed, you can 728 adjust this behavior by replacing the <filename>posixrules</filename> 729 file. 730 </para> 731 732 <note> 733 <para> 734 The facility to consult a <filename>posixrules</filename> file has 735 been deprecated by IANA, and it is likely to go away in the future. 736 One bug in this feature, which is unlikely to be fixed before it 737 disappears, is that it fails to apply DST rules to dates after 2038. 738 </para> 739 </note> 740 741 <para> 742 If the <filename>posixrules</filename> file is not present, 743 the fallback behavior is to use the 744 rule <literal>M3.2.0,M11.1.0</literal>, which corresponds to USA 745 practice as of 2020 (that is, spring forward on the second Sunday of 746 March, fall back on the first Sunday of November, both transitions 747 occurring at 2AM prevailing time). 748 </para> 749 750 <para> 751 As an example, <literal>CET-1CEST,M3.5.0,M10.5.0/3</literal> describes 752 current (as of 2020) timekeeping practice in Paris. This specification 753 says that standard time has the abbreviation <literal>CET</literal> and 754 is one hour ahead (east) of UTC; daylight savings time has the 755 abbreviation <literal>CEST</literal> and is implicitly two hours ahead 756 of UTC; daylight savings time begins on the last Sunday in March at 2AM 757 CET and ends on the last Sunday in October at 3AM CEST. 758 </para> 759 760 <para> 761 The four timezone names <literal>EST5EDT</literal>, 762 <literal>CST6CDT</literal>, <literal>MST7MDT</literal>, 763 and <literal>PST8PDT</literal> look like they are POSIX zone 764 specifications. However, they actually are treated as named time zones 765 because (for historical reasons) there are files by those names in the 766 IANA time zone database. The practical implication of this is that 767 these zone names will produce valid historical USA daylight-savings 768 transitions, even when a plain POSIX specification would not due to 769 lack of a suitable <filename>posixrules</filename> file. 770 </para> 771 772 <para> 773 One should be wary that it is easy to misspell a POSIX-style time zone 774 specification, since there is no check on the reasonableness of the 775 zone abbreviation(s). For example, <literal>SET TIMEZONE TO 776 FOOBAR0</literal> will work, leaving the system effectively using a 777 rather peculiar abbreviation for UTC. 778 </para> 779 780 </sect1> 781 782 <sect1 id="datetime-units-history"> 783 <title>History of Units</title> 784 785 <indexterm zone="datetime-units-history"> 786 <primary>Gregorian calendar</primary> 787 </indexterm> 788 789 <para> 790 The SQL standard states that <quote>Within the definition of a 791 <quote>datetime literal</quote>, the <quote>datetime 792 values</quote> are constrained by the natural rules for dates and 793 times according to the Gregorian calendar</quote>. 794 <productname>PostgreSQL</productname> follows the SQL 795 standard's lead by counting dates exclusively in the Gregorian 796 calendar, even for years before that calendar was in use. 797 This rule is known as the <firstterm>proleptic Gregorian calendar</firstterm>. 798 </para> 799 800 <para> 801 The Julian calendar was introduced by Julius Caesar in 45 BC. 802 It was in common use in the Western world 803 until the year 1582, when countries started changing to the Gregorian 804 calendar. In the Julian calendar, the tropical year is 805 approximated as 365 1/4 days = 365.25 days. This gives an error of 806 about 1 day in 128 years. 807 </para> 808 809 <para> 810 The accumulating calendar error prompted 811 Pope Gregory XIII to reform the calendar in accordance with 812 instructions from the Council of Trent. 813 In the Gregorian calendar, the tropical year is approximated as 814 365 + 97 / 400 days = 365.2425 days. Thus it takes approximately 3300 815 years for the tropical year to shift one day with respect to the 816 Gregorian calendar. 817 </para> 818 819 <para> 820 The approximation 365+97/400 is achieved by having 97 leap years 821 every 400 years, using the following rules: 822 823 <simplelist> 824 <member> 825 Every year divisible by 4 is a leap year. 826 </member> 827 <member> 828 However, every year divisible by 100 is not a leap year. 829 </member> 830 <member> 831 However, every year divisible by 400 is a leap year after all. 832 </member> 833 </simplelist> 834 835 So, 1700, 1800, 1900, 2100, and 2200 are not leap years. But 1600, 836 2000, and 2400 are leap years. 837 838 By contrast, in the older Julian calendar all years divisible by 4 are leap 839 years. 840 </para> 841 842 <para> 843 The papal bull of February 1582 decreed that 10 days should be dropped 844 from October 1582 so that 15 October should follow immediately after 845 4 October. 846 This was observed in Italy, Poland, Portugal, and Spain. Other Catholic 847 countries followed shortly after, but Protestant countries were 848 reluctant to change, and the Greek Orthodox countries didn't change 849 until the start of the 20th century. 850 851 The reform was observed by Great Britain and its dominions (including what 852 is now the USA) in 1752. 853 Thus 2 September 1752 was followed by 14 September 1752. 854 855 This is why Unix systems that have the <command>cal</command> program 856 produce the following: 857 858<screen> 859$ <userinput>cal 9 1752</userinput> 860 September 1752 861 S M Tu W Th F S 862 1 2 14 15 16 86317 18 19 20 21 22 23 86424 25 26 27 28 29 30 865</screen> 866 867 But, of course, this calendar is only valid for Great Britain and 868 dominions, not other places. 869 Since it would be difficult and confusing to try to track the actual 870 calendars that were in use in various places at various times, 871 <productname>PostgreSQL</productname> does not try, but rather follows the Gregorian 872 calendar rules for all dates, even though this method is not historically 873 accurate. 874 </para> 875 876 <para> 877 Different calendars have been developed in various parts of the 878 world, many predating the Gregorian system. 879 880 For example, 881 the beginnings of the Chinese calendar can be traced back to the 14th 882 century BC. Legend has it that the Emperor Huangdi invented that 883 calendar in 2637 BC. 884 885 The People's Republic of China uses the Gregorian calendar 886 for civil purposes. The Chinese calendar is used for determining 887 festivals. 888 </para> 889 890 </sect1> 891 892 <sect1 id="datetime-julian-dates"> 893 <title>Julian Dates</title> 894 895 <indexterm zone="datetime-julian-dates"> 896 <primary>Julian date</primary> 897 </indexterm> 898 899 <para> 900 The <firstterm>Julian Date</firstterm> system is a method for 901 numbering days. It is 902 unrelated to the Julian calendar, though it is confusingly 903 named similarly to that calendar. 904 The Julian Date system was invented by the French scholar 905 Joseph Justus Scaliger (1540-1609) 906 and probably takes its name from Scaliger's father, 907 the Italian scholar Julius Caesar Scaliger (1484-1558). 908 </para> 909 910 <para> 911 In the Julian Date system, each day has a sequential number, starting 912 from JD 0 (which is sometimes called <emphasis>the</emphasis> Julian Date). 913 JD 0 corresponds to 1 January 4713 BC in the Julian calendar, or 914 24 November 4714 BC in the Gregorian calendar. Julian Date counting 915 is most often used by astronomers for labeling their nightly observations, 916 and therefore a date runs from noon UTC to the next noon UTC, rather than 917 from midnight to midnight: JD 0 designates the 24 hours from noon UTC on 918 24 November 4714 BC to noon UTC on 25 November 4714 BC. 919 </para> 920 921 <para> 922 Although <productname>PostgreSQL</productname> supports Julian Date notation for 923 input and output of dates (and also uses Julian dates for some internal 924 datetime calculations), it does not observe the nicety of having dates 925 run from noon to noon. <productname>PostgreSQL</productname> treats a Julian Date 926 as running from local midnight to local midnight, the same as a normal 927 date. 928 </para> 929 930 <para> 931 This definition does, however, provide a way to obtain the astronomical 932 definition when you need it: do the arithmetic in time 933 zone <literal>UTC+12</literal>. For example, 934<programlisting> 935=> SELECT extract(julian from '2021-06-23 7:00:00-04'::timestamptz at time zone 'UTC+12'); 936 date_part 937-------------------- 938 2459388.9583333335 939(1 row) 940=> SELECT extract(julian from '2021-06-23 8:00:00-04'::timestamptz at time zone 'UTC+12'); 941 date_part 942----------- 943 2459389 944(1 row) 945=> SELECT extract(julian from date '2021-06-23'); 946 date_part 947----------- 948 2459389 949(1 row) 950</programlisting> 951 </para> 952 953 </sect1> 954</appendix> 955