1
0
mirror of https://github.com/MariaDB/server.git synced 2025-04-18 21:44:20 +03:00

MDEV-30877: Output cardinality for derived table ignores GROUP BY

(Variant 3) (commit in 11.4)
When a derived table has a GROUP BY clause:

  SELECT ...
    FROM  (SELECT ... GROUP BY col1, col2) AS tbl

The optimizer would use inner join's output cardinality as an estimate
of derived table size, ignoring the fact that GROUP BY operation would
produce much fewer groups.

Add code to produce tighter bounds:
- The GROUP BY list is split into per-table lists. If GROUP BY list has
  expressions that refer to multiple tables, we fall back to join output
  cardinality.
- For each table, the first cardinality estimate is join_tab->read_records.
- Then, we try to get a tighter bound by using index statistics.
- If indexes do not cover all GROUP BY columns, we try to use per-column
  EITS statistics.
This commit is contained in:
Sergei Petrunia 2025-01-23 20:20:00 +02:00
parent cd03bf5c53
commit ef966af801
17 changed files with 794 additions and 41 deletions

View File

@ -71,6 +71,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc
../sql/log_event.cc ../sql/log_event_server.cc
../sql/mf_iocache.cc ../sql/my_decimal.cc
../sql/net_serv.cc ../sql/opt_range.cc
../sql/opt_group_by_cardinality.cc
../sql/opt_rewrite_date_cmp.cc
../sql/opt_rewrite_remove_casefold.cc
../sql/opt_sum.cc

View File

@ -317,7 +317,7 @@ a 7.0000
b 3.5000
explain SELECT s.name, AVG(s.val) AS median FROM (SELECT x.name, x.val FROM t1 x, t1 y WHERE x.name=y.name GROUP BY x.name, x.val HAVING SUM(y.val <= x.val) >= COUNT(*)/2 AND SUM(y.val >= x.val) >= COUNT(*)/2) AS s GROUP BY s.name;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 289 Using temporary; Using filesort
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 17 Using temporary; Using filesort
2 DERIVED x ALL NULL NULL NULL NULL 17 Using temporary; Using filesort
2 DERIVED y ALL NULL NULL NULL NULL 17 Using where; Using join buffer (flat, BNL join)
drop table t1;

View File

@ -20183,7 +20183,7 @@ where t2.b < 40 and t2.a=t3.a and t3.c=t.c;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 90 60.00 Using where
1 PRIMARY t3 ref idx_a idx_a 5 test.t2.a 1 100.00 Using where
1 PRIMARY <derived2> ref key0 key0 128 test.t3.c 10 100.00
1 PRIMARY <derived2> ref key0 key0 128 test.t3.c 5 100.00
2 DERIVED t4 ALL idx_c NULL NULL NULL 160 100.00 Using temporary; Using filesort
Warnings:
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`t`.`c` AS `t_c`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t2` join `test`.`t3` join (/* select#2 */ select `test`.`t4`.`c` AS `c`,max(`test`.`t4`.`b`) AS `max`,min(`test`.`t4`.`b`) AS `min` from `test`.`t4` group by `test`.`t4`.`c`) `t` where `test`.`t3`.`a` = `test`.`t2`.`a` and `t`.`c` = `test`.`t3`.`c` and `test`.`t2`.`b` < 40
@ -20233,7 +20233,7 @@ EXPLAIN
"used_key_parts": ["c"],
"ref": ["test.t3.c"],
"loops": 80.99999987,
"rows": 10,
"rows": 5,
"cost": "COST_REPLACED",
"filtered": 100,
"materialized": {
@ -22796,7 +22796,7 @@ from t1 limit 5;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 1000
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY <derived3> ref key0 key0 5 test.t1.a 100
2 DEPENDENT SUBQUERY <derived3> ref key0 key0 5 test.t1.a 1
3 DERIVED t2 ALL a NULL NULL NULL 1000 Using temporary; Using filesort
select
a,

View File

@ -283,7 +283,7 @@ on t3.a=t.a and t3.c=t.c
where t3.b > 15;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t3 range idx_b idx_b 5 NULL 2 Using index condition; Using where
1 PRIMARY <derived2> ref key0 key0 133 test.t3.a,test.t3.c 4
1 PRIMARY <derived2> ref key0 key0 133 test.t3.a,test.t3.c 2
2 DERIVED t4 ALL NULL NULL NULL NULL 40 Using filesort
drop table t3, t4;
# End of 10.3 tests
@ -809,7 +809,7 @@ id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 5
1 PRIMARY t2 ALL NULL NULL NULL NULL 50 Using where; Using join buffer (flat, BNL join)
1 PRIMARY t3 ALL NULL NULL NULL NULL 15 Using where; Using join buffer (incremental, BNL join)
1 PRIMARY <derived2> ref key0 key0 5 test.t1.b 1000 Using where
1 PRIMARY <derived2> ref key0 key0 5 test.t1.b 10 Using where
2 DERIVED t10 ALL grp_id NULL NULL NULL 10000 Using temporary; Using filesort
2 DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join)
select *

View File

@ -154,7 +154,7 @@ INSERT INTO t2 VALUES (1),(2);
EXPLAIN EXTENDED SELECT 1
FROM (SELECT COUNT(DISTINCT t1.a) FROM t1,t2 GROUP BY t1.a) AS s1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:
@ -162,7 +162,7 @@ Note 1003 /* select#1 */ select 1 AS `1` from (/* select#2 */ select count(disti
EXPLAIN EXTENDED SELECT 1
FROM (SELECT COUNT(DISTINCT t1.a) FROM t1,t2 GROUP BY t1.a) AS s1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:
@ -172,7 +172,7 @@ prepare s1 from
FROM (SELECT COUNT(DISTINCT t1.a) FROM t1,t2 GROUP BY t1.a) AS s1';
execute s1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:
@ -182,14 +182,14 @@ prepare s1 from
FROM (SELECT COUNT(DISTINCT t1.a) FROM t1,t2 GROUP BY t1.a) AS s1';
execute s1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:
Note 1003 /* select#1 */ select 1 AS `1` from (/* select#2 */ select count(distinct `test`.`t1`.`a`) AS `COUNT(DISTINCT t1.a)` from `test`.`t1` join `test`.`t2` group by `test`.`t1`.`a`) `s1`
execute s1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:

View File

@ -990,8 +990,8 @@ INSERT INTO t1 VALUES (),();
EXPLAIN EXTENDED SELECT 1 FROM
(SELECT DISTINCT GROUP_CONCAT(td.f1) FROM t1,t1 AS td GROUP BY td.f1) AS d,t1;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00 Using join buffer (flat, BNL join)
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED td ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:
@ -1012,7 +1012,7 @@ EXPLAIN EXTENDED SELECT 1 FROM
(SELECT GROUP_CONCAT(t1.a ORDER BY t1.a ASC) FROM
t1 t2, t1 GROUP BY t1.a) AS d;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4 100.00
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2 100.00
2 DERIVED t2 ALL NULL NULL NULL NULL 2 100.00 Using temporary; Using filesort
2 DERIVED t1 ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join)
Warnings:

View File

@ -0,0 +1,213 @@
#
# MDEV-30877: Output cardinality for derived table ignores GROUP BY
#
create table t1 (
groups_20 int,
groups_20_2 int,
b int,
index (groups_20)
);
insert into t1 select seq/1000, seq/1000, seq from seq_1_to_20000;
create table t2 (a int, b int, index(a));
insert into t2 select seq, seq from seq_1_to_10;
analyze table t1 persistent for all;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status Table is already up to date
set optimizer_trace=1;
# Case 1: one indexed column
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1
group by groups_20) TBL
where
1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
2 DERIVED t1 index NULL groups_20 5 NULL 20000 Using index
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
[
{
"join_output_cardinality": 20000,
"estimation":
[
{
"table": "t1",
"steps":
[
{
"index_name": "groups_20",
"cardinality": 20.99999895
}
],
"cardinality": 20.99999895
}
],
"post_group_cardinality": 20.99999895
}
]
# Case 2: one non- indexed column
explain
select *
from
t2,
(select count(*) cnt, groups_20_2 from t1
group by groups_20_2) TBL
where
1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
2 DERIVED t1 ALL NULL NULL NULL NULL 20000 Using temporary; Using filesort
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
[
{
"join_output_cardinality": 20000,
"estimation":
[
{
"table": "t1",
"steps":
[
{
"column": "groups_20_2",
"cardinality": 20.99999895
}
],
"cardinality": 20.99999895
}
],
"post_group_cardinality": 20.99999895
}
]
# Case 4: one indexed column, multiple tables
create table t3(c int);
insert into t3 select seq from seq_1_to_10;
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1,t3
group by groups_20) TBL;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
2 DERIVED t3 ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
2 DERIVED t1 index NULL groups_20 5 NULL 20000 Using index; Using join buffer (flat, BNL join)
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
[
{
"join_output_cardinality": 200000,
"estimation":
[
{
"table": "t1",
"steps":
[
{
"index_name": "groups_20",
"cardinality": 20.99999895
}
],
"cardinality": 20.99999895
}
],
"post_group_cardinality": 20.99999895
}
]
# Case 5: group by two tables
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1,t3
group by groups_20, t3.c) TBL;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 209 Using join buffer (flat, BNL join)
2 DERIVED t3 ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
2 DERIVED t1 index NULL groups_20 5 NULL 20000 Using index; Using join buffer (flat, BNL join)
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
[
{
"join_output_cardinality": 200000,
"estimation":
[
{
"table": "t1",
"steps":
[
{
"index_name": "groups_20",
"cardinality": 20.99999895
}
],
"cardinality": 20.99999895
},
{
"table": "t3",
"steps":
[],
"cardinality": 10
}
],
"post_group_cardinality": 209.9999895
}
]
# Now, without an index
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1 use index(),t3 group by groups_20) TBL;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
2 DERIVED t3 ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
2 DERIVED t1 ALL NULL NULL NULL NULL 20000 Using join buffer (flat, BNL join)
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
[
{
"join_output_cardinality": 200000,
"estimation":
[
{
"table": "t1",
"steps":
[
{
"column": "groups_20",
"cardinality": 20.99999895
}
],
"cardinality": 20.99999895
}
],
"post_group_cardinality": 20.99999895
}
]
set optimizer_trace=default;
drop table t1, t2, t3;

View File

@ -0,0 +1,108 @@
--echo #
--echo # MDEV-30877: Output cardinality for derived table ignores GROUP BY
--echo #
--source include/have_sequence.inc
--source include/not_embedded.inc
create table t1 (
groups_20 int,
groups_20_2 int,
b int,
index (groups_20)
);
insert into t1 select seq/1000, seq/1000, seq from seq_1_to_20000;
create table t2 (a int, b int, index(a));
insert into t2 select seq, seq from seq_1_to_10;
analyze table t1 persistent for all;
set optimizer_trace=1;
--echo # Case 1: one indexed column
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1
group by groups_20) TBL
where
1;
--disable_view_protocol
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
--enable_view_protocol
--echo # Case 2: one non- indexed column
explain
select *
from
t2,
(select count(*) cnt, groups_20_2 from t1
group by groups_20_2) TBL
where
1;
--disable_view_protocol
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
--enable_view_protocol
--echo # Case 4: one indexed column, multiple tables
create table t3(c int);
insert into t3 select seq from seq_1_to_10;
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1,t3
group by groups_20) TBL;
--disable_view_protocol
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
--enable_view_protocol
--echo # Case 5: group by two tables
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1,t3
group by groups_20, t3.c) TBL;
--disable_view_protocol
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
--enable_view_protocol
--echo # Now, without an index
explain
select *
from
t2,
(select count(*) cnt, groups_20 from t1 use index(),t3 group by groups_20) TBL;
--disable_view_protocol
select
json_detailed(json_extract(trace, '$**.materialized_output_cardinality'))
from
information_schema.optimizer_trace;
--enable_view_protocol
set optimizer_trace=default;
drop table t1, t2, t3;

View File

@ -514,6 +514,23 @@ select * from v2 {
}
]
},
{
"materialized_output_cardinality": {
"join_output_cardinality": 1,
"estimation": [
{
"table": "t1",
"steps": [
{
"column": "b",
"cardinality": 2
}
],
"cardinality": 2
}
]
}
},
{
"check_split_materialized": {
"not_applicable": "no candidate field can be accessed through ref"
@ -803,7 +820,7 @@ explain select * from v2 {
# Non-Mergeable view
explain select * from v1 ;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 4
2 DERIVED t1 ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
QUERY TRACE MISSING_BYTES_BEYOND_MAX_MEM_SIZE INSUFFICIENT_PRIVILEGES
explain select * from v1 {
@ -908,6 +925,24 @@ explain select * from v1 {
}
]
},
{
"materialized_output_cardinality": {
"join_output_cardinality": 10,
"estimation": [
{
"table": "t1",
"steps": [
{
"column": "b",
"cardinality": 4
}
],
"cardinality": 4
}
],
"post_group_cardinality": 4
}
},
{
"check_split_materialized": {
"not_applicable": "group list has no candidates"
@ -953,9 +988,9 @@ explain select * from v1 {
{
"table": "<derived2>",
"table_scan": {
"rows": 10,
"read_cost": 0.010103506,
"read_and_compare_cost": 0.010446846
"rows": 4,
"read_cost": 0.010041402,
"read_and_compare_cost": 0.010178738
}
}
]
@ -974,19 +1009,19 @@ explain select * from v1 {
"considered_access_paths": [
{
"access_type": "scan",
"rows": 10,
"rows_after_filter": 10,
"rows_out": 10,
"cost": 0.010446846,
"rows": 4,
"rows_after_filter": 4,
"rows_out": 4,
"cost": 0.010178738,
"index_only": false,
"chosen": true
}
],
"chosen_access_method": {
"type": "scan",
"rows_read": 10,
"rows_out": 10,
"cost": 0.010446846,
"rows_read": 4,
"rows_out": 4,
"cost": 0.010178738,
"uses_join_buffering": false
}
}
@ -996,15 +1031,15 @@ explain select * from v1 {
{
"plan_prefix": "",
"table": "<derived2>",
"rows_for_plan": 10,
"cost_for_plan": 0.010446846
"rows_for_plan": 4,
"cost_for_plan": 0.010178738
}
]
},
{
"best_join_order": ["<derived2>"],
"rows": 10,
"cost": 0.010446846
"rows": 4,
"cost": 0.010178738
},
{
"attaching_conditions_to_tables": {

View File

@ -143,9 +143,9 @@ and total_revenue = (select max(total_revenue) from revenue0)
order by s_suppkey;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using filesort
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 1 100.00 Using where
3 DERIVED lineitem range i_l_shipdate,i_l_suppkey i_l_shipdate 4 NULL 269 100.00 Using where; Using temporary; Using filesort
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 269 100.00
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 10 100.00
4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 269 100.00 Using where; Using temporary; Using filesort
Warnings:
Note 1003 /* select#1 */ select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where `revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey` and `revenue0`.`total_revenue` = (/* select#2 */ select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`) order by `dbt3_s001`.`supplier`.`s_suppkey`
@ -164,9 +164,9 @@ and total_revenue = (select max(total_revenue) from revenue0)
order by s_suppkey;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY supplier ALL PRIMARY NULL NULL NULL 10 100.00 Using filesort
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 1 100.00 Using where
3 DERIVED lineitem range i_l_shipdate,i_l_suppkey i_l_shipdate 4 NULL 269 100.00 Using where; Using temporary; Using filesort
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 269 100.00
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 10 100.00
4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 269 100.00 Using where; Using temporary; Using filesort
Warnings:
Note 1003 /* select#1 */ select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where `revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey` and `revenue0`.`total_revenue` = (/* select#2 */ select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`) order by `dbt3_s001`.`supplier`.`s_suppkey`

View File

@ -148,9 +148,9 @@ and total_revenue = (select max(total_revenue) from revenue0)
order by s_suppkey;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY supplier index PRIMARY PRIMARY 4 NULL 10 100.00
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 1 100.00 Using where
3 DERIVED lineitem range i_l_shipdate,i_l_suppkey i_l_shipdate 4 NULL 229 100.00 Using where; Using temporary; Using filesort
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 229 100.00
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 10 100.00
4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 229 100.00 Using where; Using temporary; Using filesort
Warnings:
Note 1003 /* select#1 */ select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where `revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey` and `revenue0`.`total_revenue` = (/* select#2 */ select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`) order by `dbt3_s001`.`supplier`.`s_suppkey`
@ -169,9 +169,9 @@ and total_revenue = (select max(total_revenue) from revenue0)
order by s_suppkey;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY supplier index PRIMARY PRIMARY 4 NULL 10 100.00
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 10 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 5 dbt3_s001.supplier.s_suppkey 1 100.00 Using where
3 DERIVED lineitem range i_l_shipdate,i_l_suppkey i_l_shipdate 4 NULL 229 100.00 Using where; Using temporary; Using filesort
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 229 100.00
2 SUBQUERY <derived4> ALL NULL NULL NULL NULL 10 100.00
4 DERIVED lineitem range i_l_shipdate i_l_shipdate 4 NULL 229 100.00 Using where; Using temporary; Using filesort
Warnings:
Note 1003 /* select#1 */ select `dbt3_s001`.`supplier`.`s_suppkey` AS `s_suppkey`,`dbt3_s001`.`supplier`.`s_name` AS `s_name`,`dbt3_s001`.`supplier`.`s_address` AS `s_address`,`dbt3_s001`.`supplier`.`s_phone` AS `s_phone`,`revenue0`.`total_revenue` AS `total_revenue` from `dbt3_s001`.`supplier` join `dbt3_s001`.`revenue0` where `revenue0`.`supplier_no` = `dbt3_s001`.`supplier`.`s_suppkey` and `revenue0`.`total_revenue` = (/* select#2 */ select max(`revenue0`.`total_revenue`) from `dbt3_s001`.`revenue0`) order by `dbt3_s001`.`supplier`.`s_suppkey`

View File

@ -772,7 +772,7 @@ id select_type table type possible_keys key key_len ref rows Extra
explain select t1.* from t1 left join v2b on t1.a=v2b.b;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ref key0 key0 8 test.t1.a 10 Using where
1 PRIMARY <derived2> ref key0 key0 8 test.t1.a 1 Using where
2 DERIVED t11 ALL NULL NULL NULL NULL 1000 Using temporary; Using filesort
# Check format JSON as well
explain format=JSON select t1.* from t1 left join v2b on t1.a=v2b.b;
@ -803,7 +803,7 @@ EXPLAIN
"used_key_parts": ["b"],
"ref": ["test.t1.a"],
"loops": 10,
"rows": 10,
"rows": 1,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "trigcond(t1.a = v2b.b and trigcond(t1.a is not null))",
@ -870,7 +870,7 @@ EXPLAIN
explain select t1.* from t1 left join v2c on t1.a=v2c.b;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 10
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 10 Using where
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 1 Using where
2 DERIVED t11 ALL NULL NULL NULL NULL 1000 Using temporary; Using filesort
2 DERIVED t12 eq_ref PRIMARY PRIMARY 4 test.t11.b 1 Using where
# Check format JSON as well
@ -902,7 +902,7 @@ EXPLAIN
"used_key_parts": ["b"],
"ref": ["test.t1.a"],
"loops": 10,
"rows": 10,
"rows": 1,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "trigcond(trigcond(t1.a is not null))",

View File

@ -114,6 +114,7 @@ SET (SQL_SOURCE
mysqld.cc net_serv.cc keycaches.cc
../sql-common/client_plugin.c
opt_range.cc
opt_group_by_cardinality.cc
opt_rewrite_date_cmp.cc
opt_rewrite_remove_casefold.cc
opt_sum.cc

View File

@ -0,0 +1,376 @@
/*
Copyright (c) 2025, MariaDB
This program is free software; you can redistribute it and/or modify
it under the terms of the GNU General Public License as published by
the Free Software Foundation; version 2 of the License.
This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU General Public License for more details.
You should have received a copy of the GNU General Public License
along with this program; if not, write to the Free Software
Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1335 USA */
/**
@file
Contains estimate_post_group_cardinality() which estimates cardinality
after GROUP BY operation is applied.
*/
#include "mariadb.h"
#include "sql_priv.h"
#include "sql_select.h"
#include "sql_statistics.h"
#include "opt_trace.h"
static
double estimate_table_group_cardinality(JOIN *join, Item ***group_list,
Item* const *end);
inline bool has_one_bit_set(table_map val)
{
return val && !(val & (val-1));
}
/*
@brief
Sort the Items that refer to one table (so have only one bit in
used_tables()). Used to get the items that refer to the same table
to be next to each other.
*/
int cmp_items_by_used_tables(const void *a_val, const void *b_val)
{
table_map v1= (*((Item**)a_val))->used_tables();
table_map v2= (*((Item**)b_val))->used_tables();
return v1 > v2 ? 1 : (v1 < v2 ? -1 : 0);
}
/*
@brief
Given a SELECT with GROUP BY clause, estimate the cardinality of output
after the grouping operation is performed.
@detail
Consider a query
SELECT ...
FROM t1, t2, t3 ...
WHERE ...
GROUP BY
col1, col2, ...
Join optimizer produces an estimate of number of record combinations we'll
get after all join operations are performed (denote this join_output_card).
This function produces a conservative (i.e. upper bound) estimate of how
many groups will be produced by the GROUP BY operation.
It does it as follows:
* Split the GROUP BY clause into per-table lists.
(if there are GROUP BY items that refer to multiple tables, refuse
to work and return join_output_card).
* Compute n_groups estimate for each table and its GROUP BY sub-list.
* Compute a product of these estimates, n_groups_prod.
* Return MIN(join_ouput_card, n_groups_prod).
@param
join_output_card Number of rows after join operation
@return
Number of rows that will be left after grouping operation
*/
double estimate_post_group_cardinality(JOIN *join, double join_output_card)
{
Dynamic_array<Item*> group_cols(join->thd->mem_root);
ORDER *cur_group;
Json_writer_object wrapper(join->thd);
Json_writer_object trace(join->thd, "materialized_output_cardinality");
trace.add("join_output_cardinality", join_output_card);
/*
Walk the GROUP BY list and put items into group_cols array. Array is
easier to work with: we will sort it and then produce estimates for
sub-arrays that refer to just one table.
Also check that each item depends on just one table (if not, bail out).
*/
for (cur_group= join->group_list; cur_group; cur_group= cur_group->next)
{
Item *item= *cur_group->item;
table_map map= item->used_tables();
if ((map & PSEUDO_TABLE_BITS) || !has_one_bit_set(map))
{
/* Can't estimate */
return join_output_card;
}
group_cols.append(item);
}
DBUG_ASSERT(group_cols.size());
group_cols.sort(cmp_items_by_used_tables);
double new_card= 1.0;
Item **pos= group_cols.front();
Json_writer_array trace_steps(join->thd, "estimation");
while (pos != group_cols.end())
{
new_card *= estimate_table_group_cardinality(join, &pos, group_cols.end());
if (new_card > join_output_card)
return join_output_card;
}
trace_steps.end();
trace.add("post_group_cardinality", new_card);
return new_card;
}
/*
@brief
Compute number of groups for a GROUP BY list that refers to a single table
@detail
Consider a query:
SELECT ...
FROM t1, t2, t3 ...
WHERE ...
GROUP BY
t1.col1, ... t1.colN -- expressions only refer to t1.
The number of groups is estimated using the following:
== 1. Use found_records ==
There cannot be more rows than the number of records in t1 that match the
WHERE clause, that is, JOIN_TAB(t1)->found_records.
This estimate doesn't depend on the expressions in the GROUP BY list, so we
use it as a fall-back estimate.
== 2. Use index statistics ==
If t1 has an INDEX(col1, ... colN) then the number of different
combinations of {col1, ..., colN} can be obtained from index statistics.
It is possible to cover the GROUP BY list with several indexes (without
overlaps) and use a product of n_distinct statistics. For example, for
GROUP BY key1part1, key1part2, key2part1, key2part2, key2part3
the estimate would be:
n_groups= n_distinct(key1, parts=2) * n_distinct(key2, parts=3)
There can be multiple ways one can cover GROUP BY list with different
indexes. We try to use indexes that cover more GROUP BY columns, first.
This may cause us to fail later. For example, for
GROUP BY a, b, c, d
and indexes
INDEX idx1(a,b,c)
INDEX idx2(a,b)
INDEX idx3(c,d)
We will use idx1 and then will be unable to get any estimate for column d.
We could have used idx2 and idx3, instead, and could have covered all
columns. We ignore such cases.
Note that when using index statistics, we ignore the WHERE condition
selectivity. That's because we cannot tell how the WHERE affects index
stats. Does it
A. reduce the number of GROUP BY groups, or
B. make each GROUP BY group smaller ?
We conservatively assume that B holds.
== 3 Use per-column EITS statistics ==
If we fail to cover GROUP BY with indexes, we try to use column statistics
for the remaining columns.
@param join the Join object we're computing for
@param group_list INOUT Array of Item* from GROUP BY clause, ordered
by table. This function should process the table
it is pointing to, and advance the pointer so it
points at 'end' or at the next table.
@param end IN End of the above array.
*/
double estimate_table_group_cardinality(JOIN *join, Item ***group_list,
Item* const *end)
{
TABLE *table= NULL;
key_map possible_keys;
Dynamic_array<int> columns(join->thd->mem_root);
double card= 1.0;
double table_records_after_where= DBL_MAX; // Safety
table_map table_bit= (**group_list)->used_tables();
/*
join->map2table is not set yet, so find our table in JOIN_TABs.
*/
for (JOIN_TAB *tab= join->join_tab;
tab < join->join_tab + join->top_join_tab_count;
tab++)
{
if (tab->table->map == table_bit)
{
table= tab->table;
table_records_after_where= rows2double(tab->found_records);
break;
}
}
DBUG_ASSERT(table);
Json_writer_object trace_obj(join->thd);
trace_obj.add_table_name(table);
Json_writer_array trace_steps(join->thd, "steps");
possible_keys.clear_all();
bool found_complex_item= false;
/*
Walk through the group list and collect references to fields.
If there are other kinds of items, return table's cardinality.
*/
Item **p;
for (p= *group_list;
p != end && (*p)->used_tables() == table_bit;
p++)
{
Item *real= (*p)->real_item();
if (real->type() == Item::FIELD_ITEM)
{
Field *field= ((Item_field*)real)->field;
possible_keys.merge(field->part_of_key);
columns.append(field->field_index);
}
else
found_complex_item= true;
}
/* Tell the caller where group_list ended */
*group_list= p;
if (found_complex_item)
goto whole_table;
possible_keys.intersect(table->keys_in_use_for_query);
/*
Ok, group_list has only columns and we've got them in 'columns'.
*/
while (!possible_keys.is_clear_all())
{
/* Find the index which has the longest prefix covered by columns. */
uint longest_key= UINT_MAX;
int longest_len= 0;
key_map::Iterator key_it(possible_keys);
uint key;
while ((key= key_it++) != key_map::Iterator::BITMAP_END)
{
const KEY *keyinfo= table->key_info + key;
/* Find the length of index prefix covered by GROUP BY columns */
int part;
for (part= 0; part < (int)keyinfo->usable_key_parts; part++)
{
uint field_index= keyinfo->key_part[part].field->field_index;
if (columns.find_first(field_index) == columns.NOT_FOUND)
break;
}
if (part > 0) // At least one column is covered
{
/* Make sure the index has statistics available */
if (!keyinfo->actual_rec_per_key(part - 1))
{
possible_keys.clear_bit(key);
continue;
}
if (part > longest_len)
{
longest_len= part;
longest_key= key;
}
}
else
{
/*
The index can't cover even one-column prefix. Remove it from
consideration.
*/
possible_keys.clear_bit(key);
}
}
if (longest_key == UINT_MAX)
break; // No indexes are usable, stop.
possible_keys.clear_bit(longest_key);
/* Multiply cardinality by index prefix's cardinality */
const KEY *keyinfo= table->key_info + longest_key;
double index_card= (rows2double(table->stat_records()) /
keyinfo->actual_rec_per_key(longest_len-1));
/* Safety in case of inconsistent statistics: */
set_if_bigger(index_card, 1.0);
Json_writer_object trace_idx(join->thd);
trace_idx.add("index_name", keyinfo->name)
.add("cardinality", index_card);
card *= index_card;
if (card > table_records_after_where)
goto whole_table;
/* Remove the columns we've handled from consideration */
for (int part= 0; part < longest_len; part++)
{
uint field_index= keyinfo->key_part[part].field->field_index;
size_t idx= columns.find_first(field_index);
if (idx != columns.NOT_FOUND)
columns.del(idx);
else
DBUG_ASSERT(0); // Can't happen, we've found it above.
}
if (!columns.size())
break; // If we've covered all columns, stop.
}
/*
If there are some columns left for which we couldn't get cardinality
from index statistics, try getting it from columns' histograms
*/
for (size_t i=0; i < columns.size(); i++)
{
double freq;
Field *field= table->field[columns.at(i)];
if (!field->read_stats ||
(freq= field->read_stats->get_avg_frequency()) == 0.0)
goto whole_table;
double column_card= rows2double(table->stat_records()) / freq;
Json_writer_object trace_col(join->thd);
trace_col.add("column", field->field_name)
.add("cardinality", column_card);
card *= column_card;
if (card > table_records_after_where)
goto whole_table;
}
normal_exit:
trace_steps.end();
trace_obj.add("cardinality", card);
return card;
whole_table:
card= table_records_after_where;
goto normal_exit;
}

View File

@ -182,6 +182,19 @@ public:
return ((const Elem*)array.buffer) + array.elements - 1;
}
static const size_t NOT_FOUND= (size_t)-1;
/// @returns index of the first element equal to el, or NOT_FOUND
size_t find_first(const Elem &el) const
{
for (size_t i=0; i < size() ; i++)
{
if (el == at(i))
return i;
}
return NOT_FOUND;
}
size_t size() const { return array.elements; }
const Elem *end() const

View File

@ -6357,6 +6357,10 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list,
for (i= 0; i < join->table_count ; i++)
if (double rr= join->best_positions[i].records_read)
records= COST_MULT(records, rr);
if (join->group_list)
records= estimate_post_group_cardinality(join, records);
rows= double_to_rows(records);
set_if_smaller(rows, unit->lim.get_select_limit());
join->select_lex->increase_derived_records(rows);

View File

@ -2712,6 +2712,8 @@ void propagate_new_equalities(THD *thd, Item *cond,
#define PREV_BITS(type, N_BITS) ((type)my_set_bits(N_BITS))
double estimate_post_group_cardinality(JOIN *join, double join_output_card);
bool dbug_user_var_equals_str(THD *thd, const char *name, const char *value);
#endif /* SQL_SELECT_INCLUDED */