This will allow to avoid superfluous sleep during query execution, since this not only not desired behavoiur, but also may hang the server, since if you will execute enough queries that will use MySQL database but will not allow enough connections (or your MySQL server is too slow) then you may run out of threads in the global thread pool. Also note that right now it is possible to get deadlock when the mysql pool is full, consider the following scenario: - you have m1 and m2 mysql tables - you have q1 and q2 queries, bot queries join m1 and m2 - q1 allocated connection for m1 but cannot allocate connection for m2 - q2 allocated connection for m2 but cannot allocate connection for m1 - but to resolve the lock one should give up on the locking while it is not possible right now... And then you got no free threads and this: # grep -h ^202 /proc/$(pgrep clickhouse-serv)/task/*/syscall | cut -d' ' -f2 | sort | uniq -c | sort -nr | head 1554 0x7ffb60b92fe8 # mutex in mysqlxx::PoolWithFailover::get 1375 0x7ffb9f1c4748 # mutex in ::PoolEntryHelper::~PoolEntryHelper from DB::MultiplexedConnections::invalidateReplica 1160 0x7ffb612918b8 # mutex in mysqlxx::PoolWithFailover::get 42 0x7ffb9f057984 # mutex in ThreadPoolImpl<std::__1::thread>::worker *NOTE: 202 is a `futex` with WAIT* (Went with `syscall` because debugging 10k+ threads is not easy, and eventually it may TRAP)
4.5 KiB
toc_priority | toc_title |
---|---|
4 | MySQL |
MySQL
The MySQL engine allows you to perform SELECT
and INSERT
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'])
SETTINGS
[connection_pool_size=16, ]
[connection_max_tries=3, ]
[connection_wait_timeout=5, ] /* 0 -- do not wait */
[connection_auto_close=true ]
;
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.
- The external_table_functions_use_nulls setting defines how to handle Nullable columns. Default value: 1. If 0, the table function does not make Nullable columns and inserts default values instead of nulls. This is also applicable for NULL values inside arrays.
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.
Supports multiple replicas that must be listed by |
. For example:
CREATE TABLE test_replicas (id UInt32, name String, age UInt32, money UInt32) ENGINE = MySQL(`mysql{2|3|4}:3306`, 'clickhouse', 'test_replicas', 'root', 'clickhouse');
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 │
└────────────────┴────────┘