diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 009ae8776c3..48e01d8dd6f 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -544,4 +544,56 @@ id c counter 3 b 2 4 a 2 drop table t1; +CREATE TABLE t1( +id int AUTO_INCREMENT PRIMARY KEY, +stat_id int NOT NULL, +acct_id int DEFAULT NULL, +INDEX idx1 (stat_id, acct_id), +INDEX idx2 (acct_id) +) ENGINE=MyISAM; +CREATE TABLE t2( +id int AUTO_INCREMENT PRIMARY KEY, +stat_id int NOT NULL, +acct_id int DEFAULT NULL, +INDEX idx1 (stat_id, acct_id), +INDEX idx2 (acct_id) +) ENGINE=InnoDB; +INSERT INTO t1(stat_id,acct_id) VALUES +(1,759), (2,831), (3,785), (4,854), (1,921), +(1,553), (2,589), (3,743), (2,827), (2,545), +(4,779), (4,783), (1,597), (1,785), (4,832), +(1,741), (1,833), (3,788), (2,973), (1,907); +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +UPDATE t1 SET acct_id=785 +WHERE MOD(stat_id,2)=0 AND MOD(id,stat_id)=MOD(acct_id,stat_id); +OPTIMIZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 optimize status OK +SELECT COUNT(*) FROM t1; +COUNT(*) +40960 +SELECT COUNT(*) FROM t1 WHERE acct_id=785; +COUNT(*) +8702 +EXPLAIN SELECT COUNT(*) FROM t1 WHERE stat_id IN (1,3) AND acct_id=785; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range idx1,idx2 idx1 9 NULL 2 Using where; Using index +INSERT INTO t2 SELECT * FROM t1; +OPTIMIZE TABLE t2; +Table Op Msg_type Msg_text +test.t2 optimize status OK +EXPLAIN SELECT COUNT(*) FROM t2 WHERE stat_id IN (1,3) AND acct_id=785; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range idx1,idx2 idx1 9 NULL 2 Using where; Using index +DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index c9e1de8c3ab..90f9047291c 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -518,4 +518,58 @@ select * from t1; drop table t1; +# +# Bug #28189: optimizer erroniously prefers ref access to range access +# for an InnoDB table +# + +CREATE TABLE t1( + id int AUTO_INCREMENT PRIMARY KEY, + stat_id int NOT NULL, + acct_id int DEFAULT NULL, + INDEX idx1 (stat_id, acct_id), + INDEX idx2 (acct_id) +) ENGINE=MyISAM; + +CREATE TABLE t2( + id int AUTO_INCREMENT PRIMARY KEY, + stat_id int NOT NULL, + acct_id int DEFAULT NULL, + INDEX idx1 (stat_id, acct_id), + INDEX idx2 (acct_id) +) ENGINE=InnoDB; + +INSERT INTO t1(stat_id,acct_id) VALUES + (1,759), (2,831), (3,785), (4,854), (1,921), + (1,553), (2,589), (3,743), (2,827), (2,545), + (4,779), (4,783), (1,597), (1,785), (4,832), + (1,741), (1,833), (3,788), (2,973), (1,907); + +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +INSERT INTO t1(stat_id,acct_id) SELECT stat_id, mod(id+100000, acct_id) FROM t1; +UPDATE t1 SET acct_id=785 + WHERE MOD(stat_id,2)=0 AND MOD(id,stat_id)=MOD(acct_id,stat_id); +OPTIMIZE TABLE t1; + +SELECT COUNT(*) FROM t1; +SELECT COUNT(*) FROM t1 WHERE acct_id=785; + +EXPLAIN SELECT COUNT(*) FROM t1 WHERE stat_id IN (1,3) AND acct_id=785; + +INSERT INTO t2 SELECT * FROM t1; +OPTIMIZE TABLE t2; + +EXPLAIN SELECT COUNT(*) FROM t2 WHERE stat_id IN (1,3) AND acct_id=785; + +DROP TABLE t1,t2; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 3a480c01ac1..967322600a7 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -4189,7 +4189,7 @@ best_access_path(JOIN *join, !(s->quick && best_key && s->quick->index == best_key->key && // (2) best_max_key_part >= s->table->quick_key_parts[best_key->key]) &&// (2) !((s->table->file->table_flags() & HA_TABLE_SCAN_ON_INDEX) && // (3) - ! s->table->used_keys.is_clear_all() && best_key) && // (3) + ! s->table->used_keys.is_clear_all() && best_key && !s->quick) &&// (3) !(s->table->force_index && best_key && !s->quick)) // (4) { // Check full join ha_rows rnd_records= s->found_records;