Skip to content
/ server Public

Commit 84dd75e

Browse files
committed
MDEV-19683 Add support for Oracle TO_DATE()
Syntax: TO_DATE(string_expression [DEFAULT string_expression ON CONVERSION ERROR], format_string [,NLS_FORMAT_STRING]) The format_string has the same format elements as TO_CHAR(), except a few elements that are not supported/usable for TO_DATE(). TO_DATE() returns a datetime or date value, depending on if the format element FF is used. Allowed separators, same as TO_CHAR(): space, tab and any of !#%'()*+,-./:;<=> '&' can also be used if next character is not a character a-z or A-Z "text' indicates a text string that is verbatim in the format. One cannot use " as a separator. Format elements supported by TO_DATE(): AD Anno Domini ("in the year of the Lord") AD_DOT Anno Domini ("in the year of the Lord") AM Meridian indicator (Before midday) AM_DOT Meridian indicator (Before midday) DAY Name of day DD Day (1-31) DDD Day of year (1-336) DY Abbreviated name of day FF[1-6] Fractional seconds HH Hour (1-12) HH12 Hour (1-12) HH24 Hour (0-23) MI Minutes (0-59) MM Month (1-12) MON Abbreviated name of month MONTH Name of Month PM Meridian indicator (After midday) PM_DOT Meridian indicator (After midday) RR 20th century dates in the 21st century. 2 digits 50-99 is assumed from 2000, 0-49 is assumed from 1900. RRRR 20th century dates in the 21st century. 4 digits SS Seconds SYYYY Signed 4 digit year; MariaDB only supports positive years Y 1 digit year YY 2 digits year YYY 3 digits year YYYY 4 digits year Note that if there is a missing part of the date, the current date is used! For example if 'MM-DD HH-MM-SS' then the current year will be used. (Oracle behaviour) Not supported options: - BC, D, DL, DS, E, EE, FM, FX, RM, SSSSS, TS, TZD, TZH, TZR, X,SY BC is not supported by MariaDB datetime. - Most of the other are exotic formats does not make sence in MariaDB as we return datetime or datetime with fractions, not string. - D (day-of-week) is not supported as it is not clear exactly how it would map to MariaDB. This element depends on the NLS territory of the session. - RR only works with 2 digit years (In Oracle RR can also work with 4 digit years in some context but the rules are not clear). Extensions / differences compared to Oracle; - MariaDB supports FF (fractional seconds). If FF[#] is used, then TO_DATE will return a datetime with # of subseconds. If FF is not used a datetime will be returned. There is warning (no error) if string contains more digts than what is specified with F(#] - Names can be shortened to it's unique prefix. For example January and Ja works fine. - No error if the date string is shorter format_string and the next not used character is not a number.. This is useful to get a date from a mixed set of strings in date or datetime format. Oracle gives an error if date string is too short. - MariaDB supports short locales as language names - NLS_DATE_FORMAT can use both " and ' for quoting. - NLS_DATE_FORMAT must be a constant string. - This is to ensure that the server knows which locale to use when executing the function. New formats handled by TO_CHAR(): FF[1-6] Fractional seconds DDD Daynumber 1-366 IW Week 1-53 according to ISO 8601 I 1 digit year according to ISO 8601 IY 2 digit year according to ISO 8601 IYY 3 digit year according to ISO 8601 IYYY 4 digit year according to ISO 8601 SYYY 4 digit year according to ISO 8601 (Oracle can do signed) Supported NLS_FORMAT_STRING options are: NLS_CALENDAR=GREGORIAN NLS_DATE_LANGUAGE=language Support languages are: - All MariaDB short locales, like en_AU. - The following Oracle language names: ALBANIAN, AMERICAN, ARABIC, BASQUE, BELARUSIAN, BRAZILIAN PORTUGUESE BULGARIAN, CANADIAN FRENCH, CATALAN, CROATIAN, CYRILLIC SERBIAN CZECH, DANISH, DUTCH, ENGLISH, ESTONIAN, FINNISH, FRENCH, GERMAN, GREEK, HEBREW, HINDI, HUNGARIAN, ICELANDIC, INDONESIAN ITALIAN, JAPANESE, KANNADA, KOREAN, LATIN AMERICAN SPANISH, LATVIAN, LITHUANIAN, MACEDONIAN, MALAY, MEXICAN SPANISH, NORWEGIAN, POLISH, PORTUGUESE, ROMANIAN, RUSSIAN, SIMPLIFIED CHINESE, SLOVAK, SLOVENIAN, SPANISH, SWAHILI, SWEDISH, TAMIL, THAI, TRADITIONAL CHINESE, TURKISH, UKRAINIAN, VIETNAMESE Development bugs fixed: MDEV-38403 Server crashes in Item_func_to_date::fix_length_and_dec upon using an invalid argument MDEV-38400 compat/oracle.func_to_date fails with PS protocol and cursor protocol (Fixed by Serg) MDEV-38404 TO_DATE: MTR coverage omissions, round 1 MDEV-38509 TO_DATE: AD_DOT does not appear to be supported MDEV-38513 TO_DATE: NULL value for format string causes assertion failure MDEV-38521 TO_DATE: Date strings with non-ASCII symbols cause warnings and wrong results MDEV-38578 TO_DATE: Possibly unexpected results upon wrong input MDEV-38582 TO_DATE: NLS_DATE_LANGUAGE=JAPANESE does not parse values which work in Oracle MDEV-38584 TO_DATE: NLS_DATE_LANGUAGE=VIETNAMESE does not parse values which work in Oracle MDEV-38703 TO_DATE: Quotation for multi-word NLS_DATE_LANGUAGE leads to syntax error in view definition MDEV-38675 TO_DATE: MSAN/Valgrind/UBSAN errors in extract_oracle_date_time MDEV-38635 TO_DATE: UBSAN errors in item_timefunc.h upon comparison with a view column MDEV-38719 TO_DATE: Assertion `&my_charset_bin != charset()' failed in String::append_for_single_quote_using_mb_wc Known issues: - Format string character matches inside quotes are done one-letter-to-one-letter, like in LIKE predicate. That means things like expansions and contractions do not work. For example 'ss' does not match 'ß' in collations which treat them as equal for the comparison operator. Match is done taking into account case and accent sensitivity of the subject argument collation, so for example this now works: MariaDB [test]> SELECT TO_DATE('1920á12','YYYY"a"MM') AS c; +---------------------+ | c | +---------------------+ | 1920-12-17 00:00:00 | +---------------------+ Co-author and reviewer: Alexander Barkov <[email protected]>
1 parent 0187841 commit 84dd75e

19 files changed

+2715
-200
lines changed

include/typelib.h

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -34,7 +34,7 @@ typedef struct st_typelib { /* Different types saved here */
3434
const int *hidden_values;
3535
} TYPELIB;
3636

37-
#define CREATE_TYPELIB_FOR(X) { (unsigned int)(sizeof(X)/sizeof(X[0])) - 1, "", X, NULL, NULL }
37+
#define CREATE_TYPELIB_FOR(X) { (unsigned int)(sizeof(X)/sizeof(X[0])) - 1, "", X, (uint[(sizeof(X)/sizeof(X[0]))-1]){0}, NULL }
3838

3939
extern my_ulonglong find_typeset(const char *x, TYPELIB *typelib,
4040
int *error_position);

mysql-test/suite/compat/oracle/r/func_to_char.result

Lines changed: 46 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -154,6 +154,43 @@ A.D.9999-12-31 PM11:59:59 A.D..9999-12-31 P.M.23:59:59
154154
A.D.2021-01-03 AM08:30:00 A.D..2021-01-03 A.M.08:30:00
155155
A.D.2021-07-03 PM06:30:00 A.D..2021-07-03 P.M.18:30:00
156156
#
157+
# Test FF
158+
#
159+
SELECT TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF');
160+
TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF')
161+
2025-10-11 12:10:14.123456
162+
SELECT TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF6');
163+
TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF6')
164+
2025-10-11 12:10:14.123456
165+
SELECT TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF5');
166+
TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF5')
167+
2025-10-11 12:10:14.12345
168+
#
169+
# Test DDD, I*
170+
#
171+
select c3,to_char(c3, 'DDD') from t_to_char1 where c0 = 3;
172+
c3 to_char(c3, 'DDD')
173+
2021-01-03 08:30:00 003
174+
select c3,to_char(c3, 'I') from t_to_char1 where c0 = 3;
175+
c3 to_char(c3, 'I')
176+
2021-01-03 08:30:00 0
177+
select c3,to_char(c3, 'I-MM') from t_to_char1 where c0 = 3;
178+
c3 to_char(c3, 'I-MM')
179+
2021-01-03 08:30:00 0-01
180+
select c3,to_char(c3, 'IY') from t_to_char1 where c0 = 3;
181+
c3 to_char(c3, 'IY')
182+
2021-01-03 08:30:00 20
183+
select c3,to_char(c3, 'IYY-MM') from t_to_char1 where c0 = 3;
184+
c3 to_char(c3, 'IYY-MM')
185+
2021-01-03 08:30:00 020-01
186+
select c3, to_char(c3, 'IYYY-IW') from t_to_char1 where c0 between 3 and 4;
187+
c3 to_char(c3, 'IYYY-IW')
188+
2021-01-03 08:30:00 2020-53
189+
2021-07-03 18:30:00 2021-26
190+
select to_char("2001-01-01", "IYYY-IW");
191+
to_char("2001-01-01", "IYYY-IW")
192+
2001-1
193+
#
157194
# test format without order
158195
#
159196
SELECT TO_CHAR(c1, 'MM-YYYY-DD') AS C1, TO_CHAR(c2, 'HH:SS:MI') AS C2, TO_CHAR(c3, 'DD-YY-MM MI:SS:HH24') AS C3 FROM t_to_char1;
@@ -275,6 +312,10 @@ select to_char(c3, 'YYYY&DDD') from t_to_char1 where c0 = 1;
275312
ERROR HY000: Invalid argument error: date format not recognized at &DDD in function to_char.
276313
select to_char(c3, 'xxYYYY-DD') from t_to_char1 where c0 = 1;
277314
ERROR HY000: Invalid argument error: date format not recognized at xxYYYY-D in function to_char.
315+
SELECT TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF7');
316+
ERROR HY000: Invalid argument error: date format not recognized at 7 in function to_char.
317+
SELECT TO_CHAR('2025-10-11 12:13:14.123456', 'YYYY-MM-DD HH:MM:SS.FF0');
318+
ERROR HY000: Invalid argument error: date format not recognized at 0 in function to_char.
278319
SET character_set_client='latin1';
279320
SET character_set_connection='latin1';
280321
SET character_set_results='latin1';
@@ -289,10 +330,10 @@ to_char(c3, 'YYYYYYYYYYYYYYY')
289330
202120212021021
290331
select to_char(c3, 'YYYYYYYYYYYYYYYDDDDDD') from t_to_char1;
291332
to_char(c3, 'YYYYYYYYYYYYYYYDDDDDD')
292-
100010001000000010101
293-
999999999999999313131
294-
202120212021021030303
295-
202120212021021030303
333+
100010001000000001001
334+
999999999999999365365
335+
202120212021021003003
336+
202120212021021184184
296337
#
297338
# oracle max length is 144
298339
#
@@ -325,19 +366,13 @@ ERROR 42000: Incorrect parameter count in the call to native function 'to_char'
325366
#
326367
# oracle support format but mariadb does not support
327368
#
328-
select to_char(c3, 'DDD') from t_to_char1 where c0 = 1;
329-
ERROR HY000: Invalid argument error: date format not recognized at D in function to_char.
330369
select to_char(c3, 'D') from t_to_char1 where c0 = 1;
331370
ERROR HY000: Invalid argument error: date format not recognized at D in function to_char.
332371
select to_char(c3, 'DS') from t_to_char1 where c0 = 1;
333372
ERROR HY000: Invalid argument error: date format not recognized at DS in function to_char.
334-
select to_char(c3, 'IY') from t_to_char1 where c0 = 1;
335-
ERROR HY000: Invalid argument error: date format not recognized at IY in function to_char.
336-
select to_char(c3, 'IYYY') from t_to_char1 where c0 = 1;
337-
ERROR HY000: Invalid argument error: date format not recognized at IYYY in function to_char.
338373
#
339374
# test for first argument data type
340-
#
375+
#
341376
select to_char(1, 'yyyy');
342377
ERROR HY000: Invalid argument error: data type of first argument must be type date/datetime/time or string in function to_char.
343378
select to_char(1.1, 'yyyy');
Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,15 @@
1+
#
2+
# MDEV-19683 Add support for Oracle TO_DATE()
3+
#
4+
SET NAMES utf8mb3;
5+
SET time_zone=_latin1'+03:00';
6+
SET timestamp=1100000000;
7+
SELECT TO_DATE('1920я12',convert('YYYY"я"MM' using ucs2)) AS c;
8+
c
9+
1920-12-09 00:00:00
10+
SELECT TO_DATE(convert('1920я12' using ucs2),'YYYY"я"MM') AS c;
11+
c
12+
1920-12-09 00:00:00
13+
SELECT TO_DATE(convert('1920я12' using ucs2),convert('YYYY"я"MM' using ucs2)) AS c;
14+
c
15+
1920-12-09 00:00:00

0 commit comments

Comments
 (0)