mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-10 01:25:21 +00:00
DOCAPI-4293: MySQL engine and mysql table functions docs.
This commit is contained in:
parent
1707cd79c8
commit
8cc4586f86
@ -3,21 +3,35 @@
|
||||
|
||||
The MySQL engine allows you to perform `SELECT` queries on data that is stored on a remote MySQL server.
|
||||
|
||||
Call format:
|
||||
## Creating a Table
|
||||
|
||||
```
|
||||
MySQL('host:port', 'database', 'table', 'user', 'password'[, replace_query, 'on_duplicate_clause']);
|
||||
```sql
|
||||
CREATE TABLE [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster]
|
||||
(
|
||||
name1 [type1] [DEFAULT|MATERIALIZED|ALIAS expr1] [TTL expr1],
|
||||
name2 [type2] [DEFAULT|MATERIALIZED|ALIAS expr2] [TTL expr2],
|
||||
...
|
||||
INDEX index_name1 expr1 TYPE type1(...) GRANULARITY value1,
|
||||
INDEX index_name2 expr2 TYPE type2(...) GRANULARITY value2
|
||||
) ENGINE = MySQL('host:port', 'database', 'table', 'user', 'password'[, replace_query, 'on_duplicate_clause']);
|
||||
```
|
||||
|
||||
**Call parameters**
|
||||
See the detailed description of the [CREATE TABLE](../../query_language/create.md#create-table-query) query.
|
||||
|
||||
- `host:port` — Address of the MySQL server.
|
||||
- `database` — Database name on the MySQL server.
|
||||
- `table` — Name of the table.
|
||||
- `user` — The MySQL User.
|
||||
The table structure should not be the same as the original MySQL table structure:
|
||||
|
||||
- Names of columns should be the same as in the original MySQL table, but you can use any set of columns in any order.
|
||||
- Types of columns may differ from the original MySQL table. ClickHouse tries to [cast](../../query_language/functions/type_conversion_functions.md#type_conversion_function-cast) the value into the ClickHouse data type.
|
||||
|
||||
**Engine Parameters**
|
||||
|
||||
- `host:port` — MySQL server address.
|
||||
- `database` — Remote database name.
|
||||
- `table` — Remote table name.
|
||||
- `user` — MySQL user.
|
||||
- `password` — User password.
|
||||
- `replace_query` — Flag that sets query substitution `INSERT INTO` to `REPLACE INTO`. If `replace_query=1`, the query is replaced.
|
||||
- `on_duplicate_clause` — Adds the `ON DUPLICATE KEY on_duplicate_clause` expression to the `INSERT` query.
|
||||
- `on_duplicate_clause` — The `ON DUPLICATE KEY on_duplicate_clause` expression that is added to the `INSERT` query.
|
||||
|
||||
Example: `INSERT INTO t (c1,c2) VALUES ('a', 2) ON DUPLICATE KEY UPDATE c2 = c2 + 1`, where `on_duplicate_clause` is `UPDATE c2 = c2 + 1`. See MySQL documentation to find which `on_duplicate_clause` you can use with `ON DUPLICATE KEY` clause.
|
||||
|
||||
@ -27,7 +41,53 @@ At this time, simple `WHERE` clauses such as ` =, !=, >, >=, <, <=` are executed
|
||||
|
||||
The rest of the conditions and the `LIMIT` sampling constraint are executed in ClickHouse only after the query to MySQL finishes.
|
||||
|
||||
The `MySQL` engine does not support the [Nullable](../../data_types/nullable.md) data type, so when reading data from MySQL tables, `NULL` is converted to default values for the specified column type (usually 0 or an empty string).
|
||||
## Usage Example
|
||||
|
||||
Table in MySQL:
|
||||
|
||||
```
|
||||
mysql> CREATE TABLE `test`.`test` (
|
||||
-> `int_id` INT NOT NULL AUTO_INCREMENT,
|
||||
-> `int_nullable` INT NULL DEFAULT NULL,
|
||||
-> `float` FLOAT NOT NULL,
|
||||
-> `float_nullable` FLOAT NULL DEFAULT NULL,
|
||||
-> PRIMARY KEY (`int_id`));
|
||||
Query OK, 0 rows affected (0,09 sec)
|
||||
|
||||
mysql> insert into test (`int_id`, `float`) VALUES (1,2);
|
||||
Query OK, 1 row affected (0,00 sec)
|
||||
|
||||
mysql> select * from test;
|
||||
+--------+--------------+-------+----------------+
|
||||
| int_id | int_nullable | float | float_nullable |
|
||||
+--------+--------------+-------+----------------+
|
||||
| 1 | NULL | 2 | NULL |
|
||||
+--------+--------------+-------+----------------+
|
||||
1 row in set (0,00 sec)
|
||||
```
|
||||
|
||||
Table in ClickHouse, getting data from the MySQL table:
|
||||
|
||||
```sql
|
||||
CREATE TABLE mysql_table
|
||||
(
|
||||
`float_nullable` Nullable(Float32),
|
||||
`int_id` Int32
|
||||
)
|
||||
ENGINE = MySQL('localhost:3306', 'test', 'test', 'bayonet', '123')
|
||||
```
|
||||
```sql
|
||||
SELECT * FROM mysql_table6
|
||||
```
|
||||
```text
|
||||
┌─float_nullable─┬─int_id─┐
|
||||
│ ᴺᵁᴸᴸ │ 1 │
|
||||
└────────────────┴────────┘
|
||||
```
|
||||
|
||||
## See Also
|
||||
|
||||
- [The 'mysql' table function](../../query_language/table_functions/mysql.md)
|
||||
- [Using MySQL as a source of extenal dictionary](../../query_language/dicts/external_dicts_dict_sources.md#dicts-external_dicts_dict_sources-mysql)
|
||||
|
||||
[Original article](https://clickhouse.yandex/docs/en/operations/table_engines/mysql/) <!--hide-->
|
||||
|
72
docs/en/query_language/table_functions/mysql.md
Normal file
72
docs/en/query_language/table_functions/mysql.md
Normal file
@ -0,0 +1,72 @@
|
||||
# mysql
|
||||
|
||||
Allows to perform `SELECT` queries on data that is stored on a remote MySQL server.
|
||||
|
||||
```
|
||||
mysql('host:port', 'database', 'table', 'user', 'password'[, replace_query, 'on_duplicate_clause']);
|
||||
```
|
||||
|
||||
**Parameters**
|
||||
|
||||
- `host:port` — MySQL server address.
|
||||
- `database` — Remote database name.
|
||||
- `table` — Remote table name.
|
||||
- `user` — MySQL user.
|
||||
- `password` — User password.
|
||||
- `replace_query` — Flag that sets query substitution `INSERT INTO` to `REPLACE INTO`. If `replace_query=1`, the query is replaced.
|
||||
- `on_duplicate_clause` — The `ON DUPLICATE KEY on_duplicate_clause` expression that is added to the `INSERT` query.
|
||||
|
||||
Example: `INSERT INTO t (c1,c2) VALUES ('a', 2) ON DUPLICATE KEY UPDATE c2 = c2 + 1`, where `on_duplicate_clause` is `UPDATE c2 = c2 + 1`. See MySQL documentation to find which `on_duplicate_clause` you can use with `ON DUPLICATE KEY` clause.
|
||||
|
||||
To specify `on_duplicate_clause` you need to pass `0` to the `replace_query` parameter. If you simultaneously pass `replace_query = 1` and `on_duplicate_clause`, ClickHouse generates an exception.
|
||||
|
||||
At this time, simple `WHERE` clauses such as ` =, !=, >, >=, <, <=` are executed on the MySQL server.
|
||||
|
||||
The rest of the conditions and the `LIMIT` sampling constraint are executed in ClickHouse only after the query to MySQL finishes.
|
||||
|
||||
**Returned Value**
|
||||
|
||||
A table object with the same columns as the original MySQL table.
|
||||
|
||||
## Usage Example
|
||||
|
||||
Table in MySQL:
|
||||
|
||||
```
|
||||
mysql> CREATE TABLE `test`.`test` (
|
||||
-> `int_id` INT NOT NULL AUTO_INCREMENT,
|
||||
-> `int_nullable` INT NULL DEFAULT NULL,
|
||||
-> `float` FLOAT NOT NULL,
|
||||
-> `float_nullable` FLOAT NULL DEFAULT NULL,
|
||||
-> PRIMARY KEY (`int_id`));
|
||||
Query OK, 0 rows affected (0,09 sec)
|
||||
|
||||
mysql> insert into test (`int_id`, `float`) VALUES (1,2);
|
||||
Query OK, 1 row affected (0,00 sec)
|
||||
|
||||
mysql> select * from test;
|
||||
+--------+--------------+-------+----------------+
|
||||
| int_id | int_nullable | float | float_nullable |
|
||||
+--------+--------------+-------+----------------+
|
||||
| 1 | NULL | 2 | NULL |
|
||||
+--------+--------------+-------+----------------+
|
||||
1 row in set (0,00 sec)
|
||||
```
|
||||
|
||||
Selection of the data from ClickHouse:
|
||||
|
||||
```sql
|
||||
SELECT * FROM mysql('localhost:3306', 'test', 'test', 'bayonet', '123')
|
||||
```
|
||||
```text
|
||||
┌─int_id─┬─int_nullable─┬─float─┬─float_nullable─┐
|
||||
│ 1 │ ᴺᵁᴸᴸ │ 2 │ ᴺᵁᴸᴸ │
|
||||
└────────┴──────────────┴───────┴────────────────┘
|
||||
```
|
||||
|
||||
## See Also
|
||||
|
||||
- [The 'MySQL' table engine](../../operations/table_engines/mysql.md)
|
||||
- [Using MySQL as a source of extenal dictionary](../dicts/external_dicts_dict_sources.md#dicts-external_dicts_dict_sources-mysql)
|
||||
|
||||
[Original article](https://clickhouse.yandex/docs/en/query_language/table_functions/mysql/) <!--hide-->
|
1
docs/fa/query_language/table_functions/mysql.md
Symbolic link
1
docs/fa/query_language/table_functions/mysql.md
Symbolic link
@ -0,0 +1 @@
|
||||
../../../en/query_language/table_functions/mysql.md
|
@ -299,7 +299,7 @@ SELECT * FROM odbc('DSN=gregtest;Servername=some-server.com', 'test_db');
|
||||
## СУБД
|
||||
|
||||
|
||||
### MySQL
|
||||
### MySQL {#dicts-external_dicts_dict_sources-mysql}
|
||||
|
||||
Пример настройки:
|
||||
|
||||
|
72
docs/ru/query_language/table_functions/mysql.md
Normal file
72
docs/ru/query_language/table_functions/mysql.md
Normal file
@ -0,0 +1,72 @@
|
||||
# mysql
|
||||
|
||||
Allows to perform `SELECT` queries on data that is stored on a remote MySQL server.
|
||||
|
||||
```
|
||||
mysql('host:port', 'database', 'table', 'user', 'password'[, replace_query, 'on_duplicate_clause']);
|
||||
```
|
||||
|
||||
**Parameters**
|
||||
|
||||
- `host:port` — MySQL server address.
|
||||
- `database` — Remote database name.
|
||||
- `table` — Remote table name.
|
||||
- `user` — MySQL user.
|
||||
- `password` — User password.
|
||||
- `replace_query` — Flag that sets query substitution `INSERT INTO` to `REPLACE INTO`. If `replace_query=1`, the query is replaced.
|
||||
- `on_duplicate_clause` — The `ON DUPLICATE KEY on_duplicate_clause` expression that is added to the `INSERT` query.
|
||||
|
||||
Example: `INSERT INTO t (c1,c2) VALUES ('a', 2) ON DUPLICATE KEY UPDATE c2 = c2 + 1`, where `on_duplicate_clause` is `UPDATE c2 = c2 + 1`. See MySQL documentation to find which `on_duplicate_clause` you can use with `ON DUPLICATE KEY` clause.
|
||||
|
||||
To specify `on_duplicate_clause` you need to pass `0` to the `replace_query` parameter. If you simultaneously pass `replace_query = 1` and `on_duplicate_clause`, ClickHouse generates an exception.
|
||||
|
||||
At this time, simple `WHERE` clauses such as ` =, !=, >, >=, <, <=` are executed on the MySQL server.
|
||||
|
||||
The rest of the conditions and the `LIMIT` sampling constraint are executed in ClickHouse only after the query to MySQL finishes.
|
||||
|
||||
**Returned Value**
|
||||
|
||||
A table object with the same columns as the original MySQL table.
|
||||
|
||||
## Usage Example
|
||||
|
||||
Table in MySQL:
|
||||
|
||||
```
|
||||
mysql> CREATE TABLE `test`.`test` (
|
||||
-> `int_id` INT NOT NULL AUTO_INCREMENT,
|
||||
-> `int_nullable` INT NULL DEFAULT NULL,
|
||||
-> `float` FLOAT NOT NULL,
|
||||
-> `float_nullable` FLOAT NULL DEFAULT NULL,
|
||||
-> PRIMARY KEY (`int_id`));
|
||||
Query OK, 0 rows affected (0,09 sec)
|
||||
|
||||
mysql> insert into test (`int_id`, `float`) VALUES (1,2);
|
||||
Query OK, 1 row affected (0,00 sec)
|
||||
|
||||
mysql> select * from test;
|
||||
+--------+--------------+-------+----------------+
|
||||
| int_id | int_nullable | float | float_nullable |
|
||||
+--------+--------------+-------+----------------+
|
||||
| 1 | NULL | 2 | NULL |
|
||||
+--------+--------------+-------+----------------+
|
||||
1 row in set (0,00 sec)
|
||||
```
|
||||
|
||||
Selection of the data from ClickHouse:
|
||||
|
||||
```sql
|
||||
SELECT * FROM mysql('localhost:3306', 'test', 'test', 'bayonet', '123')
|
||||
```
|
||||
```text
|
||||
┌─int_id─┬─int_nullable─┬─float─┬─float_nullable─┐
|
||||
│ 1 │ ᴺᵁᴸᴸ │ 2 │ ᴺᵁᴸᴸ │
|
||||
└────────┴──────────────┴───────┴────────────────┘
|
||||
```
|
||||
|
||||
## See Also
|
||||
|
||||
- [The 'MySQL' table engine](../../operations/table_engines/mysql.md)
|
||||
- [Using MySQL as a source of extenal dictionary](../dicts/external_dicts_dict_sources.md#dicts-external_dicts_dict_sources-mysql)
|
||||
|
||||
[Original article](https://clickhouse.yandex/docs/en/query_language/table_functions/mysql/) <!--hide-->
|
@ -148,6 +148,7 @@ nav:
|
||||
- 'numbers': 'query_language/table_functions/numbers.md'
|
||||
- 'remote': 'query_language/table_functions/remote.md'
|
||||
- 'url': 'query_language/table_functions/url.md'
|
||||
- 'mysql': 'query_language/table_functions/mysql.md'
|
||||
- 'jdbc': 'query_language/table_functions/jdbc.md'
|
||||
- 'Dictionaries':
|
||||
- 'Introduction': 'query_language/dicts/index.md'
|
||||
|
@ -147,6 +147,7 @@ nav:
|
||||
- 'numbers': 'query_language/table_functions/numbers.md'
|
||||
- 'remote': 'query_language/table_functions/remote.md'
|
||||
- 'url': 'query_language/table_functions/url.md'
|
||||
- 'mysql': 'query_language/table_functions/mysql.md'
|
||||
- 'jdbc': 'query_language/table_functions/jdbc.md'
|
||||
- 'Dictionaries':
|
||||
- 'Introduction': 'query_language/dicts/index.md'
|
||||
|
@ -147,6 +147,7 @@ nav:
|
||||
- 'numbers': 'query_language/table_functions/numbers.md'
|
||||
- 'remote': 'query_language/table_functions/remote.md'
|
||||
- 'url': 'query_language/table_functions/url.md'
|
||||
- 'mysql': 'query_language/table_functions/mysql.md'
|
||||
- 'jdbc': 'query_language/table_functions/jdbc.md'
|
||||
- 'Словари':
|
||||
- 'Введение': 'query_language/dicts/index.md'
|
||||
|
@ -146,6 +146,7 @@ nav:
|
||||
- 'numbers': 'query_language/table_functions/numbers.md'
|
||||
- 'remote': 'query_language/table_functions/remote.md'
|
||||
- 'url': 'query_language/table_functions/url.md'
|
||||
- 'mysql': 'query_language/table_functions/mysql.md'
|
||||
- 'jdbc': 'query_language/table_functions/jdbc.md'
|
||||
- 'Dictionaries':
|
||||
- 'Introduction': 'query_language/dicts/index.md'
|
||||
|
1
docs/zh/query_language/table_functions/mysql.md
Symbolic link
1
docs/zh/query_language/table_functions/mysql.md
Symbolic link
@ -0,0 +1 @@
|
||||
../../../en/query_language/table_functions/mysql.md
|
Loading…
Reference in New Issue
Block a user