From 2bc4c6330bfe887a5ffde1695b08c28569f3a696 Mon Sep 17 00:00:00 2001 From: "David E. Wheeler" Date: Thu, 1 Jan 2026 15:26:25 -0500 Subject: [PATCH] Fix binary date/time conversion; add Date32 Add tests for Postgres aggregate function pushdown. Eventually it will cover all of the aggregate functions; for now it tests `avg()` and `array_agg()`, with `min()` started but commented-out, because Postgres doesn't push it down, instead sending a an `ORDER BY` and `LIMIT 1`, which works great for some databases, but as of now pg_clickhouse doesn't push down that `LIMIT 1`. And it would be better to let it execute its own plan. More investigation on that in future commits. Meanwhile, fix a few bugs discovered while testing `array_agg()` and a failing ClickBench query. First, ClickHouse UUID arrays fetched via the http engine failed to parse into Postgres Arrays because ClickHouse single-quotes each UUID and Postgres does not. Update the parser to replace those single quotes with spaces, which Postgres happily ignores. Next, dates were improperly displayed as `10529827-09-17` instead of `2025-12-05` when loaded in arrays (as by `date_agg()`). Tome Lane suggested using `timestamptz_date` instead of the `time_t_to_timestamptz(val)` call used previously, but it kept returning the wrong values: off by a day in the aggregation tests and `2000-01-01` in the binary insert tests. Turns out there were two issues: 1). `timestamp_date` is the right function, not `timestamptz_date`; and 2) there was some conversion code just for Dates after selection! Switching to `timestamp_date` and eliminating the conversion code fixed those issues. Finally, dates from ClickBench weren't showing up at all. I figured out that the dates I was looking at were all `1970-01-01`, and that the binary conversion code handled a "special case" where an epoch value of `0` was null. It's not! So add tests for epoch zero `Date` and `DateTime` values and remove those "special cases". This revealed an issue where a DateTime64 epoch `0` returned `2000-01-01` on macOS, though not on Linux. Switching to `time_t_to_timestamptz` fixes the issue, but requires separate handling of sub-second precision, done with integers rather than floats, fixing imprecision in the output of some timestamps. While at it, add support for `Date32`, which behaves exactly like `Date` as far as Postgres is concerned. --- CHANGELOG.md | 15 + doc/pg_clickhouse.md | 3 + src/binary.cpp | 46 +-- src/convert.c | 11 +- src/custom_types.c | 7 + src/fdw.c.in | 3 + src/pglink.c | 4 +- test/expected/aggregates.out | 579 +++++++++++++++++++++++++++++ test/expected/binary_inserts.out | 30 +- test/expected/binary_inserts_1.out | 29 +- test/expected/http_inserts.out | 30 +- test/expected/http_inserts_1.out | 29 +- test/sql/aggregates.sql | 235 ++++++++++++ test/sql/binary_inserts.sql | 12 +- test/sql/http_inserts.sql | 12 +- 15 files changed, 947 insertions(+), 98 deletions(-) create mode 100644 test/expected/aggregates.out create mode 100644 test/sql/aggregates.sql diff --git a/CHANGELOG.md b/CHANGELOG.md index 3770ed3..28891c9 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -25,6 +25,21 @@ All notable changes to this project will be documented in this file. It uses the docs](doc/pg_clickhouse.md), including the new `PREPARE`/`EXECUTE` support and `INSERT`, `SET`, `COPY`, as well as shared library preloading. +### 🪲 Bug Fixes + +* Fixed the http engine's parsing of UUID arrays selected from ClickHouse. +* Fixed the binary engine's conversion of Date values, which in arrays ended + up too large by several orders of magnitude (e.g., `2025-12-05` would be + converted to `10529827-09-17` 😱). Thanks to Tom Lane for the pointer to + the proper function to easily convert epoch seconds to a date. +* Fixed a binary engine bug where dates and timestamps for epoch 0 + (`1970-01-01 00:00:00`) rendered as `NULL`. +* Added support for the `Date32` ClickHouse type. +* Fixed conversion of `array_agg()` to support ClickHouse versions prior to + 23.8. +* Fixed the precision of fractional seconds in the binary engine's + conversion of ClickHouse DateTime64 values to Postgres TIMESTAMP (#114). + ### 📔 Notes * Removed unused code designed to support custom PostgreSQL extensions: diff --git a/doc/pg_clickhouse.md b/doc/pg_clickhouse.md index 799c06b..1415c05 100644 --- a/doc/pg_clickhouse.md +++ b/doc/pg_clickhouse.md @@ -788,6 +788,7 @@ types: ------------+------------------+------------------------------- Bool | boolean | Date | date | + Date32 | date | DateTime | timestamp | Decimal | numeric | Float32 | real | @@ -916,6 +917,8 @@ pushed down. These PostgreSQL aggregate functions pushdown to ClickHouse. +* [array_agg](https://clickhouse.com/docs/sql-reference/aggregate-functions/reference/grouparray) +* [avg](https://clickhouse.com/docs/sql-reference/aggregate-functions/reference/avg) * [count](https://clickhouse.com/docs/sql-reference/aggregate-functions/reference/count) ### Custom Aggregates diff --git a/src/binary.cpp b/src/binary.cpp index 7b784ba..6e1f005 100644 --- a/src/binary.cpp +++ b/src/binary.cpp @@ -299,6 +299,7 @@ static Oid get_corr_postgres_type(const TypeRef & type) case Type::Code::LowCardinality: return get_corr_postgres_type(type->As()->GetNestedType()); case Type::Code::Date: + case Type::Code::Date32: return DATEOID; case Type::Code::DateTime: return TIMESTAMPOID; @@ -538,14 +539,17 @@ static void column_append(clickhouse::ColumnRef col, Datum val, Oid valtype, boo break; } case DATEOID: { - Timestamp t = date2timestamp_no_overflow(DatumGetDateADT(val)); - pg_time_t d = timestamptz_to_time_t(t); + Timestamp t = date2timestamp_no_overflow(DatumGetDateADT(val)); + pg_time_t d = timestamptz_to_time_t(t); switch (col->Type()->GetCode()) { case Type::Code::Date: col->As()->Append(d); break; + case Type::Code::Date32: + col->As()->Append(d); + break; default: THROW_UNEXPECTED_COLUMN("DATE", col); } @@ -864,44 +868,28 @@ static Datum make_datum(clickhouse::ColumnRef col, size_t row, Oid * valtype, bo case Type::Code::Date: { auto val = static_cast(col->As()->At(row)); *valtype = DATEOID; - - if (val == 0) - /* clickhouse special case */ - *is_null = true; - else - { - Timestamp t = (Timestamp)time_t_to_timestamptz(val); - ret = TimestampGetDatum(t); - } + ret = DirectFunctionCall1(timestamp_date, time_t_to_timestamptz(val)); + } + break; + case Type::Code::Date32: { + auto val = static_cast(col->As()->At(row)); + *valtype = DATEOID; + ret = DirectFunctionCall1(timestamp_date, time_t_to_timestamptz(val)); } break; case Type::Code::DateTime: { auto val = static_cast(col->As()->At(row)); *valtype = TIMESTAMPOID; - - if (val == 0) - *is_null = true; - else - { - Timestamp t = (Timestamp)time_t_to_timestamptz(val); - ret = TimestampGetDatum(t); - } + ret = TimestampGetDatum(time_t_to_timestamptz(val)); } break; case Type::Code::DateTime64: { auto dt_col = col->As(); auto val = dt_col->At(row); - + int64 power = pow(10, dt_col->GetPrecision()); *valtype = TIMESTAMPOID; - - if (val == 0) - *is_null = true; - else - { - ret = ((1.0 * val) / pow(10, dt_col->GetPrecision()) - - (POSTGRES_EPOCH_JDATE - UNIX_EPOCH_JDATE) * SECS_PER_DAY) - * USECS_PER_SEC; - } + ret = TimestampGetDatum(time_t_to_timestamptz(val / power)) + + (val % power) * (USECS_PER_SEC / power); } break; case Type::Code::UUID: { diff --git a/src/convert.c b/src/convert.c index aeebc57..157e071 100644 --- a/src/convert.c +++ b/src/convert.c @@ -181,13 +181,6 @@ convert_bool_to_int16(ch_convert_output_state * state, Datum val) return Int16GetDatum(DatumGetBool(val) ? 1 : 0); } -static Datum -convert_date(ch_convert_state * state, Datum val) -{ - val = DirectFunctionCall1(timestamp_date, val); - return convert_generic(state, val); -} - Datum ch_binary_convert_datum(void *state, Datum val) { @@ -206,9 +199,7 @@ ch_binary_init_convert_state(Datum val, Oid intype, Oid outtype) state->typmod = -1; state->ctype = COERCION_PATH_NONE; - if (intype == DATEOID) - state->func = convert_date; - else if (intype == ANYARRAYOID) + if (intype == ANYARRAYOID) { ch_binary_array_t *slot = (ch_binary_array_t *) DatumGetPointer(val); diff --git a/src/custom_types.c b/src/custom_types.c index 90c2a25..948944a 100644 --- a/src/custom_types.c +++ b/src/custom_types.c @@ -37,6 +37,7 @@ #define F_DATE_PART_TEXT_DATE 1384 #define F_PERCENTILE_CONT_FLOAT8_FLOAT8 3974 #define F_PERCENTILE_CONT_FLOAT8_INTERVAL 3976 +#define F_ARRAY_AGG_ANYNONARRAY 2335 /* * Prior to Postgres 14 EXTRACT mapped directly to DATE_PART. @@ -195,6 +196,7 @@ chfdw_check_for_custom_function(Oid funcid) case F_REGEXP_LIKE_TEXT_TEXT: case F_PERCENTILE_CONT_FLOAT8_FLOAT8: case F_PERCENTILE_CONT_FLOAT8_INTERVAL: + case F_ARRAY_AGG_ANYNONARRAY: special_builtin = true; break; default: @@ -269,6 +271,11 @@ chfdw_check_for_custom_function(Oid funcid) strcpy(entry->custom_name, "quantile"); break; } + case F_ARRAY_AGG_ANYNONARRAY: + { + strcpy(entry->custom_name, "groupArray"); + break; + } } if (special_builtin) diff --git a/src/fdw.c.in b/src/fdw.c.in index 62f4464..291ab09 100644 --- a/src/fdw.c.in +++ b/src/fdw.c.in @@ -905,6 +905,9 @@ fetch_tuple(ChFdwScanState * fsstate, TupleDesc tupdesc) valstr[pos] = '{'; if (valstr[pos] == ']') valstr[pos] = '}'; + if (valstr[pos] == '\'' && pgtype == UUIDARRAYOID) + /* Remove ClickHouse's single quotes around UUIDs */ + valstr[pos] = ' '; pos++; } } diff --git a/src/pglink.c b/src/pglink.c index 28144a0..fd217b8 100644 --- a/src/pglink.c +++ b/src/pglink.c @@ -382,7 +382,7 @@ chfdw_datum_to_ch_literal(Datum value, Oid type) text = OidOutputFunctionCall(typoutput, value); len = strlen(text); result = palloc(len * 2 + 1); - ch_escape_string(result, text, len+1); + ch_escape_string(result, text, len + 1); return result; } case DATEOID: @@ -785,6 +785,7 @@ binary_insert_tuple(void *istate, TupleTableSlot * slot) ('String', 'text', ''), ('DateTime', 'timestamp', ''), ('Date', 'date', ''), + ('Date32', 'date', ''), ('UUID', 'uuid', ''), ('IPv4', 'inet', ''), ('IPv6', 'inet', ''), @@ -810,6 +811,7 @@ static char *str_types_map[][2] = { {"String", "TEXT"}, {"DateTime", "TIMESTAMP"}, {"Date", "DATE"}, /* must come after other Date types */ + {"Date32", "DATE"}, {"UUID", "UUID"}, {"IPv4", "inet"}, {"IPv6", "inet"}, diff --git a/test/expected/aggregates.out b/test/expected/aggregates.out new file mode 100644 index 0000000..f4afdd4 --- /dev/null +++ b/test/expected/aggregates.out @@ -0,0 +1,579 @@ +\unset ECHO + clickhouse_raw_query +---------------------- + +(1 row) + + clickhouse_raw_query +---------------------- + +(1 row) + + clickhouse_raw_query +---------------------- + +(1 row) + + clickhouse_raw_query +---------------------- + +(1 row) + + Foreign table "agg_bin.hits" + Column | Type | Collation | Nullable | Default | FDW options +-----------+-----------------------------+-----------+----------+---------+------------- + id | bigint | | not null | | + uuid | uuid | | not null | | + timestamp | timestamp without time zone | | not null | | + datestamp | date | | not null | | + path | text | | not null | | + duration | bigint | | not null | | + cost | numeric(10,2) | | not null | | +Server: agg_bin_svr +FDW options: (database 'agg_test', table_name 'hits', engine 'MergeTree') + + Foreign table "agg_http.hits" + Column | Type | Collation | Nullable | Default | FDW options +-----------+-----------------------------+-----------+----------+---------+------------- + id | bigint | | not null | | + uuid | uuid | | not null | | + timestamp | timestamp without time zone | | not null | | + datestamp | date | | not null | | + path | text | | not null | | + duration | bigint | | not null | | + cost | numeric(10,2) | | not null | | +Server: agg_http_svr +FDW options: (database 'agg_test', table_name 'hits', engine 'MergeTree') + +-- AVG(UInt64) + QUERY PLAN +------------------------------------------------- + Foreign Scan + Output: (avg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(id) FROM agg_test.hits +(4 rows) + + avg +--------------- + 2420827679.54 +(1 row) + + QUERY PLAN +------------------------------------------------- + Foreign Scan + Output: (avg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(id) FROM agg_test.hits +(4 rows) + + avg +--------------- + 2420827679.54 +(1 row) + + QUERY PLAN +--------------------------------------------------------------------------- + Foreign Scan + Output: (avg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(id) FROM agg_test.hits WHERE ((id < 1000000000)) +(4 rows) + + avg +------------- + 404449748.2 +(1 row) + + QUERY PLAN +--------------------------------------------------------------------------- + Foreign Scan + Output: (avg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(id) FROM agg_test.hits WHERE ((id < 1000000000)) +(4 rows) + + avg +------------- + 404449748.2 +(1 row) + +-- AVG(UInt32) + QUERY PLAN +------------------------------------------------------- + Foreign Scan + Output: (avg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(duration) FROM agg_test.hits +(4 rows) + + avg +------ + 1095 +(1 row) + + QUERY PLAN +------------------------------------------------------- + Foreign Scan + Output: (avg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(duration) FROM agg_test.hits +(4 rows) + + avg +------ + 1095 +(1 row) + + QUERY PLAN +--------------------------------------------------------------------------------------- + Foreign Scan + Output: (avg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(duration) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + avg +------ + 1095 +(1 row) + + QUERY PLAN +--------------------------------------------------------------------------------------- + Foreign Scan + Output: (avg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(duration) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + avg +------ + 1095 +(1 row) + +-- AVG(Decimal) + QUERY PLAN +--------------------------------------------------- + Foreign Scan + Output: (avg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(cost) FROM agg_test.hits +(4 rows) + + avg +-------- + 5.0768 +(1 row) + + QUERY PLAN +--------------------------------------------------- + Foreign Scan + Output: (avg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(cost) FROM agg_test.hits +(4 rows) + + avg +-------- + 5.0768 +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------- + Foreign Scan + Output: (avg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(cost) FROM agg_test.hits WHERE ((cost < 1000000000)) +(4 rows) + + avg +-------- + 5.0768 +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------- + Foreign Scan + Output: (avg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT avg(cost) FROM agg_test.hits WHERE ((cost < 1000000000)) +(4 rows) + + avg +-------- + 5.0768 +(1 row) + +-- array_agg(UInt64) + QUERY PLAN +-------------------------------------------------------- + Foreign Scan + Output: (array_agg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(id) FROM agg_test.hits +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {3498231651,1431223188,1331538905,3451631267,2757160710,4049681990,3319320102,2178896781,2433222225,3948091185,3122655508,3095867833,2720322600,2400403412,3159416553,4160213552,3910581405,3267604082,3841934465,4264738908,2005666276,3824162205,352088655,467263982,2890629064,4072815052,1008605146,837437371,3517179953,2836779925,1470995555,3849384968,3334361077,3258018379,1750004811,280308092,3231552675,392385086,287518381,1334989359,4093728327,1406653594,366963527,3432633864,104048445,914876110,1982637736,41607833,3814959307,1538392900} +(1 row) + + QUERY PLAN +-------------------------------------------------------- + Foreign Scan + Output: (array_agg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(id) FROM agg_test.hits +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {3498231651,1431223188,1331538905,3451631267,2757160710,4049681990,3319320102,2178896781,2433222225,3948091185,3122655508,3095867833,2720322600,2400403412,3159416553,4160213552,3910581405,3267604082,3841934465,4264738908,2005666276,3824162205,352088655,467263982,2890629064,4072815052,1008605146,837437371,3517179953,2836779925,1470995555,3849384968,3334361077,3258018379,1750004811,280308092,3231552675,392385086,287518381,1334989359,4093728327,1406653594,366963527,3432633864,104048445,914876110,1982637736,41607833,3814959307,1538392900} +(1 row) + + QUERY PLAN +---------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(id) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------ + {352088655,467263982,837437371,280308092,392385086,287518381,366963527,104048445,914876110,41607833} +(1 row) + + QUERY PLAN +---------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(id)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(id) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------ + {352088655,467263982,837437371,280308092,392385086,287518381,366963527,104048445,914876110,41607833} +(1 row) + +-- array_agg(UUID) + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(uuid)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(uuid) FROM agg_test.hits +(4 rows) + + array_agg +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {8cab5a51-8927-43f4-8104-b2c81ffc3d8a,691a0477-c3fa-404d-a478-d4caaaa24832,f44459f2-9bbd-4149-9ac8-69c7b22f1aa0,148181e2-a573-481f-9e2a-02441d523034,974f2e1d-6918-4cce-935c-d445428584cc,720ad53d-db83-4091-a262-cfc7347f96ae,b623608d-459d-43d2-90ac-d1a8de83ff17,d205ee5d-dd47-4a63-be2f-198fcfb7403b,1f1dd4dd-2b05-4876-b98c-cb5ba1f34b89,a77b5881-262a-47c4-8494-a211e48b9c6c,aef92b53-0b2a-4777-8d9d-ce5a6443ef54,99f9a13a-357a-40fd-b415-1966865468d3,5c740ee9-a7a2-43e4-8ab1-e8c147f78c8b,d12fe0f1-9c4c-4039-9027-3e9f62d1da54,7885ab07-3740-461f-ac0c-c8732c07d86e,031a4434-e4f8-465d-8b13-7537ad578e93,1c0f3511-3f88-4d4a-a053-724449619420,d60a7c1d-dccf-427b-b685-9a6077a88867,c066fdd6-0172-46aa-9792-63455cb069b4,9f420aa6-f015-4caa-a2f8-2ca0e7a652a6,b8615e95-f95f-458e-aa87-b6e6634503d9,06fa959e-afe3-414d-9771-650547091079,f5468669-4391-4ed7-99be-82061f8f3f93,77af0ea8-2fef-4a21-bee0-335f9aa995c6,368679e8-8f2a-47dd-8bce-b491bdd09720,90b90c80-8f8e-44e1-9468-e4d2cddd22bb,6da3afd4-4fa3-49b7-ab29-ffe1b2bb7082,b5628648-e429-4fb9-9d77-de539d32f29f,3e4b5d8b-7b09-4d1c-9eb4-855f0ae108d2,5e57a6fe-0196-4100-865a-7d6dc55765c2,0d8c0e39-679f-4034-b48f-aa1595b02dfc,533582ce-95eb-4fb6-804e-6256ea6adaac,a04b2cbd-c5b9-4f65-8449-0827d6c7f712,d5c34dc5-b5db-455d-9528-fe466bdadd2c,eda72c6e-3161-47dd-ba25-cf059bb995da,68b5127e-9819-453f-812d-f1b90979f872,4886ebda-a378-4181-a291-c235ec1047a8,69229156-bb5a-450d-91a0-474f39a20bab,1adf4190-5147-4e7e-b354-7715a5a81c40,52220ad9-02f0-4ad7-ad74-dc6add362a99,44cccdf8-d398-40c7-9e41-117a37e93b9e,e636df93-8421-4926-bf6f-1d1ee36edd35,af62cc2f-e706-4d1d-a740-fd80c55a1250,b50622a5-0e0a-4f66-8be1-84c7cc6851b6,19b74725-9827-4d84-b4dc-b86788193002,2ddfb5b7-9ae5-428b-9351-48e823230672,969e2c53-c735-4649-a6a3-3107ed089cb0,ad89a796-f7c6-4549-bd2e-ced0e586a5a5,70525fca-b870-4976-9377-fc959353302a,7e3f2fe1-5312-4257-ba3e-54662ba14b56} +(1 row) + + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(uuid)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(uuid) FROM agg_test.hits +(4 rows) + + array_agg +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {8cab5a51-8927-43f4-8104-b2c81ffc3d8a,691a0477-c3fa-404d-a478-d4caaaa24832,f44459f2-9bbd-4149-9ac8-69c7b22f1aa0,148181e2-a573-481f-9e2a-02441d523034,974f2e1d-6918-4cce-935c-d445428584cc,720ad53d-db83-4091-a262-cfc7347f96ae,b623608d-459d-43d2-90ac-d1a8de83ff17,d205ee5d-dd47-4a63-be2f-198fcfb7403b,1f1dd4dd-2b05-4876-b98c-cb5ba1f34b89,a77b5881-262a-47c4-8494-a211e48b9c6c,aef92b53-0b2a-4777-8d9d-ce5a6443ef54,99f9a13a-357a-40fd-b415-1966865468d3,5c740ee9-a7a2-43e4-8ab1-e8c147f78c8b,d12fe0f1-9c4c-4039-9027-3e9f62d1da54,7885ab07-3740-461f-ac0c-c8732c07d86e,031a4434-e4f8-465d-8b13-7537ad578e93,1c0f3511-3f88-4d4a-a053-724449619420,d60a7c1d-dccf-427b-b685-9a6077a88867,c066fdd6-0172-46aa-9792-63455cb069b4,9f420aa6-f015-4caa-a2f8-2ca0e7a652a6,b8615e95-f95f-458e-aa87-b6e6634503d9,06fa959e-afe3-414d-9771-650547091079,f5468669-4391-4ed7-99be-82061f8f3f93,77af0ea8-2fef-4a21-bee0-335f9aa995c6,368679e8-8f2a-47dd-8bce-b491bdd09720,90b90c80-8f8e-44e1-9468-e4d2cddd22bb,6da3afd4-4fa3-49b7-ab29-ffe1b2bb7082,b5628648-e429-4fb9-9d77-de539d32f29f,3e4b5d8b-7b09-4d1c-9eb4-855f0ae108d2,5e57a6fe-0196-4100-865a-7d6dc55765c2,0d8c0e39-679f-4034-b48f-aa1595b02dfc,533582ce-95eb-4fb6-804e-6256ea6adaac,a04b2cbd-c5b9-4f65-8449-0827d6c7f712,d5c34dc5-b5db-455d-9528-fe466bdadd2c,eda72c6e-3161-47dd-ba25-cf059bb995da,68b5127e-9819-453f-812d-f1b90979f872,4886ebda-a378-4181-a291-c235ec1047a8,69229156-bb5a-450d-91a0-474f39a20bab,1adf4190-5147-4e7e-b354-7715a5a81c40,52220ad9-02f0-4ad7-ad74-dc6add362a99,44cccdf8-d398-40c7-9e41-117a37e93b9e,e636df93-8421-4926-bf6f-1d1ee36edd35,af62cc2f-e706-4d1d-a740-fd80c55a1250,b50622a5-0e0a-4f66-8be1-84c7cc6851b6,19b74725-9827-4d84-b4dc-b86788193002,2ddfb5b7-9ae5-428b-9351-48e823230672,969e2c53-c735-4649-a6a3-3107ed089cb0,ad89a796-f7c6-4549-bd2e-ced0e586a5a5,70525fca-b870-4976-9377-fc959353302a,7e3f2fe1-5312-4257-ba3e-54662ba14b56} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------ + Foreign Scan + Output: (array_agg(uuid)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(uuid) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {f5468669-4391-4ed7-99be-82061f8f3f93,77af0ea8-2fef-4a21-bee0-335f9aa995c6,b5628648-e429-4fb9-9d77-de539d32f29f,68b5127e-9819-453f-812d-f1b90979f872,69229156-bb5a-450d-91a0-474f39a20bab,1adf4190-5147-4e7e-b354-7715a5a81c40,af62cc2f-e706-4d1d-a740-fd80c55a1250,19b74725-9827-4d84-b4dc-b86788193002,2ddfb5b7-9ae5-428b-9351-48e823230672,ad89a796-f7c6-4549-bd2e-ced0e586a5a5} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------ + Foreign Scan + Output: (array_agg(uuid)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(uuid) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {f5468669-4391-4ed7-99be-82061f8f3f93,77af0ea8-2fef-4a21-bee0-335f9aa995c6,b5628648-e429-4fb9-9d77-de539d32f29f,68b5127e-9819-453f-812d-f1b90979f872,69229156-bb5a-450d-91a0-474f39a20bab,1adf4190-5147-4e7e-b354-7715a5a81c40,af62cc2f-e706-4d1d-a740-fd80c55a1250,19b74725-9827-4d84-b4dc-b86788193002,2ddfb5b7-9ae5-428b-9351-48e823230672,ad89a796-f7c6-4549-bd2e-ced0e586a5a5} +(1 row) + +-- array_agg(DateTime64) + QUERY PLAN +----------------------------------------------------------------- + Foreign Scan + Output: (array_agg("timestamp")) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray("timestamp") FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + {"2025-12-05 11:51:04.390884","2025-12-05 12:22:20.135213","2025-12-05 14:31:50.452533","2025-12-05 19:06:00.126014","2025-12-05 19:07:10.399278","2025-12-05 20:07:22.673831","2025-12-06 03:25:34.627161","2025-12-06 05:50:56.818572","2025-12-06 13:02:50.972837","2025-12-07 15:42:06.88149","2025-12-07 17:28:58.124117","2025-12-07 23:20:36.618385","2025-12-08 01:59:58.417052","2025-12-08 03:00:24.806643","2025-12-08 14:42:58.34422","2025-12-08 20:14:32.23635","2025-12-09 00:08:20.392948","2025-12-10 00:39:44.518284","2025-12-10 00:49:32.950914","2025-12-10 04:57:48.584719","2025-12-10 09:29:52.666577","2025-12-10 13:40:28.486178","2025-12-10 16:24:16.877779","2025-12-12 09:52:04.236867","2025-12-12 20:46:06.572602","2025-12-12 23:50:54.686406","2025-12-13 06:58:08.868876","2025-12-13 10:27:26.390655","2025-12-13 14:15:10.219085","2025-12-13 14:54:36.17439","2025-12-13 17:08:04.502729","2025-12-13 18:05:14.46441","2025-12-13 21:09:06.290341","2025-12-14 11:21:28.869821","2025-12-14 17:21:16.478761","2025-12-14 22:32:04.449588","2025-12-15 07:35:16.55788","2025-12-15 16:41:30.608217","2025-12-15 17:07:24.893024","2025-12-15 18:34:26.171566","2025-12-15 21:17:32.577173","2025-12-16 09:13:10.107266","2025-12-16 10:11:58.434566","2025-12-16 13:04:10.855999","2025-12-16 16:17:36.473802","2025-12-17 02:07:56.978358","2025-12-17 11:09:02.207676","2025-12-18 16:36:18.43735","2025-12-18 22:57:20.264686","2025-12-19 07:24:50.960198"} +(1 row) + + QUERY PLAN +----------------------------------------------------------------- + Foreign Scan + Output: (array_agg("timestamp")) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray("timestamp") FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + {"2025-12-05 11:51:04.390884","2025-12-05 12:22:20.135213","2025-12-05 14:31:50.452533","2025-12-05 19:06:00.126014","2025-12-05 19:07:10.399278","2025-12-05 20:07:22.673831","2025-12-06 03:25:34.627161","2025-12-06 05:50:56.818572","2025-12-06 13:02:50.972837","2025-12-07 15:42:06.88149","2025-12-07 17:28:58.124117","2025-12-07 23:20:36.618385","2025-12-08 01:59:58.417052","2025-12-08 03:00:24.806643","2025-12-08 14:42:58.34422","2025-12-08 20:14:32.23635","2025-12-09 00:08:20.392948","2025-12-10 00:39:44.518284","2025-12-10 00:49:32.950914","2025-12-10 04:57:48.584719","2025-12-10 09:29:52.666577","2025-12-10 13:40:28.486178","2025-12-10 16:24:16.877779","2025-12-12 09:52:04.236867","2025-12-12 20:46:06.572602","2025-12-12 23:50:54.686406","2025-12-13 06:58:08.868876","2025-12-13 10:27:26.390655","2025-12-13 14:15:10.219085","2025-12-13 14:54:36.17439","2025-12-13 17:08:04.502729","2025-12-13 18:05:14.46441","2025-12-13 21:09:06.290341","2025-12-14 11:21:28.869821","2025-12-14 17:21:16.478761","2025-12-14 22:32:04.449588","2025-12-15 07:35:16.55788","2025-12-15 16:41:30.608217","2025-12-15 17:07:24.893024","2025-12-15 18:34:26.171566","2025-12-15 21:17:32.577173","2025-12-16 09:13:10.107266","2025-12-16 10:11:58.434566","2025-12-16 13:04:10.855999","2025-12-16 16:17:36.473802","2025-12-17 02:07:56.978358","2025-12-17 11:09:02.207676","2025-12-18 16:36:18.43735","2025-12-18 22:57:20.264686","2025-12-19 07:24:50.960198"} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg("timestamp")) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray("timestamp") FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"2025-12-10 16:24:16.877779","2025-12-12 09:52:04.236867","2025-12-13 10:27:26.390655","2025-12-14 22:32:04.449588","2025-12-15 16:41:30.608217","2025-12-15 17:07:24.893024","2025-12-16 10:11:58.434566","2025-12-16 16:17:36.473802","2025-12-17 02:07:56.978358","2025-12-18 16:36:18.43735"} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg("timestamp")) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray("timestamp") FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"2025-12-10 16:24:16.877779","2025-12-12 09:52:04.236867","2025-12-13 10:27:26.390655","2025-12-14 22:32:04.449588","2025-12-15 16:41:30.608217","2025-12-15 17:07:24.893024","2025-12-16 10:11:58.434566","2025-12-16 16:17:36.473802","2025-12-17 02:07:56.978358","2025-12-18 16:36:18.43735"} +(1 row) + +-- array_agg(Date) + QUERY PLAN +--------------------------------------------------------------- + Foreign Scan + Output: (array_agg(datestamp)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(datestamp) FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-06,2025-12-06,2025-12-06,2025-12-07,2025-12-07,2025-12-07,2025-12-08,2025-12-08,2025-12-08,2025-12-08,2025-12-09,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-12,2025-12-12,2025-12-12,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-14,2025-12-14,2025-12-14,2025-12-15,2025-12-15,2025-12-15,2025-12-15,2025-12-15,2025-12-16,2025-12-16,2025-12-16,2025-12-16,2025-12-17,2025-12-17,2025-12-18,2025-12-18,2025-12-19} +(1 row) + + QUERY PLAN +--------------------------------------------------------------- + Foreign Scan + Output: (array_agg(datestamp)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(datestamp) FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-05,2025-12-06,2025-12-06,2025-12-06,2025-12-07,2025-12-07,2025-12-07,2025-12-08,2025-12-08,2025-12-08,2025-12-08,2025-12-09,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-10,2025-12-12,2025-12-12,2025-12-12,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-13,2025-12-14,2025-12-14,2025-12-14,2025-12-15,2025-12-15,2025-12-15,2025-12-15,2025-12-15,2025-12-16,2025-12-16,2025-12-16,2025-12-16,2025-12-17,2025-12-17,2025-12-18,2025-12-18,2025-12-19} +(1 row) + + QUERY PLAN +----------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(datestamp)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(datestamp) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +----------------------------------------------------------------------------------------------------------------- + {2025-12-10,2025-12-12,2025-12-13,2025-12-14,2025-12-15,2025-12-15,2025-12-16,2025-12-16,2025-12-17,2025-12-18} +(1 row) + + QUERY PLAN +----------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(datestamp)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(datestamp) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +----------------------------------------------------------------------------------------------------------------- + {2025-12-10,2025-12-12,2025-12-13,2025-12-14,2025-12-15,2025-12-15,2025-12-16,2025-12-16,2025-12-17,2025-12-18} +(1 row) + +-- array_agg(String) + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(path)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(path) FROM agg_test.hits +(4 rows) + + array_agg +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {/users/283434,/users/802683,/search,/users/283434,/users/7392323,/users/7392323,/users/7392323,/widgets/voluptatem,/users,/users,/users/802683,/search,/search,/users/802683,/search,/profile,/widgets/voluptatem,/users/1321945,/users,/widgets/natus,/users/802683,/widgets/voluptatem,/widgets/aperiam,/widgets/totam,/search,/widgets/natus,/search,/widgets/omnis,/users,/users/1739238,/users/283434,/search,/users/1739238,/widgets/omnis,/widgets/omnis,/widgets/natus,/users/283434,/widgets/totam,/widgets/voluptatem,/widgets/aperiam,/widgets,/search,/widgets,/search,/widgets/voluptatem,/widgets/totam,/search,/search,/widgets/omnis,/users/802683} +(1 row) + + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(path)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(path) FROM agg_test.hits +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {'/users/283434','/users/802683','/search','/users/283434','/users/7392323','/users/7392323','/users/7392323','/widgets/voluptatem','/users','/users','/users/802683','/search','/search','/users/802683','/search','/profile','/widgets/voluptatem','/users/1321945','/users','/widgets/natus','/users/802683','/widgets/voluptatem','/widgets/aperiam','/widgets/totam','/search','/widgets/natus','/search','/widgets/omnis','/users','/users/1739238','/users/283434','/search','/users/1739238','/widgets/omnis','/widgets/omnis','/widgets/natus','/users/283434','/widgets/totam','/widgets/voluptatem','/widgets/aperiam','/widgets','/search','/widgets','/search','/widgets/voluptatem','/widgets/totam','/search','/search','/widgets/omnis','/users/802683'} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------ + Foreign Scan + Output: (array_agg(path)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(path) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------- + {/widgets/aperiam,/widgets/totam,/widgets/omnis,/widgets/natus,/widgets/totam,/widgets/voluptatem,/widgets,/widgets/voluptatem,/widgets/totam,/search} +(1 row) + + QUERY PLAN +------------------------------------------------------------------------------------------ + Foreign Scan + Output: (array_agg(path)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(path) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {'/widgets/aperiam','/widgets/totam','/widgets/omnis','/widgets/natus','/widgets/totam','/widgets/voluptatem','/widgets','/widgets/voluptatem','/widgets/totam','/search'} +(1 row) + +-- array_agg(UInt32) + QUERY PLAN +-------------------------------------------------------------- + Foreign Scan + Output: (array_agg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(duration) FROM agg_test.hits +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {304,541,599,1829,87,243,615,298,1409,83,1332,2011,84,3542,234,48,2498,1784,9,2556,772,253,64,1056,14,148,963,226,2125,3839,4437,2,2,2092,2478,15,1268,66,7672,54,3,81,916,4990,501,31,165,47,148,216} +(1 row) + + QUERY PLAN +-------------------------------------------------------------- + Foreign Scan + Output: (array_agg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(duration) FROM agg_test.hits +(4 rows) + + array_agg +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {304,541,599,1829,87,243,615,298,1409,83,1332,2011,84,3542,234,48,2498,1784,9,2556,772,253,64,1056,14,148,963,226,2125,3839,4437,2,2,2092,2478,15,1268,66,7672,54,3,81,916,4990,501,31,165,47,148,216} +(1 row) + + QUERY PLAN +---------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(duration) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +---------------------------------------- + {64,1056,226,15,66,7672,916,501,31,47} +(1 row) + + QUERY PLAN +---------------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(duration)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(duration) FROM agg_test.hits WHERE ((duration < 1000000000)) +(4 rows) + + array_agg +---------------------------------------- + {64,1056,226,15,66,7672,916,501,31,47} +(1 row) + +-- array_agg(Decimal) + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(cost) FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {1.29,8.38,4.28,6.51,2.15,3.02,5.94,2.98,5.60,7.01,4.26,7.40,7.55,2.34,7.57,5.66,2.61,3.51,3.52,4.43,5.55,5.24,5.10,1.99,1.81,6.80,3.54,8.14,8.21,4.55,1.33,7.42,2.23,5.24,6.04,8.53,4.43,3.57,2.47,1.20,3.55,8.17,8.24,2.36,4.79,6.75,8.90,7.69,8.09,5.90} +(1 row) + + QUERY PLAN +---------------------------------------------------------- + Foreign Scan + Output: (array_agg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(cost) FROM agg_test.hits +(4 rows) + + array_agg +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + {1.29,8.38,4.28,6.51,2.15,3.02,5.94,2.98,5.6,7.01,4.26,7.4,7.55,2.34,7.57,5.66,2.61,3.51,3.52,4.43,5.55,5.24,5.1,1.99,1.81,6.8,3.54,8.14,8.21,4.55,1.33,7.42,2.23,5.24,6.04,8.53,4.43,3.57,2.47,1.2,3.55,8.17,8.24,2.36,4.79,6.75,8.9,7.69,8.09,5.9} +(1 row) + + QUERY PLAN +-------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(cost) FROM agg_test.hits WHERE ((cost < 1000000000)) +(4 rows) + + array_agg +----------------------------------------------------- + {5.10,1.99,8.14,8.53,3.57,2.47,8.24,4.79,6.75,7.69} +(1 row) + + QUERY PLAN +-------------------------------------------------------------------------------------- + Foreign Scan + Output: (array_agg(cost)) + Relations: Aggregate on (hits) + Remote SQL: SELECT groupArray(cost) FROM agg_test.hits WHERE ((cost < 1000000000)) +(4 rows) + + array_agg +---------------------------------------------------- + {5.1,1.99,8.14,8.53,3.57,2.47,8.24,4.79,6.75,7.69} +(1 row) + +NOTICE: drop cascades to foreign table agg_bin.hits +NOTICE: drop cascades to foreign table agg_http.hits diff --git a/test/expected/binary_inserts.out b/test/expected/binary_inserts.out index 6182e48..6f19f98 100644 --- a/test/expected/binary_inserts.out +++ b/test/expected/binary_inserts.out @@ -50,7 +50,7 @@ SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( (1 row) SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); clickhouse_raw_query @@ -171,7 +171,7 @@ SELECT * FROM null_ints ORDER BY c1; (13 rows) /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex Foreign table "public.complex" Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description @@ -182,7 +182,8 @@ ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); c4 | text | | not null | | | extended | | c5 | character varying(10) | | not null | | | extended | | c6 | text | | not null | | | extended | | - c7 | timestamp(3) without time zone | | not null | | | plain | | + c7 | date | | not null | | | plain | | + c8 | timestamp(3) without time zone | | not null | | | plain | | Not-null constraints: "complex_c1_not_null" NOT NULL "c1" "complex_c2_not_null" NOT NULL "c2" @@ -191,20 +192,25 @@ Not-null constraints: "complex_c5_not_null" NOT NULL "c5" "complex_c6_not_null" NOT NULL "c6" "complex_c7_not_null" NOT NULL "c7" + "complex_c8_not_null" NOT NULL "c8" Server: binary_inserts_loopback FDW options: (database 'binary_inserts_test', table_name 'complex', engine 'MergeTree') INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; - c1 | c2 | c3 | c4 | c5 | c6 | c7 -----+------------+---------------------+----+--------+------+---------------------------- - 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02.122999 - 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02.234 - 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 -(3 rows) + c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 +----+------------+---------------------+----+--------+------+------------+------------------------- + 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-01 | 2020-06-02 10:01:02.123 + 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-02 | 2020-06-03 11:01:02.234 + 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-03 | 2020-06-04 12:01:02 + 4 | 1970-01-01 | 1970-01-01 00:00:00 | 5 | fix_t4 | low4 | 1970-01-01 | 1970-01-01 00:00:00 + 5 | 2000-01-01 | 2000-01-01 00:00:00 | 5 | fix_t5 | low5 | 2000-01-01 | 2000-01-01 00:00:00 +(5 rows) /* check arrays */ INSERT INTO arrays VALUES diff --git a/test/expected/binary_inserts_1.out b/test/expected/binary_inserts_1.out index 2e372c4..4f6b884 100644 --- a/test/expected/binary_inserts_1.out +++ b/test/expected/binary_inserts_1.out @@ -50,7 +50,7 @@ SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( (1 row) SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); clickhouse_raw_query @@ -171,7 +171,7 @@ SELECT * FROM null_ints ORDER BY c1; (13 rows) /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex Foreign table "public.complex" Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description @@ -182,21 +182,26 @@ ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); c4 | text | | not null | | | extended | | c5 | character varying(10) | | not null | | | extended | | c6 | text | | not null | | | extended | | - c7 | timestamp(3) without time zone | | not null | | | plain | | + c7 | date | | not null | | | plain | | + c8 | timestamp(3) without time zone | | not null | | | plain | | Server: binary_inserts_loopback FDW options: (database 'binary_inserts_test', table_name 'complex', engine 'MergeTree') INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; - c1 | c2 | c3 | c4 | c5 | c6 | c7 -----+------------+---------------------+----+--------+------+---------------------------- - 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02.122999 - 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02.234 - 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 -(3 rows) + c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 +----+------------+---------------------+----+--------+------+------------+------------------------- + 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-01 | 2020-06-02 10:01:02.123 + 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-02 | 2020-06-03 11:01:02.234 + 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-03 | 2020-06-04 12:01:02 + 4 | 1970-01-01 | 1970-01-01 00:00:00 | 5 | fix_t4 | low4 | 1970-01-01 | 1970-01-01 00:00:00 + 5 | 2000-01-01 | 2000-01-01 00:00:00 | 5 | fix_t5 | low5 | 2000-01-01 | 2000-01-01 00:00:00 +(5 rows) /* check arrays */ INSERT INTO arrays VALUES diff --git a/test/expected/http_inserts.out b/test/expected/http_inserts.out index 05e65e5..72e8de0 100644 --- a/test/expected/http_inserts.out +++ b/test/expected/http_inserts.out @@ -50,7 +50,7 @@ SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.null_ints ( (1 row) SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); clickhouse_raw_query @@ -171,7 +171,7 @@ SELECT * FROM null_ints ORDER BY c1; (13 rows) /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex Foreign table "public.complex" Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description @@ -182,7 +182,8 @@ ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); c4 | text | | not null | | | extended | | c5 | character varying(10) | | not null | | | extended | | c6 | text | | not null | | | extended | | - c7 | timestamp(3) without time zone | | not null | | | plain | | + c7 | date | | not null | | | plain | | + c8 | timestamp(3) without time zone | | not null | | | plain | | Not-null constraints: "complex_c1_not_null" NOT NULL "c1" "complex_c2_not_null" NOT NULL "c2" @@ -191,20 +192,25 @@ Not-null constraints: "complex_c5_not_null" NOT NULL "c5" "complex_c6_not_null" NOT NULL "c6" "complex_c7_not_null" NOT NULL "c7" + "complex_c8_not_null" NOT NULL "c8" Server: http_inserts_loopback FDW options: (database 'http_inserts_test', table_name 'complex', engine 'MergeTree') INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; - c1 | c2 | c3 | c4 | c5 | c6 | c7 -----+------------+---------------------+----+--------+------+--------------------- - 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02 - 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02 - 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 -(3 rows) + c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 +----+------------+---------------------+----+--------+------+------------+--------------------- + 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-01 | 2020-06-02 10:01:02 + 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-02 | 2020-06-03 11:01:02 + 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-03 | 2020-06-04 12:01:02 + 4 | 1970-01-01 | 1970-01-01 00:00:00 | 5 | fix_t4 | low4 | 1970-01-01 | 1970-01-01 00:00:00 + 5 | 2000-01-01 | 2000-01-01 00:00:00 | 5 | fix_t5 | low5 | 2000-01-01 | 2000-01-01 00:00:00 +(5 rows) /* check arrays */ INSERT INTO arrays VALUES diff --git a/test/expected/http_inserts_1.out b/test/expected/http_inserts_1.out index 889f411..d58977a 100644 --- a/test/expected/http_inserts_1.out +++ b/test/expected/http_inserts_1.out @@ -50,7 +50,7 @@ SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.null_ints ( (1 row) SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); clickhouse_raw_query @@ -171,7 +171,7 @@ SELECT * FROM null_ints ORDER BY c1; (13 rows) /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex Foreign table "public.complex" Column | Type | Collation | Nullable | Default | FDW options | Storage | Stats target | Description @@ -182,21 +182,26 @@ ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); c4 | text | | not null | | | extended | | c5 | character varying(10) | | not null | | | extended | | c6 | text | | not null | | | extended | | - c7 | timestamp(3) without time zone | | not null | | | plain | | + c7 | date | | not null | | | plain | | + c8 | timestamp(3) without time zone | | not null | | | plain | | Server: http_inserts_loopback FDW options: (database 'http_inserts_test', table_name 'complex', engine 'MergeTree') INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; - c1 | c2 | c3 | c4 | c5 | c6 | c7 -----+------------+---------------------+----+--------+------+--------------------- - 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-02 10:01:02 - 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-03 11:01:02 - 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-04 12:01:02 -(3 rows) + c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 +----+------------+---------------------+----+--------+------+------------+--------------------- + 1 | 2020-06-01 | 2020-06-02 10:01:02 | t1 | fix_t1 | low1 | 2020-06-01 | 2020-06-02 10:01:02 + 2 | 2020-06-02 | 2020-06-03 10:01:02 | 5 | fix_t2 | low2 | 2020-06-02 | 2020-06-03 11:01:02 + 3 | 2020-06-03 | 2020-06-04 10:01:02 | 5 | fix_t3 | low3 | 2020-06-03 | 2020-06-04 12:01:02 + 4 | 1970-01-01 | 1970-01-01 00:00:00 | 5 | fix_t4 | low4 | 1970-01-01 | 1970-01-01 00:00:00 + 5 | 2000-01-01 | 2000-01-01 00:00:00 | 5 | fix_t5 | low5 | 2000-01-01 | 2000-01-01 00:00:00 +(5 rows) /* check arrays */ INSERT INTO arrays VALUES diff --git a/test/sql/aggregates.sql b/test/sql/aggregates.sql new file mode 100644 index 0000000..da3368d --- /dev/null +++ b/test/sql/aggregates.sql @@ -0,0 +1,235 @@ +\unset ECHO +SET client_min_messages = notice; +SET datestyle = 'ISO'; + +-- Create servers for each engine. +CREATE SERVER agg_bin_svr FOREIGN DATA WRAPPER clickhouse_fdw + OPTIONS(dbname 'system', driver 'binary'); +CREATE USER MAPPING FOR CURRENT_USER SERVER agg_bin_svr; + +CREATE SERVER agg_http_svr FOREIGN DATA WRAPPER clickhouse_fdw + OPTIONS(dbname 'system', driver 'http'); +CREATE USER MAPPING FOR CURRENT_USER SERVER agg_http_svr; + +-- Create a ClickHouse table to query. +SELECT clickhouse_raw_query('DROP DATABASE IF EXISTS agg_test'); +SELECT clickhouse_raw_query('CREATE DATABASE agg_test'); +SELECT clickhouse_raw_query($$ + CREATE TABLE agg_test.hits ( + id Int64 NOT NULL, + uuid UUID NOT NULL, + timestamp DateTime64(6,'UTC') NOT NULL, + datestamp Date NOT NULL, + path String NOT NULL, + duration UInt32 NOT NULL, + cost Decimal(10, 2) NOT NULL + ) ENGINE = MergeTree ORDER BY (timestamp); +$$); + +/* Queries used to generate the insert values below. + +SELECT clickhouse_raw_query($$ + INSERT INTO agg_test.hits + WITH gen AS ( + SELECT toDateTime64(concat('2025-12-19 10:42:00.', floor(randUniform(0, 999999))), 6, 'UTC') - (rand() % 86400 * 14) AS ts + FROM numbers(50) + ) + SELECT abs(rand()), + generateUUIDv4(), + ts, + date(ts), + ['/profile', '/users', '/users/1321945', '/users/283434', '/users/802683', '/users/1739238', '/users/7392323', '/widgets', '/search', '/search', '/search', '/widgets/omnis', '/widgets/natus', '/widgets/voluptatem', '/widgets/totam', '/widgets/aperiam'][1+rand()%16], + round(randChiSquared(1) * 1000), + cast(randChiSquared(1) * rand() %8+1 AS Decimal(10, 2)) + FROM gen; +$$); +SELECT clickhouse_raw_query('select * from agg_test.hits format values'); + +*/ + +-- Insert data. +SELECT clickhouse_raw_query($$ + INSERT INTO agg_test.hits VALUES + (3498231651,'8cab5a51-8927-43f4-8104-b2c81ffc3d8a','2025-12-05 11:51:04.390884','2025-12-05','/users/283434',304,1.29), + (1431223188,'691a0477-c3fa-404d-a478-d4caaaa24832','2025-12-05 12:22:20.135213','2025-12-05','/users/802683',541,8.38), + (1331538905,'f44459f2-9bbd-4149-9ac8-69c7b22f1aa0','2025-12-05 14:31:50.452533','2025-12-05','/search',599,4.28), + (3451631267,'148181e2-a573-481f-9e2a-02441d523034','2025-12-05 19:06:00.126014','2025-12-05','/users/283434',1829,6.51), + (2757160710,'974f2e1d-6918-4cce-935c-d445428584cc','2025-12-05 19:07:10.399278','2025-12-05','/users/7392323',87,2.15), + (4049681990,'720ad53d-db83-4091-a262-cfc7347f96ae','2025-12-05 20:07:22.673831','2025-12-05','/users/7392323',243,3.02), + (3319320102,'b623608d-459d-43d2-90ac-d1a8de83ff17','2025-12-06 03:25:34.627161','2025-12-06','/users/7392323',615,5.94), + (2178896781,'d205ee5d-dd47-4a63-be2f-198fcfb7403b','2025-12-06 05:50:56.818572','2025-12-06','/widgets/voluptatem',298,2.98), + (2433222225,'1f1dd4dd-2b05-4876-b98c-cb5ba1f34b89','2025-12-06 13:02:50.972837','2025-12-06','/users',1409,5.6), + (3948091185,'a77b5881-262a-47c4-8494-a211e48b9c6c','2025-12-07 15:42:06.881490','2025-12-07','/users',83,7.01), + (3122655508,'aef92b53-0b2a-4777-8d9d-ce5a6443ef54','2025-12-07 17:28:58.124117','2025-12-07','/users/802683',1332,4.26), + (3095867833,'99f9a13a-357a-40fd-b415-1966865468d3','2025-12-07 23:20:36.618385','2025-12-07','/search',2011,7.4), + (2720322600,'5c740ee9-a7a2-43e4-8ab1-e8c147f78c8b','2025-12-08 01:59:58.417052','2025-12-08','/search',84,7.55), + (2400403412,'d12fe0f1-9c4c-4039-9027-3e9f62d1da54','2025-12-08 03:00:24.806643','2025-12-08','/users/802683',3542,2.34), + (3159416553,'7885ab07-3740-461f-ac0c-c8732c07d86e','2025-12-08 14:42:58.344220','2025-12-08','/search',234,7.57), + (4160213552,'031a4434-e4f8-465d-8b13-7537ad578e93','2025-12-08 20:14:32.236350','2025-12-08','/profile',48,5.66), + (3910581405,'1c0f3511-3f88-4d4a-a053-724449619420','2025-12-09 00:08:20.392948','2025-12-09','/widgets/voluptatem',2498,2.61), + (3267604082,'d60a7c1d-dccf-427b-b685-9a6077a88867','2025-12-10 00:39:44.518284','2025-12-10','/users/1321945',1784,3.51), + (3841934465,'c066fdd6-0172-46aa-9792-63455cb069b4','2025-12-10 00:49:32.950914','2025-12-10','/users',9,3.52), + (4264738908,'9f420aa6-f015-4caa-a2f8-2ca0e7a652a6','2025-12-10 04:57:48.584719','2025-12-10','/widgets/natus',2556,4.43), + (2005666276,'b8615e95-f95f-458e-aa87-b6e6634503d9','2025-12-10 09:29:52.666577','2025-12-10','/users/802683',772,5.55), + (3824162205,'06fa959e-afe3-414d-9771-650547091079','2025-12-10 13:40:28.486178','2025-12-10','/widgets/voluptatem',253,5.24), + (352088655,'f5468669-4391-4ed7-99be-82061f8f3f93','2025-12-10 16:24:16.877779','2025-12-10','/widgets/aperiam',64,5.1), + (467263982,'77af0ea8-2fef-4a21-bee0-335f9aa995c6','2025-12-12 09:52:04.236867','2025-12-12','/widgets/totam',1056,1.99), + (2890629064,'368679e8-8f2a-47dd-8bce-b491bdd09720','2025-12-12 20:46:06.572602','2025-12-12','/search',14,1.81), + (4072815052,'90b90c80-8f8e-44e1-9468-e4d2cddd22bb','2025-12-12 23:50:54.686406','2025-12-12','/widgets/natus',148,6.8), + (1008605146,'6da3afd4-4fa3-49b7-ab29-ffe1b2bb7082','2025-12-13 06:58:08.868876','2025-12-13','/search',963,3.54), + (837437371,'b5628648-e429-4fb9-9d77-de539d32f29f','2025-12-13 10:27:26.390655','2025-12-13','/widgets/omnis',226,8.14), + (3517179953,'3e4b5d8b-7b09-4d1c-9eb4-855f0ae108d2','2025-12-13 14:15:10.219085','2025-12-13','/users',2125,8.21), + (2836779925,'5e57a6fe-0196-4100-865a-7d6dc55765c2','2025-12-13 14:54:36.174390','2025-12-13','/users/1739238',3839,4.55), + (1470995555,'0d8c0e39-679f-4034-b48f-aa1595b02dfc','2025-12-13 17:08:04.502729','2025-12-13','/users/283434',4437,1.33), + (3849384968,'533582ce-95eb-4fb6-804e-6256ea6adaac','2025-12-13 18:05:14.464410','2025-12-13','/search',2,7.42), + (3334361077,'a04b2cbd-c5b9-4f65-8449-0827d6c7f712','2025-12-13 21:09:06.290341','2025-12-13','/users/1739238',2,2.23), + (3258018379,'d5c34dc5-b5db-455d-9528-fe466bdadd2c','2025-12-14 11:21:28.869821','2025-12-14','/widgets/omnis',2092,5.24), + (1750004811,'eda72c6e-3161-47dd-ba25-cf059bb995da','2025-12-14 17:21:16.478761','2025-12-14','/widgets/omnis',2478,6.04), + (280308092,'68b5127e-9819-453f-812d-f1b90979f872','2025-12-14 22:32:04.449588','2025-12-14','/widgets/natus',15,8.53), + (3231552675,'4886ebda-a378-4181-a291-c235ec1047a8','2025-12-15 07:35:16.557880','2025-12-15','/users/283434',1268,4.43), + (392385086,'69229156-bb5a-450d-91a0-474f39a20bab','2025-12-15 16:41:30.608217','2025-12-15','/widgets/totam',66,3.57), + (287518381,'1adf4190-5147-4e7e-b354-7715a5a81c40','2025-12-15 17:07:24.893024','2025-12-15','/widgets/voluptatem',7672,2.47), + (1334989359,'52220ad9-02f0-4ad7-ad74-dc6add362a99','2025-12-15 18:34:26.171566','2025-12-15','/widgets/aperiam',54,1.2), + (4093728327,'44cccdf8-d398-40c7-9e41-117a37e93b9e','2025-12-15 21:17:32.577173','2025-12-15','/widgets',3,3.55), + (1406653594,'e636df93-8421-4926-bf6f-1d1ee36edd35','2025-12-16 09:13:10.107266','2025-12-16','/search',81,8.17), + (366963527,'af62cc2f-e706-4d1d-a740-fd80c55a1250','2025-12-16 10:11:58.434566','2025-12-16','/widgets',916,8.24), + (3432633864,'b50622a5-0e0a-4f66-8be1-84c7cc6851b6','2025-12-16 13:04:10.855999','2025-12-16','/search',4990,2.36), + (104048445,'19b74725-9827-4d84-b4dc-b86788193002','2025-12-16 16:17:36.473802','2025-12-16','/widgets/voluptatem',501,4.79), + (914876110,'2ddfb5b7-9ae5-428b-9351-48e823230672','2025-12-17 02:07:56.978358','2025-12-17','/widgets/totam',31,6.75), + (1982637736,'969e2c53-c735-4649-a6a3-3107ed089cb0','2025-12-17 11:09:02.207676','2025-12-17','/search',165,8.9), + (41607833,'ad89a796-f7c6-4549-bd2e-ced0e586a5a5','2025-12-18 16:36:18.437350','2025-12-18','/search',47,7.69), + (3814959307,'70525fca-b870-4976-9377-fc959353302a','2025-12-18 22:57:20.264686','2025-12-18','/widgets/omnis',148,8.09), + (1538392900,'7e3f2fe1-5312-4257-ba3e-54662ba14b56','2025-12-19 07:24:50.960198','2025-12-19','/users/802683',216,5.9) +$$); + + +CREATE SCHEMA agg_bin; +CREATE SCHEMA agg_http; +IMPORT FOREIGN SCHEMA "agg_test" FROM SERVER agg_bin_svr INTO agg_bin; +\d agg_bin.hits +IMPORT FOREIGN SCHEMA "agg_test" FROM SERVER agg_http_svr INTO agg_http; +\d agg_http.hits + +\set id_limit 1000000000 + +\echo -- AVG(UInt64) +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(id) FROM agg_bin.hits; +SELECT avg(id) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(id) FROM agg_http.hits; +SELECT avg(id) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(id) FROM agg_bin.hits WHERE id < :id_limit; +SELECT avg(id) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(id) FROM agg_http.hits WHERE id < :id_limit; +SELECT avg(id) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- AVG(UInt32) +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(duration) FROM agg_bin.hits; +SELECT avg(duration) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(duration) FROM agg_http.hits; +SELECT avg(duration) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(duration) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT avg(duration) FROM agg_bin.hits WHERE duration < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(duration) FROM agg_http.hits WHERE duration < :id_limit; +SELECT avg(duration) FROM agg_http.hits WHERE duration < :id_limit; + +\echo -- AVG(Decimal) +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(cost) FROM agg_bin.hits; +SELECT avg(cost) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(cost) FROM agg_http.hits; +SELECT avg(cost) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(cost) FROM agg_bin.hits WHERE cost < :id_limit; +SELECT avg(cost) FROM agg_bin.hits WHERE cost < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT avg(cost) FROM agg_http.hits WHERE cost < :id_limit; +SELECT avg(cost) FROM agg_http.hits WHERE cost < :id_limit; + +\echo -- array_agg(UInt64) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(id) FROM agg_bin.hits; +SELECT array_agg(id) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(id) FROM agg_http.hits; +SELECT array_agg(id) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(id) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(id) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(id) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(id) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(UUID) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(uuid) FROM agg_bin.hits; +SELECT array_agg(uuid) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(uuid) FROM agg_http.hits; +SELECT array_agg(uuid) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(uuid) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(uuid) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(uuid) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(uuid) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(DateTime64) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(timestamp) FROM agg_bin.hits; +SELECT array_agg(timestamp) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(timestamp) FROM agg_http.hits; +SELECT array_agg(timestamp) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(timestamp) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(timestamp) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(timestamp) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(timestamp) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(Date) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(datestamp) FROM agg_bin.hits; +SELECT array_agg(datestamp) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(datestamp) FROM agg_http.hits; +SELECT array_agg(datestamp) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(datestamp) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(datestamp) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(datestamp) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(datestamp) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(String) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(path) FROM agg_bin.hits; +SELECT array_agg(path) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(path) FROM agg_http.hits; +SELECT array_agg(path) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(path) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(path) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(path) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(path) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(UInt32) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(duration) FROM agg_bin.hits; +SELECT array_agg(duration) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(duration) FROM agg_http.hits; +SELECT array_agg(duration) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(duration) FROM agg_bin.hits WHERE duration < :id_limit; +SELECT array_agg(duration) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(duration) FROM agg_http.hits WHERE duration < :id_limit; +SELECT array_agg(duration) FROM agg_http.hits WHERE id < :id_limit; + +\echo -- array_agg(Decimal) +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(cost) FROM agg_bin.hits; +SELECT array_agg(cost) FROM agg_bin.hits; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(cost) FROM agg_http.hits; +SELECT array_agg(cost) FROM agg_http.hits; + +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(cost) FROM agg_bin.hits WHERE cost < :id_limit; +SELECT array_agg(cost) FROM agg_bin.hits WHERE id < :id_limit; +EXPLAIN (VERBOSE, COSTS OFF) SELECT array_agg(cost) FROM agg_http.hits WHERE cost < :id_limit; +SELECT array_agg(cost) FROM agg_http.hits WHERE id < :id_limit; + +-- \echo -- min(UInt64) +-- EXPLAIN (VERBOSE, COSTS OFF) SELECT min(id) FROM agg_bin.hits; +-- SELECT min(id) FROM agg_bin.hits; +-- EXPLAIN (VERBOSE, COSTS OFF) SELECT min(id) FROM agg_http.hits; +-- SELECT min(id) FROM agg_http.hits; + +-- Clean up. +DROP USER MAPPING FOR CURRENT_USER SERVER agg_bin_svr; +DROP SERVER agg_bin_svr CASCADE; +DROP USER MAPPING FOR CURRENT_USER SERVER agg_http_svr; +DROP SERVER agg_http_svr CASCADE; diff --git a/test/sql/binary_inserts.sql b/test/sql/binary_inserts.sql index 206cfd9..b0ac570 100644 --- a/test/sql/binary_inserts.sql +++ b/test/sql/binary_inserts.sql @@ -25,7 +25,7 @@ SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.null_ints ( '); SELECT clickhouse_raw_query('CREATE TABLE binary_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); @@ -66,12 +66,14 @@ SELECT * FROM null_ints ORDER BY c1; SELECT * FROM null_ints ORDER BY c1; /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; /* check arrays */ diff --git a/test/sql/http_inserts.sql b/test/sql/http_inserts.sql index ce5d39a..596e4cd 100644 --- a/test/sql/http_inserts.sql +++ b/test/sql/http_inserts.sql @@ -25,7 +25,7 @@ SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.null_ints ( '); SELECT clickhouse_raw_query('CREATE TABLE http_inserts_test.complex ( - c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 DateTime64(3) + c1 Int32, c2 Date, c3 DateTime, c4 String, c5 FixedString(10), c6 LowCardinality(String), c7 Date32, c8 DateTime64(3) ) ENGINE = MergeTree PARTITION BY c1 ORDER BY (c1); '); @@ -66,12 +66,14 @@ SELECT * FROM null_ints ORDER BY c1; SELECT * FROM null_ints ORDER BY c1; /* check dates and strings */ -ALTER TABLE complex ALTER COLUMN c7 SET DATA TYPE timestamp(3); +ALTER TABLE complex ALTER COLUMN c8 SET DATA TYPE timestamp(3); \d+ complex INSERT INTO complex VALUES - (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-02 10:01:02.123'), - (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-03 11:01:02.234'), - (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-04 12:01:02'); + (1, '2020-06-01', '2020-06-02 10:01:02', 't1', 'fix_t1', 'low1', '2020-06-01', '2020-06-02 10:01:02.123'), + (2, '2020-06-02', '2020-06-03 10:01:02', 5, 'fix_t2', 'low2', '2020-06-02', '2020-06-03 11:01:02.234'), + (3, '2020-06-03', '2020-06-04 10:01:02', 5, 'fix_t3', 'low3', '2020-06-03', '2020-06-04 12:01:02'), + (4, '1970-01-01', '1970-01-01 00:00:00', 5, 'fix_t4', 'low4', '1970-01-01', '1970-01-01 00:00:00'), + (5, '2000-01-01', '2000-01-01 00:00:00', 5, 'fix_t5', 'low5', '2000-01-01', '2000-01-01 00:00:00'); SELECT * FROM complex ORDER BY c1; /* check arrays */