Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Change SHOW COLUMNS query to display MySQL types in MySQL Compatibility mode #49577

Merged
merged 25 commits into from Jun 21, 2023
Merged
Show file tree
Hide file tree
Changes from 1 commit
Commits
Show all changes
25 commits
Select commit Hold shift + click to select a range
18d1a43
Change SHOW COLUMNS query to display MySQL types in MySQL Compatibili…
tpanetti May 5, 2023
ddbad79
Change SHOW COLUMNS query to display MySQL types in MySQL Compatibili…
tpanetti May 5, 2023
4bc55cd
Merge branch 'master' into mysql_compatible_types
tpanetti May 30, 2023
6e8dc67
Merge branch 'mysql_compatible_types' of https://github.com/tpanetti/…
tpanetti May 30, 2023
38634cc
Convert Clickhouse Types to MySQL types in Compatibility mode
tpanetti May 24, 2023
bd5a1ae
Revert "Change SHOW COLUMNS query to display MySQL types in MySQL Com…
tpanetti May 30, 2023
4c92bc7
Fix incompatible ClickHouse -> MySQL types for compability mode
tpanetti May 31, 2023
05dfe58
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 2, 2023
423afec
Change case and function name for MySQL Compatible types
tpanetti Jun 2, 2023
495482c
Refactor ClickHouse->MySQL Type conversion and add configuration sett…
tpanetti Jun 5, 2023
016e30c
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 7, 2023
96d7b2e
Disable fasttest for MySQL Compatibility Type Conversion and refactor…
tpanetti Jun 9, 2023
5769d7f
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 9, 2023
cb8c207
Rename setting and description for MySQL compatible types
tpanetti Jun 10, 2023
252a10c
Add "no-parallel" tag to MySQL Compatible Types test to fix test issue
tpanetti Jun 12, 2023
8683f5e
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 12, 2023
fa4bc6b
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 13, 2023
d1b96b5
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 13, 2023
a502967
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 14, 2023
0477221
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 14, 2023
45328a4
Fix test for MySQL Compatible Types to use clickhouse_client rather t…
tpanetti Jun 14, 2023
6959486
Fix test for MySQL Compatible types (drop database properly)
tpanetti Jun 14, 2023
18fb4fb
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 14, 2023
8790497
Fix test for MySQL Compatible Types (suppress password warning)
tpanetti Jun 14, 2023
dbdf77c
Merge branch 'master' into mysql_compatible_types
tpanetti Jun 14, 2023
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
78 changes: 76 additions & 2 deletions src/Interpreters/InterpreterShowColumnsQuery.cpp
Expand Up @@ -26,11 +26,17 @@ String InterpreterShowColumnsQuery::getRewrittenQuery()

WriteBufferFromOwnString rewritten_query;

rewritten_query << "SELECT name AS field, type AS type, startsWith(type, 'Nullable') AS null, trim(concatWithSeparator(' ', if(is_in_primary_key, 'PRI', ''), if (is_in_sorting_key, 'SOR', ''))) AS key, if(default_kind IN ('ALIAS', 'DEFAULT', 'MATERIALIZED'), default_expression, NULL) AS default, '' AS extra ";

// TODO Interpret query.extended. It is supposed to show internal/virtual columns. Need to fetch virtual column names, see
// IStorage::getVirtuals(). We can't easily do that via SQL.

// If connected via MySQL Compatibility mode, convert ClickHouse types to MySQL
if (getContext()->getClientInfo().interface == DB::ClientInfo::Interface::MYSQL)
{
rewritten_query << getMySQLQuery();
}
else {
rewritten_query << "SELECT name AS field, type AS type, startsWith(type, 'Nullable') AS null, trim(concatWithSeparator(' ', if(is_in_primary_key, 'PRI', ''), if (is_in_sorting_key, 'SOR', ''))) AS key, if(default_kind IN ('ALIAS', 'DEFAULT', 'MATERIALIZED'), default_expression, NULL) AS default, '' AS extra ";
}
if (query.full)
{
/// "Full" mode is mostly for MySQL compat
Expand Down Expand Up @@ -93,6 +99,74 @@ String InterpreterShowColumnsQuery::getRewrittenQuery()

}

String InterpreterShowColumnsQuery::getMySQLQuery()
{
WriteBufferFromOwnString mysql_specific_query;

mysql_specific_query << "SELECT name AS field, "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< "CASE "
<< " WHEN startsWith(type, 'Nullable') THEN "
<< " CASE "
<< " WHEN substring(type, 10, length(type) - 10) IN ('UInt8', 'Int8') THEN 'tinyint' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) IN ('UInt16', 'Int16') THEN 'smallint' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) IN ('UInt32', 'Int32') THEN 'int' "
<< " WHEN substring(type, 10, length(type) - 10) IN ('UInt64', 'Int64', 'UInt128', 'Int128', 'UInt256', 'Int256') THEN 'bigint' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) = 'Float32' THEN 'float' "
<< " WHEN substring(type, 10, length(type) - 10) = 'Float64' THEN 'double' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Decimal%' THEN 'decimal' "
<< " WHEN substring(type, 10, length(type) - 10) = 'Boolean' THEN 'tinyint' "
<< " WHEN substring(type, 10, length(type) - 10) = 'String' THEN 'text' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'FixedString%' THEN 'text' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Date%' THEN 'date' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'DateTime%' THEN 'datetime' "
<< " WHEN substring(type, 10, length(type) - 10) = 'JSON' THEN 'json' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) = 'UUID' THEN 'binary' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Enum%' THEN 'enum' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'LowCardinality%' THEN 'text' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Array%' THEN 'json' "
rschu1ze marked this conversation as resolved.
Show resolved Hide resolved
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Map%' THEN 'json' "
<< " WHEN substring(type, 10, length(type) - 10) IN ('SimpleAggregateFunction', 'AggregateFunction') THEN 'text' "
<< " WHEN substring(type, 10, length(type) - 10) = 'Nested' THEN 'json' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'Tuple%' THEN 'json' "
<< " WHEN substring(type, 10, length(type) - 10) LIKE 'IPv%' THEN 'text' "
<< " WHEN substring(type, 10, length(type) - 10) IN ('Expression', 'Set', 'Nothing', 'Interval') THEN 'text' "
<< " ELSE substring(type, 10, length(type) - 10) "
<< " END "
<< " ELSE "
<< " CASE "
<< " WHEN type IN ('UInt8', 'Int8') THEN 'tinyint' "
<< " WHEN type IN ('UInt16', 'Int16') THEN 'smallint' "
<< " WHEN type IN ('UInt32', 'Int32') THEN 'int' "
<< " WHEN type IN ('UInt64', 'Int64', 'UInt128', 'Int128', 'UInt256', 'Int256') THEN 'bigint' "
<< " WHEN type = 'Float32' THEN 'float' "
<< " WHEN type = 'Float64' THEN 'double' "
<< " WHEN type LIKE 'Decimal%' THEN 'decimal' "
<< " WHEN type = 'Boolean' THEN 'tinyint' "
<< " WHEN type = 'String' THEN 'text' "
<< " WHEN type LIKE 'FixedString%' THEN 'text' "
<< " WHEN type LIKE 'Date%' THEN 'date' "
<< " WHEN type LIKE 'DateTime%' THEN 'datetime' "
<< " WHEN type = 'JSON' THEN 'json' "
<< " WHEN type = 'UUID' THEN 'binary' "
<< " WHEN type LIKE 'Enum%' THEN 'enum' "
<< " WHEN type LIKE 'LowCardinality%' THEN 'text' "
<< " WHEN type LIKE 'Array%' THEN 'json' "
<< " WHEN type LIKE 'Map%' THEN 'json' "
<< " WHEN type IN ('SimpleAggregateFunction', 'AggregateFunction') THEN 'text' "
<< " WHEN type = 'Nested' THEN 'json' "
<< " WHEN type LIKE 'Tuple%' THEN 'json' "
<< " WHEN type LIKE 'IPv%' THEN 'text' "
<< " WHEN type IN ('Expression', 'Set', 'Nothing', 'Interval') THEN 'text' "
<< " ELSE type "
<< " END "
<< "END AS type, "
<< "startsWith(type, 'Nullable') AS null, "
<< "trim(concatWithSeparator(' ', if(is_in_primary_key, 'PRI', ''), if (is_in_sorting_key, 'SOR', ''))) AS key, "
<< "if(default_kind IN ('ALIAS', 'DEFAULT', 'MATERIALIZED'), default_expression, NULL) AS default, "
<< "'' AS extra ";

return mysql_specific_query.str();
}

BlockIO InterpreterShowColumnsQuery::execute()
{
Expand Down
1 change: 1 addition & 0 deletions src/Interpreters/InterpreterShowColumnsQuery.h
Expand Up @@ -26,6 +26,7 @@ class InterpreterShowColumnsQuery : public IInterpreter, WithMutableContext
ASTPtr query_ptr;

String getRewrittenQuery();
String getMySQLQuery();
};


Expand Down
@@ -0,0 +1,213 @@
Drop tables if they exist
Create tab table
Create pseudo-random database name
Create tab duplicate table
Run MySQL test
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
int32 int 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_int json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uint64 bigint 0 PRI SOR NULL
uuid_value binary 0 NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
int32 int 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_int json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uint64 bigint 0 PRI SOR NULL
uuid_value binary 0 NULL
field type null key default extra collation comment privileges
array_value json 0 NULL NULL
boolean_value tinyint 0 NULL NULL
date32_value date 0 NULL NULL
date_value date 0 NULL NULL
datetime64_value date 0 NULL NULL
datetime_value date 0 NULL NULL
decimal_value decimal 0 NULL NULL
enum_value enum 0 NULL NULL
fixed_string_value text 0 NULL NULL
float32 float 0 NULL NULL
float64 double 0 NULL NULL
int32 int 0 NULL NULL
ipv4_value text 0 NULL NULL
ipv6_value text 0 NULL NULL
json_value text 0 NULL NULL
low_cardinality text 0 NULL NULL
map_value json 0 NULL NULL
nested.nested_int json 0 NULL NULL
nested.nested_string json 0 NULL NULL
nullable_value int 0 NULL NULL
string_value text 0 NULL NULL
tuple_value json 0 NULL NULL
uint64 bigint 0 PRI SOR NULL NULL
uuid_value binary 0 NULL NULL
field type null key default extra
int32 int 0 NULL
nested.nested_int json 0 NULL
uint64 bigint 0 PRI SOR NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uuid_value binary 0 NULL
field type null key default extra
int32 int 0 NULL
nested.nested_int json 0 NULL
uint64 bigint 0 PRI SOR NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uuid_value binary 0 NULL
field type null key default extra
int32 int 0 NULL
nested.nested_int json 0 NULL
uint64 bigint 0 PRI SOR NULL
field type null key default extra
array_value json 0 NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
int32 int 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_int json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uint64 bigint 0 PRI SOR NULL
uuid_value binary 0 NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
int32 int 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_int json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uint64 bigint 0 PRI SOR NULL
uuid_value binary 0 NULL
field type null key default extra
array_value json 0 NULL
boolean_value tinyint 0 NULL
date32_value date 0 NULL
date_value date 0 NULL
datetime64_value date 0 NULL
datetime_value date 0 NULL
decimal_value decimal 0 NULL
enum_value enum 0 NULL
fixed_string_value text 0 NULL
float32 float 0 NULL
float64 double 0 NULL
int32 int 0 NULL
ipv4_value text 0 NULL
ipv6_value text 0 NULL
json_value text 0 NULL
low_cardinality text 0 NULL
map_value json 0 NULL
nested.nested_int json 0 NULL
nested.nested_string json 0 NULL
nullable_value int 0 NULL
string_value text 0 NULL
tuple_value json 0 NULL
uint64 bigint 0 PRI SOR NULL
uuid_value binary 0 NULL