Adding Postgres blog to Postgres DB engine page cc @DanRoscigno @gingerwizard
4.8 KiB
slug | sidebar_position | sidebar_label |
---|---|---|
/en/engines/database-engines/postgresql | 40 | PostgreSQL |
PostgreSQL
Allows to connect to databases on a remote PostgreSQL server. Supports read and write operations (SELECT
and INSERT
queries) to exchange data between ClickHouse and PostgreSQL.
Gives the real-time access to table list and table structure from remote PostgreSQL with the help of SHOW TABLES
and DESCRIBE TABLE
queries.
Supports table structure modifications (ALTER TABLE ... ADD|DROP COLUMN
). If use_table_cache
parameter (see the Engine Parameters below) it set to 1
, the table structure is cached and not checked for being modified, but can be updated with DETACH
and ATTACH
queries.
Creating a Database
CREATE DATABASE test_database
ENGINE = PostgreSQL('host:port', 'database', 'user', 'password'[, `schema`, `use_table_cache`]);
Engine Parameters
host:port
— PostgreSQL server address.database
— Remote database name.user
— PostgreSQL user.password
— User password.schema
— PostgreSQL schema.use_table_cache
— Defines if the database table structure is cached or not. Optional. Default value:0
.
Data Types Support
PostgreSQL | ClickHouse |
---|---|
DATE | Date |
TIMESTAMP | DateTime |
REAL | Float32 |
DOUBLE | Float64 |
DECIMAL, NUMERIC | Decimal |
SMALLINT | Int16 |
INTEGER | Int32 |
BIGINT | Int64 |
SERIAL | UInt32 |
BIGSERIAL | UInt64 |
TEXT, CHAR | String |
INTEGER | Nullable(Int32) |
ARRAY | Array |
Examples of Use
Database in ClickHouse, exchanging data with the PostgreSQL server:
CREATE DATABASE test_database
ENGINE = PostgreSQL('postgres1:5432', 'test_database', 'postgres', 'mysecretpassword', 'schema_name',1);
SHOW DATABASES;
┌─name──────────┐
│ default │
│ test_database │
│ system │
└───────────────┘
SHOW TABLES FROM test_database;
┌─name───────┐
│ test_table │
└────────────┘
Reading data from the PostgreSQL table:
SELECT * FROM test_database.test_table;
┌─id─┬─value─┐
│ 1 │ 2 │
└────┴───────┘
Writing data to the PostgreSQL table:
INSERT INTO test_database.test_table VALUES (3,4);
SELECT * FROM test_database.test_table;
┌─int_id─┬─value─┐
│ 1 │ 2 │
│ 3 │ 4 │
└────────┴───────┘
Consider the table structure was modified in PostgreSQL:
postgre> ALTER TABLE test_table ADD COLUMN data Text
As the use_table_cache
parameter was set to 1
when the database was created, the table structure in ClickHouse was cached and therefore not modified:
DESCRIBE TABLE test_database.test_table;
┌─name───┬─type──────────────┐
│ id │ Nullable(Integer) │
│ value │ Nullable(Integer) │
└────────┴───────────────────┘
After detaching the table and attaching it again, the structure was updated:
DETACH TABLE test_database.test_table;
ATTACH TABLE test_database.test_table;
DESCRIBE TABLE test_database.test_table;
┌─name───┬─type──────────────┐
│ id │ Nullable(Integer) │
│ value │ Nullable(Integer) │
│ data │ Nullable(String) │
└────────┴───────────────────┘