3.8 KiB
toc_priority | toc_title |
---|---|
42 | postgresql |
postgresql
Allows SELECT
and INSERT
queries to be performed on data that is stored on a remote PostgreSQL server.
Syntax
postgresql('host:port', 'database', 'table', 'user', 'password')
Arguments
-
host:port
— PostgreSQL server address. -
database
— Remote database name. -
table
— Remote table name. -
user
— PostgreSQL user. -
password
— User password.
SELECT Queries on PostgreSQL side run as COPY (SELECT ...) TO STDOUT
inside read-only PostgreSQL transaction with commit after each SELECT
query.
Simple WHERE
clauses such as =, !=, >, >=, <, <=, IN
are executed on the PostgreSQL server.
All joins, aggregations, sorting, IN [ array ]
conditions and the LIMIT
sampling constraint are executed in ClickHouse only after the query to PostgreSQL finishes.
INSERT Queries on PostgreSQL side run as COPY "table_name" (field1, field2, ... fieldN) FROM STDIN
inside PostgreSQL transaction with auto-commit after each INSERT
statement.
PostgreSQL Array types converts into ClickHouse arrays.
Be careful in PostgreSQL an array data type column like Integer[] may contain arrays of different dimensions in different rows, but in ClickHouse it is only allowed to have multidimensional arrays of the same dimension in all rows.
Returned Value
A table object with the same columns as the original PostgreSQL table.
!!! info "Note"
In the INSERT
query to distinguish table function postgresql(...)
from table name with column names list you must use keywords FUNCTION
or TABLE FUNCTION
. See examples below.
Examples
Table in PostgreSQL:
postgres=# CREATE TABLE "public"."test" (
"int_id" SERIAL,
"int_nullable" INT NULL DEFAULT NULL,
"float" FLOAT NOT NULL,
"str" VARCHAR(100) NOT NULL DEFAULT '',
"float_nullable" FLOAT NULL DEFAULT NULL,
PRIMARY KEY (int_id));
CREATE TABLE
postgres=# insert into test (int_id, str, "float") VALUES (1,'test',2);
INSERT 0 1
postgresql> select * from test;
int_id | int_nullable | float | str | float_nullable
--------+--------------+-------+------+----------------
1 | | 2 | test |
(1 row)
Selecting data from ClickHouse:
SELECT * FROM postgresql('localhost:5432', 'test', 'test', 'postgresql_user', 'password') WHERE str IN ('test');
┌─int_id─┬─int_nullable─┬─float─┬─str──┬─float_nullable─┐
│ 1 │ ᴺᵁᴸᴸ │ 2 │ test │ ᴺᵁᴸᴸ │
└────────┴──────────────┴───────┴──────┴────────────────┘
Inserting:
INSERT INTO TABLE FUNCTION postgresql('localhost:5432', 'test', 'test', 'postgrsql_user', 'password') (int_id, float) VALUES (2, 3);
SELECT * FROM postgresql('localhost:5432', 'test', 'test', 'postgresql_user', 'password');
┌─int_id─┬─int_nullable─┬─float─┬─str──┬─float_nullable─┐
│ 1 │ ᴺᵁᴸᴸ │ 2 │ test │ ᴺᵁᴸᴸ │
│ 2 │ ᴺᵁᴸᴸ │ 3 │ │ ᴺᵁᴸᴸ │
└────────┴──────────────┴───────┴──────┴────────────────┘
See Also