Commit 1e828236 authored by Yuchen Pei's avatar Yuchen Pei

MDEV-25008 Estimate outer_lookup_keys later in mysql_delete and mysql_update

This helps make better choice of materialization vs in-to-exists
parent 85c60586
......@@ -801,3 +801,42 @@ DROP FUNCTION f1;
DROP FUNCTION f2;
DROP TABLE t1;
# End of MariaDB 10.10 tests
#
# MDEV-25008: Delete query gets stuck on mariadb, same query works
# on MySQL 8.0.21
#
CREATE TABLE t1 (
id int NOT NULL PRIMARY KEY,
item_id varchar(100),
seller_name varchar(400),
variant varchar(400),
FULLTEXT KEY t1_serial_IDX (item_id,seller_name,variant)
)engine=innodb;
insert into t1 select seq,seq,seq,seq from seq_1_to_10000;
explain
DELETE FROM t1 WHERE id NOT IN
(SELECT m FROM (SELECT max(id) m FROM t1 GROUP BY item_id, seller_name, variant) AS innertable);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL # Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL #
3 DERIVED t1 ALL NULL NULL NULL NULL # Using temporary; Using filesort
explain
UPDATE t1 SET item_id="foo" WHERE id NOT IN
(SELECT m FROM (SELECT max(id) m FROM t1 GROUP BY item_id, seller_name, variant) AS innertable);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index NULL PRIMARY 4 NULL # Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL #
3 DERIVED t1 ALL NULL NULL NULL NULL # Using temporary; Using filesort
drop table t1;
create table t1 (a int primary key, b int, c int, key(b));
insert into t1 select seq, seq, seq from seq_1_to_20000;
create table t2 as select * from t1;
explain delete from t1 where b <= 2 and a not in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 range b b 5 NULL 2 Using where
2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 20000 Using where
explain delete from t1 where b <= 3 and a not in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 range b b 5 NULL 3 Using where
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 20000
drop table t1, t2;
......@@ -743,3 +743,44 @@ DROP TABLE t1;
--enable_ps2_protocol
--echo # End of MariaDB 10.10 tests
--echo #
--echo # MDEV-25008: Delete query gets stuck on mariadb, same query works
--echo # on MySQL 8.0.21
--echo #
--source include/have_innodb.inc
--source include/have_sequence.inc
# original case
CREATE TABLE t1 (
id int NOT NULL PRIMARY KEY,
item_id varchar(100),
seller_name varchar(400),
variant varchar(400),
FULLTEXT KEY t1_serial_IDX (item_id,seller_name,variant)
)engine=innodb;
insert into t1 select seq,seq,seq,seq from seq_1_to_10000;
# Masking the `rows` column as the value might vary a bit
--replace_column 9 #
explain
DELETE FROM t1 WHERE id NOT IN
(SELECT m FROM (SELECT max(id) m FROM t1 GROUP BY item_id, seller_name, variant) AS innertable);
# Masking the `rows` column as the value might vary a bit
--replace_column 9 #
explain
UPDATE t1 SET item_id="foo" WHERE id NOT IN
(SELECT m FROM (SELECT max(id) m FROM t1 GROUP BY item_id, seller_name, variant) AS innertable);
drop table t1;
# example of not full table
create table t1 (a int primary key, b int, c int, key(b));
insert into t1 select seq, seq, seq from seq_1_to_20000;
create table t2 as select * from t1;
explain delete from t1 where b <= 2 and a not in (select b from t2);
explain delete from t1 where b <= 3 and a not in (select b from t2);
drop table t1, t2;
......@@ -2663,9 +2663,7 @@ static int fill_used_fields_bitmap(PARAM *param)
In the table struct the following information is updated:
quick_keys - Which keys can be used
quick_rows - How many rows the key matches
opt_range_condition_rows - E(# rows that will satisfy the table
condition)
opt_range_condition_rows - E(# rows that will satisfy the table condition)
IMPLEMENTATION
opt_range_condition_rows value is obtained as follows:
......
......@@ -6803,15 +6803,15 @@ bool JOIN::choose_subquery_plan(table_map join_tables)
&dummy,
&outer_lookup_keys);
}
else
{
/*
TODO: outer_join can be NULL for DELETE statements.
How to compute its cost?
In case of a DELETE or UPDATE, get number of scanned rows as an
(upper bound) estimate of how many times the subquery will be
executed.
*/
else if (outer_join && outer_join->sql_cmd_dml)
outer_lookup_keys= (double) outer_join->sql_cmd_dml->get_scanned_rows();
else
outer_lookup_keys= 1;
}
/*
B. Estimate the cost and number of records of the subquery both
unmodified, and with injected IN->EXISTS predicates.
......
......@@ -329,10 +329,12 @@ class Sql_cmd_dml : public Sql_cmd
select_result *get_result() { return result; }
my_off_t get_scanned_rows() { return scanned_rows; }
protected:
Sql_cmd_dml()
: Sql_cmd(), lex(nullptr), result(nullptr),
m_empty_query(false)
m_empty_query(false), scanned_rows(0)
{}
/**
......@@ -399,6 +401,7 @@ class Sql_cmd_dml : public Sql_cmd
LEX *lex; /**< Pointer to LEX for this statement */
select_result *result; /**< Pointer to object for handling of the result */
bool m_empty_query; /**< True if query will produce no rows */
my_off_t scanned_rows; /**< Number of scanned rows */
};
......
......@@ -388,8 +388,13 @@ bool Sql_cmd_delete::delete_from_single_table(THD *thd)
thd->lex->promote_select_describe_flag_if_needed();
/* Apply the IN=>EXISTS transformation to all subqueries and optimize them. */
if (select_lex->optimize_unflattened_subqueries(false))
/*
It is too early to choose subquery optimization strategies without
an estimate of how many times the subquery will be executed so we
call optimize_unflattened_subqueries() with const_only= true, and
apply materialization / in-to-exists later.
*/
if (select_lex->optimize_unflattened_subqueries(true))
DBUG_RETURN(TRUE);
const_cond= (!conds || conds->const_item());
......@@ -517,6 +522,8 @@ bool Sql_cmd_delete::delete_from_single_table(THD *thd)
goto produce_explain_and_leave;
delete select;
if (select_lex->optimize_unflattened_subqueries(false))
DBUG_RETURN(TRUE);
free_underlaid_joins(thd, select_lex);
/*
Error was already created by quick select evaluation (check_quick()).
......@@ -556,7 +563,16 @@ bool Sql_cmd_delete::delete_from_single_table(THD *thd)
if (options & OPTION_QUICK)
(void) table->file->extra(HA_EXTRA_QUICK);
query_plan.scanned_rows= select? select->records: table->file->stats.records;
/*
Estimate the number of scanned rows and have it accessible in
JOIN::choose_subquery_plan() from the outer join through
JOIN::sql_cmd_dml
*/
scanned_rows= query_plan.scanned_rows= select ?
select->records : table->file->stats.records;
select_lex->join->sql_cmd_dml= (Sql_cmd_dml *) this;
if (select_lex->optimize_unflattened_subqueries(false))
DBUG_RETURN(TRUE);
if (order)
{
table->update_const_key_parts(conds);
......
......@@ -564,6 +564,7 @@ void JOIN::init(THD *thd_arg, List<Item> &fields_arg,
is_orig_degenerated= false;
with_ties_order_count= 0;
prepared= false;
sql_cmd_dml= NULL;
};
......@@ -33,6 +33,7 @@
#include "records.h" /* READ_RECORD */
#include "opt_range.h" /* SQL_SELECT, QUICK_SELECT_I */
#include "filesort.h"
#include "sql_delete.h"
#include "cset_narrowing.h"
......@@ -1722,6 +1723,13 @@ class JOIN :public Sql_alloc
*/
bool is_orig_degenerated;
/*
UPDATE and DELETE may have an imitation JOIN, which is not NULL,
but has NULL join_tab. In such cases we may want to access
sql_cmd_dml::scanned_rows to choose optimization strategies.
*/
Sql_cmd_dml *sql_cmd_dml;
JOIN(THD *thd_arg, List<Item> &fields_arg, ulonglong select_options_arg,
select_result *result_arg)
:fields_list(fields_arg)
......
......@@ -423,7 +423,7 @@ bool Sql_cmd_update::update_single_table(THD *thd)
switch_to_nullable_trigger_fields(*values, table);
/* Apply the IN=>EXISTS transformation to all subqueries and optimize them */
if (select_lex->optimize_unflattened_subqueries(false))
if (select_lex->optimize_unflattened_subqueries(true))
DBUG_RETURN(TRUE);
if (conds)
......@@ -481,6 +481,8 @@ bool Sql_cmd_update::update_single_table(THD *thd)
goto produce_explain_and_leave;
delete select;
if (select_lex->optimize_unflattened_subqueries(false))
DBUG_RETURN(TRUE);
free_underlaid_joins(thd, select_lex);
/*
There was an error or the error was already sent by
......@@ -533,7 +535,17 @@ bool Sql_cmd_update::update_single_table(THD *thd)
table->update_const_key_parts(conds);
order= simple_remove_const(order, conds);
query_plan.scanned_rows= select? select->records: table->file->stats.records;
/*
Estimate the number of scanned rows and have it accessible in
JOIN::choose_subquery_plan() from the outer join through
JOIN::sql_cmd_dml
*/
scanned_rows= query_plan.scanned_rows= select ?
select->records : table->file->stats.records;
select_lex->join->sql_cmd_dml= (Sql_cmd_dml *) this;
if (select_lex->optimize_unflattened_subqueries(false))
DBUG_RETURN(TRUE);
if (select && select->quick && select->quick->unique_key_range())
{
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment