ClickHouse/docs/en/engines/table-engines/integrations/postgresql.md
2022-08-28 10:53:34 -04:00

6.2 KiB

slug sidebar_position sidebar_label
/en/engines/table-engines/integrations/postgresql 11 PostgreSQL

PostgreSQL

The PostgreSQL engine allows to perform SELECT and INSERT 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'[, `schema`]);

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.
  • 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 — PostgreSQL server address.
  • database — Remote database name.
  • table — Remote table name.
  • user — PostgreSQL user.
  • password — User password.
  • schema — Non-default table schema. Optional.
  • on conflict ... — example: ON CONFLICT DO NOTHING. Optional. Note: adding this option will make insertion less efficient.

or via config (since version 21.11):

<named_collections>
    <postgres1>
        <host></host>
        <port></port>
        <user></user>
        <password></password>
        <table></table>
    </postgres1>
    <postgres2>
        <host></host>
        <port></port>
        <user></user>
        <password></password>
    </postgres2>
</named_collections>

Some parameters can be overriden by key value arguments:

SELECT * FROM postgresql(postgres1, schema='schema1', table='table1');

Implementation Details

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 =, !=, >, >=, <, <=, and 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 are converted into ClickHouse arrays.

:::warning Be careful - in PostgreSQL an array data, created like a type_name[], may contain multi-dimensional arrays of different dimensions in different table rows in same column. But in ClickHouse it is only allowed to have multidimensional arrays of the same count of dimensions in all table rows in same column. :::

Supports multiple replicas that must be listed by |. For example:

CREATE TABLE test_replicas (id UInt32, name String) ENGINE = PostgreSQL(`postgres{2|3|4}:5432`, 'clickhouse', 'test_replicas', 'postgres', 'mysecretpassword');

Replicas priority for PostgreSQL dictionary source is supported. The bigger the number in map, the less the priority. The highest priority is 0.

In the example below replica example01-1 has the highest priority:

<postgresql>
    <port>5432</port>
    <user>clickhouse</user>
    <password>qwerty</password>
    <replica>
        <host>example01-1</host>
        <priority>1</priority>
    </replica>
    <replica>
        <host>example01-2</host>
        <priority>2</priority>
    </replica>
    <db>db_name</db>
    <table>table_name</table>
    <where>id=10</where>
    <invalidate_query>SQL_QUERY</invalidate_query>
</postgresql>
</source>

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 │
└────────────────┴──────┴────────┘

Using Non-default Schema:

postgres=# CREATE SCHEMA "nice.schema";

postgres=# CREATE TABLE "nice.schema"."nice.table" (a integer);

postgres=# INSERT INTO "nice.schema"."nice.table" SELECT i FROM generate_series(0, 99) as t(i)
CREATE TABLE pg_table_schema_with_dots (a UInt32)
        ENGINE PostgreSQL('localhost:5432', 'clickhouse', 'nice.table', 'postgrsql_user', 'password', 'nice.schema');

See Also

Original article