From 6348e63f62de2c71e193b111512a6777a75f3bfd Mon Sep 17 00:00:00 2001 From: "bell@sanja.is.com.ua" <> Date: Mon, 7 Jul 2003 18:40:19 +0300 Subject: [PATCH] Optimisation if simple IN subselect with primary index (SCRUM) (part of WL#818) --- mysql-test/r/subselect.result | 10 ++++- mysql-test/t/subselect.test | 2 + sql/item_subselect.cc | 82 +++++++++++++++++++++++++++++++++-- sql/item_subselect.h | 43 ++++++++++++++++++ sql/sql_lex.h | 2 +- sql/sql_select.cc | 43 +++++++++++++++++- sql/sql_select.h | 5 ++- 7 files changed, 177 insertions(+), 10 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index c9238c052a7..a596987e3ed 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -1226,7 +1226,15 @@ a explain select * from t2 where t2.a in (select a from t1); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t2 index NULL PRIMARY 4 NULL 4 Using where; Using index -2 DEPENDENT SUBQUERY t1 eq_ref PRIMARY PRIMARY 4 func 1 Using where; Using index +2 DEPENDENT SUBQUERY t1 simple_in PRIMARY PRIMARY 4 func 1 Using index +select * from t2 where t2.a in (select a from t1 where t1.b <> 30); +a +2 +4 +explain select * from t2 where t2.a in (select a from t1 where t1.b <> 30); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 index NULL PRIMARY 4 NULL 4 Using where; Using index +2 DEPENDENT SUBQUERY t1 simple_in PRIMARY PRIMARY 4 func 1 Using index; Using where select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a); a 2 diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index e360f2bbd60..a2cab4672c0 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -819,6 +819,8 @@ insert into t2 values (2), (3), (4), (5); insert into t3 values (10,3), (20,4), (30,5); select * from t2 where t2.a in (select a from t1); explain select * from t2 where t2.a in (select a from t1); +select * from t2 where t2.a in (select a from t1 where t1.b <> 30); +explain select * from t2 where t2.a in (select a from t1 where t1.b <> 30); select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a); explain select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a); drop table t1, t2, t3; diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index d295e5c8261..e3f7d157ecd 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -36,7 +36,7 @@ inline Item * and_items(Item* cond, Item *item) Item_subselect::Item_subselect(): Item_result_field(), engine_owner(1), value_assigned(0), substitution(0), - have_to_be_excluded(0) + have_to_be_excluded(0), engine_changed(0) { reset(); /* @@ -117,16 +117,22 @@ bool Item_subselect::fix_fields(THD *thd_param, TABLE_LIST *tables, Item **ref) bool Item_subselect::exec() { + int res; MEM_ROOT *old_root= my_pthread_getspecific_ptr(MEM_ROOT*, THR_MALLOC); if (&thd->mem_root != old_root) { my_pthread_setspecific_ptr(THR_MALLOC, &thd->mem_root); - int res= engine->exec(); + res= engine->exec(); my_pthread_setspecific_ptr(THR_MALLOC, old_root); - return (res); } else - return engine->exec(); + res= engine->exec(); + if (engine_changed) + { + engine_changed= 0; + return exec(); + } + return (res); } Item::Type Item_subselect::type() const @@ -795,6 +801,13 @@ int subselect_union_engine::prepare() return unit->prepare(thd, result, 0); } +int subselect_simplein_engine::prepare() +{ + //this never should be called + DBUG_ASSERT(0); + return 1; +} + static Item_result set_row(SELECT_LEX *select_lex, Item * item, Item_cache **row, bool *maybe_null) { @@ -873,6 +886,12 @@ void subselect_union_engine::fix_length_and_dec(Item_cache **row) } } +void subselect_simplein_engine::fix_length_and_dec(Item_cache **row) +{ + //this never should be called + DBUG_ASSERT(0); +} + int subselect_single_select_engine::exec() { DBUG_ENTER("subselect_single_select_engine::exec"); @@ -889,6 +908,10 @@ int subselect_single_select_engine::exec() join->thd->lex.current_select= save_select; DBUG_RETURN(join->error?join->error:1); } + if (item->engine_changed) + { + DBUG_RETURN(1); + } } if ((select_lex->dependent || select_lex->uncacheable) && executed) { @@ -922,6 +945,51 @@ int subselect_union_engine::exec() return res; } +int subselect_simplein_engine::exec() +{ + DBUG_ENTER("subselect_simplein_engine::exec"); + int error; + TABLE *table= tab->table; + if ((tab->ref.key_err= (*tab->ref.key_copy)->copy())) + { + table->status= STATUS_NOT_FOUND; + error= -1; + } + else + { + error= table->file->index_read(table->record[0], + tab->ref.key_buff, + tab->ref.key_length,HA_READ_KEY_EXACT); + if (error && error != HA_ERR_KEY_NOT_FOUND) + error= report_error(table, error); + else + { + error= 0; + table->null_row= 0; + if (table->status) + ((Item_in_subselect *) item)->value= 0; + else + ((Item_in_subselect *) item)->value= (!cond || cond->val_int()?1:0); + } + } + { + int tmp= 0; + if ((tmp= table->file->extra(HA_EXTRA_NO_CACHE))) + { + DBUG_PRINT("error", ("extra(HA_EXTRA_NO_CACHE) failed")); + error= 1; + } + if ((tmp= table->file->index_end())) + { + DBUG_PRINT("error", ("index_end() failed")); + error= 1; + } + if (error == 1) + table->file->print_error(tmp, MYF(0)); + } + DBUG_RETURN(error != 0) +} + uint subselect_single_select_engine::cols() { return select_lex->item_list.elements; @@ -961,3 +1029,9 @@ void subselect_union_engine::exclude() { unit->exclude_level(); } + +void subselect_simplein_engine::exclude() +{ + //this never should be called + DBUG_ASSERT(0); +} diff --git a/sql/item_subselect.h b/sql/item_subselect.h index bf165289cff..f9fd30141af 100644 --- a/sql/item_subselect.h +++ b/sql/item_subselect.h @@ -48,7 +48,12 @@ protected: bool have_to_be_excluded; public: + /* changed engine indicator */ + bool engine_changed; + enum trans_res {OK, REDUCE, ERROR}; + enum subs_type {UNKNOWN_SUBS, SINGLEROW_SUBS, + EXISTS_SUBS, IN_SUBS, ALLANY_SUBS}; Item_subselect(); Item_subselect(Item_subselect *item) @@ -59,9 +64,12 @@ public: max_columns= item->max_columns; engine= item->engine; engine_owner= 0; + engine_changed= item->engine_changed; name= item->name; } + virtual subs_type substype() { return UNKNOWN_SUBS; } + /* We need this method, because some compilers do not allow 'this' pointer in constructor initialization list, but we need pass pointer @@ -95,6 +103,12 @@ public: else str->append("-subselect-"); } + bool change_engine(subselect_engine *eng) + { + engine= eng; + engine_changed= 1; + return eng == 0; + } friend class select_subselect; friend class Item_in_optimizer; @@ -116,6 +130,9 @@ public: max_length= item->max_length; decimals= item->decimals; } + + subs_type substype() { return SINGLEROW_SUBS; } + void reset(); trans_res select_transformer(JOIN *join); void store(uint i, Item* item); @@ -152,6 +169,7 @@ public: } Item_exists_subselect(): Item_subselect() {} + subs_type substype() { return EXISTS_SUBS; } void reset() { value= 0; @@ -165,6 +183,7 @@ public: void fix_length_and_dec(); friend class select_exists_subselect; + friend class subselect_simplein_engine; }; /* IN subselect */ @@ -185,6 +204,8 @@ public: Item_in_subselect(THD *thd, Item * left_expr, st_select_lex *select_lex); Item_in_subselect(Item_in_subselect *item); Item_in_subselect(): Item_exists_subselect(), abort_on_null(0) {} + + subs_type substype() { return IN_SUBS; } void reset() { value= 0; @@ -218,6 +239,7 @@ public: Item_allany_subselect(THD *thd, Item * left_expr, compare_func_creator f, st_select_lex *select_lex); Item_allany_subselect(Item_allany_subselect *item); + subs_type substype() { return ALLANY_SUBS; } trans_res select_transformer(JOIN *join); }; @@ -288,3 +310,24 @@ public: bool uncacheable(); void exclude(); }; + +struct st_join_table; +class subselect_simplein_engine: public subselect_engine +{ + st_join_table *tab; + Item *cond; +public: + + subselect_simplein_engine(THD *thd, st_join_table *tab_arg, + Item_subselect *subs, Item *where) + :subselect_engine(thd, subs, 0), tab(tab_arg), cond(where) + {} + + int prepare(); + void fix_length_and_dec(Item_cache** row); + int exec(); + uint cols() { return 1; } + bool dependent() { return 1; } + bool uncacheable() { return 1; } + void exclude(); +}; diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 63d0ade75a2..6d47894d737 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -283,7 +283,7 @@ public: st_select_lex *return_to; /* LIMIT clause runtime counters */ ha_rows select_limit_cnt, offset_limit_cnt; - /* not NULL if union used in subselect, point to subselect item */ + /* not NULL if unit used in subselect, point to subselect item */ Item_subselect *item; /* thread handler */ THD *thd; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 78ba3027d91..f1eda3a8740 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -32,7 +32,7 @@ const char *join_type_str[]={ "UNKNOWN","system","const","eq_ref","ref", "MAYBE_REF","ALL","range","index","fulltext", - "ref_or_null" + "ref_or_null","simple_in" }; static void optimize_keyuse(JOIN *join, DYNAMIC_ARRAY *keyuse_array); @@ -723,6 +723,45 @@ JOIN::optimize() (select_lex->ftfunc_list->elements ? SELECT_NO_JOIN_CACHE : 0)); + /* + is this simple IN subquery? + */ + if (!group_list && !order && !having && + unit->item && unit->item->substype() == Item_subselect::IN_SUBS && + tables == 1 && join_tab[0].type == JT_EQ_REF && + conds && + !unit->first_select()->next_select()) + { + Item *where= 0; + bool ok= 0; + if (conds->type() == Item::FUNC_ITEM && + ((class Item_func *)this->conds)->functype() == Item_func::EQ_FUNC && + ((Item_func *)conds)->arguments()[0]->type() == Item::REF_ITEM && + ((Item_func *)conds)->arguments()[1]->type() == Item::FIELD_ITEM) + { + ok= 1; + join_tab->info= "Using index"; + } + else if (conds->type() == Item::COND_ITEM && + ((class Item_func *)this->conds)->functype() == + Item_func::COND_AND_FUNC) + { + ok= 1; + where= conds; + join_tab->info= "Using index; Using where"; + } + + if (ok) + { + join_tab[0].type= JT_SIMPLE_IN; + error= 0; + DBUG_RETURN(unit->item-> + change_engine(new subselect_simplein_engine(thd, join_tab, + unit->item, + where))); + } + } + /* Need to tell Innobase that to play it safe, it should fetch all columns of the tables: this is because MySQL may build row @@ -5337,7 +5376,7 @@ flush_cached_records(JOIN *join,JOIN_TAB *join_tab,bool skipp_last) /* Help function when we get some an error from the table handler */ -static int report_error(TABLE *table, int error) +int report_error(TABLE *table, int error) { if (error == HA_ERR_END_OF_FILE || error == HA_ERR_KEY_NOT_FOUND) { diff --git a/sql/sql_select.h b/sql/sql_select.h index a4554183312..57f60d93130 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -75,7 +75,8 @@ typedef struct st_join_cache { */ enum join_type { JT_UNKNOWN,JT_SYSTEM,JT_CONST,JT_EQ_REF,JT_REF,JT_MAYBE_REF, - JT_ALL, JT_RANGE, JT_NEXT, JT_FT, JT_REF_OR_NULL}; + JT_ALL, JT_RANGE, JT_NEXT, JT_FT, JT_REF_OR_NULL, + JT_SIMPLE_IN}; class JOIN; @@ -305,7 +306,6 @@ bool create_myisam_from_heap(THD *thd, TABLE *table, TMP_TABLE_PARAM *param, /* functions from opt_sum.cc */ int opt_sum_query(TABLE_LIST *tables, List &all_fields,COND *conds); - /* class to copying an field/item to a key struct */ class store_key :public Sql_alloc @@ -407,3 +407,4 @@ public: bool cp_buffer_from_ref(TABLE_REF *ref); bool error_if_full_join(JOIN *join); void relink_tables(SELECT_LEX *select_lex); +int report_error(TABLE *table, int error);