Skip to content

Commit

Permalink
Adjust costs for doing index scan in cost_group_min_max()
Browse files Browse the repository at this point in the history
The idea is that when doing a tree dive (once per group), we need to
compare key values, which is fast.  For each new group, we have to
compare the full where clause for the row.
Compared to original code, the cost of group_min_max() has slightly
increased which affects some test with only a few rows.
main.group_min_max and main.distinct have been modified to show the
effect of the change.

The patch also adjust the number of groups in case of quick selects:
- For simple WHERE clauses, ensure that we have at least as many groups
  as we have conditions on the used group-by key parts.
  The assumption is that each condition will create at least one group.
- Ensure that there are no more groups than rows found by quick_select

Test changes:
- For some small tables there has been a change of
  Using index for group-by -> Using index for group-by (scanning)
  Range -> Index and Using index for group-by -> Using index
  • Loading branch information
montywi authored and spetrunia committed Feb 2, 2023
1 parent bc9805e commit 6fa7451
Show file tree
Hide file tree
Showing 18 changed files with 221 additions and 102 deletions.
6 changes: 3 additions & 3 deletions mysql-test/main/derived_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -19749,7 +19749,7 @@ id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <subquery3> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY <derived2> ref key0 key0 5 test.t3.id 2
3 MATERIALIZED t2 ALL NULL NULL NULL NULL 3
2 DERIVED cp2 range NULL a 5 NULL 7 Using index for group-by
2 DERIVED cp2 index NULL a 5 NULL 7 Using index
explain format=json select * from t1, (select a from t1 cp2 group by a) dt, t3
where dt.a = t1.a and t1.a = t3.id and t1.a in (select a from t2);
EXPLAIN
Expand Down Expand Up @@ -19826,13 +19826,13 @@ EXPLAIN
{
"table": {
"table_name": "cp2",
"access_type": "range",
"access_type": "index",
"key": "a",
"key_length": "5",
"used_key_parts": ["a"],
"rows": 7,
"filtered": 100,
"using_index_for_group_by": true
"using_index": true
}
}
]
Expand Down
14 changes: 9 additions & 5 deletions mysql-test/main/distinct.result
Original file line number Diff line number Diff line change
Expand Up @@ -538,10 +538,10 @@ PRIMARY KEY (a,b));
INSERT INTO t2 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
EXPLAIN SELECT DISTINCT a FROM t2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range NULL PRIMARY 4 NULL 3 Using index for group-by
1 SIMPLE t2 index NULL PRIMARY 8 NULL 3 Using index
EXPLAIN SELECT DISTINCT a,a FROM t2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range NULL PRIMARY 4 NULL 3 Using index for group-by
1 SIMPLE t2 index NULL PRIMARY 8 NULL 3 Using index
EXPLAIN SELECT DISTINCT b,a FROM t2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index NULL PRIMARY 8 NULL 3 Using index
Expand Down Expand Up @@ -754,9 +754,6 @@ INSERT INTO t1(a, b, c) VALUES (1, 1, 1),
(1, 2, 1),
(1, 2, 2),
(1, 2, 3);
EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL PRIMARY 16 NULL 6 Using index for group-by; Using temporary
SELECT DISTINCT a, b, d, c FROM t1;
a b d c
1 1 0 1
Expand All @@ -765,6 +762,13 @@ a b d c
1 2 0 1
1 2 0 2
1 2 0 3
EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL a 16 NULL 6 Using index
INSERT INTO t1 SELECT seq/10,seq/10,seq/10,seq/10,seq from seq_1_to_100;
EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL PRIMARY 16 NULL 10 Using index for group-by; Using temporary
DROP TABLE t1;
#
# Bug #46159: simple query that never returns
Expand Down
6 changes: 4 additions & 2 deletions mysql-test/main/distinct.test
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@
#

--source include/default_optimizer_switch.inc
--source include/have_sequence.inc
--disable_warnings
drop table if exists t1,t2,t3;
--enable_warnings
Expand Down Expand Up @@ -574,9 +575,10 @@ INSERT INTO t1(a, b, c) VALUES (1, 1, 1),
(1, 2, 2),
(1, 2, 3);

EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;

SELECT DISTINCT a, b, d, c FROM t1;
EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;
INSERT INTO t1 SELECT seq/10,seq/10,seq/10,seq/10,seq from seq_1_to_100;
EXPLAIN SELECT DISTINCT a, b, d, c FROM t1;

DROP TABLE t1;

Expand Down
13 changes: 9 additions & 4 deletions mysql-test/main/group_by.result
Original file line number Diff line number Diff line change
Expand Up @@ -1578,7 +1578,7 @@ id select_type table type possible_keys key key_len ref rows Extra
EXPLAIN SELECT a FROM t1 FORCE INDEX FOR JOIN (i2)
FORCE INDEX FOR GROUP BY (i2) GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL i2 4 NULL 144 Using index for group-by
1 SIMPLE t1 index NULL i2 9 NULL 144 Using index
EXPLAIN SELECT a FROM t1 USE INDEX () IGNORE INDEX (i2);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 144
Expand Down Expand Up @@ -1701,7 +1701,7 @@ NULL 1
1 2
EXPLAIN SELECT a from t2 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range NULL a 5 NULL 6 Using index for group-by
1 SIMPLE t2 index NULL a 10 NULL 6 Using index
SELECT a from t2 GROUP BY a;
a
NULL
Expand All @@ -1714,6 +1714,11 @@ b
NULL
1
2
insert into t2 SELECT NULL, NULL from seq_1_to_10;
# Expect: Using index for group-by
EXPLAIN SELECT b from t2 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range NULL a 5 NULL 9 Using index for group-by
DROP TABLE t1;
DROP TABLE t2;
CREATE TABLE t1 ( a INT, b INT );
Expand Down Expand Up @@ -2452,15 +2457,15 @@ test.t1 analyze status OK

EXPLAIN SELECT SQL_BUFFER_RESULT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range b b 9 NULL 2 Using where; Using index for group-by; Using temporary
1 SIMPLE t1 ref b b 4 const 6 Using where; Using index; Using temporary

SELECT SQL_BUFFER_RESULT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
MIN(a) b
0 a

EXPLAIN SELECT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range b b 9 NULL 2 Using where; Using index for group-by
1 SIMPLE t1 ref b b 4 const 6 Using where; Using index

SELECT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
MIN(a) b
Expand Down
7 changes: 7 additions & 0 deletions mysql-test/main/group_by.test
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
--source include/have_sequence.inc

# Initialise
--disable_warnings
drop table if exists t1,t2,t3;
Expand Down Expand Up @@ -1164,6 +1166,11 @@ SELECT a from t2 GROUP BY a;
EXPLAIN SELECT b from t2 GROUP BY b;
SELECT b from t2 GROUP BY b;

# Show that we are using 'range' when there is more NULL rows in the table
insert into t2 SELECT NULL, NULL from seq_1_to_10;
--echo # Expect: Using index for group-by
EXPLAIN SELECT b from t2 GROUP BY a;

DROP TABLE t1;
DROP TABLE t2;

Expand Down
44 changes: 39 additions & 5 deletions mysql-test/main/group_min_max.result
Original file line number Diff line number Diff line change
Expand Up @@ -2353,6 +2353,9 @@ t1;
id2 id3 id5 id4 id3 id6 id5 id1
1 1 1 1 1 1 1 1
DROP TABLE t1,t2,t3,t4,t5,t6;
#
# Bug#22342: No results returned for query using max and group by
#
CREATE TABLE t1 (a int, b int, KEY (a,b), KEY b (b));
INSERT INTO t1 VALUES
(1,1),(1,2),(1,0),(1,3),
Expand All @@ -2361,17 +2364,28 @@ ANALYZE TABLE t1;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c));
INSERT INTO t2 SELECT a,b,b FROM t1;
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range a,b a 10 NULL 2 Using where; Using index for group-by
1 SIMPLE t1 range a,b a 10 NULL 6 Using where; Using index
insert into t1 select 1,seq from seq_1_to_100;
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range a,b a 10 NULL 6 Using where; Using index
analyze table t1;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range a,b a 10 NULL 1 Using where; Using index for group-by
SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
MAX(b) a
1 1
SELECT MIN(b), a FROM t1 WHERE b > 1 AND a = 1 GROUP BY a;
MIN(b) a
2 1
CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c));
INSERT INTO t2 SELECT a,b,b FROM t1;
explain SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range PRIMARY PRIMARY 12 NULL 1 Using where; Using index
Expand Down Expand Up @@ -3657,14 +3671,34 @@ KEY (f1,f2)
) ;
insert into t1 values(1,'A'),(1 , 'B'), (1, 'C'), (2, 'A'),
(3, 'A'), (3, 'B'), (3, 'C'), (3, 'D');
explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL f1 5 NULL 8 Using index for group-by (scanning)
SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
f1 COUNT(DISTINCT f2)
1 3
2 1
3 4
insert into t1 select seq/10,char(64+mod(seq,4)) from seq_1_to_100;
explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL f1 5 NULL 10 Using index for group-by
SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
f1 COUNT(DISTINCT f2)
0 4
1 4
2 4
3 5
4 4
5 4
6 4
7 4
8 4
9 4
10 4
explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL f1 5 NULL 8 Using index for group-by
1 SIMPLE t1 range NULL f1 5 NULL 10 Using index for group-by
drop table t1;
# End of test#50539.
#
Expand Down Expand Up @@ -3760,7 +3794,7 @@ CREATE INDEX break_it ON t1 (a, b);
EXPLAIN
SELECT distinct a, b FROM t1 where a = '3' ORDER BY b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range break_it break_it 10 NULL 2 Using where; Using index for group-by; Using filesort
1 SIMPLE t1 ref break_it break_it 5 const 6 Using where; Using index; Using filesort
SELECT distinct a, b FROM t1 where a = '3' ORDER BY b;
a b
3 1
Expand Down
22 changes: 14 additions & 8 deletions mysql-test/main/group_min_max.test
Original file line number Diff line number Diff line change
Expand Up @@ -899,23 +899,27 @@ t1;

DROP TABLE t1,t2,t3,t4,t5,t6;

#
# Bug#22342: No results returned for query using max and group by
#
--echo #
--echo # Bug#22342: No results returned for query using max and group by
--echo #
CREATE TABLE t1 (a int, b int, KEY (a,b), KEY b (b));
INSERT INTO t1 VALUES
(1,1),(1,2),(1,0),(1,3),
(1,-1),(1,-2),(1,-3),(1,-4);
ANALYZE TABLE t1;
CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c));
INSERT INTO t2 SELECT a,b,b FROM t1;

explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
insert into t1 select 1,seq from seq_1_to_100;
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
analyze table t1;
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;

SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
SELECT MIN(b), a FROM t1 WHERE b > 1 AND a = 1 GROUP BY a;
CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c));
INSERT INTO t2 SELECT a,b,b FROM t1;
explain SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a;
SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a;

DROP TABLE t1,t2;

#
Expand Down Expand Up @@ -1439,10 +1443,12 @@ CREATE TABLE t1 (
) ;
insert into t1 values(1,'A'),(1 , 'B'), (1, 'C'), (2, 'A'),
(3, 'A'), (3, 'B'), (3, 'C'), (3, 'D');

explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
insert into t1 select seq/10,char(64+mod(seq,4)) from seq_1_to_100;
explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;
explain SELECT f1, COUNT(DISTINCT f2) FROM t1 GROUP BY f1;

drop table t1;
--echo # End of test#50539.

Expand Down
6 changes: 3 additions & 3 deletions mysql-test/main/group_min_max_innodb.result
Original file line number Diff line number Diff line change
Expand Up @@ -180,7 +180,7 @@ F 17
EXPLAIN SELECT c1, max(i2) FROM t1 WHERE (c1 = 'C' OR c1 = 'F' ) AND ( i2 = 17 )
GROUP BY c1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range k1 k1 5 NULL 1 Using where; Using index for group-by
1 SIMPLE t1 range k1 k1 5 NULL 2 Using where; Using index for group-by
SELECT c1, max(i2) FROM t1 WHERE (c1 = 'C' OR c1 = 'F' ) AND ( i2 = 17 )
GROUP BY c1;
c1 max(i2)
Expand All @@ -200,7 +200,7 @@ EXPLAIN SELECT c1, i1, max(i2) FROM t2
WHERE (c1 = 'C' OR ( c1 = 'F' AND i1 < 35)) AND ( i2 = 17 )
GROUP BY c1,i1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range k2 k2 9 NULL 60 Using where; Using index for group-by
1 SIMPLE t2 range k2 k2 5 NULL 60 Using where; Using index
SELECT c1, i1, max(i2) FROM t2
WHERE (c1 = 'C' OR ( c1 = 'F' AND i1 < 35)) AND ( i2 = 17 )
GROUP BY c1,i1;
Expand All @@ -211,7 +211,7 @@ EXPLAIN SELECT c1, i1, max(i2) FROM t2
WHERE (((c1 = 'C' AND i1 < 40) OR ( c1 = 'F' AND i1 < 35)) AND ( i2 = 17 ))
GROUP BY c1,i1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 range k2 k2 9 NULL 60 Using where; Using index for group-by
1 SIMPLE t2 range k2 k2 5 NULL 60 Using where; Using index
SELECT c1, i1, max(i2) FROM t2
WHERE (((c1 = 'C' AND i1 < 40) OR ( c1 = 'F' AND i1 < 35)) AND ( i2 = 17 ))
GROUP BY c1,i1;
Expand Down
Loading

0 comments on commit 6fa7451

Please sign in to comment.