├── pg_clickhouse.control ├── src ├── internal.c ├── include │ ├── internal.h │ ├── engine.h │ ├── http.h │ └── binary.hh ├── parser.c ├── shipable.c ├── http.c └── connection.c ├── test ├── sql │ ├── deparse_checks.sql │ ├── where_sub.sql │ ├── json.sql │ ├── decimal.sql │ ├── custom_casts.sql │ ├── engines.sql │ ├── binary_inserts.sql │ ├── function_pushdown.sql │ ├── binary.sql │ ├── gucs.sql │ ├── subquery_pushdown.sql │ ├── binary_queries.sql │ ├── import_schema.sql │ └── http.sql └── expected │ ├── json_2.out │ ├── where_sub.out │ ├── where_sub_1.out │ ├── deparse_checks_1.out │ ├── deparse_checks.out │ ├── result_map.txt │ ├── json.out │ ├── json_1.out │ ├── gucs.out │ ├── decimal.out │ ├── function_pushdown.out │ ├── custom_casts.out │ ├── binary_inserts_1.out │ ├── binary_inserts.out │ ├── subquery_pushdown.out │ ├── subquery_pushdown_1.out │ └── binary.out ├── Dockerfile ├── META.json ├── docker-bake.hcl ├── CHANGELOG.md ├── sql └── pg_clickhouse.sql ├── Makefile └── README.md /pg_clickhouse.control: -------------------------------------------------------------------------------- 1 | comment = 'Interfaces to query ClickHouse databases from PostgreSQL' 2 | default_version = '0.1' 3 | module_pathname = 'pg_clickhouse' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /src/internal.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | 4 | int 5 | ends_with(const char *s, const char *suffix) 6 | { 7 | size_t slen = strlen(s); 8 | size_t suffix_len = strlen(suffix); 9 | 10 | return suffix_len <= slen && !strcmp(s + slen - suffix_len, suffix); 11 | } 12 | 13 | /* 14 | * Check whether the given string matches a ClickHouse Cloud host name. 15 | */ 16 | int 17 | ch_is_cloud_host(const char *host) 18 | { 19 | if (!host) 20 | return 0; 21 | return ends_with(host, ".clickhouse.cloud") 22 | || ends_with(host, ".clickhouse-staging.com") 23 | || ends_with(host, ".clickhouse-dev.com"); 24 | } 25 | -------------------------------------------------------------------------------- /src/include/internal.h: -------------------------------------------------------------------------------- 1 | #ifndef CLICKHOUSE_INTERNAL_H 2 | #define CLICKHOUSE_INTERNAL_H 3 | 4 | #include "curl/curl.h" 5 | 6 | typedef struct ch_http_connection_t 7 | { 8 | CURL *curl; 9 | char *dbname; 10 | char *base_url; 11 | } ch_http_connection_t; 12 | 13 | typedef struct ch_binary_connection_t 14 | { 15 | void *client; 16 | void *options; 17 | char *error; 18 | } ch_binary_connection_t; 19 | 20 | /* 21 | * Check whether the given string matches a ClickHouse Cloud host name. 22 | */ 23 | extern int ch_is_cloud_host(const char *host); 24 | int ends_with(const char *s, const char *suffix); 25 | 26 | #endif /* CLICKHOUSE_INTERNAL_H */ 27 | -------------------------------------------------------------------------------- /src/include/engine.h: -------------------------------------------------------------------------------- 1 | #ifndef CLICKHOUSE_ENGINE_H 2 | #define CLICKHOUSE_ENGINE_H 3 | 4 | #include "nodes/pathnodes.h" 5 | 6 | /* 7 | * ch_connection_details defines the details for connecting to ClickHouse. 8 | */ 9 | typedef struct 10 | { 11 | char *host; 12 | int port; 13 | char *username; 14 | char *password; 15 | char *dbname; 16 | } ch_connection_details; 17 | 18 | /* 19 | * ch_query an SQL query to execute on ClickHouse. 20 | */ 21 | typedef struct 22 | { 23 | const char *sql; 24 | const List *settings; 25 | } ch_query; 26 | 27 | #define new_query(sql) {sql, chfdw_parse_options(ch_session_settings, true, false)} 28 | 29 | #endif /* CLICKHOUSE_ENGINE_H */ 30 | -------------------------------------------------------------------------------- /test/sql/deparse_checks.sql: -------------------------------------------------------------------------------- 1 | CREATE SERVER deparse_lookback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'deparse_test'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 3 | 4 | SELECT clickhouse_raw_query('drop database if exists deparse_test'); 5 | SELECT clickhouse_raw_query('create database deparse_test'); 6 | SELECT clickhouse_raw_query(' 7 | create table deparse_test.t1 (a int, b Int8) 8 | engine = MergeTree() 9 | order by a'); 10 | 11 | SELECT clickhouse_raw_query(' 12 | insert into deparse_test.t1 select number % 10, number % 10 > 5 from numbers(1, 100);'); 13 | 14 | IMPORT FOREIGN SCHEMA "deparse_test" FROM SERVER deparse_lookback INTO public; 15 | \d+ t1 16 | ALTER TABLE t1 ALTER COLUMN b SET DATA TYPE bool; 17 | 18 | EXPLAIN (VERBOSE, COSTS OFF) 19 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 20 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 21 | 22 | EXPLAIN (VERBOSE, COSTS OFF) 23 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 24 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 25 | 26 | DROP USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 27 | SELECT clickhouse_raw_query('DROP DATABASE deparse_test'); 28 | DROP SERVER deparse_lookback CASCADE; 29 | -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | ARG PG_MAJOR=18 2 | 3 | FROM postgres:$PG_MAJOR-trixie AS build 4 | 5 | WORKDIR /work 6 | COPY . . 7 | RUN apt-get update && apt-get install -y --no-install-recommends \ 8 | postgresql-server-dev-$PG_MAJOR \ 9 | libcurl4-openssl-dev \ 10 | uuid-dev \ 11 | make \ 12 | cmake \ 13 | libssl-dev \ 14 | g++ 15 | 16 | RUN make && make install DESTDIR=/dest 17 | 18 | FROM postgres:$PG_MAJOR-trixie 19 | 20 | # Install dependencies 21 | RUN apt-get update && apt-get install -y --no-install-recommends libcurl4t64 uuid \ 22 | && apt-get clean \ 23 | && rm -rf /var/cache/apt/* /var/lib/apt/lists/* 24 | 25 | # Install extension files. 26 | COPY --chmod=644 --from=build \ 27 | /dest/usr/share/postgresql/$PG_MAJOR/extension/*.* \ 28 | /usr/share/postgresql/$PG_MAJOR/extension/ 29 | 30 | # Install shared libraries. 31 | COPY --chmod=755 --from=build \ 32 | /dest/usr/lib/postgresql/$PG_MAJOR/lib/*.so* \ 33 | /usr/lib/postgresql/$PG_MAJOR/lib/ 34 | 35 | # Install bitcode files. 36 | COPY --chmod=644 --from=build \ 37 | /dest/usr/lib/postgresql/$PG_MAJOR/lib/bitcode/*.bc \ 38 | /usr/lib/postgresql/$PG_MAJOR/lib/bitcode/ 39 | COPY --chmod=644 --from=build \ 40 | /dest/usr/lib/postgresql/$PG_MAJOR/lib/bitcode/pg_clickhouse/src/*.bc \ 41 | /usr/lib/postgresql/$PG_MAJOR/lib/bitcode/pg_clickhouse/src/ 42 | -------------------------------------------------------------------------------- /test/sql/where_sub.sql: -------------------------------------------------------------------------------- 1 | CREATE SERVER where_sub_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'where_sub_test', driver 'binary'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 3 | 4 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS where_sub_test'); 5 | SELECT clickhouse_raw_query('CREATE DATABASE where_sub_test'); 6 | SELECT clickhouse_raw_query($$ 7 | CREATE TABLE where_sub_test.orders ( 8 | id Int32, 9 | date Date, 10 | class String 11 | ) ENGINE = MergeTree ORDER BY (id); 12 | $$); 13 | 14 | SELECT clickhouse_raw_query($$ 15 | CREATE TABLE where_sub_test.lines ( 16 | order_id Int32, 17 | num Int32, 18 | created_at Date, 19 | updated_at Date 20 | ) ENGINE = MergeTree ORDER BY (order_id, num); 21 | $$); 22 | 23 | CREATE SCHEMA where_sub; 24 | IMPORT FOREIGN SCHEMA "where_sub_test" FROM SERVER where_sub_loopback INTO where_sub; 25 | 26 | -- \d where_sub.orders 27 | -- \d where_sub.lines 28 | 29 | EXPLAIN (VERBOSE, COSTS OFF) 30 | SELECT class, COUNT(*) AS order_count 31 | FROM where_sub.orders 32 | WHERE date >= date '2025-07-01' 33 | AND date < date(date '2025-07-01' + interval '3month') 34 | AND EXISTS ( 35 | SELECT * FROM where_sub.lines 36 | WHERE order_id = id AND created_at < updated_at 37 | ) 38 | GROUP BY class 39 | ORDER BY class; 40 | 41 | SELECT clickhouse_raw_query('DROP DATABASE where_sub_test'); 42 | DROP USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 43 | DROP SERVER where_sub_loopback CASCADE; 44 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg_clickhouse", 3 | "abstract": "Query ClickHouse databases from PostgreSQL", 4 | "description": "Provides a Foreign Data Wrapper and other interfaces for easy and efficient access to ClickHouse databases, including pushdown of WHERE, JOIN, and aggregates expressions as well as comprehensive EXPLAIN and ANALYZE support.", 5 | "version": "0.1.1", 6 | "maintainer": "David E. Wheeler ", 7 | "license": "apache_2_0", 8 | "provides": { 9 | "pg_clickhouse": { 10 | "abstract": "Interfaces to query ClickHouse databases from Postgres", 11 | "file": "pg_clickhouse.control", 12 | "docfile": "doc/pg_clickhouse.md", 13 | "version": "0.1.1" 14 | } 15 | }, 16 | "prereqs": { 17 | "runtime": { 18 | "requires": { 19 | "PostgreSQL": "13.0.0" 20 | } 21 | } 22 | }, 23 | "no_index": { 24 | "directory": ["vendor", "test"] 25 | }, 26 | "resources": { 27 | "bugtracker": { 28 | "web": "http://github.com/clickhouse/pg_clickhouse/issues/" 29 | }, 30 | "repository": { 31 | "url": "git://github.com/clickhouse/pg_clickhouse.git", 32 | "web": "http://github.com/clickhouse/pg_clickhouse/", 33 | "type": "git" 34 | } 35 | }, 36 | "generated_by": "David E. Wheeler", 37 | "meta-spec": { 38 | "version": "1.0.0", 39 | "url": "http://pgxn.org/meta/spec.txt" 40 | }, 41 | "tags": [ 42 | "foreign data wrapper", 43 | "fdw", 44 | "clickhouse", 45 | "analytics", 46 | "external data", 47 | "pushdown", 48 | "aggregate" 49 | ] 50 | } 51 | -------------------------------------------------------------------------------- /src/include/http.h: -------------------------------------------------------------------------------- 1 | #ifndef CLICKHOUSE_HTTP_H 2 | #define CLICKHOUSE_HTTP_H 3 | 4 | #include "postgres.h" 5 | #include "nodes/pg_list.h" 6 | #include "lib/stringinfo.h" 7 | #include "engine.h" 8 | 9 | typedef struct ch_http_connection_t ch_http_connection_t; 10 | typedef struct ch_http_response_t 11 | { 12 | char *data; 13 | size_t datasize; 14 | long http_status; 15 | char query_id[37]; 16 | double pretransfer_time; 17 | double total_time; 18 | } ch_http_response_t; 19 | 20 | typedef enum 21 | { 22 | CH_CONT, 23 | CH_EOL, 24 | CH_EOF 25 | } ch_read_status; 26 | 27 | typedef struct 28 | { 29 | char *data; 30 | size_t buflen; 31 | size_t curpos; 32 | size_t maxpos; 33 | char *val; 34 | bool done; 35 | } ch_http_read_state; 36 | 37 | typedef struct 38 | { 39 | StringInfoData sql; 40 | char *sql_begin; /* beginning part of constructed sql */ 41 | List *target_attrs; /* list of target attribute numbers */ 42 | int p_nums; /* number of parameters to transmit */ 43 | ch_http_connection_t *conn; 44 | } ch_http_insert_state; 45 | 46 | void ch_http_init(int verbose, uint32_t query_id_prefix); 47 | void ch_http_set_progress_func(void *progressfunc); 48 | ch_http_connection_t *ch_http_connection(ch_connection_details * details); 49 | void ch_http_close(ch_http_connection_t * conn); 50 | ch_http_response_t *ch_http_simple_query(ch_http_connection_t * conn, const ch_query *query); 51 | char *ch_http_last_error(void); 52 | 53 | /* read */ 54 | void ch_http_read_state_init(ch_http_read_state * state, char *data, size_t datalen); 55 | void ch_http_read_state_free(ch_http_read_state * state); 56 | int ch_http_read_next(ch_http_read_state * state); 57 | void ch_http_response_free(ch_http_response_t * resp); 58 | 59 | #endif /* CLICKHOUSE_HTTP_H */ 60 | -------------------------------------------------------------------------------- /test/sql/json.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'binary'); 3 | CREATE SERVER http_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 6 | 7 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS json_test'); 8 | SELECT clickhouse_raw_query('CREATE DATABASE json_test'); 9 | SELECT clickhouse_raw_query($$ 10 | CREATE TABLE json_test.things ( 11 | id Int32 NOT NULL, 12 | data JSON NOT NULL 13 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 14 | $$); 15 | 16 | CREATE SCHEMA json_bin; 17 | CREATE SCHEMA json_http; 18 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER binary_json_loopback INTO json_bin; 19 | \d json_bin.things 20 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER http_json_loopback INTO json_http; 21 | \d json_http.things 22 | 23 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 24 | INSERT INTO json_bin.things VALUES 25 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 26 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}') 27 | ; 28 | 29 | INSERT INTO json_http.things VALUES 30 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 31 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}'), 32 | (3, '{"id": 3, "name": "gizmo", "size": "medium", "stocked": true}'), 33 | (4, '{"id": 4, "name": "doodad", "size": "large", "stocked": false}') 34 | ; 35 | 36 | SELECT * FROM json_bin.things ORDER BY id; 37 | SELECT * FROM json_http.things ORDER BY id; 38 | 39 | SELECT clickhouse_raw_query('DROP DATABASE json_test'); 40 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 41 | DROP USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 42 | DROP SERVER binary_json_loopback CASCADE; 43 | DROP SERVER http_json_loopback CASCADE; 44 | -------------------------------------------------------------------------------- /test/sql/decimal.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_decimal_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'decimal_test', driver 'binary'); 3 | CREATE SERVER http_decimal_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'decimal_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_decimal_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_decimal_loopback; 6 | 7 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS decimal_test'); 8 | SELECT clickhouse_raw_query('CREATE DATABASE decimal_test'); 9 | SELECT clickhouse_raw_query($$ 10 | CREATE TABLE decimal_test.decimals ( 11 | id Int32 NOT NULL, 12 | dec Decimal(8, 0) NOT NULL, 13 | dec32 Decimal32(4) NOT NULL, 14 | dec64 Decimal64(6) NOT NULL, 15 | dec128 Decimal128(8) NOT NULL 16 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 17 | $$); 18 | 19 | CREATE SCHEMA dec_bin; 20 | CREATE SCHEMA dec_http; 21 | IMPORT FOREIGN SCHEMA "decimal_test" FROM SERVER binary_decimal_loopback INTO dec_bin; 22 | \d dec_bin.decimals 23 | IMPORT FOREIGN SCHEMA "decimal_test" FROM SERVER http_decimal_loopback INTO dec_http; 24 | \d dec_http.decimals 25 | 26 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 27 | INSERT INTO dec_bin.decimals (id, dec, dec32, dec64, dec128) VALUES 28 | (1, 42::NUMERIC, 98.6::NUMERIC, 102.4::NUMERIC, 1024.003::NUMERIC), 29 | (2, 9999, 9999.9999, 9999999.999999, 99999999999.99999999), 30 | (3, -9999, -9999.9999, -9999999.999999, -99999999999.99999999) 31 | ; 32 | 33 | INSERT INTO dec_http.decimals VALUES 34 | (4, 1000000::NUMERIC, 10000::NUMERIC, 3000000000::NUMERIC, 400000000000::NUMERIC), 35 | (5, -1, -0.0001, -0.000001, -0.00000001), 36 | (6, 0, 0, 0, 0) 37 | ; 38 | 39 | SELECT * FROM dec_bin.decimals ORDER BY id; 40 | SELECT * FROM dec_http.decimals ORDER BY id; 41 | 42 | SELECT clickhouse_raw_query('DROP DATABASE decimal_test'); 43 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_decimal_loopback; 44 | DROP USER MAPPING FOR CURRENT_USER SERVER http_decimal_loopback; 45 | DROP SERVER binary_decimal_loopback CASCADE; 46 | DROP SERVER http_decimal_loopback CASCADE; 47 | -------------------------------------------------------------------------------- /src/parser.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | #include 4 | #include 5 | #include 6 | #include 7 | 8 | #include 9 | #include 10 | 11 | void 12 | ch_http_read_state_init(ch_http_read_state * state, char *data, size_t datalen) 13 | { 14 | state->data = datalen > 0 ? data : NULL; 15 | state->maxpos = datalen - 1; 16 | state->buflen = 1024; 17 | state->val = malloc(state->buflen); 18 | state->done = false; 19 | } 20 | 21 | void 22 | ch_http_read_state_free(ch_http_read_state * state) 23 | { 24 | free(state->val); 25 | } 26 | 27 | int 28 | ch_http_read_next(ch_http_read_state * state) 29 | { 30 | size_t pos = state->curpos, 31 | len = 0; 32 | char *data = state->data; 33 | 34 | state->val[0] = '\0'; 35 | if (state->done) 36 | return CH_EOF; 37 | 38 | while (pos < state->maxpos && data[pos] != '\t' && data[pos] != '\n') 39 | { 40 | if (data[pos] == '\\') 41 | { 42 | /* unescape some sequences */ 43 | switch (data[pos + 1]) 44 | { 45 | case '\\': 46 | state->val[len] = '\\'; 47 | break; 48 | case '\'': 49 | state->val[len] = '\''; 50 | break; 51 | case 'n': 52 | state->val[len] = '\n'; 53 | break; 54 | case 't': 55 | state->val[len] = '\t'; 56 | break; 57 | case '0': 58 | state->val[len] = '\0'; 59 | break; 60 | case 'r': 61 | state->val[len] = '\r'; 62 | break; 63 | case 'b': 64 | state->val[len] = '\b'; 65 | break; 66 | case 'f': 67 | state->val[len] = '\f'; 68 | break; 69 | default: 70 | goto copy; 71 | } 72 | len++; 73 | pos += 2; 74 | } 75 | else 76 | copy: 77 | state->val[len++] = data[pos++]; 78 | 79 | /* extend the value size if needed */ 80 | if (len == state->buflen) 81 | { 82 | state->buflen *= 2; 83 | state->val = realloc(state->val, state->buflen); 84 | } 85 | } 86 | 87 | state->val[len] = '\0'; 88 | state->curpos = pos + 1; 89 | 90 | if (data[pos] == '\t') 91 | return CH_CONT; 92 | 93 | assert(data[pos] == '\n'); 94 | int res = pos < state->maxpos ? CH_EOL : CH_EOF; 95 | 96 | state->done = (res == CH_EOF); 97 | 98 | return res; 99 | } 100 | -------------------------------------------------------------------------------- /test/sql/custom_casts.sql: -------------------------------------------------------------------------------- 1 | CREATE SERVER casts_loopback FOREIGN DATA WRAPPER clickhouse_fdw 2 | OPTIONS(dbname 'casts_test', driver 'binary'); 3 | CREATE USER MAPPING FOR CURRENT_USER SERVER casts_loopback; 4 | 5 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS casts_test'); 6 | SELECT clickhouse_raw_query('CREATE DATABASE casts_test'); 7 | 8 | SELECT clickhouse_raw_query($$ 9 | CREATE TABLE casts_test.things ( 10 | num integer, 11 | name text 12 | ) ENGINE = MergeTree ORDER BY (num); 13 | $$); 14 | 15 | SELECT clickhouse_raw_query($$ 16 | INSERT INTO casts_test.things 17 | SELECT number, toString(number) 18 | FROM numbers(10); 19 | $$); 20 | 21 | IMPORT FOREIGN SCHEMA casts_test FROM SERVER casts_loopback INTO public; 22 | 23 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUInt8(num) IN (8, 3, 5); 24 | SELECT num FROM things WHERE toUInt8(num) IN (8, 3, 5); 25 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUInt8(name) IN (1, 2, 3); 26 | SELECT num FROM things WHERE toUInt8(name) IN (1, 2, 3); 27 | 28 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint16(num) IN (8, 3, 5); 29 | SELECT num FROM things WHERE toUint16(num) IN (8, 3, 5); 30 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint16(name) IN (1, 2, 3); 31 | SELECT num FROM things WHERE toUint16(name) IN (1, 2, 3); 32 | 33 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint32(num) IN (8, 3, 5); 34 | SELECT num FROM things WHERE toUint32(num) IN (8, 3, 5); 35 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint32(name) IN (1, 2, 3); 36 | SELECT num FROM things WHERE toUint32(name) IN (1, 2, 3); 37 | 38 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint64(num) IN (8, 3, 5); 39 | SELECT num FROM things WHERE toUint64(num) IN (8, 3, 5); 40 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint64(name) IN (1, 2, 3); 41 | SELECT num FROM things WHERE toUint64(name) IN (1, 2, 3); 42 | 43 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint128(num) IN (8, 3, 5); 44 | SELECT num FROM things WHERE toUint128(num) IN (8, 3, 5); 45 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint128(name) IN (1, 2, 3); 46 | SELECT num FROM things WHERE toUint128(name) IN (1, 2, 3); 47 | 48 | DROP USER MAPPING FOR CURRENT_USER SERVER casts_loopback; 49 | SELECT clickhouse_raw_query('DROP DATABASE casts_test'); 50 | DROP SERVER casts_loopback CASCADE; 51 | -------------------------------------------------------------------------------- /docker-bake.hcl: -------------------------------------------------------------------------------- 1 | # Variables to be specified externally. 2 | variable "registry" { 3 | default = "ghcr.io/clickhouse" 4 | description = "The image registry." 5 | } 6 | 7 | variable "version" { 8 | default = "" 9 | description = "The release version." 10 | } 11 | 12 | variable "revision" { 13 | default = "" 14 | description = "The current Git commit SHA." 15 | } 16 | 17 | # Postgres versions to build. Pass comma-delimited list: pg_versions=18,16. 18 | variable "pg_versions" { 19 | type = list(number) 20 | default = [18, 17, 16, 15, 14, 13] 21 | } 22 | 23 | # Values to use in the targets. 24 | now = timestamp() 25 | authors = "David E. Wheeler" 26 | url = "https://github.com/ClickHouse/pg_clickhouse" 27 | 28 | target "default" { 29 | platforms = ["linux/amd64", "linux/arm64"] 30 | matrix = { 31 | pgv = pg_versions 32 | } 33 | name = "pg_clickhouse-${pgv}" 34 | context = "." 35 | args = { 36 | PG_MAJOR = "${pgv}" 37 | } 38 | tags = [ 39 | "${registry}/pg_clickhouse:${pgv}", 40 | "${registry}/pg_clickhouse:${pgv}-${version}", 41 | ] 42 | annotations = [ 43 | "index,manifest:org.opencontainers.image.created=${now}", 44 | "index,manifest:org.opencontainers.image.url=${url}", 45 | "index,manifest:org.opencontainers.image.source=${url}", 46 | "index,manifest:org.opencontainers.image.version=${pgv}-${version}", 47 | "index,manifest:org.opencontainers.image.revision=${revision}", 48 | "index,manifest:org.opencontainers.image.vendor=${authors}", 49 | "index,manifest:org.opencontainers.image.title=PostgreSQL with pg_clickhouse", 50 | "index,manifest:org.opencontainers.image.description=PostgreSQL ${pgv} with pg_clickhouse ${version}", 51 | "index,manifest:org.opencontainers.image.documentation=${url}", 52 | "index,manifest:org.opencontainers.image.authors=${authors}", 53 | "index,manifest:org.opencontainers.image.licenses=PostgreSQL AND Apache-2.0", 54 | "index,manifest:org.opencontainers.image.base.name=postgres", 55 | ] 56 | labels = { 57 | "org.opencontainers.image.created" = "${now}", 58 | "org.opencontainers.image.url" = "${url}", 59 | "org.opencontainers.image.source" = "${url}", 60 | "org.opencontainers.image.version" = "${pgv}-${version}", 61 | "org.opencontainers.image.revision" = "${revision}", 62 | "org.opencontainers.image.vendor" = "${authors}", 63 | "org.opencontainers.image.title" = "PostgreSQL with pg_clickhouse", 64 | "org.opencontainers.image.description" = "PostgreSQL ${pgv} with pg_clickhouse ${version}", 65 | "org.opencontainers.image.documentation" = "${url}", 66 | "org.opencontainers.image.authors" = "${authors}", 67 | "org.opencontainers.image.licenses" = "PostgreSQL AND Apache-2.0" 68 | "org.opencontainers.image.base.name" = "scratch", 69 | } 70 | } 71 | -------------------------------------------------------------------------------- /test/expected/json_2.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'binary'); 3 | CREATE SERVER http_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS json_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE json_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | SELECT clickhouse_raw_query($$ 19 | CREATE TABLE json_test.things ( 20 | id Int32 NOT NULL, 21 | data JSON NOT NULL 22 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 23 | $$); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | CREATE SCHEMA json_bin; 30 | CREATE SCHEMA json_http; 31 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER binary_json_loopback INTO json_bin; 32 | ERROR: pg_clickhouse: could not map things.data type <'json')> 33 | \d json_bin.things 34 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER http_json_loopback INTO json_http; 35 | ERROR: pg_clickhouse: could not map things.data type <'json')> 36 | \d json_http.things 37 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 38 | INSERT INTO json_bin.things VALUES 39 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 40 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}') 41 | ; 42 | ERROR: relation "json_bin.things" does not exist 43 | LINE 1: INSERT INTO json_bin.things VALUES 44 | ^ 45 | INSERT INTO json_http.things VALUES 46 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 47 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}'), 48 | (3, '{"id": 3, "name": "gizmo", "size": "medium", "stocked": true}'), 49 | (4, '{"id": 4, "name": "doodad", "size": "large", "stocked": false}') 50 | ; 51 | ERROR: relation "json_http.things" does not exist 52 | LINE 1: INSERT INTO json_http.things VALUES 53 | ^ 54 | SELECT * FROM json_bin.things ORDER BY id; 55 | ERROR: relation "json_bin.things" does not exist 56 | LINE 1: SELECT * FROM json_bin.things ORDER BY id; 57 | ^ 58 | SELECT * FROM json_http.things ORDER BY id; 59 | ERROR: relation "json_http.things" does not exist 60 | LINE 1: SELECT * FROM json_http.things ORDER BY id; 61 | ^ 62 | SELECT clickhouse_raw_query('DROP DATABASE json_test'); 63 | clickhouse_raw_query 64 | ---------------------- 65 | 66 | (1 row) 67 | 68 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 69 | DROP USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 70 | DROP SERVER binary_json_loopback CASCADE; 71 | DROP SERVER http_json_loopback CASCADE; 72 | -------------------------------------------------------------------------------- /test/expected/where_sub.out: -------------------------------------------------------------------------------- 1 | CREATE SERVER where_sub_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'where_sub_test', driver 'binary'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 3 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS where_sub_test'); 4 | clickhouse_raw_query 5 | ---------------------- 6 | 7 | (1 row) 8 | 9 | SELECT clickhouse_raw_query('CREATE DATABASE where_sub_test'); 10 | clickhouse_raw_query 11 | ---------------------- 12 | 13 | (1 row) 14 | 15 | SELECT clickhouse_raw_query($$ 16 | CREATE TABLE where_sub_test.orders ( 17 | id Int32, 18 | date Date, 19 | class String 20 | ) ENGINE = MergeTree ORDER BY (id); 21 | $$); 22 | clickhouse_raw_query 23 | ---------------------- 24 | 25 | (1 row) 26 | 27 | SELECT clickhouse_raw_query($$ 28 | CREATE TABLE where_sub_test.lines ( 29 | order_id Int32, 30 | num Int32, 31 | created_at Date, 32 | updated_at Date 33 | ) ENGINE = MergeTree ORDER BY (order_id, num); 34 | $$); 35 | clickhouse_raw_query 36 | ---------------------- 37 | 38 | (1 row) 39 | 40 | CREATE SCHEMA where_sub; 41 | IMPORT FOREIGN SCHEMA "where_sub_test" FROM SERVER where_sub_loopback INTO where_sub; 42 | -- \d where_sub.orders 43 | -- \d where_sub.lines 44 | EXPLAIN (VERBOSE, COSTS OFF) 45 | SELECT class, COUNT(*) AS order_count 46 | FROM where_sub.orders 47 | WHERE date >= date '2025-07-01' 48 | AND date < date(date '2025-07-01' + interval '3month') 49 | AND EXISTS ( 50 | SELECT * FROM where_sub.lines 51 | WHERE order_id = id AND created_at < updated_at 52 | ) 53 | GROUP BY class 54 | ORDER BY class; 55 | QUERY PLAN 56 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 57 | Foreign Scan 58 | Output: orders.class, (count(*)) 59 | Relations: Aggregate on ((orders) LEFT SEMI JOIN (lines)) 60 | Remote SQL: SELECT r1.class, count(*) FROM where_sub_test.orders r1 LEFT SEMI JOIN where_sub_test.lines r3 ON (((r3.created_at < r3.updated_at)) AND ((r1.id = r3.order_id))) WHERE ((r1.date >= '07-01-2025')) AND ((r1.date < '10-01-2025')) GROUP BY r1.class ORDER BY r1.class ASC NULLS LAST 61 | (4 rows) 62 | 63 | SELECT clickhouse_raw_query('DROP DATABASE where_sub_test'); 64 | clickhouse_raw_query 65 | ---------------------- 66 | 67 | (1 row) 68 | 69 | DROP USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 70 | DROP SERVER where_sub_loopback CASCADE; 71 | NOTICE: drop cascades to 2 other objects 72 | DETAIL: drop cascades to foreign table where_sub.lines 73 | drop cascades to foreign table where_sub.orders 74 | -------------------------------------------------------------------------------- /test/expected/where_sub_1.out: -------------------------------------------------------------------------------- 1 | CREATE SERVER where_sub_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'where_sub_test', driver 'binary'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 3 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS where_sub_test'); 4 | clickhouse_raw_query 5 | ---------------------- 6 | 7 | (1 row) 8 | 9 | SELECT clickhouse_raw_query('CREATE DATABASE where_sub_test'); 10 | clickhouse_raw_query 11 | ---------------------- 12 | 13 | (1 row) 14 | 15 | SELECT clickhouse_raw_query($$ 16 | CREATE TABLE where_sub_test.orders ( 17 | id Int32, 18 | date Date, 19 | class String 20 | ) ENGINE = MergeTree ORDER BY (id); 21 | $$); 22 | clickhouse_raw_query 23 | ---------------------- 24 | 25 | (1 row) 26 | 27 | SELECT clickhouse_raw_query($$ 28 | CREATE TABLE where_sub_test.lines ( 29 | order_id Int32, 30 | num Int32, 31 | created_at Date, 32 | updated_at Date 33 | ) ENGINE = MergeTree ORDER BY (order_id, num); 34 | $$); 35 | clickhouse_raw_query 36 | ---------------------- 37 | 38 | (1 row) 39 | 40 | CREATE SCHEMA where_sub; 41 | IMPORT FOREIGN SCHEMA "where_sub_test" FROM SERVER where_sub_loopback INTO where_sub; 42 | -- \d where_sub.orders 43 | -- \d where_sub.lines 44 | EXPLAIN (VERBOSE, COSTS OFF) 45 | SELECT class, COUNT(*) AS order_count 46 | FROM where_sub.orders 47 | WHERE date >= date '2025-07-01' 48 | AND date < date(date '2025-07-01' + interval '3month') 49 | AND EXISTS ( 50 | SELECT * FROM where_sub.lines 51 | WHERE order_id = id AND created_at < updated_at 52 | ) 53 | GROUP BY class 54 | ORDER BY class; 55 | QUERY PLAN 56 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 57 | Foreign Scan 58 | Output: orders.class, (count(*)) 59 | Relations: Aggregate on ((orders) LEFT SEMI JOIN (lines)) 60 | Remote SQL: SELECT r1.class, count(*) FROM where_sub_test.orders r1 LEFT SEMI JOIN where_sub_test.lines r2 ON (((r2.created_at < r2.updated_at)) AND ((r1.id = r2.order_id))) WHERE ((r1.date >= '07-01-2025')) AND ((r1.date < '10-01-2025')) GROUP BY r1.class ORDER BY r1.class ASC NULLS LAST 61 | (4 rows) 62 | 63 | SELECT clickhouse_raw_query('DROP DATABASE where_sub_test'); 64 | clickhouse_raw_query 65 | ---------------------- 66 | 67 | (1 row) 68 | 69 | DROP USER MAPPING FOR CURRENT_USER SERVER where_sub_loopback; 70 | DROP SERVER where_sub_loopback CASCADE; 71 | NOTICE: drop cascades to 2 other objects 72 | DETAIL: drop cascades to foreign table where_sub.lines 73 | drop cascades to foreign table where_sub.orders 74 | -------------------------------------------------------------------------------- /test/sql/engines.sql: -------------------------------------------------------------------------------- 1 | CREATE SERVER engines_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'engines_test'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER engines_loopback; 3 | 4 | SELECT clickhouse_raw_query('drop database if exists engines_test'); 5 | SELECT clickhouse_raw_query('create database engines_test'); 6 | SELECT clickhouse_raw_query(' 7 | create table engines_test.t1 (a int, b int) 8 | engine = MergeTree() 9 | order by a'); 10 | 11 | SELECT clickhouse_raw_query(' 12 | create table engines_test.t2 (a int, b AggregateFunction(sum, Int32)) 13 | engine = AggregatingMergeTree() 14 | order by a'); 15 | 16 | SELECT clickhouse_raw_query(' 17 | create table engines_test.t3 (a int, b Array(Int32), c Array(Int32)) 18 | engine = MergeTree() 19 | order by a'); 20 | 21 | SELECT clickhouse_raw_query(' 22 | insert into engines_test.t1 select number % 10, number from numbers(1, 100);'); 23 | 24 | SELECT clickhouse_raw_query(' 25 | insert into engines_test.t2 select number % 10 as a, sumState(toInt32(number)) as b from numbers(1, 100) group by a;'); 26 | 27 | SELECT clickhouse_raw_query(' 28 | insert into engines_test.t3 select number % 10, 29 | [1, number % 10 + 1], [1, 1] from numbers(1, 100);'); 30 | 31 | SELECT clickhouse_raw_query(' 32 | create materialized view engines_test.t1_aggr 33 | engine=AggregatingMergeTree() 34 | order by a populate as select a, sumState(b) as b from engines_test.t1 group by a;'); 35 | 36 | SELECT clickhouse_raw_query(' 37 | create materialized view engines_test.t3_aggr 38 | engine=AggregatingMergeTree() 39 | order by a populate as select a, sumMapState(b, c) as b from engines_test.t3 group by a;'); 40 | 41 | SELECT clickhouse_raw_query(' 42 | create table engines_test.t4 (a int, 43 | b AggregateFunction(sum, Int32), 44 | c AggregateFunction(sumMap, Array(Int32), Array(Int32)), 45 | d SimpleAggregateFunction(sum, Int64), 46 | e AggregateFunction(count), 47 | f AggregateFunction(quantile, Int32)) 48 | engine = AggregatingMergeTree() 49 | order by a'); 50 | 51 | IMPORT FOREIGN SCHEMA "engines_test" FROM SERVER engines_loopback INTO public; 52 | 53 | \d+ t1 54 | \d+ t1_aggr 55 | \d+ t2 56 | \d+ t3 57 | \d+ t3_aggr 58 | \d+ t4 59 | 60 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a, sum(b) FROM t1 GROUP BY a; 61 | SELECT a, sum(b) FROM t1 GROUP BY a ORDER BY a; 62 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a, sum(b) FROM t1_aggr GROUP BY a; 63 | SELECT a, sum(b) FROM t1_aggr GROUP BY a ORDER BY a; 64 | 65 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a, sum(b) FROM t2 GROUP BY a; 66 | SELECT a, sum(b) FROM t2 GROUP BY a ORDER BY a; 67 | 68 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a, percentile_cont(0.75) WITHIN GROUP (ORDER BY f) FROM t4 GROUP BY a; 69 | SELECT a, percentile_cont(0.75) WITHIN GROUP (ORDER BY f) FROM t4 GROUP BY a; 70 | 71 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a, percentile_cont(0.75) WITHIN GROUP (ORDER BY f) / sum(d) FROM t4 GROUP BY a; 72 | SELECT a, percentile_cont(0.75) WITHIN GROUP (ORDER BY f) / sum(d) FROM t4 GROUP BY a; 73 | 74 | DROP USER MAPPING FOR CURRENT_USER SERVER engines_loopback; 75 | SELECT clickhouse_raw_query('DROP DATABASE engines_test'); 76 | DROP SERVER engines_loopback CASCADE; 77 | -------------------------------------------------------------------------------- /src/include/binary.hh: -------------------------------------------------------------------------------- 1 | #ifndef CLICKHOUSE_BINARY_H 2 | #define CLICKHOUSE_BINARY_H 3 | 4 | #include "engine.h" 5 | 6 | #ifdef __cplusplus 7 | extern "C" 8 | { 9 | #endif 10 | 11 | typedef struct ch_binary_connection_t ch_binary_connection_t; 12 | typedef struct ch_insert_block_h ch_insert_block_h; 13 | typedef struct ch_binary_response_t 14 | { 15 | void *values; 16 | size_t columns_count; 17 | size_t blocks_count; 18 | char *error; 19 | bool success; 20 | } ch_binary_response_t; 21 | 22 | typedef struct 23 | { 24 | ch_binary_response_t *resp; 25 | Oid *coltypes; 26 | Datum *values; 27 | bool *nulls; 28 | 29 | size_t block; /* current block */ 30 | size_t row; /* row in current block */ 31 | void *gc; /* allocated objects while reading */ 32 | char *error; 33 | bool done; 34 | } ch_binary_read_state_t; 35 | 36 | typedef struct 37 | { 38 | Datum *datums; 39 | bool *nulls; 40 | size_t len; 41 | Oid *types; 42 | } ch_binary_tuple_t; 43 | 44 | typedef struct 45 | { 46 | Datum *datums; 47 | bool *nulls; 48 | size_t len; 49 | Oid item_type; /* used on selects */ 50 | Oid array_type; /* used on selects */ 51 | } ch_binary_array_t; 52 | 53 | typedef struct 54 | { 55 | MemoryContext memcxt; /* used for cleanup */ 56 | MemoryContextCallback callback; 57 | 58 | TupleDesc outdesc; 59 | ch_insert_block_h *insert_block; /* clickhouse::Block */ 60 | size_t len; 61 | void *conversion_states; 62 | char *table_name; 63 | 64 | Datum *values; 65 | bool *nulls; 66 | bool success; 67 | 68 | ch_binary_connection_t *conn; 69 | } ch_binary_insert_state; 70 | 71 | extern ch_binary_connection_t * ch_binary_connect(ch_connection_details * details, char **error); 72 | extern void ch_binary_close(ch_binary_connection_t * conn); 73 | extern ch_binary_response_t * ch_binary_simple_query(ch_binary_connection_t * conn, 74 | const ch_query * query, bool (*check_cancel) (void)); 75 | extern void ch_binary_response_free(ch_binary_response_t * resp); 76 | 77 | /* reading */ 78 | void ch_binary_read_state_init(ch_binary_read_state_t * state, ch_binary_response_t * resp); 79 | void ch_binary_read_state_free(ch_binary_read_state_t * state); 80 | bool ch_binary_read_row(ch_binary_read_state_t * state); 81 | Datum ch_binary_convert_datum(void *state, Datum val); 82 | void *ch_binary_init_convert_state(Datum val, Oid intype, Oid outtype); 83 | void ch_binary_free_convert_state(void *); 84 | 85 | /* insertion */ 86 | void ch_binary_prepare_insert(void *conn, const ch_query * query, 87 | ch_binary_insert_state * state); 88 | void ch_binary_insert_columns(ch_binary_insert_state * state); 89 | void ch_binary_column_append_data(ch_binary_insert_state * state, size_t colidx); 90 | void *ch_binary_make_tuple_map(TupleDesc indesc, TupleDesc outdesc); 91 | void ch_binary_insert_state_free(void *c); 92 | void ch_binary_do_output_convertion(ch_binary_insert_state * insert_state, 93 | TupleTableSlot * slot); 94 | 95 | #ifdef __cplusplus 96 | } 97 | #endif 98 | 99 | #endif /* CLICKHOUSE_BINARY_H */ 100 | -------------------------------------------------------------------------------- /test/expected/deparse_checks_1.out: -------------------------------------------------------------------------------- 1 | CREATE SERVER deparse_lookback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'deparse_test'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 3 | SELECT clickhouse_raw_query('drop database if exists deparse_test'); 4 | clickhouse_raw_query 5 | ---------------------- 6 | 7 | (1 row) 8 | 9 | SELECT clickhouse_raw_query('create database deparse_test'); 10 | clickhouse_raw_query 11 | ---------------------- 12 | 13 | (1 row) 14 | 15 | SELECT clickhouse_raw_query(' 16 | create table deparse_test.t1 (a int, b Int8) 17 | engine = MergeTree() 18 | order by a'); 19 | clickhouse_raw_query 20 | ---------------------- 21 | 22 | (1 row) 23 | 24 | SELECT clickhouse_raw_query(' 25 | insert into deparse_test.t1 select number % 10, number % 10 > 5 from numbers(1, 100);'); 26 | clickhouse_raw_query 27 | ---------------------- 28 | 29 | (1 row) 30 | 31 | IMPORT FOREIGN SCHEMA "deparse_test" FROM SERVER deparse_lookback INTO public; 32 | \d+ t1 33 | Foreign table "public.t1" 34 | Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description 35 | --------+----------+-----------+----------+---------+-------------+---------+--------------+------------- 36 | a | integer | | not null | | | plain | | 37 | b | smallint | | not null | | | plain | | 38 | Server: deparse_lookback 39 | FDW options: (database 'deparse_test', table_name 't1', engine 'MergeTree') 40 | 41 | ALTER TABLE t1 ALTER COLUMN b SET DATA TYPE bool; 42 | EXPLAIN (VERBOSE, COSTS OFF) 43 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 44 | QUERY PLAN 45 | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------- 46 | Foreign Scan 47 | Output: (CASE WHEN b THEN 1 ELSE 2 END), (max(a)) 48 | Relations: Aggregate on (t1) 49 | Remote SQL: SELECT CASE WHEN b = 1 THEN toInt32(1) ELSE toInt32(2) END, max(a) FROM deparse_test.t1 GROUP BY (CASE WHEN b = 1 THEN toInt32(1) ELSE toInt32(2) END) 50 | (4 rows) 51 | 52 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 53 | g1 | max 54 | ----+----- 55 | 2 | 5 56 | 1 | 9 57 | (2 rows) 58 | 59 | EXPLAIN (VERBOSE, COSTS OFF) 60 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 61 | QUERY PLAN 62 | ----------------------------------------------------------------------------------------------------- 63 | Foreign Scan on public.t1 64 | Output: a, b 65 | Remote SQL: SELECT a, b FROM deparse_test.t1 ORDER BY a ASC NULLS FIRST, b ASC NULLS LAST LIMIT 3 66 | (3 rows) 67 | 68 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 69 | a | b 70 | ---+--- 71 | 0 | f 72 | 0 | f 73 | 0 | f 74 | (3 rows) 75 | 76 | DROP USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 77 | SELECT clickhouse_raw_query('DROP DATABASE deparse_test'); 78 | clickhouse_raw_query 79 | ---------------------- 80 | 81 | (1 row) 82 | 83 | DROP SERVER deparse_lookback CASCADE; 84 | NOTICE: drop cascades to foreign table t1 85 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Changelog 2 | 3 | All notable changes to this project will be documented in this file. It uses the 4 | [Keep a Changelog] format, and this project adheres to [Semantic Versioning]. 5 | 6 | [Keep a Changelog]: https://keepachangelog.com/en/1.1.0/ 7 | [Semantic Versioning]: https://semver.org/spec/v2.0.0.html 8 | "Semantic Versioning 2.0.0" 9 | 10 | ## [v0.1.1] — Not Yet Released 11 | 12 | 13 | [v0.1.1]: https://github.com/clickhouse/pg_clickhouse/compare/v0.1.0...v0.1.1 14 | 15 | ## [v0.1.0] — 2025-12-09 16 | 17 | ### ⚡ Improvements 18 | 19 | * Improved function and aggregate pushdown 20 | * Added TLS support to both the http and binary engines 21 | * Added pushdown aggregate functions: 22 | * `uniq()` 23 | * `uniqExact()` 24 | * `uniqCombined()` 25 | * `uniqCombined64()` 26 | * `uniqExact()` 27 | * `uniqHLL12()` 28 | * `uniqTheta()` 29 | * Added pushdown functions: 30 | * `toUInt8()` 31 | * `toUInt16()` 32 | * `toUInt32()` 33 | * `toUInt64()` 34 | * `toUInt128()` 35 | * `quantile()` 36 | * `quantileExact()` 37 | * Mapped PostgreSQL `regexp_like()` to push down to ClickHouse `match()` 38 | function 39 | * Mapped PostgreSQL `extract()` to push down to equivalent ClickHouse 40 | DateTime extraction functions (already mapped to `date_part()`) 41 | * Mapped PostgreSQL `percentile_cont()` ordered set aggregate function to 42 | push down to ClickHouse `quantile()` parametrized 43 | * Mapped the `COUNT()` return value to `bigint` 44 | * Added the query text and, for the http engine, the status code to error 45 | messages 46 | * Added `pg_clickhouse.session_settings` GUC, defaulting to 47 | `join_use_nulls 1, group_by_use_nulls 1, final 1` 48 | * Added mappings and support for additional data types: 49 | * `Bool` => `boolean` 50 | * `Decimal` => `numeric` 51 | * `JSON` => `jsonb` (http engine only) 52 | * Added the `dbname` option to http engine connections, including 53 | `clickhouse_raw_query()` 54 | * Added LEFT SEMI JOIN pushdown for `EXISTS()` subqueries 55 | 56 | ### 🏗️ Build Setup 57 | 58 | * Ported from clickhouse_fdw 59 | * Made lots of general code cleanup 60 | * Added PGXS build pipeline 61 | * Added PGXN and GitHub release workflows 62 | * Added `pg_clickhouse` OCI image workflow that publishes to 63 | ghcr.io/clickhouse/pg_clickhouse, with tags for PostgreSQL versions 13-18 64 | 65 | ### 📚 Documentation 66 | 67 | * Added tutorial in [doc/tutorial.md](doc/tutorial.md) 68 | * Added reference documentation in [doc/pg_clickhouse.md](doc/pg_clickhouse.md) 69 | 70 | ### 🪲 Bug Fixes 71 | 72 | * Fixed `dictGet()`, `argMin()`, and `argMax()` 73 | * Fixed bug in filtered `COUNT()` 74 | * Fixed `AggregateFunction` option to propagate to a nested aggregate 75 | function call 76 | * Improved unsigned integer support 77 | 78 | ### ⬆️ Dependency Updates 79 | 80 | * Updated vendored clickhouse-cpp library 81 | * Reimplemented binary engine inserts with clickhouse-cpp improvements 82 | * Support and tested against PostgreSQL 13-18 83 | * Support and tested against ClickHouse 23-25 84 | 85 | ### 📔 Notes 86 | 87 | * Set full version in `PG_MODULE_MAGIC_EXT` 88 | * Set to default ports to TLS for ClickHouse Cloud host names 89 | 90 | [v0.1.0]: https://github.com/clickhouse/pg_clickhouse/compare/a1487bd...v0.1.0 91 | [RFC 9535]: https://www.rfc-editor.org/rfc/rfc9535.html 92 | "RFC 9535 JSONPath: Query Expressions for JSON" 93 | -------------------------------------------------------------------------------- /test/expected/deparse_checks.out: -------------------------------------------------------------------------------- 1 | CREATE SERVER deparse_lookback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'deparse_test'); 2 | CREATE USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 3 | SELECT clickhouse_raw_query('drop database if exists deparse_test'); 4 | clickhouse_raw_query 5 | ---------------------- 6 | 7 | (1 row) 8 | 9 | SELECT clickhouse_raw_query('create database deparse_test'); 10 | clickhouse_raw_query 11 | ---------------------- 12 | 13 | (1 row) 14 | 15 | SELECT clickhouse_raw_query(' 16 | create table deparse_test.t1 (a int, b Int8) 17 | engine = MergeTree() 18 | order by a'); 19 | clickhouse_raw_query 20 | ---------------------- 21 | 22 | (1 row) 23 | 24 | SELECT clickhouse_raw_query(' 25 | insert into deparse_test.t1 select number % 10, number % 10 > 5 from numbers(1, 100);'); 26 | clickhouse_raw_query 27 | ---------------------- 28 | 29 | (1 row) 30 | 31 | IMPORT FOREIGN SCHEMA "deparse_test" FROM SERVER deparse_lookback INTO public; 32 | \d+ t1 33 | Foreign table "public.t1" 34 | Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description 35 | --------+----------+-----------+----------+---------+-------------+---------+--------------+------------- 36 | a | integer | | not null | | | plain | | 37 | b | smallint | | not null | | | plain | | 38 | Not-null constraints: 39 | "t1_a_not_null" NOT NULL "a" 40 | "t1_b_not_null" NOT NULL "b" 41 | Server: deparse_lookback 42 | FDW options: (database 'deparse_test', table_name 't1', engine 'MergeTree') 43 | 44 | ALTER TABLE t1 ALTER COLUMN b SET DATA TYPE bool; 45 | EXPLAIN (VERBOSE, COSTS OFF) 46 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 47 | QUERY PLAN 48 | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------- 49 | Foreign Scan 50 | Output: (CASE WHEN b THEN 1 ELSE 2 END), (max(a)) 51 | Relations: Aggregate on (t1) 52 | Remote SQL: SELECT CASE WHEN b = 1 THEN toInt32(1) ELSE toInt32(2) END, max(a) FROM deparse_test.t1 GROUP BY (CASE WHEN b = 1 THEN toInt32(1) ELSE toInt32(2) END) 53 | (4 rows) 54 | 55 | SELECT (CASE WHEN b THEN 1 ELSE 2 END) as g1, MAX(a) FROM t1 GROUP BY g1; 56 | g1 | max 57 | ----+----- 58 | 2 | 5 59 | 1 | 9 60 | (2 rows) 61 | 62 | EXPLAIN (VERBOSE, COSTS OFF) 63 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 64 | QUERY PLAN 65 | ----------------------------------------------------------------------------------------------------- 66 | Foreign Scan on public.t1 67 | Output: a, b 68 | Remote SQL: SELECT a, b FROM deparse_test.t1 ORDER BY a ASC NULLS FIRST, b ASC NULLS LAST LIMIT 3 69 | (3 rows) 70 | 71 | SELECT * FROM t1 ORDER BY a NULLS FIRST, b LIMIT 3; 72 | a | b 73 | ---+--- 74 | 0 | f 75 | 0 | f 76 | 0 | f 77 | (3 rows) 78 | 79 | DROP USER MAPPING FOR CURRENT_USER SERVER deparse_lookback; 80 | SELECT clickhouse_raw_query('DROP DATABASE deparse_test'); 81 | clickhouse_raw_query 82 | ---------------------- 83 | 84 | (1 row) 85 | 86 | DROP SERVER deparse_lookback CASCADE; 87 | NOTICE: drop cascades to foreign table t1 88 | -------------------------------------------------------------------------------- /test/expected/result_map.txt: -------------------------------------------------------------------------------- 1 | Test Results Map 2 | ================ 3 | 4 | Tables describing the various `*.out` files and the versions of PostgreSQL or 5 | ClickHouse they cover. 6 | 7 | * Postgres coverage run using latest ClickHouse release. 8 | * ClickHouse coverage run from PostgreSQL 18. 9 | 10 | binary_inserts.sql 11 | ------------------ 12 | 13 | Postgres | File 14 | ----------|---------------------- 15 | 18 | binary_inserts.out 16 | 13-17 | binary_inserts_1.out 17 | 18 | ClickHouse | File 19 | ------------|-------------------- 20 | 22-25 | binary_inserts.out 21 | 22 | binary_queries.sql 23 | ------------------ 24 | 25 | Postgres | File 26 | ----------|---------------------- 27 | 18 | binary_queries.out 28 | 17 | binary_queries_1.out 29 | 16 | binary_queries_2.out 30 | 13-15 | binary_queries_3.out 31 | 32 | ClickHouse | File 33 | ------------|---------------------- 34 | 25 | binary_queries.out 35 | 23-24 | binary_queries_4.out 36 | 23 | binary_queries_5.out 37 | 22 | binary_queries_6.out 38 | 39 | deparse_checks.sql 40 | ------------------ 41 | 42 | Postgres | File 43 | ----------|---------------------- 44 | 18 | deparse_checks.out 45 | 13-17 | deparse_checks_1.out 46 | 47 | ClickHouse | File 48 | ------------|-------------------- 49 | 22-25 | deparse_checks.out 50 | 51 | engines.sql 52 | ----------- 53 | 54 | Postgres | File 55 | ----------|--------------- 56 | 18 | engines.out 57 | 13-17 | engines_1.out 58 | 59 | ClickHouse | File 60 | ------------|------------- 61 | 22-25 | engines.out 62 | 63 | functions.sql 64 | ------------- 65 | 66 | Postgres | File 67 | ----------|--------------- 68 | 15-18 | functions.out 69 | 14 | functions_1.out 70 | 13 | functions_2.out 71 | 72 | ClickHouse | File 73 | ------------|--------------- 74 | 22-25 | functions.out 75 | 76 | http.sql 77 | -------- 78 | 79 | Postgres | File 80 | ----------|------------ 81 | 18 | http.out 82 | 17 | http_1.out 83 | 16 | http_2.out 84 | 13-15 | http_3.out 85 | 86 | ClickHouse | File 87 | ------------|------------ 88 | 23-25 | http.out 89 | 23 | http_4.out 90 | 22 | http_5.out 91 | 92 | import_schema.sql 93 | ----------------- 94 | 95 | Postgres | File 96 | ----------|--------------------- 97 | 18 | import_schema.out 98 | 13-17 | import_schema_1.out 99 | 100 | ClickHouse | File 101 | ------------|--------------------- 102 | 23-25 | import_schema.out 103 | 22 | import_schema_2.out 104 | 105 | json.sql 106 | -------- 107 | 108 | Postgres | File 109 | ----------|---------- 110 | 13-18 | json.out 111 | 112 | ClickHouse | File 113 | ------------|------------ 114 | 25.8+ | json.out 115 | 24.8-25.3 | json_1.out 116 | 22-24.3 | json_2.out 117 | 118 | subquery_pushdown.sql 119 | --------------------- 120 | 121 | Postgres | File 122 | ----------|------------------------- 123 | 18 | subquery_pushdown.out 124 | 13-17 | subquery_pushdown_1.out 125 | 126 | ClickHouse | File 127 | ------------|----------------------- 128 | 22-25 | subquery_pushdown.out 129 | 130 | where_sub.sql 131 | ------------- 132 | 133 | Postgres | File 134 | ----------|----------------- 135 | 18 | where_sub.out 136 | 13-17 | where_sub_1.out 137 | 138 | ClickHouse | File 139 | ------------|----------------- 140 | 22-25 | where_sub.out 141 | -------------------------------------------------------------------------------- /test/sql/binary_inserts.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_inserts_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'binary_inserts_test', driver 'binary'); 3 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 4 | 5 | SELECT clickhouse_raw_query('drop database if exists binary_inserts_test'); 6 | SELECT clickhouse_raw_query('create database binary_inserts_test'); 7 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.ints ( 8 | c1 Int8, c2 Int16, c3 Int32, c4 Int64 9 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 10 | '); 11 | 12 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.uints ( 13 | c1 UInt8, c2 UInt16, c3 UInt32, c4 UInt64, c5 Bool 14 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 15 | '); 16 | 17 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.floats ( 18 | c1 Float32, c2 Float64 19 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1) SETTINGS allow_floating_point_partition_key=1; 20 | '); 21 | 22 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( 23 | c1 Int8, c2 Nullable(Int32) 24 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 25 | '); 26 | 27 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( 28 | c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) 29 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 30 | '); 31 | 32 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.arrays ( 33 | c1 Int32, c2 Array(Int32) 34 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 35 | '); 36 | 37 | IMPORT FOREIGN SCHEMA "binary_inserts_test" FROM SERVER binary_inserts_loopback INTO public; 38 | 39 | /* ints */ 40 | INSERT INTO ints 41 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(1, 3) i; 42 | SELECT * FROM ints ORDER BY c1; 43 | INSERT INTO ints (c1, c4, c3, c2) 44 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(4, 6) i; 45 | SELECT * FROM ints ORDER BY c1; 46 | 47 | /* check dropping columns (that will change attnums) */ 48 | ALTER TABLE ints DROP COLUMN c1; 49 | ALTER TABLE ints ADD COLUMN c1 SMALLINT; 50 | INSERT INTO ints (c1, c2, c3, c4) 51 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(7, 8) i; 52 | SELECT c1, c2, c3, c4 FROM ints ORDER BY c1; 53 | 54 | /* check other number types */ 55 | INSERT INTO uints 56 | SELECT i, i + 1, i + 2, i+ 3, (i % 2)::bool FROM generate_series(1, 3) i; 57 | SELECT * FROM uints ORDER BY c1; 58 | INSERT INTO floats 59 | SELECT i * 1.1, i + 2.1 FROM generate_series(1, 3) i; 60 | SELECT * FROM floats ORDER BY c1; 61 | 62 | /* check nullable */ 63 | INSERT INTO null_ints SELECT i, case WHEN i % 2 = 0 THEN NULL ELSE i END FROM generate_series(1, 10) i; 64 | INSERT INTO null_ints(c1) SELECT i FROM generate_series(11, 13) i; 65 | SELECT * FROM null_ints ORDER BY c1; 66 | SELECT * FROM null_ints ORDER BY c1; 67 | 68 | /* check dates and strings */ 69 | ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); 70 | \d+ complex 71 | INSERT INTO complex VALUES 72 | (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), 73 | (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), 74 | (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); 75 | SELECT * FROM complex ORDER BY c1; 76 | 77 | /* check arrays */ 78 | INSERT INTO arrays VALUES 79 | (1, ARRAY[1,2]), 80 | (2, ARRAY[3,4,5]), 81 | (3, ARRAY[6,4]); 82 | SELECT * FROM arrays ORDER BY c1; 83 | 84 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 85 | SELECT clickhouse_raw_query('DROP DATABASE binary_inserts_test'); 86 | DROP SERVER binary_inserts_loopback CASCADE; 87 | -------------------------------------------------------------------------------- /test/sql/function_pushdown.sql: -------------------------------------------------------------------------------- 1 | \unset ECHO 2 | SET client_min_messages = notice; 3 | CREATE TABLE agg_test ( a int, b int, c timestamp, d text ); 4 | INSERT INTO agg_test VALUES (1, 1, '2025-10-1 19:33:15', 'first'); 5 | 6 | DO $do$ 7 | DECLARE 8 | q TEXT; 9 | BEGIN 10 | FOREACH q IN ARRAY ARRAY[ 11 | -- Aggregates 12 | 'SELECT argMax(a, b) FROM agg_test', 13 | 'SELECT argMax(a, b) FROM agg_test', 14 | 'SELECT argMax(a, c) FROM agg_test', 15 | 'SELECT argMax(a, d) FROM agg_test', 16 | 'SELECT argMax(d, a) FROM agg_test', 17 | 'SELECT argMax(d, b) FROM agg_test', 18 | 'SELECT argMax(d, c) FROM agg_test', 19 | 20 | 'SELECT argMin(a, b) FROM agg_test', 21 | 'SELECT argMin(a, c) FROM agg_test', 22 | 'SELECT argMin(a, d) FROM agg_test', 23 | 'SELECT argMin(d, a) FROM agg_test', 24 | 'SELECT argMin(d, b) FROM agg_test', 25 | 'SELECT argMin(d, c) FROM agg_test', 26 | 27 | 'SELECT uniq(a) FROM agg_test', 28 | 'SELECT uniq(a, b) FROM agg_test', 29 | 'SELECT uniq(a, b, c) FROM agg_test', 30 | 'SELECT uniq(a, b, c, d) FROM agg_test', 31 | 32 | 'SELECT uniqExact(a) FROM agg_test', 33 | 'SELECT uniqExact(a, b) FROM agg_test', 34 | 'SELECT uniqExact(a, b, c) FROM agg_test', 35 | 'SELECT uniqExact(a, b, c, d) FROM agg_test', 36 | 37 | 'SELECT uniqCombined(a) FROM agg_test', 38 | 'SELECT uniqCombined(a, b) FROM agg_test', 39 | 'SELECT uniqCombined(a, b, c) FROM agg_test', 40 | 'SELECT uniqCombined(a, b, c, d) FROM agg_test', 41 | 42 | 'SELECT uniqCombined64(a) FROM agg_test', 43 | 'SELECT uniqCombined64(a, b) FROM agg_test', 44 | 'SELECT uniqCombined64(a, b, c) FROM agg_test', 45 | 'SELECT uniqCombined64(a, b, c, d) FROM agg_test', 46 | 47 | 'SELECT uniqHLL12(a) FROM agg_test', 48 | 'SELECT uniqHLL12(a, b) FROM agg_test', 49 | 'SELECT uniqHLL12(a, b, c) FROM agg_test', 50 | 'SELECT uniqHLL12(a, b, c, d) FROM agg_test', 51 | 52 | 'SELECT uniqTheta(a) FROM agg_test', 53 | 'SELECT uniqTheta(a, b) FROM agg_test', 54 | 'SELECT uniqTheta(a, b, c) FROM agg_test', 55 | 'SELECT uniqTheta(a, b, c, d) FROM agg_test', 56 | 57 | -- Functions 58 | $$ SELECT ch_push_agg_text('hello', 1) $$, 59 | $$ SELECT ch_push_agg_text('goodbye', true) $$, 60 | 61 | $$ SELECT ch_argmax('x'::text, 'x'::text, 3) $$, 62 | $$ SELECT ch_argmax(3, 3, true) $$, 63 | $$ SELECT ch_argmax(true, false, now()) $$, 64 | 65 | $$ SELECT ch_argmin('x'::text, 'x'::text, 3) $$, 66 | $$ SELECT ch_argmin(3, 3, true) $$, 67 | $$ SELECT ch_argmin(true, false, now()) $$, 68 | 69 | $$ SELECT dictGet('', '', '{"x": true}'::json) $$, 70 | $$ SELECT dictGet('a', 'b', ARRAY[1]) $$, 71 | 72 | $$ SELECT quantile(1) $$, 73 | $$ SELECT quantile('x') $$, 74 | $$ SELECT quantileExact(42) $$, 75 | $$ SELECT quantileExact(98.6) $$, 76 | 77 | $$ SELECT toUInt8('x') $$, 78 | $$ SELECT toUInt8(8) $$, 79 | $$ SELECT toUInt16('x') $$, 80 | $$ SELECT toUInt16(16) $$, 81 | $$ SELECT toUInt32('x') $$, 82 | $$ SELECT toUInt32(32) $$, 83 | $$ SELECT toUInt64('x') $$, 84 | $$ SELECT toUInt64(64) $$ 85 | 86 | ] LOOP 87 | BEGIN 88 | EXECUTE q; 89 | RAISE NOTICE '`%`: did not fail', q; 90 | EXCEPTION WHEN OTHERS OR ASSERT_FAILURE THEN 91 | RAISE NOTICE '%: % - %', q, SQLSTATE, SQLERRM; 92 | IF SQLSTATE != 'HV000' THEN 93 | RAISE EXCEPTION ' Unexpected error code: % - %', SQLSTATE, SQLERRM; 94 | END IF; 95 | END; 96 | END LOOP; 97 | END; 98 | $do$ LANGUAGE plpgsql; 99 | -------------------------------------------------------------------------------- /test/expected/json.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'binary'); 3 | CREATE SERVER http_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS json_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE json_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | SELECT clickhouse_raw_query($$ 19 | CREATE TABLE json_test.things ( 20 | id Int32 NOT NULL, 21 | data JSON NOT NULL 22 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 23 | $$); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | CREATE SCHEMA json_bin; 30 | CREATE SCHEMA json_http; 31 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER binary_json_loopback INTO json_bin; 32 | \d json_bin.things 33 | Foreign table "json_bin.things" 34 | Column | Type | Collation | Nullable | Default | FDW options 35 | --------+---------+-----------+----------+---------+------------- 36 | id | integer | | not null | | 37 | data | jsonb | | not null | | 38 | Server: binary_json_loopback 39 | FDW options: (database 'json_test', table_name 'things', engine 'MergeTree') 40 | 41 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER http_json_loopback INTO json_http; 42 | \d json_http.things 43 | Foreign table "json_http.things" 44 | Column | Type | Collation | Nullable | Default | FDW options 45 | --------+---------+-----------+----------+---------+------------- 46 | id | integer | | not null | | 47 | data | jsonb | | not null | | 48 | Server: http_json_loopback 49 | FDW options: (database 'json_test', table_name 'things', engine 'MergeTree') 50 | 51 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 52 | INSERT INTO json_bin.things VALUES 53 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 54 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}') 55 | ; 56 | ERROR: pg_clickhouse: could not prepare insert - unsupported column type: JSON 57 | INSERT INTO json_http.things VALUES 58 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 59 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}'), 60 | (3, '{"id": 3, "name": "gizmo", "size": "medium", "stocked": true}'), 61 | (4, '{"id": 4, "name": "doodad", "size": "large", "stocked": false}') 62 | ; 63 | SELECT * FROM json_bin.things ORDER BY id; 64 | ERROR: pg_clickhouse: unsupported column type: JSON 65 | DETAIL: Remote Query: SELECT id, data FROM json_test.things ORDER BY id ASC NULLS LAST 66 | SELECT * FROM json_http.things ORDER BY id; 67 | id | data 68 | ----+----------------------------------------------------------------- 69 | 1 | {"id": 1, "name": "widget", "size": "large", "stocked": true} 70 | 2 | {"id": 2, "name": "sprocket", "size": "small", "stocked": true} 71 | 3 | {"id": 3, "name": "gizmo", "size": "medium", "stocked": true} 72 | 4 | {"id": 4, "name": "doodad", "size": "large", "stocked": false} 73 | (4 rows) 74 | 75 | SELECT clickhouse_raw_query('DROP DATABASE json_test'); 76 | clickhouse_raw_query 77 | ---------------------- 78 | 79 | (1 row) 80 | 81 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 82 | DROP USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 83 | DROP SERVER binary_json_loopback CASCADE; 84 | NOTICE: drop cascades to foreign table json_bin.things 85 | DROP SERVER http_json_loopback CASCADE; 86 | NOTICE: drop cascades to foreign table json_http.things 87 | -------------------------------------------------------------------------------- /test/expected/json_1.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'binary'); 3 | CREATE SERVER http_json_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'json_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS json_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE json_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | SELECT clickhouse_raw_query($$ 19 | CREATE TABLE json_test.things ( 20 | id Int32 NOT NULL, 21 | data JSON NOT NULL 22 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 23 | $$); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | CREATE SCHEMA json_bin; 30 | CREATE SCHEMA json_http; 31 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER binary_json_loopback INTO json_bin; 32 | \d json_bin.things 33 | Foreign table "json_bin.things" 34 | Column | Type | Collation | Nullable | Default | FDW options 35 | --------+---------+-----------+----------+---------+------------- 36 | id | integer | | not null | | 37 | data | jsonb | | not null | | 38 | Server: binary_json_loopback 39 | FDW options: (database 'json_test', table_name 'things', engine 'MergeTree') 40 | 41 | IMPORT FOREIGN SCHEMA "json_test" FROM SERVER http_json_loopback INTO json_http; 42 | \d json_http.things 43 | Foreign table "json_http.things" 44 | Column | Type | Collation | Nullable | Default | FDW options 45 | --------+---------+-----------+----------+---------+------------- 46 | id | integer | | not null | | 47 | data | jsonb | | not null | | 48 | Server: http_json_loopback 49 | FDW options: (database 'json_test', table_name 'things', engine 'MergeTree') 50 | 51 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 52 | INSERT INTO json_bin.things VALUES 53 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 54 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}') 55 | ; 56 | ERROR: pg_clickhouse: could not prepare insert - unsupported column type: JSON 57 | INSERT INTO json_http.things VALUES 58 | (1, '{"id": 1, "name": "widget", "size": "large", "stocked": true}'), 59 | (2, '{"id": 2, "name": "sprocket", "size": "small", "stocked": true}'), 60 | (3, '{"id": 3, "name": "gizmo", "size": "medium", "stocked": true}'), 61 | (4, '{"id": 4, "name": "doodad", "size": "large", "stocked": false}') 62 | ; 63 | SELECT * FROM json_bin.things ORDER BY id; 64 | ERROR: pg_clickhouse: unsupported column type: JSON 65 | DETAIL: Remote Query: SELECT id, data FROM json_test.things ORDER BY id ASC NULLS LAST 66 | SELECT * FROM json_http.things ORDER BY id; 67 | id | data 68 | ----+------------------------------------------------------------------- 69 | 1 | {"id": "1", "name": "widget", "size": "large", "stocked": true} 70 | 2 | {"id": "2", "name": "sprocket", "size": "small", "stocked": true} 71 | 3 | {"id": "3", "name": "gizmo", "size": "medium", "stocked": true} 72 | 4 | {"id": "4", "name": "doodad", "size": "large", "stocked": false} 73 | (4 rows) 74 | 75 | SELECT clickhouse_raw_query('DROP DATABASE json_test'); 76 | clickhouse_raw_query 77 | ---------------------- 78 | 79 | (1 row) 80 | 81 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_json_loopback; 82 | DROP USER MAPPING FOR CURRENT_USER SERVER http_json_loopback; 83 | DROP SERVER binary_json_loopback CASCADE; 84 | NOTICE: drop cascades to foreign table json_bin.things 85 | DROP SERVER http_json_loopback CASCADE; 86 | NOTICE: drop cascades to foreign table json_http.things 87 | -------------------------------------------------------------------------------- /test/sql/binary.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_loopback FOREIGN DATA WRAPPER clickhouse_fdw 3 | OPTIONS(dbname 'binary_test', driver 'binary'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_loopback; 5 | 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS binary_test'); 7 | SELECT clickhouse_raw_query('CREATE DATABASE binary_test'); 8 | 9 | -- integer types 10 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.ints ( 11 | c1 Int8, c2 Int16, c3 Int32, c4 Int64, 12 | c5 UInt8, c6 UInt16, c7 UInt32, c8 UInt64, 13 | c9 Float32, c10 Float64, c11 Bool 14 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 15 | '); 16 | SELECT clickhouse_raw_query('INSERT INTO binary_test.ints SELECT 17 | number, number + 1, number + 2, number + 3, number + 4, number + 5, 18 | number + 6, number + 7, number + 8.1, number + 9.2, cast(number % 2 as Bool) 19 | FROM numbers(10);'); 20 | 21 | -- date and string types 22 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.types ( 23 | c1 Date, c2 DateTime, c3 String, c4 FixedString(5), c5 UUID, 24 | c6 Enum8(''one'' = 1, ''two'' = 2), 25 | c7 Enum16(''one'' = 1, ''two'' = 2, ''three'' = 3) 26 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 27 | '); 28 | SELECT clickhouse_raw_query('INSERT INTO binary_test.types SELECT 29 | addDays(toDate(''1990-01-01''), number), 30 | addMinutes(addSeconds(addDays(toDateTime(''1990-01-01 10:00:00''), number), number), number), 31 | format(''number {0}'', toString(number)), 32 | format(''num {0}'', toString(number)), 33 | format(''f4bf890f-f9dc-4332-ad5c-0c18e73f28e{0}'', toString(number)), 34 | ''two'', 35 | ''three'' 36 | FROM numbers(10);'); 37 | 38 | -- array types 39 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.arrays ( 40 | c1 Array(Int), c2 Array(String) 41 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 42 | '); 43 | SELECT clickhouse_raw_query('INSERT INTO binary_test.arrays SELECT 44 | [number, number + 1], 45 | [format(''num{0}'', toString(number)), format(''num{0}'', toString(number + 1))] 46 | FROM numbers(10);'); 47 | 48 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.tuples ( 49 | c1 Int8, 50 | c2 Tuple(Int, String, Float32), 51 | c3 UInt8 52 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 53 | '); 54 | SELECT clickhouse_raw_query('INSERT INTO binary_test.tuples SELECT 55 | number, 56 | (number, toString(number), number + 1.0), 57 | number % 2 58 | FROM numbers(10);'); 59 | 60 | CREATE FOREIGN TABLE fints ( 61 | c1 int2, 62 | c2 int2, 63 | c3 int, 64 | c4 int8, 65 | c5 int2, 66 | c6 int, 67 | c7 int8, 68 | c8 int8, 69 | c9 float4, 70 | c10 float8, 71 | c11 bool 72 | ) SERVER binary_loopback OPTIONS (table_name 'ints'); 73 | 74 | CREATE FOREIGN TABLE ftypes ( 75 | c1 date, 76 | c2 timestamp without time zone, 77 | c3 text, 78 | c4 text, 79 | c5 uuid, 80 | c6 text, -- Enum8 81 | c7 text -- Enum16 82 | ) SERVER binary_loopback OPTIONS (table_name 'types'); 83 | 84 | CREATE FOREIGN TABLE farrays ( 85 | c1 int[], 86 | c2 text[] 87 | ) SERVER binary_loopback OPTIONS (table_name 'arrays'); 88 | 89 | CREATE FOREIGN TABLE farrays2 ( 90 | c1 int8[], 91 | c2 text[] 92 | ) SERVER binary_loopback OPTIONS (table_name 'arrays'); 93 | 94 | CREATE TABLE tupformat(a int, b text, c float4); 95 | CREATE FOREIGN TABLE ftuples ( 96 | c1 int, 97 | c2 tupformat, 98 | c3 bool 99 | ) SERVER binary_loopback OPTIONS (table_name 'tuples'); 100 | 101 | -- integers 102 | SELECT * FROM fints ORDER BY c1; 103 | SELECT c2, c1, c8, c3, c4, c7, c6, c5 FROM fints ORDER BY c1; 104 | SELECT a, b FROM (SELECT c1 * 10 as a, c8 * 11 as b FROM fints ORDER BY a LIMIT 2) t1; 105 | SELECT NULL FROM fints LIMIT 2; 106 | SELECT c2, NULL, c1, NULL FROM fints ORDER BY c2 LIMIT 2; 107 | 108 | -- types 109 | SELECT * FROM ftypes ORDER BY c1; 110 | SELECT c2, c1, c4, c3, c5, c7, c6 FROM ftypes ORDER BY c1; 111 | 112 | -- arrays 113 | SELECT * FROM farrays ORDER BY c1; 114 | SELECT * FROM farrays2 ORDER BY c1; 115 | 116 | -- tuples 117 | SELECT * FROM ftuples ORDER BY c1; 118 | 119 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_loopback; 120 | SELECT clickhouse_raw_query('DROP DATABASE binary_test'); 121 | 122 | DROP SERVER binary_loopback CASCADE; 123 | -------------------------------------------------------------------------------- /test/expected/gucs.out: -------------------------------------------------------------------------------- 1 | \unset ECHO 2 | NOTICE: OK `` 3 | NOTICE: OK `join_use_nulls 1` 4 | NOTICE: OK `join_use_nulls 1, xyz true` 5 | NOTICE: OK ` additional_result_filter 'x != 2' ` 6 | NOTICE: OK ` additional_result_filter 'x != 2' ,join_use_nulls 1 ` 7 | NOTICE: OK ` xxx DEFAULT, yyy foo\,bar, zzz 'He said, \'Hello\'', aaa hi\ there ` 8 | NOTICE: ERR 42601 - pg_clickhouse: missing value for parameter "join_use_nulls" in options string 9 | NOTICE: ERR 42601 - pg_clickhouse: missing comma after "join_use_nulls" value in options string 10 | NOTICE: ERR 42601 - pg_clickhouse: unterminated quoted string in options string 11 | NOTICE: ERR 42601 - pg_clickhouse: missing comma after "join_use_nulls" value in options string 12 | name | value 13 | --------------------+------- 14 | final | 1 15 | group_by_use_nulls | 1 16 | join_use_nulls | 1 17 | (3 rows) 18 | 19 | name | value 20 | --------------------+------- 21 | final | 1 22 | group_by_use_nulls | 1 23 | join_use_nulls | 1 24 | (3 rows) 25 | 26 | pg_clickhouse.session_settings 27 | -------------------------------------------- 28 | + 29 | connect_timeout 2, + 30 | count_distinct_implementation uniq, + 31 | join_algorithm 'prefer_partial_merge',+ 32 | join_use_nulls 0, + 33 | join_use_nulls 1, + 34 | log_queries_min_type QUERY_FINISH, + 35 | max_block_size 32768, + 36 | max_execution_time 45, + 37 | max_result_rows 1024, + 38 | metrics_perf_events_list 'this,that', + 39 | network_compression_method ZSTD, + 40 | poll_interval 5, + 41 | totals_mode after_having_auto + 42 | 43 | (1 row) 44 | 45 | name | value 46 | -------------------------------+---------------------- 47 | connect_timeout | 2 48 | count_distinct_implementation | uniq 49 | join_algorithm | prefer_partial_merge 50 | join_use_nulls | 1 51 | log_queries_min_type | QUERY_FINISH 52 | max_block_size | 32768 53 | max_execution_time | 45 54 | max_result_rows | 1024 55 | metrics_perf_events_list | this,that 56 | network_compression_method | ZSTD 57 | poll_interval | 5 58 | totals_mode | after_having_auto 59 | (12 rows) 60 | 61 | name | value 62 | -------------------------------+---------------------- 63 | connect_timeout | 2 64 | count_distinct_implementation | uniq 65 | join_algorithm | prefer_partial_merge 66 | join_use_nulls | 1 67 | log_queries_min_type | QUERY_FINISH 68 | max_block_size | 32768 69 | max_execution_time | 45 70 | max_result_rows | 1024 71 | metrics_perf_events_list | this,that 72 | network_compression_method | ZSTD 73 | poll_interval | 5 74 | totals_mode | after_having_auto 75 | (12 rows) 76 | 77 | name | ?column? 78 | -------------------------------+---------- 79 | connect_timeout | t 80 | count_distinct_implementation | t 81 | join_algorithm | t 82 | join_use_nulls | t 83 | log_queries_min_type | t 84 | max_block_size | t 85 | max_execution_time | t 86 | max_result_rows | t 87 | metrics_perf_events_list | t 88 | network_compression_method | t 89 | poll_interval | t 90 | totals_mode | t 91 | (12 rows) 92 | 93 | name | ?column? 94 | -------------------------------+---------- 95 | connect_timeout | t 96 | count_distinct_implementation | t 97 | join_algorithm | t 98 | join_use_nulls | t 99 | log_queries_min_type | t 100 | max_block_size | t 101 | max_execution_time | t 102 | max_result_rows | t 103 | metrics_perf_events_list | t 104 | network_compression_method | t 105 | poll_interval | t 106 | totals_mode | t 107 | (12 rows) 108 | 109 | NOTICE: drop cascades to foreign table bin_remote_settings 110 | NOTICE: drop cascades to foreign table http_remote_settings 111 | -------------------------------------------------------------------------------- /test/sql/gucs.sql: -------------------------------------------------------------------------------- 1 | \unset ECHO 2 | SET client_min_messages = notice; 3 | 4 | -- Load pg_clickhouse; 5 | LOAD 'pg_clickhouse'; 6 | 7 | -- Test parsing. 8 | DO $do$ 9 | DECLARE 10 | cfg TEXT; 11 | BEGIN 12 | FOREACH cfg IN ARRAY ARRAY[ 13 | -- Success. 14 | '', 15 | 'join_use_nulls 1', 16 | 'join_use_nulls 1, xyz true', 17 | $$ additional_result_filter 'x != 2' $$, 18 | $$ additional_result_filter 'x != 2' ,join_use_nulls 1 $$, 19 | $$ xxx DEFAULT, yyy foo\,bar, zzz 'He said, \'Hello\'', aaa hi\ there $$, 20 | 21 | -- Failure. 22 | 'join_use_nulls', 23 | 'join_use_nulls = xyz', 24 | $$ additional_result_filter 'x != 2 $$, 25 | 'join_use_nulls xyz no_preceding_comma = 2' 26 | ] LOOP 27 | BEGIN 28 | RAISE NOTICE 'OK `%`', set_config('pg_clickhouse.session_settings', cfg, true); 29 | EXCEPTION WHEN OTHERS OR ASSERT_FAILURE THEN 30 | RAISE NOTICE 'ERR % - %', SQLSTATE, SQLERRM; 31 | END; 32 | END LOOP; 33 | END; 34 | $do$ LANGUAGE plpgsql; 35 | 36 | -- Create servers for each engine. 37 | CREATE SERVER guc_bin_svr FOREIGN DATA WRAPPER clickhouse_fdw 38 | OPTIONS(dbname 'system', driver 'binary'); 39 | CREATE USER MAPPING FOR CURRENT_USER SERVER guc_bin_svr; 40 | 41 | CREATE SERVER guc_http_svr FOREIGN DATA WRAPPER clickhouse_fdw 42 | OPTIONS(dbname 'system', driver 'http'); 43 | CREATE USER MAPPING FOR CURRENT_USER SERVER guc_http_svr; 44 | 45 | -- Create foreign tables for each engine. 46 | CREATE FOREIGN TABLE bin_remote_settings ( 47 | name text, 48 | value text 49 | ) 50 | SERVER guc_bin_svr 51 | OPTIONS (table_name 'settings'); 52 | 53 | CREATE FOREIGN TABLE http_remote_settings ( 54 | name text, 55 | value text 56 | ) 57 | SERVER guc_http_svr 58 | OPTIONS (table_name 'settings'); 59 | 60 | -- Reset to defaults. 61 | RESET pg_clickhouse.session_settings; 62 | SELECT name, value FROM bin_remote_settings 63 | WHERE name IN ('join_use_nulls', 'group_by_use_nulls', 'final') 64 | ORDER BY name; 65 | 66 | SELECT name, value FROM http_remote_settings 67 | WHERE name IN ('join_use_nulls', 'group_by_use_nulls', 'final') 68 | ORDER BY name; 69 | 70 | -- List of seeings changed below. 71 | select '{ 72 | connect_timeout, 73 | count_distinct_implementation, 74 | join_algorithm, 75 | join_use_nulls, 76 | log_queries_min_type, 77 | max_block_size, 78 | max_execution_time, 79 | max_result_rows, 80 | metrics_perf_events_list, 81 | network_compression_method, 82 | poll_interval, 83 | totals_mode 84 | }' set_list \gset 85 | 86 | -- Unset and get defaults. 87 | SET pg_clickhouse.session_settings TO ''; 88 | 89 | CREATE TEMPORARY TABLE default_settings AS 90 | SELECT name, value 91 | FROM bin_remote_settings 92 | WHERE name = ANY(:'set_list'); 93 | 94 | -- Customize all of the above settings. 95 | SET pg_clickhouse.session_settings TO $$ 96 | connect_timeout 2, 97 | count_distinct_implementation uniq, 98 | join_algorithm 'prefer_partial_merge', 99 | join_use_nulls 0, 100 | join_use_nulls 1, 101 | log_queries_min_type QUERY_FINISH, 102 | max_block_size 32768, 103 | max_execution_time 45, 104 | max_result_rows 1024, 105 | metrics_perf_events_list 'this,that', 106 | network_compression_method ZSTD, 107 | poll_interval 5, 108 | totals_mode after_having_auto 109 | $$; 110 | 111 | SHOW pg_clickhouse.session_settings; 112 | 113 | -- Check the remote settings for both engines. 114 | SELECT name, value 115 | FROM bin_remote_settings 116 | WHERE name = ANY(:'set_list') 117 | ORDER BY name; 118 | 119 | SELECT name, value 120 | FROM http_remote_settings 121 | WHERE name = ANY(:'set_list') 122 | ORDER BY name; 123 | 124 | -- Unset back to defaults. 125 | SET pg_clickhouse.session_settings TO ''; 126 | 127 | SELECT remote.name, remote.value IS NOT DISTINCT FROM def.value 128 | FROM bin_remote_settings remote 129 | JOIN default_settings def ON remote.name = def.name 130 | WHERE remote.name = ANY(:'set_list') 131 | ORDER BY remote.name; 132 | 133 | SELECT remote.name, remote.value IS NOT DISTINCT FROM def.value 134 | FROM http_remote_settings remote 135 | JOIN default_settings def ON remote.name = def.name 136 | WHERE remote.name = ANY(:'set_list') 137 | ORDER BY remote.name; 138 | 139 | -- Clean up. 140 | DROP USER MAPPING FOR CURRENT_USER SERVER guc_bin_svr; 141 | DROP SERVER guc_bin_svr CASCADE; 142 | DROP USER MAPPING FOR CURRENT_USER SERVER guc_http_svr; 143 | DROP SERVER guc_http_svr CASCADE; 144 | -------------------------------------------------------------------------------- /test/expected/decimal.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_decimal_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'decimal_test', driver 'binary'); 3 | CREATE SERVER http_decimal_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'decimal_test', driver 'http'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_decimal_loopback; 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_decimal_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS decimal_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE decimal_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | SELECT clickhouse_raw_query($$ 19 | CREATE TABLE decimal_test.decimals ( 20 | id Int32 NOT NULL, 21 | dec Decimal(8, 0) NOT NULL, 22 | dec32 Decimal32(4) NOT NULL, 23 | dec64 Decimal64(6) NOT NULL, 24 | dec128 Decimal128(8) NOT NULL 25 | ) ENGINE = MergeTree PARTITION BY id ORDER BY (id); 26 | $$); 27 | clickhouse_raw_query 28 | ---------------------- 29 | 30 | (1 row) 31 | 32 | CREATE SCHEMA dec_bin; 33 | CREATE SCHEMA dec_http; 34 | IMPORT FOREIGN SCHEMA "decimal_test" FROM SERVER binary_decimal_loopback INTO dec_bin; 35 | \d dec_bin.decimals 36 | Foreign table "dec_bin.decimals" 37 | Column | Type | Collation | Nullable | Default | FDW options 38 | --------+---------------+-----------+----------+---------+------------- 39 | id | integer | | not null | | 40 | dec | numeric(8,0) | | not null | | 41 | dec32 | numeric(9,4) | | not null | | 42 | dec64 | numeric(18,6) | | not null | | 43 | dec128 | numeric(38,8) | | not null | | 44 | Server: binary_decimal_loopback 45 | FDW options: (database 'decimal_test', table_name 'decimals', engine 'MergeTree') 46 | 47 | IMPORT FOREIGN SCHEMA "decimal_test" FROM SERVER http_decimal_loopback INTO dec_http; 48 | \d dec_http.decimals 49 | Foreign table "dec_http.decimals" 50 | Column | Type | Collation | Nullable | Default | FDW options 51 | --------+---------------+-----------+----------+---------+------------- 52 | id | integer | | not null | | 53 | dec | numeric(8,0) | | not null | | 54 | dec32 | numeric(9,4) | | not null | | 55 | dec64 | numeric(18,6) | | not null | | 56 | dec128 | numeric(38,8) | | not null | | 57 | Server: http_decimal_loopback 58 | FDW options: (database 'decimal_test', table_name 'decimals', engine 'MergeTree') 59 | 60 | -- Fails pending https://github.com/ClickHouse/clickhouse-cpp/issues/422 61 | INSERT INTO dec_bin.decimals (id, dec, dec32, dec64, dec128) VALUES 62 | (1, 42::NUMERIC, 98.6::NUMERIC, 102.4::NUMERIC, 1024.003::NUMERIC), 63 | (2, 9999, 9999.9999, 9999999.999999, 99999999999.99999999), 64 | (3, -9999, -9999.9999, -9999999.999999, -99999999999.99999999) 65 | ; 66 | INSERT INTO dec_http.decimals VALUES 67 | (4, 1000000::NUMERIC, 10000::NUMERIC, 3000000000::NUMERIC, 400000000000::NUMERIC), 68 | (5, -1, -0.0001, -0.000001, -0.00000001), 69 | (6, 0, 0, 0, 0) 70 | ; 71 | SELECT * FROM dec_bin.decimals ORDER BY id; 72 | id | dec | dec32 | dec64 | dec128 73 | ----+---------+------------+-------------------+----------------------- 74 | 1 | 42 | 98.6000 | 102.400000 | 1024.00300000 75 | 2 | 9999 | 9999.9999 | 9999999.999999 | 99999999999.99999999 76 | 3 | -9999 | -9999.9999 | -9999999.999999 | -99999999999.99999999 77 | 4 | 1000000 | 10000.0000 | 3000000000.000000 | 400000000000.00000000 78 | 5 | -1 | -0.0001 | -0.000001 | -0.00000001 79 | 6 | 0 | 0.0000 | 0.000000 | 0.00000000 80 | (6 rows) 81 | 82 | SELECT * FROM dec_http.decimals ORDER BY id; 83 | id | dec | dec32 | dec64 | dec128 84 | ----+---------+------------+-------------------+----------------------- 85 | 1 | 42 | 98.6000 | 102.400000 | 1024.00300000 86 | 2 | 9999 | 9999.9999 | 9999999.999999 | 99999999999.99999999 87 | 3 | -9999 | -9999.9999 | -9999999.999999 | -99999999999.99999999 88 | 4 | 1000000 | 10000.0000 | 3000000000.000000 | 400000000000.00000000 89 | 5 | -1 | -0.0001 | -0.000001 | -0.00000001 90 | 6 | 0 | 0.0000 | 0.000000 | 0.00000000 91 | (6 rows) 92 | 93 | SELECT clickhouse_raw_query('DROP DATABASE decimal_test'); 94 | clickhouse_raw_query 95 | ---------------------- 96 | 97 | (1 row) 98 | 99 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_decimal_loopback; 100 | DROP USER MAPPING FOR CURRENT_USER SERVER http_decimal_loopback; 101 | DROP SERVER binary_decimal_loopback CASCADE; 102 | NOTICE: drop cascades to foreign table dec_bin.decimals 103 | DROP SERVER http_decimal_loopback CASCADE; 104 | NOTICE: drop cascades to foreign table dec_http.decimals 105 | -------------------------------------------------------------------------------- /test/sql/subquery_pushdown.sql: -------------------------------------------------------------------------------- 1 | -- Test for TPC-H Q4 style EXISTS subquery pushdown 2 | -- TPC-H schema reference: https://raw.githubusercontent.com/Vonng/pgtpc/refs/heads/master/tpch/ddl/schema.ddl 3 | SET datestyle = 'ISO'; 4 | CREATE SERVER subquery_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'subquery_test', driver 'binary'); 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 6 | 7 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS subquery_test'); 8 | SELECT clickhouse_raw_query('CREATE DATABASE subquery_test'); 9 | 10 | -- Create TPC-H orders table (matching official schema) 11 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.orders 12 | (o_orderkey Int32, o_custkey Int32, o_orderstatus FixedString(1), o_totalprice Decimal(15,2), 13 | o_orderdate Date, o_orderpriority FixedString(15), o_clerk FixedString(15), o_shippriority Int32, o_comment String) 14 | ENGINE = MergeTree ORDER BY o_orderkey; 15 | '); 16 | 17 | -- Create TPC-H lineitem table (matching official schema) 18 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.lineitem 19 | (l_orderkey Int32, l_partkey Int32, l_suppkey Int32, l_linenumber Int32, 20 | l_quantity Decimal(15,2), l_extendedprice Decimal(15,2), l_discount Decimal(15,2), l_tax Decimal(15,2), 21 | l_returnflag FixedString(1), l_linestatus FixedString(1), l_shipdate Date, l_commitdate Date, 22 | l_receiptdate Date, l_shipinstruct FixedString(25), l_shipmode FixedString(10), l_comment String) 23 | ENGINE = MergeTree ORDER BY (l_orderkey, l_linenumber); 24 | '); 25 | 26 | -- Insert sample orders data 27 | SELECT clickhouse_raw_query($$ 28 | INSERT INTO subquery_test.orders VALUES 29 | (1, 100, 'O', 1000.00, '1993-07-15', '1-URGENT', 'Clerk#000000001', 0, 'order1'), 30 | (2, 101, 'O', 2000.00, '1993-07-20', '2-HIGH', 'Clerk#000000002', 0, 'order2'), 31 | (3, 102, 'O', 3000.00, '1993-08-01', '1-URGENT', 'Clerk#000000003', 0, 'order3'), 32 | (4, 103, 'O', 4000.00, '1993-08-15', '3-MEDIUM', 'Clerk#000000004', 0, 'order4'), 33 | (5, 104, 'O', 5000.00, '1993-06-01', '1-URGENT', 'Clerk#000000005', 0, 'order5'), 34 | (6, 105, 'O', 6000.00, '1993-09-15', '2-HIGH', 'Clerk#000000006', 0, 'order6'), 35 | (7, 106, 'O', 7000.00, '1993-07-25', '4-NOT SPECIFIED', 'Clerk#000000007', 0, 'order7'), 36 | (8, 107, 'O', 8000.00, '1993-08-20', '5-LOW', 'Clerk#000000008', 0, 'order8'); 37 | $$); 38 | 39 | -- Insert sample lineitem data (l_commitdate < l_receiptdate for some items) 40 | SELECT clickhouse_raw_query($$ 41 | INSERT INTO subquery_test.lineitem VALUES 42 | (1, 10, 1, 1, 10.00, 100.00, 0.10, 0.05, 'N', 'O', '1993-07-20', '1993-07-15', '1993-07-25', 'DELIVER IN PERSON', 'TRUCK', 'item1'), 43 | (2, 20, 2, 1, 20.00, 200.00, 0.10, 0.05, 'N', 'O', '1993-07-25', '1993-07-20', '1993-07-30', 'DELIVER IN PERSON', 'AIR', 'item2'), 44 | (3, 30, 3, 1, 30.00, 300.00, 0.10, 0.05, 'N', 'O', '1993-08-05', '1993-08-10', '1993-08-08', 'DELIVER IN PERSON', 'SHIP', 'item3'), 45 | (4, 40, 4, 1, 40.00, 400.00, 0.10, 0.05, 'N', 'O', '1993-08-20', '1993-08-15', '1993-08-25', 'DELIVER IN PERSON', 'RAIL', 'item4'), 46 | (7, 70, 7, 1, 70.00, 700.00, 0.10, 0.05, 'N', 'O', '1993-07-30', '1993-07-25', '1993-08-05', 'DELIVER IN PERSON', 'AIR', 'item7'), 47 | (8, 80, 8, 1, 80.00, 800.00, 0.10, 0.05, 'N', 'O', '1993-08-25', '1993-08-30', '1993-08-28', 'DELIVER IN PERSON', 'TRUCK', 'item8'); 48 | $$); 49 | 50 | -- Create foreign tables (matching TPC-H schema types) 51 | CREATE SCHEMA subquery_test; 52 | IMPORT FOREIGN SCHEMA "subquery_test" FROM SERVER subquery_loopback INTO subquery_test; 53 | 54 | -- Disable hash and merge joins to get consistent explain output 55 | SET SESSION enable_hashjoin TO false; 56 | SET SESSION enable_mergejoin TO false; 57 | SET SESSION search_path = subquery_test,public; 58 | 59 | -- =================================================================== 60 | -- Test SEMI-JOIN / EXISTS subquery pushdown (TPC-H Q4 style query) 61 | -- =================================================================== 62 | 63 | -- First, show the explain plan - this should show SEMI JOIN being pushed down 64 | EXPLAIN (VERBOSE, COSTS OFF) 65 | SELECT 66 | o_orderpriority, 67 | count(*) as order_count 68 | FROM 69 | orders 70 | WHERE 71 | o_orderdate >= date '1993-07-01' 72 | AND o_orderdate < date '1993-10-01' 73 | AND EXISTS ( 74 | SELECT * FROM lineitem 75 | WHERE l_orderkey = o_orderkey 76 | AND l_commitdate < l_receiptdate 77 | ) 78 | GROUP BY 79 | o_orderpriority 80 | ORDER BY 81 | o_orderpriority; 82 | 83 | -- Execute the actual query 84 | SELECT 85 | o_orderpriority, 86 | count(*) as order_count 87 | FROM 88 | orders 89 | WHERE 90 | o_orderdate >= date '1993-07-01' 91 | AND o_orderdate < date '1993-10-01' 92 | AND EXISTS ( 93 | SELECT * FROM lineitem 94 | WHERE l_orderkey = o_orderkey 95 | AND l_commitdate < l_receiptdate 96 | ) 97 | GROUP BY 98 | o_orderpriority 99 | ORDER BY 100 | o_orderpriority; 101 | 102 | -- Simpler EXISTS test without aggregation 103 | EXPLAIN (VERBOSE, COSTS OFF) 104 | SELECT o_orderkey, o_orderpriority FROM orders 105 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 106 | ORDER BY o_orderkey; 107 | 108 | SELECT o_orderkey, o_orderpriority FROM orders 109 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 110 | ORDER BY o_orderkey; 111 | 112 | -- Cleanup 113 | SELECT clickhouse_raw_query('DROP DATABASE subquery_test'); 114 | DROP USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 115 | DROP SERVER subquery_loopback CASCADE; 116 | -------------------------------------------------------------------------------- /test/expected/function_pushdown.out: -------------------------------------------------------------------------------- 1 | \unset ECHO 2 | NOTICE: SELECT argMax(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 3 | NOTICE: SELECT argMax(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 4 | NOTICE: SELECT argMax(a, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 5 | NOTICE: SELECT argMax(a, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 6 | NOTICE: SELECT argMax(d, a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 7 | NOTICE: SELECT argMax(d, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 8 | NOTICE: SELECT argMax(d, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMax() 9 | NOTICE: SELECT argMin(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 10 | NOTICE: SELECT argMin(a, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 11 | NOTICE: SELECT argMin(a, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 12 | NOTICE: SELECT argMin(d, a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 13 | NOTICE: SELECT argMin(d, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 14 | NOTICE: SELECT argMin(d, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate argMin() 15 | NOTICE: SELECT uniq(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniq() 16 | NOTICE: SELECT uniq(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniq() 17 | NOTICE: SELECT uniq(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniq() 18 | NOTICE: SELECT uniq(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniq() 19 | NOTICE: SELECT uniqExact(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqExact() 20 | NOTICE: SELECT uniqExact(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqExact() 21 | NOTICE: SELECT uniqExact(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqExact() 22 | NOTICE: SELECT uniqExact(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqExact() 23 | NOTICE: SELECT uniqCombined(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined() 24 | NOTICE: SELECT uniqCombined(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined() 25 | NOTICE: SELECT uniqCombined(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined() 26 | NOTICE: SELECT uniqCombined(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined() 27 | NOTICE: SELECT uniqCombined64(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined64() 28 | NOTICE: SELECT uniqCombined64(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined64() 29 | NOTICE: SELECT uniqCombined64(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined64() 30 | NOTICE: SELECT uniqCombined64(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqCombined64() 31 | NOTICE: SELECT uniqHLL12(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqHLL12() 32 | NOTICE: SELECT uniqHLL12(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqHLL12() 33 | NOTICE: SELECT uniqHLL12(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqHLL12() 34 | NOTICE: SELECT uniqHLL12(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqHLL12() 35 | NOTICE: SELECT uniqTheta(a) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqTheta() 36 | NOTICE: SELECT uniqTheta(a, b) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqTheta() 37 | NOTICE: SELECT uniqTheta(a, b, c) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqTheta() 38 | NOTICE: SELECT uniqTheta(a, b, c, d) FROM agg_test: HV000 - pg_clickhouse: failed to push down aggregate uniqTheta() 39 | NOTICE: SELECT ch_push_agg_text('hello', 1) : HV000 - pg_clickhouse: failed to push down hello 40 | NOTICE: SELECT ch_push_agg_text('goodbye', true) : HV000 - pg_clickhouse: failed to push down goodbye 41 | NOTICE: SELECT ch_argmax('x'::text, 'x'::text, 3) : HV000 - pg_clickhouse: failed to push down aggregate argMax() 42 | NOTICE: SELECT ch_argmax(3, 3, true) : HV000 - pg_clickhouse: failed to push down aggregate argMax() 43 | NOTICE: SELECT ch_argmax(true, false, now()) : HV000 - pg_clickhouse: failed to push down aggregate argMax() 44 | NOTICE: SELECT ch_argmin('x'::text, 'x'::text, 3) : HV000 - pg_clickhouse: failed to push down aggregate argMin() 45 | NOTICE: SELECT ch_argmin(3, 3, true) : HV000 - pg_clickhouse: failed to push down aggregate argMin() 46 | NOTICE: SELECT ch_argmin(true, false, now()) : HV000 - pg_clickhouse: failed to push down aggregate argMin() 47 | NOTICE: SELECT dictGet('', '', '{"x": true}'::json) : HV000 - pg_clickhouse: failed to push down dictget() 48 | NOTICE: SELECT dictGet('a', 'b', ARRAY[1]) : HV000 - pg_clickhouse: failed to push down dictget() 49 | NOTICE: SELECT quantile(1) : HV000 - pg_clickhouse: failed to push down aggregate quantile() 50 | NOTICE: SELECT quantile('x') : HV000 - pg_clickhouse: failed to push down aggregate quantile() 51 | NOTICE: SELECT quantileExact(42) : HV000 - pg_clickhouse: failed to push down aggregate quantileExact() 52 | NOTICE: SELECT quantileExact(98.6) : HV000 - pg_clickhouse: failed to push down aggregate quantileExact() 53 | NOTICE: SELECT toUInt8('x') : HV000 - pg_clickhouse: failed to push down touint8() 54 | NOTICE: SELECT toUInt8(8) : HV000 - pg_clickhouse: failed to push down touint8() 55 | NOTICE: SELECT toUInt16('x') : HV000 - pg_clickhouse: failed to push down touint16() 56 | NOTICE: SELECT toUInt16(16) : HV000 - pg_clickhouse: failed to push down touint16() 57 | NOTICE: SELECT toUInt32('x') : HV000 - pg_clickhouse: failed to push down touint32() 58 | NOTICE: SELECT toUInt32(32) : HV000 - pg_clickhouse: failed to push down touint32() 59 | NOTICE: SELECT toUInt64('x') : HV000 - pg_clickhouse: failed to push down touint64() 60 | NOTICE: SELECT toUInt64(64) : HV000 - pg_clickhouse: failed to push down touint64() 61 | -------------------------------------------------------------------------------- /test/expected/custom_casts.out: -------------------------------------------------------------------------------- 1 | CREATE SERVER casts_loopback FOREIGN DATA WRAPPER clickhouse_fdw 2 | OPTIONS(dbname 'casts_test', driver 'binary'); 3 | CREATE USER MAPPING FOR CURRENT_USER SERVER casts_loopback; 4 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS casts_test'); 5 | clickhouse_raw_query 6 | ---------------------- 7 | 8 | (1 row) 9 | 10 | SELECT clickhouse_raw_query('CREATE DATABASE casts_test'); 11 | clickhouse_raw_query 12 | ---------------------- 13 | 14 | (1 row) 15 | 16 | SELECT clickhouse_raw_query($$ 17 | CREATE TABLE casts_test.things ( 18 | num integer, 19 | name text 20 | ) ENGINE = MergeTree ORDER BY (num); 21 | $$); 22 | clickhouse_raw_query 23 | ---------------------- 24 | 25 | (1 row) 26 | 27 | SELECT clickhouse_raw_query($$ 28 | INSERT INTO casts_test.things 29 | SELECT number, toString(number) 30 | FROM numbers(10); 31 | $$); 32 | clickhouse_raw_query 33 | ---------------------- 34 | 35 | (1 row) 36 | 37 | IMPORT FOREIGN SCHEMA casts_test FROM SERVER casts_loopback INTO public; 38 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUInt8(num) IN (8, 3, 5); 39 | QUERY PLAN 40 | ----------------------------------------------------------------------------------- 41 | Foreign Scan on public.things 42 | Output: num 43 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt8(num) IN (8,3,5))) 44 | (3 rows) 45 | 46 | SELECT num FROM things WHERE toUInt8(num) IN (8, 3, 5); 47 | num 48 | ----- 49 | 3 50 | 5 51 | 8 52 | (3 rows) 53 | 54 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUInt8(name) IN (1, 2, 3); 55 | QUERY PLAN 56 | ------------------------------------------------------------------------------------ 57 | Foreign Scan on public.things 58 | Output: num 59 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt8(name) IN (1,2,3))) 60 | (3 rows) 61 | 62 | SELECT num FROM things WHERE toUInt8(name) IN (1, 2, 3); 63 | num 64 | ----- 65 | 1 66 | 2 67 | 3 68 | (3 rows) 69 | 70 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint16(num) IN (8, 3, 5); 71 | QUERY PLAN 72 | ------------------------------------------------------------------------------------ 73 | Foreign Scan on public.things 74 | Output: num 75 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt16(num) IN (8,3,5))) 76 | (3 rows) 77 | 78 | SELECT num FROM things WHERE toUint16(num) IN (8, 3, 5); 79 | num 80 | ----- 81 | 3 82 | 5 83 | 8 84 | (3 rows) 85 | 86 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint16(name) IN (1, 2, 3); 87 | QUERY PLAN 88 | ------------------------------------------------------------------------------------- 89 | Foreign Scan on public.things 90 | Output: num 91 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt16(name) IN (1,2,3))) 92 | (3 rows) 93 | 94 | SELECT num FROM things WHERE toUint16(name) IN (1, 2, 3); 95 | num 96 | ----- 97 | 1 98 | 2 99 | 3 100 | (3 rows) 101 | 102 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint32(num) IN (8, 3, 5); 103 | QUERY PLAN 104 | ------------------------------------------------------------------------------------ 105 | Foreign Scan on public.things 106 | Output: num 107 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt32(num) IN (8,3,5))) 108 | (3 rows) 109 | 110 | SELECT num FROM things WHERE toUint32(num) IN (8, 3, 5); 111 | num 112 | ----- 113 | 3 114 | 5 115 | 8 116 | (3 rows) 117 | 118 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint32(name) IN (1, 2, 3); 119 | QUERY PLAN 120 | ------------------------------------------------------------------------------------- 121 | Foreign Scan on public.things 122 | Output: num 123 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt32(name) IN (1,2,3))) 124 | (3 rows) 125 | 126 | SELECT num FROM things WHERE toUint32(name) IN (1, 2, 3); 127 | num 128 | ----- 129 | 1 130 | 2 131 | 3 132 | (3 rows) 133 | 134 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint64(num) IN (8, 3, 5); 135 | QUERY PLAN 136 | ------------------------------------------------------------------------------------ 137 | Foreign Scan on public.things 138 | Output: num 139 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt64(num) IN (8,3,5))) 140 | (3 rows) 141 | 142 | SELECT num FROM things WHERE toUint64(num) IN (8, 3, 5); 143 | num 144 | ----- 145 | 3 146 | 5 147 | 8 148 | (3 rows) 149 | 150 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint64(name) IN (1, 2, 3); 151 | QUERY PLAN 152 | ------------------------------------------------------------------------------------- 153 | Foreign Scan on public.things 154 | Output: num 155 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt64(name) IN (1,2,3))) 156 | (3 rows) 157 | 158 | SELECT num FROM things WHERE toUint64(name) IN (1, 2, 3); 159 | num 160 | ----- 161 | 1 162 | 2 163 | 3 164 | (3 rows) 165 | 166 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint128(num) IN (8, 3, 5); 167 | QUERY PLAN 168 | ------------------------------------------------------------------------------------- 169 | Foreign Scan on public.things 170 | Output: num 171 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt128(num) IN (8,3,5))) 172 | (3 rows) 173 | 174 | SELECT num FROM things WHERE toUint128(num) IN (8, 3, 5); 175 | num 176 | ----- 177 | 3 178 | 5 179 | 8 180 | (3 rows) 181 | 182 | EXPLAIN (VERBOSE, COSTS OFF) SELECT num FROM things WHERE toUint128(name) IN (1, 2, 3); 183 | QUERY PLAN 184 | -------------------------------------------------------------------------------------- 185 | Foreign Scan on public.things 186 | Output: num 187 | Remote SQL: SELECT num FROM casts_test.things WHERE ((toUInt128(name) IN (1,2,3))) 188 | (3 rows) 189 | 190 | SELECT num FROM things WHERE toUint128(name) IN (1, 2, 3); 191 | num 192 | ----- 193 | 1 194 | 2 195 | 3 196 | (3 rows) 197 | 198 | DROP USER MAPPING FOR CURRENT_USER SERVER casts_loopback; 199 | SELECT clickhouse_raw_query('DROP DATABASE casts_test'); 200 | clickhouse_raw_query 201 | ---------------------- 202 | 203 | (1 row) 204 | 205 | DROP SERVER casts_loopback CASCADE; 206 | NOTICE: drop cascades to foreign table things 207 | -------------------------------------------------------------------------------- /sql/pg_clickhouse.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION pg_clickhouse" to load this file. \quit 3 | 4 | -- Set up the FDW. 5 | CREATE FUNCTION clickhouse_fdw_handler() 6 | RETURNS fdw_handler 7 | AS 'MODULE_PATHNAME' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION clickhouse_raw_query(TEXT, TEXT DEFAULT 'host=localhost port=8123') 11 | RETURNS TEXT 12 | AS 'MODULE_PATHNAME' 13 | LANGUAGE C STRICT; 14 | 15 | CREATE FUNCTION clickhouse_fdw_validator(text[], oid) 16 | RETURNS VOID 17 | AS 'MODULE_PATHNAME' 18 | LANGUAGE C STRICT; 19 | 20 | CREATE FOREIGN DATA WRAPPER clickhouse_fdw 21 | HANDLER clickhouse_fdw_handler 22 | VALIDATOR clickhouse_fdw_validator; 23 | 24 | -- Function used by variadic aggregate functions when pushdown fails. The 25 | -- first argument should describe the operation that should have been pushed 26 | -- down. 27 | CREATE FUNCTION ch_push_agg_text(TEXT, VARIADIC "any") RETURNS TEXT 28 | AS 'MODULE_PATHNAME', 'clickhouse_op_push_fail' 29 | LANGUAGE C STRICT; 30 | 31 | -- Function used by aggregates that take a single value of any type. 32 | CREATE FUNCTION ch_any_text(TEXT, "any") RETURNS TEXT 33 | AS 'MODULE_PATHNAME', 'clickhouse_op_push_fail' 34 | LANGUAGE C STRICT; 35 | 36 | -- No-op functions used for aggregate final functions with specific types. 37 | -- Allows their states to be text. Return NULL. 38 | CREATE FUNCTION ch_noop_bigint(TEXT) RETURNS BIGINT 39 | AS 'MODULE_PATHNAME', 'clickhouse_noop' 40 | LANGUAGE C STRICT; 41 | 42 | CREATE FUNCTION ch_noop_float8(TEXT) RETURNS float8 43 | AS 'MODULE_PATHNAME', 'clickhouse_noop' 44 | LANGUAGE C STRICT; 45 | 46 | CREATE FUNCTION ch_noop_float8_float8(TEXT, float8) RETURNS float8 47 | AS 'MODULE_PATHNAME', 'clickhouse_noop' 48 | LANGUAGE C STRICT; 49 | 50 | -- Create error-raising argMax aggregate that should be pushed down to 51 | -- ClickHouse. 52 | CREATE FUNCTION ch_argmax(anyelement, anyelement, anycompatible) 53 | RETURNS anyelement AS $$ 54 | BEGIN 55 | RAISE 'pg_clickhouse: failed to push down aggregate argMax()' 56 | USING ERRCODE = 'fdw_error'; 57 | END; 58 | $$ 59 | LANGUAGE 'plpgsql' IMMUTABLE; 60 | 61 | CREATE AGGREGATE argMax(anyelement, anycompatible) 62 | ( 63 | sfunc = ch_argmax, 64 | stype = anyelement 65 | ); 66 | 67 | -- Create error-raising argMin aggregate that should be pushed down to 68 | -- ClickHouse. 69 | CREATE FUNCTION ch_argmin(anyelement, anyelement, anycompatible) 70 | RETURNS anyelement AS $$ 71 | BEGIN 72 | RAISE 'pg_clickhouse: failed to push down aggregate argMin()' 73 | USING ERRCODE = 'fdw_error'; 74 | END; 75 | $$ 76 | LANGUAGE 'plpgsql' IMMUTABLE; 77 | 78 | CREATE AGGREGATE argMin(anyelement, anycompatible) 79 | ( 80 | sfunc = ch_argmin, 81 | stype = anyelement 82 | ); 83 | 84 | CREATE AGGREGATE quantile(float8 ORDER BY "any") 85 | ( 86 | SFUNC = ch_any_text, -- raises error 87 | INITCOND = 'aggregate quantile()', -- what to push down 88 | STYPE = TEXT, -- state type 89 | FINALFUNC = ch_noop_float8_float8 -- returns NULL 90 | ); 91 | 92 | CREATE AGGREGATE quantile("any") 93 | ( 94 | SFUNC = ch_any_text, -- raises error 95 | INITCOND = 'aggregate quantile()', -- what to push down 96 | STYPE = TEXT, -- state type 97 | FINALFUNC = ch_noop_float8 -- returns NULL 98 | ); 99 | 100 | CREATE AGGREGATE quantileExact(float8 ORDER BY "any") 101 | ( 102 | SFUNC = ch_any_text, -- raises error 103 | INITCOND = 'aggregate quantileExact()', -- what to push down 104 | STYPE = TEXT, -- state type 105 | FINALFUNC = ch_noop_float8_float8 -- returns NULL 106 | ); 107 | 108 | CREATE AGGREGATE quantileExact("any") 109 | ( 110 | SFUNC = ch_any_text, -- raises error 111 | INITCOND = 'aggregate quantileExact()', -- what to push down 112 | STYPE = TEXT, -- state type 113 | FINALFUNC = ch_noop_float8 -- returns NULL 114 | ); 115 | 116 | -- Variadic aggregates that take any number of arguments of any type and 117 | -- return a UINT64 (we settle for BIGINT). 118 | CREATE AGGREGATE uniq(VARIADIC "any") 119 | ( 120 | SFUNC = ch_push_agg_text, -- raises error 121 | INITCOND = 'aggregate uniq()', -- what to push down 122 | STYPE = TEXT, -- state type 123 | FINALFUNC = ch_noop_bigint -- returns NULL 124 | ); 125 | 126 | CREATE AGGREGATE uniqExact(VARIADIC "any") 127 | ( 128 | SFUNC = ch_push_agg_text, 129 | INITCOND = 'aggregate uniqExact()', 130 | STYPE = TEXT, 131 | FINALFUNC = ch_noop_bigint 132 | ); 133 | 134 | CREATE AGGREGATE uniqCombined(VARIADIC "any") 135 | ( 136 | SFUNC = ch_push_agg_text, 137 | INITCOND = 'aggregate uniqCombined()', 138 | STYPE = TEXT, 139 | FINALFUNC = ch_noop_bigint 140 | ); 141 | 142 | CREATE AGGREGATE uniqCombined64(VARIADIC "any") 143 | ( 144 | SFUNC = ch_push_agg_text, 145 | INITCOND = 'aggregate uniqCombined64()', 146 | STYPE = TEXT, 147 | FINALFUNC = ch_noop_bigint 148 | ); 149 | 150 | CREATE AGGREGATE uniqHLL12(VARIADIC "any") 151 | ( 152 | SFUNC = ch_push_agg_text, 153 | INITCOND = 'aggregate uniqHLL12()', 154 | STYPE = TEXT, 155 | FINALFUNC = ch_noop_bigint 156 | ); 157 | 158 | CREATE AGGREGATE uniqTheta(VARIADIC "any") 159 | ( 160 | SFUNC = ch_push_agg_text, 161 | INITCOND = 'aggregate uniqTheta()', 162 | STYPE = TEXT, 163 | FINALFUNC = ch_noop_bigint 164 | ); 165 | 166 | /* 167 | * XXX Other variadic aggregates to add: 168 | * 169 | * ❯ rg -Fl. 'variable number of parameters' 170 | * docs/en/sql-reference/aggregate-functions/reference/corrmatrix.md 171 | * docs/en/sql-reference/aggregate-functions/reference/covarsampmatrix.md 172 | * docs/en/sql-reference/aggregate-functions/reference/covarpopmatrix.md 173 | * 174 | * Plus variadic hashing functions: 175 | * https://clickhouse.com/docs/sql-reference/functions/hash-functions 176 | */ 177 | 178 | -- Create error-raising functions that should be pushed down to ClickHouse. 179 | CREATE FUNCTION dictGet(TEXT, TEXT, ANYELEMENT) RETURNS TEXT 180 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 181 | LANGUAGE C STRICT; 182 | 183 | -- Create error-raising functions used for casting to ClickHouse unsigned integers. 184 | CREATE FUNCTION toUInt8("any") RETURNS smallint 185 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 186 | LANGUAGE C STRICT; 187 | 188 | CREATE FUNCTION toUInt16("any") RETURNS smallint 189 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 190 | LANGUAGE C STRICT; 191 | 192 | CREATE FUNCTION toUInt32("any") RETURNS INTEGER 193 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 194 | LANGUAGE C STRICT; 195 | 196 | CREATE FUNCTION toUInt64("any") RETURNS BIGINT 197 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 198 | LANGUAGE C STRICT; 199 | 200 | CREATE FUNCTION toUInt128("any") RETURNS BIGINT 201 | AS 'MODULE_PATHNAME', 'clickhouse_push_fail' 202 | LANGUAGE C STRICT; 203 | -------------------------------------------------------------------------------- /src/shipable.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * shippable.c 4 | * Determine which database objects are shippable to a remote server. 5 | * 6 | * Portions Copyright (c) 2012-2019, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2019-2022, Adjust GmbH 8 | * Copyright (c) 2025, ClickHouse, Inc. 9 | * 10 | * IDENTIFICATION 11 | * github.com/clickhouse/pg_clickhouse/src/shippable.c 12 | * 13 | *------------------------------------------------------------------------- 14 | */ 15 | 16 | #include "postgres.h" 17 | 18 | #include "fdw.h" 19 | 20 | #include "access/transam.h" 21 | #include "catalog/dependency.h" 22 | #include "catalog/pg_proc.h" 23 | #include "catalog/pg_type.h" 24 | #include "catalog/pg_operator.h" 25 | #include "utils/hsearch.h" 26 | #include "utils/inval.h" 27 | #include "utils/syscache.h" 28 | 29 | 30 | /* Hash table for caching the results of shippability lookups */ 31 | static HTAB * ShippableCacheHash = NULL; 32 | 33 | /* 34 | * Hash key for shippability lookups. We include the FDW server OID because 35 | * decisions may differ per-server. Otherwise, objects are identified by 36 | * their (local!) OID and catalog OID. 37 | */ 38 | typedef struct 39 | { 40 | /* XXX we assume this struct contains no padding bytes */ 41 | Oid objid; /* function/operator/type OID */ 42 | Oid classid; /* OID of its catalog (pg_proc, etc) */ 43 | Oid serverid; /* FDW server we are concerned with */ 44 | } ShippableCacheKey; 45 | 46 | typedef struct 47 | { 48 | ShippableCacheKey key; /* hash key - must be first */ 49 | bool shippable; 50 | } ShippableCacheEntry; 51 | 52 | 53 | /* 54 | * Flush cache entries when pg_foreign_server is updated. 55 | * 56 | * We do this because of the possibility of ALTER SERVER being used to change 57 | * a server's extensions option. We do not currently bother to check whether 58 | * objects' extension membership changes once a shippability decision has been 59 | * made for them, however. 60 | */ 61 | static void 62 | InvalidateShippableCacheCallback(Datum arg, int cacheid, uint32 hashvalue) 63 | { 64 | HASH_SEQ_STATUS status; 65 | ShippableCacheEntry *entry; 66 | 67 | /* 68 | * In principle we could flush only cache entries relating to the 69 | * pg_foreign_server entry being outdated; but that would be more 70 | * complicated, and it's probably not worth the trouble. So for now, just 71 | * flush all entries. 72 | */ 73 | hash_seq_init(&status, ShippableCacheHash); 74 | while ((entry = (ShippableCacheEntry *) hash_seq_search(&status)) != NULL) 75 | { 76 | if (hash_search(ShippableCacheHash, 77 | (void *) &entry->key, 78 | HASH_REMOVE, 79 | NULL) == NULL) 80 | { 81 | elog(ERROR, "hash table corrupted"); 82 | } 83 | } 84 | } 85 | 86 | /* 87 | * Initialize the backend-lifespan cache of shippability decisions. 88 | */ 89 | static void 90 | InitializeShippableCache(void) 91 | { 92 | HASHCTL ctl; 93 | 94 | /* Create the hash table. */ 95 | MemSet(&ctl, 0, sizeof(ctl)); 96 | ctl.keysize = sizeof(ShippableCacheKey); 97 | ctl.entrysize = sizeof(ShippableCacheEntry); 98 | ShippableCacheHash = 99 | hash_create("Shippability cache", 256, &ctl, HASH_ELEM | HASH_BLOBS); 100 | 101 | /* Set up invalidation callback on pg_foreign_server. */ 102 | CacheRegisterSyscacheCallback(FOREIGNSERVEROID, 103 | InvalidateShippableCacheCallback, 104 | (Datum) 0); 105 | } 106 | 107 | /* 108 | * Returns true if given object (operator/function/type) is shippable 109 | * according to the server options. 110 | * 111 | * Right now "shippability" is exclusively a function of whether the object 112 | * belongs to an extension declared by the user. In the future we could 113 | * additionally have a whitelist of functions/operators declared one at a time. 114 | */ 115 | static bool 116 | lookup_shippable(Oid objectId, Oid classId, CHFdwRelationInfo * fpinfo) 117 | { 118 | Oid extensionOid; 119 | 120 | /* 121 | * Is object a member of some extension? (Note: this is a fairly 122 | * expensive lookup, which is why we try to cache the results.) 123 | */ 124 | extensionOid = getExtensionOfObject(classId, objectId); 125 | 126 | /* If so, is that extension in fpinfo->shippable_extensions? */ 127 | if (OidIsValid(extensionOid) && 128 | list_member_oid(fpinfo->shippable_extensions, extensionOid)) 129 | { 130 | return true; 131 | } 132 | 133 | return false; 134 | } 135 | 136 | /* 137 | * Return true if given object is one of PostgreSQL's built-in objects. 138 | * 139 | * We use FirstUnpinnedObjectId as the cutoff, so that we only consider 140 | * objects with hand-assigned OIDs to be "built in", not for instance any 141 | * function or type defined in the information_schema. 142 | * 143 | * Our constraints for dealing with types are tighter than they are for 144 | * functions or operators: we want to accept only types that are in pg_catalog, 145 | * else deparse_type_name might incorrectly fail to schema-qualify their names. 146 | * Thus we must exclude information_schema types. 147 | * 148 | * XXX there is a problem with this, which is that the set of built-in 149 | * objects expands over time. Something that is built-in to us might not 150 | * be known to the remote server, if it's of an older version. But keeping 151 | * track of that would be a huge exercise. 152 | */ 153 | bool 154 | chfdw_is_builtin(Oid objectId) 155 | { 156 | return (objectId < FirstUnpinnedObjectId); 157 | } 158 | 159 | /* 160 | * chfdw_is_shippable 161 | * Is this object (function/operator/type) shippable to foreign server? 162 | */ 163 | bool 164 | chfdw_is_shippable(Oid objectId, Oid classId, CHFdwRelationInfo * fpinfo, 165 | CustomObjectDef * *outcdef) 166 | { 167 | ShippableCacheKey key; 168 | ShippableCacheEntry *entry; 169 | 170 | /* Built-in objects are presumed shippable. */ 171 | if (chfdw_is_builtin(objectId)) 172 | return true; 173 | 174 | if (classId == ProcedureRelationId) 175 | { 176 | CustomObjectDef *cdef = chfdw_check_for_custom_function(objectId); 177 | 178 | if (outcdef != NULL) 179 | *outcdef = cdef; 180 | 181 | return (cdef && cdef->cf_type != CF_UNSHIPPABLE); 182 | } 183 | else if (classId == TypeRelationId && chfdw_check_for_custom_type(objectId) != NULL) 184 | return true; 185 | else if (classId == OperatorRelationId && chfdw_check_for_custom_operator(objectId, NULL) != NULL) 186 | return true; 187 | 188 | /* Otherwise, give up if user hasn't specified any shippable extensions. */ 189 | if (fpinfo->shippable_extensions == NIL) 190 | return false; 191 | 192 | /* Initialize cache if first time through. */ 193 | if (!ShippableCacheHash) 194 | { 195 | InitializeShippableCache(); 196 | } 197 | 198 | /* Set up cache hash key */ 199 | key.objid = objectId; 200 | key.classid = classId; 201 | key.serverid = fpinfo->server->serverid; 202 | 203 | /* See if we already cached the result. */ 204 | entry = (ShippableCacheEntry *) 205 | hash_search(ShippableCacheHash, 206 | (void *) &key, 207 | HASH_FIND, 208 | NULL); 209 | 210 | if (!entry) 211 | { 212 | /* Not found in cache, so perform shippability lookup. */ 213 | bool shippable = lookup_shippable(objectId, classId, fpinfo); 214 | 215 | /* 216 | * Don't create a new hash entry until *after* we have the shippable 217 | * result in hand, as the underlying catalog lookups might trigger a 218 | * cache invalidation. 219 | */ 220 | entry = (ShippableCacheEntry *) 221 | hash_search(ShippableCacheHash, 222 | (void *) &key, 223 | HASH_ENTER, 224 | NULL); 225 | 226 | entry->shippable = shippable; 227 | } 228 | 229 | return entry->shippable; 230 | } 231 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = $(shell grep -m 1 '"name":' META.json | \ 2 | sed -e 's/[[:space:]]*"name":[[:space:]]*"\([^"]*\)",/\1/') 3 | EXTVERSION = $(shell grep -m 1 'default_version' pg_clickhouse.control | \ 4 | sed -e "s/[[:space:]]*default_version[[:space:]]*=[[:space:]]*'\([^']*\)',\{0,1\}/\1/") 5 | DISTVERSION = $(shell grep -m 1 '[[:space:]]\{3\}"version":' META.json | \ 6 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 7 | 8 | DATA = $(wildcard sql/$(EXTENSION)--*.sql) 9 | DOCS = $(wildcard doc/*.md) 10 | TESTS = $(wildcard test/sql/*.sql) 11 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 12 | REGRESS_OPTS = --inputdir=test --load-extension=$(EXTENSION) 13 | PG_CONFIG ?= pg_config 14 | MODULE_big = $(EXTENSION) 15 | CURL_CONFIG ?= curl-config 16 | OS ?= $(shell uname -s | tr A-Z a-z) 17 | ARCH = $(shell uname -m) 18 | 19 | # Collect all the C++ and C files to compile into MODULE_big. 20 | OBJS = $(sort \ 21 | $(subst .cpp,.o, $(wildcard src/*.cpp src/*/*.cpp)) \ 22 | $(subst .c.in,.o, $(wildcard src/*.c.in src/*/*.c)) \ 23 | $(subst .c,.o, $(wildcard src/*.c src/*/*.c)) \ 24 | ) 25 | 26 | # clickhouse-cpp source and build directories. 27 | CH_CPP_DIR = vendor/clickhouse-cpp 28 | CH_CPP_BUILD_DIR = vendor/_build/$(OS)-$(ARCH) 29 | 30 | # List the clickhouse-cpp libraries we require. 31 | CH_CPP_LIB = $(CH_CPP_BUILD_DIR)/clickhouse/libclickhouse-cpp-lib$(DLSUFFIX) 32 | CH_CPP_FLAGS = -D CMAKE_BUILD_TYPE=Release -D WITH_OPENSSL=ON 33 | 34 | # Build static on Darwin by default. 35 | ifndef ($(CH_BUILD)) 36 | # ifeq ($(OS),darwin) 37 | CH_BUILD = static 38 | # endif 39 | endif 40 | 41 | # Are we statically compiling clickhouse-cpp into the extension or no? 42 | ifeq ($(CH_BUILD), static) 43 | # We'll need all the clickhouse-cpp static libraries. 44 | CH_CPP_LIB = $(CH_CPP_BUILD_DIR)/clickhouse/libclickhouse-cpp-lib.a 45 | SHLIB_LINK = $(CH_CPP_LIB) \ 46 | $(CH_CPP_BUILD_DIR)/contrib/cityhash/cityhash/libcityhash.a \ 47 | $(CH_CPP_BUILD_DIR)/contrib/absl/absl/libabsl_int128.a \ 48 | $(CH_CPP_BUILD_DIR)/contrib/lz4/lz4/liblz4.a \ 49 | $(CH_CPP_BUILD_DIR)/contrib/zstd/zstd/libzstdstatic.a 50 | else 51 | # Build and install the shared library. 52 | SHLIB_LINK = -L$(CH_CPP_BUILD_DIR)/clickhouse -lclickhouse-cpp-lib 53 | CH_CPP_FLAGS += -D BUILD_SHARED_LIBS=ON 54 | endif 55 | 56 | # Add include directories. 57 | PG_CPPFLAGS = -I./src/include -I$(CH_CPP_DIR) -I$(CH_CPP_DIR)/contrib/absl 58 | 59 | # Include other libraries compiled into clickhouse-cpp. 60 | PG_LDFLAGS = -lstdc++ -lssl -lcrypto $(shell $(CURL_CONFIG) --libs) 61 | 62 | # clickhouse-cpp requires C++ v17. 63 | PG_CXXFLAGS = -std=c++17 64 | 65 | # Suppress annoying pre-c99 warning and include curl flags. 66 | PG_CFLAGS = -Wno-declaration-after-statement $(shell $(CURL_CONFIG) --cflags) 67 | 68 | # We'll need libuuid except on darwin, where it's included in the OS. 69 | ifneq ($(OS),darwin) 70 | PG_LDFLAGS += -luuid 71 | endif 72 | 73 | # Clean up the clickhouse-cpp build directory and generated files. 74 | EXTRA_CLEAN = $(CH_CPP_BUILD_DIR) sql/$(EXTENSION)--$(EXTVERSION).sql src/fdw.c compile_commands.json 75 | 76 | # Import PGXS. 77 | PGXS := $(shell $(PG_CONFIG) --pgxs) 78 | include $(PGXS) 79 | 80 | # We'll need the clickhouse-cpp library and rpath so it can be found. 81 | SHLIB_LINK += -Wl,-rpath,$(pkglibdir)/ 82 | 83 | # PostgresSQL 15 and earlier violate a C++ v17 storage specifier error. 84 | ifeq ($(shell test $(MAJORVERSION) -lt 16; echo $$?),0) 85 | PG_CXXFLAGS += -Wno-register 86 | endif 87 | 88 | # Add the flags to the bitcode compiler variables. 89 | COMPILE.cc.bc += $(PG_CPPFLAGS) 90 | COMPILE.cxx.bc += $(PG_CXXFLAGS) 91 | 92 | # shlib is the final output product: clickhouse-cpp and all .o dependencies. 93 | $(shlib): $(CH_CPP_LIB) $(OBJS) 94 | 95 | # Clone clickhouse-cpp submodule. 96 | $(CH_CPP_DIR)/CMakeLists.txt: 97 | git submodule update --init 98 | 99 | # Require the vendored clickhouse-cpp. 100 | $(OBJS): $(CH_CPP_DIR)/CMakeLists.txt 101 | 102 | # Build clickhouse-cpp. 103 | $(CH_CPP_LIB): export CXXFLAGS=-fPIC 104 | $(CH_CPP_LIB): export CFLAGS=-fPIC 105 | $(CH_CPP_LIB): $(CH_CPP_DIR)/CMakeLists.txt 106 | cmake -B $(CH_CPP_BUILD_DIR) -S $(CH_CPP_DIR) $(CH_CPP_FLAGS) -DCMAKE_EXPORT_COMPILE_COMMANDS=ON 107 | cmake --build $(CH_CPP_BUILD_DIR) --parallel $(nproc) --target all 108 | 109 | # Require the versioned C source and SQL script. 110 | all: sql/$(EXTENSION)--$(EXTVERSION).sql src/fdw.c 111 | 112 | # Versioned SQL script. 113 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 114 | cp $< $@ 115 | 116 | # Versioned source file. 117 | src/fdw.c: src/fdw.c.in 118 | sed -e 's,__VERSION__,$(DISTVERSION),g' $< > $@ 119 | 120 | # Configure the installation of the clickhouse-cpp library. 121 | ifeq ($(CH_BUILD), static) 122 | install-ch-cpp: 123 | else 124 | # Copy all dynamic files; use -a to preserve symlinks. 125 | install-ch-cpp: $(CH_CPP_LIB) $(shlib) 126 | cp -a $(CH_CPP_BUILD_DIR)/clickhouse/libclickhouse-cpp-lib*$(DLSUFFIX)* $(DESTDIR)$(pkglibdir)/ 127 | endif 128 | 129 | install: install-ch-cpp 130 | 131 | # Build a PGXN distribution bundle. 132 | dist: $(EXTENSION)-$(DISTVERSION).zip 133 | 134 | $(EXTENSION)-$(DISTVERSION).zip: 135 | git archive-all -v --prefix "$(EXTENSION)-$(DISTVERSION)/" --force-submodules $(EXTENSION)-$(DISTVERSION).zip 136 | 137 | # Test the PGXN distribution. 138 | dist-test: $(EXTENSION)-$(DISTVERSION).zip 139 | unzip $(EXTENSION)-$(DISTVERSION).zip 140 | cd $(EXTENSION)-$(DISTVERSION) 141 | make && make install && make installcheck 142 | 143 | .PHONY: release-notes # Show release notes for current version (must have `mknotes` in PATH). 144 | release-notes: CHANGELOG.md 145 | mknotes -v v$(DISTVERSION) -f $< -r https://github.com/$(or $(GITHUB_REPOSITORY),ClickHouse/pg_clickhouse) 146 | 147 | .PHONY: tempcheck # Run tests with a temporary PostgreSQL instance 148 | tempcheck: install 149 | $(pg_regress_installcheck) --temp-instance=/tmp/pg_clickhouse_test $(REGRESS_OPTS) $(REGRESS) 150 | 151 | # Run `make installcheck` and copy all result files to test/expected/. Use for 152 | # basic test changes with the latest version of Postgres, but be aware that 153 | # alternate `_n.out` files will not be updated. 154 | # 155 | # DO NOT RUN UNLESS YOU'RE CERTAIN ALL YOUR TESTS ARE PASSING! 156 | .PHONY: results 157 | results: 158 | $(MAKE) installcheck || true 159 | rsync -rlpgovP results/ test/expected 160 | 161 | # Run make print-VARIABLE_NAME to print VARIABLE_NAME's flavor and value. 162 | print-% : ; $(info $* is $(flavor $*) variable set to "$($*)") @true 163 | 164 | # OCI images. 165 | REGISTRY ?= localhost:5001 166 | REVISION := $(shell git rev-parse --short HEAD) 167 | PLATFORMS ?= linux/amd64,linux/arm64 168 | PG_VERSIONS ?= 18,17,16,15,14,13 169 | .PHONY: image # Build the linux/amd64 OCI image. 170 | image: 171 | registry=$(REGISTRY) version=$(DISTVERSION) revision=$(REVISION) pg_versions=$(PG_VERSIONS) \ 172 | docker buildx bake --set "*.platform=$(PLATFORMS)" \ 173 | $(if $(filter true,$(PUSH)),--push,) \ 174 | $(if $(filter true,$(LOAD)),--load,) \ 175 | 176 | bake-vars: 177 | @echo "registry=$(REGISTRY)" 178 | @echo "version=$(DISTVERSION)" 179 | @echo "revision=$(REVISION)" 180 | @echo "pg_versions=$(PG_VERSIONS)" 181 | 182 | # Format the .c and .h files according to the PostgreSQL indentation standard. 183 | # Requires `pg_bsd_indent` to be in the path. 184 | indent: 185 | @for fn in $(wildcard src/*.c.in src/*.c src/*/*.hh src/*/*.cpp); do printf "%s\n" "$$fn"; pg_bsd_indent -bad -bap -bbb -bc -bl -cli1 -cp33 -cdb -nce -d0 -di12 -nfc1 -i4 -l79 -lp -lpl -nip -npro -sac -tpg -ts4 "$$fn"; done 186 | @rm *.BAK 187 | 188 | .PHONY: lsp # Generate compile_commands.json for IDE/clangd support. 189 | lsp: compile_commands.json 190 | 191 | # Requires https://github.com/rizsotto/Bear. 192 | compile_commands.json: 193 | $(MAKE) clean 194 | bear -- $(MAKE) all 195 | -------------------------------------------------------------------------------- /src/http.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | #include 4 | #include 5 | #include 6 | #include 7 | 8 | #include 9 | #include 10 | #include 11 | 12 | #define DATABASE_HEADER "X-ClickHouse-Database" 13 | 14 | static char curl_error_buffer[CURL_ERROR_SIZE]; 15 | static bool curl_error_happened = false; 16 | static long curl_verbose = 0; 17 | static void *curl_progressfunc = NULL; 18 | static bool curl_initialized = false; 19 | static char ch_query_id_prefix[5]; 20 | 21 | void 22 | ch_http_init(int verbose, uint32_t query_id_prefix) 23 | { 24 | curl_verbose = verbose; 25 | snprintf(ch_query_id_prefix, 5, "%x", query_id_prefix); 26 | 27 | if (!curl_initialized) 28 | { 29 | curl_initialized = true; 30 | curl_global_init(CURL_GLOBAL_ALL); 31 | } 32 | } 33 | 34 | void 35 | ch_http_set_progress_func(void *progressfunc) 36 | { 37 | curl_progressfunc = progressfunc; 38 | } 39 | 40 | static size_t write_data(void *contents, size_t size, size_t nmemb, void *userp) 41 | { 42 | size_t realsize = size * nmemb; 43 | ch_http_response_t *res = userp; 44 | 45 | if (res->data == NULL) 46 | res->data = malloc(realsize + 1); 47 | else 48 | res->data = realloc(res->data, res->datasize + realsize + 1); 49 | 50 | memcpy(&(res->data[res->datasize]), contents, realsize); 51 | res->datasize += realsize; 52 | res->data[res->datasize] = 0; 53 | 54 | return realsize; 55 | } 56 | 57 | #define CLICKHOUSE_PORT 8123 58 | #define CLICKHOUSE_TLS_PORT 8443 59 | #define HTTP_TLS_PORT 443 60 | 61 | ch_http_connection_t * 62 | ch_http_connection(ch_connection_details * details) 63 | { 64 | int n; 65 | char *connstring = NULL; 66 | size_t len = 20; /* all symbols from url string + some extra */ 67 | char *host = details->host, 68 | *username = details->username, 69 | *password = details->password; 70 | int port = details->port; 71 | 72 | curl_error_happened = false; 73 | ch_http_connection_t *conn = calloc(sizeof(ch_http_connection_t), 1); 74 | 75 | if (!conn) 76 | goto cleanup; 77 | 78 | conn->curl = curl_easy_init(); 79 | if (!conn->curl) 80 | goto cleanup; 81 | 82 | conn->dbname = details->dbname ? strdup(details->dbname) : NULL; 83 | 84 | 85 | if (!host || !*host) 86 | host = "localhost"; 87 | 88 | if (!port) 89 | port = ch_is_cloud_host(host) ? CLICKHOUSE_TLS_PORT : CLICKHOUSE_PORT; 90 | 91 | len += strlen(host) + snprintf(NULL, 0, "%d", port); 92 | 93 | if (username) 94 | { 95 | username = curl_easy_escape(conn->curl, username, 0); 96 | len += strlen(username); 97 | } 98 | 99 | if (password) 100 | { 101 | password = curl_easy_escape(conn->curl, password, 0); 102 | len += strlen(password); 103 | } 104 | 105 | connstring = calloc(len, 1); 106 | if (!connstring) 107 | goto cleanup; 108 | 109 | char *scheme = port == CLICKHOUSE_TLS_PORT || port == HTTP_TLS_PORT ? "https" : "http"; 110 | 111 | if (username && password) 112 | { 113 | n = snprintf(connstring, len, "%s://%s:%s@%s:%d/", scheme, username, password, host, port); 114 | curl_free(username); 115 | curl_free(password); 116 | } 117 | else if (username) 118 | { 119 | n = snprintf(connstring, len, "%s://%s@%s:%d/", scheme, username, host, port); 120 | curl_free(username); 121 | } 122 | else 123 | n = snprintf(connstring, len, "%s://%s:%d/", scheme, host, port); 124 | 125 | if (n < 0) 126 | goto cleanup; 127 | 128 | conn->base_url = connstring; 129 | 130 | return conn; 131 | 132 | cleanup: 133 | snprintf(curl_error_buffer, CURL_ERROR_SIZE, "OOM"); 134 | curl_error_happened = true; 135 | if (connstring) 136 | free(connstring); 137 | 138 | if (conn) 139 | free(conn); 140 | 141 | return NULL; 142 | } 143 | 144 | static void 145 | set_query_id(ch_http_response_t * resp) 146 | { 147 | uuid_t id; 148 | 149 | uuid_generate(id); 150 | uuid_unparse(id, resp->query_id); 151 | } 152 | 153 | ch_http_response_t * 154 | ch_http_simple_query(ch_http_connection_t * conn, const ch_query * query) 155 | { 156 | char *url; 157 | CURLcode errcode; 158 | static char errbuffer[CURL_ERROR_SIZE]; 159 | struct curl_slist *headers = NULL; 160 | CURLU *cu = curl_url(); 161 | ListCell *lc; 162 | DefElem *setting; 163 | char *buf = NULL; 164 | 165 | ch_http_response_t *resp = calloc(sizeof(ch_http_response_t), 1); 166 | 167 | if (resp == NULL) 168 | return NULL; 169 | 170 | set_query_id(resp); 171 | 172 | assert(conn && conn->curl); 173 | 174 | /* Construct the base URL with the query ID. */ 175 | curl_url_set(cu, CURLUPART_URL, conn->base_url, 0); 176 | buf = psprintf("query_id=%s", resp->query_id); 177 | curl_url_set(cu, CURLUPART_QUERY, buf, CURLU_APPENDQUERY | CURLU_URLENCODE); 178 | pfree(buf); 179 | 180 | /* Append each of the settings as a query param. */ 181 | foreach(lc, (List *) query->settings) 182 | { 183 | setting = (DefElem *) lfirst(lc); 184 | buf = psprintf("%s=%s", setting->defname, strVal(setting->arg)); 185 | curl_url_set(cu, CURLUPART_QUERY, buf, CURLU_APPENDQUERY | CURLU_URLENCODE); 186 | pfree(buf); 187 | } 188 | curl_url_get(cu, CURLUPART_URL, &url, 0); 189 | curl_url_cleanup(cu); 190 | 191 | /* constant */ 192 | errbuffer[0] = '\0'; 193 | curl_easy_reset(conn->curl); 194 | curl_easy_setopt(conn->curl, CURLOPT_WRITEFUNCTION, write_data); 195 | curl_easy_setopt(conn->curl, CURLOPT_ERRORBUFFER, errbuffer); 196 | curl_easy_setopt(conn->curl, CURLOPT_PATH_AS_IS, 1L); 197 | curl_easy_setopt(conn->curl, CURLOPT_URL, url); 198 | curl_easy_setopt(conn->curl, CURLOPT_NOSIGNAL, 1L); 199 | 200 | /* variable */ 201 | curl_easy_setopt(conn->curl, CURLOPT_WRITEDATA, resp); 202 | curl_easy_setopt(conn->curl, CURLOPT_POSTFIELDS, query->sql); 203 | curl_easy_setopt(conn->curl, CURLOPT_VERBOSE, curl_verbose); 204 | if (curl_progressfunc) 205 | { 206 | curl_easy_setopt(conn->curl, CURLOPT_NOPROGRESS, 0L); 207 | curl_easy_setopt(conn->curl, CURLOPT_XFERINFOFUNCTION, curl_progressfunc); 208 | curl_easy_setopt(conn->curl, CURLOPT_XFERINFODATA, conn); 209 | } 210 | else 211 | curl_easy_setopt(conn->curl, CURLOPT_NOPROGRESS, 1L); 212 | if (conn->dbname) 213 | { 214 | headers = curl_slist_append(headers, psprintf("%s: %s", DATABASE_HEADER, conn->dbname)); 215 | curl_easy_setopt(conn->curl, CURLOPT_HTTPHEADER, headers); 216 | } 217 | 218 | curl_error_happened = false; 219 | errcode = curl_easy_perform(conn->curl); 220 | curl_free(url); 221 | if (headers) 222 | curl_slist_free_all(headers); 223 | 224 | 225 | if (errcode == CURLE_ABORTED_BY_CALLBACK) 226 | { 227 | resp->http_status = 418; /* I'm teapot */ 228 | return resp; 229 | } 230 | else if (errcode != CURLE_OK) 231 | { 232 | resp->http_status = 419; /* illegal http status */ 233 | resp->data = strdup(errbuffer); 234 | resp->datasize = strlen(errbuffer); 235 | return resp; 236 | } 237 | 238 | errcode = curl_easy_getinfo(conn->curl, CURLINFO_PRETRANSFER_TIME, 239 | &resp->pretransfer_time); 240 | if (errcode != CURLE_OK) 241 | resp->pretransfer_time = 0; 242 | 243 | errcode = curl_easy_getinfo(conn->curl, CURLINFO_TOTAL_TIME, &resp->total_time); 244 | if (errcode != CURLE_OK) 245 | resp->total_time = 0; 246 | 247 | /* 248 | * All good with request, but we need http status to make sure query went 249 | * ok 250 | */ 251 | curl_easy_getinfo(conn->curl, CURLINFO_RESPONSE_CODE, &resp->http_status); 252 | if (curl_verbose && resp->http_status != 200) 253 | fprintf(stderr, "%s", resp->data); 254 | 255 | return resp; 256 | } 257 | 258 | void 259 | ch_http_close(ch_http_connection_t * conn) 260 | { 261 | free(conn->base_url); 262 | if (conn->dbname) 263 | free(conn->dbname); 264 | curl_easy_cleanup(conn->curl); 265 | } 266 | 267 | char * 268 | ch_http_last_error(void) 269 | { 270 | if (curl_error_happened) 271 | return curl_error_buffer; 272 | 273 | return NULL; 274 | } 275 | 276 | void 277 | ch_http_response_free(ch_http_response_t * resp) 278 | { 279 | if (resp->data) 280 | free(resp->data); 281 | 282 | free(resp); 283 | } 284 | -------------------------------------------------------------------------------- /test/expected/binary_inserts_1.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_inserts_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'binary_inserts_test', driver 'binary'); 3 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 4 | SELECT clickhouse_raw_query('drop database if exists binary_inserts_test'); 5 | clickhouse_raw_query 6 | ---------------------- 7 | 8 | (1 row) 9 | 10 | SELECT clickhouse_raw_query('create database binary_inserts_test'); 11 | clickhouse_raw_query 12 | ---------------------- 13 | 14 | (1 row) 15 | 16 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.ints ( 17 | c1 Int8, c2 Int16, c3 Int32, c4 Int64 18 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 19 | '); 20 | clickhouse_raw_query 21 | ---------------------- 22 | 23 | (1 row) 24 | 25 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.uints ( 26 | c1 UInt8, c2 UInt16, c3 UInt32, c4 UInt64, c5 Bool 27 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 28 | '); 29 | clickhouse_raw_query 30 | ---------------------- 31 | 32 | (1 row) 33 | 34 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.floats ( 35 | c1 Float32, c2 Float64 36 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1) SETTINGS allow_floating_point_partition_key=1; 37 | '); 38 | clickhouse_raw_query 39 | ---------------------- 40 | 41 | (1 row) 42 | 43 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( 44 | c1 Int8, c2 Nullable(Int32) 45 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 46 | '); 47 | clickhouse_raw_query 48 | ---------------------- 49 | 50 | (1 row) 51 | 52 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( 53 | c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) 54 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 55 | '); 56 | clickhouse_raw_query 57 | ---------------------- 58 | 59 | (1 row) 60 | 61 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.arrays ( 62 | c1 Int32, c2 Array(Int32) 63 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 64 | '); 65 | clickhouse_raw_query 66 | ---------------------- 67 | 68 | (1 row) 69 | 70 | IMPORT FOREIGN SCHEMA "binary_inserts_test" FROM SERVER binary_inserts_loopback INTO public; 71 | /* ints */ 72 | INSERT INTO ints 73 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(1, 3) i; 74 | SELECT * FROM ints ORDER BY c1; 75 | c1 | c2 | c3 | c4 76 | ----+----+----+---- 77 | 1 | 2 | 3 | 4 78 | 2 | 3 | 4 | 5 79 | 3 | 4 | 5 | 6 80 | (3 rows) 81 | 82 | INSERT INTO ints (c1, c4, c3, c2) 83 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(4, 6) i; 84 | SELECT * FROM ints ORDER BY c1; 85 | c1 | c2 | c3 | c4 86 | ----+----+----+---- 87 | 1 | 2 | 3 | 4 88 | 2 | 3 | 4 | 5 89 | 3 | 4 | 5 | 6 90 | 4 | 7 | 6 | 5 91 | 5 | 8 | 7 | 6 92 | 6 | 9 | 8 | 7 93 | (6 rows) 94 | 95 | /* check dropping columns (that will change attnums) */ 96 | ALTER TABLE ints DROP COLUMN c1; 97 | ALTER TABLE ints ADD COLUMN c1 SMALLINT; 98 | INSERT INTO ints (c1, c2, c3, c4) 99 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(7, 8) i; 100 | SELECT c1, c2, c3, c4 FROM ints ORDER BY c1; 101 | c1 | c2 | c3 | c4 102 | ----+----+----+---- 103 | 1 | 2 | 3 | 4 104 | 2 | 3 | 4 | 5 105 | 3 | 4 | 5 | 6 106 | 4 | 7 | 6 | 5 107 | 5 | 8 | 7 | 6 108 | 6 | 9 | 8 | 7 109 | 7 | 8 | 9 | 10 110 | 8 | 9 | 10 | 11 111 | (8 rows) 112 | 113 | /* check other number types */ 114 | INSERT INTO uints 115 | SELECT i, i + 1, i + 2, i+ 3, (i % 2)::bool FROM generate_series(1, 3) i; 116 | SELECT * FROM uints ORDER BY c1; 117 | c1 | c2 | c3 | c4 | c5 118 | ----+----+----+----+---- 119 | 1 | 2 | 3 | 4 | t 120 | 2 | 3 | 4 | 5 | f 121 | 3 | 4 | 5 | 6 | t 122 | (3 rows) 123 | 124 | INSERT INTO floats 125 | SELECT i * 1.1, i + 2.1 FROM generate_series(1, 3) i; 126 | SELECT * FROM floats ORDER BY c1; 127 | c1 | c2 128 | -----+----- 129 | 1.1 | 3.1 130 | 2.2 | 4.1 131 | 3.3 | 5.1 132 | (3 rows) 133 | 134 | /* check nullable */ 135 | INSERT INTO null_ints SELECT i, case WHEN i % 2 = 0 THEN NULL ELSE i END FROM generate_series(1, 10) i; 136 | INSERT INTO null_ints(c1) SELECT i FROM generate_series(11, 13) i; 137 | SELECT * FROM null_ints ORDER BY c1; 138 | c1 | c2 139 | ----+---- 140 | 1 | 1 141 | 2 | 142 | 3 | 3 143 | 4 | 144 | 5 | 5 145 | 6 | 146 | 7 | 7 147 | 8 | 148 | 9 | 9 149 | 10 | 150 | 11 | 151 | 12 | 152 | 13 | 153 | (13 rows) 154 | 155 | SELECT * FROM null_ints ORDER BY c1; 156 | c1 | c2 157 | ----+---- 158 | 1 | 1 159 | 2 | 160 | 3 | 3 161 | 4 | 162 | 5 | 5 163 | 6 | 164 | 7 | 7 165 | 8 | 166 | 9 | 9 167 | 10 | 168 | 11 | 169 | 12 | 170 | 13 | 171 | (13 rows) 172 | 173 | /* check dates and strings */ 174 | ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); 175 | \d+ complex 176 | Foreign table "public.complex" 177 | Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description 178 | --------+--------------------------------+-----------+----------+---------+-------------+----------+--------------+------------- 179 | c1 | integer | | not null | | | plain | | 180 | c2 | date | | not null | | | plain | | 181 | c3 | timestamp without time zone | | not null | | | plain | | 182 | c4 | text | | not null | | | extended | | 183 | c5 | character varying(10) | | not null | | | extended | | 184 | c6 | text | | not null | | | extended | | 185 | c7 | timestamp(3) without time zone | | not null | | | plain | | 186 | Server: binary_inserts_loopback 187 | FDW options: (database 'binary_inserts_test', table_name 'complex', engine 'MergeTree') 188 | 189 | INSERT INTO complex VALUES 190 | (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), 191 | (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), 192 | (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); 193 | SELECT * FROM complex ORDER BY c1; 194 | c1 | c2 | c3 | c4 | c5 | c6 | c7 195 | ----+------------+---------------------+----+--------+------+---------------------------- 196 | 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02.122999 197 | 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02.234 198 | 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 199 | (3 rows) 200 | 201 | /* check arrays */ 202 | INSERT INTO arrays VALUES 203 | (1, ARRAY[1,2]), 204 | (2, ARRAY[3,4,5]), 205 | (3, ARRAY[6,4]); 206 | SELECT * FROM arrays ORDER BY c1; 207 | c1 | c2 208 | ----+--------- 209 | 1 | {1,2} 210 | 2 | {3,4,5} 211 | 3 | {6,4} 212 | (3 rows) 213 | 214 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 215 | SELECT clickhouse_raw_query('DROP DATABASE binary_inserts_test'); 216 | clickhouse_raw_query 217 | ---------------------- 218 | 219 | (1 row) 220 | 221 | DROP SERVER binary_inserts_loopback CASCADE; 222 | NOTICE: drop cascades to 6 other objects 223 | DETAIL: drop cascades to foreign table arrays 224 | drop cascades to foreign table complex 225 | drop cascades to foreign table floats 226 | drop cascades to foreign table ints 227 | drop cascades to foreign table null_ints 228 | drop cascades to foreign table uints 229 | -------------------------------------------------------------------------------- /src/connection.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * connection,c 4 | * Connection management functions for pg_clickhouse 5 | * 6 | * Portions Copyright (c) 2012-2019, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2019-2022, Adjust GmbH 8 | * Copyright (c) 2025, ClickHouse, Inc. 9 | * 10 | * IDENTIFICATION 11 | * github.com/clickhouse/pg_clickhouse/src/connection.c 12 | * 13 | *------------------------------------------------------------------------- 14 | */ 15 | 16 | #include "postgres.h" 17 | 18 | #include "access/htup_details.h" 19 | #include "catalog/pg_user_mapping.h" 20 | #include "common/int.h" 21 | #include "access/xact.h" 22 | #include "mb/pg_wchar.h" 23 | #include "miscadmin.h" 24 | #include "pgstat.h" 25 | #include "storage/latch.h" 26 | #include "utils/builtins.h" 27 | #include "utils/hsearch.h" 28 | #include "utils/inval.h" 29 | #include "utils/memutils.h" 30 | #include "utils/syscache.h" 31 | 32 | #include "fdw.h" 33 | 34 | /* 35 | * Connection cache (initialized on first use) 36 | */ 37 | static HTAB * ConnectionHash = NULL; 38 | static void chfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue); 39 | 40 | static ch_connection 41 | clickhouse_connect(ForeignServer * server, UserMapping * user) 42 | { 43 | char *driver = "http"; 44 | 45 | /* default settings */ 46 | ch_connection_details details = {"127.0.0.1", 0, NULL, NULL, "default"}; 47 | 48 | chfdw_extract_options(server->options, &driver, &details.host, 49 | &details.port, &details.dbname, &details.username, &details.password); 50 | chfdw_extract_options(user->options, &driver, &details.host, 51 | &details.port, &details.dbname, &details.username, &details.password); 52 | 53 | if (strcmp(driver, "http") == 0) 54 | { 55 | return chfdw_http_connect(&details); 56 | } 57 | else if (strcmp(driver, "binary") == 0) 58 | { 59 | return chfdw_binary_connect(&details); 60 | } 61 | else 62 | elog(ERROR, "invalid ClickHouse connection driver"); 63 | } 64 | 65 | ch_connection 66 | chfdw_get_connection(UserMapping * user) 67 | { 68 | bool found; 69 | ConnCacheEntry *entry; 70 | ConnCacheKey key; 71 | 72 | /* First time through, initialize connection cache hashtable */ 73 | if (ConnectionHash == NULL) 74 | { 75 | HASHCTL ctl; 76 | 77 | MemSet(&ctl, 0, sizeof(ctl)); 78 | ctl.keysize = sizeof(ConnCacheKey); 79 | ctl.entrysize = sizeof(ConnCacheEntry); 80 | /* allocate ConnectionHash in the cache context */ 81 | ctl.hcxt = CacheMemoryContext; 82 | ConnectionHash = hash_create("pg_clickhouse connections", 8, 83 | &ctl, 84 | HASH_ELEM | HASH_BLOBS | HASH_CONTEXT); 85 | 86 | /* 87 | * Register some callback functions that manage connection cleanup. 88 | * This should be done just once in each backend. 89 | */ 90 | CacheRegisterSyscacheCallback(FOREIGNSERVEROID, 91 | chfdw_inval_callback, (Datum) 0); 92 | CacheRegisterSyscacheCallback(USERMAPPINGOID, 93 | chfdw_inval_callback, (Datum) 0); 94 | } 95 | 96 | /* Create hash key for the entry. Assume no pad bytes in key struct */ 97 | key.userid = user->umid; 98 | 99 | /* 100 | * Find or create cached entry for requested connection. 101 | */ 102 | entry = hash_search(ConnectionHash, &key, HASH_ENTER, &found); 103 | if (!found) 104 | { 105 | /* 106 | * We need only clear "conn" here; remaining fields will be filled 107 | * later when "conn" is set. 108 | */ 109 | entry->gate.conn = NULL; 110 | } 111 | 112 | /* 113 | * If the connection needs to be remade due to invalidation, disconnect as 114 | * soon as we're out of all transactions. 115 | */ 116 | if (entry->gate.conn != NULL && entry->invalidated) 117 | { 118 | elog(LOG, "closing connection to ClickHouse due to invalidation"); 119 | entry->gate.methods->disconnect(entry->gate.conn); 120 | entry->gate.conn = NULL; 121 | } 122 | 123 | /* 124 | * We don't check the health of cached connection here, because it would 125 | * require some overhead. Broken connection will be detected when the 126 | * connection is actually used. 127 | */ 128 | 129 | /* 130 | * If cache entry doesn't have a connection, we have to establish a new 131 | * connection. (If clickhouse_connect throws an error, the cache entry 132 | * will remain in a valid empty state, ie conn == NULL.) 133 | */ 134 | if (entry->gate.conn == NULL) 135 | { 136 | ForeignServer *server = GetForeignServer(user->serverid); 137 | 138 | /* Reset all transient state fields, to be sure all are clean */ 139 | entry->invalidated = false; 140 | entry->server_hashvalue = 141 | GetSysCacheHashValue1(FOREIGNSERVEROID, 142 | ObjectIdGetDatum(server->serverid)); 143 | entry->mapping_hashvalue = 144 | GetSysCacheHashValue1(USERMAPPINGOID, 145 | ObjectIdGetDatum(user->umid)); 146 | 147 | /* Now try to make the connection */ 148 | entry->gate = clickhouse_connect(server, user); 149 | 150 | elog(DEBUG3, 151 | "new pg_clickhouse connection %p for server \"%s\" (user mapping oid %u, userid %u)", 152 | entry->gate.conn, server->servername, user->umid, user->userid); 153 | } 154 | 155 | return entry->gate; 156 | } 157 | 158 | /* 159 | * Connection invalidation callback function 160 | * 161 | * After a change to a pg_foreign_server or pg_user_mapping catalog entry, 162 | * mark connections depending on that entry as needing to be remade. 163 | * We can't immediately destroy them, since they might be in the midst of 164 | * a transaction, but we'll remake them at the next opportunity. 165 | * 166 | * Although most cache invalidation callbacks blow away all the related stuff 167 | * regardless of the given hashvalue, connections are expensive enough that 168 | * it's worth trying to avoid that. 169 | * 170 | * NB: We could avoid unnecessary disconnection more strictly by examining 171 | * individual option values, but it seems too much effort for the gain. 172 | */ 173 | static void 174 | chfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue) 175 | { 176 | HASH_SEQ_STATUS scan; 177 | ConnCacheEntry *entry; 178 | 179 | Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID); 180 | 181 | /* ConnectionHash must exist already, if we're registered */ 182 | hash_seq_init(&scan, ConnectionHash); 183 | while ((entry = (ConnCacheEntry *) hash_seq_search(&scan))) 184 | { 185 | /* Ignore empty entries */ 186 | if (entry->gate.conn == NULL) 187 | continue; 188 | 189 | /* hashvalue == 0 means a cache reset, must clear all state */ 190 | if (hashvalue == 0 || 191 | (cacheid == FOREIGNSERVEROID && 192 | entry->server_hashvalue == hashvalue) || 193 | (cacheid == USERMAPPINGOID && 194 | entry->mapping_hashvalue == hashvalue)) 195 | { 196 | entry->invalidated = true; 197 | } 198 | } 199 | } 200 | 201 | ch_connection_details * 202 | connstring_parse(const char *connstring) 203 | { 204 | ListCell *lc; 205 | List *options = chfdw_parse_options(connstring, false, true); 206 | ch_connection_details *details = palloc0(sizeof(ch_connection_details)); 207 | 208 | if (options == NIL) 209 | return details; 210 | 211 | foreach(lc, options) 212 | { 213 | DefElem *elem = (DefElem *) lfirst(lc); 214 | char *pname = elem->defname; 215 | char *pval = strVal(elem->arg); 216 | 217 | if (strcmp(pname, "host") == 0) 218 | { 219 | details->host = pval; 220 | } 221 | else if (strcmp(pname, "port") == 0) 222 | { 223 | details->port = pg_strtoint32(pval); 224 | } 225 | else if (strcmp(pname, "username") == 0) 226 | { 227 | details->username = pval; 228 | } 229 | else if (strcmp(pname, "password") == 0) 230 | { 231 | details->password = pval; 232 | } 233 | else if (strcmp(pname, "dbname") == 0) 234 | { 235 | details->dbname = pval; 236 | } 237 | else if (strcmp(pname, "") != 0) 238 | { 239 | ereport(ERROR, 240 | (errcode(ERRCODE_SYNTAX_ERROR), 241 | errmsg("pg_clickhouse: invalid connection option \"%s\"", pname))); 242 | } 243 | } 244 | 245 | return details; 246 | } 247 | -------------------------------------------------------------------------------- /test/expected/binary_inserts.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_inserts_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'binary_inserts_test', driver 'binary'); 3 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 4 | SELECT clickhouse_raw_query('drop database if exists binary_inserts_test'); 5 | clickhouse_raw_query 6 | ---------------------- 7 | 8 | (1 row) 9 | 10 | SELECT clickhouse_raw_query('create database binary_inserts_test'); 11 | clickhouse_raw_query 12 | ---------------------- 13 | 14 | (1 row) 15 | 16 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.ints ( 17 | c1 Int8, c2 Int16, c3 Int32, c4 Int64 18 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 19 | '); 20 | clickhouse_raw_query 21 | ---------------------- 22 | 23 | (1 row) 24 | 25 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.uints ( 26 | c1 UInt8, c2 UInt16, c3 UInt32, c4 UInt64, c5 Bool 27 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 28 | '); 29 | clickhouse_raw_query 30 | ---------------------- 31 | 32 | (1 row) 33 | 34 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.floats ( 35 | c1 Float32, c2 Float64 36 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1) SETTINGS allow_floating_point_partition_key=1; 37 | '); 38 | clickhouse_raw_query 39 | ---------------------- 40 | 41 | (1 row) 42 | 43 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( 44 | c1 Int8, c2 Nullable(Int32) 45 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 46 | '); 47 | clickhouse_raw_query 48 | ---------------------- 49 | 50 | (1 row) 51 | 52 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( 53 | c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) 54 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 55 | '); 56 | clickhouse_raw_query 57 | ---------------------- 58 | 59 | (1 row) 60 | 61 | SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.arrays ( 62 | c1 Int32, c2 Array(Int32) 63 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 64 | '); 65 | clickhouse_raw_query 66 | ---------------------- 67 | 68 | (1 row) 69 | 70 | IMPORT FOREIGN SCHEMA "binary_inserts_test" FROM SERVER binary_inserts_loopback INTO public; 71 | /* ints */ 72 | INSERT INTO ints 73 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(1, 3) i; 74 | SELECT * FROM ints ORDER BY c1; 75 | c1 | c2 | c3 | c4 76 | ----+----+----+---- 77 | 1 | 2 | 3 | 4 78 | 2 | 3 | 4 | 5 79 | 3 | 4 | 5 | 6 80 | (3 rows) 81 | 82 | INSERT INTO ints (c1, c4, c3, c2) 83 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(4, 6) i; 84 | SELECT * FROM ints ORDER BY c1; 85 | c1 | c2 | c3 | c4 86 | ----+----+----+---- 87 | 1 | 2 | 3 | 4 88 | 2 | 3 | 4 | 5 89 | 3 | 4 | 5 | 6 90 | 4 | 7 | 6 | 5 91 | 5 | 8 | 7 | 6 92 | 6 | 9 | 8 | 7 93 | (6 rows) 94 | 95 | /* check dropping columns (that will change attnums) */ 96 | ALTER TABLE ints DROP COLUMN c1; 97 | ALTER TABLE ints ADD COLUMN c1 SMALLINT; 98 | INSERT INTO ints (c1, c2, c3, c4) 99 | SELECT i, i + 1, i + 2, i+ 3 FROM generate_series(7, 8) i; 100 | SELECT c1, c2, c3, c4 FROM ints ORDER BY c1; 101 | c1 | c2 | c3 | c4 102 | ----+----+----+---- 103 | 1 | 2 | 3 | 4 104 | 2 | 3 | 4 | 5 105 | 3 | 4 | 5 | 6 106 | 4 | 7 | 6 | 5 107 | 5 | 8 | 7 | 6 108 | 6 | 9 | 8 | 7 109 | 7 | 8 | 9 | 10 110 | 8 | 9 | 10 | 11 111 | (8 rows) 112 | 113 | /* check other number types */ 114 | INSERT INTO uints 115 | SELECT i, i + 1, i + 2, i+ 3, (i % 2)::bool FROM generate_series(1, 3) i; 116 | SELECT * FROM uints ORDER BY c1; 117 | c1 | c2 | c3 | c4 | c5 118 | ----+----+----+----+---- 119 | 1 | 2 | 3 | 4 | t 120 | 2 | 3 | 4 | 5 | f 121 | 3 | 4 | 5 | 6 | t 122 | (3 rows) 123 | 124 | INSERT INTO floats 125 | SELECT i * 1.1, i + 2.1 FROM generate_series(1, 3) i; 126 | SELECT * FROM floats ORDER BY c1; 127 | c1 | c2 128 | -----+----- 129 | 1.1 | 3.1 130 | 2.2 | 4.1 131 | 3.3 | 5.1 132 | (3 rows) 133 | 134 | /* check nullable */ 135 | INSERT INTO null_ints SELECT i, case WHEN i % 2 = 0 THEN NULL ELSE i END FROM generate_series(1, 10) i; 136 | INSERT INTO null_ints(c1) SELECT i FROM generate_series(11, 13) i; 137 | SELECT * FROM null_ints ORDER BY c1; 138 | c1 | c2 139 | ----+---- 140 | 1 | 1 141 | 2 | 142 | 3 | 3 143 | 4 | 144 | 5 | 5 145 | 6 | 146 | 7 | 7 147 | 8 | 148 | 9 | 9 149 | 10 | 150 | 11 | 151 | 12 | 152 | 13 | 153 | (13 rows) 154 | 155 | SELECT * FROM null_ints ORDER BY c1; 156 | c1 | c2 157 | ----+---- 158 | 1 | 1 159 | 2 | 160 | 3 | 3 161 | 4 | 162 | 5 | 5 163 | 6 | 164 | 7 | 7 165 | 8 | 166 | 9 | 9 167 | 10 | 168 | 11 | 169 | 12 | 170 | 13 | 171 | (13 rows) 172 | 173 | /* check dates and strings */ 174 | ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); 175 | \d+ complex 176 | Foreign table "public.complex" 177 | Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description 178 | --------+--------------------------------+-----------+----------+---------+-------------+----------+--------------+------------- 179 | c1 | integer | | not null | | | plain | | 180 | c2 | date | | not null | | | plain | | 181 | c3 | timestamp without time zone | | not null | | | plain | | 182 | c4 | text | | not null | | | extended | | 183 | c5 | character varying(10) | | not null | | | extended | | 184 | c6 | text | | not null | | | extended | | 185 | c7 | timestamp(3) without time zone | | not null | | | plain | | 186 | Not-null constraints: 187 | "complex_c1_not_null" NOT NULL "c1" 188 | "complex_c2_not_null" NOT NULL "c2" 189 | "complex_c3_not_null" NOT NULL "c3" 190 | "complex_c4_not_null" NOT NULL "c4" 191 | "complex_c5_not_null" NOT NULL "c5" 192 | "complex_c6_not_null" NOT NULL "c6" 193 | "complex_c7_not_null" NOT NULL "c7" 194 | Server: binary_inserts_loopback 195 | FDW options: (database 'binary_inserts_test', table_name 'complex', engine 'MergeTree') 196 | 197 | INSERT INTO complex VALUES 198 | (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), 199 | (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), 200 | (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); 201 | SELECT * FROM complex ORDER BY c1; 202 | c1 | c2 | c3 | c4 | c5 | c6 | c7 203 | ----+------------+---------------------+----+--------+------+---------------------------- 204 | 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02.122999 205 | 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02.234 206 | 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 207 | (3 rows) 208 | 209 | /* check arrays */ 210 | INSERT INTO arrays VALUES 211 | (1, ARRAY[1,2]), 212 | (2, ARRAY[3,4,5]), 213 | (3, ARRAY[6,4]); 214 | SELECT * FROM arrays ORDER BY c1; 215 | c1 | c2 216 | ----+--------- 217 | 1 | {1,2} 218 | 2 | {3,4,5} 219 | 3 | {6,4} 220 | (3 rows) 221 | 222 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_inserts_loopback; 223 | SELECT clickhouse_raw_query('DROP DATABASE binary_inserts_test'); 224 | clickhouse_raw_query 225 | ---------------------- 226 | 227 | (1 row) 228 | 229 | DROP SERVER binary_inserts_loopback CASCADE; 230 | NOTICE: drop cascades to 6 other objects 231 | DETAIL: drop cascades to foreign table arrays 232 | drop cascades to foreign table complex 233 | drop cascades to foreign table floats 234 | drop cascades to foreign table ints 235 | drop cascades to foreign table null_ints 236 | drop cascades to foreign table uints 237 | -------------------------------------------------------------------------------- /test/sql/binary_queries.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_queries_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'binary_queries_test', driver 'binary'); 3 | CREATE SERVER binary_queries_loopback2 FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'binary_queries_test', driver 'binary'); 4 | 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback; 6 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback2; 7 | 8 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS binary_queries_test'); 9 | SELECT clickhouse_raw_query('CREATE DATABASE binary_queries_test'); 10 | SELECT clickhouse_raw_query('CREATE TABLE binary_queries_test.t1 11 | (c1 Int, c2 Int, c3 String, c4 Date, c5 Date, c6 String, c7 String, c8 String) 12 | ENGINE = MergeTree PARTITION BY c4 ORDER BY (c1); 13 | '); 14 | SELECT clickhouse_raw_query('CREATE TABLE binary_queries_test.t2 (c1 Int, c2 String) 15 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 16 | SELECT clickhouse_raw_query('CREATE TABLE binary_queries_test.t3 (c1 Int, c3 String) 17 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 18 | SELECT clickhouse_raw_query('CREATE TABLE binary_queries_test.t4 (c1 Int, c2 Int, c3 String) 19 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 20 | 21 | CREATE FOREIGN TABLE ft1 ( 22 | c0 int, 23 | c1 int NOT NULL, 24 | c2 int NOT NULL, 25 | c3 text, 26 | c4 date, 27 | c5 date, 28 | c6 varchar(10), 29 | c7 char(10) default 'ft1', 30 | c8 text 31 | ) SERVER binary_queries_loopback OPTIONS (table_name 't1'); 32 | 33 | ALTER FOREIGN TABLE ft1 DROP COLUMN c0; 34 | 35 | CREATE FOREIGN TABLE ft2 ( 36 | c1 int NOT NULL, 37 | c2 text NOT NULL 38 | ) SERVER binary_queries_loopback OPTIONS (table_name 't2'); 39 | 40 | CREATE FOREIGN TABLE ft4 ( 41 | c1 int NOT NULL, 42 | c2 int NOT NULL, 43 | c3 text 44 | ) SERVER binary_queries_loopback OPTIONS (table_name 't4'); 45 | 46 | CREATE FOREIGN TABLE ft5 ( 47 | c1 int NOT NULL, 48 | c2 int NOT NULL, 49 | c3 text 50 | ) SERVER binary_queries_loopback OPTIONS (table_name 't4'); 51 | 52 | CREATE FOREIGN TABLE ft6 ( 53 | c1 int NOT NULL, 54 | c2 int NOT NULL, 55 | c3 text 56 | ) SERVER binary_queries_loopback2 OPTIONS (table_name 't4'); 57 | 58 | select clickhouse_raw_query($$ 59 | INSERT INTO binary_queries_test.t1 60 | SELECT number, 61 | number % 10, 62 | toString(number), 63 | toDate('1990-01-01'), 64 | toDate('1990-01-01'), 65 | number % 10, 66 | number % 10, 67 | 'foo' 68 | FROM numbers(1, 110);$$); 69 | 70 | select clickhouse_raw_query($$ 71 | INSERT INTO binary_queries_test.t2 72 | SELECT number, 73 | concat('AAA', toString(number)) 74 | FROM numbers(1, 100);$$); 75 | 76 | select clickhouse_raw_query($$ 77 | INSERT INTO binary_queries_test.t4 78 | SELECT number, 79 | number + 1, 80 | concat('AAA', toString(number)) 81 | FROM numbers(1, 100);$$); 82 | 83 | \set VERBOSITY terse 84 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work 85 | 86 | ALTER SERVER binary_queries_loopback OPTIONS (SET dbname 'no such database'); 87 | 88 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail 89 | 90 | ALTER USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback OPTIONS (ADD user 'no such user'); 91 | 92 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail 93 | 94 | ALTER SERVER binary_queries_loopback OPTIONS (SET dbname 'binary_queries_test'); 95 | ALTER USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback OPTIONS (DROP user); 96 | 97 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again 98 | 99 | \set VERBOSITY default 100 | ANALYZE ft1; 101 | 102 | EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c1 OFFSET 100 LIMIT 10; 103 | SELECT * FROM ft1 ORDER BY c1 OFFSET 100 LIMIT 10; 104 | 105 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c1, t1.tableoid OFFSET 100 LIMIT 10; 106 | 107 | SELECT * FROM ft1 t1 ORDER BY t1.c1, t1.tableoid OFFSET 100 LIMIT 10; 108 | 109 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c1 OFFSET 100 LIMIT 10; 110 | 111 | SELECT t1 FROM ft1 t1 ORDER BY t1.c1 OFFSET 100 LIMIT 10; 112 | 113 | SELECT * FROM ft1 WHERE false; 114 | 115 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1'; 116 | 117 | SELECT COUNT(*) FROM ft1 t1; 118 | 119 | SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c2 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1; 120 | 121 | SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c2) FROM ft2 t2) ORDER BY c1; 122 | 123 | WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c2 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1; 124 | 125 | SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1; 126 | 127 | SET enable_hashjoin TO false; 128 | 129 | SET enable_nestloop TO false; 130 | 131 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1.c1, t2.c1 FROM ft2 t1 JOIN ft1 t2 ON (t1.c1 = t2.c1) OFFSET 100 LIMIT 10; 132 | 133 | SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 134 | 135 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) OFFSET 100 LIMIT 10; 136 | 137 | EXPLAIN SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 138 | SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 139 | 140 | RESET enable_hashjoin; 141 | RESET enable_nestloop; 142 | 143 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const 144 | 145 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr 146 | 147 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest 148 | 149 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest 150 | 151 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr 152 | 153 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l) 154 | 155 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE 1 = factorial(c1); -- OpExpr(r) 156 | 157 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr 158 | 159 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr 160 | 161 | SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]) ORDER BY c1; -- ScalarArrayOpExpr 162 | 163 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- ArrayRef 164 | 165 | SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1] ORDER BY c1; -- ArrayRef 166 | 167 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars 168 | 169 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote 170 | 171 | EXPLAIN (VERBOSE, COSTS OFF) SELECT (CASE WHEN c1 < 10 THEN 1 WHEN c1 < 50 THEN 2 ELSE 3 END) a, 172 | sum(length(c2)) FROM ft2 GROUP BY a ORDER BY a; 173 | SELECT (CASE WHEN c1 < 10 THEN 1 WHEN c1 < 50 THEN 2 ELSE 3 END) a, 174 | sum(length(c2)) FROM ft2 GROUP BY a ORDER BY a; 175 | 176 | EXPLAIN (VERBOSE, COSTS OFF) SELECT SUM(c1) FILTER (WHERE c1 < 20) FROM ft2; 177 | SELECT SUM(c1) FILTER (WHERE c1 < 20) FROM ft2; 178 | 179 | EXPLAIN (VERBOSE, COSTS OFF) SELECT COUNT(DISTINCT c1) FROM ft2; 180 | SELECT COUNT(DISTINCT c1) FROM ft2; 181 | 182 | /* DISTINCT with IF */ 183 | EXPLAIN (VERBOSE, COSTS OFF) SELECT COUNT(DISTINCT c1) FILTER (WHERE c1 < 20) FROM ft2; 184 | SELECT COUNT(DISTINCT c1) FILTER (WHERE c1 < 20) FROM ft2; 185 | 186 | /* https://github.com/ClickHouse/pg_clickhouse/issues/25 */ 187 | EXPLAIN (VERBOSE, COSTS OFF) SELECT COUNT(*) FILTER (WHERE c1 < 20) FROM ft2; 188 | SELECT COUNT(*) FILTER (WHERE c1 < 10) FROM ft2; 189 | 190 | SELECT clickhouse_raw_query('DROP DATABASE binary_queries_test'); 191 | 192 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback2; 193 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_queries_loopback; 194 | DROP SERVER binary_queries_loopback2 CASCADE; 195 | DROP SERVER binary_queries_loopback CASCADE; 196 | -------------------------------------------------------------------------------- /test/expected/subquery_pushdown.out: -------------------------------------------------------------------------------- 1 | -- Test for TPC-H Q4 style EXISTS subquery pushdown 2 | -- TPC-H schema reference: https://raw.githubusercontent.com/Vonng/pgtpc/refs/heads/master/tpch/ddl/schema.ddl 3 | SET datestyle = 'ISO'; 4 | CREATE SERVER subquery_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'subquery_test', driver 'binary'); 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS subquery_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE subquery_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | -- Create TPC-H orders table (matching official schema) 19 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.orders 20 | (o_orderkey Int32, o_custkey Int32, o_orderstatus FixedString(1), o_totalprice Decimal(15,2), 21 | o_orderdate Date, o_orderpriority FixedString(15), o_clerk FixedString(15), o_shippriority Int32, o_comment String) 22 | ENGINE = MergeTree ORDER BY o_orderkey; 23 | '); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | -- Create TPC-H lineitem table (matching official schema) 30 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.lineitem 31 | (l_orderkey Int32, l_partkey Int32, l_suppkey Int32, l_linenumber Int32, 32 | l_quantity Decimal(15,2), l_extendedprice Decimal(15,2), l_discount Decimal(15,2), l_tax Decimal(15,2), 33 | l_returnflag FixedString(1), l_linestatus FixedString(1), l_shipdate Date, l_commitdate Date, 34 | l_receiptdate Date, l_shipinstruct FixedString(25), l_shipmode FixedString(10), l_comment String) 35 | ENGINE = MergeTree ORDER BY (l_orderkey, l_linenumber); 36 | '); 37 | clickhouse_raw_query 38 | ---------------------- 39 | 40 | (1 row) 41 | 42 | -- Insert sample orders data 43 | SELECT clickhouse_raw_query($$ 44 | INSERT INTO subquery_test.orders VALUES 45 | (1, 100, 'O', 1000.00, '1993-07-15', '1-URGENT', 'Clerk#000000001', 0, 'order1'), 46 | (2, 101, 'O', 2000.00, '1993-07-20', '2-HIGH', 'Clerk#000000002', 0, 'order2'), 47 | (3, 102, 'O', 3000.00, '1993-08-01', '1-URGENT', 'Clerk#000000003', 0, 'order3'), 48 | (4, 103, 'O', 4000.00, '1993-08-15', '3-MEDIUM', 'Clerk#000000004', 0, 'order4'), 49 | (5, 104, 'O', 5000.00, '1993-06-01', '1-URGENT', 'Clerk#000000005', 0, 'order5'), 50 | (6, 105, 'O', 6000.00, '1993-09-15', '2-HIGH', 'Clerk#000000006', 0, 'order6'), 51 | (7, 106, 'O', 7000.00, '1993-07-25', '4-NOT SPECIFIED', 'Clerk#000000007', 0, 'order7'), 52 | (8, 107, 'O', 8000.00, '1993-08-20', '5-LOW', 'Clerk#000000008', 0, 'order8'); 53 | $$); 54 | clickhouse_raw_query 55 | ---------------------- 56 | 57 | (1 row) 58 | 59 | -- Insert sample lineitem data (l_commitdate < l_receiptdate for some items) 60 | SELECT clickhouse_raw_query($$ 61 | INSERT INTO subquery_test.lineitem VALUES 62 | (1, 10, 1, 1, 10.00, 100.00, 0.10, 0.05, 'N', 'O', '1993-07-20', '1993-07-15', '1993-07-25', 'DELIVER IN PERSON', 'TRUCK', 'item1'), 63 | (2, 20, 2, 1, 20.00, 200.00, 0.10, 0.05, 'N', 'O', '1993-07-25', '1993-07-20', '1993-07-30', 'DELIVER IN PERSON', 'AIR', 'item2'), 64 | (3, 30, 3, 1, 30.00, 300.00, 0.10, 0.05, 'N', 'O', '1993-08-05', '1993-08-10', '1993-08-08', 'DELIVER IN PERSON', 'SHIP', 'item3'), 65 | (4, 40, 4, 1, 40.00, 400.00, 0.10, 0.05, 'N', 'O', '1993-08-20', '1993-08-15', '1993-08-25', 'DELIVER IN PERSON', 'RAIL', 'item4'), 66 | (7, 70, 7, 1, 70.00, 700.00, 0.10, 0.05, 'N', 'O', '1993-07-30', '1993-07-25', '1993-08-05', 'DELIVER IN PERSON', 'AIR', 'item7'), 67 | (8, 80, 8, 1, 80.00, 800.00, 0.10, 0.05, 'N', 'O', '1993-08-25', '1993-08-30', '1993-08-28', 'DELIVER IN PERSON', 'TRUCK', 'item8'); 68 | $$); 69 | clickhouse_raw_query 70 | ---------------------- 71 | 72 | (1 row) 73 | 74 | -- Create foreign tables (matching TPC-H schema types) 75 | CREATE SCHEMA subquery_test; 76 | IMPORT FOREIGN SCHEMA "subquery_test" FROM SERVER subquery_loopback INTO subquery_test; 77 | -- Disable hash and merge joins to get consistent explain output 78 | SET SESSION enable_hashjoin TO false; 79 | SET SESSION enable_mergejoin TO false; 80 | SET SESSION search_path = subquery_test,public; 81 | -- =================================================================== 82 | -- Test SEMI-JOIN / EXISTS subquery pushdown (TPC-H Q4 style query) 83 | -- =================================================================== 84 | -- First, show the explain plan - this should show SEMI JOIN being pushed down 85 | EXPLAIN (VERBOSE, COSTS OFF) 86 | SELECT 87 | o_orderpriority, 88 | count(*) as order_count 89 | FROM 90 | orders 91 | WHERE 92 | o_orderdate >= date '1993-07-01' 93 | AND o_orderdate < date '1993-10-01' 94 | AND EXISTS ( 95 | SELECT * FROM lineitem 96 | WHERE l_orderkey = o_orderkey 97 | AND l_commitdate < l_receiptdate 98 | ) 99 | GROUP BY 100 | o_orderpriority 101 | ORDER BY 102 | o_orderpriority; 103 | QUERY PLAN 104 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 105 | Foreign Scan 106 | Output: orders.o_orderpriority, (count(*)) 107 | Relations: Aggregate on ((orders) LEFT SEMI JOIN (lineitem)) 108 | Remote SQL: SELECT r1.o_orderpriority, count(*) FROM subquery_test.orders r1 LEFT SEMI JOIN subquery_test.lineitem r3 ON (((r3.l_commitdate < r3.l_receiptdate)) AND ((r1.o_orderkey = r3.l_orderkey))) WHERE ((r1.o_orderdate >= '1993-07-01')) AND ((r1.o_orderdate < '1993-10-01')) GROUP BY r1.o_orderpriority ORDER BY r1.o_orderpriority ASC NULLS LAST 109 | (4 rows) 110 | 111 | -- Execute the actual query 112 | SELECT 113 | o_orderpriority, 114 | count(*) as order_count 115 | FROM 116 | orders 117 | WHERE 118 | o_orderdate >= date '1993-07-01' 119 | AND o_orderdate < date '1993-10-01' 120 | AND EXISTS ( 121 | SELECT * FROM lineitem 122 | WHERE l_orderkey = o_orderkey 123 | AND l_commitdate < l_receiptdate 124 | ) 125 | GROUP BY 126 | o_orderpriority 127 | ORDER BY 128 | o_orderpriority; 129 | o_orderpriority | order_count 130 | -----------------+------------- 131 | 1-URGENT | 1 132 | 2-HIGH | 1 133 | 3-MEDIUM | 1 134 | 4-NOT SPECIFIED | 1 135 | (4 rows) 136 | 137 | -- Simpler EXISTS test without aggregation 138 | EXPLAIN (VERBOSE, COSTS OFF) 139 | SELECT o_orderkey, o_orderpriority FROM orders 140 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 141 | ORDER BY o_orderkey; 142 | QUERY PLAN 143 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 144 | Foreign Scan 145 | Output: orders.o_orderkey, orders.o_orderpriority 146 | Relations: (orders) LEFT SEMI JOIN (lineitem) 147 | Remote SQL: SELECT r1.o_orderkey, r1.o_orderpriority FROM subquery_test.orders r1 LEFT SEMI JOIN subquery_test.lineitem r2 ON (((r1.o_orderkey = r2.l_orderkey))) ORDER BY r1.o_orderkey ASC NULLS LAST 148 | (4 rows) 149 | 150 | SELECT o_orderkey, o_orderpriority FROM orders 151 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 152 | ORDER BY o_orderkey; 153 | o_orderkey | o_orderpriority 154 | ------------+----------------- 155 | 1 | 1-URGENT 156 | 2 | 2-HIGH 157 | 3 | 1-URGENT 158 | 4 | 3-MEDIUM 159 | 7 | 4-NOT SPECIFIED 160 | 8 | 5-LOW 161 | (6 rows) 162 | 163 | -- Cleanup 164 | SELECT clickhouse_raw_query('DROP DATABASE subquery_test'); 165 | clickhouse_raw_query 166 | ---------------------- 167 | 168 | (1 row) 169 | 170 | DROP USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 171 | DROP SERVER subquery_loopback CASCADE; 172 | NOTICE: drop cascades to 2 other objects 173 | DETAIL: drop cascades to foreign table lineitem 174 | drop cascades to foreign table orders 175 | -------------------------------------------------------------------------------- /test/expected/subquery_pushdown_1.out: -------------------------------------------------------------------------------- 1 | -- Test for TPC-H Q4 style EXISTS subquery pushdown 2 | -- TPC-H schema reference: https://raw.githubusercontent.com/Vonng/pgtpc/refs/heads/master/tpch/ddl/schema.ddl 3 | SET datestyle = 'ISO'; 4 | CREATE SERVER subquery_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'subquery_test', driver 'binary'); 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 6 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS subquery_test'); 7 | clickhouse_raw_query 8 | ---------------------- 9 | 10 | (1 row) 11 | 12 | SELECT clickhouse_raw_query('CREATE DATABASE subquery_test'); 13 | clickhouse_raw_query 14 | ---------------------- 15 | 16 | (1 row) 17 | 18 | -- Create TPC-H orders table (matching official schema) 19 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.orders 20 | (o_orderkey Int32, o_custkey Int32, o_orderstatus FixedString(1), o_totalprice Decimal(15,2), 21 | o_orderdate Date, o_orderpriority FixedString(15), o_clerk FixedString(15), o_shippriority Int32, o_comment String) 22 | ENGINE = MergeTree ORDER BY o_orderkey; 23 | '); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | -- Create TPC-H lineitem table (matching official schema) 30 | SELECT clickhouse_raw_query('CREATE TABLE subquery_test.lineitem 31 | (l_orderkey Int32, l_partkey Int32, l_suppkey Int32, l_linenumber Int32, 32 | l_quantity Decimal(15,2), l_extendedprice Decimal(15,2), l_discount Decimal(15,2), l_tax Decimal(15,2), 33 | l_returnflag FixedString(1), l_linestatus FixedString(1), l_shipdate Date, l_commitdate Date, 34 | l_receiptdate Date, l_shipinstruct FixedString(25), l_shipmode FixedString(10), l_comment String) 35 | ENGINE = MergeTree ORDER BY (l_orderkey, l_linenumber); 36 | '); 37 | clickhouse_raw_query 38 | ---------------------- 39 | 40 | (1 row) 41 | 42 | -- Insert sample orders data 43 | SELECT clickhouse_raw_query($$ 44 | INSERT INTO subquery_test.orders VALUES 45 | (1, 100, 'O', 1000.00, '1993-07-15', '1-URGENT', 'Clerk#000000001', 0, 'order1'), 46 | (2, 101, 'O', 2000.00, '1993-07-20', '2-HIGH', 'Clerk#000000002', 0, 'order2'), 47 | (3, 102, 'O', 3000.00, '1993-08-01', '1-URGENT', 'Clerk#000000003', 0, 'order3'), 48 | (4, 103, 'O', 4000.00, '1993-08-15', '3-MEDIUM', 'Clerk#000000004', 0, 'order4'), 49 | (5, 104, 'O', 5000.00, '1993-06-01', '1-URGENT', 'Clerk#000000005', 0, 'order5'), 50 | (6, 105, 'O', 6000.00, '1993-09-15', '2-HIGH', 'Clerk#000000006', 0, 'order6'), 51 | (7, 106, 'O', 7000.00, '1993-07-25', '4-NOT SPECIFIED', 'Clerk#000000007', 0, 'order7'), 52 | (8, 107, 'O', 8000.00, '1993-08-20', '5-LOW', 'Clerk#000000008', 0, 'order8'); 53 | $$); 54 | clickhouse_raw_query 55 | ---------------------- 56 | 57 | (1 row) 58 | 59 | -- Insert sample lineitem data (l_commitdate < l_receiptdate for some items) 60 | SELECT clickhouse_raw_query($$ 61 | INSERT INTO subquery_test.lineitem VALUES 62 | (1, 10, 1, 1, 10.00, 100.00, 0.10, 0.05, 'N', 'O', '1993-07-20', '1993-07-15', '1993-07-25', 'DELIVER IN PERSON', 'TRUCK', 'item1'), 63 | (2, 20, 2, 1, 20.00, 200.00, 0.10, 0.05, 'N', 'O', '1993-07-25', '1993-07-20', '1993-07-30', 'DELIVER IN PERSON', 'AIR', 'item2'), 64 | (3, 30, 3, 1, 30.00, 300.00, 0.10, 0.05, 'N', 'O', '1993-08-05', '1993-08-10', '1993-08-08', 'DELIVER IN PERSON', 'SHIP', 'item3'), 65 | (4, 40, 4, 1, 40.00, 400.00, 0.10, 0.05, 'N', 'O', '1993-08-20', '1993-08-15', '1993-08-25', 'DELIVER IN PERSON', 'RAIL', 'item4'), 66 | (7, 70, 7, 1, 70.00, 700.00, 0.10, 0.05, 'N', 'O', '1993-07-30', '1993-07-25', '1993-08-05', 'DELIVER IN PERSON', 'AIR', 'item7'), 67 | (8, 80, 8, 1, 80.00, 800.00, 0.10, 0.05, 'N', 'O', '1993-08-25', '1993-08-30', '1993-08-28', 'DELIVER IN PERSON', 'TRUCK', 'item8'); 68 | $$); 69 | clickhouse_raw_query 70 | ---------------------- 71 | 72 | (1 row) 73 | 74 | -- Create foreign tables (matching TPC-H schema types) 75 | CREATE SCHEMA subquery_test; 76 | IMPORT FOREIGN SCHEMA "subquery_test" FROM SERVER subquery_loopback INTO subquery_test; 77 | -- Disable hash and merge joins to get consistent explain output 78 | SET SESSION enable_hashjoin TO false; 79 | SET SESSION enable_mergejoin TO false; 80 | SET SESSION search_path = subquery_test,public; 81 | -- =================================================================== 82 | -- Test SEMI-JOIN / EXISTS subquery pushdown (TPC-H Q4 style query) 83 | -- =================================================================== 84 | -- First, show the explain plan - this should show SEMI JOIN being pushed down 85 | EXPLAIN (VERBOSE, COSTS OFF) 86 | SELECT 87 | o_orderpriority, 88 | count(*) as order_count 89 | FROM 90 | orders 91 | WHERE 92 | o_orderdate >= date '1993-07-01' 93 | AND o_orderdate < date '1993-10-01' 94 | AND EXISTS ( 95 | SELECT * FROM lineitem 96 | WHERE l_orderkey = o_orderkey 97 | AND l_commitdate < l_receiptdate 98 | ) 99 | GROUP BY 100 | o_orderpriority 101 | ORDER BY 102 | o_orderpriority; 103 | QUERY PLAN 104 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 105 | Foreign Scan 106 | Output: orders.o_orderpriority, (count(*)) 107 | Relations: Aggregate on ((orders) LEFT SEMI JOIN (lineitem)) 108 | Remote SQL: SELECT r1.o_orderpriority, count(*) FROM subquery_test.orders r1 LEFT SEMI JOIN subquery_test.lineitem r2 ON (((r2.l_commitdate < r2.l_receiptdate)) AND ((r1.o_orderkey = r2.l_orderkey))) WHERE ((r1.o_orderdate >= '1993-07-01')) AND ((r1.o_orderdate < '1993-10-01')) GROUP BY r1.o_orderpriority ORDER BY r1.o_orderpriority ASC NULLS LAST 109 | (4 rows) 110 | 111 | -- Execute the actual query 112 | SELECT 113 | o_orderpriority, 114 | count(*) as order_count 115 | FROM 116 | orders 117 | WHERE 118 | o_orderdate >= date '1993-07-01' 119 | AND o_orderdate < date '1993-10-01' 120 | AND EXISTS ( 121 | SELECT * FROM lineitem 122 | WHERE l_orderkey = o_orderkey 123 | AND l_commitdate < l_receiptdate 124 | ) 125 | GROUP BY 126 | o_orderpriority 127 | ORDER BY 128 | o_orderpriority; 129 | o_orderpriority | order_count 130 | -----------------+------------- 131 | 1-URGENT | 1 132 | 2-HIGH | 1 133 | 3-MEDIUM | 1 134 | 4-NOT SPECIFIED | 1 135 | (4 rows) 136 | 137 | -- Simpler EXISTS test without aggregation 138 | EXPLAIN (VERBOSE, COSTS OFF) 139 | SELECT o_orderkey, o_orderpriority FROM orders 140 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 141 | ORDER BY o_orderkey; 142 | QUERY PLAN 143 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 144 | Foreign Scan 145 | Output: orders.o_orderkey, orders.o_orderpriority 146 | Relations: (orders) LEFT SEMI JOIN (lineitem) 147 | Remote SQL: SELECT r1.o_orderkey, r1.o_orderpriority FROM subquery_test.orders r1 LEFT SEMI JOIN subquery_test.lineitem r2 ON (((r1.o_orderkey = r2.l_orderkey))) ORDER BY r1.o_orderkey ASC NULLS LAST 148 | (4 rows) 149 | 150 | SELECT o_orderkey, o_orderpriority FROM orders 151 | WHERE EXISTS (SELECT 1 FROM lineitem WHERE l_orderkey = o_orderkey) 152 | ORDER BY o_orderkey; 153 | o_orderkey | o_orderpriority 154 | ------------+----------------- 155 | 1 | 1-URGENT 156 | 2 | 2-HIGH 157 | 3 | 1-URGENT 158 | 4 | 3-MEDIUM 159 | 7 | 4-NOT SPECIFIED 160 | 8 | 5-LOW 161 | (6 rows) 162 | 163 | -- Cleanup 164 | SELECT clickhouse_raw_query('DROP DATABASE subquery_test'); 165 | clickhouse_raw_query 166 | ---------------------- 167 | 168 | (1 row) 169 | 170 | DROP USER MAPPING FOR CURRENT_USER SERVER subquery_loopback; 171 | DROP SERVER subquery_loopback CASCADE; 172 | NOTICE: drop cascades to 2 other objects 173 | DETAIL: drop cascades to foreign table lineitem 174 | drop cascades to foreign table orders 175 | -------------------------------------------------------------------------------- /test/sql/import_schema.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER import_loopback FOREIGN DATA WRAPPER clickhouse_fdw 3 | OPTIONS(dbname 'import_test', driver 'http'); 4 | CREATE SERVER import_loopback_bin FOREIGN DATA WRAPPER clickhouse_fdw 5 | OPTIONS(dbname 'import_test', driver 'binary'); 6 | CREATE SCHEMA clickhouse; 7 | CREATE SCHEMA clickhouse_bin; 8 | CREATE SCHEMA clickhouse_limit; 9 | CREATE SCHEMA clickhouse_except; 10 | CREATE USER MAPPING FOR CURRENT_USER SERVER import_loopback; 11 | CREATE USER MAPPING FOR CURRENT_USER SERVER import_loopback_bin; 12 | 13 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS import_test'); 14 | SELECT clickhouse_raw_query('CREATE DATABASE import_test'); 15 | SELECT clickhouse_raw_query('CREATE DATABASE import_test_2'); 16 | 17 | -- integer types 18 | SELECT clickhouse_raw_query('CREATE TABLE import_test.ints ( 19 | c1 Int8, c2 Int16, c3 Int32, c4 Int64, 20 | c5 UInt8, c6 UInt16, c7 UInt32, c8 UInt64, 21 | c9 Float32, c10 Nullable(Float64) 22 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 23 | '); 24 | SELECT clickhouse_raw_query('INSERT INTO import_test.ints SELECT 25 | number, number + 1, number + 2, number + 3, number + 4, number + 5, 26 | number + 6, number + 7, number + 8.1, number + 9.2 FROM numbers(10);'); 27 | SELECT clickhouse_raw_query('INSERT INTO import_test.ints SELECT 28 | number, number + 1, number + 2, number + 3, number + 4, number + 5, 29 | number + 6, number + 7, number + 8.1, NULL FROM numbers(10, 2);'); 30 | 31 | SELECT clickhouse_raw_query('CREATE TABLE import_test.types ( 32 | c1 Date, c2 DateTime, c3 String, c4 FixedString(5), c5 UUID, 33 | c6 Enum8(''one'' = 1, ''two'' = 2), 34 | c7 Enum16(''one'' = 1, ''two'' = 2, ''three'' = 3), 35 | c9 Nullable(FixedString(50)), 36 | c8 LowCardinality(String) 37 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 38 | '); 39 | SELECT clickhouse_raw_query('INSERT INTO import_test.types SELECT 40 | addDays(toDate(''1990-01-01''), number), 41 | addMinutes(addSeconds(addDays(toDateTime(''1990-01-01 10:00:00''), number), number), number), 42 | format(''number {0}'', toString(number)), 43 | format(''num {0}'', toString(number)), 44 | format(''f4bf890f-f9dc-4332-ad5c-0c18e73f28e{0}'', toString(number)), 45 | ''two'', 46 | ''three'', 47 | toString(number), 48 | format(''cardinal {0}'', toString(number)) 49 | FROM numbers(10);'); 50 | 51 | SELECT clickhouse_raw_query('CREATE TABLE import_test.types2 ( 52 | c1 LowCardinality(Nullable(String)) 53 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1) SETTINGS allow_nullable_key = 1; 54 | '); 55 | SELECT clickhouse_raw_query('INSERT INTO import_test.types2 SELECT 56 | format(''cardinal {0}'', toString(number + 1)) 57 | FROM numbers(10);'); 58 | 59 | SELECT clickhouse_raw_query('CREATE TABLE import_test.ip ( 60 | c1 IPv4, 61 | c2 IPv6 62 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 63 | '); 64 | SELECT clickhouse_raw_query($$ 65 | INSERT INTO import_test.ip VALUES 66 | ('116.106.34.242', '2001:44c8:129:2632:33:0:252:2'), 67 | ('116.106.34.243', '2a02:e980:1e::1'), 68 | ('116.106.34.244', '::1'); 69 | $$); 70 | 71 | -- array types 72 | SELECT clickhouse_raw_query('CREATE TABLE import_test.arrays ( 73 | c1 Array(Int), c2 Array(String) 74 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 75 | '); 76 | SELECT clickhouse_raw_query('INSERT INTO import_test.arrays SELECT 77 | [number, number + 1], 78 | [format(''num{0}'', toString(number)), format(''num{0}'', toString(number + 1))] 79 | FROM numbers(10);'); 80 | 81 | -- tuple 82 | SELECT clickhouse_raw_query('CREATE TABLE import_test.tuples ( 83 | c1 Int8, 84 | c2 Tuple(Int, String, Float32), 85 | c3 Nested(a Int, b Int), 86 | c4 Int16 87 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 88 | '); 89 | SELECT clickhouse_raw_query('INSERT INTO import_test.tuples SELECT 90 | number, 91 | (number, toString(number), number + 1.0), 92 | [toInt32(number),1,1], 93 | [toInt32(number),2,2], 94 | toInt16(number) 95 | FROM numbers(10);'); 96 | 97 | -- datetime with timezones 98 | SELECT clickhouse_raw_query('CREATE TABLE import_test.timezones ( 99 | t1 DateTime64(6,''UTC''), 100 | t2 DateTime64(6,''Europe/Berlin''), 101 | t4 DateTime(''Europe/Berlin''), 102 | t5 DateTime64(6)) 103 | ENGINE = MergeTree ORDER BY (t1) SETTINGS index_granularity=8192;'); 104 | 105 | SELECT clickhouse_raw_query('INSERT INTO import_test.timezones VALUES ( 106 | ''2020-01-01 11:00:00'', 107 | ''2020-01-01 11:00:00'', 108 | ''2020-01-01 11:00:00'', 109 | ''2020-01-01 11:00:00'')'); 110 | 111 | SELECT clickhouse_raw_query('INSERT INTO import_test.timezones VALUES ( 112 | ''2020-01-01 12:00:00'', 113 | ''2020-01-01 12:00:00'', 114 | ''2020-01-01 12:00:00'', 115 | ''2020-01-01 12:00:00'')'); 116 | 117 | IMPORT FOREIGN SCHEMA "import_test" FROM SERVER import_loopback INTO clickhouse; 118 | 119 | \d+ clickhouse.ints; 120 | \d+ clickhouse.types; 121 | \d+ clickhouse.types2; 122 | \d+ clickhouse.arrays; 123 | \d+ clickhouse.tuples; 124 | \d+ clickhouse.timezones; 125 | \d+ clickhouse.ip; 126 | 127 | SELECT * FROM clickhouse.ints ORDER BY c1 DESC LIMIT 4; 128 | SELECT * FROM clickhouse.types ORDER BY c1 LIMIT 2; 129 | SELECT * FROM clickhouse.types2 ORDER BY c1 LIMIT 2; 130 | SELECT * FROM clickhouse.arrays ORDER BY c1 LIMIT 2; 131 | SELECT * FROM clickhouse.tuples ORDER BY c1 LIMIT 2; 132 | SELECT * FROM clickhouse.timezones ORDER BY t1 LIMIT 2; 133 | SELECT * FROM clickhouse.ip ORDER BY c1; 134 | 135 | IMPORT FOREIGN SCHEMA "import_test" FROM SERVER import_loopback_bin INTO clickhouse_bin; 136 | 137 | \d+ clickhouse_bin.ints; 138 | \d+ clickhouse_bin.types; 139 | \d+ clickhouse_bin.types2; 140 | \d+ clickhouse_bin.arrays; 141 | \d+ clickhouse_bin.tuples; 142 | \d+ clickhouse_bin.timezones; 143 | \d+ clickhouse_bin.ip; 144 | 145 | SELECT * FROM clickhouse_bin.ints ORDER BY c1 DESC LIMIT 4; 146 | SELECT * FROM clickhouse_bin.types ORDER BY c1 LIMIT 2; 147 | SELECT * FROM clickhouse_bin.types2 ORDER BY c1 LIMIT 2; 148 | SELECT * FROM clickhouse_bin.arrays ORDER BY c1 LIMIT 2; 149 | SELECT * FROM clickhouse_bin.tuples ORDER BY c1 LIMIT 2; 150 | SELECT * FROM clickhouse_bin.timezones ORDER BY t1 LIMIT 2; 151 | SELECT * FROM clickhouse.ip ORDER BY c1; 152 | 153 | IMPORT FOREIGN SCHEMA "import_test" LIMIT TO (ints, types) FROM SERVER import_loopback INTO clickhouse_limit; 154 | 155 | \d+ clickhouse_limit.ints; 156 | \d+ clickhouse_limit.types; 157 | \d+ clickhouse_limit.arrays; 158 | \d+ clickhouse_limit.tuples; 159 | 160 | IMPORT FOREIGN SCHEMA "import_test" EXCEPT (ints, types) FROM SERVER import_loopback INTO clickhouse_except; 161 | 162 | \d+ clickhouse_except.ints; 163 | \d+ clickhouse_except.types; 164 | \d+ clickhouse_except.arrays; 165 | \d+ clickhouse_except.tuples; 166 | 167 | -- check custom database 168 | SELECT clickhouse_raw_query('CREATE TABLE import_test_2.custom_option (a Int64) ENGINE = MergeTree ORDER BY (a)'); 169 | IMPORT FOREIGN SCHEMA "import_test_2" FROM SERVER import_loopback INTO clickhouse; 170 | 171 | EXPLAIN VERBOSE SELECT * FROM clickhouse.custom_option; 172 | ALTER FOREIGN TABLE clickhouse.custom_option OPTIONS (DROP database); 173 | EXPLAIN VERBOSE SELECT * FROM clickhouse.custom_option; 174 | 175 | -- check overflows. 176 | SELECT clickhouse_raw_query($$ 177 | INSERT INTO import_test.ints (c1, c2, c3, c4, c5, c6, c7, c8, c9, c10) VALUES 178 | ( 179 | -- Min values 180 | -128, -32768, -2147483648, -9223372036854775808, 181 | 0, 0, 0, 0, 182 | 1.175494351e-38, 2.2250738585072014e-308 183 | ), 184 | ( 185 | -- Max values 186 | 127, 32767, 2147483647, 9223372036854775807, 187 | 255, 65535, 4294967295, 18446744073709551615, 188 | 3.402823466e+38, 1.7976931348623158e+308 189 | ) 190 | $$); 191 | 192 | SELECT clickhouse_raw_query($$ 193 | SELECT * FROM import_test.ints 194 | WHERE c1 IN (127, -128) 195 | ORDER BY c1; 196 | $$); 197 | 198 | -- Error on 18446744073709551615. 199 | SELECT * FROM clickhouse_bin.ints 200 | WHERE c1 IN (127, -128) 201 | ORDER BY c1; 202 | 203 | SELECT * FROM clickhouse.ints 204 | WHERE c1 IN (127, -128) 205 | ORDER BY c1; 206 | 207 | -- Ignore 18446744073709551615 208 | SELECT * FROM clickhouse_bin.ints WHERE c1 = -128 209 | UNION 210 | SELECT c1, c2, c3, c4, c5, c6, c7, NULL, c9, c10 211 | FROM clickhouse_bin.ints 212 | WHERE c1 = 127 213 | ORDER BY c1; 214 | 215 | SELECT * FROM clickhouse.ints WHERE c1 = -128 216 | UNION 217 | SELECT c1, c2, c3, c4, c5, c6, c7, NULL, c9, c10 218 | FROM clickhouse.ints 219 | WHERE c1 = 127 220 | ORDER BY c1; 221 | 222 | DROP USER MAPPING FOR CURRENT_USER SERVER import_loopback; 223 | DROP USER MAPPING FOR CURRENT_USER SERVER import_loopback_bin; 224 | 225 | SELECT clickhouse_raw_query('DROP DATABASE import_test'); 226 | SELECT clickhouse_raw_query('DROP DATABASE import_test_2'); 227 | DROP SERVER import_loopback_bin CASCADE; 228 | DROP SERVER import_loopback CASCADE; 229 | -------------------------------------------------------------------------------- /test/sql/http.sql: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER http_loopback FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'http_test', driver 'http'); 3 | CREATE SERVER http_loopback2 FOREIGN DATA WRAPPER clickhouse_fdw OPTIONS(dbname 'http_test'); 4 | 5 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_loopback; 6 | CREATE USER MAPPING FOR CURRENT_USER SERVER http_loopback2; 7 | 8 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS http_test'); 9 | SELECT clickhouse_raw_query('CREATE DATABASE http_test', ''); 10 | SELECT clickhouse_raw_query('CREATE TABLE http_test.t1 11 | (c1 Int, c2 Int, c3 String, c4 Date, c5 Date, c6 String, c7 String, c8 String) 12 | ENGINE = MergeTree PARTITION BY c4 ORDER BY (c1); 13 | '); 14 | SELECT clickhouse_raw_query('CREATE TABLE http_test.t2 (c1 Int, c2 String) 15 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 16 | SELECT clickhouse_raw_query('CREATE TABLE http_test.t3 (c1 Int, c3 String) 17 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 18 | SELECT clickhouse_raw_query('CREATE TABLE http_test.t4 (c1 Int, c2 Int, c3 String, c4 Bool) 19 | ENGINE = MergeTree PARTITION BY c1 % 10000 ORDER BY (c1);'); 20 | SELECT clickhouse_raw_query(' 21 | CREATE TABLE tcopy 22 | (c1 Int32, c2 Int64, c3 Date, c4 Nullable(DateTime), c5 DateTime, c6 String) 23 | ENGINE = MergeTree 24 | PARTITION BY c3 25 | ORDER BY (c1, c2, c3); 26 | ', 'dbname=http_test'); 27 | 28 | CREATE FOREIGN TABLE ft1 ( 29 | c0 int, 30 | c1 int NOT NULL, 31 | c2 int NOT NULL, 32 | c3 text, 33 | c4 date, 34 | c5 date, 35 | c6 varchar(10), 36 | c7 char(10) default 'ft1', 37 | c8 text 38 | ) SERVER http_loopback OPTIONS (table_name 't1'); 39 | 40 | ALTER FOREIGN TABLE ft1 DROP COLUMN c0; 41 | 42 | CREATE FOREIGN TABLE ft2 ( 43 | c1 int NOT NULL, 44 | c2 text NOT NULL 45 | ) SERVER http_loopback OPTIONS (table_name 't2'); 46 | 47 | CREATE FOREIGN TABLE ft3 ( 48 | c1 int NOT NULL, 49 | c3 text 50 | ) SERVER http_loopback OPTIONS (table_name 't3'); 51 | 52 | CREATE FOREIGN TABLE ft4 ( 53 | c1 int NOT NULL, 54 | c2 int NOT NULL, 55 | c3 text, 56 | c4 bool 57 | ) SERVER http_loopback OPTIONS (table_name 't4'); 58 | 59 | CREATE FOREIGN TABLE ft5 ( 60 | c1 int NOT NULL, 61 | c2 int NOT NULL, 62 | c3 text, 63 | c4 bool 64 | ) SERVER http_loopback OPTIONS (table_name 't4'); 65 | 66 | CREATE FOREIGN TABLE ft6 ( 67 | c1 int NOT NULL, 68 | c2 int NOT NULL, 69 | c3 text, 70 | c4 bool 71 | ) SERVER http_loopback2 OPTIONS (table_name 't4'); 72 | 73 | CREATE FOREIGN TABLE ftcopy ( 74 | c1 int, 75 | c2 int8, 76 | c3 date, 77 | c4 timestamp without time zone, 78 | c5 time, 79 | c6 text 80 | ) SERVER http_loopback OPTIONS (table_name 'tcopy'); 81 | 82 | INSERT INTO ft1 83 | SELECT id, 84 | id % 10, 85 | to_char(id, 'FM00000'), 86 | '1990-01-01', 87 | '1990-01-01', 88 | id % 10, 89 | id % 10, 90 | 'foo' 91 | FROM generate_series(1, 110) id; 92 | 93 | INSERT INTO ft2 94 | SELECT id, 95 | 'AAA' || to_char(id, 'FM000') 96 | FROM generate_series(1, 100) id; 97 | 98 | INSERT INTO ft3 VALUES (1, E'lf\ntab\t\b\f\r'); 99 | SELECT c3, (c3 = E'lf\ntab\t\b\f\r') AS true FROM ft3 WHERE c1 = 1; 100 | INSERT INTO ft3 VALUES (2, 'lf\ntab\t\b\f\r'); 101 | SELECT c3, (c3 = 'lf\ntab\t\b\f\r') AS true FROM ft3 WHERE c1 = 2; 102 | INSERT INTO ft3 VALUES (3, ''); 103 | SELECT c3, (c3 = '') AS true FROM ft3 WHERE c1 = 3; 104 | 105 | INSERT INTO ft4 106 | SELECT id, 107 | id + 1, 108 | 'AAA' || to_char(id, 'FM000'), 109 | (id % 2)::bool 110 | FROM generate_series(1, 100) id; 111 | 112 | SELECT * FROM ft5 ORDER BY c1 LIMIT 5; 113 | 114 | COPY ftcopy FROM stdin; 115 | 1 2 1990-01-01 1990-01-01 10:01:02 10:01:02 val1 116 | 2 3 1990-02-02 1990-02-02 11:02:03 11:01:02 val2 117 | \. 118 | 119 | INSERT INTO ftcopy VALUES 120 | (3, 4, '1990-03-03', '1990-03-03 12:02:02', '12:02:02', 'val3'), 121 | (4, 5, '1991-04-04', '1990-04-04 12:04:04', '12:02:04', 'val4'), 122 | (5, 6, '1991-04-04', NULL, '12:02:05', 'val5'); 123 | 124 | EXPLAIN (VERBOSE) SELECT * FROM ftcopy ORDER BY c1; 125 | SELECT * FROM ftcopy ORDER BY c1; 126 | 127 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work 128 | 129 | ALTER SERVER http_loopback OPTIONS (SET dbname 'no such database'); 130 | 131 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1; -- should fail 132 | 133 | ALTER USER MAPPING FOR CURRENT_USER SERVER http_loopback OPTIONS (ADD user 'no such user'); 134 | 135 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1; -- should fail 136 | 137 | ALTER SERVER http_loopback OPTIONS (SET dbname 'http_test'); 138 | ALTER USER MAPPING FOR CURRENT_USER SERVER http_loopback OPTIONS (DROP user); 139 | 140 | SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again 141 | 142 | ANALYZE ft1; 143 | 144 | EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10; 145 | SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10; 146 | 147 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10; 148 | 149 | SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10; 150 | 151 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; 152 | 153 | SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; 154 | 155 | SELECT * FROM ft1 WHERE false; 156 | 157 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1'; 158 | 159 | SELECT COUNT(*) FROM ft1 t1; 160 | 161 | SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c2 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1; 162 | 163 | SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c2) FROM ft2 t2) ORDER BY c1; 164 | 165 | WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c2 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1; 166 | 167 | SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1; 168 | 169 | SET enable_hashjoin TO false; 170 | 171 | SET enable_nestloop TO false; 172 | 173 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1.c1, t2.c1 FROM ft2 t1 JOIN ft1 t2 ON (t1.c1 = t2.c1) OFFSET 100 LIMIT 10; 174 | 175 | SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 176 | 177 | EXPLAIN (VERBOSE, COSTS OFF) SELECT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) OFFSET 100 LIMIT 10; 178 | 179 | EXPLAIN SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 180 | SELECT DISTINCT t1.c1, t2.c1 FROM ft2 t1 LEFT JOIN ft1 t2 ON (t1.c1 = t2.c1) order by t1.c1 LIMIT 10; 181 | 182 | RESET enable_hashjoin; 183 | RESET enable_nestloop; 184 | 185 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const 186 | 187 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr 188 | 189 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest 190 | 191 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest 192 | 193 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr 194 | 195 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l) 196 | 197 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE 1 = factorial(c1); -- OpExpr(r) 198 | 199 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr 200 | 201 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr 202 | 203 | SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]) ORDER BY c1; -- ScalarArrayOpExpr 204 | 205 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- ArrayRef 206 | 207 | SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1] ORDER BY c1; -- ArrayRef 208 | 209 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars 210 | 211 | EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote 212 | 213 | EXPLAIN (VERBOSE, COSTS OFF) SELECT (CASE WHEN c1 < 10 THEN 1 WHEN c1 < 50 THEN 2 ELSE 3 END) a, 214 | sum(length(c2)) FROM ft2 GROUP BY a ORDER BY a; 215 | SELECT (CASE WHEN c1 < 10 THEN 1 WHEN c1 < 50 THEN 2 ELSE 3 END) a, 216 | sum(length(c2)) FROM ft2 GROUP BY a ORDER BY a; 217 | 218 | EXPLAIN (VERBOSE, COSTS OFF) SELECT SUM(c1) FILTER (WHERE c1 < 20) FROM ft2; 219 | SELECT SUM(c1) FILTER (WHERE c1 < 20) FROM ft2; 220 | 221 | EXPLAIN (VERBOSE, COSTS OFF) SELECT COUNT(DISTINCT c1) FROM ft2; 222 | SELECT COUNT(DISTINCT c1) FROM ft2; 223 | 224 | /* DISTINCT with IF */ 225 | EXPLAIN (VERBOSE, COSTS OFF) SELECT COUNT(DISTINCT c1) FILTER (WHERE c1 < 20) FROM ft2; 226 | 227 | DROP USER MAPPING FOR CURRENT_USER SERVER http_loopback2; 228 | DROP USER MAPPING FOR CURRENT_USER SERVER http_loopback; 229 | SELECT clickhouse_raw_query('DROP DATABASE http_test'); 230 | DROP SERVER http_loopback2 CASCADE; 231 | DROP SERVER http_loopback CASCADE; 232 | -------------------------------------------------------------------------------- /test/expected/binary.out: -------------------------------------------------------------------------------- 1 | SET datestyle = 'ISO'; 2 | CREATE SERVER binary_loopback FOREIGN DATA WRAPPER clickhouse_fdw 3 | OPTIONS(dbname 'binary_test', driver 'binary'); 4 | CREATE USER MAPPING FOR CURRENT_USER SERVER binary_loopback; 5 | SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS binary_test'); 6 | clickhouse_raw_query 7 | ---------------------- 8 | 9 | (1 row) 10 | 11 | SELECT clickhouse_raw_query('CREATE DATABASE binary_test'); 12 | clickhouse_raw_query 13 | ---------------------- 14 | 15 | (1 row) 16 | 17 | -- integer types 18 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.ints ( 19 | c1 Int8, c2 Int16, c3 Int32, c4 Int64, 20 | c5 UInt8, c6 UInt16, c7 UInt32, c8 UInt64, 21 | c9 Float32, c10 Float64, c11 Bool 22 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 23 | '); 24 | clickhouse_raw_query 25 | ---------------------- 26 | 27 | (1 row) 28 | 29 | SELECT clickhouse_raw_query('INSERT INTO binary_test.ints SELECT 30 | number, number + 1, number + 2, number + 3, number + 4, number + 5, 31 | number + 6, number + 7, number + 8.1, number + 9.2, cast(number % 2 as Bool) 32 | FROM numbers(10);'); 33 | clickhouse_raw_query 34 | ---------------------- 35 | 36 | (1 row) 37 | 38 | -- date and string types 39 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.types ( 40 | c1 Date, c2 DateTime, c3 String, c4 FixedString(5), c5 UUID, 41 | c6 Enum8(''one'' = 1, ''two'' = 2), 42 | c7 Enum16(''one'' = 1, ''two'' = 2, ''three'' = 3) 43 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 44 | '); 45 | clickhouse_raw_query 46 | ---------------------- 47 | 48 | (1 row) 49 | 50 | SELECT clickhouse_raw_query('INSERT INTO binary_test.types SELECT 51 | addDays(toDate(''1990-01-01''), number), 52 | addMinutes(addSeconds(addDays(toDateTime(''1990-01-01 10:00:00''), number), number), number), 53 | format(''number {0}'', toString(number)), 54 | format(''num {0}'', toString(number)), 55 | format(''f4bf890f-f9dc-4332-ad5c-0c18e73f28e{0}'', toString(number)), 56 | ''two'', 57 | ''three'' 58 | FROM numbers(10);'); 59 | clickhouse_raw_query 60 | ---------------------- 61 | 62 | (1 row) 63 | 64 | -- array types 65 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.arrays ( 66 | c1 Array(Int), c2 Array(String) 67 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 68 | '); 69 | clickhouse_raw_query 70 | ---------------------- 71 | 72 | (1 row) 73 | 74 | SELECT clickhouse_raw_query('INSERT INTO binary_test.arrays SELECT 75 | [number, number + 1], 76 | [format(''num{0}'', toString(number)), format(''num{0}'', toString(number + 1))] 77 | FROM numbers(10);'); 78 | clickhouse_raw_query 79 | ---------------------- 80 | 81 | (1 row) 82 | 83 | SELECT clickhouse_raw_query('CREATE TABLE binary_test.tuples ( 84 | c1 Int8, 85 | c2 Tuple(Int, String, Float32), 86 | c3 UInt8 87 | ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); 88 | '); 89 | clickhouse_raw_query 90 | ---------------------- 91 | 92 | (1 row) 93 | 94 | SELECT clickhouse_raw_query('INSERT INTO binary_test.tuples SELECT 95 | number, 96 | (number, toString(number), number + 1.0), 97 | number % 2 98 | FROM numbers(10);'); 99 | clickhouse_raw_query 100 | ---------------------- 101 | 102 | (1 row) 103 | 104 | CREATE FOREIGN TABLE fints ( 105 | c1 int2, 106 | c2 int2, 107 | c3 int, 108 | c4 int8, 109 | c5 int2, 110 | c6 int, 111 | c7 int8, 112 | c8 int8, 113 | c9 float4, 114 | c10 float8, 115 | c11 bool 116 | ) SERVER binary_loopback OPTIONS (table_name 'ints'); 117 | CREATE FOREIGN TABLE ftypes ( 118 | c1 date, 119 | c2 timestamp without time zone, 120 | c3 text, 121 | c4 text, 122 | c5 uuid, 123 | c6 text, -- Enum8 124 | c7 text -- Enum16 125 | ) SERVER binary_loopback OPTIONS (table_name 'types'); 126 | CREATE FOREIGN TABLE farrays ( 127 | c1 int[], 128 | c2 text[] 129 | ) SERVER binary_loopback OPTIONS (table_name 'arrays'); 130 | CREATE FOREIGN TABLE farrays2 ( 131 | c1 int8[], 132 | c2 text[] 133 | ) SERVER binary_loopback OPTIONS (table_name 'arrays'); 134 | CREATE TABLE tupformat(a int, b text, c float4); 135 | CREATE FOREIGN TABLE ftuples ( 136 | c1 int, 137 | c2 tupformat, 138 | c3 bool 139 | ) SERVER binary_loopback OPTIONS (table_name 'tuples'); 140 | -- integers 141 | SELECT * FROM fints ORDER BY c1; 142 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c9 | c10 | c11 143 | ----+----+----+----+----+----+----+----+------+------+----- 144 | 0 | 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8.1 | 9.2 | f 145 | 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9.1 | 10.2 | t 146 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10.1 | 11.2 | f 147 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11.1 | 12.2 | t 148 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12.1 | 13.2 | f 149 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13.1 | 14.2 | t 150 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14.1 | 15.2 | f 151 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15.1 | 16.2 | t 152 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16.1 | 17.2 | f 153 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16 | 17.1 | 18.2 | t 154 | (10 rows) 155 | 156 | SELECT c2, c1, c8, c3, c4, c7, c6, c5 FROM fints ORDER BY c1; 157 | c2 | c1 | c8 | c3 | c4 | c7 | c6 | c5 158 | ----+----+----+----+----+----+----+---- 159 | 1 | 0 | 7 | 2 | 3 | 6 | 5 | 4 160 | 2 | 1 | 8 | 3 | 4 | 7 | 6 | 5 161 | 3 | 2 | 9 | 4 | 5 | 8 | 7 | 6 162 | 4 | 3 | 10 | 5 | 6 | 9 | 8 | 7 163 | 5 | 4 | 11 | 6 | 7 | 10 | 9 | 8 164 | 6 | 5 | 12 | 7 | 8 | 11 | 10 | 9 165 | 7 | 6 | 13 | 8 | 9 | 12 | 11 | 10 166 | 8 | 7 | 14 | 9 | 10 | 13 | 12 | 11 167 | 9 | 8 | 15 | 10 | 11 | 14 | 13 | 12 168 | 10 | 9 | 16 | 11 | 12 | 15 | 14 | 13 169 | (10 rows) 170 | 171 | SELECT a, b FROM (SELECT c1 * 10 as a, c8 * 11 as b FROM fints ORDER BY a LIMIT 2) t1; 172 | a | b 173 | ----+---- 174 | 0 | 77 175 | 10 | 88 176 | (2 rows) 177 | 178 | SELECT NULL FROM fints LIMIT 2; 179 | ?column? 180 | ---------- 181 | 182 | 183 | (2 rows) 184 | 185 | SELECT c2, NULL, c1, NULL FROM fints ORDER BY c2 LIMIT 2; 186 | c2 | ?column? | c1 | ?column? 187 | ----+----------+----+---------- 188 | 1 | | 0 | 189 | 2 | | 1 | 190 | (2 rows) 191 | 192 | -- types 193 | SELECT * FROM ftypes ORDER BY c1; 194 | c1 | c2 | c3 | c4 | c5 | c6 | c7 195 | ------------+---------------------+----------+-------+--------------------------------------+-----+------- 196 | 1990-01-01 | 1990-01-01 10:00:00 | number 0 | num 0 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e0 | two | three 197 | 1990-01-02 | 1990-01-02 10:01:01 | number 1 | num 1 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e1 | two | three 198 | 1990-01-03 | 1990-01-03 10:02:02 | number 2 | num 2 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e2 | two | three 199 | 1990-01-04 | 1990-01-04 10:03:03 | number 3 | num 3 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e3 | two | three 200 | 1990-01-05 | 1990-01-05 10:04:04 | number 4 | num 4 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e4 | two | three 201 | 1990-01-06 | 1990-01-06 10:05:05 | number 5 | num 5 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e5 | two | three 202 | 1990-01-07 | 1990-01-07 10:06:06 | number 6 | num 6 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e6 | two | three 203 | 1990-01-08 | 1990-01-08 10:07:07 | number 7 | num 7 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e7 | two | three 204 | 1990-01-09 | 1990-01-09 10:08:08 | number 8 | num 8 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e8 | two | three 205 | 1990-01-10 | 1990-01-10 10:09:09 | number 9 | num 9 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e9 | two | three 206 | (10 rows) 207 | 208 | SELECT c2, c1, c4, c3, c5, c7, c6 FROM ftypes ORDER BY c1; 209 | c2 | c1 | c4 | c3 | c5 | c7 | c6 210 | ---------------------+------------+-------+----------+--------------------------------------+-------+----- 211 | 1990-01-01 10:00:00 | 1990-01-01 | num 0 | number 0 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e0 | three | two 212 | 1990-01-02 10:01:01 | 1990-01-02 | num 1 | number 1 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e1 | three | two 213 | 1990-01-03 10:02:02 | 1990-01-03 | num 2 | number 2 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e2 | three | two 214 | 1990-01-04 10:03:03 | 1990-01-04 | num 3 | number 3 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e3 | three | two 215 | 1990-01-05 10:04:04 | 1990-01-05 | num 4 | number 4 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e4 | three | two 216 | 1990-01-06 10:05:05 | 1990-01-06 | num 5 | number 5 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e5 | three | two 217 | 1990-01-07 10:06:06 | 1990-01-07 | num 6 | number 6 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e6 | three | two 218 | 1990-01-08 10:07:07 | 1990-01-08 | num 7 | number 7 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e7 | three | two 219 | 1990-01-09 10:08:08 | 1990-01-09 | num 8 | number 8 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e8 | three | two 220 | 1990-01-10 10:09:09 | 1990-01-10 | num 9 | number 9 | f4bf890f-f9dc-4332-ad5c-0c18e73f28e9 | three | two 221 | (10 rows) 222 | 223 | -- arrays 224 | SELECT * FROM farrays ORDER BY c1; 225 | c1 | c2 226 | --------+-------------- 227 | {0,1} | {num0,num1} 228 | {1,2} | {num1,num2} 229 | {2,3} | {num2,num3} 230 | {3,4} | {num3,num4} 231 | {4,5} | {num4,num5} 232 | {5,6} | {num5,num6} 233 | {6,7} | {num6,num7} 234 | {7,8} | {num7,num8} 235 | {8,9} | {num8,num9} 236 | {9,10} | {num9,num10} 237 | (10 rows) 238 | 239 | SELECT * FROM farrays2 ORDER BY c1; 240 | ERROR: pg_clickhouse: could not cast value from integer[] to bigint[] 241 | -- tuples 242 | SELECT * FROM ftuples ORDER BY c1; 243 | c1 | c2 | c3 244 | ----+----------+---- 245 | 0 | (0,0,1) | f 246 | 1 | (1,1,2) | t 247 | 2 | (2,2,3) | f 248 | 3 | (3,3,4) | t 249 | 4 | (4,4,5) | f 250 | 5 | (5,5,6) | t 251 | 6 | (6,6,7) | f 252 | 7 | (7,7,8) | t 253 | 8 | (8,8,9) | f 254 | 9 | (9,9,10) | t 255 | (10 rows) 256 | 257 | DROP USER MAPPING FOR CURRENT_USER SERVER binary_loopback; 258 | SELECT clickhouse_raw_query('DROP DATABASE binary_test'); 259 | clickhouse_raw_query 260 | ---------------------- 261 | 262 | (1 row) 263 | 264 | DROP SERVER binary_loopback CASCADE; 265 | NOTICE: drop cascades to 5 other objects 266 | DETAIL: drop cascades to foreign table fints 267 | drop cascades to foreign table ftypes 268 | drop cascades to foreign table farrays 269 | drop cascades to foreign table farrays2 270 | drop cascades to foreign table ftuples 271 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | pg_clickhouse Postgres Extension 2 | ================================ 3 | 4 | [![PGXN]][⚙️] [![Docker]][🐳] [![GitHub]][🐙] [![Postgres]][🐘] [![ClickHouse]][🏠] 5 | 6 | This library contains `pg_clickhouse`, a PostgreSQL extension that runs 7 | analytics queries on ClickHouse right from PostgreSQL without rewriting any 8 | SQL. It supports PostgreSQL 13 and later and ClickHouse v23 and later. 9 | 10 | ## Getting Started 11 | 12 | The simplest way to try pg_clickhouse is the [Docker image][🐳], which 13 | contains the standard PostgreSQL Docker image with the pg_clickhouse 14 | extension: 15 | 16 | ```sh 17 | docker run --name pg_clickhouse -e POSTGRES_PASSWORD=my_pass \ 18 | -d ghcr.io/clickhouse/pg_clickhouse:18 19 | docker exec -it pg_clickhouse psql -U postgres -c 'CREATE EXTENSION pg_clickhouse' 20 | ``` 21 | 22 | See the [tutorial](doc/tutorial.md) to get started importing ClickHouse tables 23 | and pushing down queries. 24 | 25 | ## Documentation 26 | 27 | * [Reference](doc/pg_clickhouse.md) 28 | * [Tutorial](doc/tutorial.md) 29 | 30 | ## Test Case: TPC-H 31 | 32 | This table compares [TPC-H] query performance between regular PostgreSQL 33 | tables and pg_clickhouse connected to ClickHouse, both loaded at scaling 34 | factor 1; ✅ indicates full pushdown, while a dash indicates a query 35 | cancellation after 1m. All tests run on a MacBook Pro M4 Max with 36 GB of 36 | memory. 37 | 38 | | Query | Pushdown | pg_clickhouse | PostgreSQL | 39 | | -----------------: | :------: | ------------: | ---------: | 40 | | [Query 1](#r2q1) | ✅ | 73ms | 4478ms | 41 | | [Query 2](#r2q2) | | - | 560ms | 42 | | [Query 3](#r2q3) | ✅ | 74ms | 1454ms | 43 | | [Query 4](#r2q4) | ✅ | 67ms | 650ms | 44 | | [Query 5](#r2q5) | ✅ | 104ms | 452ms | 45 | | [Query 6](#r2q6) | ✅ | 42ms | 740ms | 46 | | [Query 7](#r2q7) | ✅ | 83ms | 633ms | 47 | | [Query 8](#r2q8) | ✅ | 114ms | 320ms | 48 | | [Query 9](#r2q9) | ✅ | 136ms | 3028ms | 49 | | [Query 10](#r2q10) | ✅ | 10ms | 6ms | 50 | | [Query 11](#r2q11) | ✅ | 78ms | 213ms | 51 | | [Query 12](#r2q12) | ✅ | 37ms | 1101ms | 52 | | [Query 13](#r2q13) | | 1242ms | 967ms | 53 | | [Query 14](#r2q14) | ✅ | 51ms | 193ms | 54 | | [Query 15](#r2q15) | | 522ms | 1095ms | 55 | | [Query 16](#r2q16) | | 1797ms | 492ms | 56 | | [Query 17](#r2q17) | | 9ms | 1802ms | 57 | | [Query 18](#r2q18) | | 10ms | 6185ms | 58 | | [Query 19](#r2q19) | | 532ms | 64ms | 59 | | [Query 20](#r2q20) | | 4595ms | 473ms | 60 | | [Query 21](#r2q21) | | 1702ms | 1334ms | 61 | | [Query 22](#r2q22) | | 268ms | 257ms | 62 | 63 | ### Compile From Source 64 | 65 | #### General Unix 66 | 67 | The PostgreSQL and curl development packages include `pg_config` and 68 | `curl-config` in the path, so you should be able to just run `make` (or 69 | `gmake`), then `make install`, then in your database `CREATE EXTENSION http`. 70 | 71 | #### Debian / Ubuntu / APT 72 | 73 | See [PostgreSQL Apt] for details on pulling from the PostgreSQL Apt repository. 74 | 75 | ```sh 76 | sudo apt install \ 77 | postgresql-server-18 \ 78 | libcurl4-openssl-dev \ 79 | uuid-dev \ 80 | libssl-dev \ 81 | make \ 82 | cmake \ 83 | g++ 84 | ``` 85 | 86 | #### RedHat / CentOS / Yum 87 | 88 | ```sh 89 | sudo yum install \ 90 | postgresql-server \ 91 | libcurl-devel \ 92 | libuuid-devel \ 93 | openssl-libs \ 94 | automake \ 95 | cmake \ 96 | gcc 97 | ``` 98 | 99 | See [PostgreSQL Yum] for details on pulling from the PostgreSQL Yum repository. 100 | 101 | #### Install From PGXN 102 | 103 | With the above dependencies satisfied use the [PGXN client] (available as 104 | [Homebrew], [Apt] and Yum packages named `pgxnclient`) to download, compile, 105 | and install `pg_clickhouse`: 106 | 107 | 108 | ```sh 109 | pgxn install pg_clickhouse 110 | ``` 111 | 112 | #### Compile and Install 113 | 114 | To build and install the ClickHouse library and `pg_clickhouse`, run: 115 | 116 | ```sh 117 | make 118 | sudo make install 119 | ``` 120 | 121 | 132 | 133 | If your host has several PostgreSQL installations, you might need to specify 134 | the appropriate version of `pg_config`: 135 | 136 | ```sh 137 | export PG_CONFIG=/usr/lib/postgresql/18/bin/pg_config 138 | make 139 | sudo make install 140 | ``` 141 | 142 | If `curl-config` is not in the path on you host, you can specify the path 143 | explicitly: 144 | 145 | ```sh 146 | export CURL_CONFIG=/opt/homebrew/opt/curl/bin/curl-config 147 | make 148 | sudo make install 149 | ``` 150 | 151 | If you encounter an error such as: 152 | 153 | ``` text 154 | "Makefile", line 8: Need an operator 155 | ``` 156 | 157 | You need to use GNU make, which may well be installed on your system as 158 | `gmake`: 159 | 160 | ``` sh 161 | gmake 162 | gmake install 163 | gmake installcheck 164 | ``` 165 | 166 | If you encounter an error such as: 167 | 168 | ``` text 169 | make: pg_config: Command not found 170 | ``` 171 | 172 | Be sure that you have `pg_config` installed and in your path. If you used a 173 | package management system such as RPM to install PostgreSQL, be sure that the 174 | `-devel` package is also installed. If necessary tell the build process where 175 | to find it: 176 | 177 | ``` sh 178 | export PG_CONFIG=/path/to/pg_config 179 | make 180 | sudo make install 181 | ``` 182 | 183 | To install the extension in a custom prefix on PostgreSQL 18 or later, pass 184 | the `prefix` argument to `install` (but no other `make` targets): 185 | 186 | ```sh 187 | sudo make install prefix=/usr/local/extras 188 | ``` 189 | 190 | Then ensure that the prefix is included in the following [`postgresql.conf` 191 | parameters]: 192 | 193 | ```ini 194 | extension_control_path = '/usr/local/extras/postgresql/share:$system' 195 | dynamic_library_path = '/usr/local/extras/postgresql/lib:$libdir' 196 | ``` 197 | 198 | #### Testing 199 | 200 | To run the test suite, once the extension has been installed, run 201 | 202 | ```sh 203 | make installcheck 204 | ``` 205 | 206 | If you encounter an error such as: 207 | 208 | ``` text 209 | ERROR: must be owner of database regression 210 | ``` 211 | 212 | You need to run the test suite using a super user, such as the default 213 | "postgres" super user: 214 | 215 | ``` sh 216 | make installcheck PGUSER=postgres 217 | ``` 218 | 219 | ### Loading 220 | 221 | Once `pg_clickhouse` is installed, you can add it to a database by connecting 222 | as a super user and running: 223 | 224 | ``` sql 225 | CREATE EXTENSION pg_clickhouse; 226 | ``` 227 | 228 | If you want to install `pg_clickhouse` and all of its supporting objects into 229 | a specific schema, use the `SCHEMA` clause to specify the schema, like so: 230 | 231 | ``` sql 232 | CREATE SCHEMA env; 233 | CREATE EXTENSION pg_clickhouse SCHEMA env; 234 | ``` 235 | 236 | ## Dependencies 237 | 238 | The `pg_clickhouse` extension requires [PostgreSQL] 13 or higher, [libcurl], 239 | [libuuid]. Building the extension requires a C and C++ compiler, [libSSL], [GNU 240 | make], and [CMake]. 241 | 242 | ## Road Map 243 | 244 | Our top focus is finishing pushdown coverage for analytic workloads before 245 | adding DML features. Our road map: 246 | 247 | * Get the remaining 10 un-pushed-down TPC-H queries optimally planned 248 | * Test and fix pushdown for the ClickBench queries 249 | * Support transparent pushdown of all PostgreSQL aggregate functions 250 | * Support transparent pushdown of all PostgreSQL functions 251 | * Allow server-level and session-level ClickHouse settings via CREATE SERVER 252 | and GUCs 253 | * Support all ClickHouse data types 254 | * Support lightweight DELETEs and UPDATEs 255 | * Support batch insertion via COPY 256 | * Add a function to execute an arbitrary ClickHouse query and return its 257 | results as a tables 258 | * Add support for pushdown of UNION queries when they all query the remote 259 | database 260 | 261 | ## Authors 262 | 263 | * [David E. Wheeler](https://justatheory.com/) 264 | * [Ildus Kurbangaliev](https://github.com/ildus) 265 | * [Ibrar Ahmed](https://github.com/ibrarahmad) 266 | 267 | ## Copyright 268 | 269 | * Copyright (c) 2025, ClickHouse 270 | * Portions Copyright (c) 2023-2025, Ildus Kurbangaliev 271 | * Portions Copyright (c) 2019-2023, Adjust GmbH 272 | * Portions Copyright (c) 2012-2019, PostgreSQL Global Development Group 273 | 274 | [PGXN]: https://badge.fury.io/pg/pg_clickhouse.svg 275 | [⚙️]: https://pgxn.org/dist/pg_clickhouse "Latest version on PGXN" 276 | [Postgres]: https://github.com/clickhouse/pg_clickhouse/actions/workflows/postgres.yml/badge.svg 277 | [🐘]: https://github.com/clickhouse/pg_clickhouse/actions/workflows/postgres.yml "Tested with PostgreSQL 13-18" 278 | [ClickHouse]: https://github.com/clickhouse/pg_clickhouse/actions/workflows/clickhouse.yml/badge.svg 279 | [🏠]: https://github.com/clickhouse/pg_clickhouse/actions/workflows/clickhouse.yml "Tested with ClickHouse v23–25" 280 | [Docker]: https://img.shields.io/github/v/release/ClickHouse/pg_clickhouse?label=%F0%9F%90%B3%20Docker&color=44cc11 281 | [🐳]: https://github.com/ClickHouse/pg_clickhouse/pkgs/container/pg_clickhouse "Latest Docker release" 282 | [GitHub]: https://img.shields.io/github/v/release/ClickHouse/pg_clickhouse?label=%F0%9F%90%99%20GitHub&color=44cc11 283 | [🐙]: https://github.com/ClickHouse/pg_clickhouse/releases "Latest release on GitHub" 284 | 285 | [PostgreSQL Apt]: https://wiki.postgresql.org/wiki/Apt 286 | [PostgreSQL Yum]: https://yum.postgresql.org 287 | [PGXN client]: https://pgxn.github.io/pgxnclient/ "PGXN Client’s documentation" 288 | [Homebrew]: https://formulae.brew.sh/formula/pgxnclient#default "PGXN client on Homebrew" 289 | [Apt]: https://tracker.debian.org/pkg/pgxnclient "PGXN client on Debian Apt" 290 | [`postgresql.conf` parameters]: https://www.postgresql.org/docs/devel/runtime-config-client.html#RUNTIME-CONFIG-CLIENT-OTHER 291 | [PostgreSQL]: https://www.postgresql.org "PostgreSQL: The World's Most Advanced Open Source Relational Database" 292 | [libcurl]: https://curl.se/libcurl/ "libcurl — your network transfer library" 293 | [libuuid]: https://linux.die.net/man/3/libuuid "libuuid - DCE compatible Universally Unique Identifier library" 294 | [GNU make]: https://www.gnu.org/software/make "GNU Make" 295 | [CMake]: https://cmake.org/ "CMake: A Powerful Software Build System" 296 | [LibSSL]: https://openssl-library.org "OpenSSL Library" 297 | [TPC-H]: https://www.tpc.org/tpch/ 298 | --------------------------------------------------------------------------------