Skip to content

Commit

Permalink
Updated optimizer costs in multi_range_read_info_const() and sql_sele…
Browse files Browse the repository at this point in the history
…ct.cc

- multi_range_read_info_const now uses the new records_in_range interface
- Added handler::avg_io_cost()
- Don't calculate avg_io_cost() in get_sweep_read_cost if avg_io_cost is
  not 1.0.  In this case we trust the avg_io_cost() from the handler.
- Changed test_quick_select to use TIME_FOR_COMPARE instead of
  TIME_FOR_COMPARE_IDX to align this with the rest of the code.
- Fixed bug when using test_if_cheaper_ordering where we didn't use
  keyread if index was changed
- Fixed a bug where we didn't use index only read when using order-by-index
- Added keyread_time() to HEAP.
  The default keyread_time() was optimized for blocks and not suitable for
  HEAP. The effect was the HEAP prefered table scans over ranges for btree
  indexes.
- Fixed get_sweep_read_cost() for HEAP tables
- Ensure that range and ref have same cost for simple ranges
  Added a small cost (MULTI_RANGE_READ_SETUP_COST) to ranges to ensure
  we favior ref for range for simple queries.
- Fixed that matching_candidates_in_table() uses same number of records
  as the rest of the optimizer
- Added avg_io_cost() to JT_EQ_REF cost. This helps calculate the cost for
  HEAP and temporary tables better. A few tests changed because of this.
- heap::read_time() and heap::keyread_time() adjusted to not add +1.
  This was to ensure that handler::keyread_time() doesn't give
  higher cost for heap tables than for normal tables. One effect of
  this is that heap and derived tables stored in heap will prefer
  key access as this is now regarded as cheap.
- Changed cost for index read in sql_select.cc to match
  multi_range_read_info_const(). All index cost calculation is now
  done trough one function.
- 'ref' will now use quick_cost for keys if it exists. This is done
  so that for '=' ranges, 'ref' is prefered over 'range'.
- scan_time() now takes avg_io_costs() into account
- get_delayed_table_estimates() uses block_size and avg_io_cost()
- Removed default argument to test_if_order_by_key(); simplifies code
  • Loading branch information
montywi committed Mar 27, 2020
1 parent b3ab310 commit eb483c5
Show file tree
Hide file tree
Showing 158 changed files with 1,686 additions and 1,365 deletions.
1 change: 0 additions & 1 deletion include/my_base.h
Original file line number Diff line number Diff line change
Expand Up @@ -615,7 +615,6 @@ enum data_file_type {
#define EQ_RANGE 32U
#define NULL_RANGE 64U
#define GEOM_FLAG 128U
#define SKIP_RANGE 256U

typedef struct st_key_range
{
Expand Down
4 changes: 4 additions & 0 deletions mysql-test/include/icp_tests.inc
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
--source include/have_sequence.inc

--echo #
--echo # Bug#36981 - "innodb crash when selecting for update"
--echo #
Expand Down Expand Up @@ -721,10 +723,12 @@ DROP TABLE t1;

CREATE TABLE t1 (b int NOT NULL, c int, a varchar(1024), PRIMARY KEY (b));
INSERT INTO t1 VALUES (1,4,'Ill');
insert into t1 select seq+100,5,seq from seq_1_to_100;

CREATE TABLE t2 (a varchar(1024), KEY (a(512)));
INSERT INTO t2 VALUES
('Ill'), ('eckqzsflbzaffti'), ('w'), ('she'), ('gxbwypqtjzwywwer'), ('w');
insert into t2 select seq from seq_1_to_100;

SET SESSION optimizer_switch='index_condition_pushdown=off';
EXPLAIN
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/include/index_merge1.inc
Original file line number Diff line number Diff line change
Expand Up @@ -182,7 +182,7 @@ alter table t2 add index i321(key3, key2, key1);
explain select key3 from t2 where key1 = 100 or key2 = 100;

# index_merge vs 'index', 'index' is better.
explain select key3 from t2 where key1 < 500 or key2 < 500;
explain select key3 from t2 where key1 < 600 or key2 < 600;

# index_merge vs 'all', index_merge is better.
explain select key7 from t2 where key1 <100 or key2 < 100;
Expand Down
30 changes: 15 additions & 15 deletions mysql-test/main/cte_nonrecursive.result
Original file line number Diff line number Diff line change
Expand Up @@ -1159,27 +1159,27 @@ with cte as
union
(select a from t1 where a < 2);
a
1
4
5
7
1
prepare stmt from "with cte as
(select a from t1 where a between 4 and 7 group by a)
(select a from cte where exists( select a from t1 where cte.a=t1.a ))
union
(select a from t1 where a < 2)";
execute stmt;
a
1
4
5
7
1
execute stmt;
a
1
4
5
7
1
deallocate prepare stmt;
with cte as
(select a from t1 where a between 4 and 7 group by a)
Expand Down Expand Up @@ -1216,9 +1216,9 @@ union
(select a from cte where exists( select a from t1 where cte.a=t1.a ));
a
1
7
5
4
5
7
prepare stmt from "with cte as
(select a from t1 where a between 4 and 7)
(select a from t1 where a < 2)
Expand All @@ -1227,15 +1227,15 @@ union
execute stmt;
a
1
7
5
4
5
7
execute stmt;
a
1
7
5
4
5
7
deallocate prepare stmt;
with cte as
(select a from t1 where a between 4 and 7)
Expand All @@ -1244,9 +1244,9 @@ where exists( select a from t1 where t1.a < 2 and cte.a=t1.a ))
union
(select a from cte where exists( select a from t1 where cte.a=t1.a ));
a
7
5
4
5
7
prepare stmt from "with cte as
(select a from t1 where a between 4 and 7)
(select a from cte
Expand All @@ -1255,14 +1255,14 @@ union
(select a from cte where exists( select a from t1 where cte.a=t1.a ))";
execute stmt;
a
7
5
4
5
7
execute stmt;
a
7
5
4
5
7
deallocate prepare stmt;
drop table t1;
#
Expand Down
12 changes: 12 additions & 0 deletions mysql-test/main/cte_nonrecursive.test
Original file line number Diff line number Diff line change
Expand Up @@ -808,9 +808,12 @@ with cte as
union
(select a from t1 where a < 2);

--sorted_result
eval $q1;
eval prepare stmt from "$q1";
--sorted_result
execute stmt;
--sorted_result
execute stmt;
deallocate prepare stmt;

Expand All @@ -821,9 +824,12 @@ with cte as
union
(select a from cte where exists( select a from t1 where cte.a=t1.a ));

--sorted_result
eval $q2;
eval prepare stmt from "$q2";
--sorted_result
execute stmt;
--sorted_result
execute stmt;
deallocate prepare stmt;

Expand All @@ -834,9 +840,12 @@ with cte as
union
(select a from cte where exists( select a from t1 where cte.a=t1.a ));

--sorted_result
eval $q3;
eval prepare stmt from "$q3";
--sorted_result
execute stmt;
--sorted_result
execute stmt;
deallocate prepare stmt;

Expand All @@ -848,9 +857,12 @@ with cte as
union
(select a from cte where exists( select a from t1 where cte.a=t1.a ));

--sorted_result
eval $q4;
eval prepare stmt from "$q4";
--sorted_result
execute stmt;
--sorted_result
execute stmt;
deallocate prepare stmt;

Expand Down
4 changes: 2 additions & 2 deletions mysql-test/main/ctype_ucs.result
Original file line number Diff line number Diff line change
Expand Up @@ -1569,7 +1569,7 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range a a 23 NULL 1 Using where; Using index
EXPLAIN SELECT * FROM t1 WHERE a LIKE 'c%';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index a a 23 NULL 31 Using where; Using index
1 SIMPLE t1 range a a 23 NULL 31 Using where; Using index
SELECT * FROM t1 WHERE a LIKE 'c%';
a
ca
Expand All @@ -1585,7 +1585,7 @@ ch
ALTER TABLE t1 MODIFY a VARCHAR(10) CHARACTER SET ucs2 COLLATE ucs2_croatian_ci;
EXPLAIN SELECT * FROM t1 WHERE a LIKE 'd%';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index a a 23 NULL 31 Using where; Using index
1 SIMPLE t1 range a a 23 NULL 31 Using where; Using index
SELECT hex(concat('d',_ucs2 0x017E,'%'));
hex(concat('d',_ucs2 0x017E,'%'))
0064017E0025
Expand Down
15 changes: 9 additions & 6 deletions mysql-test/main/derived.result
Original file line number Diff line number Diff line change
Expand Up @@ -324,11 +324,11 @@ create table t2 (a int, b int, primary key (a));
insert into t2 values (1,7),(2,7);
explain select a from t2 where a>1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index PRIMARY PRIMARY 4 NULL 2 Using where; Using index
1 SIMPLE t2 range PRIMARY PRIMARY 4 NULL 1 Using where; Using index
explain select a from (select a from t2 where a>1) tt;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2
2 DERIVED t2 index PRIMARY PRIMARY 4 NULL 2 Using where; Using index
2 DERIVED t2 range PRIMARY PRIMARY 4 NULL 1 Using where; Using index
drop table t2;
CREATE TABLE `t1` ( `itemid` int(11) NOT NULL default '0', `grpid` varchar(15) NOT NULL default '', `vendor` int(11) NOT NULL default '0', `date_` date NOT NULL default '0000-00-00', `price` decimal(12,2) NOT NULL default '0.00', PRIMARY KEY (`itemid`,`grpid`,`vendor`,`date_`), KEY `itemid` (`itemid`,`vendor`), KEY `itemid_2` (`itemid`,`date_`));
insert into t1 values (128, 'rozn', 2, curdate(), 10),
Expand Down Expand Up @@ -1064,16 +1064,19 @@ INSERT INTO t2 VALUES (NULL),(NULL);
CREATE TABLE t3 (c VARCHAR(1024) CHARACTER SET utf8, d INT) ENGINE=MyISAM;
CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v3 AS SELECT * FROM t3;
INSERT INTO t3 VALUES ('abc',NULL),('def',4);
INSERT INTO t1 select seq from seq_1_to_1000;
INSERT INTO t2 select seq+1000 from seq_1_to_1000;
INSERT INTO t3 select 'qqq',seq+2000 from seq_1_to_1000;
set @save_join_cache_level= @@join_cache_level;
SET join_cache_level= 8;
explain
SELECT * FROM v1, t2, v3 WHERE a = c AND b = d;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2
1 PRIMARY <derived3> hash_ALL NULL #hash#$hj 3075 func 2 Using where; Using join buffer (flat, BNLH join)
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 1002
1 PRIMARY <derived3> hash_ALL NULL #hash#$hj 3075 func 1002 Using where; Using join buffer (flat, BNLH join)
1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 v3.d 1 Using index
3 DERIVED t3 ALL NULL NULL NULL NULL 2
2 DERIVED t1 ALL NULL NULL NULL NULL 2
3 DERIVED t3 ALL NULL NULL NULL NULL 1002
2 DERIVED t1 ALL NULL NULL NULL NULL 1002
SELECT * FROM v1, t2, v3 WHERE a = c AND b = d;
a b c d
DROP VIEW v1, v3;
Expand Down
4 changes: 4 additions & 0 deletions mysql-test/main/derived.test
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
# Initialize
--source include/default_optimizer_switch.inc
--source include/have_sequence.inc

--disable_warnings
drop table if exists t1,t2,t3;
Expand Down Expand Up @@ -919,6 +920,9 @@ INSERT INTO t2 VALUES (NULL),(NULL);
CREATE TABLE t3 (c VARCHAR(1024) CHARACTER SET utf8, d INT) ENGINE=MyISAM;
CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v3 AS SELECT * FROM t3;
INSERT INTO t3 VALUES ('abc',NULL),('def',4);
INSERT INTO t1 select seq from seq_1_to_1000;
INSERT INTO t2 select seq+1000 from seq_1_to_1000;
INSERT INTO t3 select 'qqq',seq+2000 from seq_1_to_1000;

set @save_join_cache_level= @@join_cache_level;
SET join_cache_level= 8;
Expand Down
Loading

0 comments on commit eb483c5

Please sign in to comment.