3.4 KiB
slug | sidebar_position | sidebar_label |
---|---|---|
/en/sql-reference/table-functions/odbc | 44 | odbc |
odbc
Returns table that is connected via ODBC.
odbc(connection_settings, external_database, external_table)
Parameters:
connection_settings
— Name of the section with connection settings in theodbc.ini
file.external_database
— Name of a database in an external DBMS.external_table
— Name of a table in theexternal_database
.
To safely implement ODBC connections, ClickHouse uses a separate program clickhouse-odbc-bridge
. If the ODBC driver is loaded directly from clickhouse-server
, driver problems can crash the ClickHouse server. ClickHouse automatically starts clickhouse-odbc-bridge
when it is required. The ODBC bridge program is installed from the same package as the clickhouse-server
.
The fields with the NULL
values from the external table are converted into the default values for the base data type. For example, if a remote MySQL table field has the INT NULL
type it is converted to 0 (the default value for ClickHouse Int32
data type).
Usage Example
Getting data from the local MySQL installation via ODBC
This example is checked for Ubuntu Linux 18.04 and MySQL server 5.7.
Ensure that unixODBC and MySQL Connector are installed.
By default (if installed from packages), ClickHouse starts as user clickhouse
. Thus you need to create and configure this user in the MySQL server.
$ sudo mysql
mysql> CREATE USER 'clickhouse'@'localhost' IDENTIFIED BY 'clickhouse';
mysql> GRANT ALL PRIVILEGES ON *.* TO 'clickhouse'@'clickhouse' WITH GRANT OPTION;
Then configure the connection in /etc/odbc.ini
.
$ cat /etc/odbc.ini
[mysqlconn]
DRIVER = /usr/local/lib/libmyodbc5w.so
SERVER = 127.0.0.1
PORT = 3306
DATABASE = test
USERNAME = clickhouse
PASSWORD = clickhouse
You can check the connection using the isql
utility from the unixODBC installation.
$ isql -v mysqlconn
+-------------------------+
| Connected! |
| |
...
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)
Retrieving data from the MySQL table in ClickHouse:
SELECT * FROM odbc('DSN=mysqlconn', 'test', 'test')
┌─int_id─┬─int_nullable─┬─float─┬─float_nullable─┐
│ 1 │ 0 │ 2 │ 0 │
└────────┴──────────────┴───────┴────────────────┘