ClickHouse/docs/en/engines/database-engines/materialized-postgresql.md
2021-07-25 23:33:17 +03:00

3.1 KiB

toc_priority toc_title
30 MaterializedPostgreSQL

MaterializedPostgreSQL

Creating a Database

CREATE DATABASE test_database
ENGINE = MaterializedPostgreSQL('postgres1:5432', 'postgres_database', 'postgres_user', 'postgres_password');

SELECT * FROM test_database.postgres_table;

Settings

  1. materialized_postgresql_max_block_size — Number of rows collected in memory before flushing data into table. Default: 65536.

  2. materialized_postgresql_tables_list — A comma-separated list of PostgreSQL database tables, which will be replicated via MaterializedPostgreSQL database engine. Default: empty list - means whole PostgreSQL database will be replicated.

  3. materialized_postgresql_allow_automatic_update — Allow to reload table in the background, when schema changes are detected. Default: 0 (false). DDL queries on PostgreSQL side are not replicated via ClickHouse MaterializedPostgreSQL engine, because it is not allowed with PostgreSQL logical replication protocol, but the fact of DDL changes is detected transactioanlly. In this case the default behaviour is to stop replicating those tables once DDL is detected. However, if this setting is enabled, then, instead of stopping replication of those tables, they will be reloaded in the background via database snapshot without data losses and replication will continue for them.

CREATE DATABASE test_database
ENGINE = MaterializedPostgreSQL('postgres1:5432', 'postgres_database', 'postgres_user', 'postgres_password')
SETTINGS materialized_postgresql_max_block_size = 65536,
         materialized_postgresql_tables_list = 'table1,table2,table3';

SELECT * FROM test_database.table1;

Requirements

  1. Setting wal_level to logical and max_replication_slots to at least 2 in the PostgreSQL config file.

  2. Each replicated table must have one of the following replica identity:

  • primary key (by default)

  • index

postgres# CREATE TABLE postgres_table (a Integer NOT NULL, b Integer, c Integer NOT NULL, d Integer, e Integer NOT NULL);
postgres# CREATE unique INDEX postgres_table_index on postgres_table(a, c, e);
postgres# ALTER TABLE postgres_table REPLICA IDENTITY USING INDEX postgres_table_index;

The primary key is always checked first. If it is absent, then the index, defined as replica identity index, is checked. If the index is used as a replica identity, there has to be only one such index in a table. You can check what type is used for a specific table with the following command:

postgres# SELECT CASE relreplident
          WHEN 'd' THEN 'default'
          WHEN 'n' THEN 'nothing'
          WHEN 'f' THEN 'full'
          WHEN 'i' THEN 'index'
       END AS replica_identity
FROM pg_class
WHERE oid = 'postgres_table'::regclass;

!!! warning "Warning" Replication of TOAST values is not supported. Default value for the data type will be used.