Skip to content

Commit

Permalink
Update row and key fetch cost models to take into account data copy c…
Browse files Browse the repository at this point in the history
…osts

Before this patch, when calculating the cost of fetching and using a
row/key from the engine, we took into account the cost of finding a
row or key from the engine, but did not consistently take into account
index only accessed, clustered key or covered keys for all access
paths.

The cost of the WHERE clause (TIME_FOR_COMPARE) was not consistently
considered in best_access_path().  TIME_FOR_COMPARE was used in
calculation in other places, like greedy_search(), but was in some
cases (like scans) done an a different number of rows than was
accessed.

The cost calculation of row and index scans didn't take into account
the number of rows that where accessed, only the number of accepted
rows.

When using a filter, the cost of index_only_reads and cost of
accessing and disregarding 'filtered rows' where not taken into
account, which made filters cost less than there actually where.

To remedy the above, the following key & row fetch related costs
has been added:

- The cost of fetching and using a row is now split into different costs:
  - key + Row fetch cost (as before) but multiplied with the variable
  'optimizer_cache_cost' (default to 0.5). This allows the user to
  tell the optimizer the likehood of finding the key and row in the
  engine cache.
- ROW_COPY_COST, The cost copying a row from the engine to the
  sql layer or creating a row from the join_cache to the record
  buffer. Mostly affects table scan costs.
- ROW_LOOKUP_COST, the cost of fetching a row by rowid.
- KEY_COPY_COST the cost of finding the next key and copying it from
  the engine to the SQL layer. This is used when we calculate the cost
  index only reads. It makes index scans more expensive than before if
  they cover a lot of rows. (main.index_merge_myisam)
- KEY_LOOKUP_COST, the cost of finding the first key in a range.
  This replaces the old define IDX_LOOKUP_COST, but with a higher cost.
- KEY_NEXT_FIND_COST, the cost of finding the next key (and rowid).
  when doing a index scan and comparing the rowid to the filter.
  Before this cost was assumed to be 0.

All of the above constants/variables are now tuned to be somewhat in
proportion of executing complexity to each other.  There is tuning
need for these in the future, but that can wait until the above are
made user variables as that will make tuning much easier.

To make the usage of the above easy, there are new (not virtual)
cost calclation functions in handler:
- ha_read_time(), like read_time(), but take optimizer_cache_cost into
  account.
- ha_read_and_copy_time(), like ha_read_time() but take into account
  ROW_COPY_TIME
- ha_read_and_compare_time(), like ha_read_and_copy_time() but take
  TIME_FOR_COMPARE into account.
- ha_rnd_pos_time(). Read row with row id, taking ROW_COPY_COST
  into account.  This is used with filesort where we don't need
  to execute the WHERE clause again.
- ha_keyread_time(), like keyread_time() but take
  optimizer_cache_cost into account.
- ha_keyread_and_copy_time(), like ha_keyread_time(), but add
  KEY_COPY_COST.
- ha_key_scan_time(), like key_scan_time() but take
  optimizer_cache_cost nto account.
- ha_key_scan_and_compare_time(), like ha_key_scan_time(), but add
  KEY_COPY_COST & TIME_FOR_COMPARE.

I also added some setup costs for doing different types of scans and
creating temporary tables (on disk and in memory). This encourages
the optimizer to not use these for simple 'a few row' lookups if
there are adequate key lookup strategies.
- TABLE_SCAN_SETUP_COST, cost of starting a table scan.
- INDEX_SCAN_SETUP_COST, cost of starting an index scan.
- HEAP_TEMPTABLE_CREATE_COST, cost of creating in memory
  temporary table.
- DISK_TEMPTABLE_CREATE_COST, cost of creating an on disk temporary
  table.

When calculating cost of fetching ranges, we had a cost of
IDX_LOOKUP_COST (0.125) for doing a key div for a new range. This is
now replaced with 'io_cost * KEY_LOOKUP_COST (1.0) *
optimizer_cache_cost', which matches the cost we use for 'ref' and
other key lookups. The effect is that the cost is now a bit higher
when we have many ranges for a key.

Allmost all calculation with TIME_FOR_COMPARE is now done in
best_access_path(). 'JOIN::read_time' now includes the full
cost for finding the rows in the table.

In the result files, many of the changes are now again close to what
they where before the "Update cost for hash and cached joins" commit,
as that commit didn't fix the filter cost (too complex to do
everything in one commit).

The above changes showed a lot of a lot of inconsistencies in
optimizer cost calculation. The main objective with the other changes
was to do calculation as similar (and accurate) as possible and to make
different plans more comparable.

Detailed list of changes:

- Calculate index_only_cost consistently and correctly for all scan
  and ref accesses. The row fetch_cost and index_only_cost now
  takes into account clustered keys, covered keys and index
  only accesses.
- cost_for_index_read now returns both full cost and index_only_cost
- Fixed cost calculation of get_sweep_read_cost() to match other
  similar costs. This is bases on the assumption that data is more
  often stored on SSD than a hard disk.
- Replaced constant 2.0 with new define TABLE_SCAN_SETUP_COST.
- Some scan cost estimates did not take into account
  TIME_FOR_COMPARE. Now all scan costs takes this into
  account. (main.show_explain)
- Added session variable optimizer_cache_hit_ratio (default 50%). By
  adjusting this on can reduce or increase the cost of index or direct
  record lookups. The effect of the default is that key lookups is now
  a bit cheaper than before. See usage of 'optimizer_cache_cost' in
  handler.h.
- JOIN_TAB::scan_time() did not take into account index only scans,
  which produced a wrong cost when index scan was used. Changed
  JOIN_TAB:::scan_time() to take into consideration clustered and
  covered keys. The values are now cached and we only have to call
  this function once. Other calls are changed to use the cached
  values.  Function renamed to JOIN_TAB::estimate_scan_time().
- Fixed that most index cost calculations are done the same way and
  more close to 'range' calculations. The cost is now lower than
  before for small data sets and higher for large data sets as we take
  into account how many keys are read (main.opt_trace_selectivity,
  main.limit_rows_examined).
- Ensured that index_scan_cost() ==
  range(scan_of_all_rows_in_table_using_one_range) +
  MULTI_RANGE_READ_INFO_CONST. One effect of this is that if there
  is choice of doing a full index scan and a range-index scan over
  almost the whole table then index scan will be preferred (no
  range-read setup cost).  (innodb.innodb, main.show_explain,
  main.range)
  - Fixed the EQ_REF and REF takes into account clustered and covered
    keys.  This changes some plans to use covered or clustered indexes
    as these are much cheaper.  (main.subselect_mat_cost,
    main.state_tables_innodb, main.limit_rows_examined)
  - Rowid filter setup cost and filter compare cost now takes into
    account fetching and checking the rowid (KEY_NEXT_FIND_COST).
    (main.partition_pruning heap.heap_btree main.log_state)
  - Added KEY_NEXT_FIND_COST to
    Range_rowid_filter_cost_info::lookup_cost to account of the time
    to find and check the next key value against the container
  - Introduced ha_keyread_time(rows) that takes into account finding
    the next row and copying the key value to 'record'
    (KEY_COPY_COST).
  - Introduced ha_key_scan_time() for calculating an index scan over
    all rows.
  - Added IDX_LOOKUP_COST to keyread_time() as a startup cost.
  - Added index_only_fetch_cost() as a convenience function to
    OPT_RANGE.
  - keyread_time() cost is slightly reduced to prefer shorter keys.
    (main.index_merge_myisam)
  - All of the above caused some index_merge combinations to be
    rejected because of cost (main.index_intersect). In some cases
    'ref' where replaced with index_merge because of the low
    cost calculation of get_sweep_read_cost().
  - Some index usage moved from PRIMARY to a covering index.
    (main.subselect_innodb)
- Changed cost calculation of filter to take KEY_LOOKUP_COST and
  TIME_FOR_COMPARE into account.  See sql_select.cc::apply_filter().
  filter parameters and costs are now written to optimizer_trace.
- Don't use matchings_records_in_range() to try to estimate the number
  of filtered rows for ranges. The reason is that we want to ensure
  that 'range' is calculated similar to 'ref'. There is also more work
  needed to calculate the selectivity when using ranges and ranges and
  filtering.  This causes filtering column in EXPLAIN EXTENDED to be
  100.00 for some cases where range cannot use filtering.
  (main.rowid_filter)
- Introduced ha_scan_time() that takes into account the CPU cost of
  finding the next row and copying the row from the engine to
  'record'. This causes costs of table scan to slightly increase and
  some test to changed their plan from ALL to RANGE or ALL to ref.
  (innodb.innodb_mysql, main.select_pkeycache)
  In a few cases where scan time of very small tables have lower cost
  than a ref or range, things changed from ref/range to ALL.
  (main.myisam, main.func_group, main.limit_rows_examined,
  main.subselect2)
- Introduced ha_scan_and_compare_time() which is like ha_scan_time()
  but also adds the cost of the where clause (TIME_FOR_COMPARE).
- Added small cost for creating temporary table for
  materialization. This causes some very small tables to use scan
  instead of materialization.
- Added checking of the WHERE clause (TIME_FOR_COMPARE) of the
  accepted rows to ROR costs in get_best_ror_intersect()
- Removed '- 0.001' from 'join->best_read' and optimize_straight_join()
  to ensure that the 'Last_query_cost' status variable contains the
  same value as the one that was calculated by the optimizer.
- Take avg_io_cost() into account in handler::keyread_time() and
  handler::read_time(). This should have no effect as it's 1.0 by
  default, except for heap that overrides these functions.
- Some 'ref_or_null' accesses changed to 'range' because of cost
  adjustments (main.order_by)
- Added scan type "scan_with_join_cache" for optimizer_trace. This is
  just to show in the trace what kind of scan was used.
- When using 'scan_with_join_cache' take into account number of
  preceding tables (as have to restore all fields for all previous
  table combination when checking the where clause)
  The new cost added is:
  (row_combinations * ROW_COPY_COST * number_of_cached_tables).
  This increases the cost of join buffering in proportion of the
  number of tables in the join buffer. One effect is that full scans
  are now done earlier as the cost is then smaller.
  (main.join_outer_innodb, main.greedy_optimizer)
- Removed the usage of 'worst_seeks' in cost_for_index_read as it
  caused wrong plans to be created; It prefered JT_EQ_REF even if it
  would be much more expensive than a full table scan. A related
  issue was that worst_seeks only applied to full lookup, not to
  clustered or index only lookups, which is not consistent. This
  caused some plans to use index scan instead of eq_ref (main.union)
- Changed federated block size from 4096 to 1500, which is the
  typical size of an IO packet.
- Added costs for reading rows to Federated. Needed as there is no
  caching of rows in the federated engine.
- Added ha_innobase::rnd_pos_time() cost function.
- A lot of extra things added to optimizer trace
  - More costs, especially for materialization and index_merge.
  - Make lables more uniform
  - Fixed a lot of minor bugs
  - Added 'trace_started()' around a lot of trace blocks.
- When calculating ORDER BY with LIMIT cost for using an index
  the cost did not take into account the number of row retrivals
  that has to be done or the cost of comparing the rows with the
  WHERE clause. The cost calculated would be just a fraction of
  the real cost. Now we calculate the cost as we do for ranges
  and 'ref'.
- 'Using index for group-by' is used a bit more than before as
  now take into account the WHERE clause cost when comparing
  with 'ref' and prefer the method with fewer row combinations.
  (main.group_min_max).

Bugs fixed:
- Fixed that we don't calculate TIME_FOR_COMPARE twice for some plans,
  like in optimize_straight_join() and greedy_search()
- Fixed bug in save_explain_data where we could test for the wrong
  index when displaying 'Using index'. This caused some old plans to
  show 'Using index'.  (main.subselect_innodb, main.subselect2)
- Fixed bug in get_best_ror_intersect() where 'min_cost' was not
  updated, and the cost we compared with was not the one that was
  used.
- Fixed very wrong cost calculation for priority queues in
  check_if_pq_applicable(). (main.order_by now correctly uses priority
  queue)
- When calculating cost of EQ_REF or REF, we added the cost of
  comparing the WHERE clause with the found rows, not all row
  combinations. This made ref and eq_ref to be regarded way to cheap
  compared to other access methods.
- FORCE INDEX cost calculation didn't take into account clustered or
  covered indexes.
- JT_EQ_REF cost was estimated as avg_io_cost(), which is half the
  cost of a JT_REF key. This may be true for InnoDB primary key, but
  not for other unique keys or other engines. Now we use handler
  function to calculate the cost, which allows us to handle
  consistently clustered, covered keys and not covered keys.
- ha_start_keyread() didn't call extra_opt() if keyread was already
  enabled but still changed the 'keyread' variable (which is wrong).
  Fixed by not doing anything if keyread is already enabled.
- multi_range_read_info_cost() didn't take into account io_cost when
  calculating the cost of ranges.
- fix_semijoin_strategies_for_picked_join_order() used the wrong
  record_count when calling best_access_path() for SJ_OPT_FIRST_MATCH
  and SJ_OPT_LOOSE_SCAN.
- Hash joins didn't provide correct best_cost to the upper level, which
  means that the cost for hash_joins more expensive than calculated
  in best_access_path (a difference of 10x * TIME_OF_COMPARE).
  This is fixed in the new code thanks to that we now include
  TIME_OF_COMPARE cost in 'read_time'.

Other things:
- Added some 'if (thd->trace_started())' to speed up code
- Removed not used function Cost_estimate::is_zero()
- Simplified testing of HA_POS_ERROR in get_best_ror_intersect().
  (No cost changes)
- Moved ha_start_keyread() from join_read_const_table() to join_read_const()
  to enable keyread for all types of JT_CONST tables.
- Made a few very short functions inline in handler.h

Notes:
- In main.rowid_filter the join order of order and lineitem is swapped.
  This is because the cost of doing a range fetch of lineitem(98 rows) is
  almost as big as the whole join of order,lineitem. The filtering will
  also ensure that we only have to do very small key fetches of the rows
  in lineitem.
- main.index_merge_myisam had a few changes where we are now using
  less keys for index_merge. This is because index scans are now more
  expensive than before.
- handler->optimizer_cache_cost is updated in ha_external_lock().
  This ensures that it is up to date per statements.
  Not an optimal solution (for locked tables), but should be ok for now.
- 'DELETE FROM t1 WHERE t1.a > 0 ORDER BY t1.a' does not take cost of
  filesort into consideration when table scan is chosen.
  (main.myisam_explain_non_select_all)
- perfschema.table_aggregate_global_* has changed because an update
  on a table with 1 row will now use table scan instead of key lookup.

TODO in upcomming commits:
- Fix selectivity calculation for ranges with and without filtering and
  when there is a ref access but scan is chosen.
  For this we have to store the lowest known value for
  'accepted_records' in the OPT_RANGE structure.
- Change that records_read does not include filtered rows.
- test_if_cheaper_ordering() needs to be updated to properly calculate
  costs. This will fix tests like main.order_by_innodb,
  main.single_delete_update
- Extend get_range_limit_read_cost() to take into considering
  cost_for_index_read() if there where no quick keys. This will reduce
  the computed cost for ORDER BY with LIMIT in some cases.
  (main.innodb_ext_key)
- Fix that we take into account selectivity when counting the number
  of rows we have to read when considering using a index table scan to
  resolve ORDER BY.
- Add new calculation for rnd_pos_time() where we take into account the
  benefit of reading multiple rows from the same page.
  • Loading branch information
montywi authored and spetrunia committed Feb 2, 2023
1 parent 034aeda commit b6215b9
Show file tree
Hide file tree
Showing 243 changed files with 9,297 additions and 6,808 deletions.
1 change: 1 addition & 0 deletions mysql-test/include/ctype_numconv.inc
Original file line number Diff line number Diff line change
Expand Up @@ -1739,6 +1739,7 @@ CREATE TABLE t1 (
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
ALTER TABLE t1 MODIFY date_column DATETIME DEFAULT NULL;
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
Expand Down
5 changes: 5 additions & 0 deletions mysql-test/include/last_query_cost.inc
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
--disable_query_log
--disable_column_names
show status like 'last_query_cost';
--enable_column_names
--enable_query_log
2 changes: 2 additions & 0 deletions mysql-test/include/world.inc
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@

# Table Country

BEGIN;
INSERT IGNORE INTO Country VALUES
('AFG','Afghanistan',652090.00,22720000,1),
('NLD','Netherlands',41526.00,15864000,5),
Expand Down Expand Up @@ -5339,5 +5340,6 @@ INSERT INTO CountryLanguage VALUES
('CHN','Dong',0.2),
('RUS','Belorussian',0.3),
('USA','Portuguese',0.2);
COMMIT;

ANALYZE TABLE Country, City, CountryLanguage;
91 changes: 91 additions & 0 deletions mysql-test/main/costs.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
create table t1 (a int primary key, b int, c int, d int, e int, key ba (b,a), key bda (b,d,a), key cba (c,b,a), key cb (c,b), key d (d)) engine=aria;
insert into t1 select seq,seq,seq,seq,seq from seq_1_to_10;
insert into t1 values(20,2,2,2,2),(21,3,4,5,6);
#
# Get different scan costs
#
explain select sum(e) as "table_scan" from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 12
Last_query_cost 5.500000
explain select sum(a) as "index scan" from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL PRIMARY 4 NULL 12 Using index
Last_query_cost 3.202929
#
# Range scans should be used if we don't examine all rows in the table
#
explain select count(a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
Last_query_cost 0.000000
explain select count(*) from t1 where a > 0;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 12 Using where; Using index
Last_query_cost 3.202929
explain select count(*) from t1 where a > 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 12 Using where; Using index
Last_query_cost 3.202929
explain select count(*) from t1 where a > 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 11 Using where; Using index
Last_query_cost 2.997685
#
# Shorter indexes are prefered over longer indexs
#
explain select sum(a+b) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL ba 9 NULL 12 Using index
Last_query_cost 3.204394
explain select count(*) from t1 where b between 5 and 10;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range ba,bda ba 5 NULL 6 Using where; Using index
Last_query_cost 1.872197
explain select sum(b+c) from t1 where b between 5 and 6 and c between 5 and 6;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range ba,bda,cba,cb cb 10 NULL 2 Using where; Using index
Last_query_cost 0.970781
# Cost of 'd' should be slightly smaller as key 'ba' is longer than 'd'
explain select count(*) from t1 where b > 6;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range ba,bda ba 5 NULL 5 Using where; Using index
Last_query_cost 1.646831
explain select count(*) from t1 where d > 6;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range d d 5 NULL 5 Using where; Using index
Last_query_cost 1.646343
#
# Check covering index usage
#
explain select a,b,c from t1 where a=b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL cba 14 NULL 12 Using where; Using index
Last_query_cost 3.205859
#
# Prefer ref keys over ranges
#
explain select count(*) from t1 where b=2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref ba,bda ba 5 const 2 Using index
Last_query_cost 0.950732
explain select count(*) from t1 where b=2 and c=2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ref ba,bda,cba,cb cb 10 const,const 2 Using index
Last_query_cost 0.950781
explain select count(*) from t1 where b=3 and c between 3 and 4;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range ba,bda,cba,cb cb 10 NULL 2 Using where; Using index
Last_query_cost 0.970781
#
# Prefer eq keys over ref keys
#
explain select a,b,e from t1 where a=10 or a=11;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 2 Using index condition
Last_query_cost 2.520488
explain select a,b,e from t1 where d=10 or d=11;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range d d 5 NULL 2 Using index condition
Last_query_cost 2.520537
drop table t1;
75 changes: 75 additions & 0 deletions mysql-test/main/costs.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,75 @@
#
# Test of cost calcuations. This test is using the Aria engine as the cost
# calculations are stable for it.
#
--source include/have_sequence.inc

create table t1 (a int primary key, b int, c int, d int, e int, key ba (b,a), key bda (b,d,a), key cba (c,b,a), key cb (c,b), key d (d)) engine=aria;
insert into t1 select seq,seq,seq,seq,seq from seq_1_to_10;
insert into t1 values(20,2,2,2,2),(21,3,4,5,6);

--echo #
--echo # Get different scan costs
--echo #

explain select sum(e) as "table_scan" from t1;
--source include/last_query_cost.inc
explain select sum(a) as "index scan" from t1;
--source include/last_query_cost.inc

--echo #
--echo # Range scans should be used if we don't examine all rows in the table
--echo #
explain select count(a) from t1;
--source include/last_query_cost.inc
explain select count(*) from t1 where a > 0;
--source include/last_query_cost.inc
explain select count(*) from t1 where a > 1;
--source include/last_query_cost.inc
explain select count(*) from t1 where a > 2;
--source include/last_query_cost.inc

--echo #
--echo # Shorter indexes are prefered over longer indexs
--echo #
explain select sum(a+b) from t1;
--source include/last_query_cost.inc
explain select count(*) from t1 where b between 5 and 10;
--source include/last_query_cost.inc
explain select sum(b+c) from t1 where b between 5 and 6 and c between 5 and 6;
--source include/last_query_cost.inc

--echo # Cost of 'd' should be slightly smaller as key 'ba' is longer than 'd'
explain select count(*) from t1 where b > 6;
--source include/last_query_cost.inc
explain select count(*) from t1 where d > 6;
--source include/last_query_cost.inc


--echo #
--echo # Check covering index usage
--echo #
explain select a,b,c from t1 where a=b;
--source include/last_query_cost.inc

--echo #
--echo # Prefer ref keys over ranges
--echo #

explain select count(*) from t1 where b=2;
--source include/last_query_cost.inc
explain select count(*) from t1 where b=2 and c=2;
--source include/last_query_cost.inc
explain select count(*) from t1 where b=3 and c between 3 and 4;
--source include/last_query_cost.inc

--echo #
--echo # Prefer eq keys over ref keys
--echo #

explain select a,b,e from t1 where a=10 or a=11;
--source include/last_query_cost.inc
explain select a,b,e from t1 where d=10 or d=11;
--source include/last_query_cost.inc

drop table t1;
8 changes: 4 additions & 4 deletions mysql-test/main/cte_nonrecursive.result
Original file line number Diff line number Diff line change
Expand Up @@ -418,8 +418,8 @@ t2.c in (with t as (select * from t1 where t1.a<5)
select t2.c from t2,t where t2.c=t.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 4
1 PRIMARY <subquery3> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 PRIMARY <subquery3> eq_ref distinct_key distinct_key 4 func 1
3 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 Using where
3 MATERIALIZED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
explain
Expand All @@ -430,8 +430,8 @@ from t2,(select * from t1 where t1.a<5) as t
where t2.c=t.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 4
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 Using where
2 MATERIALIZED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
# two different definitions of t: one in the with clause of the main query,
Expand Down Expand Up @@ -461,8 +461,8 @@ t.c in (with t as (select * from t1 where t1.a<5)
select t2.c from t2,t where t2.c=t.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 4 Using where
1 PRIMARY <subquery4> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 PRIMARY <subquery4> eq_ref distinct_key distinct_key 4 func 1
4 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 Using where
4 MATERIALIZED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
explain
Expand All @@ -472,8 +472,8 @@ t.c in (select t2.c from t2, (select * from t1 where t1.a<5) as t
where t2.c=t.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 4 Using where
1 PRIMARY <subquery3> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 PRIMARY <subquery3> eq_ref distinct_key distinct_key 4 func 1
3 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 Using where
3 MATERIALIZED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
# another with table tt is defined in the with clause of a subquery
Expand Down
6 changes: 3 additions & 3 deletions mysql-test/main/cte_recursive.result
Original file line number Diff line number Diff line change
Expand Up @@ -4565,9 +4565,9 @@ id select_type table type possible_keys key key_len ref rows Extra
4 RECURSIVE UNION <derived2> ALL NULL NULL NULL NULL 2
5 RECURSIVE UNION <derived2> ALL NULL NULL NULL NULL 2
NULL UNION RESULT <union3,4,5> ALL NULL NULL NULL NULL NULL
2 DERIVED h ALL NULL NULL NULL NULL 12
2 DERIVED <derived3> ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
2 DERIVED w ALL NULL NULL NULL NULL 12 Using where; Using join buffer (incremental, BNL join)
2 DERIVED h ALL NULL NULL NULL NULL 12 Using where
2 DERIVED <derived3> ref key0 key0 5 test.h.id 2
2 DERIVED w ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
prepare stmt from "with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
w_id, w_name, w_dob, w_father, w_mother)
Expand Down
1 change: 1 addition & 0 deletions mysql-test/main/ctype_binary.result
Original file line number Diff line number Diff line change
Expand Up @@ -2763,6 +2763,7 @@ id INT(11) DEFAULT NULL,
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range date_column date_column 4 NULL 2 Using index condition
Expand Down
1 change: 1 addition & 0 deletions mysql-test/main/ctype_cp1251.result
Original file line number Diff line number Diff line change
Expand Up @@ -3175,6 +3175,7 @@ id INT(11) DEFAULT NULL,
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range date_column date_column 4 NULL 2 Using index condition
Expand Down
1 change: 1 addition & 0 deletions mysql-test/main/ctype_latin1.result
Original file line number Diff line number Diff line change
Expand Up @@ -3484,6 +3484,7 @@ id INT(11) DEFAULT NULL,
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range date_column date_column 4 NULL 2 Using index condition
Expand Down
5 changes: 3 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 range a a 23 NULL 31 Using where; Using index
1 SIMPLE t1 index 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 range a a 23 NULL 31 Using where; Using index
1 SIMPLE t1 index a a 23 NULL 31 Using where; Using index
SELECT hex(concat('d',_ucs2 0x017E,'%'));
hex(concat('d',_ucs2 0x017E,'%'))
0064017E0025
Expand Down Expand Up @@ -4368,6 +4368,7 @@ id INT(11) DEFAULT NULL,
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range date_column date_column 4 NULL 2 Using index condition
Expand Down
1 change: 1 addition & 0 deletions mysql-test/main/ctype_utf8.result
Original file line number Diff line number Diff line change
Expand Up @@ -5235,6 +5235,7 @@ id INT(11) DEFAULT NULL,
date_column DATE DEFAULT NULL,
KEY(date_column));
INSERT INTO t1 VALUES (1,'2010-09-01'),(2,'2010-10-01');
INSERT INTO t1 VALUES (3,'2012-09-01'),(4,'2012-10-01'),(5,'2012-10-01');
EXPLAIN SELECT * FROM t1 WHERE date_column BETWEEN '2010-09-01' AND '2010-10-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range date_column date_column 4 NULL 2 Using index condition
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/main/derived.result
Original file line number Diff line number Diff line change
Expand Up @@ -237,7 +237,7 @@ count(*)
explain select count(*) from t1 INNER JOIN (SELECT A.E1, A.E2, A.E3 FROM t1 AS A WHERE A.E3 = (SELECT MAX(B.E3) FROM t1 AS B WHERE A.E2 = B.E2)) AS THEMAX ON t1.E1 = THEMAX.E2 AND t1.E1 = t1.E2;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 2
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 THEMAX.E2 1 Using where
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
2 DERIVED A ALL NULL NULL NULL NULL 2 Using where
3 DEPENDENT SUBQUERY B ALL NULL NULL NULL NULL 2 Using where
drop table t1;
Expand Down
28 changes: 14 additions & 14 deletions mysql-test/main/derived_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -19188,7 +19188,7 @@ DROP TABLE t1;
CREATE TABLE t1 (pk1 INT PRIMARY KEY, f INT) ENGINE=Aria;
INSERT INTO t1 VALUES (1,0),(2,0);
CREATE TABLE t2 (pk2 INT PRIMARY KEY) ENGINE=Aria;
INSERT INTO t2 VALUES (1),(2),(3);
INSERT INTO t2 VALUES (1),(2),(3),(11),(12),(13);
CREATE VIEW v2 AS SELECT pk2, COUNT(*) AS cnt FROM t2 GROUP BY pk2;
SELECT * FROM t1 INNER JOIN v2 ON pk1 = pk2 WHERE f <> 5;
pk1 f pk2 cnt
Expand Down Expand Up @@ -19506,8 +19506,8 @@ explain extended select id, a from t1 where id in (select id from v1);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 20 100.00
1 PRIMARY <derived3> ref key0 key0 4 test.t1.id 2 100.00 FirstMatch(t1)
3 LATERAL DERIVED t1 eq_ref PRIMARY PRIMARY 4 test.t1.id 1 100.00
3 LATERAL DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
3 DERIVED t1 ALL PRIMARY NULL NULL NULL 20 100.00 Using temporary; Using filesort
3 DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` semi join (`test`.`v1`) where `v1`.`id` = `test`.`t1`.`id`
select id, a from t1
Expand Down Expand Up @@ -19544,10 +19544,10 @@ group by t1.id) dt);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 20 100.00
1 PRIMARY <derived3> ref key0 key0 4 test.t1.id 2 100.00 FirstMatch(t1)
3 LATERAL DERIVED t1 eq_ref PRIMARY PRIMARY 4 test.t1.id 1 100.00
3 LATERAL DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
3 DERIVED t1 ALL PRIMARY NULL NULL NULL 20 100.00 Using temporary; Using filesort
3 DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` semi join ((/* select#3 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` left join `test`.`t2` on(`test`.`t2`.`ro_id` = `test`.`t1`.`id` and `test`.`t2`.`flag` = 1) where `test`.`t1`.`id` = `test`.`t1`.`id` group by `test`.`t1`.`id`) `dt`) where `dt`.`id` = `test`.`t1`.`id`
Note 1003 /* select#1 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` semi join ((/* select#3 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` left join `test`.`t2` on(`test`.`t2`.`ro_id` = `test`.`t1`.`id` and `test`.`t2`.`flag` = 1) where 1 group by `test`.`t1`.`id`) `dt`) where `dt`.`id` = `test`.`t1`.`id`
drop view v1;
drop table t1,t2;
#
Expand Down Expand Up @@ -20061,7 +20061,7 @@ JOIN (SELECT t1_id FROM t2 WHERE reporting_person = 1 GROUP BY t1_id) tx
ON tx.t1_id = t1.id
WHERE t1.id BETWEEN 200 AND 100000;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t3 range t1_id t1_id 5 NULL 47 Using where; Using index
1 PRIMARY t3 index t1_id t1_id 15 NULL 47 Using where; Using index
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t3.t1_id 1 Using index
1 PRIMARY <derived2> ref key0 key0 5 test.t3.t1_id 2
2 LATERAL DERIVED t2 ref t1_id t1_id 5 test.t1.id 3 Using index condition; Using where
Expand All @@ -20080,11 +20080,11 @@ EXPLAIN
{
"table": {
"table_name": "t3",
"access_type": "range",
"access_type": "index",
"possible_keys": ["t1_id"],
"key": "t1_id",
"key_length": "5",
"used_key_parts": ["t1_id"],
"key_length": "15",
"used_key_parts": ["t1_id", "YEAR", "quarter"],
"rows": 47,
"filtered": 100,
"attached_condition": "t3.t1_id between 200 and 100000 and t3.t1_id is not null",
Expand Down Expand Up @@ -20416,8 +20416,8 @@ WHERE charges.to_ledger_id = 2;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY charges ALL PRIMARY,fk_charge_from_ledger,fk_charge_to_ledger NULL NULL NULL 20 Using where
1 PRIMARY <derived2> ref key0 key0 17 test.charges.from_ledger_id,test.charges.id 4
2 DERIVED transaction_items ALL fk_items_transaction NULL NULL NULL 40 Using temporary; Using filesort
2 DERIVED transactions eq_ref PRIMARY PRIMARY 8 test.transaction_items.transaction_id 1
2 DERIVED transactions ALL PRIMARY NULL NULL NULL 40 Using temporary; Using filesort
2 DERIVED transaction_items ref fk_items_transaction fk_items_transaction 8 test.transactions.id 1
INSERT INTO charges (id, from_ledger_id, to_ledger_id, amount) VALUES
(101, 4, 2, 100), (102, 7, 2, 200);
set optimizer_switch='split_materialized=on';
Expand Down Expand Up @@ -20608,8 +20608,8 @@ WHERE charges.to_ledger_id = 2;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY charges ALL fk_charge_to_ledger NULL NULL NULL 20 Using where
1 PRIMARY <derived2> ref key0 key0 18 test.charges.from_ledger_id,test.charges.id 4
2 DERIVED transaction_items ALL fk_items_transaction NULL NULL NULL 40 Using temporary; Using filesort
2 DERIVED transactions eq_ref PRIMARY PRIMARY 8 test.transaction_items.transaction_id 1
2 DERIVED transactions ALL PRIMARY NULL NULL NULL 40 Using temporary; Using filesort
2 DERIVED transaction_items ref fk_items_transaction fk_items_transaction 8 test.transactions.id 1
set optimizer_switch='split_materialized=default';
DROP TABLE transaction_items;
DROP TABLE transactions;
Expand Down
Loading

0 comments on commit b6215b9

Please sign in to comment.