ClickHouse/docs/en/engines/table-engines/integrations/postgresql.md
Slach 831135432f add PostgreSQL engine and table function documentation
Signed-off-by: Slach <bloodjazman@gmail.com>
2021-03-08 03:39:24 +03:00

3.4 KiB
Raw Blame History

toc_priority toc_title
8 PostgreSQL

PosgtreSQL

The PostgreSQL engine allows you to perform SELECT queries on data that is stored on a remote PostgreSQL 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 = PostgreSQL('host:port', 'database', 'table', 'user', 'password');

See a detailed description of the CREATE TABLE query.

The table structure can differ from the original PostgreSQL table structure:

  • Column names should be the same as in the original PostgreSQL table, but you can use just some of these columns and in any order.
  • Column types may differ from those in the original PostgreSQL table. ClickHouse tries to cast values to the ClickHouse data types.

Engine Parameters

  • 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.

Usage Example

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)

Table in ClickHouse, retrieving data from the PostgreSQL table created above:

CREATE TABLE default.postgresql_table
(
    `float_nullable` Nullable(Float32),
    `str` String,
    `int_id` Int32
)
ENGINE = PostgreSQL('localhost:5432', 'public', 'test', 'postges_user', 'postgres_password');
SELECT * FROM postgresql_table WHERE str IN ('test') 
┌─float_nullable─┬─str──┬─int_id─┐
│           ᴺᵁᴸᴸ │ test │      1 │
└────────────────┴──────┴────────┘
1 rows in set. Elapsed: 0.019 sec.

See Also