Skip to content

Commit b6484ca

Browse files
committed
Disallow partitionwise grouping when collations don't match
If the collation of any grouping column doesn’t match the collation of the corresponding partition key, partitionwise grouping can yield incorrect results. For example, rows that would be grouped under the grouping collation may end up in different partitions under the partitioning collation. In such cases, full partitionwise grouping would produce results that differ from those without partitionwise grouping, so disallowed that. Partial partitionwise aggregation is still allowed, as the Finalize step reconciles partition-level aggregates with grouping requirements across all partitions, ensuring that the final output remains consistent. This commit also fixes group_by_has_partkey() by ensuring the RelabelType node is stripped from grouping expressions when matching them to partition key expressions to avoid false mismatches. Bug: #18568 Reported-by: Webbo Han <1105066510@qq.com> Author: Webbo Han <1105066510@qq.com> Reviewed-by: Tender Wang <tndrwang@gmail.com> Reviewed-by: Aleksander Alekseev <aleksander@timescale.com> Reviewed-by: Jian He <jian.universality@gmail.com> Discussion: https://postgr.es/m/18568-2a9afb6b9f7e6ed3@postgresql.org Discussion: https://postgr.es/m/tencent_9D9103CDA420C07768349CC1DFF88465F90A@qq.com Discussion: https://postgr.es/m/CAHewXNno_HKiQ6PqyLYfuqDtwp7KKHZiH1J7Pqyz0nr+PS2Dwg@mail.gmail.com Backpatch-through: 12
1 parent 78b1c55 commit b6484ca

File tree

3 files changed

+163
-8
lines changed

3 files changed

+163
-8
lines changed

src/backend/optimizer/plan/planner.c

Lines changed: 36 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -4023,9 +4023,10 @@ create_ordinary_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
40234023
* If this is the topmost relation or if the parent relation is doing
40244024
* full partitionwise aggregation, then we can do full partitionwise
40254025
* aggregation provided that the GROUP BY clause contains all of the
4026-
* partitioning columns at this level. Otherwise, we can do at most
4027-
* partial partitionwise aggregation. But if partial aggregation is
4028-
* not supported in general then we can't use it for partitionwise
4026+
* partitioning columns at this level and the collation used by GROUP
4027+
* BY matches the partitioning collation. Otherwise, we can do at
4028+
* most partial partitionwise aggregation. But if partial aggregation
4029+
* is not supported in general then we can't use it for partitionwise
40294030
* aggregation either.
40304031
*
40314032
* Check parse->groupClause not processed_groupClause, because it's
@@ -8005,8 +8006,8 @@ create_partitionwise_grouping_paths(PlannerInfo *root,
80058006
/*
80068007
* group_by_has_partkey
80078008
*
8008-
* Returns true, if all the partition keys of the given relation are part of
8009-
* the GROUP BY clauses, false otherwise.
8009+
* Returns true if all the partition keys of the given relation are part of
8010+
* the GROUP BY clauses, including having matching collation, false otherwise.
80108011
*/
80118012
static bool
80128013
group_by_has_partkey(RelOptInfo *input_rel,
@@ -8034,13 +8035,40 @@ group_by_has_partkey(RelOptInfo *input_rel,
80348035

80358036
foreach(lc, partexprs)
80368037
{
8038+
ListCell *lg;
80378039
Expr *partexpr = lfirst(lc);
8040+
Oid partcoll = input_rel->part_scheme->partcollation[cnt];
80388041

8039-
if (list_member(groupexprs, partexpr))
8042+
foreach(lg, groupexprs)
80408043
{
8041-
found = true;
8042-
break;
8044+
Expr *groupexpr = lfirst(lg);
8045+
Oid groupcoll = exprCollation((Node *) groupexpr);
8046+
8047+
/*
8048+
* Note: we can assume there is at most one RelabelType node;
8049+
* eval_const_expressions() will have simplified if more than
8050+
* one.
8051+
*/
8052+
if (IsA(groupexpr, RelabelType))
8053+
groupexpr = ((RelabelType *) groupexpr)->arg;
8054+
8055+
if (equal(groupexpr, partexpr))
8056+
{
8057+
/*
8058+
* Reject a match if the grouping collation does not match
8059+
* the partitioning collation.
8060+
*/
8061+
if (OidIsValid(partcoll) && OidIsValid(groupcoll) &&
8062+
partcoll != groupcoll)
8063+
return false;
8064+
8065+
found = true;
8066+
break;
8067+
}
80438068
}
8069+
8070+
if (found)
8071+
break;
80448072
}
80458073

80468074
/*

src/test/regress/expected/collate.icu.utf8.out

Lines changed: 90 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2052,6 +2052,96 @@ SELECT (SELECT count(*) FROM test33_0) <> (SELECT count(*) FROM test33_1);
20522052
t
20532053
(1 row)
20542054

2055+
--
2056+
-- Bug #18568
2057+
--
2058+
-- Partitionwise aggregate (full or partial) should not be used when a
2059+
-- partition key's collation doesn't match that of the GROUP BY column it is
2060+
-- matched with.
2061+
SET max_parallel_workers_per_gather TO 0;
2062+
SET enable_incremental_sort TO off;
2063+
CREATE TABLE pagg_tab3 (a text, c text collate case_insensitive) PARTITION BY LIST(c collate "C");
2064+
CREATE TABLE pagg_tab3_p1 PARTITION OF pagg_tab3 FOR VALUES IN ('a', 'b');
2065+
CREATE TABLE pagg_tab3_p2 PARTITION OF pagg_tab3 FOR VALUES IN ('B', 'A');
2066+
INSERT INTO pagg_tab3 SELECT i % 4 + 1, substr('abAB', (i % 4) + 1 , 1) FROM generate_series(0, 19) i;
2067+
ANALYZE pagg_tab3;
2068+
SET enable_partitionwise_aggregate TO false;
2069+
EXPLAIN (COSTS OFF)
2070+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
2071+
QUERY PLAN
2072+
-----------------------------------------------------------
2073+
Sort
2074+
Sort Key: (upper(pagg_tab3.c)) COLLATE case_insensitive
2075+
-> HashAggregate
2076+
Group Key: pagg_tab3.c
2077+
-> Append
2078+
-> Seq Scan on pagg_tab3_p2 pagg_tab3_1
2079+
-> Seq Scan on pagg_tab3_p1 pagg_tab3_2
2080+
(7 rows)
2081+
2082+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
2083+
upper | count
2084+
-------+-------
2085+
A | 10
2086+
B | 10
2087+
(2 rows)
2088+
2089+
-- No "full" partitionwise aggregation allowed, though "partial" is allowed.
2090+
SET enable_partitionwise_aggregate TO true;
2091+
EXPLAIN (COSTS OFF)
2092+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
2093+
QUERY PLAN
2094+
--------------------------------------------------------------
2095+
Sort
2096+
Sort Key: (upper(pagg_tab3.c)) COLLATE case_insensitive
2097+
-> Finalize HashAggregate
2098+
Group Key: pagg_tab3.c
2099+
-> Append
2100+
-> Partial HashAggregate
2101+
Group Key: pagg_tab3.c
2102+
-> Seq Scan on pagg_tab3_p2 pagg_tab3
2103+
-> Partial HashAggregate
2104+
Group Key: pagg_tab3_1.c
2105+
-> Seq Scan on pagg_tab3_p1 pagg_tab3_1
2106+
(11 rows)
2107+
2108+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
2109+
upper | count
2110+
-------+-------
2111+
A | 10
2112+
B | 10
2113+
(2 rows)
2114+
2115+
-- OK to use full partitionwise aggregate after changing the GROUP BY column's
2116+
-- collation to be the same as that of the partition key.
2117+
EXPLAIN (COSTS OFF)
2118+
SELECT c collate "C", count(c) FROM pagg_tab3 GROUP BY c collate "C" ORDER BY 1;
2119+
QUERY PLAN
2120+
--------------------------------------------------------
2121+
Sort
2122+
Sort Key: ((pagg_tab3.c)::text) COLLATE "C"
2123+
-> Append
2124+
-> HashAggregate
2125+
Group Key: (pagg_tab3.c)::text
2126+
-> Seq Scan on pagg_tab3_p2 pagg_tab3
2127+
-> HashAggregate
2128+
Group Key: (pagg_tab3_1.c)::text
2129+
-> Seq Scan on pagg_tab3_p1 pagg_tab3_1
2130+
(9 rows)
2131+
2132+
SELECT c collate "C", count(c) FROM pagg_tab3 GROUP BY c collate "C" ORDER BY 1;
2133+
c | count
2134+
---+-------
2135+
A | 5
2136+
B | 5
2137+
a | 5
2138+
b | 5
2139+
(4 rows)
2140+
2141+
DROP TABLE pagg_tab3;
2142+
RESET enable_partitionwise_aggregate;
2143+
RESET max_parallel_workers_per_gather;
2144+
RESET enable_incremental_sort;
20552145
-- cleanup
20562146
RESET search_path;
20572147
SET client_min_messages TO warning;

src/test/regress/sql/collate.icu.utf8.sql

Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -796,6 +796,43 @@ INSERT INTO test33 VALUES (2, 'DEF');
796796
-- they end up in the same partition (but it's platform-dependent which one)
797797
SELECT (SELECT count(*) FROM test33_0) <> (SELECT count(*) FROM test33_1);
798798

799+
--
800+
-- Bug #18568
801+
--
802+
-- Partitionwise aggregate (full or partial) should not be used when a
803+
-- partition key's collation doesn't match that of the GROUP BY column it is
804+
-- matched with.
805+
SET max_parallel_workers_per_gather TO 0;
806+
SET enable_incremental_sort TO off;
807+
808+
CREATE TABLE pagg_tab3 (a text, c text collate case_insensitive) PARTITION BY LIST(c collate "C");
809+
CREATE TABLE pagg_tab3_p1 PARTITION OF pagg_tab3 FOR VALUES IN ('a', 'b');
810+
CREATE TABLE pagg_tab3_p2 PARTITION OF pagg_tab3 FOR VALUES IN ('B', 'A');
811+
INSERT INTO pagg_tab3 SELECT i % 4 + 1, substr('abAB', (i % 4) + 1 , 1) FROM generate_series(0, 19) i;
812+
ANALYZE pagg_tab3;
813+
814+
SET enable_partitionwise_aggregate TO false;
815+
EXPLAIN (COSTS OFF)
816+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
817+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
818+
819+
-- No "full" partitionwise aggregation allowed, though "partial" is allowed.
820+
SET enable_partitionwise_aggregate TO true;
821+
EXPLAIN (COSTS OFF)
822+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
823+
SELECT upper(c collate case_insensitive), count(c) FROM pagg_tab3 GROUP BY c collate case_insensitive ORDER BY 1;
824+
825+
-- OK to use full partitionwise aggregate after changing the GROUP BY column's
826+
-- collation to be the same as that of the partition key.
827+
EXPLAIN (COSTS OFF)
828+
SELECT c collate "C", count(c) FROM pagg_tab3 GROUP BY c collate "C" ORDER BY 1;
829+
SELECT c collate "C", count(c) FROM pagg_tab3 GROUP BY c collate "C" ORDER BY 1;
830+
831+
DROP TABLE pagg_tab3;
832+
833+
RESET enable_partitionwise_aggregate;
834+
RESET max_parallel_workers_per_gather;
835+
RESET enable_incremental_sort;
799836

800837
-- cleanup
801838
RESET search_path;

0 commit comments

Comments
 (0)