Skip to content

Commit 94f69e9

Browse files
author
Jan Wedvik
committed
Bug#35483044 Hypergraph: Invalid row estimate for filter on 'Index range scan'
This commit improves row estimates for the following cases: - field <=> NULL : If field is non-nullable, then the selectivity is 0. This fixes the error described in the bug report, where the selectivity of such a term was estimated to be 0.1. - field=NULL : The selectivity is 0. - field <=> other_expression : Use the same algorithm as for 'field=other_expression', meaning that we use histograms or index statistics if applicable. This commit also changes mysql-test/include/index_merge1.inc so that the code for populating table t0 is pure SQL rather than perl. This makes it easier to run part of the index_merge_... tests in isolation, by copying the relevant SQL code from a .result file. Change-Id: Ibba50f61a60edc0184293edb7317c5be6e082223
1 parent 5373499 commit 94f69e9

10 files changed

+338
-66
lines changed

mysql-test/include/index_merge1.inc

Lines changed: 18 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -49,19 +49,25 @@ create table t0
4949
INDEX i8(key8)
5050
);
5151

52-
--disable_query_log
53-
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
52+
DELIMITER |;
5453

55-
let $1=9;
56-
set @d=2;
57-
while ($1)
58-
{
59-
eval insert into t0 select key1+@d, key2+@d, key3+@d, key4+@d, key5+@d,
60-
key6+@d, key7+@d, key8-@d from t0;
61-
eval set @d=@d*2;
62-
dec $1;
63-
}
64-
--enable_query_log
54+
create procedure populate_t0()
55+
begin
56+
declare d int default 2;
57+
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
58+
59+
while d<=POW(2,9) do
60+
insert into t0 select key1+d, key2+d, key3+d, key4+d, key5+d,
61+
key6+d, key7+d, key8-d from t0;
62+
set d = d*2;
63+
end while;
64+
end|
65+
66+
DELIMITER ;|
67+
68+
call populate_t0();
69+
70+
drop procedure populate_t0;
6571

6672
analyze table t0;
6773

mysql-test/r/filter_single_col_idx_big_myisam.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1219,7 +1219,7 @@ Warnings:
12191219
Note 1003 /* select#1 */ select `test`.`t1`.`col1_idx` AS `col1_idx`,`test`.`t1`.`col2_idx` AS `col2_idx`,`test`.`t1`.`col3` AS `col3`,`test`.`t1`.`col4` AS `col4`,`test`.`t1`.`vc` AS `vc`,`test`.`t1`.`vc_ft` AS `vc_ft` from `test`.`t1` where (`test`.`t1`.`col3` is null)
12201220
EXPLAIN SELECT * FROM t1 WHERE t1.col3 = NULL;
12211221
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1222-
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 1029 10.00 Using where
1222+
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 1029 0.10 Using where
12231223
Warnings:
12241224
Note 1003 /* select#1 */ select `test`.`t1`.`col1_idx` AS `col1_idx`,`test`.`t1`.`col2_idx` AS `col2_idx`,`test`.`t1`.`col3` AS `col3`,`test`.`t1`.`col4` AS `col4`,`test`.`t1`.`vc` AS `vc`,`test`.`t1`.`vc_ft` AS `vc_ft` from `test`.`t1` where (`test`.`t1`.`col3` = NULL)
12251225
EXPLAIN SELECT * FROM t1 WHERE t1.col3>NULL;
@@ -1283,7 +1283,7 @@ Warnings:
12831283
Note 1003 /* select#1 */ select `test`.`t1`.`col1_idx` AS `col1_idx`,`test`.`t1`.`col2_idx` AS `col2_idx`,`test`.`t1`.`col3` AS `col3`,`test`.`t1`.`col4` AS `col4`,`test`.`t1`.`vc` AS `vc`,`test`.`t1`.`vc_ft` AS `vc_ft` from `test`.`t1` where false
12841284
EXPLAIN SELECT * FROM t1 WHERE t1.col4 = NULL;
12851285
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1286-
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 1029 10.00 Using where
1286+
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 1029 0.10 Using where
12871287
Warnings:
12881288
Note 1003 /* select#1 */ select `test`.`t1`.`col1_idx` AS `col1_idx`,`test`.`t1`.`col2_idx` AS `col2_idx`,`test`.`t1`.`col3` AS `col3`,`test`.`t1`.`col4` AS `col4`,`test`.`t1`.`vc` AS `vc`,`test`.`t1`.`vc_ft` AS `vc_ft` from `test`.`t1` where (`test`.`t1`.`col4` = NULL)
12891289
EXPLAIN SELECT * FROM t1 WHERE t1.col4>NULL;

mysql-test/r/filter_single_col_idx_small_myisam.result

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -139,7 +139,7 @@ id select_type table partitions type possible_keys key key_len ref rows filtered
139139
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 10.00 Using where
140140
EXPLAIN SELECT * FROM t1 WHERE t1.col3 = NULL;
141141
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
142-
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 10.00 Using where
142+
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 0.78 Using where
143143
EXPLAIN SELECT * FROM t1 WHERE t1.col3>NULL;
144144
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
145145
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 33.33 Using where
@@ -179,7 +179,7 @@ id select_type table partitions type possible_keys key key_len ref rows filtered
179179
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
180180
EXPLAIN SELECT * FROM t1 WHERE t1.col4 = NULL;
181181
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
182-
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 10.00 Using where
182+
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 0.78 Using where
183183
EXPLAIN SELECT * FROM t1 WHERE t1.col4>NULL;
184184
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
185185
1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 128 33.33 Using where

mysql-test/r/hypergraph_bugs.result

Lines changed: 95 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1185,3 +1185,98 @@ EXPLAIN
11851185
-> Covering index lookup on x2 using k1 (a=x1.b) (rows=6)
11861186

11871187
DROP TABLE t1;
1188+
#
1189+
# Bug#35483044 Hypergraph: Invalid row estimate for filter on
1190+
# 'Index range scan'
1191+
#
1192+
CREATE TABLE t1 (
1193+
a INT PRIMARY KEY,
1194+
b INT NOT NULL,
1195+
c INT,
1196+
KEY k_b(b),
1197+
KEY k_c(c)
1198+
);
1199+
INSERT INTO t1 WITH RECURSIVE qn(n) AS
1200+
(SELECT 1 UNION ALL SELECT n+1 FROM qn WHERE n<30) SELECT n, n/2, n/2 FROM qn;
1201+
ANALYZE TABLE t1;
1202+
Table Op Msg_type Msg_text
1203+
test.t1 analyze status OK
1204+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c=NULL;
1205+
EXPLAIN
1206+
-> Filter: ((t1.b = 5) or (t1.c = NULL)) (rows=2)
1207+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1208+
1209+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c<=>NULL;
1210+
EXPLAIN
1211+
-> Deduplicate rows sorted by row ID (rows=4.8)
1212+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1213+
-> Index range scan on t1 using k_c over (c = NULL) (rows=1)
1214+
1215+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c IS NULL;
1216+
EXPLAIN
1217+
-> Deduplicate rows sorted by row ID (rows=4.8)
1218+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1219+
-> Index range scan on t1 using k_c over (c = NULL) (rows=1)
1220+
1221+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=NULL OR c=5;
1222+
EXPLAIN
1223+
-> Filter: ((t1.b = NULL) or (t1.c = 5)) (rows=2)
1224+
-> Index range scan on t1 using k_c over (c = 5) (rows=2)
1225+
1226+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b<=>NULL OR c=5;
1227+
EXPLAIN
1228+
-> Filter: ((t1.b <=> NULL) or (t1.c = 5)) (rows=2)
1229+
-> Index range scan on t1 using k_c over (c = 5) (rows=2)
1230+
1231+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b<=>FLOOR(RAND(0));
1232+
EXPLAIN
1233+
-> Filter: (t1.b <=> floor(rand(0))) (rows=2)
1234+
-> Table scan on t1 (rows=30)
1235+
1236+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE c<=>FLOOR(RAND(0));
1237+
EXPLAIN
1238+
-> Filter: (t1.c <=> floor(rand(0))) (rows=2)
1239+
-> Table scan on t1 (rows=30)
1240+
1241+
ANALYZE TABLE t1 UPDATE HISTOGRAM ON b,c;
1242+
Table Op Msg_type Msg_text
1243+
test.t1 histogram status Histogram statistics created for column 'b'.
1244+
test.t1 histogram status Histogram statistics created for column 'c'.
1245+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c=NULL;
1246+
EXPLAIN
1247+
-> Filter: ((t1.b = 5) or (t1.c = NULL)) (rows=2)
1248+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1249+
1250+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c<=>NULL;
1251+
EXPLAIN
1252+
-> Deduplicate rows sorted by row ID (rows=2.03)
1253+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1254+
-> Index range scan on t1 using k_c over (c = NULL) (rows=1)
1255+
1256+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=5 OR c IS NULL;
1257+
EXPLAIN
1258+
-> Deduplicate rows sorted by row ID (rows=2.03)
1259+
-> Index range scan on t1 using k_b over (b = 5) (rows=2)
1260+
-> Index range scan on t1 using k_c over (c = NULL) (rows=1)
1261+
1262+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b=NULL OR c=5;
1263+
EXPLAIN
1264+
-> Filter: ((t1.b = NULL) or (t1.c = 5)) (rows=2)
1265+
-> Index range scan on t1 using k_c over (c = 5) (rows=2)
1266+
1267+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b<=>NULL OR c=5;
1268+
EXPLAIN
1269+
-> Filter: ((t1.b <=> NULL) or (t1.c = 5)) (rows=2)
1270+
-> Index range scan on t1 using k_c over (c = 5) (rows=2)
1271+
1272+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE b<=>FLOOR(RAND(0));
1273+
EXPLAIN
1274+
-> Filter: (t1.b <=> floor(rand(0))) (rows=2)
1275+
-> Table scan on t1 (rows=30)
1276+
1277+
EXPLAIN FORMAT=TREE SELECT * FROM t1 WHERE c<=>FLOOR(RAND(0));
1278+
EXPLAIN
1279+
-> Filter: (t1.c <=> floor(rand(0))) (rows=2)
1280+
-> Table scan on t1 (rows=30)
1281+
1282+
DROP TABLE t1;

mysql-test/r/index_merge_innodb.result

Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,18 @@ INDEX i6(key6),
2323
INDEX i7(key7),
2424
INDEX i8(key8)
2525
);
26+
create procedure populate_t0()
27+
begin
28+
declare d int default 2;
29+
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
30+
while d<=POW(2,9) do
31+
insert into t0 select key1+d, key2+d, key3+d, key4+d, key5+d,
32+
key6+d, key7+d, key8-d from t0;
33+
set d = d*2;
34+
end while;
35+
end|
36+
call populate_t0();
37+
drop procedure populate_t0;
2638
analyze table t0;
2739
Table Op Msg_type Msg_text
2840
test.t0 analyze status OK

mysql-test/r/index_merge_innodb_hypergraph.result

Lines changed: 16 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,18 @@ INDEX i6(key6),
2323
INDEX i7(key7),
2424
INDEX i8(key8)
2525
);
26+
create procedure populate_t0()
27+
begin
28+
declare d int default 2;
29+
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
30+
while d<=POW(2,9) do
31+
insert into t0 select key1+d, key2+d, key3+d, key4+d, key5+d,
32+
key6+d, key7+d, key8-d from t0;
33+
set d = d*2;
34+
end while;
35+
end|
36+
call populate_t0();
37+
drop procedure populate_t0;
2638
analyze table t0;
2739
Table Op Msg_type Msg_text
2840
test.t0 analyze status OK
@@ -114,7 +126,7 @@ EXPLAIN
114126
# verify fallback to "range" if there is only one non-confluent condition
115127
explain select * from t0 where key2 = 45 or key1 <=> null;
116128
EXPLAIN
117-
-> Filter: ((t0.key2 = 45) or (t0.key1 <=> NULL)) (rows=103)
129+
-> Filter: ((t0.key2 = 45) or (t0.key1 <=> NULL)) (rows=1)
118130
-> Index range scan on t0 using i2 over (key2 = 45) (rows=1)
119131

120132
explain select * from t0 where key2 = 45 or key1 is not null;
@@ -128,7 +140,7 @@ EXPLAIN
128140
# the last conj. is always false and will be discarded
129141
explain select * from t0 where key2=10 or key3=3 or key4 <=> null;
130142
EXPLAIN
131-
-> Deduplicate rows sorted by row ID (rows=104)
143+
-> Deduplicate rows sorted by row ID (rows=2)
132144
-> Index range scan on t0 using i2 over (key2 = 10) (rows=1)
133145
-> Index range scan on t0 using i3 over (key3 = 3) (rows=1)
134146

@@ -143,14 +155,14 @@ EXPLAIN
143155
explain select key1 from t0 where (key1 <=> null) or (key2 < 2) or
144156
(key3=10) or (key4 <=> null);
145157
EXPLAIN
146-
-> Sort-deduplicate by row ID (rows=472)
158+
-> Sort-deduplicate by row ID (rows=342)
147159
-> Index range scan on t0 using i2 over (key2 < 2) (rows=1)
148160
-> Index range scan on t0 using i3 over (key3 = 10) (rows=1)
149161

150162
explain select key1 from t0 where (key1 <=> null) or (key1 < 5) or
151163
(key3=10) or (key4 <=> null);
152164
EXPLAIN
153-
-> Sort-deduplicate by row ID (rows=472)
165+
-> Sort-deduplicate by row ID (rows=342)
154166
-> Index range scan on t0 using i1 over (key1 < 5) (rows=4)
155167
-> Index range scan on t0 using i3 over (key3 = 10) (rows=1)
156168

mysql-test/r/index_merge_myisam.result

Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,18 @@ INDEX i6(key6),
2323
INDEX i7(key7),
2424
INDEX i8(key8)
2525
);
26+
create procedure populate_t0()
27+
begin
28+
declare d int default 2;
29+
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
30+
while d<=POW(2,9) do
31+
insert into t0 select key1+d, key2+d, key3+d, key4+d, key5+d,
32+
key6+d, key7+d, key8-d from t0;
33+
set d = d*2;
34+
end while;
35+
end|
36+
call populate_t0();
37+
drop procedure populate_t0;
2638
analyze table t0;
2739
Table Op Msg_type Msg_text
2840
test.t0 analyze status OK

mysql-test/r/index_merge_myisam_hypergraph.result

Lines changed: 16 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,18 @@ INDEX i6(key6),
2323
INDEX i7(key7),
2424
INDEX i8(key8)
2525
);
26+
create procedure populate_t0()
27+
begin
28+
declare d int default 2;
29+
insert into t0 values (1,1,1,1,1,1,1,1023),(2,2,2,2,2,2,2,1022);
30+
while d<=POW(2,9) do
31+
insert into t0 select key1+d, key2+d, key3+d, key4+d, key5+d,
32+
key6+d, key7+d, key8-d from t0;
33+
set d = d*2;
34+
end while;
35+
end|
36+
call populate_t0();
37+
drop procedure populate_t0;
2638
analyze table t0;
2739
Table Op Msg_type Msg_text
2840
test.t0 analyze status OK
@@ -114,7 +126,7 @@ EXPLAIN
114126
# verify fallback to "range" if there is only one non-confluent condition
115127
explain select * from t0 where key2 = 45 or key1 <=> null;
116128
EXPLAIN
117-
-> Filter: ((t0.key2 = 45) or (t0.key1 <=> NULL)) (rows=103)
129+
-> Filter: ((t0.key2 = 45) or (t0.key1 <=> NULL)) (rows=1)
118130
-> Index range scan on t0 using i2 over (key2 = 45) (rows=1)
119131

120132
explain select * from t0 where key2 = 45 or key1 is not null;
@@ -128,7 +140,7 @@ EXPLAIN
128140
# the last conj. is always false and will be discarded
129141
explain select * from t0 where key2=10 or key3=3 or key4 <=> null;
130142
EXPLAIN
131-
-> Deduplicate rows sorted by row ID (rows=104)
143+
-> Deduplicate rows sorted by row ID (rows=2)
132144
-> Index range scan on t0 using i2 over (key2 = 10) (rows=1)
133145
-> Index range scan on t0 using i3 over (key3 = 3) (rows=1)
134146

@@ -143,14 +155,14 @@ EXPLAIN
143155
explain select key1 from t0 where (key1 <=> null) or (key2 < 2) or
144156
(key3=10) or (key4 <=> null);
145157
EXPLAIN
146-
-> Sort-deduplicate by row ID (rows=472)
158+
-> Sort-deduplicate by row ID (rows=342)
147159
-> Index range scan on t0 using i2 over (key2 < 2) (rows=2)
148160
-> Index range scan on t0 using i3 over (key3 = 10) (rows=1)
149161

150162
explain select key1 from t0 where (key1 <=> null) or (key1 < 5) or
151163
(key3=10) or (key4 <=> null);
152164
EXPLAIN
153-
-> Sort-deduplicate by row ID (rows=472)
165+
-> Sort-deduplicate by row ID (rows=342)
154166
-> Index range scan on t0 using i1 over (key1 < 5) (rows=5)
155167
-> Index range scan on t0 using i3 over (key3 = 10) (rows=1)
156168

0 commit comments

Comments
 (0)