From 813d81c72692b1d9512064ccef193aa317a6e627 Mon Sep 17 00:00:00 2001 From: "bell@sanja.is.com.ua" <> Date: Mon, 8 Sep 2003 21:58:09 +0300 Subject: [PATCH] removing additional IN subquery condition fixed IN optimisation bug --- mysql-test/r/subselect.result | 25 ++++++++++++++++++- mysql-test/t/subselect.test | 13 ++++++++++ sql/item_subselect.cc | 23 ++++++++++-------- sql/mysql_priv.h | 2 +- sql/mysqld.cc | 2 ++ sql/sql_select.cc | 46 +++++++++++++++++++++++++++++++++-- 6 files changed, 97 insertions(+), 14 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 625fb9f9c29..650aa9b7051 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -829,7 +829,7 @@ a t1.a in (select t2.a from t2) explain SELECT t1.a, t1.a in (select t2.a from t2) FROM t1; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 index NULL PRIMARY 4 NULL 4 Using index -2 DEPENDENT SUBQUERY t2 index_in a a 5 func 2 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_in a a 5 func 2 Using index CREATE TABLE t3 (a int(11) default '0'); INSERT INTO t3 VALUES (1),(2),(3); SELECT t1.a, t1.a in (select t2.a from t2,t3 where t3.a=t2.a) FROM t1; @@ -1369,3 +1369,26 @@ select * from t1 where ('a','b')=(select 'a','b' from t1 union select 'a','b' fr s1 tttt drop table t1; +create table t1 (s1 char(5), index s1(s1)); +create table t2 (s1 char(5), index s1(s1)); +insert into t1 values ('a1'),('a2'),('a3'); +insert into t2 values ('a1'),('a2'); +select s1, s1 NOT IN (SELECT s1 FROM t2) from t1; +s1 s1 NOT IN (SELECT s1 FROM t2) +a1 0 +a2 0 +a3 1 +select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; +s1 s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') +a1 0 +a2 1 +a3 1 +explain select s1, s1 NOT IN (SELECT s1 FROM t2) from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL s1 6 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_in s1 s1 6 func 2 Using index +explain select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL s1 6 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_in s1 s1 6 func 1 Using index; Using where +drop table t1,t2; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 4b8d63b681e..adff7da453f 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -932,3 +932,16 @@ select (select 'a','b' from t1 union select 'a','b' from t1) from t1; insert into t1 values ('tttt'); select * from t1 where ('a','b')=(select 'a','b' from t1 union select 'a','b' from t1); drop table t1; + +# +# IN optimisation test results +# +create table t1 (s1 char(5), index s1(s1)); +create table t2 (s1 char(5), index s1(s1)); +insert into t1 values ('a1'),('a2'),('a3'); +insert into t2 values ('a1'),('a2'); +select s1, s1 NOT IN (SELECT s1 FROM t2) from t1; +select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; +explain select s1, s1 NOT IN (SELECT s1 FROM t2) from t1; +explain select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; +drop table t1,t2; diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 79366086a8d..773c7ddd9de 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -576,6 +576,7 @@ Item_in_subselect::single_value_transformer(JOIN *join, item= new Item_cond_or(item, new Item_func_isnull(isnull)); } + item->name= (char *)in_additional_cond; join->conds= and_items(join->conds, item); if (join->conds->fix_fields(thd, join->tables_list, &join->conds)) DBUG_RETURN(RES_ERROR); @@ -971,6 +972,7 @@ int subselect_indexin_engine::exec() { DBUG_ENTER("subselect_indexin_engine::exec"); int error; + bool null_finding= 0; TABLE *table= tab->table; ((Item_in_subselect *) item)->value= 0; @@ -1002,29 +1004,30 @@ int subselect_indexin_engine::exec() { if (!cond || cond->val_int()) { - if (check_null && *tab->null_ref_key) + if (null_finding) ((Item_in_subselect *) item)->was_null= 1; else ((Item_in_subselect *) item)->value= 1; goto finish; } + error= table->file->index_next_same(table->record[0], + tab->ref.key_buff, + tab->ref.key_length); + if (error && error != HA_ERR_END_OF_FILE) + { + error= report_error(table, error); + goto finish; + } } else { - if (!check_null || *tab->null_ref_key) + if (!check_null || null_finding) goto finish; *tab->null_ref_key= 1; + null_finding= 1; if (safe_index_read(tab)) goto finish; } - error= table->file->index_next_same(table->record[0], - tab->ref.key_buff, - tab->ref.key_length); - if (error && error != HA_ERR_KEY_NOT_FOUND) - { - error= report_error(table, error); - goto finish; - } } } } diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index ea5dc909f74..c8583c12470 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -716,7 +716,7 @@ extern const char *command_name[]; extern const char *first_keyword, *localhost, *delayed_user, *binary_keyword; extern const char **errmesg; /* Error messages */ extern const char *myisam_recover_options_str; -extern const char *in_left_expr_name; +extern const char *in_left_expr_name, *in_additional_cond; extern uchar *days_in_month; extern char language[LIBLEN],reg_ext[FN_EXTLEN]; extern char glob_hostname[FN_REFLEN], mysql_home[FN_REFLEN]; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 45c1fdc82d1..80096e5d5e6 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -320,6 +320,8 @@ const char *myisam_recover_options_str="OFF"; const char *sql_mode_str="OFF"; /* name of reference on left espression in rewritten IN subquery */ const char *in_left_expr_name= ""; +/* name of additional condition */ +const char *in_additional_cond= ""; FILE *bootstrap_file; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 5d96f6aeee1..12d39bfacb0 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -160,6 +160,7 @@ static bool init_sum_functions(Item_sum **func, Item_sum **end); static bool update_sum_func(Item_sum **func); static void select_describe(JOIN *join, bool need_tmp_table, bool need_order, bool distinct, const char *message=NullS); +static Item *remove_additional_cond(Item* conds); /* @@ -464,8 +465,10 @@ bool JOIN::test_in_subselect(Item **where) ((class Item_func *)this->conds)->functype() == Item_func::COND_AND_FUNC) { - *where= conds; - join_tab->info= "Using index; Using where"; + if ((*where= remove_additional_cond(conds))) + join_tab->info= "Using index; Using where"; + else + join_tab->info= "Using index"; return 1; } return 0; @@ -806,6 +809,12 @@ JOIN::optimize() { join_tab[0].type= JT_INDEX_IN; error= 0; + + if ((conds= remove_additional_cond(conds))) + join_tab->info= "Using index; Using where"; + else + join_tab->info= "Using index"; + DBUG_RETURN(unit->item-> change_engine(new subselect_indexin_engine(thd, join_tab, @@ -3990,6 +3999,39 @@ change_cond_ref_to_const(I_List *save_list,Item *and_father, } } +/* + Remove additional condition inserted by IN/ALL/ANY transformation + + SYNOPSIS + remove_additional_cond() + conds - condition for processing + + RETURN VALUES + new conditions +*/ + +static Item *remove_additional_cond(Item* conds) +{ + if (conds->name == in_additional_cond) + return 0; + if (conds->type() == Item::COND_ITEM) + { + Item_cond *cnd= (Item_cond*) conds; + List_iterator li(*(cnd->argument_list())); + Item *item; + while ((item= li++)) + { + if (item->name == in_additional_cond) + { + li.remove(); + if (cnd->argument_list()->elements == 1) + return cnd->argument_list()->head(); + return conds; + } + } + } + return conds; +} static void propagate_cond_constants(I_List *save_list,COND *and_level,