Commit 22bc137c authored by unknown's avatar unknown

fix for bug #1724 'WHERE ... IN() optimizer behaviour

has changed since 4.0.14'
We need to calculate cost of RANGE
scan if it is present instead of cost of 
FULL scan.


mysql-test/r/order_by.result:
  more accurate row estimation
  for RANGE scan
mysql-test/r/range.result:
  added test case for bug #1724
  'WHERE ... IN() optimizer behaviour has changed since 4.0.14'
mysql-test/r/select.result:
  please ignore
mysql-test/t/range.test:
  added test case for bug #1724
  'WHERE ... IN() optimizer behaviour has changed since 4.0.14'
sql/sql_select.cc:
  fix for bug #1724 'WHERE ... IN() optimizer behaviour 
  has changed since 4.0.14'
  We need to calculate cost of RANGE
  scan instead of cost of FULL scan
  if RANGE is present
  Few comments cleaned up.
parent 15cc0ad2
......@@ -307,17 +307,17 @@ table type possible_keys key key_len ref rows Extra
t1 range a a 9 NULL 8 Using where; Using index
explain select * from t1 where a = 2 and b >0 order by a desc,b desc;
table type possible_keys key key_len ref rows Extra
t1 range a a 9 NULL 5 Using where; Using index
t1 range a a 9 NULL 4 Using where; Using index
explain select * from t1 where a = 2 and b is null order by a desc,b desc;
table type possible_keys key key_len ref rows Extra
t1 ref a a 9 const,const 1 Using where; Using index; Using filesort
explain select * from t1 where a = 2 and (b is null or b > 0) order by a
desc,b desc;
table type possible_keys key key_len ref rows Extra
t1 range a a 9 NULL 6 Using where; Using index
t1 range a a 9 NULL 5 Using where; Using index
explain select * from t1 where a = 2 and b > 0 order by a desc,b desc;
table type possible_keys key key_len ref rows Extra
t1 range a a 9 NULL 5 Using where; Using index
t1 range a a 9 NULL 4 Using where; Using index
explain select * from t1 where a = 2 and b < 2 order by a desc,b desc;
table type possible_keys key key_len ref rows Extra
t1 range a a 9 NULL 2 Using where; Using index
......
......@@ -273,3 +273,20 @@ table type possible_keys key key_len ref rows Extra
t2 ref j1 j1 4 const 1 Using where; Using index
t1 ALL i2 NULL NULL NULL 4 Range checked for each record (index map: 2)
DROP TABLE t1,t2;
CREATE TABLE t1 (
a int(11) default NULL,
b int(11) default NULL,
KEY a (a),
KEY b (b)
) TYPE=MyISAM;
INSERT INTO t1 VALUES
(1,1),(2,1),(3,1),(4,1),(5,1),(6,1),(7,1),(8,1),(9,1),(10,2),(10,2),
(13,2),(14,2),(15,2),(16,2),(17,3),(17,3),(16,3),(17,3),(19,3),(20,3),
(21,4),(22,5),(23,5),(24,5),(25,5),(26,5),(30,5),(31,5),(32,5),(33,5),
(33,5),(33,5),(33,5),(33,5),(34,5),(35,5);
EXPLAIN SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
table type possible_keys key key_len ref rows Extra
t1 range a,b a 5 NULL 2 Using where
SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
a b
DROP TABLE t1;
......@@ -2136,10 +2136,10 @@ a a a
select * from (t1 as t2 left join t1 as t3 using (a)) inner join t1 on t1.a>1;
a a a
1 1 2
2 2 2
3 3 2
1 1 3
2 2 2
2 2 3
3 3 2
3 3 3
select * from t1 inner join (t1 as t2 left join t1 as t3 using (a)) on t1.a>1;
a a a
......
......@@ -214,3 +214,26 @@ explain select * from t1, t2 where (t1.key1 <t2.keya + 1) and t2.keya=3;
explain select * from t1 force index(i2), t2 where (t1.key1 <t2.keya + 1) and t2.keya=3;
DROP TABLE t1,t2;
# bug #1724: use RANGE on more selective column instead of REF on less
# selective
CREATE TABLE t1 (
a int(11) default NULL,
b int(11) default NULL,
KEY a (a),
KEY b (b)
) TYPE=MyISAM;
INSERT INTO t1 VALUES
(1,1),(2,1),(3,1),(4,1),(5,1),(6,1),(7,1),(8,1),(9,1),(10,2),(10,2),
(13,2),(14,2),(15,2),(16,2),(17,3),(17,3),(16,3),(17,3),(19,3),(20,3),
(21,4),(22,5),(23,5),(24,5),(25,5),(26,5),(30,5),(31,5),(32,5),(33,5),
(33,5),(33,5),(33,5),(33,5),(34,5),(35,5);
EXPLAIN SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
DROP TABLE t1;
# we expect that optimizer will choose key on A
......@@ -2145,8 +2145,6 @@ find_best(JOIN *join,table_map rest_tables,uint idx,double record_count,
!(s->table->force_index && best_key))
{ // Check full join
ha_rows rnd_records= s->found_records;
/* Estimate cost of reading table. */
tmp= s->table->file->scan_time();
/*
If there is a restriction on the table, assume that 25% of the
rows can be skipped on next part.
......@@ -2156,15 +2154,35 @@ find_best(JOIN *join,table_map rest_tables,uint idx,double record_count,
if (found_constraint)
rnd_records-= rnd_records/4;
if (s->on_expr) // Can't use join cache
/*
Range optimizer never proposes a RANGE if it isn't better
than FULL: so if RANGE is present, it's always preferred to FULL.
Here we estimate its cost.
*/
if (s->quick)
{
/*
For each record we:
- read record range through 'quick'
- skip rows which does not satisfy WHERE constraints
*/
tmp= record_count *
/* We have to read the whole table for each record */
(tmp +
(s->quick->read_time +
(s->found_records - rnd_records)/(double) TIME_FOR_COMPARE);
}
else
{
/* Estimate cost of reading table. */
tmp= s->table->file->scan_time();
if (s->on_expr) // Can't use join cache
{
/*
And we have to skip rows which does not satisfy join
condition for each record.
For each record we have to:
- read the whole table record
- skip rows which does not satisfy join condition
*/
tmp= record_count *
(tmp +
(s->records - rnd_records)/(double) TIME_FOR_COMPARE);
}
else
......@@ -2182,10 +2200,11 @@ find_best(JOIN *join,table_map rest_tables,uint idx,double record_count,
*/
tmp+= (s->records - rnd_records)/(double) TIME_FOR_COMPARE;
}
}
/*
We estimate the cost of evaluating WHERE clause for found records
as record_count * rnd_records + TIME_FOR_COMPARE. This cost plus
as record_count * rnd_records / TIME_FOR_COMPARE. This cost plus
tmp give us total cost of using TABLE SCAN
*/
if (best == DBL_MAX ||
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment