mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-27 10:02:01 +00:00
MySQL compat: Align behavior of %f in formatDateTime() with parseDateTime()
This commit is contained in:
parent
ce2692ba79
commit
5eb31bba87
@ -1264,7 +1264,7 @@ Using replacement fields, you can define a pattern for the resulting string. “
|
|||||||
| %d | day of the month, zero-padded (01-31) | 02 |
|
| %d | day of the month, zero-padded (01-31) | 02 |
|
||||||
| %D | Short MM/DD/YY date, equivalent to %m/%d/%y | 01/02/18 |
|
| %D | Short MM/DD/YY date, equivalent to %m/%d/%y | 01/02/18 |
|
||||||
| %e | day of the month, space-padded (1-31) | 2 |
|
| %e | day of the month, space-padded (1-31) | 2 |
|
||||||
| %f | fractional second from the fractional part of DateTime64 | 1234560 |
|
| %f | fractional second, see below (*) | 1234560 |
|
||||||
| %F | short YYYY-MM-DD date, equivalent to %Y-%m-%d | 2018-01-02 |
|
| %F | short YYYY-MM-DD date, equivalent to %Y-%m-%d | 2018-01-02 |
|
||||||
| %g | two-digit year format, aligned to ISO 8601, abbreviated from four-digit notation | 18 |
|
| %g | two-digit year format, aligned to ISO 8601, abbreviated from four-digit notation | 18 |
|
||||||
| %G | four-digit year format for ISO week number, calculated from the week-based year [defined by the ISO 8601](https://en.wikipedia.org/wiki/ISO_8601#Week_dates) standard, normally useful only with %V | 2018 |
|
| %G | four-digit year format for ISO week number, calculated from the week-based year [defined by the ISO 8601](https://en.wikipedia.org/wiki/ISO_8601#Week_dates) standard, normally useful only with %V | 2018 |
|
||||||
@ -1295,6 +1295,8 @@ Using replacement fields, you can define a pattern for the resulting string. “
|
|||||||
| %z | Time offset from UTC as +HHMM or -HHMM | -0500 |
|
| %z | Time offset from UTC as +HHMM or -HHMM | -0500 |
|
||||||
| %% | a % sign | % |
|
| %% | a % sign | % |
|
||||||
|
|
||||||
|
(*) The behavior of `%f` is to print `000000` (six zeros) if the formatted value is a Date, Date32 or DateTime (which have no fractional seconds) or a DateTime64 with a precision of 0. Earlier versions of ClickHouse printed `0` in this case. The previous behavior can be restored using setting `formatdatetime_f_prints_single_zero = 1`.
|
||||||
|
|
||||||
**Example**
|
**Example**
|
||||||
|
|
||||||
Query:
|
Query:
|
||||||
|
@ -467,7 +467,8 @@ class IColumn;
|
|||||||
M(Bool, allow_introspection_functions, false, "Allow functions for introspection of ELF and DWARF for query profiling. These functions are slow and may impose security considerations.", 0) \
|
M(Bool, allow_introspection_functions, false, "Allow functions for introspection of ELF and DWARF for query profiling. These functions are slow and may impose security considerations.", 0) \
|
||||||
\
|
\
|
||||||
M(Bool, allow_execute_multiif_columnar, true, "Allow execute multiIf function columnar", 0) \
|
M(Bool, allow_execute_multiif_columnar, true, "Allow execute multiIf function columnar", 0) \
|
||||||
M(Bool, formatdatetime_parsedatetime_m_is_month_name, true, "Formatter '%M' in function 'formatDateTime' produces the month name instead of minutes.", 0) \
|
M(Bool, formatdatetime_f_prints_single_zero, false, "Formatter '%f' in function 'formatDateTime()' produces a single zero instead of six zeros if the formatted value has no fractional seconds.", 0) \
|
||||||
|
M(Bool, formatdatetime_parsedatetime_m_is_month_name, true, "Formatter '%M' in functions 'formatDateTime()' and 'parseDateTime()' produces the month name instead of minutes.", 0) \
|
||||||
\
|
\
|
||||||
M(UInt64, max_partitions_per_insert_block, 100, "Limit maximum number of partitions in single INSERTed block. Zero means unlimited. Throw exception if the block contains too many partitions. This setting is a safety threshold, because using large number of partitions is a common misconception.", 0) \
|
M(UInt64, max_partitions_per_insert_block, 100, "Limit maximum number of partitions in single INSERTed block. Zero means unlimited. Throw exception if the block contains too many partitions. This setting is a safety threshold, because using large number of partitions is a common misconception.", 0) \
|
||||||
M(Int64, max_partitions_to_read, -1, "Limit the max number of partitions that can be accessed in one query. <= 0 means unlimited.", 0) \
|
M(Int64, max_partitions_to_read, -1, "Limit the max number of partitions that can be accessed in one query. <= 0 means unlimited.", 0) \
|
||||||
|
@ -101,6 +101,7 @@ static std::map<ClickHouseVersion, SettingsChangesHistory::SettingsChanges> sett
|
|||||||
{"query_plan_aggregation_in_order", 0, 1, "Enable some refactoring around query plan"},
|
{"query_plan_aggregation_in_order", 0, 1, "Enable some refactoring around query plan"},
|
||||||
{"format_binary_max_string_size", 0, 1_GiB, "Prevent allocating large amount of memory"}}},
|
{"format_binary_max_string_size", 0, 1_GiB, "Prevent allocating large amount of memory"}}},
|
||||||
{"22.11", {{"use_structure_from_insertion_table_in_table_functions", 0, 2, "Improve using structure from insertion table in table functions"}}},
|
{"22.11", {{"use_structure_from_insertion_table_in_table_functions", 0, 2, "Improve using structure from insertion table in table functions"}}},
|
||||||
|
{"23.4", {{"formatdatetime_f_prints_single_zero", true, false, "Improved compatibility with MySQL DATE_FORMAT()/STR_TO_DATE()"}}},
|
||||||
{"23.4", {{"formatdatetime_parsedatetime_m_is_month_name", false, true, "Improved compatibility with MySQL DATE_FORMAT/STR_TO_DATE"}}},
|
{"23.4", {{"formatdatetime_parsedatetime_m_is_month_name", false, true, "Improved compatibility with MySQL DATE_FORMAT/STR_TO_DATE"}}},
|
||||||
{"22.9", {{"force_grouping_standard_compatibility", false, true, "Make GROUPING function output the same as in SQL standard and other DBMS"}}},
|
{"22.9", {{"force_grouping_standard_compatibility", false, true, "Make GROUPING function output the same as in SQL standard and other DBMS"}}},
|
||||||
{"22.7", {{"cross_to_inner_join_rewrite", 1, 2, "Force rewrite comma join to inner"},
|
{"22.7", {{"cross_to_inner_join_rewrite", 1, 2, "Force rewrite comma join to inner"},
|
||||||
|
@ -449,6 +449,20 @@ private:
|
|||||||
}
|
}
|
||||||
|
|
||||||
size_t mysqlFractionalSecond(char * dest, Time /*source*/, UInt64 fractional_second, UInt32 scale, const DateLUTImpl & /*timezone*/)
|
size_t mysqlFractionalSecond(char * dest, Time /*source*/, UInt64 fractional_second, UInt32 scale, const DateLUTImpl & /*timezone*/)
|
||||||
|
{
|
||||||
|
if (scale == 0)
|
||||||
|
scale = 6;
|
||||||
|
|
||||||
|
for (Int64 i = scale, value = fractional_second; i > 0; --i)
|
||||||
|
{
|
||||||
|
dest[i - 1] += value % 10;
|
||||||
|
value /= 10;
|
||||||
|
}
|
||||||
|
return scale;
|
||||||
|
}
|
||||||
|
|
||||||
|
/// Same as mysqlFractionalSecond but prints a single zero if the value has no fractional seconds
|
||||||
|
size_t mysqlFractionalSecondSingleZero(char * dest, Time /*source*/, UInt64 fractional_second, UInt32 scale, const DateLUTImpl & /*timezone*/)
|
||||||
{
|
{
|
||||||
if (scale == 0)
|
if (scale == 0)
|
||||||
scale = 1;
|
scale = 1;
|
||||||
@ -710,6 +724,7 @@ private:
|
|||||||
}
|
}
|
||||||
|
|
||||||
const bool mysql_M_is_month_name;
|
const bool mysql_M_is_month_name;
|
||||||
|
const bool mysql_f_prints_single_zero;
|
||||||
|
|
||||||
public:
|
public:
|
||||||
static constexpr auto name = Name::name;
|
static constexpr auto name = Name::name;
|
||||||
@ -718,6 +733,7 @@ public:
|
|||||||
|
|
||||||
explicit FunctionFormatDateTimeImpl(ContextPtr context)
|
explicit FunctionFormatDateTimeImpl(ContextPtr context)
|
||||||
: mysql_M_is_month_name(context->getSettings().formatdatetime_parsedatetime_m_is_month_name)
|
: mysql_M_is_month_name(context->getSettings().formatdatetime_parsedatetime_m_is_month_name)
|
||||||
|
, mysql_f_prints_single_zero(context->getSettings().formatdatetime_f_prints_single_zero)
|
||||||
{
|
{
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -1116,11 +1132,21 @@ public:
|
|||||||
// Fractional seconds
|
// Fractional seconds
|
||||||
case 'f':
|
case 'f':
|
||||||
{
|
{
|
||||||
/// If the time data type has no fractional part, then we print '0' as the fractional part.
|
/// If the time data type has no fractional part, we print (default) '000000' or (deprecated) '0' as fractional part.
|
||||||
|
if (mysql_f_prints_single_zero)
|
||||||
|
{
|
||||||
|
Instruction<T> instruction;
|
||||||
|
instruction.setMysqlFunc(&Instruction<T>::mysqlFractionalSecondSingleZero);
|
||||||
|
instructions.push_back(std::move(instruction));
|
||||||
|
out_template += String(scale == 0 ? 1 : scale, '0');
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
Instruction<T> instruction;
|
Instruction<T> instruction;
|
||||||
instruction.setMysqlFunc(&Instruction<T>::mysqlFractionalSecond);
|
instruction.setMysqlFunc(&Instruction<T>::mysqlFractionalSecond);
|
||||||
instructions.push_back(std::move(instruction));
|
instructions.push_back(std::move(instruction));
|
||||||
out_template += String(std::max<UInt32>(1, scale), '0');
|
out_template += String(scale == 0 ? 6 : scale, '0');
|
||||||
|
}
|
||||||
break;
|
break;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
@ -5,6 +5,7 @@ Jan Jan
|
|||||||
02 02
|
02 02
|
||||||
01/02/18 01/02/18
|
01/02/18 01/02/18
|
||||||
2 2
|
2 2
|
||||||
|
000000 000000
|
||||||
2018-01-02 2018-01-02
|
2018-01-02 2018-01-02
|
||||||
10 12
|
10 12
|
||||||
22 00
|
22 00
|
||||||
@ -43,11 +44,23 @@ no formatting pattern no formatting pattern
|
|||||||
-1100
|
-1100
|
||||||
+0300
|
+0300
|
||||||
+0530
|
+0530
|
||||||
1234560
|
000000
|
||||||
000340
|
000000
|
||||||
|
000000
|
||||||
|
000000
|
||||||
|
123
|
||||||
|
123456
|
||||||
|
123456789
|
||||||
|
0
|
||||||
|
0
|
||||||
|
0
|
||||||
|
0
|
||||||
|
123
|
||||||
|
123456
|
||||||
|
123456789
|
||||||
2022-12-08 18:11:29.123400000
|
2022-12-08 18:11:29.123400000
|
||||||
2022-12-08 18:11:29.1
|
2022-12-08 18:11:29.1
|
||||||
2022-12-08 18:11:29.0
|
2022-12-08 18:11:29.000000
|
||||||
2022-12-08 18:11:29.0
|
2022-12-08 18:11:29.000000
|
||||||
2022-12-08 00:00:00.0
|
2022-12-08 00:00:00.000000
|
||||||
2022-12-08 00:00:00.0
|
2022-12-08 00:00:00.000000
|
||||||
|
@ -17,6 +17,7 @@ SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%C'), formatDateTime(t
|
|||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%d'), formatDateTime(toDate32('2018-01-02'), '%d');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%d'), formatDateTime(toDate32('2018-01-02'), '%d');
|
||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%D'), formatDateTime(toDate32('2018-01-02'), '%D');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%D'), formatDateTime(toDate32('2018-01-02'), '%D');
|
||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%e'), formatDateTime(toDate32('2018-01-02'), '%e');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%e'), formatDateTime(toDate32('2018-01-02'), '%e');
|
||||||
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%f'), formatDateTime(toDate32('2018-01-02'), '%f');
|
||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%F'), formatDateTime(toDate32('2018-01-02'), '%F');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%F'), formatDateTime(toDate32('2018-01-02'), '%F');
|
||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%h'), formatDateTime(toDate32('2018-01-02'), '%h');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%h'), formatDateTime(toDate32('2018-01-02'), '%h');
|
||||||
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%H'), formatDateTime(toDate32('2018-01-02'), '%H');
|
SELECT formatDateTime(toDateTime('2018-01-02 22:33:44'), '%H'), formatDateTime(toDate32('2018-01-02'), '%H');
|
||||||
@ -66,8 +67,22 @@ SELECT formatDateTime(toDateTime('2020-01-01 01:00:00', 'US/Samoa'), '%z');
|
|||||||
SELECT formatDateTime(toDateTime('2020-01-01 01:00:00', 'Europe/Moscow'), '%z');
|
SELECT formatDateTime(toDateTime('2020-01-01 01:00:00', 'Europe/Moscow'), '%z');
|
||||||
SELECT formatDateTime(toDateTime('1970-01-01 00:00:00', 'Asia/Kolkata'), '%z');
|
SELECT formatDateTime(toDateTime('1970-01-01 00:00:00', 'Asia/Kolkata'), '%z');
|
||||||
|
|
||||||
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123456', 7), '%f');
|
-- %f (default settings)
|
||||||
select formatDateTime(toDateTime64('2022-12-08 18:11:29.00034', 6, 'UTC'), '%f');
|
select formatDateTime(toDate('2010-01-04'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDate32('2010-01-04'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime('2010-01-04 12:34:56'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56', 0), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123', 3), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123456', 6), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123456789', 9), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
-- %f (legacy settings)
|
||||||
|
select formatDateTime(toDate('2010-01-04'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
select formatDateTime(toDate32('2010-01-04'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
select formatDateTime(toDateTime('2010-01-04 12:34:56'), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56', 0), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123', 3), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123456', 6), '%f') SETTINGS formatdatetime_f_prints_single_zero = 0;
|
||||||
|
select formatDateTime(toDateTime64('2010-01-04 12:34:56.123456789', 9), '%f') SETTINGS formatdatetime_f_prints_single_zero = 1;
|
||||||
|
|
||||||
select formatDateTime(toDateTime64('2022-12-08 18:11:29.1234', 9, 'UTC'), '%F %T.%f');
|
select formatDateTime(toDateTime64('2022-12-08 18:11:29.1234', 9, 'UTC'), '%F %T.%f');
|
||||||
select formatDateTime(toDateTime64('2022-12-08 18:11:29.1234', 1, 'UTC'), '%F %T.%f');
|
select formatDateTime(toDateTime64('2022-12-08 18:11:29.1234', 1, 'UTC'), '%F %T.%f');
|
||||||
|
Loading…
Reference in New Issue
Block a user