From 19e7982681df74e20aa062d5605cb0f7e04c5d51 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Wed, 30 Sep 2020 15:40:23 -0400 Subject: [PATCH] Fix handling of BC years in to_date/to_timestamp. Previously, a conversion such as to_date('-44-02-01','YYYY-MM-DD') would result in '0045-02-01 BC', as the code attempted to interpret the negative year as BC, but failed to apply the correction needed for our internal handling of BC years. Fix the off-by-one problem. Also, arrange for the combination of a negative year and an explicit "BC" marker to cancel out and produce AD. This is how the negative-century case works, so it seems sane to do likewise. Continue to read "year 0000" as 1 BC. Oracle would throw an error, but we've accepted that case for a long time so I'm hesitant to change it in a back-patch. Per bug #16419 from Saeed Hubaishan. Back-patch to all supported branches. Dar Alathar-Yemen and Tom Lane Discussion: https://postgr.es/m/16419-d8d9db0a7553f01b@postgresql.org --- doc/src/sgml/func.sgml | 14 +++++++-- src/backend/utils/adt/formatting.c | 7 +++-- src/test/regress/expected/horology.out | 39 ++++++++++++++++++++++++++ src/test/regress/sql/horology.sql | 11 ++++++++ 4 files changed, 67 insertions(+), 4 deletions(-) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 521fa9e0cbe..96edf78983a 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -6175,8 +6175,18 @@ SELECT regexp_matches('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}'); - The YYYY conversion from string to timestamp or - date has a restriction when processing years with more than 4 digits. You must + In to_timestamp and to_date, + negative years are treated as signifying BC. If you write both a + negative year and an explicit BC field, you get AD + again. An input of year zero is treated as 1 BC. + + + + + + In to_timestamp and to_date, + the YYYY conversion has a restriction when + processing years with more than 4 digits. You must use some non-digit character or template after YYYY, otherwise the year is always interpreted as 4 digits. For example (with the year 20000): diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c index 24484b4c57f..d4c773e422f 100644 --- a/src/backend/utils/adt/formatting.c +++ b/src/backend/utils/adt/formatting.c @@ -3693,8 +3693,11 @@ do_to_timestamp(text *date_txt, text *fmt, /* If a 4-digit year is provided, we use that and ignore CC. */ { tm->tm_year = tmfc.year; - if (tmfc.bc && tm->tm_year > 0) - tm->tm_year = -(tm->tm_year - 1); + if (tmfc.bc) + tm->tm_year = -tm->tm_year; + /* correct for our representation of BC years */ + if (tm->tm_year < 0) + tm->tm_year++; } } else if (tmfc.cc) /* use first year of century */ diff --git a/src/test/regress/expected/horology.out b/src/test/regress/expected/horology.out index 28ef3d2f405..699e254a21d 100644 --- a/src/test/regress/expected/horology.out +++ b/src/test/regress/expected/horology.out @@ -2957,6 +2957,45 @@ SELECT to_date('2458872', 'J'); 01-23-2020 (1 row) +-- +-- Check handling of BC dates +-- +SELECT to_date('44-02-01 BC','YYYY-MM-DD BC'); + to_date +--------------- + 02-01-0044 BC +(1 row) + +SELECT to_date('-44-02-01','YYYY-MM-DD'); + to_date +--------------- + 02-01-0044 BC +(1 row) + +SELECT to_date('-44-02-01 BC','YYYY-MM-DD BC'); + to_date +------------ + 02-01-0044 +(1 row) + +SELECT to_timestamp('44-02-01 11:12:13 BC','YYYY-MM-DD HH24:MI:SS BC'); + to_timestamp +--------------------------------- + Fri Feb 01 11:12:13 0044 PST BC +(1 row) + +SELECT to_timestamp('-44-02-01 11:12:13','YYYY-MM-DD HH24:MI:SS'); + to_timestamp +--------------------------------- + Fri Feb 01 11:12:13 0044 PST BC +(1 row) + +SELECT to_timestamp('-44-02-01 11:12:13 BC','YYYY-MM-DD HH24:MI:SS BC'); + to_timestamp +------------------------------ + Mon Feb 01 11:12:13 0044 PST +(1 row) + -- -- Check handling of multiple spaces in format and/or input -- diff --git a/src/test/regress/sql/horology.sql b/src/test/regress/sql/horology.sql index a1cd2eea174..b0402ae4fe2 100644 --- a/src/test/regress/sql/horology.sql +++ b/src/test/regress/sql/horology.sql @@ -455,6 +455,17 @@ SELECT to_date('1 4 1902', 'Q MM YYYY'); -- Q is ignored SELECT to_date('3 4 21 01', 'W MM CC YY'); SELECT to_date('2458872', 'J'); +-- +-- Check handling of BC dates +-- + +SELECT to_date('44-02-01 BC','YYYY-MM-DD BC'); +SELECT to_date('-44-02-01','YYYY-MM-DD'); +SELECT to_date('-44-02-01 BC','YYYY-MM-DD BC'); +SELECT to_timestamp('44-02-01 11:12:13 BC','YYYY-MM-DD HH24:MI:SS BC'); +SELECT to_timestamp('-44-02-01 11:12:13','YYYY-MM-DD HH24:MI:SS'); +SELECT to_timestamp('-44-02-01 11:12:13 BC','YYYY-MM-DD HH24:MI:SS BC'); + -- -- Check handling of multiple spaces in format and/or input --