mirror of
https://github.com/MariaDB/server.git
synced 2025-07-29 05:21:33 +03:00
Update row and key fetch cost models to take into account data copy costs
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.
This commit is contained in:
@ -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';
|
||||
|
5
mysql-test/include/last_query_cost.inc
Normal file
5
mysql-test/include/last_query_cost.inc
Normal file
@ -0,0 +1,5 @@
|
||||
--disable_query_log
|
||||
--disable_column_names
|
||||
show status like 'last_query_cost';
|
||||
--enable_column_names
|
||||
--enable_query_log
|
@ -4,6 +4,7 @@
|
||||
|
||||
# Table Country
|
||||
|
||||
BEGIN;
|
||||
INSERT IGNORE INTO Country VALUES
|
||||
('AFG','Afghanistan',652090.00,22720000,1),
|
||||
('NLD','Netherlands',41526.00,15864000,5),
|
||||
@ -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
mysql-test/main/costs.result
Normal file
91
mysql-test/main/costs.result
Normal file
@ -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
mysql-test/main/costs.test
Normal file
75
mysql-test/main/costs.test
Normal file
@ -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;
|
@ -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
|
||||
@ -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,
|
||||
@ -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
|
||||
@ -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
|
||||
|
@ -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)
|
||||
|
@ -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
|
||||
|
@ -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
|
||||
|
@ -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
|
||||
|
@ -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
|
||||
@ -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
|
||||
@ -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
|
||||
|
@ -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
|
||||
|
@ -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;
|
||||
|
@ -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
|
||||
@ -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
|
||||
@ -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;
|
||||
#
|
||||
@ -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
|
||||
@ -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",
|
||||
@ -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';
|
||||
@ -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;
|
||||
|
@ -3324,7 +3324,7 @@ 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;
|
||||
|
||||
|
@ -111,7 +111,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 A ALL NULL NULL NULL NULL 2 Using where
|
||||
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.A.E2 1 Using where
|
||||
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
|
||||
3 DEPENDENT SUBQUERY B ALL NULL NULL NULL NULL 2 Using where
|
||||
drop table t1;
|
||||
create table t1 (a int);
|
||||
|
@ -21,7 +21,7 @@ WHERE t.n1 = t1.n1 AND t.n2 = t1.n2 AND c1 = 'a' GROUP BY n1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort
|
||||
1 PRIMARY <derived2> ref key0 key0 8 test.t1.n1,test.t1.n2 2
|
||||
2 LATERAL DERIVED t1 ref c1,n1_c1_n2 n1_c1_n2 4 test.t1.n1 1 Using where; Using index
|
||||
2 DERIVED t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort
|
||||
SELECT t1.n1 FROM t1, (SELECT n1, n2 FROM t1 WHERE c1 = 'a' GROUP BY n1) as t
|
||||
WHERE t.n1 = t1.n1 AND t.n2 = t1.n2 AND c1 = 'a' GROUP BY n1;
|
||||
n1
|
||||
@ -175,8 +175,8 @@ t1.a = dt.a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 index a,a_2 a_2 10 NULL 6 Using where; Using index
|
||||
1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2
|
||||
3 LATERAL DERIVED t1 ref a,a_2 a 5 test.t1.a 1 Using where; Using temporary; Using filesort
|
||||
3 LATERAL DERIVED t2 ref c c 5 test.t1.b 1 Using index
|
||||
3 DERIVED t1 index a,a_2 a_2 10 NULL 6 Using where; Using index; Using temporary; Using filesort
|
||||
3 DERIVED t2 ref c c 5 test.t1.b 1 Using index
|
||||
DROP TABLE t1, t2;
|
||||
#
|
||||
# Bug mdev-25714: usage non-splitting covering index is cheaper than
|
||||
@ -210,7 +210,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 1
|
||||
1 PRIMARY t1 ref idx idx 4 test.t2.id 1
|
||||
1 PRIMARY <derived2> ref key0 key0 9 test.t2.id,test.t1.id 2
|
||||
2 DERIVED t3 ref idx1,idx2 idx1 4 const 5 Using where; Using index
|
||||
2 LATERAL DERIVED t3 ref idx1,idx2 idx2 4 test.t1.itemid 1 Using index condition; Using where
|
||||
select t1.id, t1.itemid, dt.id, t2.id
|
||||
from t1,
|
||||
(select itemid, max(id) as id from t3 where userid = 1 group by itemid) dt,
|
||||
|
@ -1881,14 +1881,14 @@ WHERE (t2.a ,t1.b) NOT IN (SELECT DISTINCT c,a FROM t3 t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 2
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
|
||||
2 DEPENDENT SUBQUERY t unique_subquery PRIMARY,c PRIMARY 4 func 1 Using where
|
||||
2 DEPENDENT SUBQUERY t index_subquery PRIMARY,c c 8 func,func 2 Using index; Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 , t2
|
||||
WHERE (t2.a ,t1.b) NOT IN (SELECT DISTINCT c,a FROM (SELECT * FROM t3) t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 2
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
|
||||
2 DEPENDENT SUBQUERY t3 unique_subquery PRIMARY,c PRIMARY 4 func 1 Using where
|
||||
2 DEPENDENT SUBQUERY t3 index_subquery PRIMARY,c c 8 func,func 2 Using index; Using where
|
||||
SELECT * FROM t1 , t2
|
||||
WHERE (t2.a ,t1.b) NOT IN (SELECT DISTINCT c,a FROM (SELECT * FROM t3) t);
|
||||
b a
|
||||
@ -1931,8 +1931,8 @@ WHERE t3.b IN (SELECT v1.b FROM v1, t2
|
||||
WHERE t2.c = v1.c AND t2.c = v1.b AND v1.b = t3.c);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t2 system NULL NULL NULL NULL 1
|
||||
1 PRIMARY <derived3> ref key1 key1 8 const,const 0 Start temporary
|
||||
1 PRIMARY t3 ALL NULL NULL NULL NULL 2 Using where; End temporary; Using join buffer (flat, BNL join)
|
||||
1 PRIMARY t3 ALL NULL NULL NULL NULL 2 Using where
|
||||
1 PRIMARY <derived3> ref key1 key1 8 const,const 0 FirstMatch(t3)
|
||||
3 DERIVED t1 ALL NULL NULL NULL NULL 3 Using where
|
||||
SELECT * FROM t3
|
||||
WHERE t3.b IN (SELECT v1.b FROM v1, t2
|
||||
@ -2439,10 +2439,14 @@ CREATE TABLE t2 (a int, INDEX(a));
|
||||
INSERT INTO t2 VALUES (1), (2);
|
||||
INSERT INTO t1 SELECT a FROM (SELECT a FROM test.t1) AS s1 NATURAL JOIN
|
||||
t2 AS s2;
|
||||
INSERT INTO t1 SELECT a FROM (SELECT a FROM test.t1) AS s1 NATURAL JOIN
|
||||
t2 AS s2;
|
||||
SELECT * FROM t1;
|
||||
a
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
DELETE FROM t1;
|
||||
INSERT INTO t1 VALUES (1);
|
||||
PREPARE stmt FROM "
|
||||
@ -2459,6 +2463,8 @@ SELECT * FROM t1;
|
||||
a
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
drop table t1,t2;
|
||||
set optimizer_switch=@save968720_optimizer_switch;
|
||||
#
|
||||
|
@ -1417,6 +1417,8 @@ INSERT INTO t1 VALUES (1);
|
||||
CREATE TABLE t2 (a int, INDEX(a));
|
||||
INSERT INTO t2 VALUES (1), (2);
|
||||
|
||||
INSERT INTO t1 SELECT a FROM (SELECT a FROM test.t1) AS s1 NATURAL JOIN
|
||||
t2 AS s2;
|
||||
INSERT INTO t1 SELECT a FROM (SELECT a FROM test.t1) AS s1 NATURAL JOIN
|
||||
t2 AS s2;
|
||||
SELECT * FROM t1;
|
||||
|
@ -146,7 +146,7 @@ CREATE TABLE t1 (p int NOT NULL, a int NOT NULL, PRIMARY KEY (p,a desc));
|
||||
insert into t1 select 2,seq from seq_0_to_1000;
|
||||
EXPLAIN select MIN(a) from t1 where p = 2 group by p;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref PRIMARY PRIMARY 4 const 1000 Using index
|
||||
1 SIMPLE t1 index PRIMARY PRIMARY 8 NULL 1001 Using where; Using index
|
||||
select json_detailed(json_extract(trace, '$**.potential_group_range_indexes'))
|
||||
from information_schema.optimizer_trace;
|
||||
json_detailed(json_extract(trace, '$**.potential_group_range_indexes'))
|
||||
@ -194,7 +194,7 @@ test.t1 analyze status OK
|
||||
# Must use ROR-intersect:
|
||||
explain select * from t1 where b = 255 AND a IS NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index_merge a,b b,a 5,5 NULL 1 Using intersect(b,a); Using where; Using index
|
||||
1 SIMPLE t1 ref a,b b 5 const 2 Using where
|
||||
select * from t1 where b = 255 AND a IS NULL;
|
||||
pk a b
|
||||
10000 NULL 255
|
||||
|
@ -175,7 +175,7 @@ explain SELECT distinct t3.a FROM t3,t2,t1 WHERE t3.a=t1.b AND t1.a=t2.a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 4 Using where; Using temporary
|
||||
1 SIMPLE t3 ref a a 5 test.t1.b 2 Using index
|
||||
1 SIMPLE t2 index a a 4 NULL 5 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t2 ref a a 4 test.t1.a 2 Using index; Distinct
|
||||
SELECT distinct t3.a FROM t3,t2,t1 WHERE t3.a=t1.b AND t1.a=t2.a;
|
||||
a
|
||||
1
|
||||
|
@ -325,7 +325,7 @@ DROP TABLE t1;
|
||||
# Bug#56814 Explain + subselect + fulltext crashes server
|
||||
#
|
||||
CREATE TABLE t1(f1 VARCHAR(6) NOT NULL,
|
||||
FULLTEXT KEY(f1),UNIQUE(f1));
|
||||
FULLTEXT KEY `fulltext` (f1), UNIQUE `unique` (f1));
|
||||
INSERT INTO t1 VALUES ('test');
|
||||
EXPLAIN SELECT 1 FROM t1
|
||||
WHERE 1 > ALL((SELECT t1.f1 FROM t1 JOIN t1 a ON (MATCH(t1.f1) AGAINST (""))
|
||||
@ -333,7 +333,9 @@ WHERE t1.f1 GROUP BY t1.f1));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY a system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY t1 fulltext f1_2,f1 f1 0 1 Using where
|
||||
2 SUBQUERY t1 index unique,fulltext unique 8 NULL 1 Using where; Using index
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DECIMAL value: 'test'
|
||||
PREPARE stmt FROM
|
||||
'EXPLAIN SELECT 1 FROM t1
|
||||
WHERE 1 > ALL((SELECT t1.f1 FROM t1 RIGHT OUTER JOIN t1 a
|
||||
@ -343,12 +345,16 @@ EXECUTE stmt;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY a system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY t1 fulltext f1_2,f1 f1 0 1 Using where
|
||||
2 SUBQUERY t1 index unique,fulltext unique 8 NULL 1 Using where; Using index
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DECIMAL value: 'test'
|
||||
EXECUTE stmt;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY a system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY t1 fulltext f1_2,f1 f1 0 1 Using where
|
||||
2 SUBQUERY t1 index unique,fulltext unique 8 NULL 1 Using where; Using index
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DECIMAL value: 'test'
|
||||
DEALLOCATE PREPARE stmt;
|
||||
PREPARE stmt FROM
|
||||
'EXPLAIN SELECT 1 FROM t1
|
||||
@ -359,12 +365,15 @@ EXECUTE stmt;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY a system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY t1 fulltext f1_2,f1 f1 0 1 Using where
|
||||
2 SUBQUERY t1 index unique,fulltext unique 8 NULL 1 Using where; Using index
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DECIMAL value: 'test'
|
||||
INSERT into t1 values('test1'),('test2'),('test3'),('test4'),('test5');
|
||||
EXECUTE stmt;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY a system NULL NULL NULL NULL 1
|
||||
2 SUBQUERY t1 fulltext f1_2,f1 f1 0 1 Using where
|
||||
1 PRIMARY t1 index NULL unique 8 NULL 6 Using index
|
||||
2 SUBQUERY t1 fulltext unique,fulltext fulltext 0 1 Using where
|
||||
2 SUBQUERY a index NULL unique 8 NULL 6 Using index
|
||||
DEALLOCATE PREPARE stmt;
|
||||
DROP TABLE t1;
|
||||
End of 5.1 tests.
|
||||
|
@ -254,7 +254,7 @@ DROP TABLE t1;
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1(f1 VARCHAR(6) NOT NULL,
|
||||
FULLTEXT KEY(f1),UNIQUE(f1));
|
||||
FULLTEXT KEY `fulltext` (f1), UNIQUE `unique` (f1));
|
||||
INSERT INTO t1 VALUES ('test');
|
||||
|
||||
EXPLAIN SELECT 1 FROM t1
|
||||
@ -279,6 +279,7 @@ PREPARE stmt FROM
|
||||
WHERE t1.f1 GROUP BY t1.f1))';
|
||||
|
||||
EXECUTE stmt;
|
||||
INSERT into t1 values('test1'),('test2'),('test3'),('test4'),('test5');
|
||||
EXECUTE stmt;
|
||||
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
@ -15,6 +15,6 @@ explain
|
||||
SELECT * FROM (SELECT id FROM t1 GROUP BY id) dt WHERE 1=0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
|
||||
2 DERIVED t1 range NULL id 53 NULL 1 Using index for group-by
|
||||
2 DERIVED t1 index NULL id 53 NULL 1 Using index
|
||||
SET GLOBAL slow_query_log = @sql_tmp;
|
||||
drop table t1;
|
||||
|
@ -728,6 +728,19 @@ EXPLAIN
|
||||
"filtered": 100
|
||||
}
|
||||
},
|
||||
{
|
||||
"block-nl-join": {
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"access_type": "ALL",
|
||||
"rows": 10,
|
||||
"filtered": 100
|
||||
},
|
||||
"buffer_type": "flat",
|
||||
"buffer_size": "119",
|
||||
"join_type": "BNL"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "<subquery2>",
|
||||
@ -756,19 +769,6 @@ EXPLAIN
|
||||
}
|
||||
}
|
||||
}
|
||||
},
|
||||
{
|
||||
"block-nl-join": {
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"access_type": "ALL",
|
||||
"rows": 10,
|
||||
"filtered": 100
|
||||
},
|
||||
"buffer_type": "flat",
|
||||
"buffer_size": "1Kb",
|
||||
"join_type": "BNL"
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
@ -930,9 +930,9 @@ drop table t0;
|
||||
# MDEV-7265: "Full scan on NULL key", the join case
|
||||
#
|
||||
CREATE TABLE t1 (a INT, KEY(a));
|
||||
INSERT INTO t1 VALUES (1),(2);
|
||||
INSERT INTO t1 VALUES (1),(2),(5),(6),(7);
|
||||
CREATE TABLE t2 (b INT);
|
||||
INSERT INTO t2 VALUES (3),(4);
|
||||
INSERT INTO t2 VALUES (3),(4),(9),(10),(11);
|
||||
EXPLAIN FORMAT=JSON SELECT * FROM t1 AS outer_t1 WHERE a <> ALL ( SELECT a FROM t1, t2 WHERE b <> outer_t1.a );
|
||||
EXPLAIN
|
||||
{
|
||||
@ -946,7 +946,7 @@ EXPLAIN
|
||||
"key": "a",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"rows": 2,
|
||||
"rows": 5,
|
||||
"filtered": 100,
|
||||
"attached_condition": "!<in_optimizer>(outer_t1.a,<exists>(subquery#2))",
|
||||
"using_index": true
|
||||
@ -969,7 +969,7 @@ EXPLAIN
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"ref": ["func"],
|
||||
"rows": 2,
|
||||
"rows": 3,
|
||||
"filtered": 100,
|
||||
"attached_condition": "trigcond(<cache>(outer_t1.a) = t1.a or t1.a is null)",
|
||||
"using_index": true
|
||||
@ -981,7 +981,7 @@ EXPLAIN
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"access_type": "ALL",
|
||||
"rows": 2,
|
||||
"rows": 5,
|
||||
"filtered": 100
|
||||
},
|
||||
"buffer_type": "flat",
|
||||
|
@ -163,10 +163,10 @@ drop table t0;
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT, KEY(a));
|
||||
INSERT INTO t1 VALUES (1),(2);
|
||||
INSERT INTO t1 VALUES (1),(2),(5),(6),(7);
|
||||
|
||||
CREATE TABLE t2 (b INT);
|
||||
INSERT INTO t2 VALUES (3),(4);
|
||||
INSERT INTO t2 VALUES (3),(4),(9),(10),(11);
|
||||
|
||||
EXPLAIN FORMAT=JSON SELECT * FROM t1 AS outer_t1 WHERE a <> ALL ( SELECT a FROM t1, t2 WHERE b <> outer_t1.a );
|
||||
|
||||
|
@ -607,7 +607,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
explain
|
||||
select min(a1) from t1 where (a1 < 'KKK' or a1 > 'KKK');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 3 NULL 14 Using where; Using index
|
||||
1 SIMPLE t1 index PRIMARY PRIMARY 3 NULL 15 Using where; Using index
|
||||
explain
|
||||
select max(a3) from t1 where a2 < 2 and a3 < 'SEA';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -652,7 +652,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
explain
|
||||
select concat(min(t1.a1),min(t2.a4)) from t1, t2 where t2.a4 <> 'AME';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range k2 k2 4 NULL 6 Using where; Using index
|
||||
1 SIMPLE t2 index k2 k2 4 NULL 7 Using where; Using index
|
||||
1 SIMPLE t1 index NULL PRIMARY 3 NULL 15 Using index; Using join buffer (flat, BNL join)
|
||||
drop table t1, t2;
|
||||
create table t1 (a char(10));
|
||||
@ -1336,7 +1336,7 @@ INSERT INTO t2 ( a, b, c ) VALUES
|
||||
( 1, NULL, 2 ), ( 1, 3, 4 ), ( 1, 4, 4 ), ( 2, NULL, 2 ), ( 2, 3, 4 ), ( 2, 4, 4 );
|
||||
EXPLAIN SELECT MIN(b), MIN(c) FROM t2 WHERE a = 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref a a 5 const 3
|
||||
1 SIMPLE t2 ALL a NULL NULL NULL 6 Using where
|
||||
SELECT MIN(b), MIN(c) FROM t2 WHERE a = 1;
|
||||
MIN(b) MIN(c)
|
||||
3 2
|
||||
@ -1856,9 +1856,8 @@ NULL
|
||||
EXPLAIN EXTENDED
|
||||
SELECT MAX(a) FROM t1 WHERE (1,2) IN (SELECT a,b FROM t2 WHERE b<5) and a<10;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 8 func,func 1 100.00
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 5 100.00 Using where; FirstMatch
|
||||
1 PRIMARY t1 range a a 4 NULL 3 100.00 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 5 100.00 Using where
|
||||
Warnings:
|
||||
Note 1003 select max(`test`.`t1`.`a`) AS `MAX(a)` from `test`.`t1` semi join (`test`.`t2`) where `test`.`t2`.`a` = 1 and `test`.`t2`.`b` = 2 and `test`.`t1`.`a` < 10
|
||||
SELECT MAX(a) FROM t1 WHERE (1,2) IN (SELECT a,b FROM t2 WHERE b<5) and a<10;
|
||||
|
@ -521,7 +521,7 @@ a
|
||||
b
|
||||
explain select f1 from t1 where f1 in ('a','b');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range t1f1_idx t1f1_idx 2 NULL 2 Using where; Using index
|
||||
1 SIMPLE t1 index t1f1_idx t1f1_idx 2 NULL 3 Using where; Using index
|
||||
select f1 from t1 where f1 in (2,1);
|
||||
f1
|
||||
1
|
||||
@ -957,7 +957,7 @@ a
|
||||
# Conversion to equality is impossible due to different values
|
||||
EXPLAIN SELECT * FROM t1 WHERE a IN (1,1,2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
|
||||
1 SIMPLE t1 index PRIMARY PRIMARY 4 NULL 3 Using where; Using index
|
||||
SELECT * FROM t1 WHERE a IN (1,NULL,1);
|
||||
a
|
||||
1
|
||||
@ -1030,7 +1030,7 @@ a b
|
||||
# No conversion due to different values
|
||||
EXPLAIN SELECT * FROM t2 WHERE (a,b) IN ((2,'def'),(2,'def'),(2,'XYZ'));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range PRIMARY PRIMARY 16 NULL 2 Using where; Using index
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 16 NULL 3 Using where; Using index
|
||||
SELECT * FROM t2 WHERE (a,b) IN ((2,'def'),(2,'def'),(2,NULL));
|
||||
a b
|
||||
2 def
|
||||
@ -1078,7 +1078,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1 Using index
|
||||
EXECUTE stmt USING 2,3,4;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 3 Using where; Using index
|
||||
1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 3 Using where; Using index
|
||||
DEALLOCATE PREPARE stmt;
|
||||
DROP TABLE t1, t2, t3;
|
||||
# Nested joins
|
||||
@ -1104,7 +1104,7 @@ AND t3.a IN (1,2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 2
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t3 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 4 Using where; Using index; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 2 Using join buffer (incremental, BNL join)
|
||||
# Conversion to equalities
|
||||
EXPLAIN SELECT * FROM t1 LEFT JOIN ((t2, t3) LEFT JOIN t4 ON t2.a = t4.a)
|
||||
@ -1118,7 +1118,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
EXPLAIN SELECT * FROM t1 LEFT JOIN ((t2, t3) LEFT JOIN t4 ON t2.a = t4.a)
|
||||
ON t1.a = t2.a WHERE t1.a IN (1,3);
|
||||
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
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t1.a 1
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 2 Using where
|
||||
1 SIMPLE t3 index NULL PRIMARY 4 NULL 4 Using index
|
||||
@ -1131,7 +1131,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 const PRIMARY PRIMARY 4 const 1
|
||||
EXPLAIN SELECT * FROM v1 WHERE a IN (1,2,3);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using index condition
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t1.a 1
|
||||
# Stored procedures
|
||||
CREATE PROCEDURE p1(pa INT, pb INT)
|
||||
@ -1141,7 +1141,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||
CALL p1(2,1);
|
||||
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
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
DROP TABLE t1, t2, t3, t4;
|
||||
DROP VIEW v1;
|
||||
DROP PROCEDURE p1;
|
||||
|
@ -127,7 +127,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
@ -139,7 +139,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -151,7 +151,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -163,7 +163,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -175,7 +175,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -187,7 +187,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
set optimizer_prune_level=0;
|
||||
select @@optimizer_prune_level;
|
||||
@@optimizer_prune_level
|
||||
@ -202,24 +202,24 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.c22 1
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.c42 1
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 2705.237037
|
||||
Last_query_cost 2693.038350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.c22 1
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.c42 1
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 2705.237037
|
||||
Last_query_cost 2693.038350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -231,7 +231,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 751.472751
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -243,7 +243,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 751.472751
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -255,7 +255,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 760.922751
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -267,7 +267,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 760.922751
|
||||
set optimizer_search_depth=1;
|
||||
select @@optimizer_search_depth;
|
||||
@@optimizer_search_depth
|
||||
@ -283,7 +283,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
@ -295,7 +295,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -307,7 +307,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2068.798851
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -319,7 +319,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2068.798851
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -331,7 +331,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2073.523851
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -343,7 +343,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2073.523851
|
||||
set optimizer_search_depth=62;
|
||||
select @@optimizer_search_depth;
|
||||
@@optimizer_search_depth
|
||||
@ -354,24 +354,24 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.c22 1
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.c42 1
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 2705.237037
|
||||
Last_query_cost 2693.038350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.c22 1
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 12 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.c42 1
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 2705.237037
|
||||
Last_query_cost 2693.038350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -383,7 +383,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 751.472751
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -395,7 +395,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 751.472751
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -407,7 +407,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 760.922751
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6 Using where
|
||||
@ -419,7 +419,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 701.018727
|
||||
Last_query_cost 760.922751
|
||||
set optimizer_prune_level=2;
|
||||
select @@optimizer_prune_level;
|
||||
@@optimizer_prune_level
|
||||
@ -439,7 +439,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
@ -451,7 +451,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -463,7 +463,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -475,7 +475,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -487,7 +487,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -499,7 +499,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
set optimizer_search_depth=1;
|
||||
select @@optimizer_search_depth;
|
||||
@@optimizer_search_depth
|
||||
@ -515,7 +515,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
@ -527,7 +527,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -539,7 +539,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2068.798851
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -551,7 +551,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2068.798851
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -563,7 +563,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2073.523851
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 3 Using where
|
||||
@ -575,7 +575,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1678.037037
|
||||
Last_query_cost 2073.523851
|
||||
set optimizer_search_depth=62;
|
||||
select @@optimizer_search_depth;
|
||||
@@optimizer_search_depth
|
||||
@ -591,7 +591,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c12 = t2.c21 and t2.c22 = t3.c31 and t3.c32 = t4.c41 and t4.c42 = t5.c51 and t5.c52 = t6.c61 and t6.c62 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
@ -603,7 +603,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t7 eq_ref PRIMARY PRIMARY 4 test.t6.c62 1 Using index
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 3350.237037
|
||||
Last_query_cost 2696.338350
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -615,7 +615,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -627,7 +627,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1559.791393
|
||||
explain select t1.c11 from t1, t2, t3, t4, t5, t6, t7 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -639,7 +639,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
explain select t1.c11 from t7, t6, t5, t4, t3, t2, t1 where t1.c11 = t2.c21 and t1.c12 = t3.c31 and t1.c13 = t4.c41 and t1.c14 = t5.c51 and t1.c15 = t6.c61 and t1.c16 = t7.c71 and t2.c22 = t3.c32 and t2.c23 = t4.c42 and t2.c24 = t5.c52 and t2.c25 = t6.c62 and t2.c26 = t7.c72 and t3.c33 = t4.c43 and t3.c34 = t5.c53 and t3.c35 = t6.c63 and t3.c36 = t7.c73 and t4.c42 = t5.c54 and t4.c43 = t6.c64 and t4.c44 = t7.c74 and t5.c52 = t6.c65 and t5.c53 = t7.c75 and t6.c62 = t7.c76;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 6
|
||||
@ -651,7 +651,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 18 Using where; Using join buffer (flat, BNL join)
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 1276.787037
|
||||
Last_query_cost 1563.335143
|
||||
drop table t1,t2,t3,t4,t5,t6,t7;
|
||||
CREATE TABLE t1 (a int, b int, d int, i int);
|
||||
INSERT INTO t1 VALUES (1,1,1,1);
|
||||
@ -802,6 +802,9 @@ WHERE t100.K=t10.I
|
||||
AND t10000.K=t10.I;
|
||||
COUNT(*)
|
||||
9
|
||||
#####
|
||||
# Expect all variants of EQ joining t100 & t10000 with T10
|
||||
# to have same cost # handler_reads:
|
||||
flush status;
|
||||
EXPLAIN SELECT COUNT(*) FROM t10,t100,t10000
|
||||
WHERE t100.K=t10.I
|
||||
@ -909,6 +912,12 @@ AND t10000.K=t10.K;
|
||||
COUNT(*)
|
||||
9
|
||||
### NOTE: Handler_reads: 31, expected: 30 ###
|
||||
#####
|
||||
## EQ_REF Should be executed before table scan(ALL)
|
||||
## - Independent of #records in table being EQ_REF-joined
|
||||
#####
|
||||
#####
|
||||
# Expect: Join EQ_REF(t100) before ALL(t10000)
|
||||
flush status;
|
||||
EXPLAIN SELECT STRAIGHT_JOIN COUNT(*) FROM t10,t100,t10000
|
||||
WHERE t100.K=t10.I
|
||||
@ -948,6 +957,8 @@ WHERE t100.K=t10.I
|
||||
AND t10000.I=t10.I;
|
||||
COUNT(*)
|
||||
9000
|
||||
#####
|
||||
# Expect: Join EQ_REF(t10000) before ALL(t100) (star-join)
|
||||
flush status;
|
||||
EXPLAIN SELECT STRAIGHT_JOIN COUNT(*) FROM t10,t10000,t100
|
||||
WHERE t100.I=t10.I
|
||||
@ -2902,7 +2913,7 @@ EXPLAIN SELECT COUNT(*) FROM t1 AS x JOIN t1 ON t1.K=x.I JOIN t2 ON t2.K=x.I JOI
|
||||
DROP TABLE t100, t1, t2, t3, t4, t5, t6, t7, t8, t9, t10, t11, t12, t13, t14, t15, t16, t17, t18, t19, t20, t21, t22, t23, t24, t25, t26, t27, t28, t29, t30, t31, t32, t33, t34, t35, t36, t37, t38, t39, t40, t41, t42, t43, t44, t45, t46, t47, t48, t49, t50, t51, t52, t53, t54, t55, t56, t57, t58, t59, t60, t61;
|
||||
show status like "optimizer%";
|
||||
Variable_name Value
|
||||
Optimizer_join_prefixes_check_calls 57916
|
||||
Optimizer_join_prefixes_check_calls 60210
|
||||
SET OPTIMIZER_SEARCH_DEPTH = DEFAULT;
|
||||
#
|
||||
# Bug found when testing greedy optimizer tests
|
||||
@ -2917,8 +2928,8 @@ explain SELECT * FROM t1 AS alias1
|
||||
WHERE alias1.col_varchar_key IN (SELECT COUNT(*) FROM t1 AS SQ3_alias2 JOIN t1 AS SQ3_alias3 ON (SQ3_alias3.col_varchar_key = SQ3_alias2.col_varchar_key AND SQ3_alias3.pk = SQ3_alias2.pk));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY alias1 index NULL col_varchar_key 20 NULL 2 Using where; Using index
|
||||
2 DEPENDENT SUBQUERY SQ3_alias2 index PRIMARY,col_varchar_key col_varchar_key 20 NULL 2 Using index
|
||||
2 DEPENDENT SUBQUERY SQ3_alias3 eq_ref PRIMARY,col_varchar_key PRIMARY 4 test.SQ3_alias2.pk 1 Using where
|
||||
2 DEPENDENT SUBQUERY SQ3_alias2 index PRIMARY,col_varchar_key col_varchar_key 20 NULL 2 Using where; Using index
|
||||
2 DEPENDENT SUBQUERY SQ3_alias3 ref PRIMARY,col_varchar_key col_varchar_key 11 test.SQ3_alias2.col_varchar_key 1 Using where; Using index
|
||||
drop table t1;
|
||||
#
|
||||
# This triggered an assert failure while testing
|
||||
|
@ -441,9 +441,9 @@ WHERE t100.K=t10.I
|
||||
AND t10000.K=t10.I;
|
||||
--source include/check_qep.inc
|
||||
|
||||
#####
|
||||
# Expect all variants of EQ joining t100 & t10000 with T10
|
||||
# to have same cost # handler_reads:
|
||||
--echo #####
|
||||
--echo # Expect all variants of EQ joining t100 & t10000 with T10
|
||||
--echo # to have same cost # handler_reads:
|
||||
let $query=
|
||||
SELECT COUNT(*) FROM t10,t100,t10000
|
||||
WHERE t100.K=t10.I
|
||||
@ -493,12 +493,12 @@ WHERE t100.K=t10.I
|
||||
--source include/check_qep.inc
|
||||
|
||||
|
||||
#####
|
||||
## EQ_REF Should be executed before table scan(ALL)
|
||||
## - Independent of #records in table being EQ_REF-joined
|
||||
#####
|
||||
#####
|
||||
# Expect: Join EQ_REF(t100) before ALL(t10000)
|
||||
--echo #####
|
||||
--echo ## EQ_REF Should be executed before table scan(ALL)
|
||||
--echo ## - Independent of #records in table being EQ_REF-joined
|
||||
--echo #####
|
||||
--echo #####
|
||||
--echo # Expect: Join EQ_REF(t100) before ALL(t10000)
|
||||
let $query=
|
||||
SELECT STRAIGHT_JOIN COUNT(*) FROM t10,t100,t10000
|
||||
WHERE t100.K=t10.I
|
||||
@ -517,8 +517,8 @@ WHERE t100.K=t10.I
|
||||
AND t10000.I=t10.I;
|
||||
--source include/check_qep.inc
|
||||
|
||||
#####
|
||||
# Expect: Join EQ_REF(t10000) before ALL(t100) (star-join)
|
||||
--echo #####
|
||||
--echo # Expect: Join EQ_REF(t10000) before ALL(t100) (star-join)
|
||||
let $query=
|
||||
SELECT STRAIGHT_JOIN COUNT(*) FROM t10,t10000,t100
|
||||
WHERE t100.I=t10.I
|
||||
|
@ -2457,7 +2457,7 @@ test.t1 analyze status OK
|
||||
|
||||
EXPLAIN SELECT SQL_BUFFER_RESULT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref b b 4 const 6 Using where; Using index; Using temporary
|
||||
1 SIMPLE t1 range b b 9 NULL 2 Using where; Using index for group-by; Using temporary
|
||||
|
||||
SELECT SQL_BUFFER_RESULT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
|
||||
MIN(a) b
|
||||
@ -2465,7 +2465,7 @@ MIN(a) b
|
||||
|
||||
EXPLAIN SELECT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref b b 4 const 6 Using where; Using index
|
||||
1 SIMPLE t1 range b b 9 NULL 2 Using where; Using index for group-by
|
||||
|
||||
SELECT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
|
||||
MIN(a) b
|
||||
|
@ -2080,7 +2080,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
explain extended select a1,a2,min(b),max(b) from t1
|
||||
where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (c > 'a111') group by a1,a2;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 range idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 130 NULL 276 96.30 Using where; Using index
|
||||
1 SIMPLE t1 range idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 130 NULL 276 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`a1` AS `a1`,`test`.`t1`.`a2` AS `a2`,min(`test`.`t1`.`b`) AS `min(b)`,max(`test`.`t1`.`b`) AS `max(b)` from `test`.`t1` where (`test`.`t1`.`a1` = 'b' or `test`.`t1`.`a1` = 'd' or `test`.`t1`.`a1` = 'a' or `test`.`t1`.`a1` = 'c') and `test`.`t1`.`a2` > 'a' and `test`.`t1`.`c` > 'a111' group by `test`.`t1`.`a1`,`test`.`t1`.`a2`
|
||||
explain extended select a1,a2,b,min(c),max(c) from t1
|
||||
@ -2100,7 +2100,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index NULL idx_t2_1 163 NULL 548 Using where; Using index
|
||||
explain extended select a1,a2,b from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (c > 'a111') group by a1,a2,b;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 range idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 130 NULL 276 96.30 Using where; Using index
|
||||
1 SIMPLE t1 range idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 130 NULL 276 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`a1` AS `a1`,`test`.`t1`.`a2` AS `a2`,`test`.`t1`.`b` AS `b` from `test`.`t1` where (`test`.`t1`.`a1` = 'b' or `test`.`t1`.`a1` = 'd' or `test`.`t1`.`a1` = 'a' or `test`.`t1`.`a1` = 'c') and `test`.`t1`.`a2` > 'a' and `test`.`t1`.`c` > 'a111' group by `test`.`t1`.`a1`,`test`.`t1`.`a2`,`test`.`t1`.`b`
|
||||
explain select a1,a2,min(b),c from t2 where (a2 = 'a') and (c = 'a111') group by a1;
|
||||
@ -2368,11 +2368,11 @@ CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c));
|
||||
INSERT INTO t2 SELECT a,b,b FROM t1;
|
||||
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a,b a 10 NULL 6 Using where; Using index
|
||||
1 SIMPLE t1 range a,b a 10 NULL 2 Using where; Using index for group-by
|
||||
insert into t1 select 1,seq from seq_1_to_100;
|
||||
explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a,b a 10 NULL 6 Using where; Using index
|
||||
1 SIMPLE t1 range a,b a 10 NULL 2 Using where; Using index for group-by
|
||||
analyze table t1;
|
||||
Table Op Msg_type Msg_text
|
||||
test.t1 analyze status Engine-independent statistics collected
|
||||
@ -2460,7 +2460,7 @@ EXPLAIN SELECT (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) x
|
||||
FROM t1 AS t1_outer;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1_outer index NULL a 10 NULL 15 Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE EXISTS
|
||||
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -2470,31 +2470,31 @@ EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE
|
||||
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) > 12;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
|
||||
2 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE
|
||||
a IN (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 2
|
||||
1 PRIMARY t1_outer ref a a 5 <subquery2>.max(b) 3 Using index
|
||||
2 MATERIALIZED t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 MATERIALIZED t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
EXPLAIN SELECT 1 FROM t1 AS t1_outer GROUP BY a HAVING
|
||||
a > (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1_outer range NULL a 5 NULL 6 Using index for group-by
|
||||
2 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
EXPLAIN SELECT 1 FROM t1 AS t1_outer1 JOIN t1 AS t1_outer2
|
||||
ON t1_outer1.a = (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2)
|
||||
AND t1_outer1.b = t1_outer2.b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1_outer1 ref a a 5 const 1 Using where; Using index
|
||||
1 PRIMARY t1_outer2 index NULL a 10 NULL 15 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
2 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
EXPLAIN SELECT (SELECT (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) x
|
||||
FROM t1 AS t1_outer) x2 FROM t1 AS t1_outer2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1_outer2 index NULL a 10 NULL 15 Using index
|
||||
2 SUBQUERY t1_outer index NULL a 10 NULL 15 Using index
|
||||
3 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
3 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
CREATE TABLE t3 LIKE t1;
|
||||
FLUSH STATUS;
|
||||
INSERT INTO t3 SELECT a,MAX(b) FROM t1 GROUP BY a;
|
||||
@ -3794,7 +3794,7 @@ CREATE INDEX break_it ON t1 (a, b);
|
||||
EXPLAIN
|
||||
SELECT distinct a, b FROM t1 where a = '3' ORDER BY b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref break_it break_it 5 const 6 Using where; Using index; Using filesort
|
||||
1 SIMPLE t1 range break_it break_it 10 NULL 2 Using where; Using index for group-by; Using filesort
|
||||
SELECT distinct a, b FROM t1 where a = '3' ORDER BY b;
|
||||
a b
|
||||
3 1
|
||||
@ -4036,10 +4036,10 @@ 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
|
||||
explain select min(a) from t1 where a between "a" and "Cafeeeeeeeeeeeeeeeeeeeeeeeeee";
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 13 NULL 2 Using where; Using index
|
||||
1 SIMPLE t1 index a a 13 NULL 2 Using where; Using index
|
||||
explain select min(a) from t1 where a between "abbbbbbbbbbbbbbbbbbbb" and "Cafe2";
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 13 NULL 2 Using where; Using index
|
||||
1 SIMPLE t1 index a a 13 NULL 2 Using where; Using index
|
||||
drop table t1;
|
||||
#
|
||||
# MDEV-15433: Optimizer does not use group by optimization with distinct
|
||||
|
@ -75,7 +75,7 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name LIKE 'M%' AND Population > 300000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range Population,Name Name 35 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge Population,Name Name,Population 35,4 NULL # Using sort_intersect(Name,Population); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name LIKE 'M%' AND Population > 7000000;
|
||||
@ -355,9 +355,6 @@ COUNT(*)
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'C%';
|
||||
COUNT(*)
|
||||
551
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'B%';
|
||||
COUNT(*)
|
||||
339
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'J%';
|
||||
COUNT(*)
|
||||
256
|
||||
@ -370,7 +367,7 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'K' AND Population > 1000000 AND Country LIKE 'J%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Country,Name 4,3,35 NULL # Using sort_intersect(Population,Country,Name); Using where
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Country 4,3 NULL # Using sort_intersect(Population,Country); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'K' AND Population > 500000 AND Country LIKE 'C%';
|
||||
@ -476,7 +473,7 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 2001 AND 2500 AND Population > 300000 AND Country LIKE 'H%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country Country,PRIMARY 3,4 NULL # Using sort_intersect(Country,PRIMARY); Using where
|
||||
1 SIMPLE City range PRIMARY,Population,Country Country 3 NULL # Using index condition; Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 3701 AND 4000 AND Population > 1000000
|
||||
@ -488,7 +485,7 @@ SELECT * FROM City
|
||||
WHERE ID BETWEEN 3001 AND 4000 AND Population > 600000
|
||||
AND Country BETWEEN 'S' AND 'Z' ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range PRIMARY,Population,Country Population 4 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country Population,Country 4,3 NULL # Using sort_intersect(Population,Country); Using where
|
||||
SELECT * FROM City USE INDEX ()
|
||||
WHERE ID BETWEEN 501 AND 1000 AND Population > 700000 AND Country LIKE 'C%';
|
||||
ID Name Country Population
|
||||
@ -715,18 +712,18 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'J' AND Population > 500000 AND Country LIKE 'C%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range Population,Country,Name Name 35 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge Population,Country,Name Name,Country 35,3 NULL # Using sort_intersect(Name,Country); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 1 AND 500 AND Population > 700000 AND Country LIKE 'C%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range PRIMARY,Population,Country Population 4 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country Population,PRIMARY 4,4 NULL # Using sort_intersect(Population,PRIMARY); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 3001 AND 4000 AND Population > 600000
|
||||
AND Country BETWEEN 'S' AND 'Z';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range PRIMARY,Population,Country Population 4 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country Population,Country 4,3 NULL # Using sort_intersect(Population,Country); Using where
|
||||
SELECT * FROM City WHERE
|
||||
Name LIKE 'C%' AND Population > 1000000;
|
||||
ID Name Country Population
|
||||
@ -966,7 +963,7 @@ EXPLAIN
|
||||
SELECT * FROM t1
|
||||
WHERE (f1 < 535 OR f1 > 985) AND ( f4='r' OR f4 LIKE 'a%' ) ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY,f4 f4 35 NULL # Using index condition; Using where
|
||||
1 SIMPLE t1 index_merge PRIMARY,f4 f4,PRIMARY 35,4 NULL # Using sort_intersect(f4,PRIMARY); Using where
|
||||
SELECT * FROM t1
|
||||
WHERE (f1 < 535 OR f1 > 985) AND ( f4='r' OR f4 LIKE 'a%' ) ;
|
||||
f1 f4 f5
|
||||
|
@ -120,7 +120,6 @@ SELECT COUNT(*) FROM City WHERE Name BETWEEN 'G' AND 'K';
|
||||
SELECT COUNT(*) FROM City WHERE Population > 1000000;
|
||||
SELECT COUNT(*) FROM City WHERE Population > 500000;
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'C%';
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'B%';
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'J%';
|
||||
|
||||
|
||||
|
@ -81,12 +81,12 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name LIKE 'M%' AND Population > 300000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range Population,Name Name 35 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge Population,Name Name,Population 35,4 NULL # Using sort_intersect(Name,Population); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name LIKE 'M%' AND Population > 7000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge Population,Name Population,Name 4,35 NULL # Using sort_intersect(Population,Name); Using where
|
||||
1 SIMPLE City range Population,Name Population 4 NULL # Using index condition; Using where
|
||||
SELECT * FROM City USE INDEX ()
|
||||
WHERE Name LIKE 'C%' AND Population > 1000000;
|
||||
ID Name Country Population
|
||||
@ -341,8 +341,8 @@ ID Name Country Population
|
||||
SELECT * FROM City
|
||||
WHERE Name LIKE 'M%' AND Population > 7000000;
|
||||
ID Name Country Population
|
||||
1024 Mumbai (Bombay) IND 10500000
|
||||
3580 Moscow RUS 8389200
|
||||
1024 Mumbai (Bombay) IND 10500000
|
||||
SELECT COUNT(*) FROM City WHERE Name BETWEEN 'M' AND 'N';
|
||||
COUNT(*)
|
||||
301
|
||||
@ -361,9 +361,6 @@ COUNT(*)
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'C%';
|
||||
COUNT(*)
|
||||
551
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'B%';
|
||||
COUNT(*)
|
||||
339
|
||||
SELECT COUNT(*) FROM City WHERE Country LIKE 'J%';
|
||||
COUNT(*)
|
||||
256
|
||||
@ -371,17 +368,17 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'M' AND 'N' AND Population > 1000000 AND Country LIKE 'C%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Name,Country 4,35,3 NULL # Using sort_intersect(Population,Name,Country); Using where
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Name 4,35 NULL # Using sort_intersect(Population,Name); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'K' AND Population > 1000000 AND Country LIKE 'J%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Country,Name 4,3,35 NULL # Using sort_intersect(Population,Country,Name); Using where
|
||||
1 SIMPLE City index_merge Population,Country,Name Population,Country 4,3 NULL # Using sort_intersect(Population,Country); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'K' AND Population > 500000 AND Country LIKE 'C%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range Population,Name,Country Name # NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge Population,Name,Country Name,Population,Country # NULL # Using sort_intersect(Name,Population,Country); Using where
|
||||
SELECT * FROM City USE INDEX ()
|
||||
WHERE Name BETWEEN 'M' AND 'N' AND Population > 1000000 AND Country LIKE 'C%';
|
||||
ID Name Country Population
|
||||
@ -482,13 +479,13 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 2001 AND 2500 AND Population > 300000 AND Country LIKE 'H%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country PRIMARY,Population,Country 4,4,7 NULL # Using sort_intersect(PRIMARY,Population,Country); Using where
|
||||
1 SIMPLE City range PRIMARY,Population,Country Country 7 NULL # Using index condition; Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 3701 AND 4000 AND Population > 1000000
|
||||
AND Country BETWEEN 'S' AND 'Z';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country PRIMARY,Population,Country 4,4,7 NULL # Using sort_intersect(PRIMARY,Population,Country); Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country PRIMARY,Population 4,4 NULL # Using sort_intersect(PRIMARY,Population); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 3001 AND 4000 AND Population > 600000
|
||||
@ -721,7 +718,7 @@ EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE Name BETWEEN 'G' AND 'J' AND Population > 500000 AND Country LIKE 'C%';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range Population,Country,Name Name 35 NULL # Using index condition; Using where
|
||||
1 SIMPLE City index_merge Population,Country,Name Name,Population,Country 35,4,3 NULL # Using sort_intersect(Name,Population,Country); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ID BETWEEN 1 AND 500 AND Population > 700000 AND Country LIKE 'C%';
|
||||
@ -732,7 +729,7 @@ SELECT * FROM City
|
||||
WHERE ID BETWEEN 3001 AND 4000 AND Population > 600000
|
||||
AND Country BETWEEN 'S' AND 'Z';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City range PRIMARY,Population,Country PRIMARY 4 NULL # Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country PRIMARY,Population,Country 4,4,7 NULL # Using sort_intersect(PRIMARY,Population,Country); Using where
|
||||
SELECT * FROM City WHERE
|
||||
Name LIKE 'C%' AND Population > 1000000;
|
||||
ID Name Country Population
|
||||
|
@ -683,7 +683,7 @@ key1 key2 key3 key4 filler1
|
||||
-1 -1 100 100 key4-key3
|
||||
explain select key1,key2,key3 from t1 where key1=100 and key2=100 and key3=100;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index_merge key1,key2,key3 key1,key2,key3 5,5,5 NULL 2 Using intersect(key1,key2,key3); Using where; Using index
|
||||
1 SIMPLE t1 index_merge key1,key2,key3 key1,key2 5,5 NULL 77 Using intersect(key1,key2); Using where
|
||||
select key1,key2,key3 from t1 where key1=100 and key2=100 and key3=100;
|
||||
key1 key2 key3
|
||||
100 100 100
|
||||
@ -768,7 +768,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref sta_swt12a,sta_swt1a,sta_swt2a,sta_swt21a,st_a sta_swt21a 12 const,const,const 971
|
||||
explain select * from t1 where st_b=1 and swt1b=1 and swt2b=1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref stb_swt1a_2b,stb_swt1b,st_b stb_swt1a_2b 8 const,const 3879 Using where
|
||||
1 SIMPLE t1 ref stb_swt1a_2b,stb_swt1b,st_b stb_swt1b 8 const,const 3885 Using where
|
||||
explain select * from t1 where st_a=1 and swt1a=1 and swt2a=1 and st_b=1 and swt1b=1 and swt2b=1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index_merge sta_swt12a,sta_swt1a,sta_swt2a,sta_swt21a,st_a,stb_swt1a_2b,stb_swt1b,st_b sta_swt12a,stb_swt1a_2b 12,12 NULL 58 Using intersect(sta_swt12a,stb_swt1a_2b); Using where
|
||||
@ -910,7 +910,7 @@ INSERT INTO t1 (key1, key2, filler)
|
||||
SELECT seq/4, seq/8, 'filler-data' FROM seq_30_to_0;
|
||||
explain select pk from t1 where key1 = 1 and key2 = 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref key1,key2 key1 5 const 4 Using where
|
||||
1 SIMPLE t1 index_merge key1,key2 key1,key2 5,4 NULL 1 Using intersect(key1,key2); Using where
|
||||
select pk from t1 where key2 = 1 and key1 = 1;
|
||||
pk
|
||||
26
|
||||
@ -1487,7 +1487,7 @@ EXPLAIN SELECT t1.f1 FROM t1
|
||||
WHERE (SELECT COUNT(*) FROM t2 WHERE t2.f3 = 'h' AND t2.f2 = t1.f1) = 0 AND t1.f1 = 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 system PRIMARY NULL NULL NULL 1
|
||||
2 SUBQUERY t2 ref f2,f3 f3 2 const 2 Using index condition; Using where
|
||||
2 SUBQUERY t2 index_merge f2,f3 f3,f2 2,5 NULL 1 Using intersect(f3,f2); Using where; Using index
|
||||
DROP TABLE t1,t2;
|
||||
create table t0 (a int);
|
||||
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
|
||||
|
@ -1,17 +1,20 @@
|
||||
--- innodb_ext_key.result
|
||||
+++ innodb_ext_key,off.result
|
||||
--- main/innodb_ext_key.result
|
||||
+++ main/innodb_ext_key,off.reject
|
||||
@@ -9,7 +9,7 @@
|
||||
explain
|
||||
select count(*) from lineitem where l_orderkey=130 and l_shipdate='1992-07-01';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
-1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 8 const,const 1 Using index
|
||||
+1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 const 6 Using where; Using index
|
||||
+1 SIMPLE lineitem index_merge PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey,i_l_shipdate 4,4 NULL 1 Using intersect(i_l_orderkey,i_l_shipdate); Using where; Using index
|
||||
flush status;
|
||||
select count(*) from lineitem where l_orderkey=130 and l_shipdate='1992-07-01';
|
||||
count(*)
|
||||
@@ -19,7 +19,7 @@
|
||||
@@ -17,9 +17,9 @@
|
||||
show status like 'handler_read%';
|
||||
Variable_name Value
|
||||
Handler_read_first 0
|
||||
Handler_read_key 1
|
||||
-Handler_read_key 1
|
||||
+Handler_read_key 2
|
||||
Handler_read_last 0
|
||||
-Handler_read_next 1
|
||||
+Handler_read_next 6
|
||||
@ -95,13 +98,16 @@
|
||||
where l_shipdate='1992-07-01' and l_orderkey=130;
|
||||
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
|
||||
+1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 const 6 Using where; Using index
|
||||
+1 SIMPLE lineitem index_merge PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey,i_l_shipdate 4,4 NULL 1 Using intersect(i_l_orderkey,i_l_shipdate); Using where; Using index
|
||||
flush status;
|
||||
select max(l_linenumber) from lineitem
|
||||
where l_shipdate='1992-07-01' and l_orderkey=130;
|
||||
@@ -145,7 +145,7 @@
|
||||
@@ -143,9 +143,9 @@
|
||||
show status like 'handler_read%';
|
||||
Variable_name Value
|
||||
Handler_read_first 0
|
||||
Handler_read_key 1
|
||||
-Handler_read_key 1
|
||||
+Handler_read_key 2
|
||||
Handler_read_last 0
|
||||
-Handler_read_next 0
|
||||
+Handler_read_next 6
|
||||
@ -249,7 +255,7 @@
|
||||
drop table t1,t2,t3;
|
||||
#
|
||||
# Bug mdev-4340: performance regression with extended_keys=on
|
||||
@@ -714,13 +714,13 @@
|
||||
@@ -725,13 +725,13 @@
|
||||
select * from t1 force index(index_date_updated)
|
||||
where index_date_updated= 10 and index_id < 800;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -265,7 +271,7 @@
|
||||
drop table t0,t1,t2;
|
||||
#
|
||||
# MDEV-11196: Error:Run-Time Check Failure #2 - Stack around the variable 'key_buff'
|
||||
@@ -768,11 +768,12 @@
|
||||
@@ -766,13 +766,14 @@
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
@ -279,9 +285,12 @@
|
||||
+ "used_key_parts": ["f2"],
|
||||
+ "ref": ["const"],
|
||||
"rows": 1,
|
||||
"filtered": 100,
|
||||
- "filtered": 50,
|
||||
+ "filtered": 100,
|
||||
"index_condition": "t1.pk1 <= 5 and t1.pk2 <= 5 and t1.f2 = 'abc'",
|
||||
@@ -805,8 +806,8 @@
|
||||
"attached_condition": "t1.f1 <= '3'"
|
||||
}
|
||||
@@ -799,8 +800,8 @@
|
||||
"access_type": "range",
|
||||
"possible_keys": ["k1"],
|
||||
"key": "k1",
|
||||
@ -290,5 +299,5 @@
|
||||
+ "key_length": "3007",
|
||||
+ "used_key_parts": ["pk1", "f2"],
|
||||
"rows": 1,
|
||||
"filtered": 100,
|
||||
"filtered": 50,
|
||||
"index_condition": "t1.f2 <= 5 and t1.pk2 <= 5 and t1.pk1 = 'abc'",
|
||||
|
@ -386,8 +386,8 @@ WHERE c = a AND b IN (SELECT b FROM t1, t2 WHERE b = t.b);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t index a,b b 7 NULL 10 Using index
|
||||
1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 test.t.a 1 Using index
|
||||
1 PRIMARY t1 ref b b 3 test.t.b 2 Using index; Start temporary
|
||||
1 PRIMARY t2 index NULL PRIMARY 4 NULL 11 Using index; End temporary; Using join buffer (flat, BNL join)
|
||||
1 PRIMARY t1 ref b b 3 test.t.b 2 Using index
|
||||
1 PRIMARY t2 index NULL PRIMARY 4 NULL 11 Using index; FirstMatch(t2)
|
||||
SELECT a FROM t1 AS t, t2
|
||||
WHERE c = a AND b IN (SELECT b FROM t1, t2 WHERE b = t.b);
|
||||
a
|
||||
@ -638,14 +638,14 @@ test.t2 analyze status Engine-independent statistics collected
|
||||
test.t2 analyze status OK
|
||||
explain select a from t1 where b is null order by a desc limit 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index b PRIMARY 8 NULL 2 Using where
|
||||
1 SIMPLE t1 range b b 9 NULL 3 Using where; Using filesort
|
||||
select a from t1 where b is null order by a desc limit 2;
|
||||
a
|
||||
3
|
||||
2
|
||||
explain select a from t2 where b is null order by a desc limit 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range b b 9 NULL 3 Using where; Using filesort
|
||||
1 SIMPLE t2 index b PRIMARY 8 NULL 2 Using where
|
||||
select a from t2 where b is null order by a desc limit 2;
|
||||
a
|
||||
3
|
||||
@ -774,7 +774,7 @@ EXPLAIN
|
||||
"key_length": "3070",
|
||||
"used_key_parts": ["f2", "pk1"],
|
||||
"rows": 1,
|
||||
"filtered": 100,
|
||||
"filtered": 50,
|
||||
"index_condition": "t1.pk1 <= 5 and t1.pk2 <= 5 and t1.f2 = 'abc'",
|
||||
"attached_condition": "t1.f1 <= '3'"
|
||||
}
|
||||
@ -808,7 +808,7 @@ EXPLAIN
|
||||
"key_length": "3011",
|
||||
"used_key_parts": ["pk1", "f2", "pk2"],
|
||||
"rows": 1,
|
||||
"filtered": 100,
|
||||
"filtered": 50,
|
||||
"index_condition": "t1.f2 <= 5 and t1.pk2 <= 5 and t1.pk1 = 'abc'",
|
||||
"attached_condition": "t1.f1 <= '3'"
|
||||
}
|
||||
|
@ -880,7 +880,7 @@ select @a:= A.a + 10*(B.a + 10*C.a), @a, 'filler' from t1 A, t1 B, t1 C;
|
||||
insert into t3 select * from t2 where a < 800;
|
||||
explain select * from t2,t3 where t2.a < 200 and t2.b=t3.b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL a,b NULL NULL NULL 1000 Using where
|
||||
1 SIMPLE t2 range a,b a 5 NULL 198 Using index condition; Using where
|
||||
1 SIMPLE t3 ref b b 5 test.t2.b 1
|
||||
drop table t1, t2, t3;
|
||||
create table t1 (a int);
|
||||
@ -892,13 +892,14 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 6.016090
|
||||
Last_query_cost 3.508545
|
||||
select 'The cost of accessing t1 (dont care if it changes' '^';
|
||||
The cost of accessing t1 (dont care if it changes
|
||||
The cost of accessing t1 (dont care if it changes^
|
||||
select 'vv: Following query must use ALL(t1), eq_ref(A), eq_ref(B): vv' Z;
|
||||
Z
|
||||
vv: Following query must use ALL(t1), eq_ref(A), eq_ref(B): vv
|
||||
set @@optimizer_cache_hit_ratio=0;
|
||||
explain select * from t1, t2 A, t2 B where A.a = t1.a and B.a=A.b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
|
||||
@ -906,10 +907,11 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE B eq_ref PRIMARY PRIMARY 4 test.A.b 1
|
||||
show status like 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 34.016090
|
||||
select '^^: The above should be ~= 20 + cost(select * from t1). Value less than 20 is an error' Z;
|
||||
Last_query_cost 48.527829
|
||||
select '^^: The above should be ~= 40 + cost(select * from t1). Value less than 40 is an error' Z;
|
||||
Z
|
||||
^^: The above should be ~= 20 + cost(select * from t1). Value less than 20 is an error
|
||||
^^: The above should be ~= 40 + cost(select * from t1). Value less than 40 is an error
|
||||
set @@optimizer_cache_hit_ratio=default;
|
||||
drop table t1, t2;
|
||||
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
|
||||
CREATE TABLE t2 (c INT PRIMARY KEY, d INT);
|
||||
@ -1274,20 +1276,24 @@ test.t1 analyze status Engine-independent statistics collected
|
||||
test.t1 analyze status OK
|
||||
test.t2 analyze status Engine-independent statistics collected
|
||||
test.t2 analyze status OK
|
||||
explain SELECT * FROM t1 JOIN t2 ON t1.v = t2.v WHERE t2.v IS NULL ORDER BY 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL ix2 NULL NULL NULL 2 Using where; Using temporary; Using filesort
|
||||
1 SIMPLE t1 ref ix1 ix1 5 test.t2.v 1
|
||||
FLUSH STATUS;
|
||||
SELECT * FROM t1 JOIN t2 ON t1.v = t2.v WHERE t2.v IS NULL ORDER BY 1;
|
||||
pk v pk v
|
||||
SHOW STATUS LIKE 'Handler_read_%';
|
||||
Variable_name Value
|
||||
Handler_read_first 0
|
||||
Handler_read_key 14
|
||||
Handler_read_key 0
|
||||
Handler_read_last 0
|
||||
Handler_read_next 0
|
||||
Handler_read_prev 0
|
||||
Handler_read_retry 0
|
||||
Handler_read_rnd 0
|
||||
Handler_read_rnd_deleted 0
|
||||
Handler_read_rnd_next 1
|
||||
Handler_read_rnd_next 4
|
||||
DROP TABLE t1, t2;
|
||||
End of 5.1 tests
|
||||
#
|
||||
@ -1473,8 +1479,8 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE DU system dog_id NULL NULL NULL 1
|
||||
1 SIMPLE D system PRIMARY NULL NULL NULL 1
|
||||
1 SIMPLE DSAR system NULL NULL NULL NULL 1
|
||||
1 SIMPLE DSA ref PRIMARY PRIMARY 4 const 3 Using where; Using index
|
||||
1 SIMPLE DT ALL t_id NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE DT ALL t_id NULL NULL NULL 2 Using where
|
||||
1 SIMPLE DSA ref PRIMARY PRIMARY 8 const,test.DT.t_id,func 1 Using index
|
||||
SELECT * FROM t5 DU, t1 D, t4 DT, t2 DSA, t3 DSAR
|
||||
WHERE DU.dog_id=D.dog_id AND D.dog_id=DT.dog_id AND D.birthday=DT.birthday AND
|
||||
DT.t_id=DSA.t_id AND DT.birthday=DSA.birthday AND DSA.dog_id=DSAR.dog_id;
|
||||
|
@ -697,12 +697,11 @@ select 'The cost of accessing t1 (dont care if it changes' '^';
|
||||
|
||||
select 'vv: Following query must use ALL(t1), eq_ref(A), eq_ref(B): vv' Z;
|
||||
|
||||
set @@optimizer_cache_hit_ratio=0;
|
||||
explain select * from t1, t2 A, t2 B where A.a = t1.a and B.a=A.b;
|
||||
show status like 'Last_query_cost';
|
||||
select '^^: The above should be ~= 20 + cost(select * from t1). Value less than 20 is an error' Z;
|
||||
|
||||
|
||||
|
||||
select '^^: The above should be ~= 40 + cost(select * from t1). Value less than 40 is an error' Z;
|
||||
set @@optimizer_cache_hit_ratio=default;
|
||||
drop table t1, t2;
|
||||
|
||||
#
|
||||
@ -957,6 +956,9 @@ INSERT INTO t1 VALUES (3,'b'),(4,NULL),(5,'c'),(6,'cc'),(7,'d'),
|
||||
(8,'dd'),(9,'e'),(10,'ee');
|
||||
INSERT INTO t2 VALUES (2,NULL);
|
||||
ANALYZE TABLE t1,t2;
|
||||
# This will ensure that status tables are read now and not part of the later
|
||||
# Handler_read% counts
|
||||
explain SELECT * FROM t1 JOIN t2 ON t1.v = t2.v WHERE t2.v IS NULL ORDER BY 1;
|
||||
FLUSH STATUS;
|
||||
SELECT * FROM t1 JOIN t2 ON t1.v = t2.v WHERE t2.v IS NULL ORDER BY 1;
|
||||
SHOW STATUS LIKE 'Handler_read_%';
|
||||
|
@ -53,6 +53,7 @@ set join_cache_level=1;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 1
|
||||
# Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -60,6 +61,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -79,6 +81,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -91,6 +94,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage ALL NULL NULL NULL NULL 984 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -131,6 +135,7 @@ set join_cache_level=2;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 2
|
||||
# join_cache_level 2, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -138,6 +143,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# join_cache_level 2, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -157,6 +163,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 2, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -169,6 +176,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage ALL NULL NULL NULL NULL 984 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (incremental, BNL join)
|
||||
# join_cache_level 2, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -209,6 +217,7 @@ set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 3
|
||||
# join_cache_level 3, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -216,6 +225,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 3, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -235,6 +245,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 3, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -247,6 +258,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL NULL #hash#$hj 3 world.Country.Code 984 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 3, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -287,6 +299,7 @@ set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 4
|
||||
# join_cache_level 4, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -294,6 +307,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 4, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -313,6 +327,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 4, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -325,6 +340,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL NULL #hash#$hj 3 world.Country.Code 984 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (incremental, BNLH join)
|
||||
# join_cache_level 4, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -361,6 +377,7 @@ Ludwigshafen am Rhein Germany German
|
||||
Lungtan Taiwan Min
|
||||
L´Hospitalet de Llobregat Spain Spanish
|
||||
Lázaro Cárdenas Mexico Spanish
|
||||
# join_cache_level 4, Query 5
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
@ -379,6 +396,7 @@ Canada 31147000 NULL NULL
|
||||
Cuba 11201000 NULL NULL
|
||||
Côte d?Ivoire 14786000 NULL NULL
|
||||
Czech Republic 10278100 NULL NULL
|
||||
# join_cache_level 4, Query 6
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -404,6 +422,7 @@ Czech Republic 10278100 NULL NULL
|
||||
CREATE INDEX City_Population ON City(Population);
|
||||
CREATE INDEX City_Name ON City(Name);
|
||||
ANALYZE TABLE City;
|
||||
# After Analyze, Query 1
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -412,6 +431,7 @@ WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_range City_Population #hash#$hj:City_Population 3:4 world.Country.Code 24 Using where; Rowid-ordered scan; Using join buffer (flat, BNLH join)
|
||||
# After Analyze, Query 2
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
@ -430,6 +450,7 @@ Canada 31147000 NULL NULL
|
||||
Cuba 11201000 NULL NULL
|
||||
Côte d?Ivoire 14786000 NULL NULL
|
||||
Czech Republic 10278100 NULL NULL
|
||||
# After Analyze, Query 3
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -439,6 +460,7 @@ WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_index_merge City_Population,City_Name #hash#$hj:City_Population,City_Name 3:4,35 world.Country.Code 96 Using sort_union(City_Population,City_Name); Using where; Using join buffer (flat, BNLH join)
|
||||
# After Analyze, Query 4
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -471,6 +493,7 @@ join_buffer_size 256
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 1
|
||||
# join_cache_level 1, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -478,6 +501,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# join_cache_level 1, Join_buffer_size, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -497,6 +521,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 1, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -509,6 +534,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage ALL NULL NULL NULL NULL 984 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# join_cache_level 1, Join_buffer_size, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -549,6 +575,7 @@ set join_cache_level=2;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 2
|
||||
# join_cache_level 2, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -556,6 +583,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (flat, BNL join)
|
||||
# join_cache_level 2, Join_buffer_size, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -575,6 +603,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 2, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -587,6 +616,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage ALL NULL NULL NULL NULL 984 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE City ALL NULL NULL NULL NULL 4079 Using where; Using join buffer (incremental, BNL join)
|
||||
# join_cache_level 2, Join_buffer_size, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -627,6 +657,7 @@ set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 3
|
||||
# join_cache_level 3, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -634,6 +665,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 3, Join_buffer_size, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -653,6 +685,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 3, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -665,6 +698,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL NULL #hash#$hj 3 world.Country.Code 984 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 3, Join_buffer_size, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -705,6 +739,7 @@ set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 4
|
||||
# join_cache_level 4, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -712,6 +747,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# join_cache_level 4, Join_buffer_size, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -731,6 +767,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# join_cache_level 4, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -743,6 +780,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL NULL #hash#$hj 3 world.Country.Code 984 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE City hash_ALL NULL #hash#$hj 3 world.Country.Code 4079 Using where; Using join buffer (incremental, BNLH join)
|
||||
# join_cache_level 4, Join_buffer_size, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -816,6 +854,7 @@ set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 3
|
||||
# Part 2, join_cache_level=3, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -823,6 +862,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country range PRIMARY,Name Name 52 NULL 10 Using index condition; Rowid-ordered scan
|
||||
1 SIMPLE City hash_ALL Population,Country #hash#Country 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=3, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -842,6 +882,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# Part 2, join_cache_level=3, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -853,7 +894,8 @@ LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City ALL Country NULL NULL NULL 4079 Using where
|
||||
1 SIMPLE Country hash_ALL PRIMARY #hash#PRIMARY 3 world.City.Country 239 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE CountryLanguage hash_ALL|filter PRIMARY,Percentage #hash#PRIMARY|Percentage 3|4 world.City.Country 984 (19%) Using where; Using join buffer (flat, BNLH join); Using rowid filter
|
||||
1 SIMPLE CountryLanguage hash_range PRIMARY,Percentage #hash#PRIMARY:Percentage 3:4 world.City.Country 185 Using where; Rowid-ordered scan; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=3, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -890,6 +932,7 @@ Ludwigshafen am Rhein Germany German
|
||||
Lungtan Taiwan Min
|
||||
L´Hospitalet de Llobregat Spain Spanish
|
||||
Lázaro Cárdenas Mexico Spanish
|
||||
# Part 2, join_cache_level=3, Query 5
|
||||
EXPLAIN
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
@ -897,6 +940,7 @@ City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY Country range PRIMARY,Name Name 52 NULL 10 Using index condition; Rowid-ordered scan
|
||||
1 PRIMARY City hash_ALL Population,Country #hash#Country 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=3, Query 6
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
@ -916,6 +960,7 @@ Kaunas
|
||||
Klaipeda
|
||||
?iauliai
|
||||
Panevezys
|
||||
# Part 2, join_cache_level=3, Query 7
|
||||
EXPLAIN
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
@ -925,6 +970,7 @@ Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL PRIMARY #hash#PRIMARY 33 world.Country.Code,const 984 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=3, Query 8
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
(CountryLanguage.Country=Country.Code AND Language='English')
|
||||
@ -1016,6 +1062,7 @@ set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
join_cache_level 4
|
||||
# Part 2, join_cache_level=4, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -1023,6 +1070,7 @@ Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country range PRIMARY,Name Name 52 NULL 10 Using index condition; Rowid-ordered scan
|
||||
1 SIMPLE City hash_ALL Population,Country #hash#Country 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=4, Query 2
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
@ -1042,6 +1090,7 @@ Tripoli Lebanon
|
||||
Tripoli Libyan Arab Jamahiriya
|
||||
Vientiane Laos
|
||||
Vilnius Lithuania
|
||||
# Part 2, join_cache_level=4, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -1053,7 +1102,8 @@ LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City ALL Country NULL NULL NULL 4079 Using where
|
||||
1 SIMPLE Country hash_ALL PRIMARY #hash#PRIMARY 3 world.City.Country 239 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE CountryLanguage hash_ALL|filter PRIMARY,Percentage #hash#PRIMARY|Percentage 3|4 world.City.Country 984 (19%) Using where; Using join buffer (incremental, BNLH join); Using rowid filter
|
||||
1 SIMPLE CountryLanguage hash_range PRIMARY,Percentage #hash#PRIMARY:Percentage 3:4 world.City.Country 185 Using where; Rowid-ordered scan; Using join buffer (incremental, BNLH join)
|
||||
# Part 2, join_cache_level=4, Query 4
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -1090,6 +1140,7 @@ Ludwigshafen am Rhein Germany German
|
||||
Lungtan Taiwan Min
|
||||
L´Hospitalet de Llobregat Spain Spanish
|
||||
Lázaro Cárdenas Mexico Spanish
|
||||
# Part 2, join_cache_level=4, Query 5
|
||||
EXPLAIN
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
@ -1097,6 +1148,7 @@ City.Population > 100000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY Country range PRIMARY,Name Name 52 NULL 10 Using index condition; Rowid-ordered scan
|
||||
1 PRIMARY City hash_ALL Population,Country #hash#Country 3 world.Country.Code 4079 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=4, Query 6
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
@ -1116,6 +1168,7 @@ Kaunas
|
||||
Klaipeda
|
||||
?iauliai
|
||||
Panevezys
|
||||
# Part 2, join_cache_level=4, Query 7
|
||||
EXPLAIN
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
@ -1125,6 +1178,7 @@ Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country ALL NULL NULL NULL NULL 239 Using where
|
||||
1 SIMPLE CountryLanguage hash_ALL PRIMARY #hash#PRIMARY 33 world.Country.Code,const 984 Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=4, Query 8
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
(CountryLanguage.Country=Country.Code AND Language='English')
|
||||
@ -1209,6 +1263,7 @@ Belarus NULL
|
||||
Venezuela NULL
|
||||
Russian Federation NULL
|
||||
Vietnam NULL
|
||||
# Part 2, join_cache_level=4, Query 9
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -1217,6 +1272,7 @@ WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country range Name Name 52 NULL # Using index condition; Using where; Rowid-ordered scan
|
||||
1 SIMPLE City hash_range Population,Country #hash#Country:Population 3:4 world.Country.Code # Using where; Rowid-ordered scan; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=4, Query 10
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
@ -1236,6 +1292,7 @@ Cuba 11201000 NULL NULL
|
||||
Côte d?Ivoire 14786000 NULL NULL
|
||||
Czech Republic 10278100 NULL NULL
|
||||
CREATE INDEX City_Name ON City(Name);
|
||||
# Part 2, join_cache_level=4, City_Name, Query 1
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -1245,6 +1302,7 @@ WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE Country range Name Name 52 NULL 17 Using index condition; Using where; Rowid-ordered scan
|
||||
1 SIMPLE City hash_index_merge Population,Country,City_Name #hash#Country:Population,City_Name 3:4,35 world.Country.Code 96 Using sort_union(Population,City_Name); Using where; Using join buffer (flat, BNLH join)
|
||||
# Part 2, join_cache_level=4, City_Name, Query 2
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -2104,7 +2162,7 @@ LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City ALL Country NULL NULL NULL 4079 Using where
|
||||
1 SIMPLE Country hash_ALL PRIMARY #hash#PRIMARY 3 world.City.Country 239 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE CountryLanguage hash_ALL|filter PRIMARY,Percentage #hash#PRIMARY|Percentage 3|4 world.City.Country 984 (19%) Using where; Using join buffer (flat, BNLH join); Using rowid filter
|
||||
1 SIMPLE CountryLanguage hash_range PRIMARY,Percentage #hash#PRIMARY:Percentage 3:4 world.City.Country 185 Using where; Rowid-ordered scan; Using join buffer (flat, BNLH join)
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -2208,7 +2266,7 @@ LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City ALL Country NULL NULL NULL 4079 Using where
|
||||
1 SIMPLE Country hash_ALL PRIMARY #hash#PRIMARY 3 world.City.Country 239 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE CountryLanguage hash_ALL|filter PRIMARY,Percentage #hash#PRIMARY|Percentage 3|4 world.City.Country 984 (19%) Using where; Using join buffer (incremental, BNLH join); Using rowid filter
|
||||
1 SIMPLE CountryLanguage hash_range PRIMARY,Percentage #hash#PRIMARY:Percentage 3:4 world.City.Country 185 Using where; Rowid-ordered scan; Using join buffer (incremental, BNLH join)
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
WHERE City.Country=Country.Code AND
|
||||
@ -3075,7 +3133,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t8 eq_ref PRIMARY PRIMARY 4 test.t7.artistid 1 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t3 ref t3_metaid,t3_formatid,t3_metaidformatid t3_metaidformatid 4 test.t9.metaid 1 Using index condition; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t4 eq_ref PRIMARY,t4_formatclassid,t4_formats_idx PRIMARY 4 test.t3.formatid 1 Using where; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t1 ref t1_affiliateid,t1_metaid t1_affiliateid 4 const 2 Using where; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t1 ALL t1_affiliateid,t1_metaid NULL NULL NULL 2 Using where; Using join buffer (incremental, BNL join)
|
||||
SELECT t1.uniquekey, t1.xml AS affiliateXml,
|
||||
t8.name AS artistName, t8.artistid,
|
||||
t11.name AS genreName, t11.genreid, t11.priority AS genrePriority,
|
||||
@ -3191,7 +3249,7 @@ Warning 1292 Truncated incorrect join_buffer_size value: '32'
|
||||
set join_cache_level=8;
|
||||
EXPLAIN SELECT * FROM t1,t2 WHERE t1.a=t2.a AND t1.b >= 30;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range idx idx 5 NULL 3 Using index condition; Using where; Rowid-ordered scan
|
||||
1 SIMPLE t1 ALL idx NULL NULL NULL 7 Using where
|
||||
1 SIMPLE t2 ref idx idx 5 test.t1.a 2 Using join buffer (flat, BKAH join); Key-ordered Rowid-ordered scan
|
||||
SELECT * FROM t1,t2 WHERE t1.a=t2.a AND t1.b >= 30;
|
||||
a b a b
|
||||
@ -3371,8 +3429,8 @@ set join_cache_level=6;
|
||||
set join_buffer_size=1024;
|
||||
EXPLAIN SELECT AVG(c) FROM t1,t2 WHERE t1.a=t2.b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 2050 Using where
|
||||
1 SIMPLE t2 ref idx idx 5 test.t1.a 640 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t2 ALL idx NULL NULL NULL 1280 Using where
|
||||
1 SIMPLE t1 hash_ALL NULL #hash#$hj 5 test.t2.b 2050 Using where; Using join buffer (flat, BNLH join)
|
||||
SELECT AVG(c) FROM t1,t2 WHERE t1.a=t2.b;
|
||||
AVG(c)
|
||||
5.0000
|
||||
@ -4969,8 +5027,8 @@ FROM ((t1 LEFT JOIN (t2 JOIN t3 ON t2.a2 = t3.a3) ON t2.b2 = t1.a1)
|
||||
LEFT JOIN t4 ON t4.a4 <> 0) LEFT JOIN t5 ON t5.a5 = t2.a2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 2
|
||||
1 SIMPLE t2 ALL PRIMARY NULL NULL NULL 1 Using where
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.a2 1 Using index
|
||||
1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 1 Using where; Using index
|
||||
1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t3.a3 1 Using where
|
||||
1 SIMPLE t4 ALL NULL NULL NULL NULL 1 Using where
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t2.a2 1 Using where
|
||||
SELECT t4.a4, t5.b5
|
||||
@ -5054,13 +5112,15 @@ CREATE TABLE t2 (
|
||||
f3 int(11), f2 varchar(1024), f4 varchar(10), PRIMARY KEY (f3)
|
||||
);
|
||||
INSERT INTO t2 VALUES (6,'RPOYT','y'),(10,'JINQE','m');
|
||||
INSERT INTO t2 VALUES (100,'Q','q'),(101,'Q','q'),(102,'Q','q'),(103,'Q','q');
|
||||
INSERT INTO t2 VALUES (104,'Q','q'),(105,'Q','q'),(106,'Q','q'),(107,'Q','q');
|
||||
SET SESSION join_cache_level = 1;
|
||||
SET SESSION optimizer_switch = 'index_condition_pushdown=off';
|
||||
EXPLAIN
|
||||
SELECT * FROM t1,t2
|
||||
WHERE t1.f1 = t2.f4 AND (t1.f3 = 1 AND t2.f3 = 4 OR t1.f3 = 2 AND t2.f3 = 6);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 2 Using where; Rowid-ordered scan
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 2 Using where
|
||||
1 SIMPLE t2 range PRIMARY PRIMARY 4 NULL 2 Using where; Rowid-ordered scan; Using join buffer (flat, BNL join)
|
||||
SELECT * FROM t1,t2
|
||||
WHERE t1.f1 = t2.f4 AND (t1.f3 = 1 AND t2.f3 = 4 OR t1.f3 = 2 AND t2.f3 = 6);
|
||||
@ -5070,7 +5130,7 @@ EXPLAIN
|
||||
SELECT * FROM t1,t2
|
||||
WHERE t1.f1 = t2.f4 AND (t1.f3 = 1 AND t2.f3 = 4 OR t1.f3 = 2 AND t2.f3 = 6);
|
||||
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; Rowid-ordered scan
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 2 Using where
|
||||
1 SIMPLE t2 range PRIMARY PRIMARY 4 NULL 2 Using index condition; Using where; Rowid-ordered scan; Using join buffer (flat, BNL join)
|
||||
SELECT * FROM t1,t2
|
||||
WHERE t1.f1 = t2.f4 AND (t1.f3 = 1 AND t2.f3 = 4 OR t1.f3 = 2 AND t2.f3 = 6);
|
||||
@ -5523,7 +5583,7 @@ and t2.uid=t1.fid;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t3 ref uid uid 5 const 4 Using where; Start temporary
|
||||
1 PRIMARY t4 eq_ref PRIMARY PRIMARY 4 test.t3.fid 1 Using index
|
||||
1 PRIMARY t1 ALL uid NULL NULL NULL 11 Using where; End temporary; Using join buffer (flat, BNL join)
|
||||
1 PRIMARY t1 ref uid uid 5 test.t3.fid 2 Using where; End temporary; Using join buffer (flat, BKAH join); Rowid-ordered scan
|
||||
1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 test.t1.fid 1 Using join buffer (flat, BKAH join); Rowid-ordered scan
|
||||
select name from t2, t1
|
||||
where t1.uid in (select t4.uid from t4, t3 where t3.uid=1 and t4.uid=t3.fid)
|
||||
@ -6150,8 +6210,8 @@ a b c
|
||||
explain select t1.a, t1.b, t1.c from t1,t2
|
||||
where t2.a = t1.a and t2.b = t1.b and t2.c=t1.c;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 Using where
|
||||
1 SIMPLE t2 hash_index PRIMARY #hash#PRIMARY:PRIMARY 12:12 test.t1.c,test.t1.a,test.t1.b 2 Using index; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 12 NULL 2 Using index
|
||||
1 SIMPLE t1 hash_ALL NULL #hash#$hj 15 test.t2.a,test.t2.b,test.t2.c 2 Using where; Using join buffer (flat, BNLH join)
|
||||
drop table t1,t2;
|
||||
set join_cache_level=@save_join_cache_level;
|
||||
#
|
||||
@ -6198,7 +6258,7 @@ EXPLAIN
|
||||
{
|
||||
"table": {
|
||||
"table_name": "a",
|
||||
"access_type": "range",
|
||||
"access_type": "index",
|
||||
"possible_keys": ["PRIMARY"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
|
@ -6,6 +6,7 @@
|
||||
DROP TABLE IF EXISTS t1,t2,t3,t4,t5,t6,t7,t8,t9,t10,t11;
|
||||
DROP DATABASE IF EXISTS world;
|
||||
--enable_warnings
|
||||
--source include/have_innodb.inc
|
||||
|
||||
set @org_optimizer_switch=@@optimizer_switch;
|
||||
set @save_join_cache_level=@@join_cache_level;
|
||||
@ -53,16 +54,19 @@ set join_cache_level=1;
|
||||
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -72,6 +76,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -84,16 +89,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=2;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 2, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 2, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 2, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -103,6 +111,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 2, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -115,16 +124,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 3, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 3, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 3, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -134,7 +146,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
|
||||
--echo # join_cache_level 3, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -148,16 +160,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 4, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 4, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 4, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -167,6 +182,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 4, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -177,11 +193,13 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
|
||||
--echo # join_cache_level 4, Query 5
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # join_cache_level 4, Query 6
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -195,17 +213,20 @@ CREATE INDEX City_Name ON City(Name);
|
||||
ANALYZE TABLE City;
|
||||
--enable_result_log
|
||||
|
||||
--echo # After Analyze, Query 1
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # After Analyze, Query 2
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # After Analyze, Query 3
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -213,6 +234,7 @@ SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
(City.Population > 5000000 OR City.Name LIKE 'Za%')
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # After Analyze, Query 4
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -229,16 +251,19 @@ show variables like 'join_buffer_size';
|
||||
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 1, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 1, Join_buffer_size, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 1, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -248,6 +273,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 1, Join_buffer_size, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -260,16 +286,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=2;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 2, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 2, Join_buffer_size, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 2, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -279,6 +308,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 2, Join_buffer_size, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -291,16 +321,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 3, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 3, Join_buffer_size, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 3, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -310,6 +343,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 3, Join_buffer_size, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -322,16 +356,19 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # join_cache_level 4, Join_buffer_size, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 4, Join_buffer_size, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # join_cache_level 4, Join_buffer_size, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -341,6 +378,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # join_cache_level 4, Join_buffer_size, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -374,16 +412,19 @@ show variables like 'join_buffer_size';
|
||||
set join_cache_level=3;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -393,6 +434,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -402,15 +444,18 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 5
|
||||
EXPLAIN
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 6
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 7
|
||||
#enable after fix MDEV-27871
|
||||
--disable_view_protocol
|
||||
|
||||
@ -421,6 +466,7 @@ SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.P
|
||||
WHERE
|
||||
Country.Population > 10000000;
|
||||
|
||||
--echo # Part 2, join_cache_level=3, Query 8
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
(CountryLanguage.Country=Country.Code AND Language='English')
|
||||
@ -433,16 +479,19 @@ show variables like 'join_buffer_size';
|
||||
set join_cache_level=4;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 1
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 2
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name FROM City,Country
|
||||
WHERE City.Country=Country.Code AND
|
||||
Country.Name LIKE 'L%' AND City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 3
|
||||
EXPLAIN
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -452,6 +501,7 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 4
|
||||
--sorted_result
|
||||
SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
FROM City,Country,CountryLanguage
|
||||
@ -461,15 +511,18 @@ SELECT City.Name, Country.Name, CountryLanguage.Language
|
||||
CountryLanguage.Percentage > 50 AND
|
||||
LENGTH(Language) < LENGTH(City.Name) - 2;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 5
|
||||
EXPLAIN
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 6
|
||||
SELECT Name FROM City
|
||||
WHERE City.Country IN (SELECT Code FROM Country WHERE Country.Name LIKE 'L%') AND
|
||||
City.Population > 100000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 7
|
||||
#enable after fix MDEV-27871
|
||||
--disable_view_protocol
|
||||
|
||||
@ -480,6 +533,7 @@ SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.P
|
||||
WHERE
|
||||
Country.Population > 10000000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 8
|
||||
SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.Percentage)
|
||||
FROM Country LEFT JOIN CountryLanguage ON
|
||||
(CountryLanguage.Country=Country.Code AND Language='English')
|
||||
@ -487,7 +541,7 @@ SELECT Country.Name, IF(ISNULL(CountryLanguage.Country), NULL, CountryLanguage.P
|
||||
Country.Population > 10000000;
|
||||
|
||||
--enable_view_protocol
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 9
|
||||
--replace_column 9 #
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
@ -495,6 +549,7 @@ SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, Query 10
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND City.Population > 5000000
|
||||
@ -502,6 +557,7 @@ SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
|
||||
CREATE INDEX City_Name ON City(Name);
|
||||
|
||||
--echo # Part 2, join_cache_level=4, City_Name, Query 1
|
||||
EXPLAIN
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
@ -509,6 +565,7 @@ SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
(City.Population > 5000000 OR City.Name LIKE 'Za%')
|
||||
WHERE Country.Name LIKE 'C%' AND Country.Population > 10000000;
|
||||
|
||||
--echo # Part 2, join_cache_level=4, City_Name, Query 2
|
||||
SELECT Country.Name, Country.Population, City.Name, City.Population
|
||||
FROM Country LEFT JOIN City
|
||||
ON City.Country=Country.Code AND
|
||||
@ -3206,6 +3263,8 @@ CREATE TABLE t2 (
|
||||
f3 int(11), f2 varchar(1024), f4 varchar(10), PRIMARY KEY (f3)
|
||||
);
|
||||
INSERT INTO t2 VALUES (6,'RPOYT','y'),(10,'JINQE','m');
|
||||
INSERT INTO t2 VALUES (100,'Q','q'),(101,'Q','q'),(102,'Q','q'),(103,'Q','q');
|
||||
INSERT INTO t2 VALUES (104,'Q','q'),(105,'Q','q'),(106,'Q','q'),(107,'Q','q');
|
||||
|
||||
SET SESSION join_cache_level = 1;
|
||||
|
||||
@ -3808,8 +3867,6 @@ drop table t0,t1,t2;
|
||||
--echo # of LEFT JOIN operations when using join buffer
|
||||
--echo #
|
||||
|
||||
--source include/have_innodb.inc
|
||||
|
||||
CREATE TABLE t1 (
|
||||
id int(11) NOT NULL AUTO_INCREMENT,
|
||||
col1 varchar(255) NOT NULL DEFAULT '',
|
||||
|
@ -695,21 +695,21 @@ t0.b=t1.b AND
|
||||
(t9.a=1);
|
||||
a b a b a b a b a b a b a b a b a b a b
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
SELECT t1.a,t1.b
|
||||
FROM t1;
|
||||
@ -1062,9 +1062,9 @@ t0.b=t1.b AND
|
||||
(t8.b=t9.b OR t8.c IS NULL) AND
|
||||
(t9.a=1);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t0 ref idx_a idx_a 5 const 2 100.00
|
||||
1 SIMPLE t0 ALL idx_a NULL NULL NULL 3 66.67 Using where
|
||||
1 SIMPLE t1 ref idx_b idx_b 5 test.t0.b 2 100.00
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 ALL idx_b NULL NULL NULL 7 75.00 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t5 ALL idx_b NULL NULL NULL 7 100.00 Using where
|
||||
1 SIMPLE t7 ALL NULL NULL NULL NULL 2 100.00 Using where
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
@ -1743,10 +1743,10 @@ LEFT JOIN
|
||||
ON t4.carrier = t1.carrier;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index package_id package_id 5 NULL 45 Using where; Using index
|
||||
1 SIMPLE t3 ref package_id package_id 5 test.t2.package_id 1 Using index
|
||||
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t2.package_id 1
|
||||
1 SIMPLE t4 eq_ref PRIMARY,id PRIMARY 2 test.t1.carrier 1 Using where
|
||||
1 SIMPLE t5 ref carrier_id carrier_id 5 test.t4.id 22 Using index
|
||||
1 SIMPLE t3 ref package_id package_id 5 test.t2.package_id 1 Using index
|
||||
SELECT COUNT(*)
|
||||
FROM ((t2 JOIN t1 ON t2.package_id = t1.id)
|
||||
JOIN t3 ON t3.package_id = t1.id)
|
||||
|
@ -364,6 +364,7 @@ SELECT t0.a,t0.b,t1.a,t1.b,t2.a,t2.b,t3.a,t3.b,t4.a,t4.b,
|
||||
SELECT t9.a,t9.b
|
||||
FROM t9;
|
||||
|
||||
--sorted_result
|
||||
SELECT t0.a,t0.b,t1.a,t1.b,t2.a,t2.b,t3.a,t3.b,t4.a,t4.b,
|
||||
t5.a,t5.b,t6.a,t6.b,t7.a,t7.b,t8.a,t8.b,t9.a,t9.b
|
||||
FROM t0,t1
|
||||
|
@ -652,6 +652,7 @@ t0.b=t1.b AND
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t0 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
1 SIMPLE t1 hash_ALL NULL #hash#$hj 5 test.t0.b 3 100.00 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t4 hash_ALL NULL #hash#$hj 5 test.t2.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
@ -659,9 +660,8 @@ id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t7 hash_ALL NULL #hash#$hj 5 test.t5.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t8 hash_ALL NULL #hash#$hj 5 test.t5.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t0`.`a` AS `a`,`test`.`t0`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t5`.`a` AS `a`,`test`.`t5`.`b` AS `b`,`test`.`t6`.`a` AS `a`,`test`.`t6`.`b` AS `b`,`test`.`t7`.`a` AS `a`,`test`.`t7`.`b` AS `b`,`test`.`t8`.`a` AS `a`,`test`.`t8`.`b` AS `b`,`test`.`t9`.`a` AS `a`,`test`.`t9`.`b` AS `b` from `test`.`t0` join `test`.`t1` left join (`test`.`t2` left join (`test`.`t3` join `test`.`t4`) on(`test`.`t3`.`a` = 1 and `test`.`t4`.`b` = `test`.`t2`.`b` and `test`.`t2`.`b` is not null) join `test`.`t5` left join (`test`.`t6` join `test`.`t7` left join `test`.`t8` on(`test`.`t8`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` < 10 and `test`.`t5`.`b` is not null)) on(`test`.`t7`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` >= 2 and `test`.`t5`.`b` is not null)) on((`test`.`t3`.`b` = 2 or `test`.`t3`.`c` is null) and (`test`.`t6`.`b` = 2 or `test`.`t6`.`c` is null) and (`test`.`t5`.`b` = `test`.`t0`.`b` or `test`.`t3`.`c` is null or `test`.`t6`.`c` is null or `test`.`t8`.`c` is null) and `test`.`t1`.`a` <> 2) join `test`.`t9` where `test`.`t0`.`a` = 1 and `test`.`t1`.`b` = `test`.`t0`.`b` and `test`.`t9`.`a` = 1 and (`test`.`t2`.`a` >= 4 or `test`.`t2`.`c` is null) and (`test`.`t3`.`a` < 5 or `test`.`t3`.`c` is null) and (`test`.`t4`.`b` = `test`.`t3`.`b` or `test`.`t3`.`c` is null or `test`.`t4`.`c` is null) and (`test`.`t5`.`a` >= 2 or `test`.`t5`.`c` is null) and (`test`.`t6`.`a` >= 4 or `test`.`t6`.`c` is null) and (`test`.`t7`.`a` <= 2 or `test`.`t7`.`c` is null) and (`test`.`t8`.`a` < 1 or `test`.`t8`.`c` is null) and (`test`.`t9`.`b` = `test`.`t8`.`b` or `test`.`t8`.`c` is null)
|
||||
Note 1003 select `test`.`t0`.`a` AS `a`,`test`.`t0`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t5`.`a` AS `a`,`test`.`t5`.`b` AS `b`,`test`.`t6`.`a` AS `a`,`test`.`t6`.`b` AS `b`,`test`.`t7`.`a` AS `a`,`test`.`t7`.`b` AS `b`,`test`.`t8`.`a` AS `a`,`test`.`t8`.`b` AS `b`,`test`.`t9`.`a` AS `a`,`test`.`t9`.`b` AS `b` from `test`.`t0` join `test`.`t1` left join (`test`.`t2` left join (`test`.`t3` join `test`.`t4`) on(`test`.`t3`.`a` = 1 and `test`.`t4`.`b` = `test`.`t2`.`b` and `test`.`t2`.`b` is not null) join `test`.`t5` left join (`test`.`t6` join `test`.`t7` left join `test`.`t8` on(`test`.`t8`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` < 10 and `test`.`t5`.`b` is not null)) on(`test`.`t7`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` >= 2 and `test`.`t5`.`b` is not null)) on((`test`.`t3`.`b` = 2 or `test`.`t3`.`c` is null) and (`test`.`t6`.`b` = 2 or `test`.`t6`.`c` is null) and (`test`.`t5`.`b` = `test`.`t0`.`b` or `test`.`t3`.`c` is null or `test`.`t6`.`c` is null or `test`.`t8`.`c` is null) and `test`.`t1`.`a` <> 2) join `test`.`t9` where `test`.`t0`.`a` = 1 and `test`.`t1`.`b` = `test`.`t0`.`b` and `test`.`t9`.`a` = 1 and (`test`.`t2`.`a` >= 4 or `test`.`t2`.`c` is null) and (`test`.`t3`.`a` < 5 or `test`.`t3`.`c` is null) and (`test`.`t4`.`b` = `test`.`t3`.`b` or `test`.`t3`.`c` is null or `test`.`t4`.`c` is null) and (`test`.`t5`.`a` >= 2 or `test`.`t5`.`c` is null) and (`test`.`t6`.`a` >= 4 or `test`.`t6`.`c` is null) and (`test`.`t7`.`a` <= 2 or `test`.`t7`.`c` is null) and (`test`.`t8`.`a` < 1 or `test`.`t8`.`c` is null) and (`test`.`t8`.`b` = `test`.`t9`.`b` or `test`.`t8`.`c` is null)
|
||||
SELECT t9.a,t9.b
|
||||
FROM t9;
|
||||
a b
|
||||
@ -703,23 +703,23 @@ t0.b=t1.b AND
|
||||
(t8.b=t9.b OR t8.c IS NULL) AND
|
||||
(t9.a=1);
|
||||
a b a b a b a b a b a b a b a b a b a b
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 3 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 3 2 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 4 2 1 2 4 2 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 2 2 6 2 2 2 0 2 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 1 6 2 1 1 NULL NULL 1 2
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 3 NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 3 2 5 3 NULL NULL NULL NULL 3 3 NULL NULL NULL NULL NULL NULL 1 2
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 1
|
||||
1 2 2 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 1 2
|
||||
SELECT t1.a,t1.b
|
||||
FROM t1;
|
||||
a b
|
||||
@ -920,6 +920,7 @@ t0.b=t1.b AND
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t0 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
1 SIMPLE t1 hash_ALL NULL #hash#$hj 5 test.t0.b 3 100.00 Using where; Using join buffer (flat, BNLH join)
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t5 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t7 hash_ALL NULL #hash#$hj 5 test.t5.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
@ -927,9 +928,8 @@ id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 8 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t4 hash_ALL NULL #hash#$hj 5 test.t2.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t0`.`a` AS `a`,`test`.`t0`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t5`.`a` AS `a`,`test`.`t5`.`b` AS `b`,`test`.`t6`.`a` AS `a`,`test`.`t6`.`b` AS `b`,`test`.`t7`.`a` AS `a`,`test`.`t7`.`b` AS `b`,`test`.`t8`.`a` AS `a`,`test`.`t8`.`b` AS `b`,`test`.`t9`.`a` AS `a`,`test`.`t9`.`b` AS `b` from `test`.`t0` join `test`.`t1` left join (`test`.`t2` left join (`test`.`t3` join `test`.`t4`) on(`test`.`t3`.`a` = 1 and `test`.`t4`.`b` = `test`.`t2`.`b` and `test`.`t2`.`a` > 0 and `test`.`t2`.`b` is not null) join `test`.`t5` left join (`test`.`t6` join `test`.`t7` left join `test`.`t8` on(`test`.`t8`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` < 10 and `test`.`t5`.`b` is not null)) on(`test`.`t7`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` >= 2 and `test`.`t5`.`b` is not null)) on((`test`.`t3`.`b` = 2 or `test`.`t3`.`c` is null) and (`test`.`t6`.`b` = 2 or `test`.`t6`.`c` is null) and (`test`.`t5`.`b` = `test`.`t0`.`b` or `test`.`t3`.`c` is null or `test`.`t6`.`c` is null or `test`.`t8`.`c` is null) and `test`.`t1`.`a` <> 2) join `test`.`t9` where `test`.`t0`.`a` = 1 and `test`.`t1`.`b` = `test`.`t0`.`b` and `test`.`t9`.`a` = 1 and (`test`.`t2`.`a` >= 4 or `test`.`t2`.`c` is null) and (`test`.`t3`.`a` < 5 or `test`.`t3`.`c` is null) and (`test`.`t4`.`b` = `test`.`t3`.`b` or `test`.`t3`.`c` is null or `test`.`t4`.`c` is null) and (`test`.`t5`.`a` >= 2 or `test`.`t5`.`c` is null) and (`test`.`t6`.`a` >= 4 or `test`.`t6`.`c` is null) and (`test`.`t7`.`a` <= 2 or `test`.`t7`.`c` is null) and (`test`.`t8`.`a` < 1 or `test`.`t8`.`c` is null) and (`test`.`t9`.`b` = `test`.`t8`.`b` or `test`.`t8`.`c` is null)
|
||||
Note 1003 select `test`.`t0`.`a` AS `a`,`test`.`t0`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t5`.`a` AS `a`,`test`.`t5`.`b` AS `b`,`test`.`t6`.`a` AS `a`,`test`.`t6`.`b` AS `b`,`test`.`t7`.`a` AS `a`,`test`.`t7`.`b` AS `b`,`test`.`t8`.`a` AS `a`,`test`.`t8`.`b` AS `b`,`test`.`t9`.`a` AS `a`,`test`.`t9`.`b` AS `b` from `test`.`t0` join `test`.`t1` left join (`test`.`t2` left join (`test`.`t3` join `test`.`t4`) on(`test`.`t3`.`a` = 1 and `test`.`t4`.`b` = `test`.`t2`.`b` and `test`.`t2`.`a` > 0 and `test`.`t2`.`b` is not null) join `test`.`t5` left join (`test`.`t6` join `test`.`t7` left join `test`.`t8` on(`test`.`t8`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` < 10 and `test`.`t5`.`b` is not null)) on(`test`.`t7`.`b` = `test`.`t5`.`b` and `test`.`t6`.`b` >= 2 and `test`.`t5`.`b` is not null)) on((`test`.`t3`.`b` = 2 or `test`.`t3`.`c` is null) and (`test`.`t6`.`b` = 2 or `test`.`t6`.`c` is null) and (`test`.`t5`.`b` = `test`.`t0`.`b` or `test`.`t3`.`c` is null or `test`.`t6`.`c` is null or `test`.`t8`.`c` is null) and `test`.`t1`.`a` <> 2) join `test`.`t9` where `test`.`t0`.`a` = 1 and `test`.`t1`.`b` = `test`.`t0`.`b` and `test`.`t9`.`a` = 1 and (`test`.`t2`.`a` >= 4 or `test`.`t2`.`c` is null) and (`test`.`t3`.`a` < 5 or `test`.`t3`.`c` is null) and (`test`.`t4`.`b` = `test`.`t3`.`b` or `test`.`t3`.`c` is null or `test`.`t4`.`c` is null) and (`test`.`t5`.`a` >= 2 or `test`.`t5`.`c` is null) and (`test`.`t6`.`a` >= 4 or `test`.`t6`.`c` is null) and (`test`.`t7`.`a` <= 2 or `test`.`t7`.`c` is null) and (`test`.`t8`.`a` < 1 or `test`.`t8`.`c` is null) and (`test`.`t8`.`b` = `test`.`t9`.`b` or `test`.`t8`.`c` is null)
|
||||
INSERT INTO t4 VALUES (-3,12,0), (-4,13,0), (-1,11,0), (-3,11,0), (-5,15,0);
|
||||
INSERT INTO t5 VALUES (-3,11,0), (-2,12,0), (-3,13,0), (-4,12,0);
|
||||
CREATE INDEX idx_b ON t4(b);
|
||||
@ -1071,9 +1071,9 @@ t0.b=t1.b AND
|
||||
(t8.b=t9.b OR t8.c IS NULL) AND
|
||||
(t9.a=1);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t0 ref idx_a idx_a 5 const 2 100.00
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 ALL idx_b NULL NULL NULL 7 75.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t0 ALL idx_a NULL NULL NULL 3 66.67 Using where
|
||||
1 SIMPLE t1 ref idx_b idx_b 5 test.t0.b 2 100.00 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t9 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t5 ALL idx_b NULL NULL NULL 7 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t7 hash_ALL NULL #hash#$hj 5 test.t5.b 2 100.00 Using where; Using join buffer (incremental, BNLH join)
|
||||
1 SIMPLE t6 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join)
|
||||
@ -1752,10 +1752,10 @@ LEFT JOIN
|
||||
ON t4.carrier = t1.carrier;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index package_id package_id 5 NULL 45 Using where; Using index
|
||||
1 SIMPLE t3 ref package_id package_id 5 test.t2.package_id 1 Using index
|
||||
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t2.package_id 1 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t4 eq_ref PRIMARY,id PRIMARY 2 test.t1.carrier 1 Using where
|
||||
1 SIMPLE t5 ref carrier_id carrier_id 5 test.t4.id 22 Using index
|
||||
1 SIMPLE t3 ref package_id package_id 5 test.t2.package_id 1 Using index
|
||||
SELECT COUNT(*)
|
||||
FROM ((t2 JOIN t1 ON t2.package_id = t1.id)
|
||||
JOIN t3 ON t3.package_id = t1.id)
|
||||
@ -2085,8 +2085,8 @@ ON t6.b >= 2 AND t5.b=t7.b AND
|
||||
(t8.a > 0 OR t8.c IS NULL) AND t6.a>0 AND t7.a>0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t5 ALL NULL NULL NULL NULL 3
|
||||
1 SIMPLE t7 range PRIMARY,b_i PRIMARY 4 NULL 2 Using where; Rowid-ordered scan; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t6 range|filter PRIMARY,b_i PRIMARY|b_i 4|5 NULL 3 (86%) Using where; Rowid-ordered scan; Using join buffer (incremental, BNL join); Using rowid filter
|
||||
1 SIMPLE t7 ref|filter PRIMARY,b_i b_i|PRIMARY 5|4 test.t5.b 2 (29%) Using where; Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan; Using rowid filter
|
||||
1 SIMPLE t6 ALL PRIMARY,b_i NULL NULL NULL 7 Using where; Using join buffer (incremental, BNL join)
|
||||
1 SIMPLE t8 ref b_i b_i 5 test.t5.b 2 Using where; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
|
||||
SELECT t5.a,t5.b,t6.a,t6.b,t7.a,t7.b,t8.a,t8.b
|
||||
FROM t5
|
||||
|
@ -2260,7 +2260,7 @@ create table t2 (a int, b int, c int, key(b), key(c));
|
||||
insert into t2 select
|
||||
@a:=A.a + 10*B.a+100*C.a,
|
||||
IF(@a<900, NULL, @a),
|
||||
IF(@a<500, NULL, @a)
|
||||
IF(@a<450, NULL, @a)
|
||||
from t1 A, t1 B, t1 C;
|
||||
delete from t1 where a=0;
|
||||
# Check that there are different #rows of NULLs for b and c, both !=10:
|
||||
@ -2269,7 +2269,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref b b 5 const 780 Using index condition
|
||||
explain select * from t2 force index (c) where c is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref c c 5 const 393 Using index condition
|
||||
1 SIMPLE t2 ref c c 5 const 312 Using index condition
|
||||
explain select * from t1 left join t2 on t2.b is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 9
|
||||
@ -2277,7 +2277,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
explain select * from t1 left join t2 on t2.c is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 9
|
||||
1 SIMPLE t2 ALL c NULL NULL NULL 1000 Using where
|
||||
1 SIMPLE t2 ref c c 5 const 312 Using where
|
||||
drop table t1,t2;
|
||||
#
|
||||
# MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause
|
||||
|
@ -1813,7 +1813,7 @@ create table t2 (a int, b int, c int, key(b), key(c));
|
||||
insert into t2 select
|
||||
@a:=A.a + 10*B.a+100*C.a,
|
||||
IF(@a<900, NULL, @a),
|
||||
IF(@a<500, NULL, @a)
|
||||
IF(@a<450, NULL, @a)
|
||||
from t1 A, t1 B, t1 C;
|
||||
|
||||
delete from t1 where a=0;
|
||||
|
@ -437,6 +437,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL a4,a6,a5,a7 NULL NULL NULL 3 Using where
|
||||
1 SIMPLE t2 ref PRIMARY PRIMARY 4 test.t1.a1 1 Using index
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.b2 1 Using where; Using index
|
||||
1 SIMPLE t10 eq_ref PRIMARY PRIMARY 1 test.t1.a6 1
|
||||
1 SIMPLE t8 eq_ref PRIMARY PRIMARY 1 test.t1.a4 1 Using index
|
||||
1 SIMPLE t4 eq_ref PRIMARY PRIMARY 4 test.t1.a2 1 Using index
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.d1 1 Using where
|
||||
@ -453,12 +454,12 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t14 eq_ref PRIMARY PRIMARY 2 test.t1.a8 1 Using where
|
||||
1 SIMPLE t15 eq_ref PRIMARY PRIMARY 2 test.t1.a9 1 Using where; Using index
|
||||
1 SIMPLE t16 ref PRIMARY PRIMARY 2 test.t15.o1 1 Using where
|
||||
1 SIMPLE t10 ALL PRIMARY NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
explain select * from v1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL a4,a6,a5,a7 NULL NULL NULL 3 Using where
|
||||
1 SIMPLE t2 ref PRIMARY PRIMARY 4 test.t1.a1 1 Using index
|
||||
1 SIMPLE t3 eq_ref PRIMARY PRIMARY 4 test.t2.b2 1 Using where; Using index
|
||||
1 SIMPLE t10 eq_ref PRIMARY PRIMARY 1 test.t1.a6 1
|
||||
1 SIMPLE t8 eq_ref PRIMARY PRIMARY 1 test.t1.a4 1 Using index
|
||||
1 SIMPLE t4 eq_ref PRIMARY PRIMARY 4 test.t1.a2 1 Using index
|
||||
1 SIMPLE t5 eq_ref PRIMARY PRIMARY 4 test.t4.d1 1 Using where
|
||||
@ -475,7 +476,6 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t14 eq_ref PRIMARY PRIMARY 2 test.t1.a8 1 Using where
|
||||
1 SIMPLE t15 eq_ref PRIMARY PRIMARY 2 test.t1.a9 1 Using where; Using index
|
||||
1 SIMPLE t16 ref PRIMARY PRIMARY 2 test.t15.o1 1 Using where
|
||||
1 SIMPLE t10 ALL PRIMARY NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
drop view v1;
|
||||
drop table t1,t2,t3,t4,t5,t6,t7,t8,t9,t10,t11,t12,t13,t14,t15,t16;
|
||||
#
|
||||
|
@ -2267,7 +2267,7 @@ create table t2 (a int, b int, c int, key(b), key(c));
|
||||
insert into t2 select
|
||||
@a:=A.a + 10*B.a+100*C.a,
|
||||
IF(@a<900, NULL, @a),
|
||||
IF(@a<500, NULL, @a)
|
||||
IF(@a<450, NULL, @a)
|
||||
from t1 A, t1 B, t1 C;
|
||||
delete from t1 where a=0;
|
||||
# Check that there are different #rows of NULLs for b and c, both !=10:
|
||||
@ -2276,7 +2276,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref b b 5 const 780 Using index condition
|
||||
explain select * from t2 force index (c) where c is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref c c 5 const 393 Using index condition
|
||||
1 SIMPLE t2 ref c c 5 const 312 Using index condition
|
||||
explain select * from t1 left join t2 on t2.b is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 9
|
||||
@ -2284,7 +2284,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
explain select * from t1 left join t2 on t2.c is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 9
|
||||
1 SIMPLE t2 ALL c NULL NULL NULL 1000 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t2 ref c c 5 const 312 Using where; Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
drop table t1,t2;
|
||||
#
|
||||
# MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause
|
||||
|
@ -231,11 +231,14 @@ numeropost
|
||||
1
|
||||
EXPLAIN SELECT numeropost FROM t1 WHERE numreponse='1';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const numreponse numreponse 4 const 1 Using index
|
||||
1 SIMPLE t1 const numreponse numreponse 4 const 1
|
||||
FLUSH TABLES;
|
||||
SELECT numeropost FROM t1 WHERE numreponse='1';
|
||||
numeropost
|
||||
1
|
||||
EXPLAIN SELECT numreponse+0 FROM t1 WHERE numreponse='1';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const numreponse numreponse 4 const 1 Using index
|
||||
drop table t1;
|
||||
create table t1 (c varchar(30) character set utf8, t text character set utf8, unique (c(2)), unique (t(3))) engine=myisam;
|
||||
show create table t1;
|
||||
@ -610,7 +613,7 @@ EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE
|
||||
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) > 12;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
|
||||
2 SUBQUERY t1 range a a 5 NULL 5 Using where; Using index
|
||||
2 SUBQUERY t1 range a a 5 NULL 2 Using where; Using index for group-by
|
||||
SELECT 1 as RES FROM t1 AS t1_outer WHERE
|
||||
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) > 12;
|
||||
RES
|
||||
@ -628,19 +631,19 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using temporary; Using filesort
|
||||
SHOW STATUS LIKE 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 10.412184
|
||||
Last_query_cost 8.506592
|
||||
EXPLAIN SELECT a, SUM( b ) FROM t1 USE INDEX( a ) GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using temporary; Using filesort
|
||||
SHOW STATUS LIKE 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 10.412184
|
||||
Last_query_cost 8.506592
|
||||
EXPLAIN SELECT a, SUM( b ) FROM t1 FORCE INDEX( a ) GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL a 5 NULL 6
|
||||
SHOW STATUS LIKE 'Last_query_cost';
|
||||
Variable_name Value
|
||||
Last_query_cost 15.399000
|
||||
Last_query_cost 11.003515
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# MDEV-21480: Unique key using ref access though eq_ref access can be used
|
||||
|
@ -227,9 +227,12 @@ drop table t1;
|
||||
CREATE TABLE t1 (numeropost mediumint(8) unsigned NOT NULL default '0', numreponse int(10) unsigned NOT NULL auto_increment, PRIMARY KEY (numeropost,numreponse), UNIQUE KEY numreponse (numreponse));
|
||||
INSERT INTO t1 (numeropost,numreponse) VALUES ('1','1'),('1','2'),('2','3'),('2','4');
|
||||
SELECT numeropost FROM t1 WHERE numreponse='1';
|
||||
# No 'Using index'
|
||||
EXPLAIN SELECT numeropost FROM t1 WHERE numreponse='1';
|
||||
FLUSH TABLES;
|
||||
SELECT numeropost FROM t1 WHERE numreponse='1';
|
||||
# This one will have 'Using index'
|
||||
EXPLAIN SELECT numreponse+0 FROM t1 WHERE numreponse='1';
|
||||
drop table t1;
|
||||
|
||||
#
|
||||
|
@ -440,25 +440,25 @@ VARIABLE_NAME VARIABLE_VALUE
|
||||
KEY_BLOCKS_NOT_FLUSHED 0
|
||||
KEY_BLOCKS_USED 4
|
||||
KEY_BLOCKS_WARM 0
|
||||
KEY_READ_REQUESTS 22
|
||||
KEY_READ_REQUESTS 21
|
||||
KEY_READS 0
|
||||
KEY_WRITE_REQUESTS 26
|
||||
KEY_WRITES 6
|
||||
select variable_value into @key_blocks_unused from information_schema.session_status where variable_name = 'Key_blocks_unused';
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default NULL NULL 2097152 1024 4 # 0 22 0 26 6
|
||||
default NULL NULL 2097152 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
delete from t2 where a='zzzz';
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default NULL NULL 2097152 1024 4 # 0 29 0 32 9
|
||||
default NULL NULL 2097152 1024 4 # 0 28 0 32 9
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
delete from t1;
|
||||
delete from t2;
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default NULL NULL 2097152 1024 4 # 0 29 0 32 9
|
||||
default NULL NULL 2097152 1024 4 # 0 28 0 32 9
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
set global key_cache_segments=2;
|
||||
select @@key_cache_segments;
|
||||
@ -488,7 +488,7 @@ VARIABLE_NAME VARIABLE_VALUE
|
||||
KEY_BLOCKS_NOT_FLUSHED 0
|
||||
KEY_BLOCKS_USED 4
|
||||
KEY_BLOCKS_WARM 0
|
||||
KEY_READ_REQUESTS 22
|
||||
KEY_READ_REQUESTS 21
|
||||
KEY_READS 0
|
||||
KEY_WRITE_REQUESTS 26
|
||||
KEY_WRITES 6
|
||||
@ -497,13 +497,13 @@ variable_value < @key_blocks_unused
|
||||
1
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 2097152 1024 4 # 0 22 0 26 6
|
||||
default 2 NULL 2097152 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
delete from t1;
|
||||
delete from t2;
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 2097152 1024 4 # 0 22 0 26 6
|
||||
default 2 NULL 2097152 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
set global key_cache_segments=1;
|
||||
select @@key_cache_segments;
|
||||
@ -533,7 +533,7 @@ VARIABLE_NAME VARIABLE_VALUE
|
||||
KEY_BLOCKS_NOT_FLUSHED 0
|
||||
KEY_BLOCKS_USED 4
|
||||
KEY_BLOCKS_WARM 0
|
||||
KEY_READ_REQUESTS 22
|
||||
KEY_READ_REQUESTS 21
|
||||
KEY_READS 0
|
||||
KEY_WRITE_REQUESTS 26
|
||||
KEY_WRITES 6
|
||||
@ -542,13 +542,13 @@ variable_value = @key_blocks_unused
|
||||
1
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 1 NULL 2097152 1024 4 # 0 22 0 26 6
|
||||
default 1 NULL 2097152 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
delete from t1;
|
||||
delete from t2;
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 1 NULL 2097152 1024 4 # 0 22 0 26 6
|
||||
default 1 NULL 2097152 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 1 0 2 1
|
||||
flush tables;
|
||||
flush status;
|
||||
@ -586,7 +586,7 @@ update t1 set p=3 where p=1;
|
||||
update t2 set i=2 where i=1;
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 32768 1024 4 # 0 22 0 26 6
|
||||
default 2 NULL 32768 1024 4 # 0 21 0 26 6
|
||||
small NULL NULL 1048576 1024 1 # 0 0 0 0 0
|
||||
insert into t1(a) select a from t1;
|
||||
insert into t1(a) select a from t1;
|
||||
@ -606,7 +606,7 @@ insert into t2(i,a) select i,a from t2;
|
||||
insert into t2(i,a) select i,a from t2;
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 32768 1024 # # 0 6733 # 3684 103
|
||||
default 2 NULL 32768 1024 # # 0 6732 # 3684 103
|
||||
small NULL NULL 1048576 1024 # # 0 0 # 0 0
|
||||
select * from t1 where p between 1010 and 1020 ;
|
||||
p a
|
||||
@ -625,7 +625,7 @@ p i a
|
||||
1020 3 zzzz
|
||||
select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 32768 1024 # # 0 6750 # 3684 103
|
||||
default 2 NULL 32768 1024 # # 0 6749 # 3684 103
|
||||
small NULL NULL 1048576 1024 # # 0 0 # 0 0
|
||||
flush tables;
|
||||
flush status;
|
||||
@ -699,7 +699,7 @@ update t2 set p=p+3000, i=2 where a='qqqq';
|
||||
select * from information_schema.key_caches where key_cache_name like "key%"
|
||||
and segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
keycache1 7 NULL 262143 2048 25 # 0 2082 25 1071 19
|
||||
keycache1 7 NULL 262143 2048 25 # 0 2114 25 1071 19
|
||||
set global keycache2.key_buffer_size=1024*1024;
|
||||
cache index t2 in keycache2;
|
||||
Table Op Msg_type Msg_text
|
||||
@ -712,7 +712,7 @@ keycache2 NULL NULL 1048576 1024 6 # 0 6 6 3 3
|
||||
select * from information_schema.key_caches where key_cache_name like "key%"
|
||||
and segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
keycache1 7 NULL 262143 2048 25 # 0 2082 25 1071 19
|
||||
keycache1 7 NULL 262143 2048 25 # 0 2114 25 1071 19
|
||||
keycache2 NULL NULL 1048576 1024 6 # 0 6 6 3 3
|
||||
cache index t2 in keycache1;
|
||||
Table Op Msg_type Msg_text
|
||||
@ -753,7 +753,7 @@ select * from information_schema.key_caches where segment_number is null;
|
||||
KEY_CACHE_NAME SEGMENTS SEGMENT_NUMBER FULL_SIZE BLOCK_SIZE USED_BLOCKS UNUSED_BLOCKS DIRTY_BLOCKS READ_REQUESTS READS WRITE_REQUESTS WRITES
|
||||
default 2 NULL 32768 1024 # # 0 3172 24 1552 18
|
||||
small NULL NULL 1048576 1024 # # 0 0 0 0 0
|
||||
keycache1 7 NULL 262143 2048 # # 0 3229 43 1594 30
|
||||
keycache1 7 NULL 262143 2048 # # 0 3277 43 1594 30
|
||||
keycache2 NULL NULL 1048576 1024 # # 0 6 6 3 3
|
||||
set global keycache1.key_cache_block_size=2*1024;
|
||||
insert into t2 values (7000, 3, 'yyyy');
|
||||
|
@ -255,7 +255,7 @@ select * from t1i
|
||||
where c1 IN (select * from t2i where c2 > ' ')
|
||||
LIMIT ROWS EXAMINED 6;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1i range PRIMARY PRIMARY 2 NULL 4 Using where; Using index
|
||||
1 PRIMARY t1i index PRIMARY PRIMARY 2 NULL 4 Using where; Using index
|
||||
1 PRIMARY t2i eq_ref PRIMARY PRIMARY 2 test.t1i.c1 1 Using index
|
||||
select * from t1i
|
||||
where c1 IN (select * from t2i where c2 > ' ')
|
||||
@ -395,7 +395,7 @@ select * from t1i
|
||||
where c1 IN (select * from t2i where c2 > ' ') LIMIT ROWS EXAMINED 17;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1i index NULL PRIMARY 2 NULL 4 Using where; Using index
|
||||
2 MATERIALIZED t2i range PRIMARY PRIMARY 2 NULL 4 Using where; Using index
|
||||
2 MATERIALIZED t2i index PRIMARY PRIMARY 2 NULL 4 Using where; Using index
|
||||
select * from t1i
|
||||
where c1 IN (select * from t2i where c2 > ' ') LIMIT ROWS EXAMINED 17;
|
||||
c1
|
||||
|
@ -1195,20 +1195,20 @@ ERROR 42S22: Unknown column 'DB_ROW_HASH_1' in 'IN/ALL/ANY subquery'
|
||||
select DB_ROW_HASH_1, DB_ROW_HASH_2 from t1,t2 where DB_ROW_HASH_1 in (select DB_ROW_HASH_1 from t2);
|
||||
DB_ROW_HASH_1 DB_ROW_HASH_2
|
||||
11 1
|
||||
22 2
|
||||
33 3
|
||||
44 4
|
||||
11 1
|
||||
11 1
|
||||
11 1
|
||||
22 2
|
||||
33 3
|
||||
44 4
|
||||
11 1
|
||||
22 2
|
||||
22 2
|
||||
22 2
|
||||
33 3
|
||||
44 4
|
||||
11 1
|
||||
22 2
|
||||
33 3
|
||||
33 3
|
||||
33 3
|
||||
44 4
|
||||
44 4
|
||||
44 4
|
||||
44 4
|
||||
select * from t2 where DB_ROW_HASH_1 in (select DB_ROW_HASH_1 from t1);
|
||||
DB_ROW_HASH_1 DB_ROW_HASH_2
|
||||
|
@ -389,6 +389,7 @@ select DB_ROW_HASH_1, DB_ROW_HASH_2 from t1;
|
||||
select DB_ROW_HASH_1, DB_ROW_HASH_2 from t1,t2;
|
||||
--error ER_BAD_FIELD_ERROR
|
||||
select * from t1 where DB_ROW_HASH_1 in (select DB_ROW_HASH_1 from t2);
|
||||
--sorted_result
|
||||
select DB_ROW_HASH_1, DB_ROW_HASH_2 from t1,t2 where DB_ROW_HASH_1 in (select DB_ROW_HASH_1 from t2);
|
||||
select * from t2 where DB_ROW_HASH_1 in (select DB_ROW_HASH_1 from t1);
|
||||
--error ER_BAD_FIELD_ERROR
|
||||
|
@ -1092,8 +1092,8 @@ a b c a b c
|
||||
set optimizer_switch='firstmatch=off';
|
||||
explain update t1, t2 set t2.c=1 where t1.a=t2.a and t1.b in (select b from t3 where t3.c< t2.c) order by t2.c, t1.c limit 10;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
|
||||
1 PRIMARY t1 ALL a NULL NULL NULL 10 Using where
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary; Using filesort
|
||||
1 PRIMARY t1 ref a a 5 test.t2.a 1
|
||||
1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Start temporary; End temporary
|
||||
update t1, t2 set t2.c=1 where t1.a=t2.a and t1.b in (select b from t3 where t3.c<=t2.c) order by t2.c, t1.c limit 5;
|
||||
select * from t2;
|
||||
|
@ -640,10 +640,14 @@ create table t1 ( a tinytext, b char(1), index idx (a(1),b) );
|
||||
insert into t1 values (null,''), (null,'');
|
||||
explain select count(*) from t1 where a is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx idx 4 const 2 Using where
|
||||
1 SIMPLE t1 ALL idx NULL NULL NULL 2 Using where
|
||||
select count(*) from t1 where a is null;
|
||||
count(*)
|
||||
2
|
||||
insert into t1 values (1,''), (2,'');
|
||||
explain select count(*) from t1 where a is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx idx 4 const 2 Using where
|
||||
drop table t1;
|
||||
create table t1 (c1 int, c2 varchar(4) not null default '',
|
||||
key(c2(3))) default charset=utf8;
|
||||
@ -2532,6 +2536,7 @@ DROP TABLE t1, t2, t3;
|
||||
#
|
||||
# BUG#51307 - widespread corruption with partitions and insert...select
|
||||
#
|
||||
call mtr.add_suppression("Enabling keys got errno 12 on test.t1, retrying");
|
||||
CREATE TABLE t1(a CHAR(255), KEY(a));
|
||||
SELECT * FROM t1, t1 AS a1;
|
||||
a a
|
||||
|
@ -593,6 +593,8 @@ create table t1 ( a tinytext, b char(1), index idx (a(1),b) );
|
||||
insert into t1 values (null,''), (null,'');
|
||||
explain select count(*) from t1 where a is null;
|
||||
select count(*) from t1 where a is null;
|
||||
insert into t1 values (1,''), (2,'');
|
||||
explain select count(*) from t1 where a is null;
|
||||
drop table t1;
|
||||
|
||||
#
|
||||
@ -1676,6 +1678,9 @@ DROP TABLE t1, t2, t3;
|
||||
--echo #
|
||||
--echo # BUG#51307 - widespread corruption with partitions and insert...select
|
||||
--echo #
|
||||
|
||||
call mtr.add_suppression("Enabling keys got errno 12 on test.t1, retrying");
|
||||
|
||||
CREATE TABLE t1(a CHAR(255), KEY(a));
|
||||
SELECT * FROM t1, t1 AS a1;
|
||||
SET myisam_sort_buffer_size=4;
|
||||
|
@ -256,9 +256,8 @@ FLUSH STATUS;
|
||||
FLUSH TABLES;
|
||||
EXPLAIN EXTENDED SELECT * FROM t1 WHERE 1 IN (SELECT 1 FROM t2 WHERE t2.b < 3);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 3 100.00 Using where; FirstMatch
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join)
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` semi join (`test`.`t2`) where `test`.`t2`.`b` < 3
|
||||
# Status of EXPLAIN EXTENDED "equivalent" SELECT query execution
|
||||
@ -268,8 +267,8 @@ Warnings:
|
||||
Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be removed in a future release. Please use 'SELECT <select list> INTO <destination> FROM...' instead
|
||||
# Status of "equivalent" SELECT query execution:
|
||||
Variable_name Value
|
||||
Handler_read_key 5
|
||||
Handler_read_rnd_next 8
|
||||
Handler_read_key 4
|
||||
Handler_read_rnd_next 5
|
||||
# Status of testing query execution:
|
||||
Variable_name Value
|
||||
Handler_read_key 4
|
||||
@ -342,16 +341,16 @@ Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be
|
||||
EXPLAIN UPDATE t1, t2 SET a = 10 WHERE a IN (SELECT b FROM t2 WHERE t2.b < 3);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 Using where
|
||||
FLUSH STATUS;
|
||||
FLUSH TABLES;
|
||||
EXPLAIN EXTENDED UPDATE t1, t2 SET a = 10 WHERE a IN (SELECT b FROM t2 WHERE t2.b < 3);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 3 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
# Status of EXPLAIN EXTENDED query
|
||||
Variable_name Value
|
||||
@ -361,8 +360,8 @@ FLUSH TABLES;
|
||||
EXPLAIN EXTENDED SELECT * FROM t1, t2 WHERE a IN (SELECT b FROM t2 WHERE t2.b < 3);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join)
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` semi join (`test`.`t2`) join `test`.`t2` where `test`.`t2`.`b` < 3
|
||||
@ -373,12 +372,12 @@ Warnings:
|
||||
Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be removed in a future release. Please use 'SELECT <select list> INTO <destination> FROM...' instead
|
||||
# Status of "equivalent" SELECT query execution:
|
||||
Variable_name Value
|
||||
Handler_read_key 7
|
||||
Handler_read_key 13
|
||||
Handler_read_rnd_next 12
|
||||
# Status of testing query execution:
|
||||
Variable_name Value
|
||||
Handler_read_key 7
|
||||
Handler_read_rnd_next 16
|
||||
Handler_read_key 9
|
||||
Handler_read_rnd_next 20
|
||||
Handler_update 2
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
@ -791,12 +790,12 @@ Warnings:
|
||||
Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be removed in a future release. Please use 'SELECT <select list> INTO <destination> FROM...' instead
|
||||
EXPLAIN DELETE FROM t1 WHERE t1.a > 0 ORDER BY t1.a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using where
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 6 Using where; Using filesort
|
||||
FLUSH STATUS;
|
||||
FLUSH TABLES;
|
||||
EXPLAIN EXTENDED DELETE FROM t1 WHERE t1.a > 0 ORDER BY t1.a;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 100.00 Using where
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 6 100.00 Using where; Using filesort
|
||||
# Status of EXPLAIN EXTENDED query
|
||||
Variable_name Value
|
||||
Handler_read_key 3
|
||||
@ -819,8 +818,11 @@ Handler_read_next 3
|
||||
# Status of testing query execution:
|
||||
Variable_name Value
|
||||
Handler_delete 3
|
||||
Handler_read_key 4
|
||||
Handler_read_next 3
|
||||
Handler_read_key 3
|
||||
Handler_read_rnd 3
|
||||
Handler_read_rnd_next 7
|
||||
Sort_rows 3
|
||||
Sort_scan 1
|
||||
|
||||
DROP TABLE t1;
|
||||
#17
|
||||
@ -1494,12 +1496,12 @@ Warnings:
|
||||
Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be removed in a future release. Please use 'SELECT <select list> INTO <destination> FROM...' instead
|
||||
EXPLAIN DELETE FROM t2 WHERE b = 10 ORDER BY a, c LIMIT 5;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 26 Using where; Using filesort
|
||||
1 SIMPLE t2 index NULL a 15 NULL 5 Using where
|
||||
FLUSH STATUS;
|
||||
FLUSH TABLES;
|
||||
EXPLAIN EXTENDED DELETE FROM t2 WHERE b = 10 ORDER BY a, c LIMIT 5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 26 100.00 Using where; Using filesort
|
||||
1 SIMPLE t2 index NULL a 15 NULL 5 100.00 Using where
|
||||
# Status of EXPLAIN EXTENDED query
|
||||
Variable_name Value
|
||||
Handler_read_key 8
|
||||
@ -1523,11 +1525,9 @@ Handler_read_next 26
|
||||
# Status of testing query execution:
|
||||
Variable_name Value
|
||||
Handler_delete 1
|
||||
Handler_read_first 1
|
||||
Handler_read_key 8
|
||||
Handler_read_rnd 1
|
||||
Handler_read_rnd_next 27
|
||||
Sort_rows 1
|
||||
Sort_scan 1
|
||||
Handler_read_next 26
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
#32
|
||||
@ -2009,12 +2009,12 @@ Warnings:
|
||||
Warning 1287 '<select expression> INTO <destination>;' is deprecated and will be removed in a future release. Please use 'SELECT <select list> INTO <destination> FROM...' instead
|
||||
EXPLAIN UPDATE t2 SET d = 10 WHERE b = 10 ORDER BY a, c LIMIT 5;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 26 Using where; Using filesort
|
||||
1 SIMPLE t2 index NULL a 15 NULL 5 Using where; Using buffer
|
||||
FLUSH STATUS;
|
||||
FLUSH TABLES;
|
||||
EXPLAIN EXTENDED UPDATE t2 SET d = 10 WHERE b = 10 ORDER BY a, c LIMIT 5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 26 100.00 Using where; Using filesort
|
||||
1 SIMPLE t2 index NULL a 15 NULL 5 100.00 Using where; Using buffer
|
||||
# Status of EXPLAIN EXTENDED query
|
||||
Variable_name Value
|
||||
Handler_read_key 8
|
||||
@ -2037,13 +2037,11 @@ Handler_read_key 8
|
||||
Handler_read_next 26
|
||||
# Status of testing query execution:
|
||||
Variable_name Value
|
||||
Handler_read_first 1
|
||||
Handler_read_key 8
|
||||
Handler_read_next 26
|
||||
Handler_read_rnd 1
|
||||
Handler_read_rnd_next 27
|
||||
Handler_update 1
|
||||
Sort_priority_queue_sorts 1
|
||||
Sort_rows 1
|
||||
Sort_scan 1
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
#42
|
||||
|
@ -407,7 +407,7 @@ WHERE (pk BETWEEN 4 AND 5 OR pk < 2) AND c1 < 240
|
||||
ORDER BY c1
|
||||
LIMIT 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range|filter PRIMARY,k1 PRIMARY|k1 4|5 NULL 3 (50%) Using index condition; Using where; Rowid-ordered scan; Using filesort; Using rowid filter
|
||||
1 SIMPLE t1 range PRIMARY,k1 PRIMARY 4 NULL 3 Using index condition; Using where; Rowid-ordered scan; Using filesort
|
||||
DROP TABLE t1;
|
||||
#
|
||||
#
|
||||
@ -429,8 +429,8 @@ SELECT * FROM t1
|
||||
WHERE pk IN (SELECT it.pk FROM t2 JOIN t2 AS it ON it.i=it.i WHERE it.pk-t1.i<10);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL # Using where
|
||||
2 DEPENDENT SUBQUERY t2 index NULL PRIMARY 4 NULL # Using index
|
||||
2 DEPENDENT SUBQUERY it eq_ref PRIMARY PRIMARY 4 func # Using index condition
|
||||
2 DEPENDENT SUBQUERY t2 index NULL PRIMARY 4 NULL # Using index; Using join buffer (flat, BNL join)
|
||||
SELECT * FROM t1
|
||||
WHERE pk IN (SELECT it.pk FROM t2 JOIN t2 AS it ON it.i=it.i WHERE it.pk-t1.i<10);
|
||||
pk i
|
||||
@ -506,7 +506,7 @@ WHERE (t2.pk <= 4 AND t1.pk IN (2,1)) OR
|
||||
(t1.pk > 1 AND t2.pk BETWEEN 6 AND 6);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 1 Using index condition; Rowid-ordered scan
|
||||
1 SIMPLE t2 range PRIMARY PRIMARY 4 NULL 2 Using index condition; Using where; Rowid-ordered scan; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t2 ALL PRIMARY NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
|
||||
SELECT c2 FROM t1 JOIN t2 ON t1.c1 = t2.c1
|
||||
WHERE (t2.pk <= 4 AND t1.pk IN (2,1)) OR
|
||||
(t1.pk > 1 AND t2.pk BETWEEN 6 AND 6);
|
||||
@ -922,7 +922,7 @@ DROP TABLE t1;
|
||||
# Bug#870046: ICP for a GROUP BY query
|
||||
#
|
||||
CREATE TABLE t1 (a int, b varchar(1), c varchar(1), INDEX idx(b));
|
||||
INSERT INTO t1 VALUES (2,'x','x'), (5,'x','y');
|
||||
INSERT INTO t1 VALUES (2,'x','x'), (5,'x','y'), (6,'a','b'), (7,'a','b');
|
||||
SET SESSION optimizer_switch='index_condition_pushdown=off';
|
||||
EXPLAIN
|
||||
SELECT a, MIN(c) FROM t1 WHERE b = 'x' AND c > 'x' GROUP BY a;
|
||||
|
@ -215,7 +215,7 @@ DROP TABLE t1;
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a int, b varchar(1), c varchar(1), INDEX idx(b));
|
||||
INSERT INTO t1 VALUES (2,'x','x'), (5,'x','y');
|
||||
INSERT INTO t1 VALUES (2,'x','x'), (5,'x','y'), (6,'a','b'), (7,'a','b');
|
||||
|
||||
SET SESSION optimizer_switch='index_condition_pushdown=off';
|
||||
EXPLAIN
|
||||
|
@ -720,6 +720,11 @@ The following specify which files/extra groups are read (specified before remain
|
||||
max_connections*5 or max_connections + table_cache*2
|
||||
(whichever is larger) number of file descriptors
|
||||
(Automatically configured unless set explicitly)
|
||||
--optimizer-cache-hit-ratio=#
|
||||
Expected hit rate of the row and index cache in storage
|
||||
engines. The value should be an integer between 0 and 99,
|
||||
where 0 means cache is empty and 99 means that value is
|
||||
almost always in the cache
|
||||
--optimizer-extra-pruning-depth=#
|
||||
If the optimizer needs to enumerate join prefix of this
|
||||
size or larger, then it will try agressively prune away
|
||||
@ -1698,6 +1703,7 @@ old-alter-table DEFAULT
|
||||
old-mode UTF8_IS_UTF8MB3
|
||||
old-passwords FALSE
|
||||
old-style-user-limits FALSE
|
||||
optimizer-cache-hit-ratio 50
|
||||
optimizer-extra-pruning-depth 8
|
||||
optimizer-max-sel-arg-weight 32000
|
||||
optimizer-prune-level 2
|
||||
|
@ -4,7 +4,7 @@ insert into t1 values (NULL), (0), (1), (2), (3), (4), (5), (6), (7), (8), (9),
|
||||
(10), (11), (12), (13), (14), (15), (16), (17), (18), (19);
|
||||
explain select * from t1 where not(not(a));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 20 Using where; Using index
|
||||
1 SIMPLE t1 index a a 5 NULL 21 Using where; Using index
|
||||
select * from t1 where not(not(a));
|
||||
a
|
||||
1
|
||||
@ -55,7 +55,7 @@ a
|
||||
10
|
||||
explain select * from t1 where not(a = 10);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 19 Using where; Using index
|
||||
1 SIMPLE t1 index a a 5 NULL 21 Using where; Using index
|
||||
select * from t1 where not(a = 10);
|
||||
a
|
||||
0
|
||||
@ -500,7 +500,7 @@ NULL NULL
|
||||
3 1
|
||||
explain extended select a, not(not(a)), not(a <= 2 and not(a)), not(a not like "1"), not (a not in (1,2)), not(a != 2) from t1 where not(not(a)) having not(not(a));
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 4 100.00 Using where; Using index
|
||||
1 SIMPLE t1 index a a 5 NULL 5 80.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`a` <> 0 AS `not(not(a))`,`test`.`t1`.`a` > 2 or `test`.`t1`.`a` <> 0 AS `not(a <= 2 and not(a))`,`test`.`t1`.`a` like '1' AS `not(a not like "1")`,`test`.`t1`.`a` in (1,2) AS `not (a not in (1,2))`,`test`.`t1`.`a` = 2 AS `not(a != 2)` from `test`.`t1` where `test`.`t1`.`a` <> 0 having `test`.`t1`.`a` <> 0
|
||||
drop table t1;
|
||||
|
@ -160,12 +160,12 @@ a b
|
||||
7 NULL
|
||||
explain select * from t1 where (a = 7 or a is null) and (b=7 or b is null);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a,b a 10 NULL 4 Using where; Using index
|
||||
1 SIMPLE t1 ref_or_null a,b a 5 const 5 Using where; Using index
|
||||
select * from t1 where (a = 7 or a is null) and (b=7 or b is null);
|
||||
a b
|
||||
NULL 7
|
||||
7 NULL
|
||||
7 7
|
||||
NULL 7
|
||||
explain select * from t1 where (a = 7 or a is null) and (a = 7 or a is null);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref_or_null a a 5 const 5 Using where; Using index
|
||||
@ -258,10 +258,11 @@ PRIMARY KEY (id)
|
||||
) ENGINE=MyISAM;
|
||||
INSERT INTO t1 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4),(9,NULL),(10,NULL);
|
||||
INSERT INTO t1 VALUES (11,5),(12,6),(13,7),(14,8),(15,9);
|
||||
INSERT INTO t1 VALUES (1000,1000),(1010,1010);
|
||||
INSERT INTO t2 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4),(9,NULL),(10,NULL);
|
||||
explain select id from t1 where uniq_id is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL idx1 NULL NULL NULL 15 Using where
|
||||
1 SIMPLE t1 ref idx1 idx1 5 const 6 Using index condition
|
||||
explain select id from t1 where uniq_id =1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const idx1 idx1 5 const 1
|
||||
@ -285,6 +286,7 @@ id
|
||||
110
|
||||
DELETE FROM t1 WHERE uniq_id IS NULL;
|
||||
DELETE FROM t2 WHERE uniq_id IS NULL;
|
||||
DELETE FROM t1 WHERE id >= 1000;
|
||||
SELECT * FROM t1 ORDER BY uniq_id, id;
|
||||
id uniq_id
|
||||
3 1
|
||||
|
@ -104,6 +104,7 @@ CREATE TABLE t2 (
|
||||
|
||||
INSERT INTO t1 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4),(9,NULL),(10,NULL);
|
||||
INSERT INTO t1 VALUES (11,5),(12,6),(13,7),(14,8),(15,9);
|
||||
INSERT INTO t1 VALUES (1000,1000),(1010,1010);
|
||||
INSERT INTO t2 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4),(9,NULL),(10,NULL);
|
||||
#
|
||||
# Check IS NULL optimization
|
||||
@ -122,6 +123,12 @@ select id from t2 where uniq_id is null;
|
||||
#
|
||||
DELETE FROM t1 WHERE uniq_id IS NULL;
|
||||
DELETE FROM t2 WHERE uniq_id IS NULL;
|
||||
|
||||
#
|
||||
# Delete extra records that were used to force null optimization
|
||||
#
|
||||
DELETE FROM t1 WHERE id >= 1000;
|
||||
|
||||
#
|
||||
# Select what is left -- notice the difference
|
||||
#
|
||||
|
File diff suppressed because it is too large
Load Diff
@ -73,7 +73,7 @@ explain select * from t1 where a=1 or b=1 {
|
||||
"range_analysis": {
|
||||
"table_scan": {
|
||||
"rows": 1000,
|
||||
"cost": 231.5878906
|
||||
"cost": 264.7939453
|
||||
},
|
||||
"potential_range_indexes": [
|
||||
{
|
||||
@ -111,12 +111,12 @@ explain select * from t1 where a=1 or b=1 {
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 1,
|
||||
"cost": 0.345585794,
|
||||
"cost": 0.745585794,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
"index_to_merge": "a",
|
||||
"cumulated_cost": 0.345585794
|
||||
"cumulated_cost": 0.745585794
|
||||
},
|
||||
{
|
||||
"range_scan_alternatives": [
|
||||
@ -127,15 +127,15 @@ explain select * from t1 where a=1 or b=1 {
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 1,
|
||||
"cost": 0.345585794,
|
||||
"cost": 0.745585794,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
"index_to_merge": "b",
|
||||
"cumulated_cost": 0.691171589
|
||||
"cumulated_cost": 1.491171589
|
||||
}
|
||||
],
|
||||
"cost_of_reading_ranges": 0.691171589,
|
||||
"cost_of_reading_ranges": 1.491171589,
|
||||
"use_roworder_union": true,
|
||||
"cause": "always cheaper than non roworder retrieval",
|
||||
"analyzing_roworder_scans": [
|
||||
@ -158,7 +158,7 @@ explain select * from t1 where a=1 or b=1 {
|
||||
}
|
||||
}
|
||||
],
|
||||
"index_roworder_union_cost": 2.484903732,
|
||||
"index_roworder_union_cost": 2.595171589,
|
||||
"members": 2,
|
||||
"chosen": true
|
||||
}
|
||||
@ -187,7 +187,7 @@ explain select * from t1 where a=1 or b=1 {
|
||||
]
|
||||
},
|
||||
"rows_for_plan": 2,
|
||||
"cost_for_plan": 2.484903732,
|
||||
"cost_for_plan": 2.595171589,
|
||||
"chosen": true
|
||||
}
|
||||
}
|
||||
@ -211,18 +211,23 @@ explain select * from t1 where a=1 or b=1 {
|
||||
{
|
||||
"best_access_path": {
|
||||
"table": "t1",
|
||||
"plan_details": {
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths": [
|
||||
{
|
||||
"access_type": "index_merge",
|
||||
"resulting_rows": 2,
|
||||
"cost": 2.484903732,
|
||||
"rows": 2,
|
||||
"rows_after_scan": 2,
|
||||
"rows_after_filter": 2,
|
||||
"cost": 2.595171589,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
"chosen_access_method": {
|
||||
"type": "index_merge",
|
||||
"records": 2,
|
||||
"cost": 2.484903732,
|
||||
"cost": 2.595171589,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -233,13 +238,14 @@ explain select * from t1 where a=1 or b=1 {
|
||||
"plan_prefix": [],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 2,
|
||||
"cost_for_plan": 2.884903732
|
||||
"cost_for_plan": 2.595171589
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"best_join_order": ["t1"],
|
||||
"cost": 2.883903732
|
||||
"rows": 2,
|
||||
"cost": 2.595171589
|
||||
},
|
||||
{
|
||||
"substitute_best_equal": {
|
||||
@ -320,7 +326,7 @@ set optimizer_trace='enabled=on';
|
||||
# 3-way ROR-intersection
|
||||
explain select key1,key2,key3 from t1 where key1=100 and key2=100 and key3=100;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index_merge key1,key2,key3 key1,key2,key3 5,5,5 NULL 2 Using intersect(key1,key2,key3); Using where; Using index
|
||||
1 SIMPLE t1 index_merge key1,key2,key3 key1,key2 5,5 NULL 77 Using intersect(key1,key2); Using where
|
||||
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives')) from INFORMATION_SCHEMA.OPTIMIZER_TRACE;
|
||||
JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
[
|
||||
@ -335,7 +341,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 2243,
|
||||
"cost": 2700.058937,
|
||||
"cost": 1695.083937,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -346,7 +352,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 2243,
|
||||
"cost": 2700.058937,
|
||||
"cost": 1695.083937,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
},
|
||||
@ -358,7 +364,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 2243,
|
||||
"cost": 2700.058937,
|
||||
"cost": 1695.083937,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
}
|
||||
@ -369,10 +375,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
[
|
||||
{
|
||||
"index": "key1",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 10.31393703,
|
||||
"disk_sweep_cost": 1923.144061,
|
||||
"cumulative_total_cost": 1933.457998,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 61.88893703,
|
||||
"disk_sweep_cost": 1682.25,
|
||||
"cumulative_total_cost": 1744.138937,
|
||||
"usable": true,
|
||||
"matching_rows_now": 2243,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -380,10 +386,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
},
|
||||
{
|
||||
"index": "key2",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 20.62787405,
|
||||
"disk_sweep_cost": 84.51771758,
|
||||
"cumulative_total_cost": 105.1455916,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 123.7778741,
|
||||
"disk_sweep_cost": 57.75,
|
||||
"cumulative_total_cost": 181.5278741,
|
||||
"usable": true,
|
||||
"matching_rows_now": 77.6360508,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -391,14 +397,15 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
},
|
||||
{
|
||||
"index": "key3",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 30.94181108,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 185.6668111,
|
||||
"disk_sweep_cost": 0,
|
||||
"cumulative_total_cost": 30.94181108,
|
||||
"cumulative_total_cost": 185.6668111,
|
||||
"usable": true,
|
||||
"matching_rows_now": 2.687185191,
|
||||
"intersect_covering_with_this_index": true,
|
||||
"chosen": true
|
||||
"chosen": false,
|
||||
"cause": "does not reduce cost"
|
||||
}
|
||||
],
|
||||
"clustered_pk":
|
||||
@ -406,9 +413,9 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"clustered_pk_added_to_intersect": false,
|
||||
"cause": "no clustered pk index"
|
||||
},
|
||||
"rows": 2,
|
||||
"cost": 30.94181108,
|
||||
"covering": true,
|
||||
"rows": 77,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"chosen": true
|
||||
},
|
||||
"analyzing_index_merge_union":
|
||||
@ -422,9 +429,9 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.chosen_range_access_summary'))
|
||||
"range_access_plan":
|
||||
{
|
||||
"type": "index_roworder_intersect",
|
||||
"rows": 2,
|
||||
"cost": 30.94181108,
|
||||
"covering": true,
|
||||
"rows": 77,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"clustered_pk_scan": false,
|
||||
"intersect_of":
|
||||
[
|
||||
@ -441,18 +448,11 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.chosen_range_access_summary'))
|
||||
"rows": 2243,
|
||||
"ranges":
|
||||
["(100) <= (key2) <= (100)"]
|
||||
},
|
||||
{
|
||||
"type": "range_scan",
|
||||
"index": "key3",
|
||||
"rows": 2243,
|
||||
"ranges":
|
||||
["(100) <= (key3) <= (100)"]
|
||||
}
|
||||
]
|
||||
},
|
||||
"rows_for_plan": 2,
|
||||
"cost_for_plan": 30.94181108,
|
||||
"rows_for_plan": 77,
|
||||
"cost_for_plan": 197.0550842,
|
||||
"chosen": true
|
||||
}
|
||||
]
|
||||
@ -486,7 +486,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 2243,
|
||||
"cost": 457.058937,
|
||||
"cost": 517.508937,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -497,13 +497,13 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 2243,
|
||||
"cost": 457.058937,
|
||||
"cost": 517.508937,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
}
|
||||
],
|
||||
"index_to_merge": "key1",
|
||||
"cumulated_cost": 457.058937
|
||||
"cumulated_cost": 517.508937
|
||||
},
|
||||
{
|
||||
"range_scan_alternatives":
|
||||
@ -516,7 +516,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 2243,
|
||||
"cost": 457.058937,
|
||||
"cost": 517.508937,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -527,16 +527,16 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": true,
|
||||
"rows": 2243,
|
||||
"cost": 457.058937,
|
||||
"cost": 517.508937,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
}
|
||||
],
|
||||
"index_to_merge": "key3",
|
||||
"cumulated_cost": 914.1178741
|
||||
"cumulated_cost": 1035.017874
|
||||
}
|
||||
],
|
||||
"cost_of_reading_ranges": 914.1178741,
|
||||
"cost_of_reading_ranges": 1035.017874,
|
||||
"use_roworder_union": true,
|
||||
"cause": "always cheaper than non roworder retrieval",
|
||||
"analyzing_roworder_scans":
|
||||
@ -553,10 +553,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
[
|
||||
{
|
||||
"index": "key1",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 10.31393703,
|
||||
"disk_sweep_cost": 1923.144061,
|
||||
"cumulative_total_cost": 1933.457998,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 61.88893703,
|
||||
"disk_sweep_cost": 1682.25,
|
||||
"cumulative_total_cost": 1744.138937,
|
||||
"usable": true,
|
||||
"matching_rows_now": 2243,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -564,10 +564,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
},
|
||||
{
|
||||
"index": "key2",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 20.62787405,
|
||||
"disk_sweep_cost": 84.51771758,
|
||||
"cumulative_total_cost": 105.1455916,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 123.7778741,
|
||||
"disk_sweep_cost": 57.75,
|
||||
"cumulative_total_cost": 181.5278741,
|
||||
"usable": true,
|
||||
"matching_rows_now": 77.6360508,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -580,7 +580,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"cause": "no clustered pk index"
|
||||
},
|
||||
"rows": 77,
|
||||
"cost": 105.1455916,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"chosen": true
|
||||
}
|
||||
@ -597,10 +597,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
[
|
||||
{
|
||||
"index": "key3",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 10.31393703,
|
||||
"disk_sweep_cost": 1923.144061,
|
||||
"cumulative_total_cost": 1933.457998,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 61.88893703,
|
||||
"disk_sweep_cost": 1682.25,
|
||||
"cumulative_total_cost": 1744.138937,
|
||||
"usable": true,
|
||||
"matching_rows_now": 2243,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -608,10 +608,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
},
|
||||
{
|
||||
"index": "key4",
|
||||
"index_scan_cost": 10.31393703,
|
||||
"cumulated_index_scan_cost": 20.62787405,
|
||||
"disk_sweep_cost": 84.51771758,
|
||||
"cumulative_total_cost": 105.1455916,
|
||||
"index_scan_cost": 61.88893703,
|
||||
"cumulated_index_scan_cost": 123.7778741,
|
||||
"disk_sweep_cost": 57.75,
|
||||
"cumulative_total_cost": 181.5278741,
|
||||
"usable": true,
|
||||
"matching_rows_now": 77.6360508,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -624,13 +624,13 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"cause": "no clustered pk index"
|
||||
},
|
||||
"rows": 77,
|
||||
"cost": 105.1455916,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"chosen": true
|
||||
}
|
||||
}
|
||||
],
|
||||
"index_roworder_union_cost": 194.9771115,
|
||||
"index_roworder_union_cost": 332.5637481,
|
||||
"members": 2,
|
||||
"chosen": true
|
||||
}
|
||||
@ -649,7 +649,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.chosen_range_access_summary'))
|
||||
{
|
||||
"type": "index_roworder_intersect",
|
||||
"rows": 77,
|
||||
"cost": 105.1455916,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"clustered_pk_scan": false,
|
||||
"intersect_of":
|
||||
@ -673,7 +673,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.chosen_range_access_summary'))
|
||||
{
|
||||
"type": "index_roworder_intersect",
|
||||
"rows": 77,
|
||||
"cost": 105.1455916,
|
||||
"cost": 197.0550842,
|
||||
"covering": false,
|
||||
"clustered_pk_scan": false,
|
||||
"intersect_of":
|
||||
@ -697,7 +697,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.chosen_range_access_summary'))
|
||||
]
|
||||
},
|
||||
"rows_for_plan": 154,
|
||||
"cost_for_plan": 194.9771115,
|
||||
"cost_for_plan": 332.5637481,
|
||||
"chosen": true
|
||||
}
|
||||
]
|
||||
|
@ -89,7 +89,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"range_analysis": {
|
||||
"table_scan": {
|
||||
"rows": 1000,
|
||||
"cost": 206
|
||||
"cost": 253
|
||||
},
|
||||
"potential_range_indexes": [
|
||||
{
|
||||
@ -118,7 +118,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 1000,
|
||||
"cost": 204.27,
|
||||
"cost": 252.02,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -128,7 +128,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 1,
|
||||
"cost": 1.345146475,
|
||||
"cost": 1.270146475,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
@ -136,10 +136,10 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"intersecting_indexes": [
|
||||
{
|
||||
"index": "key1",
|
||||
"index_scan_cost": 1.000146475,
|
||||
"cumulated_index_scan_cost": 1.000146475,
|
||||
"disk_sweep_cost": 1.004153686,
|
||||
"cumulative_total_cost": 2.004300162,
|
||||
"index_scan_cost": 0.525146475,
|
||||
"cumulated_index_scan_cost": 0.525146475,
|
||||
"disk_sweep_cost": 0.752076843,
|
||||
"cumulative_total_cost": 1.277223319,
|
||||
"usable": true,
|
||||
"matching_rows_now": 1,
|
||||
"intersect_covering_with_this_index": false,
|
||||
@ -167,7 +167,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"ranges": ["(1) <= (key1) <= (1)"]
|
||||
},
|
||||
"rows_for_plan": 1,
|
||||
"cost_for_plan": 1.345146475,
|
||||
"cost_for_plan": 1.270146475,
|
||||
"chosen": true
|
||||
}
|
||||
}
|
||||
@ -177,7 +177,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"rowid_filters": [
|
||||
{
|
||||
"key": "key1",
|
||||
"build_cost": 0.130146475,
|
||||
"build_cost": 0.526146475,
|
||||
"rows": 1
|
||||
}
|
||||
]
|
||||
@ -206,16 +206,16 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
{
|
||||
"best_access_path": {
|
||||
"table": "t1",
|
||||
"plan_details": {
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths": [
|
||||
{
|
||||
"access_type": "ref",
|
||||
"index": "key1",
|
||||
"used_range_estimates": true,
|
||||
"rows": 1,
|
||||
"cond_check_cost": 1.325146475,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 1,
|
||||
"cost": 1.325146475,
|
||||
"cost": 1.250146475,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -227,7 +227,7 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"chosen_access_method": {
|
||||
"type": "ref",
|
||||
"records": 1,
|
||||
"cost": 1.325146475,
|
||||
"cost": 1.250146475,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -238,13 +238,14 @@ explain select * from t1 where pk1 != 0 and key1 = 1 {
|
||||
"plan_prefix": [],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 1,
|
||||
"cost_for_plan": 1.525146475
|
||||
"cost_for_plan": 1.250146475
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"best_join_order": ["t1"],
|
||||
"cost": 1.524146475
|
||||
"rows": 1,
|
||||
"cost": 1.250146475
|
||||
},
|
||||
{
|
||||
"substitute_best_equal": {
|
||||
|
@ -80,7 +80,8 @@ select * from db1.t1 {
|
||||
"table": "t1",
|
||||
"table_scan": {
|
||||
"rows": 3,
|
||||
"cost": 2.005126953
|
||||
"read_cost": 1.002563477,
|
||||
"read_and_compare_cost": 1.752563477
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -93,18 +94,24 @@ select * from db1.t1 {
|
||||
{
|
||||
"best_access_path": {
|
||||
"table": "t1",
|
||||
"plan_details": {
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths": [
|
||||
{
|
||||
"access_type": "scan",
|
||||
"resulting_rows": 3,
|
||||
"cost": 2.605126953,
|
||||
"rows": 3,
|
||||
"rows_after_scan": 3,
|
||||
"rows_after_filter": 3,
|
||||
"cost": 1.752563477,
|
||||
"index_only": false,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
"chosen_access_method": {
|
||||
"type": "scan",
|
||||
"records": 3,
|
||||
"cost": 2.605126953,
|
||||
"cost": 1.752563477,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -115,13 +122,14 @@ select * from db1.t1 {
|
||||
"plan_prefix": [],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 3,
|
||||
"cost_for_plan": 3.205126953
|
||||
"cost_for_plan": 1.752563477
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"best_join_order": ["t1"],
|
||||
"cost": 3.204126953
|
||||
"rows": 3,
|
||||
"cost": 1.752563477
|
||||
},
|
||||
{
|
||||
"attaching_conditions_to_tables": {
|
||||
@ -210,7 +218,8 @@ select * from db1.v1 {
|
||||
"table": "t1",
|
||||
"table_scan": {
|
||||
"rows": 3,
|
||||
"cost": 2.005126953
|
||||
"read_cost": 1.002563477,
|
||||
"read_and_compare_cost": 1.752563477
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -223,18 +232,24 @@ select * from db1.v1 {
|
||||
{
|
||||
"best_access_path": {
|
||||
"table": "t1",
|
||||
"plan_details": {
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths": [
|
||||
{
|
||||
"access_type": "scan",
|
||||
"resulting_rows": 3,
|
||||
"cost": 2.605126953,
|
||||
"rows": 3,
|
||||
"rows_after_scan": 3,
|
||||
"rows_after_filter": 3,
|
||||
"cost": 1.752563477,
|
||||
"index_only": false,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
"chosen_access_method": {
|
||||
"type": "scan",
|
||||
"records": 3,
|
||||
"cost": 2.605126953,
|
||||
"cost": 1.752563477,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -245,13 +260,14 @@ select * from db1.v1 {
|
||||
"plan_prefix": [],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 3,
|
||||
"cost_for_plan": 3.205126953
|
||||
"cost_for_plan": 1.752563477
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"best_join_order": ["t1"],
|
||||
"cost": 3.204126953
|
||||
"rows": 3,
|
||||
"cost": 1.752563477
|
||||
},
|
||||
{
|
||||
"attaching_conditions_to_tables": {
|
||||
|
@ -42,6 +42,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"best_access_path":
|
||||
{
|
||||
"table": "t1",
|
||||
"plan_details":
|
||||
{
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths":
|
||||
[
|
||||
{
|
||||
@ -49,10 +53,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "a",
|
||||
"used_range_estimates": true,
|
||||
"rows": 104,
|
||||
"cond_check_cost": 124.96562,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 104,
|
||||
"cost": 124.96562,
|
||||
"cost": 78.54062004,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -60,10 +61,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "b",
|
||||
"used_range_estimates": true,
|
||||
"rows": 340,
|
||||
"cond_check_cost": 408.2577963,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 340,
|
||||
"cost": 408.2577963,
|
||||
"cost": 255.6327963,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
},
|
||||
@ -72,17 +70,16 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "c",
|
||||
"used_range_estimates": true,
|
||||
"rows": 632,
|
||||
"cond_check_cost": 758.7718449,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 632,
|
||||
"cost": 758.7718449,
|
||||
"cost": 475.2468449,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
},
|
||||
{
|
||||
"access_type": "index_merge",
|
||||
"resulting_rows": 7,
|
||||
"cost": 2.173416331,
|
||||
"rows": 7,
|
||||
"rows_after_scan": 7,
|
||||
"rows_after_filter": 7,
|
||||
"cost": 13.79559815,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
@ -90,7 +87,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
{
|
||||
"type": "index_merge",
|
||||
"records": 7,
|
||||
"cost": 2.173416331,
|
||||
"cost": 13.79559815,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -102,7 +99,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
[],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 7,
|
||||
"cost_for_plan": 3.573416331
|
||||
"cost_for_plan": 13.79559815
|
||||
}
|
||||
]
|
||||
]
|
||||
@ -139,6 +136,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"best_access_path":
|
||||
{
|
||||
"table": "t1",
|
||||
"plan_details":
|
||||
{
|
||||
"record_count": 1
|
||||
},
|
||||
"considered_access_paths":
|
||||
[
|
||||
{
|
||||
@ -146,10 +147,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "a",
|
||||
"used_range_estimates": true,
|
||||
"rows": 6,
|
||||
"cond_check_cost": 7.327343464,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 6,
|
||||
"cost": 7.327343464,
|
||||
"cost": 5.002343464,
|
||||
"chosen": true
|
||||
},
|
||||
{
|
||||
@ -157,10 +155,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "b",
|
||||
"used_range_estimates": true,
|
||||
"rows": 232,
|
||||
"cond_check_cost": 278.6156139,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 232,
|
||||
"cost": 278.6156139,
|
||||
"cost": 174.5906139,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
},
|
||||
@ -169,25 +164,21 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"index": "c",
|
||||
"used_range_estimates": true,
|
||||
"rows": 293,
|
||||
"cond_check_cost": 351.8394392,
|
||||
"startup_cost": 0,
|
||||
"rows_after_filter": 293,
|
||||
"cost": 351.8394392,
|
||||
"cost": 220.3644392,
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
},
|
||||
{
|
||||
"access_type": "index_merge",
|
||||
"resulting_rows": 1,
|
||||
"cost": 2.092957403,
|
||||
"chosen": true
|
||||
"type": "scan",
|
||||
"chosen": false,
|
||||
"cause": "cost"
|
||||
}
|
||||
],
|
||||
"chosen_access_method":
|
||||
{
|
||||
"type": "index_merge",
|
||||
"records": 1,
|
||||
"cost": 2.092957403,
|
||||
"type": "ref",
|
||||
"records": 6,
|
||||
"cost": 5.002343464,
|
||||
"uses_join_buffering": false
|
||||
}
|
||||
}
|
||||
@ -198,8 +189,10 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans'))
|
||||
"plan_prefix":
|
||||
[],
|
||||
"table": "t1",
|
||||
"rows_for_plan": 1,
|
||||
"cost_for_plan": 2.292957403
|
||||
"rows_for_plan": 6,
|
||||
"cost_for_plan": 5.002343464,
|
||||
"selectivity": 0.1,
|
||||
"estimated_join_cardinality": 0.6
|
||||
}
|
||||
]
|
||||
]
|
||||
|
@ -19,7 +19,9 @@ select count(*) from t1 where c=5 and b=5;
|
||||
|
||||
set optimizer_trace="enabled=on";
|
||||
select count(*) from t1 where a=2 and b=5 and c=10;
|
||||
|
||||
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.considered_execution_plans')) from INFORMATION_SCHEMA.OPTIMIZER_TRACE;
|
||||
|
||||
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) from INFORMATION_SCHEMA.OPTIMIZER_TRACE;
|
||||
|
||||
select count(*) from t1 where a=2 and b=5 and c=5;
|
||||
|
@ -38,7 +38,7 @@ JSON_DETAILED(JSON_EXTRACT(trace, '$**.analyzing_range_alternatives'))
|
||||
"using_mrr": false,
|
||||
"index_only": false,
|
||||
"rows": 2,
|
||||
"cost": 2.547733708,
|
||||
"cost": 2.022733708,
|
||||
"chosen": true
|
||||
}
|
||||
],
|
||||
|
@ -150,8 +150,8 @@ from t2 where b in (3,4)
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived4> ref key0 key0 4 test.t2.b 2 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.00
|
||||
2 MATERIALIZED <derived4> ALL NULL NULL NULL NULL 2 75.00 Using where; Using join buffer (flat, BNL join)
|
||||
4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(4)) `tvc_0` join `test`.`t2`) where `tvc_0`.`_col_1` = `test`.`t2`.`b`
|
||||
@ -168,8 +168,8 @@ from (values (3),(4)) as tvc_0
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived4> ref key0 key0 4 test.t2.b 2 100.00
|
||||
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.00
|
||||
2 MATERIALIZED <derived4> ALL NULL NULL NULL NULL 2 75.00 Using where; Using join buffer (flat, BNL join)
|
||||
4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(4)) `tvc_0` join `test`.`t2`) where `tvc_0`.`3` = `test`.`t2`.`b`
|
||||
@ -382,8 +382,8 @@ as dr_table
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived5> ref key0 key0 4 test.t1.a 2 100.00
|
||||
2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00
|
||||
2 MATERIALIZED <derived5> ALL NULL NULL NULL NULL 2 75.00 Using where; Using join buffer (flat, BNL join)
|
||||
5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (1),(2)) `tvc_0` join `test`.`t1`) where `test`.`t1`.`a` = 1 and `tvc_0`.`_col_1` = `test`.`t1`.`a`
|
||||
@ -407,8 +407,8 @@ as dr_table
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived5> ref key0 key0 4 test.t1.a 2 100.00
|
||||
2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00
|
||||
2 MATERIALIZED <derived5> ALL NULL NULL NULL NULL 2 75.00 Using where; Using join buffer (flat, BNL join)
|
||||
5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (1),(2)) `tvc_0` join `test`.`t1`) where `test`.`t1`.`a` = 1 and `tvc_0`.`1` = `test`.`t1`.`a`
|
||||
@ -444,7 +444,7 @@ where b in (3,5)
|
||||
group by b
|
||||
) as dr_table;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 12 100.00
|
||||
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 9 100.00
|
||||
2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort
|
||||
2 DERIVED <subquery3> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
3 MATERIALIZED <derived4> ALL NULL NULL NULL NULL 2 100.00
|
||||
@ -464,7 +464,7 @@ as tvc_0
|
||||
group by b
|
||||
) as dr_table;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 12 100.00
|
||||
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 9 100.00
|
||||
2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort
|
||||
2 DERIVED <subquery3> eq_ref distinct_key distinct_key 4 func 1 100.00
|
||||
3 MATERIALIZED <derived4> ALL NULL NULL NULL NULL 2 100.00
|
||||
@ -526,7 +526,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (1,2),(3,4)) `tvc_0`) where 1
|
||||
set @@in_predicate_conversion_threshold= 2;
|
||||
# trasformation works for the one IN predicate and doesn't work for the other
|
||||
# transformation works for the one IN predicate and doesn't work for the other
|
||||
set @@in_predicate_conversion_threshold= 5;
|
||||
select * from t2
|
||||
where (a,b) in ((1,2),(8,9)) and
|
||||
@ -539,11 +539,10 @@ where (a,b) in ((1,2),(8,9)) and
|
||||
(a,c) in ((1,3),(8,0),(5,1));
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 8 func,func 1 100.00
|
||||
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 3 100.00
|
||||
1 PRIMARY <derived3> ref key0 key0 8 test.t2.a,test.t2.c 2 100.00 FirstMatch(t2)
|
||||
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` semi join ((values (1,3),(8,0),(5,1)) `tvc_0`) where (`test`.`t2`.`a`,`test`.`t2`.`b`) in (<cache>((1,2)),<cache>((8,9)))
|
||||
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` semi join ((values (1,3),(8,0),(5,1)) `tvc_0`) where `tvc_0`.`_col_1` = `test`.`t2`.`a` and `tvc_0`.`_col_2` = `test`.`t2`.`c` and (`test`.`t2`.`a`,`test`.`t2`.`b`) in (<cache>((1,2)),<cache>((8,9)))
|
||||
set @@in_predicate_conversion_threshold= 2;
|
||||
#
|
||||
# mdev-14281: conversion of NOT IN predicate into subquery predicate
|
||||
@ -568,18 +567,18 @@ explain extended select * from t1
|
||||
where (a,b) not in ((1,2),(8,9), (5,1));
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 3 100.00
|
||||
2 DEPENDENT SUBQUERY <derived3> index_subquery key0 key0 8 func,func 2 100.00 Using where; Full scan on NULL key
|
||||
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`_col_1`,`tvc_0`.`_col_2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`_col_1` and `test`.`t1`.`b` = `<subquery2>`.`_col_2`))))
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),<exists>(<index_lookup>(<cache>(`test`.`t1`.`a`) in (temporary) on key0 where trigcond(<cache>(`test`.`t1`.`a`) = `tvc_0`.`_col_1`) and trigcond(<cache>(`test`.`t1`.`b`) = `tvc_0`.`_col_2`)))))
|
||||
explain extended select * from t1
|
||||
where (a,b) not in (select * from (values (1,2),(8,9), (5,1)) as tvc_0);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 3 100.00
|
||||
2 DEPENDENT SUBQUERY <derived3> index_subquery key0 key0 8 func,func 2 100.00 Using where; Full scan on NULL key
|
||||
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`1`,`tvc_0`.`2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`1` and `test`.`t1`.`b` = `<subquery2>`.`2`))))
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),<exists>(<index_lookup>(<cache>(`test`.`t1`.`a`) in (temporary) on key0 where trigcond(<cache>(`test`.`t1`.`a`) = `tvc_0`.`1`) and trigcond(<cache>(`test`.`t1`.`b`) = `tvc_0`.`2`)))))
|
||||
select * from t1
|
||||
where b < 7 and (a,b) not in ((1,2),(8,9), (5,1));
|
||||
a b
|
||||
@ -590,10 +589,10 @@ explain extended select * from t1
|
||||
where b < 7 and (a,b) not in ((1,2),(8,9), (5,1));
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 3 100.00
|
||||
2 DEPENDENT SUBQUERY <derived3> index_subquery key0 key0 8 func,func 2 100.00 Using where; Full scan on NULL key
|
||||
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where `test`.`t1`.`b` < 7 and !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`_col_1`,`tvc_0`.`_col_2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`_col_1` and `test`.`t1`.`b` = `<subquery2>`.`_col_2`))))
|
||||
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where `test`.`t1`.`b` < 7 and !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),<exists>(<index_lookup>(<cache>(`test`.`t1`.`a`) in (temporary) on key0 where trigcond(<cache>(`test`.`t1`.`a`) = `tvc_0`.`_col_1`) and trigcond(<cache>(`test`.`t1`.`b`) = `tvc_0`.`_col_2`)))))
|
||||
select * from t2
|
||||
where (a,c) not in ((1,2),(8,9), (5,1));
|
||||
a b c
|
||||
@ -606,10 +605,10 @@ explain extended select * from t2
|
||||
where (a,c) not in ((1,2),(8,9), (5,1));
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 6 100.00 Using where
|
||||
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 3 100.00
|
||||
2 DEPENDENT SUBQUERY <derived3> index_subquery key0 key0 8 func,func 2 100.00 Using where; Full scan on NULL key
|
||||
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
Warnings:
|
||||
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where !<expr_cache><`test`.`t2`.`a`,`test`.`t2`.`c`>(<in_optimizer>((`test`.`t2`.`a`,`test`.`t2`.`c`),(`test`.`t2`.`a`,`test`.`t2`.`c`) in ( <materialize> (/* select#2 */ select `tvc_0`.`_col_1`,`tvc_0`.`_col_2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t2`.`a` in <temporary table> on distinct_key where `test`.`t2`.`a` = `<subquery2>`.`_col_1` and `test`.`t2`.`c` = `<subquery2>`.`_col_2`))))
|
||||
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where !<expr_cache><`test`.`t2`.`a`,`test`.`t2`.`c`>(<in_optimizer>((`test`.`t2`.`a`,`test`.`t2`.`c`),<exists>(<index_lookup>(<cache>(`test`.`t2`.`a`) in (temporary) on key0 where trigcond(<cache>(`test`.`t2`.`a`) = `tvc_0`.`_col_1`) and trigcond(<cache>(`test`.`t2`.`c`) = `tvc_0`.`_col_2`)))))
|
||||
drop table t1, t2, t3;
|
||||
set @@in_predicate_conversion_threshold= default;
|
||||
#
|
||||
|
@ -276,7 +276,7 @@ eval $query;
|
||||
eval explain extended $query;
|
||||
set @@in_predicate_conversion_threshold= 2;
|
||||
|
||||
--echo # trasformation works for the one IN predicate and doesn't work for the other
|
||||
--echo # transformation works for the one IN predicate and doesn't work for the other
|
||||
|
||||
set @@in_predicate_conversion_threshold= 5;
|
||||
|
||||
|
@ -1192,7 +1192,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index k2 k3 5 NULL 111 Using where
|
||||
EXPLAIN SELECT id,c3 FROM t2 WHERE c2=11 ORDER BY c3 LIMIT 4000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index k2 k3 5 NULL 22318 Using where
|
||||
1 SIMPLE t2 ref k2 k2 5 const 7341 Using where; Using filesort
|
||||
EXPLAIN SELECT id,c3 FROM t2 WHERE c2 BETWEEN 10 AND 12 ORDER BY c3 LIMIT 20;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index k2 k3 5 NULL 73 Using where
|
||||
@ -1221,6 +1221,10 @@ id c3
|
||||
176 14
|
||||
186 14
|
||||
196 14
|
||||
ALTER TABLE t2 DROP INDEX k3, ADD INDEX k3 (c3,c2);
|
||||
EXPLAIN SELECT c3 FROM t2 WHERE c2=11 ORDER BY c3 LIMIT 4000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index k2 k3 10 NULL 22318 Using where; Using index
|
||||
DROP TABLE t1,t2;
|
||||
CREATE TABLE t1 (
|
||||
a INT,
|
||||
@ -1551,11 +1555,17 @@ INSERT INTO t1 VALUES (1, 10), (2, NULL);
|
||||
EXPLAIN
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref_or_null a_c,a a_c 10 const,const 2 Using where; Using index; Using filesort
|
||||
1 SIMPLE t1 range a_c,a a_c 10 NULL 2 Using where; Using index
|
||||
# Must return 1 row
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
col
|
||||
1
|
||||
# With more rows "range" changes to "ref_or_null"
|
||||
INSERT INTO t1 select seq,seq from seq_1_to_10;
|
||||
EXPLAIN
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref_or_null a_c,a a_c 10 const,const 2 Using where; Using index; Using filesort
|
||||
# Must use ref-or-null on the a_c index
|
||||
EXPLAIN
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c DESC;
|
||||
@ -3412,10 +3422,9 @@ ANALYZE
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": "REPLACED",
|
||||
"r_limit": 5,
|
||||
"r_used_priority_queue": false,
|
||||
"r_output_rows": 100,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_sort_mode": "sort_key,packed_addon_fields",
|
||||
"r_used_priority_queue": true,
|
||||
"r_output_rows": 6,
|
||||
"r_sort_mode": "sort_key,rowid",
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
"access_type": "ALL",
|
||||
@ -3453,7 +3462,7 @@ CREATE TABLE t2 SELECT * FROM t1;
|
||||
EXPLAIN SELECT (SELECT 1 FROM t1 WHERE t1.a=t2.b ORDER BY t1.b LIMIT 1) AS c FROM t2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
|
||||
2 DEPENDENT SUBQUERY t1 index PRIMARY b 5 NULL 1 Using where
|
||||
2 DEPENDENT SUBQUERY t1 eq_ref PRIMARY PRIMARY 4 test.t2.b 1 Using where
|
||||
SELECT (SELECT 1 FROM t1 WHERE t1.a=t2.b ORDER BY t1.b LIMIT 1) AS c FROM t2;
|
||||
c
|
||||
1
|
||||
@ -3501,11 +3510,10 @@ WHERE books.library_id = 8663 AND
|
||||
books.scheduled_for_removal=0 )
|
||||
ORDER BY wings.id;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 2 100.00 Using filesort
|
||||
1 PRIMARY wings eq_ref PRIMARY PRIMARY 4 test.books.wings_id 1 100.00
|
||||
2 MATERIALIZED books ref library_idx library_idx 4 const 2 100.00 Using where
|
||||
1 PRIMARY wings ALL PRIMARY NULL NULL NULL 2 100.00 Using temporary; Using filesort
|
||||
1 PRIMARY books ALL library_idx NULL NULL NULL 2 100.00 Using where; FirstMatch(wings); Using join buffer (flat, BNL join)
|
||||
Warnings:
|
||||
Note 1003 select `test`.`wings`.`id` AS `wing_id`,`test`.`wings`.`department_id` AS `department_id` from `test`.`wings` semi join (`test`.`books`) where `test`.`books`.`library_id` = 8663 and `test`.`books`.`scheduled_for_removal` = 0 and `test`.`wings`.`id` = `test`.`books`.`wings_id` order by `test`.`wings`.`id`
|
||||
Note 1003 select `test`.`wings`.`id` AS `wing_id`,`test`.`wings`.`department_id` AS `department_id` from `test`.`wings` semi join (`test`.`books`) where `test`.`books`.`library_id` = 8663 and `test`.`books`.`scheduled_for_removal` = 0 and `test`.`books`.`wings_id` = `test`.`wings`.`id` order by `test`.`wings`.`id`
|
||||
set optimizer_switch= @save_optimizer_switch;
|
||||
DROP TABLE books, wings;
|
||||
#
|
||||
|
@ -9,6 +9,7 @@
|
||||
--source include/no_view_protocol.inc
|
||||
|
||||
call mtr.add_suppression("Sort aborted.*");
|
||||
--source include/have_sequence.inc
|
||||
call mtr.add_suppression("Out of sort memory; increase server sort buffer size");
|
||||
--source include/have_sequence.inc
|
||||
|
||||
@ -803,6 +804,10 @@ EXPLAIN SELECT id,c3 FROM t2 WHERE c2 BETWEEN 20 AND 30 ORDER BY c3 LIMIT 4000;
|
||||
|
||||
SELECT id,c3 FROM t2 WHERE c2=11 ORDER BY c3 LIMIT 20;
|
||||
|
||||
# Show that order by optimization takes into account index only scans
|
||||
ALTER TABLE t2 DROP INDEX k3, ADD INDEX k3 (c3,c2);
|
||||
EXPLAIN SELECT c3 FROM t2 WHERE c2=11 ORDER BY c3 LIMIT 4000;
|
||||
|
||||
DROP TABLE t1,t2;
|
||||
|
||||
#
|
||||
@ -912,6 +917,11 @@ SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
--echo # Must return 1 row
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
|
||||
--echo # With more rows "range" changes to "ref_or_null"
|
||||
INSERT INTO t1 select seq,seq from seq_1_to_10;
|
||||
EXPLAIN
|
||||
SELECT 1 AS col FROM t1 WHERE a=2 AND (c=10 OR c IS NULL) ORDER BY c;
|
||||
|
||||
# part 2 of the problem : DESC test cases
|
||||
--echo # Must use ref-or-null on the a_c index
|
||||
--replace_column 1 x 2 x 3 x 6 x 7 x 8 x 9 x 10 x
|
||||
|
@ -53,17 +53,29 @@ KEY a_c (a,c),
|
||||
KEY a_b (a,b)
|
||||
) ENGINE=InnoDB;
|
||||
insert into t1 select A.a , B.a, C.a from t0 A, t0 B, t0 C;
|
||||
select count(*) from t1;
|
||||
count(*)
|
||||
1000
|
||||
select count(*) from t1 where a=1;
|
||||
count(*)
|
||||
200
|
||||
select count(*) from t1 where a=1 and c=2;
|
||||
count(*)
|
||||
20
|
||||
# should use ref access
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref a_c,a_b a_c 10 const,const 20 Using where; Using filesort
|
||||
# both should use range access
|
||||
# all should use range access
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 10;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref a_c,a_b a_c 10 const,const 20 Using where; Using filesort
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 300;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref a_c,a_b a_c 10 const,const 20 Using where; Using filesort
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 1000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a_c,a_b a_b 5 NULL 200 Using where
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 2000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a_c,a_b a_b 5 NULL 200 Using where
|
||||
1 SIMPLE t1 ref a_c,a_b a_c 10 const,const 20 Using where; Using filesort
|
||||
drop table t1,t0;
|
||||
# Start of 10.2 tests
|
||||
#
|
||||
@ -245,8 +257,8 @@ dd.d1, dd.d2, dd.id limit 1
|
||||
);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 index NULL PRIMARY 4 NULL # Using index
|
||||
1 PRIMARY t2 eq_ref PRIMARY,id2 PRIMARY 4 func # Using where
|
||||
2 DEPENDENT SUBQUERY dd range id2,for_latest_sort for_latest_sort 6 NULL # Using where
|
||||
1 PRIMARY t2 eq_ref PRIMARY,id2 id2 8 test.t1.id,func # Using where; Using index
|
||||
2 DEPENDENT SUBQUERY dd ref id2,for_latest_sort id2 4 test.t1.id # Using where; Using filesort
|
||||
drop table t1,t2,t3;
|
||||
# End of 10.2 tests
|
||||
#
|
||||
|
@ -66,13 +66,17 @@ KEY a_c (a,c),
|
||||
KEY a_b (a,b)
|
||||
) ENGINE=InnoDB;
|
||||
insert into t1 select A.a , B.a, C.a from t0 A, t0 B, t0 C;
|
||||
select count(*) from t1;
|
||||
select count(*) from t1 where a=1;
|
||||
select count(*) from t1 where a=1 and c=2;
|
||||
|
||||
--echo # should use ref access
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b;
|
||||
|
||||
--echo # both should use range access
|
||||
--echo # all should use range access
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 10;
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 300;
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 1000;
|
||||
explain select a,b,c from t1 where a=1 and c=2 order by b limit 2000;
|
||||
drop table t1,t0;
|
||||
|
||||
--echo # Start of 10.2 tests
|
||||
|
@ -40,6 +40,9 @@ INSERT INTO tmp SELECT f1,f2 FROM t1;
|
||||
INSERT INTO t1(f1,f2) SELECT * FROM tmp;
|
||||
INSERT INTO tmp SELECT f1,f2 FROM t1;
|
||||
INSERT INTO t1(f1,f2) SELECT * FROM tmp;
|
||||
select count(*) from t1;
|
||||
count(*)
|
||||
87700
|
||||
set sort_buffer_size= 32768;
|
||||
FLUSH STATUS;
|
||||
SHOW SESSION STATUS LIKE 'Sort%';
|
||||
@ -49,6 +52,9 @@ Sort_priority_queue_sorts 0
|
||||
Sort_range 0
|
||||
Sort_rows 0
|
||||
Sort_scan 0
|
||||
explain SELECT * FROM t1 ORDER BY f2 LIMIT 100;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 87700 Using filesort
|
||||
SELECT * FROM t1 ORDER BY f2 LIMIT 100;
|
||||
f0 f1 f2
|
||||
1 0 0
|
||||
@ -158,4 +164,9 @@ Sort_priority_queue_sorts 1
|
||||
Sort_range 0
|
||||
Sort_rows 100
|
||||
Sort_scan 1
|
||||
SHOW STATUS LIKE 'Handler_read_rnd%';
|
||||
Variable_name Value
|
||||
Handler_read_rnd 100
|
||||
Handler_read_rnd_deleted 0
|
||||
Handler_read_rnd_next 87701
|
||||
DROP TABLE t1, tmp;
|
||||
|
@ -50,6 +50,7 @@ INSERT INTO tmp SELECT f1,f2 FROM t1;
|
||||
INSERT INTO t1(f1,f2) SELECT * FROM tmp;
|
||||
INSERT INTO tmp SELECT f1,f2 FROM t1;
|
||||
INSERT INTO t1(f1,f2) SELECT * FROM tmp;
|
||||
select count(*) from t1;
|
||||
|
||||
# Test when only sortkeys fits to memory
|
||||
set sort_buffer_size= 32768;
|
||||
@ -57,8 +58,12 @@ set sort_buffer_size= 32768;
|
||||
FLUSH STATUS;
|
||||
SHOW SESSION STATUS LIKE 'Sort%';
|
||||
|
||||
explain SELECT * FROM t1 ORDER BY f2 LIMIT 100;
|
||||
SELECT * FROM t1 ORDER BY f2 LIMIT 100;
|
||||
|
||||
# Check that Sort_priority_queue_sorts is used
|
||||
SHOW SESSION STATUS LIKE 'Sort%';
|
||||
# Check that we did scan the whole table and did LIMIT lookups
|
||||
SHOW STATUS LIKE 'Handler_read_rnd%';
|
||||
|
||||
DROP TABLE t1, tmp;
|
||||
|
@ -15,13 +15,13 @@ PARTITION max VALUES LESS THAN MAXVALUE);
|
||||
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7),(8);
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
# # # # # # # # # 3 #
|
||||
# # # # range # # # # 3 #
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 7;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
# # # # # # # # # 8 #
|
||||
# # # # range # # # # 8 #
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
# # # # # # # # # 3 #
|
||||
# # # # range # # # # 3 #
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Bug#49742: Partition Pruning not working correctly for RANGE
|
||||
@ -2888,12 +2888,12 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where
|
||||
explain extended select * from t2 where b in (2,4,6);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL b NULL NULL NULL 910 25.38 Using where
|
||||
1 SIMPLE t2 range b b 5 NULL 231 100.00 Using where
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where `test`.`t2`.`b` in (2,4,6)
|
||||
explain partitions select * from t2 where b in (2,4,6);
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 231 Using where
|
||||
explain extended select * from t2 where b in (7,8,9);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL b NULL NULL NULL 910 36.81 Using where
|
||||
@ -2912,12 +2912,12 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where
|
||||
explain extended select * from t2 where b > 5 and b < 8;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 ALL b NULL NULL NULL 910 22.20 Using where
|
||||
1 SIMPLE t2 range b b 5 NULL 202 100.00 Using where
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where `test`.`t2`.`b` > 5 and `test`.`t2`.`b` < 8
|
||||
explain partitions select * from t2 where b > 5 and b < 8;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where
|
||||
1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 202 Using where
|
||||
explain extended select * from t2 where b > 5 and b < 7;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t2 range b b 5 NULL 77 100.00 Using where
|
||||
@ -2946,10 +2946,10 @@ flush status;
|
||||
update t2 set a = 111 where b in (5,6);
|
||||
show status like 'Handler_read_rnd_next';
|
||||
Variable_name Value
|
||||
Handler_read_rnd_next 915
|
||||
Handler_read_rnd_next 0
|
||||
show status like 'Handler_read_key';
|
||||
Variable_name Value
|
||||
Handler_read_key 0
|
||||
Handler_read_key 10
|
||||
flush status;
|
||||
update t2 set a = 222 where b = 7;
|
||||
show status like 'Handler_read_rnd_next';
|
||||
@ -3378,7 +3378,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1 const PRIMARY PRIMARY 8 const,const 1
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 >= 1;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where
|
||||
1 SIMPLE t1 p1,p2 ref PRIMARY PRIMARY 4 const 1 Using where
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 > 1;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where
|
||||
@ -3387,7 +3387,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1 range PRIMARY PRIMARY 8 NULL 2 Using where
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 <= 3;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where
|
||||
1 SIMPLE t1 p1,p2 ref PRIMARY PRIMARY 4 const 1 Using where
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 <= 3;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where
|
||||
@ -3405,7 +3405,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 <= 4;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where
|
||||
1 SIMPLE t1 p1,p2 ref PRIMARY PRIMARY 4 const 1 Using where
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 = 4;
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 p2 const PRIMARY PRIMARY 8 const,const 1
|
||||
@ -3465,8 +3465,8 @@ select * from t1
|
||||
where company_id = 1000
|
||||
and dept_id in (select dept_id from t2 where COMPANY_ID = 1000);
|
||||
id select_type table partitions type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t2 p_1000 ref PRIMARY PRIMARY 8 const 3 Using index
|
||||
1 PRIMARY t1 p_1000 ALL PRIMARY NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join)
|
||||
1 PRIMARY t1 p_1000 ALL PRIMARY NULL NULL NULL 6 Using where
|
||||
1 PRIMARY t2 p_1000 eq_ref PRIMARY PRIMARY 16 const,test.t1.dept_id 1 Using index
|
||||
drop table t1,t2;
|
||||
#
|
||||
# MDEV-9505: Valgrind failure in SEL_ARG::store_min,find_used_partitions,...
|
||||
|
@ -25,11 +25,11 @@ PARTITION max VALUES LESS THAN MAXVALUE);
|
||||
|
||||
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7),(8);
|
||||
|
||||
--replace_column 1 # 2 # 3 # 4 # 5 # 6 # 7 # 8 # 9 # 11 #
|
||||
--replace_column 1 # 2 # 3 # 4 # 6 # 7 # 8 # 9 # 11 #
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
|
||||
--replace_column 1 # 2 # 3 # 4 # 5 # 6 # 7 # 8 # 9 # 11 #
|
||||
--replace_column 1 # 2 # 3 # 4 # 6 # 7 # 8 # 9 # 11 #
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 7;
|
||||
--replace_column 1 # 2 # 3 # 4 # 5 # 6 # 7 # 8 # 9 # 11 #
|
||||
--replace_column 1 # 2 # 3 # 4 # 6 # 7 # 8 # 9 # 11 #
|
||||
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
|
||||
DROP TABLE t1;
|
||||
|
||||
|
@ -9,11 +9,11 @@ COUNT(*)
|
||||
3
|
||||
EXPLAIN SELECT a, MAX(b) FROM t1 WHERE a IN (10000, 1000000, 3000) GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 4 Using where; Using index
|
||||
1 SIMPLE t1 range a a 5 NULL 3 Using where; Using index for group-by
|
||||
alter table t1 partition by hash(a) partitions 1;
|
||||
EXPLAIN SELECT a, MAX(b) FROM t1 WHERE a IN (10000, 1000000, 3000) GROUP BY a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 4 Using where; Using index
|
||||
1 SIMPLE t1 range a a 5 NULL 3 Using where; Using index for group-by
|
||||
alter table t1 remove partitioning;
|
||||
insert into t1 (a,b) select seq,seq from seq_4001_to_4100;
|
||||
insert into t1 (a,b) select seq,seq from seq_10001_to_10100;
|
||||
|
@ -451,7 +451,7 @@ def Extra 253 255 14 N 1 39 8
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using filesort
|
||||
SET @arg00=1 ;
|
||||
prepare stmt1 from ' explain select a from t1 where a > ? order by b ';
|
||||
prepare stmt1 from ' explain select a from t1 force index (primary) where a > ? order by b ';
|
||||
execute stmt1 using @arg00;
|
||||
Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr
|
||||
def id 8 3 1 Y 32928 0 63
|
||||
|
@ -437,8 +437,10 @@ prepare stmt3 from ' unlock tables ' ;
|
||||
## Load/Unload table contents
|
||||
|
||||
--let $datafile = $MYSQLTEST_VARDIR/tmp/data.txt
|
||||
--disable_warnings
|
||||
--error 0,1
|
||||
--remove_file $datafile
|
||||
--enable_warnings
|
||||
|
||||
--replace_result $MYSQLTEST_VARDIR <MYSQLTEST_VARDIR>
|
||||
eval prepare stmt1 from ' load data infile ''$datafile''
|
||||
@ -497,7 +499,7 @@ prepare stmt1 from ' explain select a from t1 order by b ';
|
||||
execute stmt1;
|
||||
--disable_metadata
|
||||
SET @arg00=1 ;
|
||||
prepare stmt1 from ' explain select a from t1 where a > ? order by b ';
|
||||
prepare stmt1 from ' explain select a from t1 force index (primary) where a > ? order by b ';
|
||||
--enable_metadata
|
||||
--replace_result 4096 4_OR_8_K 8192 4_OR_8_K
|
||||
execute stmt1 using @arg00;
|
||||
|
@ -252,7 +252,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref x x 5 const 1 Using index
|
||||
explain select count(*) from t1 where x in (1,2,3,4);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range x x 5 NULL 4 Using where; Using index
|
||||
1 SIMPLE t1 index x x 5 NULL 9 Using where; Using index
|
||||
drop table t1;
|
||||
CREATE TABLE t1 (key1 int(11) NOT NULL default '0', KEY i1 (key1));
|
||||
INSERT INTO t1 VALUES (0),(0),(0),(0),(0),(1),(1);
|
||||
@ -261,12 +261,12 @@ INSERT INTO t2 VALUES (0),(0),(1),(1),(2),(2);
|
||||
explain select * from t1, t2 where (t1.key1 <t2.keya + 1) and t2.keya=3;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref j1 j1 4 const 1 Using index
|
||||
1 SIMPLE t1 range i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 index i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
explain select * from t1 force index(i1), t2 force index(j1) where
|
||||
(t1.key1 <t2.keya + 1) and t2.keya=3;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref j1 j1 4 const 1 Using index
|
||||
1 SIMPLE t1 range i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 index i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
DROP TABLE t1,t2;
|
||||
CREATE TABLE t1 (
|
||||
a int(11) default NULL,
|
||||
@ -281,7 +281,7 @@ INSERT INTO t1 VALUES
|
||||
(33,5),(33,5),(33,5),(33,5),(34,5),(35,5);
|
||||
EXPLAIN SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range|filter a,b a|b 5|5 NULL 2 (41%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE t1 ref|filter a,b b|a 5|5 const 15 (5%) Using where; Using rowid filter
|
||||
SELECT * FROM t1 WHERE a IN(1,2) AND b=5;
|
||||
a b
|
||||
DROP TABLE t1;
|
||||
@ -676,7 +676,7 @@ create table t1(a char(2), key(a(1)));
|
||||
insert into t1 values ('x'), ('xx');
|
||||
explain select a from t1 where a > 'x';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 2 NULL 2 Using where
|
||||
1 SIMPLE t1 ALL a NULL NULL NULL 2 Using where
|
||||
select a from t1 where a > 'x';
|
||||
a
|
||||
xx
|
||||
@ -1138,7 +1138,7 @@ INSERT INTO t1 VALUES
|
||||
('A2','2005-12-01 08:00:00',1000);
|
||||
EXPLAIN SELECT * FROM t1 WHERE item='A1' AND started<='2005-12-01 24:00:00';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref PRIMARY PRIMARY 20 const 3 Using index condition
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 4 Using where
|
||||
SELECT * FROM t1 WHERE item='A1' AND started<='2005-12-01 24:00:00';
|
||||
item started price
|
||||
Warnings:
|
||||
@ -1236,14 +1236,13 @@ insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
|
||||
create table t2 (a int, b int, filler char(100));
|
||||
insert into t2 select A.a + 10 * (B.a + 10 * C.a), 10, 'filler' from t1 A,
|
||||
t1 B, t1 C where A.a < 5;
|
||||
insert into t2 select 1000, b, 'filler' from t2;
|
||||
insert into t2 select 1000, b, 'filler' from t2 limit 250;
|
||||
alter table t2 add index (a,b);
|
||||
select 'In following EXPLAIN the access method should be ref, #rows~=500 (and not 2)' Z;
|
||||
Z
|
||||
In following EXPLAIN the access method should be ref, #rows~=500 (and not 2)
|
||||
# In following EXPLAIN the access method should be ref, #rows~=250
|
||||
# (and not 2) when we are not using rowid-ordered scans
|
||||
explain select * from t2 where a=1000 and b<11;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref a a 5 const 503 Using index condition
|
||||
1 SIMPLE t2 range a a 10 NULL 253 Using index condition
|
||||
drop table t1, t2;
|
||||
CREATE TABLE t1( a INT, b INT, KEY( a, b ) );
|
||||
CREATE TABLE t2( a INT, b INT, KEY( a, b ) );
|
||||
@ -2542,7 +2541,7 @@ insert into t2 values
|
||||
explain select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(2,2));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range|filter idx1,idx2 idx1|idx2 5|5 NULL 3 (60%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE t2 range idx1,idx2 idx1 5 NULL 3 Using index condition; Using where
|
||||
1 SIMPLE t1 ref idx idx 5 test.t2.d 8
|
||||
explain format=json select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(2,2));
|
||||
@ -2559,16 +2558,8 @@ EXPLAIN
|
||||
"key": "idx1",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "idx2",
|
||||
"used_key_parts": ["e"]
|
||||
},
|
||||
"rows": 12,
|
||||
"selectivity_pct": 60
|
||||
},
|
||||
"rows": 3,
|
||||
"filtered": 60,
|
||||
"filtered": 100,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((3,3)),<cache>((7,7)),<cache>((2,2)))"
|
||||
}
|
||||
@ -2628,8 +2619,8 @@ insert into t2 values
|
||||
explain select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range|filter idx1,idx2 idx1|idx2 5|5 NULL 8 (14%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE t1 ref idx idx 5 test.t2.d 8
|
||||
1 SIMPLE t1 range idx idx 5 NULL 6 Using index condition
|
||||
1 SIMPLE t2 ref|filter idx1,idx2 idx1|idx2 5|5 test.t1.a 12 (14%) Using where; Using rowid filter
|
||||
explain format=json select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1;
|
||||
EXPLAIN
|
||||
@ -2639,12 +2630,26 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"table_name": "t1",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["idx"],
|
||||
"key": "idx",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"rows": 6,
|
||||
"filtered": 100,
|
||||
"index_condition": "t1.a is not null"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["idx1", "idx2"],
|
||||
"key": "idx1",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"ref": ["test.t1.a"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "idx2",
|
||||
@ -2653,23 +2658,9 @@ EXPLAIN
|
||||
"rows": 15,
|
||||
"selectivity_pct": 14.42307692
|
||||
},
|
||||
"rows": 8,
|
||||
"rows": 12,
|
||||
"filtered": 14.42307663,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((3,3)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["idx"],
|
||||
"key": "idx",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"ref": ["test.t2.d"],
|
||||
"rows": 8,
|
||||
"filtered": 100
|
||||
"attached_condition": "(t1.a,t2.e) in (<cache>((3,3)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -2678,37 +2669,37 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
7 7 xxxyy 7 7 h
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
prepare stmt from "select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1";
|
||||
execute stmt;
|
||||
a b c d e f
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
@ -2717,16 +2708,16 @@ a b c d e f
|
||||
execute stmt;
|
||||
a b c d e f
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
@ -2739,8 +2730,8 @@ insert into t1 select * from t1;
|
||||
explain select * from t1,t2
|
||||
where a = d and (a,e) in ((4,4),(7,7),(8,8)) and length(f) = 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range|filter idx1,idx2 idx1|idx2 5|5 NULL 7 (7%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE t1 ref idx idx 5 test.t2.d 11
|
||||
1 SIMPLE t1 range idx idx 5 NULL 15 Using index condition
|
||||
1 SIMPLE t2 ref|filter idx1,idx2 idx1|idx2 5|5 test.t1.a 12 (7%) Using where; Using rowid filter
|
||||
explain format=json select * from t1,t2
|
||||
where a = d and (a,e) in ((4,4),(7,7),(8,8)) and length(f) = 1;
|
||||
EXPLAIN
|
||||
@ -2750,12 +2741,26 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"table_name": "t1",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["idx"],
|
||||
"key": "idx",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"rows": 15,
|
||||
"filtered": 100,
|
||||
"index_condition": "t1.a is not null"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t2",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["idx1", "idx2"],
|
||||
"key": "idx1",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"ref": ["test.t1.a"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "idx2",
|
||||
@ -2764,23 +2769,9 @@ EXPLAIN
|
||||
"rows": 7,
|
||||
"selectivity_pct": 6.730769231
|
||||
},
|
||||
"rows": 7,
|
||||
"filtered": 14.28571415,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((4,4)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["idx"],
|
||||
"key": "idx",
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["a"],
|
||||
"ref": ["test.t2.d"],
|
||||
"rows": 11,
|
||||
"filtered": 100
|
||||
"rows": 12,
|
||||
"filtered": 6.730769157,
|
||||
"attached_condition": "(t1.a,t2.e) in (<cache>((4,4)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -2789,14 +2780,14 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((4,4),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
alter table t2 drop index idx1, drop index idx2, add index idx3(d,e);
|
||||
# join order: (t2,t1) with ref access of t1
|
||||
# range access to t2 by 2-component keys for index idx3
|
||||
@ -2900,22 +2891,22 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((4,d+1),(7,d+1),(8,d+1)) and length(f) = 1;
|
||||
a b c d e f
|
||||
4 3 zyx 4 5 a
|
||||
4 3 zya 4 5 a
|
||||
4 3 zya 4 5 a
|
||||
4 3 zyx 4 5 a
|
||||
4 3 zya 4 5 a
|
||||
4 5 ww 4 5 a
|
||||
4 3 zyx 4 5 a
|
||||
4 5 wa 4 5 a
|
||||
4 5 wa 4 5 a
|
||||
4 5 ww 4 5 a
|
||||
4 5 wa 4 5 a
|
||||
7 7 xxxyy 7 8 b
|
||||
4 5 ww 4 5 a
|
||||
7 7 xxxya 7 8 b
|
||||
7 7 xxxya 7 8 b
|
||||
7 7 xxxyy 7 8 b
|
||||
7 7 xxxya 7 8 b
|
||||
7 8 xxxxx 7 8 b
|
||||
7 7 xxxyy 7 8 b
|
||||
7 8 xxxxa 7 8 b
|
||||
7 8 xxxxa 7 8 b
|
||||
7 8 xxxxx 7 8 b
|
||||
7 8 xxxxa 7 8 b
|
||||
7 8 xxxxx 7 8 b
|
||||
# join order: (t1,t2) with ref access of t2
|
||||
# no range access
|
||||
explain select * from t1,t2
|
||||
@ -2960,14 +2951,14 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((e,d+1),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
# join order: (t1,t2) with ref access of t2
|
||||
# range access to t1 by 1-component keys for index idx
|
||||
explain select * from t1,t2
|
||||
|
@ -1025,7 +1025,7 @@ create table t2 (a int, b int, filler char(100));
|
||||
insert into t2 select A.a + 10 * (B.a + 10 * C.a), 10, 'filler' from t1 A,
|
||||
t1 B, t1 C where A.a < 5;
|
||||
|
||||
insert into t2 select 1000, b, 'filler' from t2;
|
||||
insert into t2 select 1000, b, 'filler' from t2 limit 250;
|
||||
alter table t2 add index (a,b);
|
||||
# t2 values
|
||||
# ( 1 , 10, 'filler')
|
||||
@ -1033,13 +1033,14 @@ alter table t2 add index (a,b);
|
||||
# ( 3 , 10, 'filler')
|
||||
# (... , 10, 'filler')
|
||||
# ...
|
||||
# (1000, 10, 'filler') - 500 times
|
||||
# (1000, 10, 'filler') - 250 times
|
||||
|
||||
# 500 rows, 1 row
|
||||
# 250 rows, 1 row
|
||||
|
||||
--echo # In following EXPLAIN the access method should be ref, #rows~=250
|
||||
--echo # (and not 2) when we are not using rowid-ordered scans
|
||||
|
||||
select 'In following EXPLAIN the access method should be ref, #rows~=500 (and not 2)' Z;
|
||||
explain select * from t2 where a=1000 and b<11;
|
||||
|
||||
drop table t1, t2;
|
||||
|
||||
#
|
||||
@ -1980,6 +1981,7 @@ select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1;
|
||||
eval explain $q5;
|
||||
eval explain format=json $q5;
|
||||
--sorted_result
|
||||
eval $q5;
|
||||
eval prepare stmt from "$q5";
|
||||
execute stmt;
|
||||
@ -1995,6 +1997,7 @@ select * from t1,t2
|
||||
where a = d and (a,e) in ((4,4),(7,7),(8,8)) and length(f) = 1;
|
||||
eval explain $q6;
|
||||
eval explain format=json $q6;
|
||||
--sorted_result
|
||||
eval $q6;
|
||||
|
||||
alter table t2 drop index idx1, drop index idx2, add index idx3(d,e);
|
||||
@ -2015,6 +2018,7 @@ select * from t1,t2
|
||||
where a = d and (a,e) in ((4,d+1),(7,d+1),(8,d+1)) and length(f) = 1;
|
||||
eval explain $q8;
|
||||
eval explain format=json $q8;
|
||||
--sorted_result
|
||||
eval $q8;
|
||||
|
||||
--echo # join order: (t1,t2) with ref access of t2
|
||||
@ -2024,6 +2028,7 @@ select * from t1,t2
|
||||
where a = d and (a,e) in ((e,d+1),(7,7),(8,8)) and length(f) = 1;
|
||||
eval explain $q9;
|
||||
eval explain format=json $q9;
|
||||
--sorted_result
|
||||
eval $q9;
|
||||
|
||||
--echo # join order: (t1,t2) with ref access of t2
|
||||
|
@ -53,9 +53,9 @@ set optimizer_switch='extended_keys=on';
|
||||
explain
|
||||
select pk, a, b from t1,t2,t3 where b >= d and pk < c and b = '0';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 2
|
||||
1 SIMPLE t1 ref PRIMARY,idx1,idx2 idx1 5 const 3 Using index condition
|
||||
1 SIMPLE t3 ALL NULL NULL NULL NULL 3 Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL #
|
||||
1 SIMPLE t1 ALL PRIMARY,idx1,idx2 NULL NULL NULL # Using where; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t3 ALL NULL NULL NULL NULL # Using where; Using join buffer (incremental, BNL join)
|
||||
select pk, a, b from t1,t2,t3 where b >= d and pk < c and b = '0';
|
||||
pk a b
|
||||
1 6 0
|
||||
@ -83,6 +83,7 @@ drop table t1,t2;
|
||||
# MDEV-14440: Server crash in in handler::ha_external_lock or Assertion `inited==RND'
|
||||
# failed in handler::ha_rnd_end upon SELECT from partitioned table
|
||||
#
|
||||
call mtr.add_suppression("Got error .* when reading table");
|
||||
set @optimizer_switch_save= @@optimizer_switch;
|
||||
set optimizer_switch='index_merge_sort_intersection=off';
|
||||
create table t0(a int);
|
||||
|
@ -58,6 +58,8 @@ insert into t3 values (3),(-1),(4);
|
||||
set @save_optimizer_switch=@@optimizer_switch;
|
||||
set optimizer_switch='extended_keys=on';
|
||||
|
||||
# InnoDB sometimes returns 4 other times 5 records for t1
|
||||
--replace_column 9 #
|
||||
explain
|
||||
select pk, a, b from t1,t2,t3 where b >= d and pk < c and b = '0';
|
||||
select pk, a, b from t1,t2,t3 where b >= d and pk < c and b = '0';
|
||||
@ -89,6 +91,8 @@ drop table t1,t2;
|
||||
--echo # failed in handler::ha_rnd_end upon SELECT from partitioned table
|
||||
--echo #
|
||||
|
||||
call mtr.add_suppression("Got error .* when reading table");
|
||||
|
||||
set @optimizer_switch_save= @@optimizer_switch;
|
||||
set optimizer_switch='index_merge_sort_intersection=off';
|
||||
create table t0(a int);
|
||||
|
@ -255,7 +255,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref x x 5 const 1 Using index
|
||||
explain select count(*) from t1 where x in (1,2,3,4);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range x x 5 NULL 4 Using where; Using index
|
||||
1 SIMPLE t1 index x x 5 NULL 9 Using where; Using index
|
||||
drop table t1;
|
||||
CREATE TABLE t1 (key1 int(11) NOT NULL default '0', KEY i1 (key1));
|
||||
INSERT INTO t1 VALUES (0),(0),(0),(0),(0),(1),(1);
|
||||
@ -264,12 +264,12 @@ INSERT INTO t2 VALUES (0),(0),(1),(1),(2),(2);
|
||||
explain select * from t1, t2 where (t1.key1 <t2.keya + 1) and t2.keya=3;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref j1 j1 4 const 1 Using index
|
||||
1 SIMPLE t1 range i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 index i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
explain select * from t1 force index(i1), t2 force index(j1) where
|
||||
(t1.key1 <t2.keya + 1) and t2.keya=3;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref j1 j1 4 const 1 Using index
|
||||
1 SIMPLE t1 range i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
1 SIMPLE t1 index i1 i1 4 NULL 7 Using where; Using index; Using join buffer (flat, BNL join)
|
||||
DROP TABLE t1,t2;
|
||||
CREATE TABLE t1 (
|
||||
a int(11) default NULL,
|
||||
@ -679,7 +679,7 @@ create table t1(a char(2), key(a(1)));
|
||||
insert into t1 values ('x'), ('xx');
|
||||
explain select a from t1 where a > 'x';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 2 NULL 2 Using where
|
||||
1 SIMPLE t1 ALL a NULL NULL NULL 2 Using where
|
||||
select a from t1 where a > 'x';
|
||||
a
|
||||
xx
|
||||
@ -1141,7 +1141,7 @@ INSERT INTO t1 VALUES
|
||||
('A2','2005-12-01 08:00:00',1000);
|
||||
EXPLAIN SELECT * FROM t1 WHERE item='A1' AND started<='2005-12-01 24:00:00';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref PRIMARY PRIMARY 20 const 3 Using index condition
|
||||
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 4 Using where
|
||||
SELECT * FROM t1 WHERE item='A1' AND started<='2005-12-01 24:00:00';
|
||||
item started price
|
||||
Warnings:
|
||||
@ -1239,14 +1239,13 @@ insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
|
||||
create table t2 (a int, b int, filler char(100));
|
||||
insert into t2 select A.a + 10 * (B.a + 10 * C.a), 10, 'filler' from t1 A,
|
||||
t1 B, t1 C where A.a < 5;
|
||||
insert into t2 select 1000, b, 'filler' from t2;
|
||||
insert into t2 select 1000, b, 'filler' from t2 limit 250;
|
||||
alter table t2 add index (a,b);
|
||||
select 'In following EXPLAIN the access method should be ref, #rows~=500 (and not 2)' Z;
|
||||
Z
|
||||
In following EXPLAIN the access method should be ref, #rows~=500 (and not 2)
|
||||
# In following EXPLAIN the access method should be ref, #rows~=250
|
||||
# (and not 2) when we are not using rowid-ordered scans
|
||||
explain select * from t2 where a=1000 and b<11;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ref a a 5 const 503 Using index condition
|
||||
1 SIMPLE t2 range a a 10 NULL 253 Using index condition; Rowid-ordered scan
|
||||
drop table t1, t2;
|
||||
CREATE TABLE t1( a INT, b INT, KEY( a, b ) );
|
||||
CREATE TABLE t2( a INT, b INT, KEY( a, b ) );
|
||||
@ -2566,7 +2565,7 @@ EXPLAIN
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"rows": 3,
|
||||
"filtered": 60,
|
||||
"filtered": 100,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((3,3)),<cache>((7,7)),<cache>((2,2)))",
|
||||
"mrr_type": "Rowid-ordered scan"
|
||||
@ -2645,7 +2644,7 @@ EXPLAIN
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"rows": 8,
|
||||
"filtered": 14.42307663,
|
||||
"filtered": 100,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((3,3)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1",
|
||||
"mrr_type": "Rowid-ordered scan"
|
||||
@ -2670,22 +2669,22 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuuw 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
7 7 xxxyy 7 7 h
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
3 2 uuuw 3 3 i
|
||||
3 2 uuua 3 3 i
|
||||
3 3 zzzz 3 3 i
|
||||
3 3 zyxw 3 3 i
|
||||
3 3 zzza 3 3 i
|
||||
3 3 zyxa 3 3 i
|
||||
7 8 xxxxx 7 7 h
|
||||
prepare stmt from "select * from t1,t2
|
||||
where a = d and (a,e) in ((3,3),(7,7),(8,8)) and length(f) = 1";
|
||||
execute stmt;
|
||||
@ -2749,7 +2748,7 @@ EXPLAIN
|
||||
"key_length": "5",
|
||||
"used_key_parts": ["d"],
|
||||
"rows": 7,
|
||||
"filtered": 14.28571415,
|
||||
"filtered": 100,
|
||||
"index_condition": "t2.d is not null",
|
||||
"attached_condition": "(t2.d,t2.e) in (<cache>((4,4)),<cache>((7,7)),<cache>((8,8))) and octet_length(t2.f) = 1",
|
||||
"mrr_type": "Rowid-ordered scan"
|
||||
@ -2774,14 +2773,14 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((4,4),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
alter table t2 drop index idx1, drop index idx2, add index idx3(d,e);
|
||||
# join order: (t2,t1) with ref access of t1
|
||||
# range access to t2 by 2-component keys for index idx3
|
||||
@ -2887,22 +2886,22 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((4,d+1),(7,d+1),(8,d+1)) and length(f) = 1;
|
||||
a b c d e f
|
||||
4 5 ww 4 5 a
|
||||
7 8 xxxxx 7 8 b
|
||||
4 3 zyx 4 5 a
|
||||
7 7 xxxyy 7 8 b
|
||||
4 5 wa 4 5 a
|
||||
7 8 xxxxa 7 8 b
|
||||
4 3 zya 4 5 a
|
||||
7 7 xxxya 7 8 b
|
||||
4 5 ww 4 5 a
|
||||
7 8 xxxxx 7 8 b
|
||||
4 3 zyx 4 5 a
|
||||
7 7 xxxyy 7 8 b
|
||||
4 5 wa 4 5 a
|
||||
7 8 xxxxa 7 8 b
|
||||
4 3 zya 4 5 a
|
||||
4 3 zyx 4 5 a
|
||||
4 3 zyx 4 5 a
|
||||
4 5 wa 4 5 a
|
||||
4 5 wa 4 5 a
|
||||
4 5 ww 4 5 a
|
||||
4 5 ww 4 5 a
|
||||
7 7 xxxya 7 8 b
|
||||
7 7 xxxya 7 8 b
|
||||
7 7 xxxyy 7 8 b
|
||||
7 7 xxxyy 7 8 b
|
||||
7 8 xxxxa 7 8 b
|
||||
7 8 xxxxa 7 8 b
|
||||
7 8 xxxxx 7 8 b
|
||||
7 8 xxxxx 7 8 b
|
||||
# join order: (t1,t2) with ref access of t2
|
||||
# no range access
|
||||
explain select * from t1,t2
|
||||
@ -2947,14 +2946,14 @@ EXPLAIN
|
||||
select * from t1,t2
|
||||
where a = d and (a,e) in ((e,d+1),(7,7),(8,8)) and length(f) = 1;
|
||||
a b c d e f
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 7 xxxyy 7 7 h
|
||||
7 8 xxxxa 7 7 h
|
||||
7 7 xxxya 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
7 8 xxxxx 7 7 h
|
||||
# join order: (t1,t2) with ref access of t2
|
||||
# range access to t1 by 1-component keys for index idx
|
||||
explain select * from t1,t2
|
||||
|
@ -13,18 +13,13 @@ set @tmp_21958=@@optimizer_trace;
|
||||
set optimizer_trace=1;
|
||||
explain select * from t2 where key1 in (1,2,3) and pk not in (1,2,3);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 range PRIMARY,key1 key1 5 NULL 3 Using index condition
|
||||
1 SIMPLE t2 ALL PRIMARY,key1 NULL NULL NULL 5 Using where
|
||||
# This should show only ranges in form "(1) <= (key1) <= (1)"
|
||||
# ranges over "pk" should not be constructed.
|
||||
select json_detailed(JSON_EXTRACT(trace, '$**.ranges'))
|
||||
from information_schema.optimizer_trace;
|
||||
json_detailed(JSON_EXTRACT(trace, '$**.ranges'))
|
||||
[
|
||||
[
|
||||
"(1) <= (key1) <= (1)",
|
||||
"(2) <= (key1) <= (2)",
|
||||
"(3) <= (key1) <= (3)"
|
||||
],
|
||||
[
|
||||
"(1) <= (key1) <= (1)",
|
||||
"(2) <= (key1) <= (2)",
|
||||
@ -225,9 +220,10 @@ user_id int(10) unsigned NOT NULL DEFAULT 0,
|
||||
PRIMARY KEY (notification_type_id,item_id,item_parent_id,user_id)
|
||||
);
|
||||
insert into t1 values (1,1,1,1), (2,2,2,2), (3,3,3,3);
|
||||
insert into t1 select seq,seq,seq,seq from seq_10_to_30;
|
||||
# Run crashing query
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 2 NULL 3 Using where
|
||||
1 SIMPLE t1 range PRIMARY PRIMARY 2 NULL 5 Using where
|
||||
drop table t1;
|
||||
#
|
||||
# MDEV-25069: Assertion `root->weight >= ...' failed in SEL_ARG::tree_delete #2
|
||||
|
@ -122,6 +122,7 @@ CREATE TABLE t1 (
|
||||
PRIMARY KEY (notification_type_id,item_id,item_parent_id,user_id)
|
||||
);
|
||||
insert into t1 values (1,1,1,1), (2,2,2,2), (3,3,3,3);
|
||||
insert into t1 select seq,seq,seq,seq from seq_10_to_30;
|
||||
|
||||
let $consts=`select group_concat(concat("'",seq,"'")) from seq_1_to_4642`;
|
||||
|
||||
|
@ -333,7 +333,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
EXPLAIN
|
||||
SELECT * FROM City WHERE (ID < 600) OR (ID BETWEEN 900 AND 1500);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City ALL PRIMARY NULL NULL NULL 4079 Using where
|
||||
1 SIMPLE City range PRIMARY PRIMARY 4 NULL 1200 Using index condition
|
||||
EXPLAIN
|
||||
SELECT * FROM City WHERE Country > 'A' AND Country < 'ARG';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -1077,7 +1077,7 @@ EXPLAIN SELECT Name, Country, Population FROM City WHERE
|
||||
(Name='Samara' AND Country='RUS') OR
|
||||
(Name='Seattle' AND Country='USA');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge Country,CountryPopulation,CountryName,CityName CountryName,CityName 38,35 NULL 28 Using sort_union(CountryName,CityName); Using where
|
||||
1 SIMPLE City range Country,CountryPopulation,CountryName,CityName CountryName 38 NULL 28 Using index condition
|
||||
SELECT Name, Country, Population FROM City WHERE
|
||||
(Name='Manila' AND Country='PHL') OR
|
||||
(Name='Addis Abeba' AND Country='ETH') OR
|
||||
|
@ -365,7 +365,7 @@ WHERE ((ID < 800) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
|
||||
OR ((ID BETWEEN 900 AND 1500) AND
|
||||
(Name LIKE 'Pa%' OR (Population > 103000 AND Population < 105000)));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country,Name Name,Country,PRIMARY 39,3,4 NULL 683 Using sort_union(Name,Country,PRIMARY); Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country,Name Name,Country,Population 39,3,4 NULL 212 Using sort_union(Name,Country,Population); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ((ID < 200) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
|
||||
@ -620,7 +620,7 @@ WHERE ((Population > 101000 AND Population < 102000) AND
|
||||
((ID BETWEEN 3400 AND 3800) AND
|
||||
(Country < 'AGO' OR Name LIKE 'Pa%'));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country,Name Population,PRIMARY 4,4 NULL 440 Using sort_union(Population,PRIMARY); Using where
|
||||
1 SIMPLE City index_merge PRIMARY,Population,Country,Name Country,Name,Population 3,39,4 NULL 115 Using sort_union(Country,Name,Population); Using where
|
||||
EXPLAIN
|
||||
SELECT * FROM City
|
||||
WHERE ((Population > 101000 AND Population < 110000) AND
|
||||
@ -1804,7 +1804,7 @@ SELECT * FROM t1
|
||||
WHERE t1.a>300 AND t1.c!=0 AND t1.b>=350 AND t1.b<=400 AND
|
||||
(t1.c=0 OR t1.a=500);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range PRIMARY,idx idx 5 NULL 2 Using where; Using index
|
||||
1 SIMPLE t1 range PRIMARY,idx PRIMARY 4 NULL 1 Using where
|
||||
SELECT * FROM t1
|
||||
WHERE t1.a>300 AND t1.c!=0 AND t1.b>=350 AND t1.b<=400 AND
|
||||
(t1.c=0 OR t1.a=500);
|
||||
|
@ -242,7 +242,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"rows": 509,
|
||||
"filtered": 11.69025803,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
@ -254,7 +254,7 @@ set statement optimizer_switch='rowid_filter=off' for ANALYZE SELECT l_orderkey,
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range i_l_shipdate,i_l_quantity i_l_shipdate 4 NULL 509 510.00 11.69 11.76 Using index condition; Using where
|
||||
1 SIMPLE lineitem range i_l_shipdate,i_l_quantity i_l_shipdate 4 NULL 509 510.00 100.00 11.76 Using index condition; Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT l_orderkey, l_linenumber, l_shipdate, l_quantity FROM lineitem
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45;
|
||||
@ -281,7 +281,7 @@ ANALYZE
|
||||
"r_rows": 510,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 11.69025803,
|
||||
"filtered": 100,
|
||||
"r_filtered": 11.76470588,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
@ -359,8 +359,8 @@ FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND
|
||||
o_totalprice between 200000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 NULL 98 Using index condition
|
||||
1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (5%) Using where; Using rowid filter
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 69 Using index condition
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (2%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND
|
||||
@ -372,42 +372,42 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"rows": 69,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 200000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"rows": 98,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-01-31'"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_o_totalprice",
|
||||
"used_key_parts": ["o_totalprice"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 69,
|
||||
"selectivity_pct": 4.6
|
||||
"rows": 98,
|
||||
"selectivity_pct": 1.631973356
|
||||
},
|
||||
"rows": 1,
|
||||
"filtered": 4.599999905,
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 230000"
|
||||
"rows": 4,
|
||||
"filtered": 1.631973386,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-01-31'"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -418,8 +418,8 @@ FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND
|
||||
o_totalprice between 200000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 NULL 98 98.00 100.00 100.00 Using index condition
|
||||
1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (5%) 0.11 (10%) 4.60 100.00 Using where; Using rowid filter
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 69 71.00 100.00 100.00 Using index condition
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (2%) 0.15 (2%) 1.63 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND
|
||||
@ -436,57 +436,57 @@ ANALYZE
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"r_loops": 1,
|
||||
"rows": 69,
|
||||
"r_rows": 71,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 200000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"r_loops": 1,
|
||||
"rows": 98,
|
||||
"r_rows": 98,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-01-31'"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_o_totalprice",
|
||||
"used_key_parts": ["o_totalprice"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 69,
|
||||
"selectivity_pct": 4.6,
|
||||
"r_rows": 71,
|
||||
"r_lookups": 96,
|
||||
"r_selectivity_pct": 10.41666667,
|
||||
"rows": 98,
|
||||
"selectivity_pct": 1.631973356,
|
||||
"r_rows": 98,
|
||||
"r_lookups": 476,
|
||||
"r_selectivity_pct": 2.31092437,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 98,
|
||||
"rows": 1,
|
||||
"r_rows": 0.112244898,
|
||||
"r_loops": 71,
|
||||
"rows": 4,
|
||||
"r_rows": 0.154929577,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 4.599999905,
|
||||
"filtered": 1.631973386,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 230000"
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-01-31'"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -647,8 +647,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 509 (12%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (9%) Using where; Using rowid filter
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 139 Using index condition
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -661,8 +661,21 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"rows": 139,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -670,43 +683,21 @@ EXPLAIN
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_quantity",
|
||||
"used_key_parts": ["l_quantity"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 702,
|
||||
"selectivity_pct": 11.69025812
|
||||
"rows": 509,
|
||||
"selectivity_pct": 8.476269775
|
||||
},
|
||||
"rows": 509,
|
||||
"filtered": 11.69025803,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_o_totalprice",
|
||||
"used_key_parts": ["o_totalprice"]
|
||||
},
|
||||
"rows": 139,
|
||||
"selectivity_pct": 9.266666667
|
||||
},
|
||||
"rows": 1,
|
||||
"filtered": 9.266666412,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"rows": 4,
|
||||
"filtered": 0.990897834,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -718,8 +709,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 509 (12%) 60.00 (11%) 11.69 100.00 Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (9%) 0.27 (25%) 9.27 100.00 Using where; Using rowid filter
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 139 144.00 100.00 100.00 Using index condition
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) 0.54 (8%) 0.99 20.51 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -737,8 +728,26 @@ ANALYZE
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"r_loops": 1,
|
||||
"rows": 139,
|
||||
"r_rows": 144,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -746,63 +755,31 @@ ANALYZE
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_quantity",
|
||||
"used_key_parts": ["l_quantity"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 702,
|
||||
"selectivity_pct": 11.69025812,
|
||||
"r_rows": 605,
|
||||
"r_lookups": 510,
|
||||
"r_selectivity_pct": 11.76470588,
|
||||
"rows": 509,
|
||||
"selectivity_pct": 8.476269775,
|
||||
"r_rows": 510,
|
||||
"r_lookups": 954,
|
||||
"r_selectivity_pct": 8.176100629,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 509,
|
||||
"r_rows": 60,
|
||||
"r_loops": 144,
|
||||
"rows": 4,
|
||||
"r_rows": 0.541666667,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 11.69025803,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_o_totalprice",
|
||||
"used_key_parts": ["o_totalprice"]
|
||||
},
|
||||
"rows": 139,
|
||||
"selectivity_pct": 9.266666667,
|
||||
"r_rows": 144,
|
||||
"r_lookups": 59,
|
||||
"r_selectivity_pct": 25.42372881,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 60,
|
||||
"rows": 1,
|
||||
"r_rows": 0.266666667,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 9.266666412,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"filtered": 0.990897834,
|
||||
"r_filtered": 20.51282051,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -836,8 +813,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate 4 NULL 509 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 139 Using index condition
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -850,8 +827,21 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"rows": 139,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -859,27 +849,13 @@ EXPLAIN
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"rows": 509,
|
||||
"filtered": 11.69025803,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"rows": 1,
|
||||
"filtered": 9.266666412,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rows": 4,
|
||||
"filtered": 0.990897834,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -891,8 +867,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate 4 NULL 509 510.00 11.69 11.76 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 9.27 26.67 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 139 144.00 100.00 100.00 Using index condition
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 6.62 0.99 1.68 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -910,8 +886,26 @@ ANALYZE
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"r_loops": 1,
|
||||
"rows": 139,
|
||||
"r_rows": 144,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -919,37 +913,18 @@ ANALYZE
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"r_loops": 1,
|
||||
"rows": 509,
|
||||
"r_rows": 510,
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"r_loops": 144,
|
||||
"rows": 4,
|
||||
"r_rows": 6.625,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 11.69025803,
|
||||
"r_filtered": 11.76470588,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"r_loops": 60,
|
||||
"rows": 1,
|
||||
"r_rows": 1,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 9.266666412,
|
||||
"r_filtered": 26.66666667,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"filtered": 0.990897834,
|
||||
"r_filtered": 1.677148847,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -977,13 +952,21 @@ o_orderkey l_linenumber l_shipdate l_quantity o_totalprice
|
||||
5829 5 1997-01-31 49 183734.56
|
||||
5895 2 1997-04-27 47 201419.83
|
||||
5895 3 1997-03-15 49 201419.83
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN SELECT STRAIGHT_JOIN o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM lineitem JOIN orders ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 509 (12%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (9%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
o_totalprice between 200000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 69 Using index condition
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -1020,6 +1003,14 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 509,
|
||||
"selectivity_pct": 8.476269775
|
||||
},
|
||||
"rows": 4,
|
||||
"filtered": 8.476269722,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'"
|
||||
@ -1034,7 +1025,7 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
o_totalprice between 200000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 69 71.00 100.00 100.00 Using index condition
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 6.70 8.48 7.77 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) 0.52 (7%) 8.48 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -1081,13 +1072,26 @@ ANALYZE
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 509,
|
||||
"selectivity_pct": 8.476269775,
|
||||
"r_rows": 510,
|
||||
"r_lookups": 476,
|
||||
"r_selectivity_pct": 7.773109244,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 71,
|
||||
"rows": 4,
|
||||
"r_rows": 6.704225352,
|
||||
"r_rows": 0.521126761,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 8.476269722,
|
||||
"r_filtered": 7.773109244,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'"
|
||||
}
|
||||
}
|
||||
@ -1337,7 +1341,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_receiptDATE"],
|
||||
"rows": 18,
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
}
|
||||
@ -1366,7 +1370,7 @@ l_shipdate BETWEEN '1996-10-01' AND '1996-10-10' AND
|
||||
l_receiptdate BETWEEN '1996-10-05' AND '1996-10-10' AND
|
||||
o_totalprice BETWEEN 200000 AND 250000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 5.56 38.89 Using index condition; Using where
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 100.00 38.89 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 7.47 14.29 Using where
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT l_shipdate, l_receiptdate, o_totalprice
|
||||
FROM orders, lineitem
|
||||
@ -1403,7 +1407,7 @@ ANALYZE
|
||||
"r_rows": 18,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"r_filtered": 38.88888889,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
@ -1474,7 +1478,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_receiptDATE"],
|
||||
"rows": 18,
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
}
|
||||
@ -1503,7 +1507,7 @@ l_shipdate BETWEEN '1996-10-01' AND '1996-10-10' AND
|
||||
l_receiptdate BETWEEN '1996-10-05' AND '1996-10-10' AND
|
||||
o_totalprice BETWEEN 200000 AND 250000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 5.56 38.89 Using index condition; Using where
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 100.00 38.89 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 7.47 14.29 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT l_shipdate, l_receiptdate, o_totalprice
|
||||
FROM orders, lineitem
|
||||
@ -1540,7 +1544,7 @@ ANALYZE
|
||||
"r_rows": 18,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"r_filtered": 38.88888889,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
@ -1591,7 +1595,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1612,7 +1616,7 @@ EXPLAIN
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totaldiscount"],
|
||||
"rows": 39,
|
||||
"filtered": 3.200000048,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
}
|
||||
@ -1631,6 +1635,14 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045
|
||||
},
|
||||
"rows": 4,
|
||||
"filtered": 3.047460556,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
@ -1646,8 +1658,8 @@ o_totaldiscount BETWEEN 18000 AND 20000 AND
|
||||
o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 41.00 3.20 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 6.00 3.05 66.67 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 41.00 100.00 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) 4.00 (66%) 3.05 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1677,7 +1689,7 @@ ANALYZE
|
||||
"r_rows": 41,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.200000048,
|
||||
"filtered": 100,
|
||||
"r_filtered": 2.43902439,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
@ -1697,13 +1709,26 @@ ANALYZE
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045,
|
||||
"r_rows": 183,
|
||||
"r_lookups": 6,
|
||||
"r_selectivity_pct": 66.66666667,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 4,
|
||||
"r_rows": 6,
|
||||
"r_rows": 4,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.047460556,
|
||||
"r_filtered": 66.66666667,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
}
|
||||
}
|
||||
@ -1750,7 +1775,7 @@ EXPLAIN
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totaldiscount"],
|
||||
"rows": 39,
|
||||
"filtered": 3.200000048,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
}
|
||||
@ -1784,7 +1809,7 @@ o_totaldiscount BETWEEN 18000 AND 20000 AND
|
||||
o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 41.00 3.20 2.44 Using index condition; Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 41.00 100.00 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 6.00 3.05 66.67 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
@ -1815,7 +1840,7 @@ ANALYZE
|
||||
"r_rows": 41,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.200000048,
|
||||
"filtered": 100,
|
||||
"r_filtered": 2.43902439,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
@ -1870,7 +1895,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM v1, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1915,6 +1940,14 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045
|
||||
},
|
||||
"rows": 4,
|
||||
"filtered": "REPLACED",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
@ -1931,7 +1964,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 39 41.00 # 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey 4 dbt3_s001.orders.o_orderkey 4 6.00 # 66.67 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) 4.00 (66%) # 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM v1, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1986,13 +2019,26 @@ ANALYZE
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045,
|
||||
"r_rows": 183,
|
||||
"r_lookups": 6,
|
||||
"r_selectivity_pct": 66.66666667,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 4,
|
||||
"r_rows": 6,
|
||||
"r_rows": 4,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": "REPLACED",
|
||||
"r_filtered": 66.66666667,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
}
|
||||
}
|
||||
@ -2778,7 +2824,7 @@ ANALYZE
|
||||
"r_rows": 44,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 8.630000114,
|
||||
"filtered": 100,
|
||||
"r_filtered": 0,
|
||||
"index_condition": "t1.nm like '3400%' or t1.nm like '3402%' or t1.nm like '3403%' or t1.nm like '3404%' or t1.nm like '3405%' or t1.nm like '3406%' or t1.nm like '3407%' or t1.nm like '3409%' or t1.nm like '3411%' or t1.nm like '3412%' or t1.nm like '3413%' or t1.nm like '3414%' or t1.nm like '3415%' or t1.nm like '3416%' or t1.nm like '3417%' or t1.nm like '3418%' or t1.nm like '3419%' or t1.nm like '3421%' or t1.nm like '3422%' or t1.nm like '3423%' or t1.nm like '3424%' or t1.nm like '3425%' or t1.nm like '3426%' or t1.nm like '3427%' or t1.nm like '3428%' or t1.nm like '3429%' or t1.nm like '3430%' or t1.nm like '3431%' or t1.nm like '3432%' or t1.nm like '3433%' or t1.nm like '3434%' or t1.nm like '3435%' or t1.nm like '3436%' or t1.nm like '3437%' or t1.nm like '3439%' or t1.nm like '3440%' or t1.nm like '3441%' or t1.nm like '3442%' or t1.nm like '3443%' or t1.nm like '3444%' or t1.nm like '3445%' or t1.nm like '3446%' or t1.nm like '3447%' or t1.nm like '3448%'",
|
||||
"attached_condition": "t1.fl2 = 0"
|
||||
@ -2831,7 +2877,7 @@ ANALYZE
|
||||
"r_rows": 0,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 8.529999733,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "t1.nm like '3400%' or t1.nm like '3402%' or t1.nm like '3403%' or t1.nm like '3404%' or t1.nm like '3405%' or t1.nm like '3406%' or t1.nm like '3407%' or t1.nm like '3409%' or t1.nm like '3411%' or t1.nm like '3412%' or t1.nm like '3413%' or t1.nm like '3414%' or t1.nm like '3415%' or t1.nm like '3416%' or t1.nm like '3417%' or t1.nm like '3418%' or t1.nm like '3419%' or t1.nm like '3421%' or t1.nm like '3422%' or t1.nm like '3423%' or t1.nm like '3424%' or t1.nm like '3425%' or t1.nm like '3426%' or t1.nm like '3427%' or t1.nm like '3428%' or t1.nm like '3429%' or t1.nm like '3430%' or t1.nm like '3431%' or t1.nm like '3432%' or t1.nm like '3433%' or t1.nm like '3434%' or t1.nm like '3435%' or t1.nm like '3436%' or t1.nm like '3437%' or t1.nm like '3439%' or t1.nm like '3440%' or t1.nm like '3441%' or t1.nm like '3442%' or t1.nm like '3443%' or t1.nm like '3444%' or t1.nm like '3445%' or t1.nm like '3446%' or t1.nm like '3447%' or t1.nm like '3448%'",
|
||||
"attached_condition": "t1.fl2 = 0"
|
||||
|
@ -115,6 +115,13 @@ eval $without_filter ANALYZE FORMAT=JSON $q3;
|
||||
--sorted_result
|
||||
eval $without_filter $q3;
|
||||
|
||||
# Check different optimization
|
||||
eval $with_filter EXPLAIN SELECT STRAIGHT_JOIN o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM lineitem JOIN orders ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
|
||||
let $q4=
|
||||
SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
|
@ -245,7 +245,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"rows": 510,
|
||||
"filtered": 10.07493782,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
@ -257,7 +257,7 @@ set statement optimizer_switch='rowid_filter=off' for ANALYZE SELECT l_orderkey,
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range i_l_shipdate,i_l_quantity i_l_shipdate 4 NULL 510 510.00 10.07 11.76 Using index condition; Using where
|
||||
1 SIMPLE lineitem range i_l_shipdate,i_l_quantity i_l_shipdate 4 NULL 510 510.00 100.00 11.76 Using index condition; Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT l_orderkey, l_linenumber, l_shipdate, l_quantity FROM lineitem
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45;
|
||||
@ -284,7 +284,7 @@ ANALYZE
|
||||
"r_rows": 510,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 10.07493782,
|
||||
"filtered": 100,
|
||||
"r_filtered": 11.76470588,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
@ -633,8 +633,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 510 (10%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 144 Using where; Using index
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -647,8 +647,22 @@ EXPLAIN
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"rows": 144,
|
||||
"filtered": 100,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000",
|
||||
"using_index": true
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -656,35 +670,21 @@ EXPLAIN
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_quantity",
|
||||
"used_key_parts": ["l_quantity"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 605,
|
||||
"selectivity_pct": 10.07493755
|
||||
"rows": 510,
|
||||
"selectivity_pct": 8.492922565
|
||||
},
|
||||
"rows": 510,
|
||||
"filtered": 10.07493782,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"rows": 1,
|
||||
"filtered": 9.600000381,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"rows": 4,
|
||||
"filtered": 0.855656624,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -696,8 +696,8 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 510 (10%) 60.00 (11%) 10.07 100.00 Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 9.60 26.67 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice i_o_totalprice 9 NULL 144 144.00 100.00 100.00 Using where; Using index
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (8%) 0.54 (8%) 0.86 20.51 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -715,8 +715,27 @@ ANALYZE
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"table_name": "orders",
|
||||
"access_type": "range",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "i_o_totalprice",
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totalprice"],
|
||||
"r_loops": 1,
|
||||
"rows": 144,
|
||||
"r_rows": 144,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000",
|
||||
"using_index": true
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "lineitem",
|
||||
"access_type": "ref",
|
||||
"possible_keys": [
|
||||
"PRIMARY",
|
||||
"i_l_shipdate",
|
||||
@ -724,50 +743,31 @@ ANALYZE
|
||||
"i_l_orderkey_quantity",
|
||||
"i_l_quantity"
|
||||
],
|
||||
"key": "i_l_shipdate",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_shipDATE"],
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_quantity",
|
||||
"used_key_parts": ["l_quantity"]
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 605,
|
||||
"selectivity_pct": 10.07493755,
|
||||
"r_rows": 605,
|
||||
"r_lookups": 510,
|
||||
"r_selectivity_pct": 11.76470588,
|
||||
"rows": 510,
|
||||
"selectivity_pct": 8.492922565,
|
||||
"r_rows": 510,
|
||||
"r_lookups": 954,
|
||||
"r_selectivity_pct": 8.176100629,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 510,
|
||||
"r_rows": 60,
|
||||
"r_loops": 144,
|
||||
"rows": 4,
|
||||
"r_rows": 0.541666667,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 10.07493782,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30'",
|
||||
"attached_condition": "lineitem.l_quantity > 45"
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "orders",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY", "i_o_totalprice"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["o_orderkey"],
|
||||
"ref": ["dbt3_s001.lineitem.l_orderkey"],
|
||||
"r_loops": 60,
|
||||
"rows": 1,
|
||||
"r_rows": 1,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 9.600000381,
|
||||
"r_filtered": 26.66666667,
|
||||
"attached_condition": "orders.o_totalprice between 180000 and 230000"
|
||||
"filtered": 0.855656624,
|
||||
"r_filtered": 20.51282051,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1997-01-01' and '1997-06-30' and lineitem.l_quantity > 45"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -942,6 +942,14 @@ o_orderkey l_linenumber l_shipdate l_quantity o_totalprice
|
||||
5829 5 1997-01-31 49 183734.56
|
||||
5895 2 1997-04-27 47 201419.83
|
||||
5895 3 1997-03-15 49 201419.83
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN SELECT STRAIGHT_JOIN o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice
|
||||
FROM lineitem JOIN orders ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
l_quantity > 45 AND
|
||||
o_totalprice between 180000 and 230000;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 510 (10%) Using index condition; Using where; Using rowid filter
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 Using where
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice
|
||||
FROM orders JOIN lineitem ON o_orderkey=l_orderkey
|
||||
WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND
|
||||
@ -1306,7 +1314,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_receiptDATE"],
|
||||
"rows": 18,
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
}
|
||||
@ -1335,7 +1343,7 @@ l_shipdate BETWEEN '1996-10-01' AND '1996-10-10' AND
|
||||
l_receiptdate BETWEEN '1996-10-05' AND '1996-10-10' AND
|
||||
o_totalprice BETWEEN 200000 AND 250000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 5.56 38.89 Using index condition; Using where
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 100.00 38.89 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 5.67 14.29 Using where
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT l_shipdate, l_receiptdate, o_totalprice
|
||||
FROM orders, lineitem
|
||||
@ -1372,7 +1380,7 @@ ANALYZE
|
||||
"r_rows": 18,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"r_filtered": 38.88888889,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
@ -1443,7 +1451,7 @@ EXPLAIN
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_receiptDATE"],
|
||||
"rows": 18,
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
}
|
||||
@ -1472,7 +1480,7 @@ l_shipdate BETWEEN '1996-10-01' AND '1996-10-10' AND
|
||||
l_receiptdate BETWEEN '1996-10-05' AND '1996-10-10' AND
|
||||
o_totalprice BETWEEN 200000 AND 250000;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 5.56 38.89 Using index condition; Using where
|
||||
1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_receiptdate,i_l_orderkey,i_l_orderkey_quantity i_l_receiptdate 4 NULL 18 18.00 100.00 38.89 Using index condition; Using where
|
||||
1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 5.67 14.29 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT l_shipdate, l_receiptdate, o_totalprice
|
||||
FROM orders, lineitem
|
||||
@ -1509,7 +1517,7 @@ ANALYZE
|
||||
"r_rows": 18,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 5.555555344,
|
||||
"filtered": 100,
|
||||
"r_filtered": 38.88888889,
|
||||
"index_condition": "lineitem.l_receiptDATE between '1996-10-05' and '1996-10-10'",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-10-10'"
|
||||
@ -1560,7 +1568,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1581,7 +1589,7 @@ EXPLAIN
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totaldiscount"],
|
||||
"rows": 41,
|
||||
"filtered": 3.333333254,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
}
|
||||
@ -1596,10 +1604,18 @@ EXPLAIN
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "PRIMARY",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045
|
||||
},
|
||||
"rows": 4,
|
||||
"filtered": 3.047460556,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
@ -1615,8 +1631,8 @@ o_totaldiscount BETWEEN 18000 AND 20000 AND
|
||||
o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 41.00 3.33 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 6.00 3.05 66.67 Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 41.00 100.00 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) 4.00 (66%) 3.05 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1646,7 +1662,7 @@ ANALYZE
|
||||
"r_rows": 41,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.333333254,
|
||||
"filtered": 100,
|
||||
"r_filtered": 2.43902439,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
@ -1662,17 +1678,30 @@ ANALYZE
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "PRIMARY",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045,
|
||||
"r_rows": 183,
|
||||
"r_lookups": 6,
|
||||
"r_selectivity_pct": 66.66666667,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 4,
|
||||
"r_rows": 6,
|
||||
"r_rows": 4,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.047460556,
|
||||
"r_filtered": 66.66666667,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
}
|
||||
}
|
||||
@ -1719,7 +1748,7 @@ EXPLAIN
|
||||
"key_length": "9",
|
||||
"used_key_parts": ["o_totaldiscount"],
|
||||
"rows": 41,
|
||||
"filtered": 3.333333254,
|
||||
"filtered": 100,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
}
|
||||
@ -1753,7 +1782,7 @@ o_totaldiscount BETWEEN 18000 AND 20000 AND
|
||||
o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 41.00 3.33 2.44 Using index condition; Using where
|
||||
1 SIMPLE orders range PRIMARY,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 41.00 100.00 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 6.00 3.05 66.67 Using where
|
||||
set statement optimizer_switch='rowid_filter=off' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM orders, lineitem
|
||||
@ -1784,7 +1813,7 @@ ANALYZE
|
||||
"r_rows": 41,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 3.333333254,
|
||||
"filtered": 100,
|
||||
"r_filtered": 2.43902439,
|
||||
"index_condition": "orders.o_totaldiscount between 18000 and 20000",
|
||||
"attached_condition": "orders.o_totalprice between 200000 and 220000"
|
||||
@ -1839,7 +1868,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM v1, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1880,10 +1909,18 @@ EXPLAIN
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "PRIMARY",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045
|
||||
},
|
||||
"rows": 4,
|
||||
"filtered": "REPLACED",
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
@ -1900,7 +1937,7 @@ o_totalprice BETWEEN 200000 AND 220000 AND
|
||||
l_shipdate BETWEEN '1996-10-01' AND '1996-12-01';
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE orders range PRIMARY,i_o_orderdate,i_o_totalprice,i_o_totaldiscount i_o_totaldiscount 9 NULL 41 41.00 # 2.44 Using index condition; Using where
|
||||
1 SIMPLE lineitem ref PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity PRIMARY 4 dbt3_s001.orders.o_orderkey 4 6.00 # 66.67 Using where
|
||||
1 SIMPLE lineitem ref|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_orderkey|i_l_shipdate 4|4 dbt3_s001.orders.o_orderkey 4 (3%) 4.00 (66%) # 100.00 Using where; Using rowid filter
|
||||
set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_totaldiscount, o_totalprice, l_shipdate
|
||||
FROM v1, lineitem
|
||||
WHERE o_orderkey=l_orderkey AND
|
||||
@ -1951,17 +1988,30 @@ ANALYZE
|
||||
"i_l_orderkey",
|
||||
"i_l_orderkey_quantity"
|
||||
],
|
||||
"key": "PRIMARY",
|
||||
"key": "i_l_orderkey",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["l_orderkey"],
|
||||
"ref": ["dbt3_s001.orders.o_orderkey"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "i_l_shipdate",
|
||||
"used_key_parts": ["l_shipDATE"]
|
||||
},
|
||||
"rows": 183,
|
||||
"selectivity_pct": 3.04746045,
|
||||
"r_rows": 183,
|
||||
"r_lookups": 6,
|
||||
"r_selectivity_pct": 66.66666667,
|
||||
"r_buffer_size": "REPLACED",
|
||||
"r_filling_time_ms": "REPLACED"
|
||||
},
|
||||
"r_loops": 1,
|
||||
"rows": 4,
|
||||
"r_rows": 6,
|
||||
"r_rows": 4,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": "REPLACED",
|
||||
"r_filtered": 66.66666667,
|
||||
"r_filtered": 100,
|
||||
"attached_condition": "lineitem.l_shipDATE between '1996-10-01' and '1996-12-01'"
|
||||
}
|
||||
}
|
||||
@ -2747,7 +2797,7 @@ ANALYZE
|
||||
"r_rows": 44,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 8.630000114,
|
||||
"filtered": 100,
|
||||
"r_filtered": 0,
|
||||
"index_condition": "t1.nm like '3400%' or t1.nm like '3402%' or t1.nm like '3403%' or t1.nm like '3404%' or t1.nm like '3405%' or t1.nm like '3406%' or t1.nm like '3407%' or t1.nm like '3409%' or t1.nm like '3411%' or t1.nm like '3412%' or t1.nm like '3413%' or t1.nm like '3414%' or t1.nm like '3415%' or t1.nm like '3416%' or t1.nm like '3417%' or t1.nm like '3418%' or t1.nm like '3419%' or t1.nm like '3421%' or t1.nm like '3422%' or t1.nm like '3423%' or t1.nm like '3424%' or t1.nm like '3425%' or t1.nm like '3426%' or t1.nm like '3427%' or t1.nm like '3428%' or t1.nm like '3429%' or t1.nm like '3430%' or t1.nm like '3431%' or t1.nm like '3432%' or t1.nm like '3433%' or t1.nm like '3434%' or t1.nm like '3435%' or t1.nm like '3436%' or t1.nm like '3437%' or t1.nm like '3439%' or t1.nm like '3440%' or t1.nm like '3441%' or t1.nm like '3442%' or t1.nm like '3443%' or t1.nm like '3444%' or t1.nm like '3445%' or t1.nm like '3446%' or t1.nm like '3447%' or t1.nm like '3448%'",
|
||||
"attached_condition": "t1.fl2 = 0"
|
||||
@ -2800,7 +2850,7 @@ ANALYZE
|
||||
"r_rows": 0,
|
||||
"r_table_time_ms": "REPLACED",
|
||||
"r_other_time_ms": "REPLACED",
|
||||
"filtered": 8.529999733,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"index_condition": "t1.nm like '3400%' or t1.nm like '3402%' or t1.nm like '3403%' or t1.nm like '3404%' or t1.nm like '3405%' or t1.nm like '3406%' or t1.nm like '3407%' or t1.nm like '3409%' or t1.nm like '3411%' or t1.nm like '3412%' or t1.nm like '3413%' or t1.nm like '3414%' or t1.nm like '3415%' or t1.nm like '3416%' or t1.nm like '3417%' or t1.nm like '3418%' or t1.nm like '3419%' or t1.nm like '3421%' or t1.nm like '3422%' or t1.nm like '3423%' or t1.nm like '3424%' or t1.nm like '3425%' or t1.nm like '3426%' or t1.nm like '3427%' or t1.nm like '3428%' or t1.nm like '3429%' or t1.nm like '3430%' or t1.nm like '3431%' or t1.nm like '3432%' or t1.nm like '3433%' or t1.nm like '3434%' or t1.nm like '3435%' or t1.nm like '3436%' or t1.nm like '3437%' or t1.nm like '3439%' or t1.nm like '3440%' or t1.nm like '3441%' or t1.nm like '3442%' or t1.nm like '3443%' or t1.nm like '3444%' or t1.nm like '3445%' or t1.nm like '3446%' or t1.nm like '3447%' or t1.nm like '3448%'",
|
||||
"attached_condition": "t1.fl2 = 0"
|
||||
@ -2854,8 +2904,8 @@ union
|
||||
( select * from t1
|
||||
where (f1 is null and f2 is null) and (f2 between 'a' and 'z' or f1 in ('a')));
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ref|filter f1,f2 f1|f1 13|13 const 1 (2%) Using index condition; Using where; Using rowid filter
|
||||
2 UNION t1 ref|filter f1,f2 f1|f1 13|13 const 1 (2%) Using index condition; Using where; Using rowid filter
|
||||
1 PRIMARY t1 index_merge f1,f2 f1,f2 13,33 NULL 1 Using intersect(f1,f2); Using where
|
||||
2 UNION t1 index_merge f1,f2 f1,f2 13,33 NULL 1 Using intersect(f1,f2); Using where
|
||||
NULL UNION RESULT <union1,2> ALL NULL NULL NULL NULL NULL
|
||||
explain format=json ( select * from t1
|
||||
where (f1 is null and f2 is null) and (f2 between 'a' and 'z' or f1 in ('a')))
|
||||
@ -2876,24 +2926,28 @@ EXPLAIN
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
"access_type": "ref",
|
||||
"access_type": "index_merge",
|
||||
"possible_keys": ["f1", "f2"],
|
||||
"key": "f1",
|
||||
"key_length": "13",
|
||||
"used_key_parts": ["f1"],
|
||||
"ref": ["const"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "f1",
|
||||
"used_key_parts": ["f1"]
|
||||
},
|
||||
"rows": 1,
|
||||
"selectivity_pct": 1.587301587
|
||||
"key_length": "13,33",
|
||||
"index_merge": {
|
||||
"intersect": [
|
||||
{
|
||||
"range": {
|
||||
"key": "f1",
|
||||
"used_key_parts": ["f1"]
|
||||
}
|
||||
},
|
||||
{
|
||||
"range": {
|
||||
"key": "f2",
|
||||
"used_key_parts": ["f2"]
|
||||
}
|
||||
}
|
||||
]
|
||||
},
|
||||
"rows": 1,
|
||||
"filtered": 1.587301612,
|
||||
"index_condition": "t1.f1 is null",
|
||||
"attached_condition": "t1.f2 is null and (t1.f2 between 'a' and 'z' or t1.f1 = 'a')"
|
||||
"filtered": 100,
|
||||
"attached_condition": "t1.f1 is null and t1.f2 is null and (t1.f2 between 'a' and 'z' or t1.f1 = 'a')"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -2907,24 +2961,28 @@ EXPLAIN
|
||||
{
|
||||
"table": {
|
||||
"table_name": "t1",
|
||||
"access_type": "ref",
|
||||
"access_type": "index_merge",
|
||||
"possible_keys": ["f1", "f2"],
|
||||
"key": "f1",
|
||||
"key_length": "13",
|
||||
"used_key_parts": ["f1"],
|
||||
"ref": ["const"],
|
||||
"rowid_filter": {
|
||||
"range": {
|
||||
"key": "f1",
|
||||
"used_key_parts": ["f1"]
|
||||
},
|
||||
"rows": 1,
|
||||
"selectivity_pct": 1.587301587
|
||||
"key_length": "13,33",
|
||||
"index_merge": {
|
||||
"intersect": [
|
||||
{
|
||||
"range": {
|
||||
"key": "f1",
|
||||
"used_key_parts": ["f1"]
|
||||
}
|
||||
},
|
||||
{
|
||||
"range": {
|
||||
"key": "f2",
|
||||
"used_key_parts": ["f2"]
|
||||
}
|
||||
}
|
||||
]
|
||||
},
|
||||
"rows": 1,
|
||||
"filtered": 1.587301612,
|
||||
"index_condition": "t1.f1 is null",
|
||||
"attached_condition": "t1.f2 is null and (t1.f2 between 'a' and 'z' or t1.f1 = 'a')"
|
||||
"filtered": 100,
|
||||
"attached_condition": "t1.f1 is null and t1.f2 is null and (t1.f2 between 'a' and 'z' or t1.f1 = 'a')"
|
||||
}
|
||||
}
|
||||
]
|
||||
@ -2988,7 +3046,7 @@ count(*)
|
||||
5
|
||||
explain extended select count(*) from t1 where a between 21 and 30 and b=2;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 ref b,a b 5 const 24 9.60 Using where
|
||||
1 SIMPLE t1 ref|filter b,a b|a 5|5 const 24 (10%) 9.60 Using where; Using rowid filter
|
||||
Warnings:
|
||||
Note 1003 select count(0) AS `count(*)` from `test`.`t1` where `test`.`t1`.`b` = 2 and `test`.`t1`.`a` between 21 and 30
|
||||
select * from t1 where a between 21 and 30 and b=2;
|
||||
@ -3441,16 +3499,16 @@ WHERE 1 = 1 AND domain = 'www.mailhost.i-dev.fr' AND
|
||||
timestamp >= DATE_ADD('2017-01-30 08:24:51', INTERVAL -1 MONTH)
|
||||
ORDER BY timestamp DESC;
|
||||
id domain registrant_name registrant_organization registrant_street1 registrant_street2 registrant_street3 registrant_street4 registrant_street5 registrant_city registrant_postal_code registrant_country registrant_email registrant_telephone administrative_name administrative_organization administrative_street1 administrative_street2 administrative_street3 administrative_street4 administrative_street5 administrative_city administrative_postal_code administrative_country administrative_email administrative_telephone technical_name technical_organization technical_street1 technical_street2 technical_street3 technical_street4 technical_street5 technical_city technical_postal_code technical_country technical_email technical_telephone json timestamp
|
||||
80551 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80579 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80594 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80609 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80594 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80579 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
80551 www.mailhost.i-dev.fr NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL 2017-01-30 10:00:56
|
||||
EXPLAIN EXTENDED SELECT * FROM t1
|
||||
WHERE 1 = 1 AND domain = 'www.mailhost.i-dev.fr' AND
|
||||
timestamp >= DATE_ADD('2017-01-30 08:24:51', INTERVAL -1 MONTH)
|
||||
ORDER BY timestamp DESC;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 ALL ixEventWhoisDomainDomain,ixEventWhoisDomainTimestamp NULL NULL NULL 60 22.22 Using where; Using filesort
|
||||
1 SIMPLE t1 range|filter ixEventWhoisDomainDomain,ixEventWhoisDomainTimestamp ixEventWhoisDomainTimestamp|ixEventWhoisDomainDomain 4|98 NULL 20 (67%) 66.67 Using where; Using rowid filter
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`id` AS `id`,`test`.`t1`.`domain` AS `domain`,`test`.`t1`.`registrant_name` AS `registrant_name`,`test`.`t1`.`registrant_organization` AS `registrant_organization`,`test`.`t1`.`registrant_street1` AS `registrant_street1`,`test`.`t1`.`registrant_street2` AS `registrant_street2`,`test`.`t1`.`registrant_street3` AS `registrant_street3`,`test`.`t1`.`registrant_street4` AS `registrant_street4`,`test`.`t1`.`registrant_street5` AS `registrant_street5`,`test`.`t1`.`registrant_city` AS `registrant_city`,`test`.`t1`.`registrant_postal_code` AS `registrant_postal_code`,`test`.`t1`.`registrant_country` AS `registrant_country`,`test`.`t1`.`registrant_email` AS `registrant_email`,`test`.`t1`.`registrant_telephone` AS `registrant_telephone`,`test`.`t1`.`administrative_name` AS `administrative_name`,`test`.`t1`.`administrative_organization` AS `administrative_organization`,`test`.`t1`.`administrative_street1` AS `administrative_street1`,`test`.`t1`.`administrative_street2` AS `administrative_street2`,`test`.`t1`.`administrative_street3` AS `administrative_street3`,`test`.`t1`.`administrative_street4` AS `administrative_street4`,`test`.`t1`.`administrative_street5` AS `administrative_street5`,`test`.`t1`.`administrative_city` AS `administrative_city`,`test`.`t1`.`administrative_postal_code` AS `administrative_postal_code`,`test`.`t1`.`administrative_country` AS `administrative_country`,`test`.`t1`.`administrative_email` AS `administrative_email`,`test`.`t1`.`administrative_telephone` AS `administrative_telephone`,`test`.`t1`.`technical_name` AS `technical_name`,`test`.`t1`.`technical_organization` AS `technical_organization`,`test`.`t1`.`technical_street1` AS `technical_street1`,`test`.`t1`.`technical_street2` AS `technical_street2`,`test`.`t1`.`technical_street3` AS `technical_street3`,`test`.`t1`.`technical_street4` AS `technical_street4`,`test`.`t1`.`technical_street5` AS `technical_street5`,`test`.`t1`.`technical_city` AS `technical_city`,`test`.`t1`.`technical_postal_code` AS `technical_postal_code`,`test`.`t1`.`technical_country` AS `technical_country`,`test`.`t1`.`technical_email` AS `technical_email`,`test`.`t1`.`technical_telephone` AS `technical_telephone`,`test`.`t1`.`json` AS `json`,`test`.`t1`.`timestamp` AS `timestamp` from `test`.`t1` where `test`.`t1`.`domain` = 'www.mailhost.i-dev.fr' and `test`.`t1`.`timestamp` >= <cache>('2017-01-30 08:24:51' + interval -1 month) order by `test`.`t1`.`timestamp` desc
|
||||
SET optimizer_switch=@save_optimizer_switch;
|
||||
@ -3497,7 +3555,7 @@ SELECT * FROM t1
|
||||
WHERE (a BETWEEN 9 AND 10 OR a IS NULL) AND (b BETWEEN 9 AND 10 OR b = 9)
|
||||
ORDER BY pk LIMIT 1;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE t1 index a,b PRIMARY 4 NULL 75 54.55 Using where
|
||||
1 SIMPLE t1 index a,b PRIMARY 4 NULL 75 100.00 Using where
|
||||
Warnings:
|
||||
Note 1003 select `test`.`t1`.`pk` AS `pk`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where (`test`.`t1`.`a` between 9 and 10 or `test`.`t1`.`a` is null) and (`test`.`t1`.`b` between 9 and 10 or `test`.`t1`.`b` = 9) order by `test`.`t1`.`pk` limit 1
|
||||
ANALYZE
|
||||
@ -3505,7 +3563,7 @@ SELECT * FROM t1
|
||||
WHERE (a BETWEEN 9 AND 10 OR a IS NULL) AND (b BETWEEN 9 AND 10 OR b = 9)
|
||||
ORDER BY pk LIMIT 1;
|
||||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
|
||||
1 SIMPLE t1 index a,b PRIMARY 4 NULL 3008 3008.00 1.36 0.00 Using where
|
||||
1 SIMPLE t1 index a,b PRIMARY 4 NULL 3008 3008.00 6.38 0.00 Using where
|
||||
DROP TABLE t1;
|
||||
SET global innodb_stats_persistent= @stats.save;
|
||||
#
|
||||
@ -4082,7 +4140,7 @@ WHERE t1.c1 NOT IN (SELECT t2.c1 FROM t2, t1 AS a1
|
||||
WHERE t2.i1 = t1.pk AND t2.i1 BETWEEN 3 AND 5);
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 60 100.00 Using where
|
||||
2 DEPENDENT SUBQUERY t2 ref c1,i1 i1 5 test.t1.pk 20 100.00 Using index condition; Using where
|
||||
2 DEPENDENT SUBQUERY t2 ref|filter c1,i1 c1|i1 3|5 func 38 (25%) 25.00 Using where; Full scan on NULL key; Using rowid filter
|
||||
2 DEPENDENT SUBQUERY a1 ALL NULL NULL NULL NULL 60 100.00 Using join buffer (flat, BNL join)
|
||||
Warnings:
|
||||
Note 1276 Field or reference 'test.t1.pk' of SELECT #2 was resolved in SELECT #1
|
||||
|
@ -3540,7 +3540,7 @@ WHERE t1.id=2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t2 const idx1 NULL NULL NULL 1
|
||||
1 SIMPLE t3 ref idx1 idx1 5 const 4
|
||||
1 SIMPLE t3 ALL idx1 NULL NULL NULL 9 Using where
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id
|
||||
WHERE t1.id=2;
|
||||
id a b c d e
|
||||
@ -3597,7 +3597,7 @@ CREATE TABLE t1(id int PRIMARY KEY, b int, e int);
|
||||
CREATE TABLE t2(i int, a int, INDEX si(i), INDEX ai(a));
|
||||
CREATE TABLE t3(a int PRIMARY KEY, c char(4), INDEX ci(c));
|
||||
INSERT INTO t1 VALUES
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,93,95), (7, 77,79),
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,39,95), (7, 77,79),
|
||||
(6,63,67), (5,55,58), (3,38,39), (8,81,89);
|
||||
INSERT INTO t2 VALUES
|
||||
(21,210), (41,410), (82,820), (83,830), (84,840),
|
||||
@ -3627,6 +3627,14 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 eq_ref|filter PRIMARY,ci PRIMARY|ci 4|5 test.t2.a 1 (30%) Using where; Using rowid filter
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 9 AND t2.i BETWEEN t1.b AND t1.e AND
|
||||
t3.a=t2.a AND t3.c IN ('bb','ee');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t2 range si si 5 NULL 13 Using index condition; Using where
|
||||
1 SIMPLE t3 eq_ref|filter PRIMARY,ci PRIMARY|ci 4|5 test.t2.a 1 (30%) Using where; Using rowid filter
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND
|
||||
t3.c IN ('bb','ee');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3717,7 +3725,7 @@ COUNT(*)
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 index_merge idx1,idx2 idx2,idx1 4,10 NULL 1 Using intersect(idx2,idx1); Using where; Using index
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null=3 IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3731,7 +3739,7 @@ CREATE UNIQUE INDEX idx1 ON t1(ID1_with_null,ID2_with_null);
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 index_merge idx1,idx2 idx2,idx1 4,10 NULL 1 Using intersect(idx2,idx1); Using where; Using index
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3744,7 +3752,7 @@ EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND
|
||||
(ID2_with_null=1 OR ID2_with_null=2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 ref|filter idx1,idx2 idx1|idx2 5|4 const 2 (1%) Using index condition; Using where; Using rowid filter
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a INT, ts TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, KEY ts(ts));
|
||||
INSERT INTO t1 VALUES (30,"2006-01-03 23:00:00"), (31,"2006-01-03 23:00:00");
|
||||
@ -3765,7 +3773,7 @@ AND t1.ts BETWEEN t2.dt1 AND t2.dt2
|
||||
AND t1.ts BETWEEN "2006-01-01" AND "2006-12-31";
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t1 range ts ts 4 NULL 2 Using index condition; Using where
|
||||
1 SIMPLE t1 ALL ts NULL NULL NULL 2 Using where
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (t1.a=t2.a) WHERE t1.a=30
|
||||
AND t1.ts BETWEEN t2.dt1 AND t2.dt2
|
||||
AND t1.ts BETWEEN "2006-01-01" AND "2006-12-31";
|
||||
@ -4031,7 +4039,7 @@ EXPLAIN SELECT COUNT(*) FROM t1 f1 INNER JOIN t1 f2
|
||||
ON ( f1.b=f2.b AND f1.a<f2.a )
|
||||
WHERE 1 AND f1.b NOT IN (100,2232,3343,51111);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE f1 range inx inx 5 NULL 7 Using where; Using index
|
||||
1 SIMPLE f1 index inx inx 10 NULL 7 Using where; Using index
|
||||
1 SIMPLE f2 ref inx inx 5 test.f1.b 1 Using where; Using index
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (c1 INT, c2 INT);
|
||||
|
@ -1532,7 +1532,6 @@ INSERT INTO t4 (companynr, companyname) VALUES (68,'company 10');
|
||||
INSERT INTO t4 (companynr, companyname) VALUES (50,'company 11');
|
||||
INSERT INTO t4 (companynr, companyname) VALUES (00,'Unknown');
|
||||
--enable_query_log
|
||||
|
||||
#
|
||||
# Test of stright join to force a full join.
|
||||
#
|
||||
@ -3140,7 +3139,7 @@ CREATE TABLE t2(i int, a int, INDEX si(i), INDEX ai(a));
|
||||
CREATE TABLE t3(a int PRIMARY KEY, c char(4), INDEX ci(c));
|
||||
|
||||
INSERT INTO t1 VALUES
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,93,95), (7, 77,79),
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,39,95), (7, 77,79),
|
||||
(6,63,67), (5,55,58), (3,38,39), (8,81,89);
|
||||
INSERT INTO t2 VALUES
|
||||
(21,210), (41,410), (82,820), (83,830), (84,840),
|
||||
@ -3162,6 +3161,11 @@ SELECT t3.a FROM t1,t2,t3
|
||||
WHERE t1.id = 8 AND t2.i BETWEEN t1.b AND t1.e AND
|
||||
t3.a=t2.a AND t3.c IN ('bb','ee') ;
|
||||
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 9 AND t2.i BETWEEN t1.b AND t1.e AND
|
||||
t3.a=t2.a AND t3.c IN ('bb','ee');
|
||||
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND
|
||||
|
@ -1391,16 +1391,16 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
delete from t2 where fld1=999999;
|
||||
explain select t2.companynr,companyname from t4 left join t2 using (companynr) where t2.companynr > 0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 1199 Using where
|
||||
1 SIMPLE t4 eq_ref PRIMARY PRIMARY 1 test.t2.companynr 1 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 12 Using where
|
||||
1 SIMPLE t2 hash_ALL NULL #hash#$hj 1 test.t4.companynr 1199 Using where; Using join buffer (flat, BNLH join)
|
||||
explain select t2.companynr,companyname from t4 left join t2 using (companynr) where t2.companynr > 0 or t2.companynr < 0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 1199 Using where
|
||||
1 SIMPLE t4 eq_ref PRIMARY PRIMARY 1 test.t2.companynr 1 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 12 Using where
|
||||
1 SIMPLE t2 hash_ALL NULL #hash#$hj 1 test.t4.companynr 1199 Using where; Using join buffer (flat, BNLH join)
|
||||
explain select t2.companynr,companyname from t4 left join t2 using (companynr) where t2.companynr > 0 and t4.companynr > 0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 1199 Using where
|
||||
1 SIMPLE t4 eq_ref PRIMARY PRIMARY 1 test.t2.companynr 1 Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 12 Using where
|
||||
1 SIMPLE t2 hash_ALL NULL #hash#$hj 1 test.t4.companynr 1199 Using where; Using join buffer (flat, BNLH join)
|
||||
explain select companynr,companyname from t4 left join t2 using (companynr) where companynr > 0;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 12 Using where
|
||||
@ -3551,7 +3551,7 @@ WHERE t1.id=2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t2 const idx1 NULL NULL NULL 1
|
||||
1 SIMPLE t3 ref idx1 idx1 5 const 4
|
||||
1 SIMPLE t3 ALL idx1 NULL NULL NULL 9 Using where
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id
|
||||
WHERE t1.id=2;
|
||||
id a b c d e
|
||||
@ -3608,7 +3608,7 @@ CREATE TABLE t1(id int PRIMARY KEY, b int, e int);
|
||||
CREATE TABLE t2(i int, a int, INDEX si(i), INDEX ai(a));
|
||||
CREATE TABLE t3(a int PRIMARY KEY, c char(4), INDEX ci(c));
|
||||
INSERT INTO t1 VALUES
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,93,95), (7, 77,79),
|
||||
(1,10,19), (2,20,22), (4,41,42), (9,39,95), (7, 77,79),
|
||||
(6,63,67), (5,55,58), (3,38,39), (8,81,89);
|
||||
INSERT INTO t2 VALUES
|
||||
(21,210), (41,410), (82,820), (83,830), (84,840),
|
||||
@ -3638,6 +3638,14 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 eq_ref|filter PRIMARY,ci PRIMARY|ci 4|5 test.t2.a 1 (30%) Using where; Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan; Using rowid filter
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 9 AND t2.i BETWEEN t1.b AND t1.e AND
|
||||
t3.a=t2.a AND t3.c IN ('bb','ee');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t3 range PRIMARY,ci ci 5 NULL 6 Using index condition; Rowid-ordered scan
|
||||
1 SIMPLE t2 hash_range si #hash#$hj:si 5:5 test.t3.a 13 Using where; Rowid-ordered scan; Using join buffer (flat, BNLH join)
|
||||
EXPLAIN
|
||||
SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3
|
||||
WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND
|
||||
t3.c IN ('bb','ee');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3728,7 +3736,7 @@ COUNT(*)
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 index_merge idx1,idx2 idx2,idx1 4,10 NULL 1 Using intersect(idx2,idx1); Using where; Using index
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null=3 IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3742,7 +3750,7 @@ CREATE UNIQUE INDEX idx1 ON t1(ID1_with_null,ID2_with_null);
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 index_merge idx1,idx2 idx2,idx1 4,10 NULL 1 Using intersect(idx2,idx1); Using where; Using index
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
@ -3755,7 +3763,7 @@ EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND
|
||||
(ID2_with_null=1 OR ID2_with_null=2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 2 Using where
|
||||
1 SIMPLE t1 ref|filter idx1,idx2 idx1|idx2 5|4 const 2 (1%) Using index condition; Using where; Using rowid filter
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a INT, ts TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, KEY ts(ts));
|
||||
INSERT INTO t1 VALUES (30,"2006-01-03 23:00:00"), (31,"2006-01-03 23:00:00");
|
||||
@ -3776,7 +3784,7 @@ AND t1.ts BETWEEN t2.dt1 AND t2.dt2
|
||||
AND t1.ts BETWEEN "2006-01-01" AND "2006-12-31";
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 const PRIMARY PRIMARY 4 const 1
|
||||
1 SIMPLE t1 range ts ts 4 NULL 2 Using index condition; Using where; Rowid-ordered scan
|
||||
1 SIMPLE t1 ALL ts NULL NULL NULL 2 Using where
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (t1.a=t2.a) WHERE t1.a=30
|
||||
AND t1.ts BETWEEN t2.dt1 AND t2.dt2
|
||||
AND t1.ts BETWEEN "2006-01-01" AND "2006-12-31";
|
||||
@ -4042,7 +4050,7 @@ EXPLAIN SELECT COUNT(*) FROM t1 f1 INNER JOIN t1 f2
|
||||
ON ( f1.b=f2.b AND f1.a<f2.a )
|
||||
WHERE 1 AND f1.b NOT IN (100,2232,3343,51111);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE f1 range inx inx 5 NULL 7 Using where; Using index
|
||||
1 SIMPLE f1 index inx inx 10 NULL 7 Using where; Using index
|
||||
1 SIMPLE f2 ref inx inx 5 test.f1.b 1 Using where; Using index
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (c1 INT, c2 INT);
|
||||
|
Some files were not shown because too many files have changed in this diff Show More
Reference in New Issue
Block a user