* normalize
* split & adjust links
* re-normalize
* adjust ru links
* adjust ja/tr links
* partially apply e0d19d2aea
* reset contribs
3.8 KiB
toc_priority | toc_title |
---|---|
3 | MySQL |
MySQL
The MySQL engine allows you to perform SELECT
queries on data that is stored on a remote MySQL server.
Creating a Table
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],
...
) ENGINE = MySQL('host:port', 'database', 'table', 'user', 'password'[, replace_query, 'on_duplicate_clause']);
See a detailed description of the CREATE TABLE query.
The table structure can differ from the original MySQL table structure:
- Column names should be the same as in the original MySQL table, but you can use just some of these columns and in any order.
- Column types may differ from those in the original MySQL table. ClickHouse tries to cast values to the ClickHouse data types.
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 convertsINSERT INTO
queries toREPLACE INTO
. Ifreplace_query=1
, the query is substituted. -
on_duplicate_clause
— TheON DUPLICATE KEY on_duplicate_clause
expression that is added to theINSERT
query.Example:
INSERT INTO t (c1,c2) VALUES ('a', 2) ON DUPLICATE KEY UPDATE c2 = c2 + 1
, whereon_duplicate_clause
isUPDATE c2 = c2 + 1
. See the MySQL documentation to find whichon_duplicate_clause
you can use with theON DUPLICATE KEY
clause.To specify
on_duplicate_clause
you need to pass0
to thereplace_query
parameter. If you simultaneously passreplace_query = 1
andon_duplicate_clause
, ClickHouse generates an exception.
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.
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, retrieving data from the MySQL table created above:
CREATE TABLE mysql_table
(
`float_nullable` Nullable(Float32),
`int_id` Int32
)
ENGINE = MySQL('localhost:3306', 'test', 'test', 'bayonet', '123')
SELECT * FROM mysql_table
┌─float_nullable─┬─int_id─┐
│ ᴺᵁᴸᴸ │ 1 │
└────────────────┴────────┘