From 615da8f70bd61aa0918c08a256638d90d425fe0e Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Thu, 29 Jun 2017 15:32:17 +0300 Subject: [PATCH 001/138] New structure Table Value Constructor added in grammar. TVC can be used in UNION-statement, in view and in subquery. Files where TVC is defined and its methods are stored added. Methods exec and prepare for TVC added. Tests for TVC added. --- mysql-test/t/table_value_const.test | 30 +++++++ sql/CMakeLists.txt | 1 + sql/sql_class.h | 58 +++++++++++++ sql/sql_lex.h | 4 +- sql/sql_tvc.cc | 128 ++++++++++++++++++++++++++++ sql/sql_tvc.h | 27 ++++++ sql/sql_union.cc | 78 ++++------------- sql/sql_yacc.yy | 40 ++++++++- 8 files changed, 301 insertions(+), 65 deletions(-) create mode 100644 mysql-test/t/table_value_const.test create mode 100644 sql/sql_tvc.cc create mode 100644 sql/sql_tvc.h diff --git a/mysql-test/t/table_value_const.test b/mysql-test/t/table_value_const.test new file mode 100644 index 00000000000..6d338ab0353 --- /dev/null +++ b/mysql-test/t/table_value_const.test @@ -0,0 +1,30 @@ +values (1,2); + +select 1,2 union values (1,2); + +values (1,2) union select (1,2); + +select * from t1 where (t1.a,t1.b) in (select 5,7 union values (1,2),(2,3)); + +select * from t1 where (t1.a,t1.b) in (values (1,2),(2,3) union select 5,7); + +let $drop_view= drop view v1; + +create view v1 as values (1,2); + +eval $drop_view; + +create view v1 as values (1,2) union select 3,4; + +eval $drop_view; + +create view v1 as select 1,2 union values (3,4); + +eval $drop_view; + +create view v1 as select 1,2 union values (3,4),(5,6); + +eval $drop_view; + + + diff --git a/sql/CMakeLists.txt b/sql/CMakeLists.txt index 87e41817857..10af1fcda9b 100644 --- a/sql/CMakeLists.txt +++ b/sql/CMakeLists.txt @@ -145,6 +145,7 @@ SET (SQL_SOURCE item_windowfunc.cc sql_window.cc sql_cte.cc sql_sequence.cc sql_sequence.h ha_sequence.h + sql_tvc.cc sql_tvc.h ${WSREP_SOURCES} table_cache.cc encryption.cc temporary_tables.cc ${CMAKE_CURRENT_BINARY_DIR}/sql_builtin.cc diff --git a/sql/sql_class.h b/sql/sql_class.h index 817be9d939c..609d4ad23eb 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -6034,6 +6034,64 @@ public: }; +class Type_holder: public Sql_alloc, + public Item_args, + public Type_handler_hybrid_field_type, + public Type_all_attributes, + public Type_geometry_attributes +{ + TYPELIB *m_typelib; + bool m_maybe_null; +public: + Type_holder() + :m_typelib(NULL), + m_maybe_null(false) + { } + + void set_maybe_null(bool maybe_null_arg) { m_maybe_null= maybe_null_arg; } + bool get_maybe_null() const { return m_maybe_null; } + + uint decimal_precision() const + { + /* + Type_holder is not used directly to create fields, so + its virtual decimal_precision() is never called. + We should eventually extend create_result_table() to accept + an array of Type_holders directly, without having to allocate + Item_type_holder's and put them into List. + */ + DBUG_ASSERT(0); + return 0; + } + void set_geometry_type(uint type) + { + Type_geometry_attributes::set_geometry_type(type); + } + uint uint_geometry_type() const + { + return Type_geometry_attributes::get_geometry_type(); + } + void set_typelib(TYPELIB *typelib) + { + m_typelib= typelib; + } + TYPELIB *get_typelib() const + { + return m_typelib; + } + + bool aggregate_attributes(THD *thd) + { + for (uint i= 0; i < arg_count; i++) + m_maybe_null|= args[i]->maybe_null; + return + type_handler()->Item_hybrid_func_fix_attributes(thd, + "UNION", this, this, + args, arg_count); + } +}; + + #endif /* MYSQL_SERVER */ #endif /* SQL_CLASS_INCLUDED */ diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 61c13814eeb..dbe881f2926 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -31,7 +31,7 @@ #include "sql_window.h" #include "sql_trigger.h" #include "sp.h" // enum stored_procedure_type - +#include "sql_tvc.h" /* YACC and LEX Definitions */ @@ -999,6 +999,8 @@ public: /* it is for correct printing SELECT options */ thr_lock_type lock_type; + + table_value_constr *tvc; void init_query(); void init_select(); diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc new file mode 100644 index 00000000000..323ce5eacb9 --- /dev/null +++ b/sql/sql_tvc.cc @@ -0,0 +1,128 @@ +#include "sql_list.h" +#include "sql_tvc.h" +#include "sql_class.h" + +/** + The method searches types of columns for temporary table where values from TVC will be stored +*/ + +bool join_type_handlers_for_tvc(List_iterator_fast &li, + Type_holder *holders, uint cnt) +{ + List_item *lst; + li.rewind(); + bool first= true; + + while ((lst=li++)) + { + List_iterator_fast it(*lst); + Item *item; + + if (cnt != lst->elements) + { + /*error wrong number of values*/ + return true; + } + for (uint pos= 0; (item=it++); pos++) + { + const Type_handler *item_type_handler= item->real_type_handler(); + if (first) + holders[pos].set_handler(item_type_handler); + else if (holders[pos].aggregate_for_result(item_type_handler)) + { + /*error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION*/ + return true; + } + } + first= false; + } + return false; +} + +/** + The method searches names of columns for temporary table where values from TVC will be stored +*/ + +bool get_type_attributes_for_tvc(THD *thd_arg, + List_iterator_fast &li, + Type_holder *holders, uint count) +{ + List_item *lst; + li.rewind(); + + lst= li++; + uint first_list_el_count= lst->elements; + + for (uint pos= 0; pos < first_list_el_count; pos++) + { + if (holders[pos].alloc_arguments(thd_arg, count)) + return true; + } + + List_iterator_fast it(*lst); + Item *item; + + for (uint holder_pos= 0 ; (item= it++); holder_pos++) + { + DBUG_ASSERT(item->fixed); + holders[holder_pos].add_argument(item); + } + + for (uint pos= 0; pos < first_list_el_count; pos++) + { + if (holders[pos].aggregate_attributes(thd_arg)) + return true; + } + return false; +} + +bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, select_result *tmp_result) +{ + List_iterator_fast li(lists_of_values); + + List_item *first_elem= li++; + uint cnt= first_elem->elements; + Type_holder *holders; + + if (!(holders= new (thd_arg->mem_root) + Type_holder[cnt]) || + join_type_handlers_for_tvc(li, holders, cnt) || + get_type_attributes_for_tvc(thd_arg, li, holders, cnt)) + return true; + + List_iterator_fast it(*first_elem); + Item *item; + + sl->item_list.empty(); + for (uint pos= 0; (item= it++); pos++) + { + /* Error's in 'new' will be detected after loop */ + Item_type_holder *new_holder= new (thd_arg->mem_root) + Item_type_holder(thd_arg, + &item->name, + holders[pos].type_handler(), + &holders[pos]/*Type_all_attributes*/, + holders[pos].get_maybe_null()); + new_holder->fix_fields(thd_arg, 0); + sl->item_list.push_back(new_holder); + } + + if (thd_arg->is_fatal_error) + return true; // out of memory + + result= tmp_result; + + return false; +} + +bool table_value_constr::exec() +{ + List_iterator_fast li(lists_of_values); + List_item *elem; + + while ((elem=li++)) + { + result->send_data(*elem); + } + return false; +} \ No newline at end of file diff --git a/sql/sql_tvc.h b/sql/sql_tvc.h new file mode 100644 index 00000000000..e5c3477351c --- /dev/null +++ b/sql/sql_tvc.h @@ -0,0 +1,27 @@ +#ifndef SQL_TVC_INCLUDED +#define SQL_TVC_INCLUDED +#include "sql_type.h" +#include "item.h" + +typedef List List_item; +class select_result; + +/** + @class table_value_constr + @brief Definition of a Table Value Construction(TVC) + + It contains a list of lists of values that this TVC contains. +*/ + +class table_value_constr : public Sql_alloc +{ +public: + List lists_of_values; + select_result *result; + + bool prepare(THD *thd_arg, SELECT_LEX *sl, + select_result *tmp_result); + bool exec(); +}; + +#endif /* SQL_TVC_INCLUDED */ \ No newline at end of file diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 1c2ff2b012b..c5cedf795a3 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -692,64 +692,6 @@ bool st_select_lex_unit::prepare_join(THD *thd_arg, SELECT_LEX *sl, } -class Type_holder: public Sql_alloc, - public Item_args, - public Type_handler_hybrid_field_type, - public Type_all_attributes, - public Type_geometry_attributes -{ - TYPELIB *m_typelib; - bool m_maybe_null; -public: - Type_holder() - :m_typelib(NULL), - m_maybe_null(false) - { } - - void set_maybe_null(bool maybe_null_arg) { m_maybe_null= maybe_null_arg; } - bool get_maybe_null() const { return m_maybe_null; } - - uint decimal_precision() const - { - /* - Type_holder is not used directly to create fields, so - its virtual decimal_precision() is never called. - We should eventually extend create_result_table() to accept - an array of Type_holders directly, without having to allocate - Item_type_holder's and put them into List. - */ - DBUG_ASSERT(0); - return 0; - } - void set_geometry_type(uint type) - { - Type_geometry_attributes::set_geometry_type(type); - } - uint uint_geometry_type() const - { - return Type_geometry_attributes::get_geometry_type(); - } - void set_typelib(TYPELIB *typelib) - { - m_typelib= typelib; - } - TYPELIB *get_typelib() const - { - return m_typelib; - } - - bool aggregate_attributes(THD *thd) - { - for (uint i= 0; i < arg_count; i++) - m_maybe_null|= args[i]->maybe_null; - return - type_handler()->Item_hybrid_func_fix_attributes(thd, - "UNION", this, this, - args, arg_count); - } -}; - - /** Aggregate data type handlers for the "count" leftmost UNION parts. */ @@ -978,7 +920,12 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, if (!is_union_select && !is_recursive) { - if (prepare_join(thd_arg, first_sl, tmp_result, additional_options, + if (sl->tvc) + { + if (sl->tvc->prepare(thd_arg, sl, tmp_result)) + goto err; + } + else if (prepare_join(thd_arg, first_sl, tmp_result, additional_options, is_union_select)) goto err; types= first_sl->item_list; @@ -987,8 +934,13 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, for (;sl; sl= sl->next_select(), union_part_count++) { - if (prepare_join(thd_arg, sl, tmp_result, additional_options, - is_union_select)) + if (sl->tvc) + { + if (sl->tvc->prepare(thd_arg, sl, tmp_result)) + goto err; + } + else if (prepare_join(thd_arg, sl, tmp_result, additional_options, + is_union_select)) goto err; /* @@ -1296,6 +1248,8 @@ bool st_select_lex_unit::optimize() } for (SELECT_LEX *sl= select_cursor; sl; sl= sl->next_select()) { + if (sl->tvc) + continue; thd->lex->current_select= sl; if (optimized) @@ -1411,6 +1365,8 @@ bool st_select_lex_unit::exec() if (!saved_error) { records_at_start= table->file->stats.records; + if (sl->tvc) + sl->tvc->exec(); sl->join->exec(); if (sl == union_distinct && !(with_element && with_element->is_recursive)) { diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index a0bbf39b138..d6aceeaa8a6 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1822,11 +1822,13 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %type subselect get_select_lex get_select_lex_derived + simple_table query_specification query_term_union_not_ready query_term_union_ready query_expression_body select_paren_derived + table_value_constructor %type comp_op @@ -8467,6 +8469,9 @@ select: select_init: SELECT_SYM select_options_and_item_list select_init3 + | table_value_constructor + | table_value_constructor union_list + | table_value_constructor union_order_or_limit | '(' select_paren ')' | '(' select_paren ')' union_list | '(' select_paren ')' union_order_or_limit @@ -8474,12 +8479,23 @@ select_init: union_list_part2: SELECT_SYM select_options_and_item_list select_init3_union_query_term + | table_value_constructor + | table_value_constructor union_list + | table_value_constructor union_order_or_limit | '(' select_paren_union_query_term ')' | '(' select_paren_union_query_term ')' union_list | '(' select_paren_union_query_term ')' union_order_or_limit ; select_paren: + { + Lex->current_select->set_braces(true); + } + table_value_constructor + { + DBUG_ASSERT(Lex->current_select->braces); + } + | { /* In order to correctly parse UNION's global ORDER BY we need to @@ -9443,7 +9459,7 @@ column_default_non_parenthesized_expr: if ($$ == NULL) MYSQL_YYABORT; } - | VALUES '(' simple_ident_nospvar ')' + | VALUE_SYM '(' simple_ident_nospvar ')' { $$= new (thd->mem_root) Item_insert_value(thd, Lex->current_context(), $3); @@ -16250,6 +16266,21 @@ union_option: | ALL { $$=0; } ; +simple_table: + query_specification { $$= $1; } + | table_value_constructor { $$= $1; } + ; + +table_value_constructor: + VALUES values_list + { + LEX *lex=Lex; + $$= Lex->current_select; + mysql_init_select(Lex); + $$->tvc->lists_of_values= lex->many_values; + } + ; + /* Corresponds to the SQL Standard ::= @@ -16267,12 +16298,12 @@ query_specification: ; query_term_union_not_ready: - query_specification order_or_limit opt_select_lock_type { $$= $1; } + simple_table order_or_limit opt_select_lock_type { $$= $1; } | '(' select_paren_derived ')' union_order_or_limit { $$= $2; } ; query_term_union_ready: - query_specification opt_select_lock_type { $$= $1; } + simple_table opt_select_lock_type { $$= $1; } | '(' select_paren_derived ')' { $$= $2; } ; @@ -16534,6 +16565,9 @@ view_select: */ query_expression_body_view: SELECT_SYM select_options_and_item_list select_init3_view + | table_value_constructor + | table_value_constructor union_order_or_limit + | table_value_constructor union_list_view | '(' select_paren_view ')' | '(' select_paren_view ')' union_order_or_limit | '(' select_paren_view ')' union_list_view From 7ba19ba3848894120548f33c314ac59bcc627d1c Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Fri, 30 Jun 2017 13:54:33 +0300 Subject: [PATCH 002/138] Mistakes corrected, test file corrected. --- mysql-test/t/table_value_const.test | 8 +++++++- sql/sql_lex.cc | 1 + sql/sql_tvc.h | 4 ++++ sql/sql_union.cc | 17 +++++++++++------ sql/sql_yacc.yy | 4 +++- 5 files changed, 26 insertions(+), 8 deletions(-) diff --git a/mysql-test/t/table_value_const.test b/mysql-test/t/table_value_const.test index 6d338ab0353..00cd1baad95 100644 --- a/mysql-test/t/table_value_const.test +++ b/mysql-test/t/table_value_const.test @@ -1,9 +1,15 @@ +create table t1 (a int, b int); + +insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); + values (1,2); select 1,2 union values (1,2); values (1,2) union select (1,2); +values (1,2), (3,4) union select 1,2; + select * from t1 where (t1.a,t1.b) in (select 5,7 union values (1,2),(2,3)); select * from t1 where (t1.a,t1.b) in (values (1,2),(2,3) union select 5,7); @@ -26,5 +32,5 @@ create view v1 as select 1,2 union values (3,4),(5,6); eval $drop_view; - +drop table t1; diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 4c763f50eaf..baab673011f 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -2262,6 +2262,7 @@ void st_select_lex::init_select() with_dep= 0; join= 0; lock_type= TL_READ_DEFAULT; + tvc= 0; } /* diff --git a/sql/sql_tvc.h b/sql/sql_tvc.h index e5c3477351c..007b50d81df 100644 --- a/sql/sql_tvc.h +++ b/sql/sql_tvc.h @@ -19,6 +19,10 @@ public: List lists_of_values; select_result *result; + table_value_constr(List tvc_values) : + lists_of_values(tvc_values), result(0) + { } + bool prepare(THD *thd_arg, SELECT_LEX *sl, select_result *tmp_result); bool exec(); diff --git a/sql/sql_union.cc b/sql/sql_union.cc index c5cedf795a3..52880cd4442 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -1357,17 +1357,21 @@ bool st_select_lex_unit::exec() we don't calculate found_rows() per union part. Otherwise, SQL_CALC_FOUND_ROWS should be done on all sub parts. */ - sl->join->select_options= - (select_limit_cnt == HA_POS_ERROR || sl->braces) ? - sl->options & ~OPTION_FOUND_ROWS : sl->options | found_rows_for_union; - saved_error= sl->join->optimize(); + if (!sl->tvc) + { + sl->join->select_options= + (select_limit_cnt == HA_POS_ERROR || sl->braces) ? + sl->options & ~OPTION_FOUND_ROWS : sl->options | found_rows_for_union; + saved_error= sl->join->optimize(); + } } if (!saved_error) { records_at_start= table->file->stats.records; if (sl->tvc) sl->tvc->exec(); - sl->join->exec(); + else + sl->join->exec(); if (sl == union_distinct && !(with_element && with_element->is_recursive)) { // This is UNION DISTINCT, so there should be a fake_select_lex @@ -1376,7 +1380,8 @@ bool st_select_lex_unit::exec() DBUG_RETURN(TRUE); table->no_keyread=1; } - saved_error= sl->join->error; + if (!sl->tvc) + saved_error= sl->join->error; offset_limit_cnt= (ha_rows)(sl->offset_limit ? sl->offset_limit->val_uint() : 0); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index d6aceeaa8a6..b4a0e52f693 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -67,6 +67,7 @@ #include "lex_token.h" #include "sql_lex.h" #include "sql_sequence.h" +#include "sql_tvc.h" /* this is to get the bison compilation windows warnings out */ #ifdef _MSC_VER @@ -16277,7 +16278,8 @@ table_value_constructor: LEX *lex=Lex; $$= Lex->current_select; mysql_init_select(Lex); - $$->tvc->lists_of_values= lex->many_values; + table_value_constr tvc(lex->many_values); + $$->tvc= &tvc; } ; From 9103ee3c6b73641dcda6beeaae306b5234bca1ed Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Wed, 26 Jul 2017 22:46:16 +0300 Subject: [PATCH 003/138] Queries where TVCs are used are processed successufully. TVCs can be used separately, with UNION/UNION ALL, in derived tables, in views and in common table expressions. Tests corrected. Test results added. --- mysql-test/r/table_value_constr.result | 399 +++++++++++++++++++++++++ mysql-test/t/table_value_constr.test | 244 +++++++++++++++ 2 files changed, 643 insertions(+) create mode 100644 mysql-test/r/table_value_constr.result create mode 100644 mysql-test/t/table_value_constr.test diff --git a/mysql-test/r/table_value_constr.result b/mysql-test/r/table_value_constr.result new file mode 100644 index 00000000000..dac84fc5dcb --- /dev/null +++ b/mysql-test/r/table_value_constr.result @@ -0,0 +1,399 @@ +create table t1 (a int, b int); +insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); +# just VALUES +values (1,2); +1 2 +1 2 +values (1,2), (3,4), (5.6,0); +1 2 +1.0 2 +3.0 4 +5.6 0 +values ("abc", "def"); +abc def +abc def +# UNION using VALUES structure(s) +select 1,2 union values (1,2); +1 2 +1 2 +values (1,2) union select 1,2; +1 2 +1 2 +select 1,2 union values (1,2),(3,4),(5,6),(7,8); +1 2 +1 2 +3 4 +5 6 +7 8 +select 3,7 union values (1,2),(3,4),(5,6); +3 7 +3 7 +1 2 +3 4 +5 6 +select 3,7,4 union values (1,2,5),(4,5,6); +3 7 4 +3 7 4 +1 2 5 +4 5 6 +select 1,2 union values (1,7),(3,6.5); +1 2 +1 2.0 +1 7.0 +3 6.5 +select 1,2 union values (1,2.0),(3,6); +1 2 +1 2.0 +3 6.0 +select 1.8,2 union values (1,2),(3,6); +1.8 2 +1.8 2 +1.0 2 +3.0 6 +values (1,2.4),(3,6) union select 2.8,9; +1 2.4 +1.0 2.4 +3.0 6.0 +2.8 9.0 +values (1,2),(3,4),(5,6),(7,8) union select 5,6; +1 2 +1 2 +3 4 +5 6 +7 8 +select "ab","cdf" union values ("al","zl"),("we","q"); +ab cdf +ab cdf +al zl +we q +values ("ab", "cdf") union select "ab","cdf"; +ab cdf +ab cdf +values (1,2) union values (1,2),(5,6); +1 2 +1 2 +5 6 +values (1,2) union values (3,4),(5,6); +1 2 +1 2 +3 4 +5 6 +values (1,2) union values (1,2) union values (4,5); +1 2 +1 2 +4 5 +# UNION ALL using VALUES structure +values (1,2),(3,4) union all select 5,6; +1 2 +1 2 +3 4 +5 6 +values (1,2),(3,4) union all select 1,2; +1 2 +1 2 +3 4 +1 2 +select 5,6 union all values (1,2),(3,4); +5 6 +5 6 +1 2 +3 4 +select 1,2 union all values (1,2),(3,4); +1 2 +1 2 +1 2 +3 4 +values (1,2) union all values (1,2),(5,6); +1 2 +1 2 +1 2 +5 6 +values (1,2) union all values (3,4),(5,6); +1 2 +1 2 +3 4 +5 6 +values (1,2) union all values (1,2) union all values (4,5); +1 2 +1 2 +1 2 +4 5 +values (1,2) union all values (1,2) union values (1,2); +1 2 +1 2 +values (1,2) union values (1,2) union all values (1,2); +1 2 +1 2 +1 2 +# EXCEPT using VALUES structure(s) +select 1,2 except values (3,4),(5,6); +1 2 +1 2 +select 1,2 except values (1,2),(3,4); +1 2 +values (1,2),(3,4) except select 5,6; +1 2 +1 2 +3 4 +values (1,2),(3,4) except select 1,2; +1 2 +3 4 +values (1,2),(3,4) except values (5,6); +1 2 +1 2 +3 4 +values (1,2),(3,4) except values (1,2); +1 2 +3 4 +# INTERSECT using VALUES structure(s) +select 1,2 intersect values (3,4),(5,6); +1 2 +select 1,2 intersect values (1,2),(3,4); +1 2 +1 2 +values (1,2),(3,4) intersect select 5,6; +1 2 +values (1,2),(3,4) intersect select 1,2; +1 2 +1 2 +values (1,2),(3,4) intersect values (5,6); +1 2 +values (1,2),(3,4) intersect values (1,2); +1 2 +1 2 +# combination of different structures using VALUES structures : UNION + EXCEPT +values (1,2),(3,4) except select 1,2 union values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) except values (1,2) union values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) except values (1,2) union values (3,4); +1 2 +3 4 +values (1,2),(3,4) union values (1,2) except values (1,2); +1 2 +3 4 +# combination of different structures using VALUES structures : UNION ALL + EXCEPT +values (1,2),(3,4) except select 1,2 union all values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) except values (1,2) union all values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) except values (1,2) union all values (3,4); +1 2 +3 4 +3 4 +values (1,2),(3,4) union all values (1,2) except values (1,2); +1 2 +3 4 +# combination of different structures using VALUES structures : UNION + INTERSECT +values (1,2),(3,4) intersect select 1,2 union values (1,2); +1 2 +1 2 +values (1,2),(3,4) intersect values (1,2) union values (1,2); +1 2 +1 2 +values (1,2),(3,4) intersect values (1,2) union values (3,4); +1 2 +1 2 +3 4 +values (1,2),(3,4) union values (1,2) intersect values (1,2); +1 2 +1 2 +3 4 +# combination of different structures using VALUES structures : UNION ALL + INTERSECT +values (1,2),(3,4) intersect select 1,2 union all values (1,2); +1 2 +1 2 +1 2 +values (1,2),(3,4) intersect values (1,2) union all values (1,2); +1 2 +1 2 +1 2 +values (1,2),(3,4) intersect values (1,2) union all values (3,4); +1 2 +1 2 +3 4 +values (1,2),(3,4) union all values (1,2) intersect values (1,2); +1 2 +1 2 +3 4 +1 2 +# combination of different structures using VALUES structures : UNION + UNION ALL +values (1,2),(3,4) union all select 1,2 union values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) union all values (1,2) union values (1,2); +1 2 +1 2 +3 4 +values (1,2),(3,4) union all values (1,2) union values (3,4); +1 2 +1 2 +3 4 +values (1,2),(3,4) union values (1,2) union all values (1,2); +1 2 +1 2 +3 4 +1 2 +values (1,2) union values (1,2) union all values (1,2); +1 2 +1 2 +1 2 +# CTE using VALUES structure(s) +with t2 as (values (1,2),(3,4)) select * from t2; +1 2 +1 2 +3 4 +with t2 as (select 1,2 union values (1,2)) select * from t2; +1 2 +1 2 +with t2 as (select 1,2 union values (1,2),(3,4)) select * from t2; +1 2 +1 2 +3 4 +with t2 as (values (1,2) union select 1,2) select * from t2; +1 2 +1 2 +with t2 as (values (1,2),(3,4) union select 1,2) select * from t2; +1 2 +1 2 +3 4 +with t2 as (values (5,6) union values (1,2),(3,4)) select * from t2; +5 6 +5 6 +1 2 +3 4 +with t2 as (values (1,2) union values (1,2),(3,4)) select * from t2; +1 2 +1 2 +3 4 +with t2 as (select 1,2 union all values (1,2),(3,4)) select * from t2; +1 2 +1 2 +1 2 +3 4 +with t2 as (values (1,2),(3,4) union all select 1,2) select * from t2; +1 2 +1 2 +3 4 +1 2 +with t2 as (values (1,2) union all values (1,2),(3,4)) select * from t2; +1 2 +1 2 +1 2 +3 4 +# Derived table using VALUES structure(s) +select * from (values (1,2),(3,4)) as t2; +1 2 +1 2 +3 4 +select * from (select 1,2 union values (1,2)) as t2; +1 2 +1 2 +select * from (select 1,2 union values (1,2),(3,4)) as t2; +1 2 +1 2 +3 4 +select * from (values (1,2) union select 1,2) as t2; +1 2 +1 2 +select * from (values (1,2),(3,4) union select 1,2) as t2; +1 2 +1 2 +3 4 +select * from (values (5,6) union values (1,2),(3,4)) as t2; +5 6 +5 6 +1 2 +3 4 +select * from (values (1,2) union values (1,2),(3,4)) as t2; +1 2 +1 2 +3 4 +select * from (select 1,2 union all values (1,2),(3,4)) as t2; +1 2 +1 2 +1 2 +3 4 +select * from (values (1,2),(3,4) union all select 1,2) as t2; +1 2 +1 2 +3 4 +1 2 +select * from (values (1,2) union all values (1,2),(3,4)) as t2; +1 2 +1 2 +1 2 +3 4 +# CREATE VIEW using VALUES structure(s) +create view v1 as values (1,2),(3,4); +select * from v1; +1 2 +1 2 +3 4 +drop view v1; +create view v1 as select 1,2 union values (1,2); +select * from v1; +1 2 +1 2 +drop view v1; +create view v1 as select 1,2 union values (1,2),(3,4); +select * from v1; +1 2 +1 2 +3 4 +drop view v1; +create view v1 as values (1,2) union select 1,2; +select * from v1; +1 2 +1 2 +drop view v1; +create view v1 as values (1,2),(3,4) union select 1,2; +select * from v1; +1 2 +1 2 +3 4 +drop view v1; +create view v1 as values (5,6) union values (1,2),(3,4); +select * from v1; +5 6 +5 6 +1 2 +3 4 +drop view v1; +create view v1 as values (1,2) union values (1,2),(3,4); +select * from v1; +1 2 +1 2 +3 4 +drop view v1; +create view v1 as select 1,2 union all values (1,2),(3,4); +select * from v1; +1 2 +1 2 +1 2 +3 4 +drop view v1; +create view v1 as values (1,2),(3,4) union all select 1,2; +select * from v1; +1 2 +1 2 +3 4 +1 2 +drop view v1; +create view v1 as values (1,2) union all values (1,2),(3,4); +select * from v1; +1 2 +1 2 +1 2 +3 4 +drop view v1; +drop table t1; diff --git a/mysql-test/t/table_value_constr.test b/mysql-test/t/table_value_constr.test new file mode 100644 index 00000000000..4aba843bbac --- /dev/null +++ b/mysql-test/t/table_value_constr.test @@ -0,0 +1,244 @@ +create table t1 (a int, b int); + +insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); + +--echo # just VALUES + +values (1,2); + +values (1,2), (3,4), (5.6,0); + +values ("abc", "def"); + +--echo # UNION using VALUES structure(s) + +select 1,2 union values (1,2); + +values (1,2) union select 1,2; + +select 1,2 union values (1,2),(3,4),(5,6),(7,8); + +select 3,7 union values (1,2),(3,4),(5,6); + +select 3,7,4 union values (1,2,5),(4,5,6); + +select 1,2 union values (1,7),(3,6.5); + +select 1,2 union values (1,2.0),(3,6); + +select 1.8,2 union values (1,2),(3,6); + +values (1,2.4),(3,6) union select 2.8,9; + +values (1,2),(3,4),(5,6),(7,8) union select 5,6; + +select "ab","cdf" union values ("al","zl"),("we","q"); + +values ("ab", "cdf") union select "ab","cdf"; + +values (1,2) union values (1,2),(5,6); + +values (1,2) union values (3,4),(5,6); + +values (1,2) union values (1,2) union values (4,5); + +--echo # UNION ALL using VALUES structure + +values (1,2),(3,4) union all select 5,6; + +values (1,2),(3,4) union all select 1,2; + +select 5,6 union all values (1,2),(3,4); + +select 1,2 union all values (1,2),(3,4); + +values (1,2) union all values (1,2),(5,6); + +values (1,2) union all values (3,4),(5,6); + +values (1,2) union all values (1,2) union all values (4,5); + +values (1,2) union all values (1,2) union values (1,2); + +values (1,2) union values (1,2) union all values (1,2); + +--echo # EXCEPT using VALUES structure(s) + +select 1,2 except values (3,4),(5,6); + +select 1,2 except values (1,2),(3,4); + +values (1,2),(3,4) except select 5,6; + +values (1,2),(3,4) except select 1,2; + +values (1,2),(3,4) except values (5,6); + +values (1,2),(3,4) except values (1,2); + +--echo # INTERSECT using VALUES structure(s) + +select 1,2 intersect values (3,4),(5,6); + +select 1,2 intersect values (1,2),(3,4); + +values (1,2),(3,4) intersect select 5,6; + +values (1,2),(3,4) intersect select 1,2; + +values (1,2),(3,4) intersect values (5,6); + +values (1,2),(3,4) intersect values (1,2); + +--echo # combination of different structures using VALUES structures : UNION + EXCEPT + +values (1,2),(3,4) except select 1,2 union values (1,2); + +values (1,2),(3,4) except values (1,2) union values (1,2); + +values (1,2),(3,4) except values (1,2) union values (3,4); + +values (1,2),(3,4) union values (1,2) except values (1,2); + +--echo # combination of different structures using VALUES structures : UNION ALL + EXCEPT + +values (1,2),(3,4) except select 1,2 union all values (1,2); + +values (1,2),(3,4) except values (1,2) union all values (1,2); + +values (1,2),(3,4) except values (1,2) union all values (3,4); + +values (1,2),(3,4) union all values (1,2) except values (1,2); + +--echo # combination of different structures using VALUES structures : UNION + INTERSECT + +values (1,2),(3,4) intersect select 1,2 union values (1,2); + +values (1,2),(3,4) intersect values (1,2) union values (1,2); + +values (1,2),(3,4) intersect values (1,2) union values (3,4); + +values (1,2),(3,4) union values (1,2) intersect values (1,2); + +--echo # combination of different structures using VALUES structures : UNION ALL + INTERSECT + +values (1,2),(3,4) intersect select 1,2 union all values (1,2); + +values (1,2),(3,4) intersect values (1,2) union all values (1,2); + +values (1,2),(3,4) intersect values (1,2) union all values (3,4); + +values (1,2),(3,4) union all values (1,2) intersect values (1,2); + +--echo # combination of different structures using VALUES structures : UNION + UNION ALL + +values (1,2),(3,4) union all select 1,2 union values (1,2); + +values (1,2),(3,4) union all values (1,2) union values (1,2); + +values (1,2),(3,4) union all values (1,2) union values (3,4); + +values (1,2),(3,4) union values (1,2) union all values (1,2); + +values (1,2) union values (1,2) union all values (1,2); + +--echo # CTE using VALUES structure(s) + +with t2 as (values (1,2),(3,4)) select * from t2; + +with t2 as (select 1,2 union values (1,2)) select * from t2; + +with t2 as (select 1,2 union values (1,2),(3,4)) select * from t2; + +with t2 as (values (1,2) union select 1,2) select * from t2; + +with t2 as (values (1,2),(3,4) union select 1,2) select * from t2; + +with t2 as (values (5,6) union values (1,2),(3,4)) select * from t2; + +with t2 as (values (1,2) union values (1,2),(3,4)) select * from t2; + +with t2 as (select 1,2 union all values (1,2),(3,4)) select * from t2; + +with t2 as (values (1,2),(3,4) union all select 1,2) select * from t2; + +with t2 as (values (1,2) union all values (1,2),(3,4)) select * from t2; + +--echo # Derived table using VALUES structure(s) + +select * from (values (1,2),(3,4)) as t2; + +select * from (select 1,2 union values (1,2)) as t2; + +select * from (select 1,2 union values (1,2),(3,4)) as t2; + +select * from (values (1,2) union select 1,2) as t2; + +select * from (values (1,2),(3,4) union select 1,2) as t2; + +select * from (values (5,6) union values (1,2),(3,4)) as t2; + +select * from (values (1,2) union values (1,2),(3,4)) as t2; + +select * from (select 1,2 union all values (1,2),(3,4)) as t2; + +select * from (values (1,2),(3,4) union all select 1,2) as t2; + +select * from (values (1,2) union all values (1,2),(3,4)) as t2; + +--echo # CREATE VIEW using VALUES structure(s) + +let $drop_view= drop view v1; +let $select_view= select * from v1; + +create view v1 as values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +create view v1 as select 1,2 union values (1,2); + +eval $select_view; +eval $drop_view; + +create view v1 as select 1,2 union values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +create view v1 as values (1,2) union select 1,2; + +eval $select_view; +eval $drop_view; + +create view v1 as values (1,2),(3,4) union select 1,2; + +eval $select_view; +eval $drop_view; + +create view v1 as values (5,6) union values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +create view v1 as values (1,2) union values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +create view v1 as select 1,2 union all values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +create view v1 as values (1,2),(3,4) union all select 1,2; + +eval $select_view; +eval $drop_view; + +create view v1 as values (1,2) union all values (1,2),(3,4); + +eval $select_view; +eval $drop_view; + +drop table t1; \ No newline at end of file From 3310076dbe781e0554519fba5c4a2585a463250f Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Fri, 25 Aug 2017 19:06:13 +0200 Subject: [PATCH 004/138] Optimization that transforms IN-predicate in IN-subselect made. Trasformation goes that way: a in (1,2) -> a in (select * from (values ((1),(2))) as new_tvc) Special variable that controlls optimization added. Now optimization works only in several cases. New tests added. Old tests corrected. Now with TVC explain can be used. TVC also can be used in recursive CTEs. --- mysql-test/r/opt_tvc.result | 520 ++++++++++++++++++++++++++++++++++++ mysql-test/t/opt_tvc.test | 124 +++++++++ 2 files changed, 644 insertions(+) create mode 100644 mysql-test/r/opt_tvc.result create mode 100644 mysql-test/t/opt_tvc.test diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result new file mode 100644 index 00000000000..f3a5f182e61 --- /dev/null +++ b/mysql-test/r/opt_tvc.result @@ -0,0 +1,520 @@ +create table t1 (a int, b int); +insert into t1 +values (1,2), (4,6), (9,7), +(1,1), (2,5), (7,8); +create table t2 (a int, b int, c int); +insert into t2 +values (1,2,3), (5,1,2), (4,3,7), +(8,9,0), (10,7,1), (5,5,1); +# optimization is not used +select * from t1 where a in (1,2); +a b +1 2 +1 1 +2 5 +explain select * from t1 where a in (1,2); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using where +explain format=json select * from t1 where a in (1,2); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "t1.a in (1,2)" + } + } +} +# set minimum number of values in VALUEs list when optimization works to 2 +set @@in_subquery_conversion_threshold= 2; +# single IN-predicate in WHERE-part +select * from t1 where a in (1,2); +a b +1 2 +1 1 +2 5 +select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +); +a b +1 2 +1 1 +2 5 +explain select * from t1 where a in (1,2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json select * from t1 where a in (1,2); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "", + "access_type": "ALL", + "possible_keys": ["distinct_key"], + "rows": 2, + "filtered": 100, + "materialized": { + "unique": 1, + "query_block": { + "select_id": 2, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 3, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + } + } + } + }, + "block-nl-join": { + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + }, + "buffer_type": "flat", + "buffer_size": "256Kb", + "join_type": "BNL", + "attached_condition": "t1.a = new_tvc.`1`" + } + } +} +# AND-condition with IN-predicates in WHERE-part +select * from t1 +where a in (1,2) and +b in (1,5); +a b +1 1 +2 5 +select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +) +and b in +( +select * +from (values (1),(5)) as new_tvc +); +a b +1 1 +2 5 +explain select * from t1 +where a in (1,2) and +b in (1,5); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 +4 MATERIALIZED ALL NULL NULL NULL NULL 2 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +) +and b in +( +select * +from (values (1),(5)) as new_tvc +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 +4 MATERIALIZED ALL NULL NULL NULL NULL 2 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json select * from t1 +where a in (1,2) and +b in (1,5); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "", + "access_type": "ALL", + "possible_keys": ["distinct_key"], + "rows": 2, + "filtered": 100, + "materialized": { + "unique": 1, + "query_block": { + "select_id": 4, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 5, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + } + } + } + }, + "block-nl-join": { + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + }, + "buffer_type": "flat", + "buffer_size": "256Kb", + "join_type": "BNL", + "attached_condition": "t1.b = new_tvc.`1`" + }, + "table": { + "table_name": "", + "access_type": "eq_ref", + "possible_keys": ["distinct_key"], + "key": "distinct_key", + "key_length": "4", + "used_key_parts": ["1"], + "ref": ["func"], + "rows": 1, + "filtered": 100, + "materialized": { + "unique": 1, + "query_block": { + "select_id": 2, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 3, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + } + } + } + } + } +} +# OR-condition with IN-predicates in WHERE-part +select * from t1 +where a in (1,2) or +b in (4,5); +a b +1 2 +1 1 +2 5 +select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +) +or b in +( +select * +from (values (4),(5)) as new_tvc +); +a b +1 2 +1 1 +2 5 +explain select * from t1 +where a in (1,2) or +b in (4,5); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where +4 MATERIALIZED ALL NULL NULL NULL NULL 2 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain select * from t1 +where a in +( +select * +from (values (1),(2)) as new_tvc +) +or b in +( +select * +from (values (4),(5)) as new_tvc +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where +4 MATERIALIZED ALL NULL NULL NULL NULL 2 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json select * from t1 +where a in (1,2) or +b in (4,5); +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100, + "attached_condition": "(t1.a,t1.a in (subquery#2)) or (t1.b,t1.b in (subquery#4))" + }, + "subqueries": [ + { + "query_block": { + "select_id": 4, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 5, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + } + } + }, + { + "query_block": { + "select_id": 2, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 3, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + } + } + } + ] + } +} +# subquery with IN-predicate +select * from t1 +where a in +( +select a +from t2 where b in (3,4) +) +; +a b +4 6 +select * from t1 +where a in ( +select a from t2 +where b in +( +select * +from (values (3),(4)) as new_tvc) +) +; +a b +4 6 +explain select * from t1 +where a in +( +select a +from t2 where b in (3,4) +) +; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +4 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain select * from t1 +where a in ( +select a from t2 +where b in +( +select * +from (values (3),(4)) as new_tvc) +) +; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) +4 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json select * from t1 +where a in +( +select a +from t2 where b in (3,4) +) +; +EXPLAIN +{ + "query_block": { + "select_id": 1, + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + }, + "table": { + "table_name": "", + "access_type": "eq_ref", + "possible_keys": ["distinct_key"], + "key": "distinct_key", + "key_length": "4", + "used_key_parts": ["a"], + "ref": ["func"], + "rows": 1, + "filtered": 100, + "materialized": { + "unique": 1, + "query_block": { + "select_id": 2, + "table": { + "table_name": "", + "access_type": "ALL", + "rows": 2, + "filtered": 100, + "materialized": { + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 4, + "table": { + "message": "No tables used" + } + } + } + ] + } + } + } + }, + "block-nl-join": { + "table": { + "table_name": "t2", + "access_type": "ALL", + "rows": 6, + "filtered": 100 + }, + "buffer_type": "flat", + "buffer_size": "256Kb", + "join_type": "BNL", + "attached_condition": "t2.b = new_tvc.`3`" + } + } + } + } + } +} +drop table t1; +set @@in_subquery_conversion_threshold= default; diff --git a/mysql-test/t/opt_tvc.test b/mysql-test/t/opt_tvc.test new file mode 100644 index 00000000000..1529672fc69 --- /dev/null +++ b/mysql-test/t/opt_tvc.test @@ -0,0 +1,124 @@ +create table t1 (a int, b int); + +insert into t1 +values (1,2), (4,6), (9,7), + (1,1), (2,5), (7,8); + +create table t2 (a int, b int, c int); + +insert into t2 +values (1,2,3), (5,1,2), (4,3,7), + (8,9,0), (10,7,1), (5,5,1); + +--echo # optimization is not used + +let $query= select * from t1 where a in (1,2); +eval $query; +eval explain $query; +eval explain format=json $query; + +--echo # set minimum number of values in VALUEs list when optimization works to 2 + +set @@in_subquery_conversion_threshold= 2; + +--echo # single IN-predicate in WHERE-part + +let $query= select * from t1 where a in (1,2); + +let $optimized_query= +select * from t1 +where a in + ( + select * + from (values (1),(2)) as new_tvc + ); + +eval $query; +eval $optimized_query; +eval explain $query; +eval explain $optimized_query; +eval explain format=json $query; + +--echo # AND-condition with IN-predicates in WHERE-part + +let $query= +select * from t1 +where a in (1,2) and + b in (1,5); + +let $optimized_query= +select * from t1 +where a in +( + select * + from (values (1),(2)) as new_tvc +) +and b in +( + select * + from (values (1),(5)) as new_tvc +); + +eval $query; +eval $optimized_query; +eval explain $query; +eval explain $optimized_query; +eval explain format=json $query; + +--echo # OR-condition with IN-predicates in WHERE-part + +let $query= +select * from t1 +where a in (1,2) or + b in (4,5); + +let $optimized_query= +select * from t1 +where a in +( + select * + from (values (1),(2)) as new_tvc +) +or b in +( + select * + from (values (4),(5)) as new_tvc +); + +eval $query; +eval $optimized_query; +eval explain $query; +eval explain $optimized_query; +eval explain format=json $query; + +--echo # subquery with IN-predicate + +let $query= +select * from t1 +where a in + ( + select a + from t2 where b in (3,4) + ) +; + +let $optimized_query= +select * from t1 +where a in ( + select a from t2 + where b in + ( + select * + from (values (3),(4)) as new_tvc) + ) +; + +eval $query; +eval $optimized_query; +eval explain $query; +eval explain $optimized_query; +eval explain format=json $query; + +drop table t1; +set @@in_subquery_conversion_threshold= default; + From 570d2e7d0f2c48f9662804eb69e47ce12f983696 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Tue, 29 Aug 2017 02:32:39 +0200 Subject: [PATCH 005/138] Summarized results of two previous commits (26 July, 25 August) --- mysql-test/r/opt_tvc.result | 838 +++++++------- mysql-test/r/table_value_constr.result | 1409 ++++++++++++++++++++++-- mysql-test/t/opt_tvc.test | 262 +++-- mysql-test/t/table_value_const.test | 36 - mysql-test/t/table_value_constr.test | 901 ++++++++++++--- sql/item.h | 2 + sql/item_cmpfunc.cc | 10 + sql/item_cmpfunc.h | 9 +- sql/opt_subselect.cc | 2 + sql/share/errmsg-utf8.txt | 2 + sql/sql_class.h | 1 + sql/sql_lex.cc | 24 +- sql/sql_lex.h | 20 +- sql/sql_select.cc | 21 +- sql/sql_select.h | 1 + sql/sql_tvc.cc | 570 +++++++++- sql/sql_tvc.h | 35 +- sql/sql_union.cc | 65 +- sql/sql_yacc.yy | 73 +- sql/sys_vars.cc | 7 + sql/table.h | 1 + 21 files changed, 3428 insertions(+), 861 deletions(-) delete mode 100644 mysql-test/t/table_value_const.test diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result index f3a5f182e61..a3c71faff46 100644 --- a/mysql-test/r/opt_tvc.result +++ b/mysql-test/r/opt_tvc.result @@ -1,10 +1,10 @@ create table t1 (a int, b int); -insert into t1 +insert into t1 values (1,2), (4,6), (9,7), (1,1), (2,5), (7,8); create table t2 (a int, b int, c int); -insert into t2 -values (1,2,3), (5,1,2), (4,3,7), +insert into t2 +values (1,2,3), (5,1,2), (4,3,7), (8,9,0), (10,7,1), (5,5,1); # optimization is not used select * from t1 where a in (1,2); @@ -37,484 +37,436 @@ a b 1 2 1 1 2 5 -select * from t1 -where a in +select * from t1 +where a in ( -select * -from (values (1),(2)) as new_tvc +select * +from (values (1),(2)) as tvc_0 ); a b 1 2 1 1 2 5 -explain select * from t1 where a in (1,2); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY ALL distinct_key NULL NULL NULL 2 -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain select * from t1 -where a in +explain extended select * from t1 where a in (1,2); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` semi join ((values (1),(2)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` +explain extended select * from t1 +where a in ( -select * -from (values (1),(2)) as new_tvc +select * +from (values (1),(2)) as tvc_0 ); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY ALL distinct_key NULL NULL NULL 2 -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain format=json select * from t1 where a in (1,2); -EXPLAIN -{ - "query_block": { - "select_id": 1, - "table": { - "table_name": "", - "access_type": "ALL", - "possible_keys": ["distinct_key"], - "rows": 2, - "filtered": 100, - "materialized": { - "unique": 1, - "query_block": { - "select_id": 2, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 3, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - } - } - } - }, - "block-nl-join": { - "table": { - "table_name": "t1", - "access_type": "ALL", - "rows": 6, - "filtered": 100 - }, - "buffer_type": "flat", - "buffer_size": "256Kb", - "join_type": "BNL", - "attached_condition": "t1.a = new_tvc.`1`" - } - } -} +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` semi join ((values (1),(2)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` # AND-condition with IN-predicates in WHERE-part -select * from t1 -where a in (1,2) and +select * from t1 +where a in (1,2) and b in (1,5); a b 1 1 2 5 -select * from t1 -where a in +select * from t1 +where a in ( -select * -from (values (1),(2)) as new_tvc -) +select * +from (values (1),(2)) as tvc_0 +) and b in ( -select * -from (values (1),(5)) as new_tvc +select * +from (values (1),(5)) as tvc_1 ); a b 1 1 2 5 -explain select * from t1 -where a in (1,2) and +explain extended select * from t1 +where a in (1,2) and b in (1,5); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY ALL distinct_key NULL NULL NULL 2 -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 -4 MATERIALIZED ALL NULL NULL NULL NULL 2 -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain select * from t1 -where a in +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +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` semi join ((values (1),(2)) `tvc_0`) semi join ((values (1),(5)) `tvc_1`) where `tvc_0`.`1` = `test`.`t1`.`a` and `test`.`t1`.`b` = `tvc_1`.`1` +explain extended select * from t1 +where a in ( -select * -from (values (1),(2)) as new_tvc -) +select * +from (values (1),(2)) as tvc_0 +) and b in ( -select * -from (values (1),(5)) as new_tvc +select * +from (values (1),(5)) as tvc_1 ); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY ALL distinct_key NULL NULL NULL 2 -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 -4 MATERIALIZED ALL NULL NULL NULL NULL 2 -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain format=json select * from t1 -where a in (1,2) and -b in (1,5); -EXPLAIN -{ - "query_block": { - "select_id": 1, - "table": { - "table_name": "", - "access_type": "ALL", - "possible_keys": ["distinct_key"], - "rows": 2, - "filtered": 100, - "materialized": { - "unique": 1, - "query_block": { - "select_id": 4, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 5, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - } - } - } - }, - "block-nl-join": { - "table": { - "table_name": "t1", - "access_type": "ALL", - "rows": 6, - "filtered": 100 - }, - "buffer_type": "flat", - "buffer_size": "256Kb", - "join_type": "BNL", - "attached_condition": "t1.b = new_tvc.`1`" - }, - "table": { - "table_name": "", - "access_type": "eq_ref", - "possible_keys": ["distinct_key"], - "key": "distinct_key", - "key_length": "4", - "used_key_parts": ["1"], - "ref": ["func"], - "rows": 1, - "filtered": 100, - "materialized": { - "unique": 1, - "query_block": { - "select_id": 2, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 3, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - } - } - } - } - } -} -# OR-condition with IN-predicates in WHERE-part -select * from t1 -where a in (1,2) or -b in (4,5); -a b -1 2 -1 1 -2 5 -select * from t1 -where a in -( -select * -from (values (1),(2)) as new_tvc -) -or b in -( -select * -from (values (4),(5)) as new_tvc -); -a b -1 2 -1 1 -2 5 -explain select * from t1 -where a in (1,2) or -b in (4,5); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where -4 MATERIALIZED ALL NULL NULL NULL NULL 2 -5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain select * from t1 -where a in -( -select * -from (values (1),(2)) as new_tvc -) -or b in -( -select * -from (values (4),(5)) as new_tvc -); -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 Using where -4 MATERIALIZED ALL NULL NULL NULL NULL 2 -5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain format=json select * from t1 -where a in (1,2) or -b in (4,5); -EXPLAIN -{ - "query_block": { - "select_id": 1, - "table": { - "table_name": "t1", - "access_type": "ALL", - "rows": 6, - "filtered": 100, - "attached_condition": "(t1.a,t1.a in (subquery#2)) or (t1.b,t1.b in (subquery#4))" - }, - "subqueries": [ - { - "query_block": { - "select_id": 4, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 5, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - } - } - }, - { - "query_block": { - "select_id": 2, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 3, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - } - } - } - ] - } -} +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +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` semi join ((values (1),(2)) `tvc_0`) semi join ((values (1),(5)) `tvc_1`) where `test`.`t1`.`b` = `tvc_1`.`1` # subquery with IN-predicate -select * from t1 -where a in +select * from t1 +where a in ( -select a +select a from t2 where b in (3,4) -) -; +); a b 4 6 -select * from t1 -where a in ( -select a from t2 -where b in +select * from t1 +where a in ( -select * -from (values (3),(4)) as new_tvc) +select a from t2 +where b in +( +select * +from (values (3),(4)) as tvc_0 ) -; +); a b 4 6 -explain select * from t1 -where a in +explain extended select * from t1 +where a in ( -select a +select a from t2 where b in (3,4) -) -; -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -4 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain select * from t1 -where a in ( -select a from t2 -where b in +); +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 eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.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 `test`.`t2`.`b` = `tvc_0`.`3` +explain extended select * from t1 +where a in ( -select * -from (values (3),(4)) as new_tvc) -) -; -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t1 ALL NULL NULL NULL NULL 6 -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 -2 MATERIALIZED ALL NULL NULL NULL NULL 2 -2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) -4 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used -explain format=json select * from t1 -where a in +select a from t2 +where b in ( -select a -from t2 where b in (3,4) +select * +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 eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 6 100.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 `test`.`t2`.`b` = `tvc_0`.`3` +# derived table with IN-predicate +select * from +( +select * +from t1 +where a in (1,2) +) as dr_table; +a b +1 2 +1 1 +2 5 +select * from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) as dr_table; +a b +1 2 +1 1 +2 5 +explain extended select * from +( +select * +from t1 +where a in (1,2) +) 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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +explain extended select * from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) 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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +# non-recursive CTE with IN-predicate +with tvc_0 as +( +select * +from t1 +where a in (1,2) +) +select * from tvc_0; +a b +1 2 +1 1 +2 5 +select * from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) as dr_table; +a b +1 2 +1 1 +2 5 +explain extended with tvc_0 as +( +select * +from t1 +where a in (1,2) +) +select * from 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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 with tvc_0 as (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where `test`.`t1`.`a` in (1,2))/* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +explain extended select * from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) 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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +# VIEW with IN-predicate +create view v1 as +select * +from t1 +where a in (1,2); +create view v2 as +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 ) ; -EXPLAIN -{ - "query_block": { - "select_id": 1, - "table": { - "table_name": "t1", - "access_type": "ALL", - "rows": 6, - "filtered": 100 - }, - "table": { - "table_name": "", - "access_type": "eq_ref", - "possible_keys": ["distinct_key"], - "key": "distinct_key", - "key_length": "4", - "used_key_parts": ["a"], - "ref": ["func"], - "rows": 1, - "filtered": 100, - "materialized": { - "unique": 1, - "query_block": { - "select_id": 2, - "table": { - "table_name": "", - "access_type": "ALL", - "rows": 2, - "filtered": 100, - "materialized": { - "query_block": { - "union_result": { - "table_name": "", - "access_type": "ALL", - "query_specifications": [ - { - "query_block": { - "select_id": 4, - "table": { - "message": "No tables used" - } - } - } - ] - } - } - } - }, - "block-nl-join": { - "table": { - "table_name": "t2", - "access_type": "ALL", - "rows": 6, - "filtered": 100 - }, - "buffer_type": "flat", - "buffer_size": "256Kb", - "join_type": "BNL", - "attached_condition": "t2.b = new_tvc.`3`" - } - } - } - } - } -} -drop table t1; +select * from v1; +a b +1 2 +1 1 +2 5 +select * from v2; +a b +1 2 +1 1 +2 5 +explain extended select * from v1; +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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +explain extended select * from v2; +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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +drop view v1,v2; +# subselect defined by derived table with IN-predicate +select * from t1 +where a in +( +select 1 +from +( +select * +from t1 +where a in (1,2) +) +as dr_table +); +a b +1 2 +1 1 +select * from t1 +where a in +( +select 1 +from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) +as dr_table +); +a b +1 2 +1 1 +explain extended select * from t1 +where a in +( +select 1 +from +( +select * +from t1 +where a in (1,2) +) +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 eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00 Using where +4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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 (`test`.`t1`) where `test`.`t1`.`a` = 1 and <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#4 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +explain extended select * from t1 +where a in +( +select 1 +from +( +select * +from t1 +where a in +( +select * +from (values (1),(2)) +as tvc_0 +) +) +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 eq_ref distinct_key distinct_key 4 func 1 100.00 +2 MATERIALIZED t1 ALL NULL NULL NULL NULL 6 100.00 Using where +4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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 (`test`.`t1`) where `test`.`t1`.`a` = 1 and <`test`.`t1`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#4 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +# derived table with IN-predicate and group by +select * from +( +select max(a),b +from t1 +where b in (3,5) +group by b +) as dr_table; +max(a) b +2 5 +select * from +( +select max(a),b +from t1 +where b in +( +select * +from (values (3),(5)) +as tvc_0 +) +group by b +) as dr_table; +max(a) b +2 5 +explain extended select * from +( +select max(a),b +from t1 +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 ALL NULL NULL NULL NULL 12 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort +2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where `tvc_0`.`3` = `test`.`t1`.`b` group by `test`.`t1`.`b`) `dr_table` +explain extended select * from +( +select max(a),b +from t1 +where b in +( +select * +from (values (3),(5)) +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 ALL NULL NULL NULL NULL 12 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort +2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where 1 group by `test`.`t1`.`b`) `dr_table` +drop table t1, t2; set @@in_subquery_conversion_threshold= default; diff --git a/mysql-test/r/table_value_constr.result b/mysql-test/r/table_value_constr.result index dac84fc5dcb..411edc53168 100644 --- a/mysql-test/r/table_value_constr.result +++ b/mysql-test/r/table_value_constr.result @@ -12,289 +12,591 @@ values (1,2), (3,4), (5.6,0); values ("abc", "def"); abc def abc def -# UNION using VALUES structure(s) -select 1,2 union values (1,2); +# UNION that uses VALUES structure(s) +select 1,2 +union +values (1,2); 1 2 1 2 -values (1,2) union select 1,2; +values (1,2) +union +select 1,2; 1 2 1 2 -select 1,2 union values (1,2),(3,4),(5,6),(7,8); +select 1,2 +union +values (1,2),(3,4),(5,6),(7,8); 1 2 1 2 3 4 5 6 7 8 -select 3,7 union values (1,2),(3,4),(5,6); +select 3,7 +union +values (1,2),(3,4),(5,6); 3 7 3 7 1 2 3 4 5 6 -select 3,7,4 union values (1,2,5),(4,5,6); +select 3,7,4 +union +values (1,2,5),(4,5,6); 3 7 4 3 7 4 1 2 5 4 5 6 -select 1,2 union values (1,7),(3,6.5); +select 1,2 +union +values (1,7),(3,6.5); 1 2 1 2.0 1 7.0 3 6.5 -select 1,2 union values (1,2.0),(3,6); +select 1,2 +union +values (1,2.0),(3,6); 1 2 1 2.0 3 6.0 -select 1.8,2 union values (1,2),(3,6); +select 1.8,2 +union +values (1,2),(3,6); 1.8 2 1.8 2 1.0 2 3.0 6 -values (1,2.4),(3,6) union select 2.8,9; +values (1,2.4),(3,6) +union +select 2.8,9; 1 2.4 1.0 2.4 3.0 6.0 2.8 9.0 -values (1,2),(3,4),(5,6),(7,8) union select 5,6; +values (1,2),(3,4),(5,6),(7,8) +union +select 5,6; 1 2 1 2 3 4 5 6 7 8 -select "ab","cdf" union values ("al","zl"),("we","q"); +select "ab","cdf" +union +values ("al","zl"),("we","q"); ab cdf ab cdf al zl we q -values ("ab", "cdf") union select "ab","cdf"; +values ("ab", "cdf") +union +select "ab","cdf"; ab cdf ab cdf -values (1,2) union values (1,2),(5,6); +values (1,2) +union +values (1,2),(5,6); 1 2 1 2 5 6 -values (1,2) union values (3,4),(5,6); +values (1,2) +union +values (3,4),(5,6); 1 2 1 2 3 4 5 6 -values (1,2) union values (1,2) union values (4,5); +values (1,2) +union +values (1,2) +union values (4,5); 1 2 1 2 4 5 -# UNION ALL using VALUES structure -values (1,2),(3,4) union all select 5,6; +# UNION ALL that uses VALUES structure +values (1,2),(3,4) +union all +select 5,6; 1 2 1 2 3 4 5 6 -values (1,2),(3,4) union all select 1,2; +values (1,2),(3,4) +union all +select 1,2; 1 2 1 2 3 4 1 2 -select 5,6 union all values (1,2),(3,4); +select 5,6 +union all +values (1,2),(3,4); 5 6 5 6 1 2 3 4 -select 1,2 union all values (1,2),(3,4); +select 1,2 +union all +values (1,2),(3,4); 1 2 1 2 1 2 3 4 -values (1,2) union all values (1,2),(5,6); +values (1,2) +union all +values (1,2),(5,6); 1 2 1 2 1 2 5 6 -values (1,2) union all values (3,4),(5,6); +values (1,2) +union all +values (3,4),(5,6); 1 2 1 2 3 4 5 6 -values (1,2) union all values (1,2) union all values (4,5); +values (1,2) +union all +values (1,2) +union all +values (4,5); 1 2 1 2 1 2 4 5 -values (1,2) union all values (1,2) union values (1,2); +values (1,2) +union all +values (1,2) +union values (1,2); 1 2 1 2 -values (1,2) union values (1,2) union all values (1,2); +values (1,2) +union +values (1,2) +union all +values (1,2); 1 2 1 2 1 2 -# EXCEPT using VALUES structure(s) -select 1,2 except values (3,4),(5,6); +# EXCEPT that uses VALUES structure(s) +select 1,2 +except +values (3,4),(5,6); 1 2 1 2 -select 1,2 except values (1,2),(3,4); +select 1,2 +except +values (1,2),(3,4); 1 2 -values (1,2),(3,4) except select 5,6; +values (1,2),(3,4) +except +select 5,6; 1 2 1 2 3 4 -values (1,2),(3,4) except select 1,2; +values (1,2),(3,4) +except +select 1,2; 1 2 3 4 -values (1,2),(3,4) except values (5,6); +values (1,2),(3,4) +except +values (5,6); 1 2 1 2 3 4 -values (1,2),(3,4) except values (1,2); +values (1,2),(3,4) +except +values (1,2); 1 2 3 4 -# INTERSECT using VALUES structure(s) -select 1,2 intersect values (3,4),(5,6); +# INTERSECT that uses VALUES structure(s) +select 1,2 +intersect +values (3,4),(5,6); 1 2 -select 1,2 intersect values (1,2),(3,4); +select 1,2 +intersect +values (1,2),(3,4); 1 2 1 2 -values (1,2),(3,4) intersect select 5,6; +values (1,2),(3,4) +intersect +select 5,6; 1 2 -values (1,2),(3,4) intersect select 1,2; +values (1,2),(3,4) +intersect +select 1,2; 1 2 1 2 -values (1,2),(3,4) intersect values (5,6); +values (1,2),(3,4) +intersect +values (5,6); 1 2 -values (1,2),(3,4) intersect values (1,2); +values (1,2),(3,4) +intersect +values (1,2); 1 2 1 2 -# combination of different structures using VALUES structures : UNION + EXCEPT -values (1,2),(3,4) except select 1,2 union values (1,2); +# combination of different structures that uses VALUES structures : UNION + EXCEPT +values (1,2),(3,4) +except +select 1,2 +union values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) except values (1,2) union values (1,2); +values (1,2),(3,4) +except +values (1,2) +union +values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) except values (1,2) union values (3,4); +values (1,2),(3,4) +except +values (1,2) +union +values (3,4); 1 2 3 4 -values (1,2),(3,4) union values (1,2) except values (1,2); +values (1,2),(3,4) +union +values (1,2) +except +values (1,2); 1 2 3 4 -# combination of different structures using VALUES structures : UNION ALL + EXCEPT -values (1,2),(3,4) except select 1,2 union all values (1,2); +# combination of different structures that uses VALUES structures : UNION ALL + EXCEPT +values (1,2),(3,4) +except +select 1,2 +union all +values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) except values (1,2) union all values (1,2); +values (1,2),(3,4) +except +values (1,2) +union all +values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) except values (1,2) union all values (3,4); +values (1,2),(3,4) +except +values (1,2) +union all +values (3,4); 1 2 3 4 3 4 -values (1,2),(3,4) union all values (1,2) except values (1,2); +values (1,2),(3,4) +union all +values (1,2) +except +values (1,2); 1 2 3 4 -# combination of different structures using VALUES structures : UNION + INTERSECT -values (1,2),(3,4) intersect select 1,2 union values (1,2); +# combination of different structures that uses VALUES structures : UNION + INTERSECT +values (1,2),(3,4) +intersect +select 1,2 +union +values (1,2); 1 2 1 2 -values (1,2),(3,4) intersect values (1,2) union values (1,2); +values (1,2),(3,4) +intersect +values (1,2) +union +values (1,2); 1 2 1 2 -values (1,2),(3,4) intersect values (1,2) union values (3,4); +values (1,2),(3,4) +intersect +values (1,2) +union +values (3,4); 1 2 1 2 3 4 -values (1,2),(3,4) union values (1,2) intersect values (1,2); +values (1,2),(3,4) +union +values (1,2) +intersect +values (1,2); 1 2 1 2 3 4 -# combination of different structures using VALUES structures : UNION ALL + INTERSECT -values (1,2),(3,4) intersect select 1,2 union all values (1,2); +# combination of different structures that uses VALUES structures : UNION ALL + INTERSECT +values (1,2),(3,4) +intersect +select 1,2 +union all +values (1,2); 1 2 1 2 1 2 -values (1,2),(3,4) intersect values (1,2) union all values (1,2); +values (1,2),(3,4) +intersect +values (1,2) +union all +values (1,2); 1 2 1 2 1 2 -values (1,2),(3,4) intersect values (1,2) union all values (3,4); +values (1,2),(3,4) +intersect +values (1,2) +union all +values (3,4); 1 2 1 2 3 4 -values (1,2),(3,4) union all values (1,2) intersect values (1,2); +values (1,2),(3,4) +union all +values (1,2) +intersect +values (1,2); 1 2 1 2 3 4 1 2 -# combination of different structures using VALUES structures : UNION + UNION ALL -values (1,2),(3,4) union all select 1,2 union values (1,2); +# combination of different structures that uses VALUES structures : UNION + UNION ALL +values (1,2),(3,4) +union all +select 1,2 +union +values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) union all values (1,2) union values (1,2); +values (1,2),(3,4) +union all +values (1,2) +union +values (1,2); 1 2 1 2 3 4 -values (1,2),(3,4) union all values (1,2) union values (3,4); +values (1,2),(3,4) +union all +values (1,2) +union +values (3,4); 1 2 1 2 3 4 -values (1,2),(3,4) union values (1,2) union all values (1,2); +values (1,2),(3,4) +union +values (1,2) +union all +values (1,2); 1 2 1 2 3 4 1 2 -values (1,2) union values (1,2) union all values (1,2); +values (1,2) +union +values (1,2) +union all +values (1,2); 1 2 1 2 1 2 -# CTE using VALUES structure(s) -with t2 as (values (1,2),(3,4)) select * from t2; +# CTE that uses VALUES structure(s) : non-recursive CTE +with t2 as +( +values (1,2),(3,4) +) +select * from t2; 1 2 1 2 3 4 -with t2 as (select 1,2 union values (1,2)) select * from t2; +with t2 as +( +select 1,2 +union +values (1,2) +) +select * from t2; 1 2 1 2 -with t2 as (select 1,2 union values (1,2),(3,4)) select * from t2; +with t2 as +( +select 1,2 +union +values (1,2),(3,4) +) +select * from t2; 1 2 1 2 3 4 -with t2 as (values (1,2) union select 1,2) select * from t2; +with t2 as +( +values (1,2) +union +select 1,2 +) +select * from t2; 1 2 1 2 -with t2 as (values (1,2),(3,4) union select 1,2) select * from t2; +with t2 as +( +values (1,2),(3,4) +union +select 1,2 +) +select * from t2; 1 2 1 2 3 4 -with t2 as (values (5,6) union values (1,2),(3,4)) select * from t2; +with t2 as +( +values (5,6) +union +values (1,2),(3,4) +) +select * from t2; 5 6 5 6 1 2 3 4 -with t2 as (values (1,2) union values (1,2),(3,4)) select * from t2; +with t2 as +( +values (1,2) +union +values (1,2),(3,4) +) +select * from t2; 1 2 1 2 3 4 -with t2 as (select 1,2 union all values (1,2),(3,4)) select * from t2; +with t2 as +( +select 1,2 +union all +values (1,2),(3,4) +) +select * from t2; 1 2 1 2 1 2 3 4 -with t2 as (values (1,2),(3,4) union all select 1,2) select * from t2; +with t2 as +( +values (1,2),(3,4) +union all +select 1,2 +) +select * from t2; 1 2 1 2 3 4 1 2 -with t2 as (values (1,2) union all values (1,2),(3,4)) select * from t2; +with t2 as +( +values (1,2) +union all +values (1,2),(3,4) +) +select * from t2; 1 2 1 2 1 2 3 4 -# Derived table using VALUES structure(s) +# recursive CTE that uses VALUES structure(s) : singe VALUES structure as anchor +with recursive t2(a,b) as +( +values(1,1) +union +select t1.a, t1.b +from t1,t2 +where t1.a=t2.a +) +select * from t2; +a b +1 1 +1 2 +with recursive t2(a,b) as +( +values(1,1) +union +select t1.a+1, t1.b +from t1,t2 +where t1.a=t2.a +) +select * from t2; +a b +1 1 +2 2 +2 1 +3 5 +# recursive CTE that uses VALUES structure(s) : several VALUES structures as anchors +with recursive t2(a,b) as +( +values(1,1) +union +values (3,4) +union +select t2.a+1, t1.b +from t1,t2 +where t1.a=t2.a +) +select * from t2; +a b +1 1 +3 4 +2 2 +2 1 +3 5 +# recursive CTE that uses VALUES structure(s) : that uses UNION ALL +with recursive t2(a,b,st) as +( +values(1,1,1) +union all +select t2.a, t1.b, t2.st+1 +from t1,t2 +where t1.a=t2.a and st<3 +) +select * from t2; +a b st +1 1 1 +1 2 2 +1 1 2 +1 2 3 +1 2 3 +1 1 3 +1 1 3 +# recursive CTE that uses VALUES structure(s) : computation of factorial (first 10 elements) +with recursive fact(n,f) as +( +values(1,1) +union +select n+1,f*n from fact where n < 10 +) +select * from fact; +n f +1 1 +2 1 +3 2 +4 6 +5 24 +6 120 +7 720 +8 5040 +9 40320 +10 362880 +# Derived table that uses VALUES structure(s) : singe VALUES structure select * from (values (1,2),(3,4)) as t2; 1 2 1 2 3 4 +# Derived table that uses VALUES structure(s) : UNION with VALUES structure(s) select * from (select 1,2 union values (1,2)) as t2; 1 2 1 2 @@ -318,6 +620,7 @@ select * from (values (1,2) union values (1,2),(3,4)) as t2; 1 2 1 2 3 4 +# Derived table that uses VALUES structure(s) : UNION ALL with VALUES structure(s) select * from (select 1,2 union all values (1,2),(3,4)) as t2; 1 2 1 2 @@ -333,67 +636,997 @@ select * from (values (1,2) union all values (1,2),(3,4)) as t2; 1 2 1 2 3 4 -# CREATE VIEW using VALUES structure(s) +# CREATE VIEW that uses VALUES structure(s) : singe VALUES structure create view v1 as values (1,2),(3,4); select * from v1; 1 2 1 2 3 4 drop view v1; -create view v1 as select 1,2 union values (1,2); +# CREATE VIEW that uses VALUES structure(s) : UNION with VALUES structure(s) +create view v1 as +select 1,2 +union +values (1,2); select * from v1; 1 2 1 2 drop view v1; -create view v1 as select 1,2 union values (1,2),(3,4); +create view v1 as +select 1,2 +union +values (1,2),(3,4); select * from v1; 1 2 1 2 3 4 drop view v1; -create view v1 as values (1,2) union select 1,2; +create view v1 as +values (1,2) +union +select 1,2; select * from v1; 1 2 1 2 drop view v1; -create view v1 as values (1,2),(3,4) union select 1,2; +create view v1 as +values (1,2),(3,4) +union +select 1,2; select * from v1; 1 2 1 2 3 4 drop view v1; -create view v1 as values (5,6) union values (1,2),(3,4); +create view v1 as +values (5,6) +union +values (1,2),(3,4); select * from v1; 5 6 5 6 1 2 3 4 drop view v1; -create view v1 as values (1,2) union values (1,2),(3,4); +# CREATE VIEW that uses VALUES structure(s) : UNION ALL with VALUES structure(s) +create view v1 as +values (1,2) +union +values (1,2),(3,4); select * from v1; 1 2 1 2 3 4 drop view v1; -create view v1 as select 1,2 union all values (1,2),(3,4); +create view v1 as +select 1,2 +union all +values (1,2),(3,4); select * from v1; 1 2 1 2 1 2 3 4 drop view v1; -create view v1 as values (1,2),(3,4) union all select 1,2; +create view v1 as +values (1,2),(3,4) +union all +select 1,2; select * from v1; 1 2 1 2 3 4 1 2 drop view v1; -create view v1 as values (1,2) union all values (1,2),(3,4); +create view v1 as +values (1,2) +union all +values (1,2),(3,4); select * from v1; 1 2 1 2 1 2 3 4 drop view v1; +# prepare statement that uses VALUES structure(s): single VALUES structure +prepare stmt1 from " +values (1,2); +"; +execute stmt1; +1 2 +1 2 +execute stmt1; +1 2 +1 2 +deallocate prepare stmt1; +# prepare statement that uses VALUES structure(s): UNION with VALUES structure(s) +prepare stmt1 from " + select 1,2 + union + values (1,2),(3,4); +"; +execute stmt1; +1 2 +1 2 +3 4 +execute stmt1; +1 2 +1 2 +3 4 +deallocate prepare stmt1; +prepare stmt1 from " + values (1,2),(3,4) + union + select 1,2; +"; +execute stmt1; +1 2 +1 2 +3 4 +execute stmt1; +1 2 +1 2 +3 4 +deallocate prepare stmt1; +prepare stmt1 from " + select 1,2 + union + values (3,4) + union + values (1,2); +"; +execute stmt1; +1 2 +1 2 +3 4 +execute stmt1; +1 2 +1 2 +3 4 +deallocate prepare stmt1; +prepare stmt1 from " + values (5,6) + union + values (1,2),(3,4); +"; +execute stmt1; +5 6 +5 6 +1 2 +3 4 +execute stmt1; +5 6 +5 6 +1 2 +3 4 +deallocate prepare stmt1; +# prepare statement that uses VALUES structure(s): UNION ALL with VALUES structure(s) +prepare stmt1 from " + select 1,2 + union + values (1,2),(3,4); +"; +execute stmt1; +1 2 +1 2 +3 4 +execute stmt1; +1 2 +1 2 +3 4 +deallocate prepare stmt1; +prepare stmt1 from " + values (1,2),(3,4) + union all + select 1,2; +"; +execute stmt1; +1 2 +1 2 +3 4 +1 2 +execute stmt1; +1 2 +1 2 +3 4 +1 2 +deallocate prepare stmt1; +prepare stmt1 from " + select 1,2 + union all + values (3,4) + union all + values (1,2); +"; +execute stmt1; +1 2 +1 2 +3 4 +1 2 +execute stmt1; +1 2 +1 2 +3 4 +1 2 +deallocate prepare stmt1; +prepare stmt1 from " + values (1,2) + union all + values (1,2),(3,4); +"; +execute stmt1; +1 2 +1 2 +1 2 +3 4 +execute stmt1; +1 2 +1 2 +1 2 +3 4 +deallocate prepare stmt1; +# explain query that uses VALUES structure(s): single VALUES structure +explain +values (1,2); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json +values (1,2); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +# explain query that uses VALUES structure(s): UNION with VALUES structure(s) +explain +select 1,2 +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL +explain +values (1,2),(3,4) +union +select 1,2; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL +explain +values (5,6) +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL +explain format=json +select 1,2 +union +values (1,2),(3,4); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain format=json +values (1,2),(3,4) +union +select 1,2; +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain format=json +values (5,6) +union +values (1,2),(3,4); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain +select 1,2 +union +values (3,4) +union +values (1,2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +3 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL +explain format=json +select 1,2 +union +values (3,4) +union +values (1,2); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 3, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +# explain query that uses VALUES structure(s): UNION ALL with VALUES structure(s) +explain +select 1,2 +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL +explain +values (1,2),(3,4) +union all +select 1,2; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +explain +values (1,2) +union all +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json +values (1,2),(3,4) +union all +select 1,2; +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain format=json +select 1,2 +union +values (1,2),(3,4); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain format=json +values (1,2) +union all +values (1,2),(3,4); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +explain +select 1,2 +union all +values (3,4) +union all +values (1,2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +3 UNION NULL NULL NULL NULL NULL NULL NULL No tables used +explain format=json +select 1,2 +union all +values (3,4) +union all +values (1,2); +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 3, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +# analyze query that uses VALUES structure(s): single VALUES structure +analyze +values (1,2); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +analyze format=json +values (1,2); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 0, + "r_rows": null, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +# analyze query that uses VALUES structure(s): UNION with VALUES structure(s) +analyze +select 1,2 +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 2.00 NULL NULL +analyze +values (1,2),(3,4) +union +select 1,2; +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 2.00 NULL NULL +analyze +values (5,6) +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 3.00 NULL NULL +analyze format=json +select 1,2 +union +values (1,2),(3,4); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 1, + "r_rows": 2, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze format=json +values (1,2),(3,4) +union +select 1,2; +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 1, + "r_rows": 2, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze format=json +values (5,6) +union +values (1,2),(3,4); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 1, + "r_rows": 3, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze +select 1,2 +union +values (3,4) +union +values (1,2); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 2.00 NULL NULL +analyze format=json +select 1,2 +union +values (3,4) +union +values (1,2); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 1, + "r_rows": 2, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 3, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +# analyze query that uses VALUES structure(s): UNION ALL with VALUES structure(s) +analyze +select 1,2 +union +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL 2.00 NULL NULL +analyze +values (1,2),(3,4) +union all +select 1,2; +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +analyze +values (1,2) +union all +values (1,2),(3,4); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +analyze format=json +values (1,2),(3,4) +union all +select 1,2; +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 0, + "r_rows": null, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze format=json +select 1,2 +union +values (1,2),(3,4); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 1, + "r_rows": 2, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze format=json +values (1,2) +union all +values (1,2),(3,4); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 0, + "r_rows": null, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} +analyze +select 1,2 +union all +values (3,4) +union all +values (1,2); +id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +2 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 UNION NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL No tables used +analyze format=json +select 1,2 +union all +values (3,4) +union all +values (1,2); +ANALYZE +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "r_loops": 0, + "r_rows": null, + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + }, + { + "query_block": { + "select_id": 3, + "operation": "UNION", + "table": { + "message": "No tables used" + } + } + } + ] + } + } +} drop table t1; diff --git a/mysql-test/t/opt_tvc.test b/mysql-test/t/opt_tvc.test index 1529672fc69..fe5110ece51 100644 --- a/mysql-test/t/opt_tvc.test +++ b/mysql-test/t/opt_tvc.test @@ -1,13 +1,13 @@ create table t1 (a int, b int); -insert into t1 +insert into t1 values (1,2), (4,6), (9,7), (1,1), (2,5), (7,8); create table t2 (a int, b int, c int); -insert into t2 -values (1,2,3), (5,1,2), (4,3,7), +insert into t2 +values (1,2,3), (5,1,2), (4,3,7), (8,9,0), (10,7,1), (5,5,1); --echo # optimization is not used @@ -15,7 +15,7 @@ values (1,2,3), (5,1,2), (4,3,7), let $query= select * from t1 where a in (1,2); eval $query; eval explain $query; -eval explain format=json $query; +eval explain format=json $query; --echo # set minimum number of values in VALUEs list when optimization works to 2 @@ -25,100 +25,212 @@ set @@in_subquery_conversion_threshold= 2; let $query= select * from t1 where a in (1,2); -let $optimized_query= -select * from t1 -where a in +let $optimized_query= +select * from t1 +where a in ( - select * - from (values (1),(2)) as new_tvc + select * + from (values (1),(2)) as tvc_0 ); eval $query; eval $optimized_query; -eval explain $query; -eval explain $optimized_query; -eval explain format=json $query; +eval explain extended $query; +eval explain extended $optimized_query; --echo # AND-condition with IN-predicates in WHERE-part -let $query= -select * from t1 -where a in (1,2) and +let $query= +select * from t1 +where a in (1,2) and b in (1,5); -let $optimized_query= -select * from t1 -where a in +let $optimized_query= +select * from t1 +where a in ( - select * - from (values (1),(2)) as new_tvc -) + select * + from (values (1),(2)) as tvc_0 +) and b in ( - select * - from (values (1),(5)) as new_tvc + select * + from (values (1),(5)) as tvc_1 ); - + eval $query; eval $optimized_query; -eval explain $query; -eval explain $optimized_query; -eval explain format=json $query; - ---echo # OR-condition with IN-predicates in WHERE-part - -let $query= -select * from t1 -where a in (1,2) or - b in (4,5); - -let $optimized_query= -select * from t1 -where a in -( - select * - from (values (1),(2)) as new_tvc -) -or b in -( - select * - from (values (4),(5)) as new_tvc -); - -eval $query; -eval $optimized_query; -eval explain $query; -eval explain $optimized_query; -eval explain format=json $query; +eval explain extended $query; +eval explain extended $optimized_query; --echo # subquery with IN-predicate -let $query= -select * from t1 -where a in - ( - select a - from t2 where b in (3,4) - ) -; +let $query= +select * from t1 +where a in +( + select a + from t2 where b in (3,4) +); -let $optimized_query= -select * from t1 -where a in ( - select a from t2 - where b in +let $optimized_query= +select * from t1 +where a in +( + select a from t2 + where b in ( - select * - from (values (3),(4)) as new_tvc) + select * + from (values (3),(4)) as tvc_0 ) -; - +); + eval $query; eval $optimized_query; -eval explain $query; -eval explain $optimized_query; -eval explain format=json $query; +eval explain extended $query; +eval explain extended $optimized_query; -drop table t1; +--echo # derived table with IN-predicate + +let $query= +select * from +( + select * + from t1 + where a in (1,2) +) as dr_table; + +let $optimized_query= +select * from +( + select * + from t1 + where a in + ( + select * + from (values (1),(2)) + as tvc_0 + ) +) as dr_table; + +eval $query; +eval $optimized_query; +eval explain extended $query; +eval explain extended $optimized_query; + +--echo # non-recursive CTE with IN-predicate + +let $cte_query= +with tvc_0 as +( + select * + from t1 + where a in (1,2) +) +select * from tvc_0; + +eval $cte_query; +eval $optimized_query; +eval explain extended $cte_query; +eval explain extended $optimized_query; + +--echo # VIEW with IN-predicate + +create view v1 as + select * + from t1 + where a in (1,2); + +create view v2 as + select * + from t1 + where a in + ( + select * + from (values (1),(2)) + as tvc_0 + ) +; + +let $query= select * from v1; +let $optimized_query= select * from v2; + +eval $query; +eval $optimized_query; +eval explain extended $query; +eval explain extended $optimized_query; + +drop view v1,v2; + +--echo # subselect defined by derived table with IN-predicate + +let $query= +select * from t1 +where a in +( + select 1 + from + ( + select * + from t1 + where a in (1,2) + ) + as dr_table +); + +let $optimized_query= +select * from t1 +where a in +( + select 1 + from + ( + select * + from t1 + where a in + ( + select * + from (values (1),(2)) + as tvc_0 + ) + ) + as dr_table +); + +eval $query; +eval $optimized_query; +eval explain extended $query; +eval explain extended $optimized_query; + +--echo # derived table with IN-predicate and group by + +let $query= +select * from +( + select max(a),b + from t1 + where b in (3,5) + group by b +) as dr_table; + +let $optimized_query= +select * from +( + select max(a),b + from t1 + where b in + ( + select * + from (values (3),(5)) + as tvc_0 + ) + group by b +) as dr_table; + +eval $query; +eval $optimized_query; +eval explain extended $query; +eval explain extended $optimized_query; + +drop table t1, t2; set @@in_subquery_conversion_threshold= default; - diff --git a/mysql-test/t/table_value_const.test b/mysql-test/t/table_value_const.test deleted file mode 100644 index 00cd1baad95..00000000000 --- a/mysql-test/t/table_value_const.test +++ /dev/null @@ -1,36 +0,0 @@ -create table t1 (a int, b int); - -insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); - -values (1,2); - -select 1,2 union values (1,2); - -values (1,2) union select (1,2); - -values (1,2), (3,4) union select 1,2; - -select * from t1 where (t1.a,t1.b) in (select 5,7 union values (1,2),(2,3)); - -select * from t1 where (t1.a,t1.b) in (values (1,2),(2,3) union select 5,7); - -let $drop_view= drop view v1; - -create view v1 as values (1,2); - -eval $drop_view; - -create view v1 as values (1,2) union select 3,4; - -eval $drop_view; - -create view v1 as select 1,2 union values (3,4); - -eval $drop_view; - -create view v1 as select 1,2 union values (3,4),(5,6); - -eval $drop_view; - -drop table t1; - diff --git a/mysql-test/t/table_value_constr.test b/mysql-test/t/table_value_constr.test index 4aba843bbac..0021c27486c 100644 --- a/mysql-test/t/table_value_constr.test +++ b/mysql-test/t/table_value_constr.test @@ -1,6 +1,7 @@ create table t1 (a int, b int); -insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); +insert into t1 values (1,2),(4,6),(9,7), + (1,1),(2,5),(7,8); --echo # just VALUES @@ -10,164 +11,443 @@ values (1,2), (3,4), (5.6,0); values ("abc", "def"); ---echo # UNION using VALUES structure(s) +--echo # UNION that uses VALUES structure(s) -select 1,2 union values (1,2); +select 1,2 +union +values (1,2); -values (1,2) union select 1,2; +values (1,2) +union +select 1,2; -select 1,2 union values (1,2),(3,4),(5,6),(7,8); +select 1,2 +union +values (1,2),(3,4),(5,6),(7,8); -select 3,7 union values (1,2),(3,4),(5,6); +select 3,7 +union +values (1,2),(3,4),(5,6); -select 3,7,4 union values (1,2,5),(4,5,6); +select 3,7,4 +union +values (1,2,5),(4,5,6); -select 1,2 union values (1,7),(3,6.5); +select 1,2 +union +values (1,7),(3,6.5); -select 1,2 union values (1,2.0),(3,6); +select 1,2 +union +values (1,2.0),(3,6); -select 1.8,2 union values (1,2),(3,6); +select 1.8,2 +union +values (1,2),(3,6); -values (1,2.4),(3,6) union select 2.8,9; +values (1,2.4),(3,6) +union +select 2.8,9; -values (1,2),(3,4),(5,6),(7,8) union select 5,6; +values (1,2),(3,4),(5,6),(7,8) +union +select 5,6; -select "ab","cdf" union values ("al","zl"),("we","q"); +select "ab","cdf" +union +values ("al","zl"),("we","q"); -values ("ab", "cdf") union select "ab","cdf"; +values ("ab", "cdf") +union +select "ab","cdf"; -values (1,2) union values (1,2),(5,6); +values (1,2) +union +values (1,2),(5,6); -values (1,2) union values (3,4),(5,6); +values (1,2) +union +values (3,4),(5,6); -values (1,2) union values (1,2) union values (4,5); +values (1,2) +union +values (1,2) +union values (4,5); ---echo # UNION ALL using VALUES structure +--echo # UNION ALL that uses VALUES structure -values (1,2),(3,4) union all select 5,6; +values (1,2),(3,4) +union all +select 5,6; -values (1,2),(3,4) union all select 1,2; +values (1,2),(3,4) +union all +select 1,2; -select 5,6 union all values (1,2),(3,4); +select 5,6 +union all +values (1,2),(3,4); -select 1,2 union all values (1,2),(3,4); +select 1,2 +union all +values (1,2),(3,4); + +values (1,2) +union all +values (1,2),(5,6); -values (1,2) union all values (1,2),(5,6); - -values (1,2) union all values (3,4),(5,6); - -values (1,2) union all values (1,2) union all values (4,5); - -values (1,2) union all values (1,2) union values (1,2); - -values (1,2) union values (1,2) union all values (1,2); - ---echo # EXCEPT using VALUES structure(s) - -select 1,2 except values (3,4),(5,6); - -select 1,2 except values (1,2),(3,4); - -values (1,2),(3,4) except select 5,6; - -values (1,2),(3,4) except select 1,2; - -values (1,2),(3,4) except values (5,6); - -values (1,2),(3,4) except values (1,2); - ---echo # INTERSECT using VALUES structure(s) - -select 1,2 intersect values (3,4),(5,6); - -select 1,2 intersect values (1,2),(3,4); - -values (1,2),(3,4) intersect select 5,6; - -values (1,2),(3,4) intersect select 1,2; - -values (1,2),(3,4) intersect values (5,6); - -values (1,2),(3,4) intersect values (1,2); - ---echo # combination of different structures using VALUES structures : UNION + EXCEPT - -values (1,2),(3,4) except select 1,2 union values (1,2); - -values (1,2),(3,4) except values (1,2) union values (1,2); - -values (1,2),(3,4) except values (1,2) union values (3,4); - -values (1,2),(3,4) union values (1,2) except values (1,2); - ---echo # combination of different structures using VALUES structures : UNION ALL + EXCEPT - -values (1,2),(3,4) except select 1,2 union all values (1,2); - -values (1,2),(3,4) except values (1,2) union all values (1,2); - -values (1,2),(3,4) except values (1,2) union all values (3,4); - -values (1,2),(3,4) union all values (1,2) except values (1,2); - ---echo # combination of different structures using VALUES structures : UNION + INTERSECT - -values (1,2),(3,4) intersect select 1,2 union values (1,2); - -values (1,2),(3,4) intersect values (1,2) union values (1,2); - -values (1,2),(3,4) intersect values (1,2) union values (3,4); - -values (1,2),(3,4) union values (1,2) intersect values (1,2); - ---echo # combination of different structures using VALUES structures : UNION ALL + INTERSECT - -values (1,2),(3,4) intersect select 1,2 union all values (1,2); - -values (1,2),(3,4) intersect values (1,2) union all values (1,2); - -values (1,2),(3,4) intersect values (1,2) union all values (3,4); - -values (1,2),(3,4) union all values (1,2) intersect values (1,2); - ---echo # combination of different structures using VALUES structures : UNION + UNION ALL - -values (1,2),(3,4) union all select 1,2 union values (1,2); - -values (1,2),(3,4) union all values (1,2) union values (1,2); - -values (1,2),(3,4) union all values (1,2) union values (3,4); - -values (1,2),(3,4) union values (1,2) union all values (1,2); - -values (1,2) union values (1,2) union all values (1,2); - ---echo # CTE using VALUES structure(s) - -with t2 as (values (1,2),(3,4)) select * from t2; - -with t2 as (select 1,2 union values (1,2)) select * from t2; - -with t2 as (select 1,2 union values (1,2),(3,4)) select * from t2; - -with t2 as (values (1,2) union select 1,2) select * from t2; - -with t2 as (values (1,2),(3,4) union select 1,2) select * from t2; - -with t2 as (values (5,6) union values (1,2),(3,4)) select * from t2; - -with t2 as (values (1,2) union values (1,2),(3,4)) select * from t2; - -with t2 as (select 1,2 union all values (1,2),(3,4)) select * from t2; - -with t2 as (values (1,2),(3,4) union all select 1,2) select * from t2; - -with t2 as (values (1,2) union all values (1,2),(3,4)) select * from t2; - ---echo # Derived table using VALUES structure(s) +values (1,2) +union all +values (3,4),(5,6); + +values (1,2) +union all +values (1,2) +union all +values (4,5); + +values (1,2) +union all +values (1,2) +union values (1,2); + +values (1,2) +union +values (1,2) +union all +values (1,2); + +--echo # EXCEPT that uses VALUES structure(s) + +select 1,2 +except +values (3,4),(5,6); + +select 1,2 +except +values (1,2),(3,4); + +values (1,2),(3,4) +except +select 5,6; + +values (1,2),(3,4) +except +select 1,2; + +values (1,2),(3,4) +except +values (5,6); + +values (1,2),(3,4) +except +values (1,2); + +--echo # INTERSECT that uses VALUES structure(s) + +select 1,2 +intersect +values (3,4),(5,6); + +select 1,2 +intersect +values (1,2),(3,4); + +values (1,2),(3,4) +intersect +select 5,6; + +values (1,2),(3,4) +intersect +select 1,2; + +values (1,2),(3,4) +intersect +values (5,6); + +values (1,2),(3,4) +intersect +values (1,2); + +--echo # combination of different structures that uses VALUES structures : UNION + EXCEPT + +values (1,2),(3,4) +except +select 1,2 +union values (1,2); + +values (1,2),(3,4) +except +values (1,2) +union +values (1,2); + +values (1,2),(3,4) +except +values (1,2) +union +values (3,4); + +values (1,2),(3,4) +union +values (1,2) +except +values (1,2); + +--echo # combination of different structures that uses VALUES structures : UNION ALL + EXCEPT + +values (1,2),(3,4) +except +select 1,2 +union all +values (1,2); + +values (1,2),(3,4) +except +values (1,2) +union all +values (1,2); + +values (1,2),(3,4) +except +values (1,2) +union all +values (3,4); + +values (1,2),(3,4) +union all +values (1,2) +except +values (1,2); + +--echo # combination of different structures that uses VALUES structures : UNION + INTERSECT + +values (1,2),(3,4) +intersect +select 1,2 +union +values (1,2); + +values (1,2),(3,4) +intersect +values (1,2) +union +values (1,2); + +values (1,2),(3,4) +intersect +values (1,2) +union +values (3,4); + +values (1,2),(3,4) +union +values (1,2) +intersect +values (1,2); + +--echo # combination of different structures that uses VALUES structures : UNION ALL + INTERSECT + +values (1,2),(3,4) +intersect +select 1,2 +union all +values (1,2); + +values (1,2),(3,4) +intersect +values (1,2) +union all +values (1,2); + +values (1,2),(3,4) +intersect +values (1,2) +union all +values (3,4); + +values (1,2),(3,4) +union all +values (1,2) +intersect +values (1,2); + +--echo # combination of different structures that uses VALUES structures : UNION + UNION ALL + +values (1,2),(3,4) +union all +select 1,2 +union +values (1,2); + +values (1,2),(3,4) +union all +values (1,2) +union +values (1,2); + +values (1,2),(3,4) +union all +values (1,2) +union +values (3,4); + +values (1,2),(3,4) +union +values (1,2) +union all +values (1,2); + +values (1,2) +union +values (1,2) +union all +values (1,2); + +--echo # CTE that uses VALUES structure(s) : non-recursive CTE + +with t2 as +( + values (1,2),(3,4) +) +select * from t2; + +with t2 as +( + select 1,2 + union + values (1,2) +) +select * from t2; + +with t2 as +( + select 1,2 + union + values (1,2),(3,4) +) +select * from t2; + +with t2 as +( + values (1,2) + union + select 1,2 +) +select * from t2; + +with t2 as +( + values (1,2),(3,4) + union + select 1,2 +) +select * from t2; + +with t2 as +( + values (5,6) + union + values (1,2),(3,4) +) +select * from t2; + +with t2 as +( + values (1,2) + union + values (1,2),(3,4) +) +select * from t2; + +with t2 as +( + select 1,2 + union all + values (1,2),(3,4) +) +select * from t2; + +with t2 as +( + values (1,2),(3,4) + union all + select 1,2 +) +select * from t2; + +with t2 as +( + values (1,2) + union all + values (1,2),(3,4) +) +select * from t2; + +--echo # recursive CTE that uses VALUES structure(s) : singe VALUES structure as anchor + +with recursive t2(a,b) as +( + values(1,1) + union + select t1.a, t1.b + from t1,t2 + where t1.a=t2.a +) +select * from t2; + +with recursive t2(a,b) as +( + values(1,1) + union + select t1.a+1, t1.b + from t1,t2 + where t1.a=t2.a +) +select * from t2; + +--echo # recursive CTE that uses VALUES structure(s) : several VALUES structures as anchors + +with recursive t2(a,b) as +( + values(1,1) + union + values (3,4) + union + select t2.a+1, t1.b + from t1,t2 + where t1.a=t2.a +) +select * from t2; + +--echo # recursive CTE that uses VALUES structure(s) : that uses UNION ALL + +with recursive t2(a,b,st) as +( + values(1,1,1) + union all + select t2.a, t1.b, t2.st+1 + from t1,t2 + where t1.a=t2.a and st<3 +) +select * from t2; + +--echo # recursive CTE that uses VALUES structure(s) : computation of factorial (first 10 elements) + +with recursive fact(n,f) as +( + values(1,1) + union + select n+1,f*n from fact where n < 10 +) +select * from fact; + +--echo # Derived table that uses VALUES structure(s) : singe VALUES structure select * from (values (1,2),(3,4)) as t2; +--echo # Derived table that uses VALUES structure(s) : UNION with VALUES structure(s) + select * from (select 1,2 union values (1,2)) as t2; select * from (select 1,2 union values (1,2),(3,4)) as t2; @@ -180,13 +460,15 @@ select * from (values (5,6) union values (1,2),(3,4)) as t2; select * from (values (1,2) union values (1,2),(3,4)) as t2; +--echo # Derived table that uses VALUES structure(s) : UNION ALL with VALUES structure(s) + select * from (select 1,2 union all values (1,2),(3,4)) as t2; select * from (values (1,2),(3,4) union all select 1,2) as t2; select * from (values (1,2) union all values (1,2),(3,4)) as t2; ---echo # CREATE VIEW using VALUES structure(s) +--echo # CREATE VIEW that uses VALUES structure(s) : singe VALUES structure let $drop_view= drop view v1; let $select_view= select * from v1; @@ -196,49 +478,378 @@ create view v1 as values (1,2),(3,4); eval $select_view; eval $drop_view; -create view v1 as select 1,2 union values (1,2); +--echo # CREATE VIEW that uses VALUES structure(s) : UNION with VALUES structure(s) + +create view v1 as + select 1,2 + union + values (1,2); eval $select_view; eval $drop_view; -create view v1 as select 1,2 union values (1,2),(3,4); +create view v1 as + select 1,2 + union + values (1,2),(3,4); eval $select_view; eval $drop_view; -create view v1 as values (1,2) union select 1,2; +create view v1 as + values (1,2) + union + select 1,2; eval $select_view; eval $drop_view; -create view v1 as values (1,2),(3,4) union select 1,2; +create view v1 as + values (1,2),(3,4) + union + select 1,2; eval $select_view; eval $drop_view; -create view v1 as values (5,6) union values (1,2),(3,4); +create view v1 as + values (5,6) + union + values (1,2),(3,4); eval $select_view; eval $drop_view; -create view v1 as values (1,2) union values (1,2),(3,4); +--echo # CREATE VIEW that uses VALUES structure(s) : UNION ALL with VALUES structure(s) + +create view v1 as + values (1,2) + union + values (1,2),(3,4); eval $select_view; eval $drop_view; -create view v1 as select 1,2 union all values (1,2),(3,4); +create view v1 as + select 1,2 + union all + values (1,2),(3,4); eval $select_view; eval $drop_view; -create view v1 as values (1,2),(3,4) union all select 1,2; +create view v1 as + values (1,2),(3,4) + union all + select 1,2; eval $select_view; eval $drop_view; -create view v1 as values (1,2) union all values (1,2),(3,4); +create view v1 as + values (1,2) + union all + values (1,2),(3,4); eval $select_view; eval $drop_view; +--echo # prepare statement that uses VALUES structure(s): single VALUES structure + +prepare stmt1 from " +values (1,2); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +--echo # prepare statement that uses VALUES structure(s): UNION with VALUES structure(s) + +prepare stmt1 from " + select 1,2 + union + values (1,2),(3,4); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + values (1,2),(3,4) + union + select 1,2; +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + select 1,2 + union + values (3,4) + union + values (1,2); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + values (5,6) + union + values (1,2),(3,4); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +--echo # prepare statement that uses VALUES structure(s): UNION ALL with VALUES structure(s) + +prepare stmt1 from " + select 1,2 + union + values (1,2),(3,4); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + values (1,2),(3,4) + union all + select 1,2; +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + select 1,2 + union all + values (3,4) + union all + values (1,2); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +prepare stmt1 from " + values (1,2) + union all + values (1,2),(3,4); +"; + +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +--echo # explain query that uses VALUES structure(s): single VALUES structure + +explain +values (1,2); + +explain format=json +values (1,2); + +--echo # explain query that uses VALUES structure(s): UNION with VALUES structure(s) + +explain +select 1,2 +union +values (1,2),(3,4); + +explain +values (1,2),(3,4) +union +select 1,2; + +explain +values (5,6) +union +values (1,2),(3,4); + +explain format=json +select 1,2 +union +values (1,2),(3,4); + +explain format=json +values (1,2),(3,4) +union +select 1,2; + +explain format=json +values (5,6) +union +values (1,2),(3,4); + +explain +select 1,2 +union +values (3,4) +union +values (1,2); + +explain format=json +select 1,2 +union +values (3,4) +union +values (1,2); + +--echo # explain query that uses VALUES structure(s): UNION ALL with VALUES structure(s) + +explain +select 1,2 +union +values (1,2),(3,4); + +explain +values (1,2),(3,4) +union all +select 1,2; + +explain +values (1,2) +union all +values (1,2),(3,4); + +explain format=json +values (1,2),(3,4) +union all +select 1,2; + +explain format=json +select 1,2 +union +values (1,2),(3,4); + +explain format=json +values (1,2) +union all +values (1,2),(3,4); + +explain +select 1,2 +union all +values (3,4) +union all +values (1,2); + +explain format=json +select 1,2 +union all +values (3,4) +union all +values (1,2); + +--echo # analyze query that uses VALUES structure(s): single VALUES structure + +analyze +values (1,2); + +analyze format=json +values (1,2); + +--echo # analyze query that uses VALUES structure(s): UNION with VALUES structure(s) + +analyze +select 1,2 +union +values (1,2),(3,4); + +analyze +values (1,2),(3,4) +union +select 1,2; + +analyze +values (5,6) +union +values (1,2),(3,4); + +analyze format=json +select 1,2 +union +values (1,2),(3,4); + +analyze format=json +values (1,2),(3,4) +union +select 1,2; + +analyze format=json +values (5,6) +union +values (1,2),(3,4); + +analyze +select 1,2 +union +values (3,4) +union +values (1,2); + +analyze format=json +select 1,2 +union +values (3,4) +union +values (1,2); + +--echo # analyze query that uses VALUES structure(s): UNION ALL with VALUES structure(s) + +analyze +select 1,2 +union +values (1,2),(3,4); + +analyze +values (1,2),(3,4) +union all +select 1,2; + +analyze +values (1,2) +union all +values (1,2),(3,4); + +analyze format=json +values (1,2),(3,4) +union all +select 1,2; + +analyze format=json +select 1,2 +union +values (1,2),(3,4); + +analyze format=json +values (1,2) +union all +values (1,2),(3,4); + +analyze +select 1,2 +union all +values (3,4) +union all +values (1,2); + +analyze format=json +select 1,2 +union all +values (3,4) +union all +values (1,2); + drop table t1; \ No newline at end of file diff --git a/sql/item.h b/sql/item.h index 76ce4aa935f..c5f236179fd 100644 --- a/sql/item.h +++ b/sql/item.h @@ -1667,6 +1667,8 @@ public: virtual Item *derived_grouping_field_transformer_for_where(THD *thd, uchar *arg) { return this; } + virtual Item *in_predicate_to_in_subs_transformer(THD *thd, uchar *arg) + { return this; } virtual bool expr_cache_is_needed(THD *) { return FALSE; } virtual Item *safe_charset_converter(THD *thd, CHARSET_INFO *tocs); bool needs_charset_converter(uint32 length, CHARSET_INFO *tocs) diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 07b5f90bf69..d05d1602044 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -4327,6 +4327,16 @@ longlong Item_func_in::val_int() } +void Item_func_in::mark_as_condition_AND_part(TABLE_LIST *embedding) +{ + THD *thd= current_thd; + if (can_be_transformed_in_tvc(thd)) + thd->lex->current_select->in_funcs.push_back(this, thd->mem_root); + + emb_on_expr_nest= embedding; +} + + longlong Item_func_bit_or::val_int() { DBUG_ASSERT(fixed == 1); diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index e21e074a7a3..a41da00da2c 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -2144,11 +2144,13 @@ public: */ bool arg_types_compatible; + TABLE_LIST *emb_on_expr_nest; + Item_func_in(THD *thd, List &list): Item_func_opt_neg(thd, list), Predicant_to_list_comparator(thd, arg_count - 1), array(0), have_null(0), - arg_types_compatible(FALSE) + arg_types_compatible(FALSE), emb_on_expr_nest(0) { } longlong val_int(); bool fix_fields(THD *, Item **); @@ -2240,7 +2242,10 @@ public: return NULL; } return clone; - } + } + void mark_as_condition_AND_part(TABLE_LIST *embedding); + bool can_be_transformed_in_tvc(THD *thd); + Item *in_predicate_to_in_subs_transformer(THD *thd, uchar *arg); }; class cmp_item_row :public cmp_item diff --git a/sql/opt_subselect.cc b/sql/opt_subselect.cc index b18fb8f2ae5..f608e826f9b 100644 --- a/sql/opt_subselect.cc +++ b/sql/opt_subselect.cc @@ -1047,6 +1047,8 @@ bool convert_join_subqueries_to_semijoins(JOIN *join) DBUG_RETURN(1); if (subq_sel->handle_derived(thd->lex, DT_MERGE)) DBUG_RETURN(TRUE); + if (subq_sel->join->transform_in_predicate_into_tvc(thd)) + DBUG_RETURN(TRUE); subq_sel->update_used_tables(); } diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 1f282e6aee5..1a547e44820 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7490,3 +7490,5 @@ ER_WRONG_INSERT_INTO_SEQUENCE eng "Wrong INSERT into a SEQUENCE. One can only do single table INSERT into a squence object (like with mysqldump). If you want to change the SEQUENCE, use ALTER SEQUENCE instead." ER_SP_STACK_TRACE eng "At line %u in %s" +ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR + eng "The used TABLE VALUE CONSTRUCTOR has a different number of columns" diff --git a/sql/sql_class.h b/sql/sql_class.h index 609d4ad23eb..d2b57b4d2b9 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -691,6 +691,7 @@ typedef struct system_variables uint idle_transaction_timeout; uint idle_readonly_transaction_timeout; uint idle_readwrite_transaction_timeout; + ulong in_subquery_conversion_threshold; } SV; /** diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index baab673011f..4c59b666acb 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -2224,6 +2224,7 @@ void st_select_lex::init_query() m_agg_func_used= false; window_specs.empty(); window_funcs.empty(); + tvc= 0; } void st_select_lex::init_select() @@ -2263,6 +2264,8 @@ void st_select_lex::init_select() join= 0; lock_type= TL_READ_DEFAULT; tvc= 0; + in_funcs.empty(); + cur_tvc= 0; } /* @@ -2807,7 +2810,10 @@ void st_select_lex_unit::print(String *str, enum_query_type query_type) } if (sl->braces) str->append('('); - sl->print(thd, str, query_type); + if (sl->tvc) + sl->tvc->print(thd, str, query_type); + else + sl->print(thd, str, query_type); if (sl->braces) str->append(')'); } @@ -4188,6 +4194,22 @@ bool SELECT_LEX::merge_subquery(THD *thd, TABLE_LIST *derived, if (in_subq->emb_on_expr_nest == NO_JOIN_NEST) in_subq->emb_on_expr_nest= derived; } + + uint cnt= sizeof(expr_cache_may_be_used)/sizeof(bool); + for (uint i= 0; i < cnt; i++) + { + if (subq_select->expr_cache_may_be_used[i]) + expr_cache_may_be_used[i]= true; + } + + List_iterator_fast it(subq_select->in_funcs); + Item_func_in *in_func; + while ((in_func= it++)) + { + in_funcs.push_back(in_func, thd->mem_root); + if (in_func->emb_on_expr_nest == NO_JOIN_NEST) + in_func->emb_on_expr_nest= derived; + } } /* Walk through child's tables and adjust table map, tablenr, diff --git a/sql/sql_lex.h b/sql/sql_lex.h index dbe881f2926..b607a3c479c 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -864,6 +864,17 @@ public: those converted to jtbm nests. The list is emptied when conversion is done. */ List sj_subselects; + /* + List of IN-predicates in this st_select_lex that + can be transformed into IN-subselect defined with TVC. + */ + List in_funcs; + /* + Number of current derived table made with TVC during the + transformation of IN-predicate into IN-subquery for this + st_select_lex. + */ + uint cur_tvc; /* Needed to correctly generate 'PRIMARY' or 'SIMPLE' for select_type column @@ -1215,7 +1226,7 @@ public: bool have_window_funcs() const { return (window_funcs.elements !=0); } bool cond_pushdown_is_allowed() const - { return !have_window_funcs() && !olap && !explicit_limit; } + { return !have_window_funcs() && !olap && !explicit_limit && !tvc; } private: bool m_non_agg_field_used; @@ -1239,7 +1250,12 @@ typedef class st_select_lex SELECT_LEX; inline bool st_select_lex_unit::is_unit_op () { if (!first_select()->next_select()) - return 0; + { + if (first_select()->tvc) + return 1; + else + return 0; + } enum sub_select_type linkage= first_select()->next_select()->linkage; return linkage == UNION_TYPE || linkage == INTERSECT_TYPE || diff --git a/sql/sql_select.cc b/sql/sql_select.cc index c6613facde7..ab87bc00c8c 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -347,7 +347,8 @@ bool handle_select(THD *thd, LEX *lex, select_result *result, MYSQL_SELECT_START(thd->query()); if (select_lex->master_unit()->is_unit_op() || - select_lex->master_unit()->fake_select_lex) + select_lex->master_unit()->fake_select_lex || + select_lex->tvc) res= mysql_union(thd, lex, result, &lex->unit, setup_tables_done_option); else { @@ -1187,6 +1188,11 @@ JOIN::optimize_inner() DBUG_RETURN(TRUE); table_count= select_lex->leaf_tables.elements; } + + if (select_lex->first_cond_optimization && + transform_in_predicate_into_tvc(thd)) + DBUG_RETURN(1); + // Update used tables after all handling derived table procedures select_lex->update_used_tables(); @@ -13628,8 +13634,9 @@ static int compare_fields_by_table_order(Item *field1, static TABLE_LIST* embedding_sjm(Item *item) { Item_field *item_field= (Item_field *) (item->real_item()); - TABLE_LIST *nest= item_field->field->table->pos_in_table_list->embedding; - if (nest && nest->sj_mat_info && nest->sj_mat_info->is_used) + TABLE_LIST *tbl= item_field->field->table->pos_in_table_list; + TABLE_LIST *nest= tbl->embedding; + if (nest && nest->sj_mat_info && nest->sj_mat_info->is_used && !tbl->is_for_tvc) return nest; else return NULL; @@ -13706,6 +13713,7 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, Item *head; TABLE_LIST *current_sjm= NULL; Item *current_sjm_head= NULL; + bool force_producing_equality= false; DBUG_ASSERT(!cond || cond->type() == Item::INT_ITEM || @@ -13727,6 +13735,8 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, TABLE_LIST *emb_nest; head= item_equal->get_first(NO_PARTICULAR_TAB, NULL); it++; + if (((Item_field *)(head->real_item()))->field->table->pos_in_table_list->is_for_tvc) + force_producing_equality= true; if ((emb_nest= embedding_sjm(head))) { current_sjm= emb_nest; @@ -13794,7 +13804,7 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, produce_equality= FALSE; } - if (produce_equality) + if (produce_equality || force_producing_equality) { if (eq_item && eq_list.push_back(eq_item, thd->mem_root)) return 0; @@ -13809,7 +13819,8 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, equals on top level, or the constant. */ Item *head_item= (!item_const && current_sjm && - current_sjm_head != field_item) ? current_sjm_head: head; + current_sjm_head != field_item && + !force_producing_equality) ? current_sjm_head: head; Item *head_real_item= head_item->real_item(); if (head_real_item->type() == Item::FIELD_ITEM) head_item= head_real_item; diff --git a/sql/sql_select.h b/sql/sql_select.h index 96764fd7f00..ad15ce5eb2c 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1648,6 +1648,7 @@ public: bool need_order, bool distinct, const char *message); JOIN_TAB *first_breadth_first_tab() { return join_tab; } + bool transform_in_predicate_into_tvc(THD *thd_arg); private: /** Create a temporary table to be used for processing DISTINCT/ORDER diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 323ce5eacb9..e9476254f9e 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -1,14 +1,40 @@ #include "sql_list.h" #include "sql_tvc.h" #include "sql_class.h" +#include "opt_range.h" +#include "sql_select.h" +#include "sql_explain.h" +#include "sql_parse.h" /** - The method searches types of columns for temporary table where values from TVC will be stored + @brief + Defines types of matrix columns elements where matrix rows are defined by + some lists of values. + + @param + @param thd_arg The context of the statement + @param li The iterator on the list of lists + @param holders The structure where types of matrix columns are stored + @param first_list_el_count Count of the list values that should be. It should + be the same for each list of lists elements. It contains + number of elements of the first list from list of lists. + + @details + For each list list_a from list of lists the procedure gets its elements types and + aggregates them with the previous ones stored in holders. If list_a is the first + one in the list of lists its elements types are put in holders. + The errors can be reported when count of list_a elements is different from the + first_list_el_count. Also error can be reported when aggregation can't be made. + + @retval + true if an error was reported + false otherwise */ -bool join_type_handlers_for_tvc(List_iterator_fast &li, - Type_holder *holders, uint cnt) +bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, + Type_holder *holders, uint first_list_el_count) { + DBUG_ENTER("join_type_handlers_for_tvc"); List_item *lst; li.rewind(); bool first= true; @@ -18,10 +44,12 @@ bool join_type_handlers_for_tvc(List_iterator_fast &li, List_iterator_fast it(*lst); Item *item; - if (cnt != lst->elements) + if (first_list_el_count != lst->elements) { - /*error wrong number of values*/ - return true; + my_message(ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR, + ER_THD(thd_arg, ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR), + MYF(0)); + DBUG_RETURN(true); } for (uint pos= 0; (item=it++); pos++) { @@ -30,54 +58,105 @@ bool join_type_handlers_for_tvc(List_iterator_fast &li, holders[pos].set_handler(item_type_handler); else if (holders[pos].aggregate_for_result(item_type_handler)) { - /*error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION*/ - return true; + my_error(ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION, MYF(0), + holders[pos].type_handler()->name().ptr(), + item_type_handler->name().ptr(), + "TABLE VALUE CONSTRUCTOR"); + DBUG_RETURN(true); } } first= false; } - return false; + DBUG_RETURN(false); } + /** - The method searches names of columns for temporary table where values from TVC will be stored + @brief + Defines attributes of matrix columns elements where matrix rows are defined by + some lists of values. + + @param + @param thd_arg The context of the statement + @param li The iterator on the list of lists + @param holders The structure where names of matrix columns are stored + @param count_of_lists Count of list of lists elements + @param first_list_el_count Count of the list values that should be. It should + be the same for each list of lists elements. It contains + number of elements of the first list from list of lists. + + @details + For each list list_a from list of lists the procedure gets its elements attributes and + aggregates them with the previous ones stored in holders. + The errors can be reported when aggregation can't be made. + + @retval + true if an error was reported + false otherwise */ bool get_type_attributes_for_tvc(THD *thd_arg, List_iterator_fast &li, - Type_holder *holders, uint count) + Type_holder *holders, uint count_of_lists, + uint first_list_el_count) { + DBUG_ENTER("get_type_attributes_for_tvc"); List_item *lst; li.rewind(); - lst= li++; - uint first_list_el_count= lst->elements; - for (uint pos= 0; pos < first_list_el_count; pos++) { - if (holders[pos].alloc_arguments(thd_arg, count)) - return true; + if (holders[pos].alloc_arguments(thd_arg, count_of_lists)) + DBUG_RETURN(true); } - List_iterator_fast it(*lst); - Item *item; - - for (uint holder_pos= 0 ; (item= it++); holder_pos++) + while ((lst=li++)) { - DBUG_ASSERT(item->fixed); - holders[holder_pos].add_argument(item); + List_iterator_fast it(*lst); + Item *item; + for (uint holder_pos= 0 ; (item= it++); holder_pos++) + { + DBUG_ASSERT(item->fixed); + holders[holder_pos].add_argument(item); + } } for (uint pos= 0; pos < first_list_el_count; pos++) { if (holders[pos].aggregate_attributes(thd_arg)) - return true; + DBUG_RETURN(true); } - return false; + DBUG_RETURN(false); } -bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, select_result *tmp_result) + +/** + @brief + Prepare of TVC + + @param + @param thd_arg The context of the statement + @param sl The select where this TVC is defined + @param tmp_result Structure that contains the information + about where result of the query should be sent + @param unit_arg The union where sl is defined + + @details + Gets types and attributes of values of this TVC that will be used + for temporary table creation for this TVC. It creates Item_type_holders + for each element of the first list from list of lists (VALUES from tvc), + using its elements name, defined type and attribute. + + @retval + true if an error was reported + false otherwise +*/ + +bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, + select_result *tmp_result, + st_select_lex_unit *unit_arg) { + DBUG_ENTER("table_value_constr::prepare"); List_iterator_fast li(lists_of_values); List_item *first_elem= li++; @@ -86,9 +165,11 @@ bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, select_result *tm if (!(holders= new (thd_arg->mem_root) Type_holder[cnt]) || - join_type_handlers_for_tvc(li, holders, cnt) || - get_type_attributes_for_tvc(thd_arg, li, holders, cnt)) - return true; + join_type_handlers_for_tvc(thd_arg, li, holders, + cnt) || + get_type_attributes_for_tvc(thd_arg, li, holders, + lists_of_values.elements, cnt)) + DBUG_RETURN(true); List_iterator_fast it(*first_elem); Item *item; @@ -108,21 +189,448 @@ bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, select_result *tm } if (thd_arg->is_fatal_error) - return true; // out of memory + DBUG_RETURN(true); // out of memory result= tmp_result; - return false; + if (result && result->prepare(sl->item_list, unit_arg)) + DBUG_RETURN(true); + + DBUG_RETURN(false); } -bool table_value_constr::exec() + +/** + Save Query Plan Footprint +*/ + +int table_value_constr::save_explain_data_intern(THD *thd_arg, + Explain_query *output) { + const char *message= "No tables used"; + DBUG_ENTER("table_value_constr::save_explain_data_intern"); + DBUG_PRINT("info", ("Select 0x%lx, type %s, message %s", + (ulong)select_lex, select_lex->type, + message)); + DBUG_ASSERT(have_query_plan == QEP_AVAILABLE); + + /* There should be no attempts to save query plans for merged selects */ + DBUG_ASSERT(!select_lex->master_unit()->derived || + select_lex->master_unit()->derived->is_materialized_derived() || + select_lex->master_unit()->derived->is_with_table()); + + explain= new (output->mem_root) Explain_select(output->mem_root, + thd_arg->lex->analyze_stmt); + select_lex->set_explain_type(true); + + explain->select_id= select_lex->select_number; + explain->select_type= select_lex->type; + explain->linkage= select_lex->linkage; + explain->using_temporary= NULL; + explain->using_filesort= NULL; + /* Setting explain->message means that all other members are invalid */ + explain->message= message; + + if (select_lex->master_unit()->derived) + explain->connection_type= Explain_node::EXPLAIN_NODE_DERIVED; + + output->add_node(explain); + + if (select_lex->is_top_level_node()) + output->query_plan_ready(); + + DBUG_RETURN(0); +} + + +/** + Optimization of TVC +*/ + +void table_value_constr::optimize(THD *thd_arg) +{ + create_explain_query_if_not_exists(thd_arg->lex, thd_arg->mem_root); + have_query_plan= QEP_AVAILABLE; + + if (select_lex->select_number != UINT_MAX && + select_lex->select_number != INT_MAX /* this is not a UNION's "fake select */ && + have_query_plan != QEP_NOT_PRESENT_YET && + thd_arg->lex->explain && // for "SET" command in SPs. + (!thd_arg->lex->explain->get_select(select_lex->select_number))) + { + save_explain_data_intern(thd_arg, thd_arg->lex->explain); + } +} + + +/** + Execute of TVC +*/ + +bool table_value_constr::exec(SELECT_LEX *sl) +{ + DBUG_ENTER("table_value_constr::exec"); List_iterator_fast li(lists_of_values); List_item *elem; + if (select_options & SELECT_DESCRIBE) + DBUG_RETURN(false); + + if (result->send_result_set_metadata(sl->item_list, + Protocol::SEND_NUM_ROWS | + Protocol::SEND_EOF)) + { + DBUG_RETURN(true); + } + while ((elem=li++)) { result->send_data(*elem); } + + if (result->send_eof()) + DBUG_RETURN(true); + + DBUG_RETURN(false); +} + +/** + @brief + Print list of lists + + @param str Where to print to + @param query_type The mode of printing + @param values List of lists that needed to be print + + @details + The method prints a string representation of list of lists in the + string str. The parameter query_type specifies the mode of printing. +*/ + +void print_list_of_lists(String *str, + enum_query_type query_type, + List *values) +{ + str->append(STRING_WITH_LEN("values ")); + + bool first= 1; + List_iterator_fast li(*values); + List_item *list; + while ((list=li++)) + { + if (first) + first= 0; + else + str->append(','); + + str->append('('); + + List_iterator_fast it(*list); + Item *item; + first= 1; + + while ((item=it++)) + { + if (first) + first= 0; + else + str->append(','); + + item->print(str, query_type); + } + str->append(')'); + } +} + + +/** + @brief + Print this TVC + + @param thd_arg The context of the statement + @param str Where to print to + @param query_type The mode of printing + + @details + The method prints a string representation of this TVC in the + string str. The parameter query_type specifies the mode of printing. +*/ + +void table_value_constr::print(THD *thd_arg, String *str, + enum_query_type query_type) +{ + DBUG_ASSERT(thd_arg); + + print_list_of_lists(str, query_type, &lists_of_values); +} + + +/** + @brief + Creates new SELECT defined by TVC as derived table + + @param thd_arg The context of the statement + @param values List of values that defines TVC + + @details + The method creates this SELECT statement: + + SELECT * FROM (VALUES values) AS new_tvc + + If during creation of SELECT statement some action is + unsuccesfull backup is made to the state in which system + was at the beginning of the method. + + @retval + pointer to the created SELECT statement + NULL - if creation was unsuccesfull +*/ + +st_select_lex *make_new_subselect_for_tvc(THD *thd_arg, + List *values) +{ + LEX *lex= thd_arg->lex; + Item *item; + SELECT_LEX *sel; + SELECT_LEX_UNIT *unit; + TABLE_LIST *new_tab; + Table_ident *ti; + + Query_arena backup; + Query_arena *arena= thd_arg->activate_stmt_arena_if_needed(&backup); + + char buff[6]; + LEX_CSTRING alias; + alias.length= my_snprintf(buff, sizeof(buff), + "tvc_%u", thd_arg->lex->current_select->cur_tvc); + alias.str= thd_arg->strmake(buff, alias.length); + if (!alias.str) + goto err; + + /* + Creation of SELECT statement: SELECT * FROM ... + */ + + if (mysql_new_select(lex, 1, NULL)) + goto err; + + mysql_init_select(lex); + lex->current_select->parsing_place= SELECT_LIST; + + item= new (thd_arg->mem_root) + Item_field(thd_arg, &lex->current_select->context, + NULL, NULL, &star_clex_str); + if (item == NULL) + goto err; + if (add_item_to_list(thd_arg, item)) + goto err; + (lex->current_select->with_wild)++; + + /* + Creation of TVC as derived table + */ + + lex->derived_tables|= DERIVED_SUBQUERY; + if (mysql_new_select(lex, 1, NULL)) + goto err; + + mysql_init_select(lex); + + sel= lex->current_select; + unit= sel->master_unit(); + sel->linkage= DERIVED_TABLE_TYPE; + + if (!(sel->tvc= + new (thd_arg->mem_root) + table_value_constr(*values, + sel, + sel->options))) + goto err; + + lex->check_automatic_up(UNSPECIFIED_TYPE); + lex->current_select= sel= unit->outer_select(); + + ti= new (thd_arg->mem_root) Table_ident(unit); + if (ti == NULL) + goto err; + + if (!(new_tab= sel->add_table_to_list(thd_arg, + ti, &alias, 0, + TL_READ, MDL_SHARED_READ))) + goto err; + + new_tab->is_for_tvc= true; //shows that this derived table is defined by TVC + sel->add_joined_table(new_tab); + + new_tab->select_lex->add_where_field(new_tab->derived->first_select()); + + sel->context.table_list= + sel->context.first_name_resolution_table= + sel->table_list.first; + + sel->where= 0; + sel->set_braces(false); + unit->with_clause= 0; + + return sel; + +err: + if (arena) + thd_arg->restore_active_arena(arena, &backup); + return NULL; +} + + +/** + @brief + Transforms IN-predicate in IN-subselect + + @param thd_arg The context of the statement + @param arg Argument is 0 in this context + + @details + The method creates this SELECT statement: + + SELECT * FROM (VALUES values) AS new_tvc + + If during creation of SELECT statement some action is + unsuccesfull backup is made to the state in which system + was at the beginning of the procedure. + + @retval + pointer to the created SELECT statement + NULL - if creation was unsuccesfull +*/ + +Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, + uchar *arg) +{ + SELECT_LEX *old_select= thd->lex->current_select; + List values; + bool list_of_lists= false; + + if (args[1]->type() == Item::ROW_ITEM) + list_of_lists= true; + + for (uint i=1; i < arg_count; i++) + { + List *new_value= new (thd->mem_root) List(); + + if (list_of_lists) + { + Item_row *in_list= (Item_row *)(args[i]); + + for (uint j=0; j < in_list->cols(); i++) + new_value->push_back(in_list->element_index(j), thd->mem_root); + } + else + new_value->push_back(args[i]); + + values.push_back(new_value, thd->mem_root); + } + + st_select_lex *new_subselect= + make_new_subselect_for_tvc(thd, &values); + + if (new_subselect) + { + new_subselect->parsing_place= old_select->parsing_place; + new_subselect->table_list.first->derived_type= 10; + + Item_in_subselect *in_subs= new (thd->mem_root) Item_in_subselect + (thd, args[0], new_subselect); + thd->lex->derived_tables |= DERIVED_SUBQUERY; + in_subs->emb_on_expr_nest= emb_on_expr_nest; + in_subs->fix_fields(thd, (Item **)&in_subs); + + old_select->cur_tvc++; + thd->lex->current_select= old_select; + return in_subs; + } + + thd->lex->current_select= old_select; + return this; +} + +/** + @brief + Checks if this IN-predicate can be transformed in IN-subquery + with TVC + + @param thd The context of the statement + + @details + Compares the number of elements in the list of + values in this IN-predicate with the + in_subquery_conversion_threshold special variable + + @retval + true if transformation can be made + false otherwise +*/ + +bool Item_func_in::can_be_transformed_in_tvc(THD *thd) +{ + uint opt_can_be_used= arg_count; + + if (args[1]->type() == Item::ROW_ITEM) + opt_can_be_used*= ((Item_row *)(args[1]))->cols(); + + if (opt_can_be_used < thd->variables.in_subquery_conversion_threshold) + return false; + + return true; +} + +/** + @brief + Calls transformer that transforms IN-predicate into IN-subquery + for this select + + @param thd_arg The context of the statement + + @details + Calls in_predicate_to_in_subs_transformer + for WHERE-part and each table from join list of this SELECT +*/ + +bool JOIN::transform_in_predicate_into_tvc(THD *thd_arg) +{ + if (!select_lex->in_funcs.elements) + return false; + + SELECT_LEX *old_select= thd_arg->lex->current_select; + enum_parsing_place old_parsing_place= select_lex->parsing_place; + + thd_arg->lex->current_select= select_lex; + if (conds) + { + select_lex->parsing_place= IN_WHERE; + conds= + conds->transform(thd_arg, + &Item::in_predicate_to_in_subs_transformer, + (uchar*) 0); + select_lex->where= conds; + } + + if (join_list) + { + TABLE_LIST *table; + List_iterator li(*join_list); + select_lex->parsing_place= IN_ON; + + while ((table= li++)) + { + if (table->on_expr) + { + table->on_expr= + table->on_expr->transform(thd_arg, + &Item::in_predicate_to_in_subs_transformer, + (uchar*) 0); + } + } + } + select_lex->parsing_place= old_parsing_place; + thd_arg->lex->current_select= old_select; return false; } \ No newline at end of file diff --git a/sql/sql_tvc.h b/sql/sql_tvc.h index 007b50d81df..5524744a03c 100644 --- a/sql/sql_tvc.h +++ b/sql/sql_tvc.h @@ -6,26 +6,45 @@ typedef List List_item; class select_result; +class Explain_select; +class Explain_query; +class Item_func_in; + /** @class table_value_constr @brief Definition of a Table Value Construction(TVC) - It contains a list of lists of values that this TVC contains. + It contains a list of lists of values which this TVC is defined by and + reference on SELECT where this TVC is defined. */ - class table_value_constr : public Sql_alloc { public: List lists_of_values; select_result *result; + SELECT_LEX *select_lex; + + enum { QEP_NOT_PRESENT_YET, QEP_AVAILABLE} have_query_plan; + + Explain_select *explain; + ulonglong select_options; - table_value_constr(List tvc_values) : - lists_of_values(tvc_values), result(0) - { } + table_value_constr(List tvc_values, SELECT_LEX *sl, + ulonglong select_options_arg) : + lists_of_values(tvc_values), result(0), select_lex(sl), + have_query_plan(QEP_NOT_PRESENT_YET), explain(0), + select_options(select_options_arg) + { }; bool prepare(THD *thd_arg, SELECT_LEX *sl, - select_result *tmp_result); - bool exec(); -}; + select_result *tmp_result, + st_select_lex_unit *unit_arg); + int save_explain_data_intern(THD *thd_arg, + Explain_query *output); + void optimize(THD *thd_arg); + bool exec(SELECT_LEX *sl); + + void print(THD *thd_arg, String *str, enum_query_type query_type); +}; #endif /* SQL_TVC_INCLUDED */ \ No newline at end of file diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 52880cd4442..717863754fc 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -819,6 +819,7 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, bool is_union_select; bool have_except= FALSE, have_intersect= FALSE; bool instantiate_tmp_table= false; + bool single_tvc= !first_sl->next_select() && first_sl->tvc; DBUG_ENTER("st_select_lex_unit::prepare"); DBUG_ASSERT(thd == thd_arg); DBUG_ASSERT(thd == current_thd); @@ -845,16 +846,26 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, /* fast reinit for EXPLAIN */ for (sl= first_sl; sl; sl= sl->next_select()) { - sl->join->result= result; - select_limit_cnt= HA_POS_ERROR; - offset_limit_cnt= 0; - if (!sl->join->procedure && - result->prepare(sl->join->fields_list, this)) + if (sl->tvc) { - DBUG_RETURN(TRUE); + sl->tvc->result= result; + if (result->prepare(sl->item_list, this)) + DBUG_RETURN(TRUE); + sl->tvc->select_options|= SELECT_DESCRIBE; + } + else + { + sl->join->result= result; + select_limit_cnt= HA_POS_ERROR; + offset_limit_cnt= 0; + if (!sl->join->procedure && + result->prepare(sl->join->fields_list, this)) + { + DBUG_RETURN(TRUE); + } + sl->join->select_options|= SELECT_DESCRIBE; + sl->join->reinit(); } - sl->join->select_options|= SELECT_DESCRIBE; - sl->join->reinit(); } } DBUG_RETURN(FALSE); @@ -864,7 +875,7 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, thd_arg->lex->current_select= sl= first_sl; found_rows_for_union= first_sl->options & OPTION_FOUND_ROWS; - is_union_select= is_unit_op() || fake_select_lex; + is_union_select= is_unit_op() || fake_select_lex || single_tvc; for (SELECT_LEX *s= first_sl; s; s= s->next_select()) { @@ -884,8 +895,8 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, if (is_union_select || is_recursive) { - if (is_unit_op() && !union_needs_tmp_table() && - !have_except && !have_intersect) + if ((is_unit_op() && !union_needs_tmp_table() && + !have_except && !have_intersect) || single_tvc) { SELECT_LEX *last= first_select(); while (last->next_select()) @@ -922,7 +933,7 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, { if (sl->tvc) { - if (sl->tvc->prepare(thd_arg, sl, tmp_result)) + if (sl->tvc->prepare(thd_arg, sl, tmp_result, this)) goto err; } else if (prepare_join(thd_arg, first_sl, tmp_result, additional_options, @@ -936,7 +947,7 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, { if (sl->tvc) { - if (sl->tvc->prepare(thd_arg, sl, tmp_result)) + if (sl->tvc->prepare(thd_arg, sl, tmp_result, this)) goto err; } else if (prepare_join(thd_arg, sl, tmp_result, additional_options, @@ -1249,7 +1260,13 @@ bool st_select_lex_unit::optimize() for (SELECT_LEX *sl= select_cursor; sl; sl= sl->next_select()) { if (sl->tvc) + { + sl->tvc->select_options= + (select_limit_cnt == HA_POS_ERROR || sl->braces) ? + sl->options & ~OPTION_FOUND_ROWS : sl->options | found_rows_for_union; + sl->tvc->optimize(thd); continue; + } thd->lex->current_select= sl; if (optimized) @@ -1273,7 +1290,7 @@ bool st_select_lex_unit::optimize() we don't calculate found_rows() per union part. Otherwise, SQL_CALC_FOUND_ROWS should be done on all sub parts. */ - sl->join->select_options= + sl->join->select_options= (select_limit_cnt == HA_POS_ERROR || sl->braces) ? sl->options & ~OPTION_FOUND_ROWS : sl->options | found_rows_for_union; @@ -1357,7 +1374,14 @@ bool st_select_lex_unit::exec() we don't calculate found_rows() per union part. Otherwise, SQL_CALC_FOUND_ROWS should be done on all sub parts. */ - if (!sl->tvc) + if (sl->tvc) + { + sl->tvc->select_options= + (select_limit_cnt == HA_POS_ERROR || sl->braces) ? + sl->options & ~OPTION_FOUND_ROWS : sl->options | found_rows_for_union; + sl->tvc->optimize(thd); + } + else { sl->join->select_options= (select_limit_cnt == HA_POS_ERROR || sl->braces) ? @@ -1369,7 +1393,7 @@ bool st_select_lex_unit::exec() { records_at_start= table->file->stats.records; if (sl->tvc) - sl->tvc->exec(); + sl->tvc->exec(sl); else sl->join->exec(); if (sl == union_distinct && !(with_element && with_element->is_recursive)) @@ -1611,8 +1635,13 @@ bool st_select_lex_unit::exec_recursive() for (st_select_lex *sl= start ; sl != end; sl= sl->next_select()) { thd->lex->current_select= sl; - sl->join->exec(); - saved_error= sl->join->error; + if (sl->tvc) + sl->tvc->exec(sl); + else + { + sl->join->exec(); + saved_error= sl->join->error; + } if (!saved_error) { examined_rows+= thd->get_examined_row_count(); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index b4a0e52f693..e0e09b0b3c4 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1782,7 +1782,9 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); table_primary_ident table_primary_derived select_derived derived_table_list select_derived_union + derived_simple_table derived_query_specification + derived_table_value_constructor %type date_time_type; %type interval @@ -8546,6 +8548,15 @@ select_paren_view: /* The equivalent of select_paren for nested queries. */ select_paren_derived: + { + Lex->current_select->set_braces(true); + } + table_value_constructor + { + DBUG_ASSERT(Lex->current_select->braces); + $$= Lex->current_select->master_unit()->first_select(); + } + | { Lex->current_select->set_braces(true); } @@ -11250,9 +11261,9 @@ select_derived_union: } } union_list_derived_part2 - | derived_query_specification opt_select_lock_type - | derived_query_specification order_or_limit opt_select_lock_type - | derived_query_specification opt_select_lock_type union_list_derived + | derived_simple_table opt_select_lock_type + | derived_simple_table order_or_limit opt_select_lock_type + | derived_simple_table opt_select_lock_type union_list_derived ; union_list_derived_part2: @@ -11307,6 +11318,10 @@ select_derived: } ; +derived_simple_table: + derived_query_specification { $$= $1; } + | derived_table_value_constructor { $$= $1; } + ; /* Similar to query_specification, but for derived tables. Example: the inner parenthesized SELECT in this query: @@ -11321,6 +11336,41 @@ derived_query_specification: } ; +derived_table_value_constructor: + VALUES + { + LEX *lex=Lex; + lex->field_list.empty(); + lex->many_values.empty(); + lex->insert_list=0; + } + values_list + { + LEX *lex= Lex; + lex->derived_tables|= DERIVED_SUBQUERY; + if (!lex->expr_allows_subselect || + lex->sql_command == (int)SQLCOM_PURGE) + { + thd->parse_error(); + MYSQL_YYABORT; + } + if (lex->current_select->linkage == GLOBAL_OPTIONS_TYPE || + mysql_new_select(lex, 1, NULL)) + MYSQL_YYABORT; + mysql_init_select(lex); + lex->current_select->linkage= DERIVED_TABLE_TYPE; + + if (!(lex->current_select->tvc= + new (lex->thd->mem_root) table_value_constr(lex->many_values, + lex->current_select, + lex->current_select->options))) + MYSQL_YYABORT; + lex->many_values.empty(); + $$= NULL; + } + ; + + select_derived2: { LEX *lex= Lex; @@ -16273,13 +16323,22 @@ simple_table: ; table_value_constructor: - VALUES values_list + VALUES + { + LEX *lex=Lex; + lex->field_list.empty(); + lex->many_values.empty(); + lex->insert_list=0; + } + values_list { LEX *lex=Lex; - $$= Lex->current_select; + $$= lex->current_select; mysql_init_select(Lex); - table_value_constr tvc(lex->many_values); - $$->tvc= &tvc; + if (!($$->tvc= + new (lex->thd->mem_root) table_value_constr(lex->many_values, $$, $$->options))) + MYSQL_YYABORT; + lex->many_values.empty(); } ; diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index c2a5e183187..aadf47235c4 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -5550,4 +5550,11 @@ static Sys_var_mybool Sys_session_track_state_change( ON_CHECK(0), ON_UPDATE(update_session_track_state_change)); +static Sys_var_ulong Sys_in_subquery_conversion_threshold( + "in_subquery_conversion_threshold", + "The minimum number of scalar elements in the value list of" + "IN predicate that triggers its conversion to IN subquery", + SESSION_VAR(in_subquery_conversion_threshold), CMD_LINE(OPT_ARG), + VALID_RANGE(0, ULONG_MAX), DEFAULT(1000), BLOCK_SIZE(1)); + #endif //EMBEDDED_LIBRARY diff --git a/sql/table.h b/sql/table.h index 478b65efec5..b9606145e2a 100644 --- a/sql/table.h +++ b/sql/table.h @@ -1930,6 +1930,7 @@ struct TABLE_LIST */ st_select_lex_unit *derived; /* SELECT_LEX_UNIT of derived table */ With_element *with; /* With element defining this table (if any) */ + bool is_for_tvc; /* If specification of this table contains tvc*/ /* Bitmap of the defining with element */ table_map with_internal_reference_map; bool block_handle_derived; From 91149bbd82c1c8a1c741893a4b54e8c305ce4ebd Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Tue, 29 Aug 2017 16:58:32 +0200 Subject: [PATCH 006/138] Mistakes corrected, new error messages added --- mysql-test/r/opt_tvc.result | 8 ++++---- mysql-test/r/table_value_constr.result | 3 ++- sql/item_subselect.cc | 7 +++++++ sql/share/errmsg-utf8.txt | 8 ++++++-- sql/sql_derived.cc | 3 +++ sql/sql_select.cc | 3 +-- sql/sql_tvc.cc | 11 +++++++++-- 7 files changed, 32 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result index a3c71faff46..59f005ef510 100644 --- a/mysql-test/r/opt_tvc.result +++ b/mysql-test/r/opt_tvc.result @@ -116,13 +116,13 @@ from (values (1),(5)) as tvc_1 id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 Using where 4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used 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` semi join ((values (1),(2)) `tvc_0`) semi join ((values (1),(5)) `tvc_1`) where `test`.`t1`.`b` = `tvc_1`.`1` +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`) semi join ((values (1),(5)) `tvc_1`) where `tvc_0`.`1` = `test`.`t1`.`a` and `test`.`t1`.`b` = `tvc_1`.`1` # subquery with IN-predicate select * from t1 where a in @@ -463,10 +463,10 @@ group by b id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 12 100.00 2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort -2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 +2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 Using where 3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: -Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where 1 group by `test`.`t1`.`b`) `dr_table` +Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where `tvc_0`.`3` = `test`.`t1`.`b` group by `test`.`t1`.`b`) `dr_table` drop table t1, t2; set @@in_subquery_conversion_threshold= default; diff --git a/mysql-test/r/table_value_constr.result b/mysql-test/r/table_value_constr.result index 411edc53168..f8161edf708 100644 --- a/mysql-test/r/table_value_constr.result +++ b/mysql-test/r/table_value_constr.result @@ -1,5 +1,6 @@ create table t1 (a int, b int); -insert into t1 values (1,2),(4,6),(9,7),(1,1),(2,5),(7,8); +insert into t1 values (1,2),(4,6),(9,7), +(1,1),(2,5),(7,8); # just VALUES values (1,2); 1 2 diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 09fbf3e239c..e57239bef4e 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -265,6 +265,13 @@ bool Item_subselect::fix_fields(THD *thd_param, Item **ref) if (check_stack_overrun(thd, STACK_MIN_SIZE, (uchar*)&res)) return TRUE; + if (unit->first_select() && + unit->first_select()->tvc) + { + my_error(ER_NO_TVC_IN_SUBQUERY, MYF(0)); + res= 1; + goto end; + } if (!(res= engine->prepare(thd))) { diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 1a547e44820..c8cf51a5297 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7490,5 +7490,9 @@ ER_WRONG_INSERT_INTO_SEQUENCE eng "Wrong INSERT into a SEQUENCE. One can only do single table INSERT into a squence object (like with mysqldump). If you want to change the SEQUENCE, use ALTER SEQUENCE instead." ER_SP_STACK_TRACE eng "At line %u in %s" -ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR - eng "The used TABLE VALUE CONSTRUCTOR has a different number of columns" +ER_WRONG_NUMBER_OF_VALUES_IN_TVC + eng "The used table value constructor has a different number of values" +ER_UNKNOWN_VALUE_IN_TVC + eng "Unknown value '%d' in table values constructor definition" +ER_NO_TVC_IN_SUBQUERY + eng "The usage of table value constructor as specification of subselect isn't implemented yet" \ No newline at end of file diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index cd8540eb072..da96f5d425b 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -646,6 +646,9 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) SELECT_LEX *first_select= unit->first_select(); + if (first_select->tvc) + derived->is_for_tvc= true; + if (derived->is_recursive_with_table() && !derived->is_with_table_recursive_reference() && !derived->with->rec_result && derived->with->get_sq_rec_ref()) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ab87bc00c8c..e0e2a778e90 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -347,8 +347,7 @@ bool handle_select(THD *thd, LEX *lex, select_result *result, MYSQL_SELECT_START(thd->query()); if (select_lex->master_unit()->is_unit_op() || - select_lex->master_unit()->fake_select_lex || - select_lex->tvc) + select_lex->master_unit()->fake_select_lex) res= mysql_union(thd, lex, result, &lex->unit, setup_tables_done_option); else { diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index e9476254f9e..28d748877fd 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -46,13 +46,20 @@ bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, if (first_list_el_count != lst->elements) { - my_message(ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR, - ER_THD(thd_arg, ER_WRONG_NUMBER_OF_COLUMNS_IN_TABLE_VALUE_CONSTRUCTOR), + my_message(ER_WRONG_NUMBER_OF_VALUES_IN_TVC, + ER_THD(thd_arg, ER_WRONG_NUMBER_OF_VALUES_IN_TVC), MYF(0)); DBUG_RETURN(true); } for (uint pos= 0; (item=it++); pos++) { + if (item->type() == Item::FIELD_ITEM) + { + my_error(ER_UNKNOWN_VALUE_IN_TVC, MYF(0), + ((Item_field *)item)->full_name(), + MYF(0)); + DBUG_RETURN(true); + } const Type_handler *item_type_handler= item->real_type_handler(); if (first) holders[pos].set_handler(item_type_handler); From a5a01dbb088a100cd6d72838815f33e1e6bd409a Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Tue, 29 Aug 2017 21:03:15 +0200 Subject: [PATCH 007/138] Mistakes corrected. Now all tests in opt_tvc.test file work correctly --- mysql-test/r/opt_tvc.result | 16 ++++++++-------- sql/sql_derived.cc | 3 --- sql/sql_select.cc | 13 ++++--------- sql/sql_tvc.cc | 1 - sql/table.h | 1 - 5 files changed, 12 insertions(+), 22 deletions(-) diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result index 59f005ef510..feaafabcbf2 100644 --- a/mysql-test/r/opt_tvc.result +++ b/mysql-test/r/opt_tvc.result @@ -95,13 +95,13 @@ b in (1,5); id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used 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` semi join ((values (1),(2)) `tvc_0`) semi join ((values (1),(5)) `tvc_1`) where `tvc_0`.`1` = `test`.`t1`.`a` and `test`.`t1`.`b` = `tvc_1`.`1` +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`) semi join ((values (1),(5)) `tvc_1`) where `test`.`t1`.`b` = `tvc_1`.`1` explain extended select * from t1 where a in ( @@ -116,13 +116,13 @@ from (values (1),(5)) as tvc_1 id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 4 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 5 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used 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` semi join ((values (1),(2)) `tvc_0`) semi join ((values (1),(5)) `tvc_1`) where `tvc_0`.`1` = `test`.`t1`.`a` and `test`.`t1`.`b` = `tvc_1`.`1` +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`) semi join ((values (1),(5)) `tvc_1`) where `test`.`t1`.`b` = `tvc_1`.`1` # subquery with IN-predicate select * from t1 where a in @@ -443,11 +443,11 @@ group by b id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 12 100.00 2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort -2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: -Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where `tvc_0`.`3` = `test`.`t1`.`b` group by `test`.`t1`.`b`) `dr_table` +Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where 1 group by `test`.`t1`.`b`) `dr_table` explain extended select * from ( select max(a),b @@ -463,10 +463,10 @@ group by b id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 12 100.00 2 DERIVED t1 ALL NULL NULL NULL NULL 6 100.00 Using temporary; Using filesort -2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 Using where +2 DERIVED eq_ref distinct_key distinct_key 4 func 1 100.00 3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: -Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where `tvc_0`.`3` = `test`.`t1`.`b` group by `test`.`t1`.`b`) `dr_table` +Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where 1 group by `test`.`t1`.`b`) `dr_table` drop table t1, t2; set @@in_subquery_conversion_threshold= default; diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index da96f5d425b..cd8540eb072 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -646,9 +646,6 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) SELECT_LEX *first_select= unit->first_select(); - if (first_select->tvc) - derived->is_for_tvc= true; - if (derived->is_recursive_with_table() && !derived->is_with_table_recursive_reference() && !derived->with->rec_result && derived->with->get_sq_rec_ref()) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index e0e2a778e90..2acc3ea39b4 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13633,9 +13633,8 @@ static int compare_fields_by_table_order(Item *field1, static TABLE_LIST* embedding_sjm(Item *item) { Item_field *item_field= (Item_field *) (item->real_item()); - TABLE_LIST *tbl= item_field->field->table->pos_in_table_list; - TABLE_LIST *nest= tbl->embedding; - if (nest && nest->sj_mat_info && nest->sj_mat_info->is_used && !tbl->is_for_tvc) + TABLE_LIST *nest= item_field->field->table->pos_in_table_list->embedding; + if (nest && nest->sj_mat_info && nest->sj_mat_info->is_used) return nest; else return NULL; @@ -13712,7 +13711,6 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, Item *head; TABLE_LIST *current_sjm= NULL; Item *current_sjm_head= NULL; - bool force_producing_equality= false; DBUG_ASSERT(!cond || cond->type() == Item::INT_ITEM || @@ -13734,8 +13732,6 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, TABLE_LIST *emb_nest; head= item_equal->get_first(NO_PARTICULAR_TAB, NULL); it++; - if (((Item_field *)(head->real_item()))->field->table->pos_in_table_list->is_for_tvc) - force_producing_equality= true; if ((emb_nest= embedding_sjm(head))) { current_sjm= emb_nest; @@ -13803,7 +13799,7 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, produce_equality= FALSE; } - if (produce_equality || force_producing_equality) + if (produce_equality) { if (eq_item && eq_list.push_back(eq_item, thd->mem_root)) return 0; @@ -13818,8 +13814,7 @@ Item *eliminate_item_equal(THD *thd, COND *cond, COND_EQUAL *upper_levels, equals on top level, or the constant. */ Item *head_item= (!item_const && current_sjm && - current_sjm_head != field_item && - !force_producing_equality) ? current_sjm_head: head; + current_sjm_head != field_item) ? current_sjm_head: head; Item *head_real_item= head_item->real_item(); if (head_real_item->type() == Item::FIELD_ITEM) head_item= head_real_item; diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 28d748877fd..263dc24a9b0 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -466,7 +466,6 @@ st_select_lex *make_new_subselect_for_tvc(THD *thd_arg, TL_READ, MDL_SHARED_READ))) goto err; - new_tab->is_for_tvc= true; //shows that this derived table is defined by TVC sel->add_joined_table(new_tab); new_tab->select_lex->add_where_field(new_tab->derived->first_select()); diff --git a/sql/table.h b/sql/table.h index b9606145e2a..478b65efec5 100644 --- a/sql/table.h +++ b/sql/table.h @@ -1930,7 +1930,6 @@ struct TABLE_LIST */ st_select_lex_unit *derived; /* SELECT_LEX_UNIT of derived table */ With_element *with; /* With element defining this table (if any) */ - bool is_for_tvc; /* If specification of this table contains tvc*/ /* Bitmap of the defining with element */ table_map with_internal_reference_map; bool block_handle_derived; From 1efa9ed8cafc48950f16593ae1d3d9850d7ae1f5 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Tue, 29 Aug 2017 21:24:05 +0200 Subject: [PATCH 008/138] Some mistakes in opt_range.cc and libmysqld/CMakeLists.txt files corrected --- libmysqld/CMakeLists.txt | 1 + sql/opt_range.cc | 2 +- 2 files changed, 2 insertions(+), 1 deletion(-) diff --git a/libmysqld/CMakeLists.txt b/libmysqld/CMakeLists.txt index 6dabc5e0192..aba4b07b1f7 100644 --- a/libmysqld/CMakeLists.txt +++ b/libmysqld/CMakeLists.txt @@ -117,6 +117,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc ../sql/ha_sequence.cc ../sql/ha_sequence.h ../sql/temporary_tables.cc ../sql/session_tracker.cc + ../sql/sql_tvc.cc ../sql/sql_tvc.h ${GEN_SOURCES} ${MYSYS_LIBWRAP_SOURCE} ) diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 284f4348080..2eb885789c4 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -7501,7 +7501,7 @@ SEL_TREE *Item_bool_func::get_full_func_mm_tree(RANGE_OPT_PARAM *param, param->current_table); #ifdef HAVE_SPATIAL Field::geometry_type sav_geom_type; - LINT_INIT(sav_geom_type); + //LINT_INIT(sav_geom_type); if (field_item->field->type() == MYSQL_TYPE_GEOMETRY) { From e70177074986d5ac1f9674d2869b9d69c83c377d Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Fri, 1 Sep 2017 19:01:06 +0200 Subject: [PATCH 009/138] Memory allocation corrected. New tests added. --- mysql-test/r/opt_tvc.result | 13 ++ sql/item_cmpfunc.cc | 7 ++ sql/sql_tvc.cc | 240 +++++++++++++++++------------------- 3 files changed, 130 insertions(+), 130 deletions(-) diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result index feaafabcbf2..b4f3c81c0c0 100644 --- a/mysql-test/r/opt_tvc.result +++ b/mysql-test/r/opt_tvc.result @@ -468,5 +468,18 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: Note 1003 /* select#1 */ select `dr_table`.`max(a)` AS `max(a)`,`dr_table`.`b` AS `b` from (/* select#2 */ select max(`test`.`t1`.`a`) AS `max(a)`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (3),(5)) `tvc_0`) where 1 group by `test`.`t1`.`b`) `dr_table` +# prepare statement +prepare stmt from "select * from t1 where a in (1,2)"; +execute stmt; +a b +1 2 +1 1 +2 5 +execute stmt; +a b +1 2 +1 1 +2 5 +deallocate prepare stmt; drop table t1, t2; set @@in_subquery_conversion_threshold= default; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index d05d1602044..d1bea30cc40 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -4330,9 +4330,16 @@ longlong Item_func_in::val_int() void Item_func_in::mark_as_condition_AND_part(TABLE_LIST *embedding) { THD *thd= current_thd; + + Query_arena *arena, backup; + arena= thd->activate_stmt_arena_if_needed(&backup); + if (can_be_transformed_in_tvc(thd)) thd->lex->current_select->in_funcs.push_back(this, thd->mem_root); + if (arena) + thd->restore_active_arena(arena, &backup); + emb_on_expr_nest= embedding; } diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 263dc24a9b0..b9fd5e2e5cd 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -372,121 +372,6 @@ void table_value_constr::print(THD *thd_arg, String *str, } -/** - @brief - Creates new SELECT defined by TVC as derived table - - @param thd_arg The context of the statement - @param values List of values that defines TVC - - @details - The method creates this SELECT statement: - - SELECT * FROM (VALUES values) AS new_tvc - - If during creation of SELECT statement some action is - unsuccesfull backup is made to the state in which system - was at the beginning of the method. - - @retval - pointer to the created SELECT statement - NULL - if creation was unsuccesfull -*/ - -st_select_lex *make_new_subselect_for_tvc(THD *thd_arg, - List *values) -{ - LEX *lex= thd_arg->lex; - Item *item; - SELECT_LEX *sel; - SELECT_LEX_UNIT *unit; - TABLE_LIST *new_tab; - Table_ident *ti; - - Query_arena backup; - Query_arena *arena= thd_arg->activate_stmt_arena_if_needed(&backup); - - char buff[6]; - LEX_CSTRING alias; - alias.length= my_snprintf(buff, sizeof(buff), - "tvc_%u", thd_arg->lex->current_select->cur_tvc); - alias.str= thd_arg->strmake(buff, alias.length); - if (!alias.str) - goto err; - - /* - Creation of SELECT statement: SELECT * FROM ... - */ - - if (mysql_new_select(lex, 1, NULL)) - goto err; - - mysql_init_select(lex); - lex->current_select->parsing_place= SELECT_LIST; - - item= new (thd_arg->mem_root) - Item_field(thd_arg, &lex->current_select->context, - NULL, NULL, &star_clex_str); - if (item == NULL) - goto err; - if (add_item_to_list(thd_arg, item)) - goto err; - (lex->current_select->with_wild)++; - - /* - Creation of TVC as derived table - */ - - lex->derived_tables|= DERIVED_SUBQUERY; - if (mysql_new_select(lex, 1, NULL)) - goto err; - - mysql_init_select(lex); - - sel= lex->current_select; - unit= sel->master_unit(); - sel->linkage= DERIVED_TABLE_TYPE; - - if (!(sel->tvc= - new (thd_arg->mem_root) - table_value_constr(*values, - sel, - sel->options))) - goto err; - - lex->check_automatic_up(UNSPECIFIED_TYPE); - lex->current_select= sel= unit->outer_select(); - - ti= new (thd_arg->mem_root) Table_ident(unit); - if (ti == NULL) - goto err; - - if (!(new_tab= sel->add_table_to_list(thd_arg, - ti, &alias, 0, - TL_READ, MDL_SHARED_READ))) - goto err; - - sel->add_joined_table(new_tab); - - new_tab->select_lex->add_where_field(new_tab->derived->first_select()); - - sel->context.table_list= - sel->context.first_name_resolution_table= - sel->table_list.first; - - sel->where= 0; - sel->set_braces(false); - unit->with_clause= 0; - - return sel; - -err: - if (arena) - thd_arg->restore_active_arena(arena, &backup); - return NULL; -} - - /** @brief Transforms IN-predicate in IN-subselect @@ -512,7 +397,25 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, uchar *arg) { SELECT_LEX *old_select= thd->lex->current_select; + List values; + Item *item; + SELECT_LEX *sel; + SELECT_LEX_UNIT *unit; + TABLE_LIST *new_tab; + Table_ident *ti; + Item_in_subselect *in_subs; + + Query_arena backup; + Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); + LEX *lex= thd->lex; + + char buff[6]; + LEX_CSTRING alias; + + /* + Creation of values list of lists + */ bool list_of_lists= false; if (args[1]->type() == Item::ROW_ITEM) @@ -535,26 +438,100 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, values.push_back(new_value, thd->mem_root); } - st_select_lex *new_subselect= - make_new_subselect_for_tvc(thd, &values); + /* + Creation of TVC name + */ + alias.length= my_snprintf(buff, sizeof(buff), + "tvc_%u", old_select->cur_tvc); + alias.str= thd->strmake(buff, alias.length); + if (!alias.str) + goto err; - if (new_subselect) - { - new_subselect->parsing_place= old_select->parsing_place; - new_subselect->table_list.first->derived_type= 10; + /* + Creation of SELECT statement: SELECT * FROM ... + */ - Item_in_subselect *in_subs= new (thd->mem_root) Item_in_subselect - (thd, args[0], new_subselect); - thd->lex->derived_tables |= DERIVED_SUBQUERY; - in_subs->emb_on_expr_nest= emb_on_expr_nest; - in_subs->fix_fields(thd, (Item **)&in_subs); + if (mysql_new_select(lex, 1, NULL)) + goto err; - old_select->cur_tvc++; - thd->lex->current_select= old_select; - return in_subs; - } + mysql_init_select(lex); + lex->current_select->parsing_place= SELECT_LIST; + item= new (thd->mem_root) Item_field(thd, &lex->current_select->context, + NULL, NULL, &star_clex_str); + if (item == NULL) + goto err; + if (add_item_to_list(thd, item)) + goto err; + (lex->current_select->with_wild)++; + + /* + Creation of TVC as derived table + */ + + lex->derived_tables|= DERIVED_SUBQUERY; + if (mysql_new_select(lex, 1, NULL)) + goto err; + + mysql_init_select(lex); + + sel= lex->current_select; + unit= sel->master_unit(); + sel->linkage= DERIVED_TABLE_TYPE; + + if (!(sel->tvc= + new (thd->mem_root) + table_value_constr(values, + sel, + sel->options))) + goto err; + + lex->check_automatic_up(UNSPECIFIED_TYPE); + lex->current_select= sel= unit->outer_select(); + + ti= new (thd->mem_root) Table_ident(unit); + if (ti == NULL) + goto err; + + if (!(new_tab= sel->add_table_to_list(thd, + ti, &alias, 0, + TL_READ, MDL_SHARED_READ))) + goto err; + + sel->add_joined_table(new_tab); + + new_tab->select_lex->add_where_field(new_tab->derived->first_select()); + + sel->context.table_list= + sel->context.first_name_resolution_table= + sel->table_list.first; + + sel->where= 0; + sel->set_braces(false); + unit->with_clause= 0; + + if (!sel) + goto err; + + sel->parsing_place= old_select->parsing_place; + sel->table_list.first->derived_type= 10; + + in_subs= new (thd->mem_root) Item_in_subselect(thd, args[0], sel); + thd->lex->derived_tables |= DERIVED_SUBQUERY; + in_subs->emb_on_expr_nest= emb_on_expr_nest; + + old_select->cur_tvc++; thd->lex->current_select= old_select; + + if (arena) + thd->restore_active_arena(arena, &backup); + + in_subs->fix_fields(thd, (Item **)&in_subs); + return in_subs; + +err: + if (arena) + thd->restore_active_arena(arena, &backup); return this; } @@ -633,9 +610,12 @@ bool JOIN::transform_in_predicate_into_tvc(THD *thd_arg) table->on_expr->transform(thd_arg, &Item::in_predicate_to_in_subs_transformer, (uchar*) 0); + table->prep_on_expr= table->on_expr ? + table->on_expr->copy_andor_structure(thd) : 0; } } } + select_lex->in_funcs.empty(); select_lex->parsing_place= old_parsing_place; thd_arg->lex->current_select= old_select; return false; From d76f74d46c03a5560fa817b4481bc6e3f5dfc181 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Fri, 1 Sep 2017 19:18:50 +0200 Subject: [PATCH 010/138] Remarked opt_tvc.test added. --- mysql-test/t/opt_tvc.test | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/mysql-test/t/opt_tvc.test b/mysql-test/t/opt_tvc.test index fe5110ece51..8e2d1697a42 100644 --- a/mysql-test/t/opt_tvc.test +++ b/mysql-test/t/opt_tvc.test @@ -232,5 +232,12 @@ eval $optimized_query; eval explain extended $query; eval explain extended $optimized_query; +--echo # prepare statement + +prepare stmt from "select * from t1 where a in (1,2)"; +execute stmt; +execute stmt; +deallocate prepare stmt; + drop table t1, t2; set @@in_subquery_conversion_threshold= default; From 6bce8e14227bd30a24d8f4abe9417c4be73d83f2 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Sat, 2 Sep 2017 23:19:20 +0200 Subject: [PATCH 011/138] Post review changes for the optimization of IN predicates into IN subqueries. --- mysql-test/r/opt_tvc.result | 96 +++++++++--- mysql-test/t/opt_tvc.test | 49 +++++- sql/item_cmpfunc.cc | 5 +- sql/item_cmpfunc.h | 4 +- sql/opt_subselect.cc | 2 +- sql/sql_lex.cc | 2 +- sql/sql_lex.h | 2 +- sql/sql_select.cc | 2 +- sql/sql_select.h | 2 +- sql/sql_tvc.cc | 297 +++++++++++++++++++++--------------- 10 files changed, 310 insertions(+), 151 deletions(-) diff --git a/mysql-test/r/opt_tvc.result b/mysql-test/r/opt_tvc.result index b4f3c81c0c0..780ed6aed71 100644 --- a/mysql-test/r/opt_tvc.result +++ b/mysql-test/r/opt_tvc.result @@ -6,29 +6,26 @@ create table t2 (a int, b int, c int); insert into t2 values (1,2,3), (5,1,2), (4,3,7), (8,9,0), (10,7,1), (5,5,1); +create table t3 (a int, b varchar(16), index idx(a)); +insert into t3 values +(1, "abc"), (3, "egh"), (8, "axxx"), (10, "abc"), +(2, "ccw"), (8, "wqqe"), (7, "au"), (9, "waa"), +(3, "rass"), (9, "ert"), (9, "lok"), (8, "aww"), +(1, "todd"), (3, "rew"), (8, "aww"), (3, "sw"), +(11, "llk"), (7, "rbw"), (1, "sm"), (2, "jyp"), +(4, "yq"), (5, "pled"), (12, "ligin"), (12, "toww"), +(6, "mxm"), (15, "wanone"), (9, "sunqq"), (2, "abe"); # optimization is not used select * from t1 where a in (1,2); a b 1 2 1 1 2 5 -explain select * from t1 where a in (1,2); -id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using where -explain format=json select * from t1 where a in (1,2); -EXPLAIN -{ - "query_block": { - "select_id": 1, - "table": { - "table_name": "t1", - "access_type": "ALL", - "rows": 6, - "filtered": 100, - "attached_condition": "t1.a in (1,2)" - } - } -} +explain extended select * from t1 where a in (1,2); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 6 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where `test`.`t1`.`a` in (1,2) # set minimum number of values in VALUEs list when optimization works to 2 set @@in_subquery_conversion_threshold= 2; # single IN-predicate in WHERE-part @@ -481,5 +478,68 @@ a b 1 1 2 5 deallocate prepare stmt; -drop table t1, t2; +# use inside out access from tvc rows +set @@in_subquery_conversion_threshold= default; +select * from t3 where a in (1,4,10); +a b +1 abc +1 todd +1 sm +4 yq +10 abc +explain extended select * from t3 where a in (1,4,10); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t3 range idx idx 5 NULL 5 100.00 Using index condition +Warnings: +Note 1003 select `test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t3` where `test`.`t3`.`a` in (1,4,10) +set @@in_subquery_conversion_threshold= 2; +select * from t3 where a in (1,4,10); +a b +1 abc +1 todd +1 sm +4 yq +10 abc +explain extended select * from t3 where a in (1,4,10); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t3 ref idx idx 5 tvc_0.1 3 100.00 +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 /* select#1 */ select `test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t3` semi join ((values (1),(4),(10)) `tvc_0`) where `test`.`t3`.`a` = `tvc_0`.`1` +# use vectors in IN predeicate +set @@in_subquery_conversion_threshold= 4; +select * from t1 where (a,b) in ((1,2),(3,4)); +a b +1 2 +explain extended select * from t1 where (a,b) in ((1,2),(3,4)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` semi join ((values (1,2),(3,4)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` and `test`.`t1`.`b` = `tvc_0`.`2` +set @@in_subquery_conversion_threshold= 2; +# trasformation works for the one IN predicate and doesn't work for the other +set @@in_subquery_conversion_threshold= 5; +select * from t2 +where (a,b) in ((1,2),(8,9)) and +(a,c) in ((1,3),(8,0),(5,1)); +a b c +1 2 3 +8 9 0 +explain extended select * from t2 +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 ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t2 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` = `tvc_0`.`1` and `test`.`t2`.`c` = `tvc_0`.`3` and (`tvc_0`.`1`,`test`.`t2`.`b`) in (((1,2)),((8,9))) +set @@in_subquery_conversion_threshold= 2; +drop table t1, t2, t3; set @@in_subquery_conversion_threshold= default; diff --git a/mysql-test/t/opt_tvc.test b/mysql-test/t/opt_tvc.test index 8e2d1697a42..d04c101e87a 100644 --- a/mysql-test/t/opt_tvc.test +++ b/mysql-test/t/opt_tvc.test @@ -10,12 +10,21 @@ insert into t2 values (1,2,3), (5,1,2), (4,3,7), (8,9,0), (10,7,1), (5,5,1); +create table t3 (a int, b varchar(16), index idx(a)); +insert into t3 values + (1, "abc"), (3, "egh"), (8, "axxx"), (10, "abc"), + (2, "ccw"), (8, "wqqe"), (7, "au"), (9, "waa"), + (3, "rass"), (9, "ert"), (9, "lok"), (8, "aww"), + (1, "todd"), (3, "rew"), (8, "aww"), (3, "sw"), + (11, "llk"), (7, "rbw"), (1, "sm"), (2, "jyp"), + (4, "yq"), (5, "pled"), (12, "ligin"), (12, "toww"), + (6, "mxm"), (15, "wanone"), (9, "sunqq"), (2, "abe"); + --echo # optimization is not used let $query= select * from t1 where a in (1,2); eval $query; -eval explain $query; -eval explain format=json $query; +eval explain extended $query; --echo # set minimum number of values in VALUEs list when optimization works to 2 @@ -239,5 +248,39 @@ execute stmt; execute stmt; deallocate prepare stmt; -drop table t1, t2; +--echo # use inside out access from tvc rows + +let $query= select * from t3 where a in (1,4,10); +set @@in_subquery_conversion_threshold= default; +eval $query; +eval explain extended $query; +set @@in_subquery_conversion_threshold= 2; +eval $query; +eval explain extended $query; + +--echo # use vectors in IN predeicate + +set @@in_subquery_conversion_threshold= 4; + +let $query= +select * from t1 where (a,b) in ((1,2),(3,4)); + +eval $query; +eval explain extended $query; +set @@in_subquery_conversion_threshold= 2; + +--echo # trasformation works for the one IN predicate and doesn't work for the other + +set @@in_subquery_conversion_threshold= 5; + +let $query= +select * from t2 +where (a,b) in ((1,2),(8,9)) and + (a,c) in ((1,3),(8,0),(5,1)); + +eval $query; +eval explain extended $query; +set @@in_subquery_conversion_threshold= 2; + +drop table t1, t2, t3; set @@in_subquery_conversion_threshold= default; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index d1bea30cc40..359c27af0c7 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -4334,8 +4334,11 @@ void Item_func_in::mark_as_condition_AND_part(TABLE_LIST *embedding) Query_arena *arena, backup; arena= thd->activate_stmt_arena_if_needed(&backup); - if (can_be_transformed_in_tvc(thd)) + if (to_be_transformed_into_in_subq(thd)) + { + transform_into_subq= true; thd->lex->current_select->in_funcs.push_back(this, thd->mem_root); + } if (arena) thd->restore_active_arena(arena, &backup); diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index a41da00da2c..22d308572d5 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -2128,6 +2128,7 @@ class Item_func_in :public Item_func_opt_neg, protected: SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Field *field, Item *value); + bool transform_into_subq; public: /// An array of values, created when the bisection lookup method is used in_vector *array; @@ -2244,7 +2245,8 @@ public: return clone; } void mark_as_condition_AND_part(TABLE_LIST *embedding); - bool can_be_transformed_in_tvc(THD *thd); + bool to_be_transformed_into_in_subq(THD *thd); + bool create_value_list_for_tvc(THD *thd, List< List > *values); Item *in_predicate_to_in_subs_transformer(THD *thd, uchar *arg); }; diff --git a/sql/opt_subselect.cc b/sql/opt_subselect.cc index f608e826f9b..211f8ac53c7 100644 --- a/sql/opt_subselect.cc +++ b/sql/opt_subselect.cc @@ -1047,7 +1047,7 @@ bool convert_join_subqueries_to_semijoins(JOIN *join) DBUG_RETURN(1); if (subq_sel->handle_derived(thd->lex, DT_MERGE)) DBUG_RETURN(TRUE); - if (subq_sel->join->transform_in_predicate_into_tvc(thd)) + if (subq_sel->join->transform_in_predicates_into_in_subq(thd)) DBUG_RETURN(TRUE); subq_sel->update_used_tables(); } diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 4c59b666acb..08ad0245fb4 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -2265,7 +2265,7 @@ void st_select_lex::init_select() lock_type= TL_READ_DEFAULT; tvc= 0; in_funcs.empty(); - cur_tvc= 0; + curr_tvc_name= 0; } /* diff --git a/sql/sql_lex.h b/sql/sql_lex.h index b607a3c479c..ef5b6108044 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -874,7 +874,7 @@ public: transformation of IN-predicate into IN-subquery for this st_select_lex. */ - uint cur_tvc; + uint curr_tvc_name; /* Needed to correctly generate 'PRIMARY' or 'SIMPLE' for select_type column diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 2acc3ea39b4..870c40d5b16 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1189,7 +1189,7 @@ JOIN::optimize_inner() } if (select_lex->first_cond_optimization && - transform_in_predicate_into_tvc(thd)) + transform_in_predicates_into_in_subq(thd)) DBUG_RETURN(1); // Update used tables after all handling derived table procedures diff --git a/sql/sql_select.h b/sql/sql_select.h index ad15ce5eb2c..6e737a9b933 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1648,7 +1648,7 @@ public: bool need_order, bool distinct, const char *message); JOIN_TAB *first_breadth_first_tab() { return join_tab; } - bool transform_in_predicate_into_tvc(THD *thd_arg); + bool transform_in_predicates_into_in_subq(THD *thd); private: /** Create a temporary table to be used for processing DISTINCT/ORDER diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index b9fd5e2e5cd..1c0353dca61 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -374,164 +374,211 @@ void table_value_constr::print(THD *thd_arg, String *str, /** @brief - Transforms IN-predicate in IN-subselect + Create list of lists for TVC from the list of this IN predicate - @param thd_arg The context of the statement - @param arg Argument is 0 in this context + @param thd The context of the statement + @param values TVC list of values @details - The method creates this SELECT statement: + The method uses the list of values of this IN predicate to build + an equivalent list of values that can be used in TVC. - SELECT * FROM (VALUES values) AS new_tvc + E.g.: - If during creation of SELECT statement some action is - unsuccesfull backup is made to the state in which system - was at the beginning of the procedure. + = 5,2,7 + = (5),(2),(7) + + = (5,2),(7,1) + = (5,2),(7,1) @retval - pointer to the created SELECT statement - NULL - if creation was unsuccesfull + false if the method succeeds + true otherwise +*/ + +bool Item_func_in::create_value_list_for_tvc(THD *thd, + List< List > *values) +{ + bool is_list_of_rows= args[1]->type() == Item::ROW_ITEM; + + for (uint i=1; i < arg_count; i++) + { + List *tvc_value; + if (!(tvc_value= new (thd->mem_root) List())) + return true; + + if (is_list_of_rows) + { + Item_row *row_list= (Item_row *)(args[i]); + + for (uint j=0; j < row_list->cols(); j++) + { + if (tvc_value->push_back(row_list->element_index(j), + thd->mem_root)) + return true; + } + } + else if (tvc_value->push_back(args[i])) + return true; + + if (values->push_back(tvc_value, thd->mem_root)) + return true; + } + return false; +} + + +static bool create_tvc_name(THD *thd, st_select_lex *parent_select, + LEX_CSTRING *alias) +{ + char buff[6]; + + alias->length= my_snprintf(buff, sizeof(buff), + "tvc_%u", parent_select->curr_tvc_name); + alias->str= thd->strmake(buff, alias->length); + if (!alias->str) + return true; + + return false; +} + +/** + @brief + Transform IN predicate into IN subquery + + @param thd The context of the statement + @param arg Not used + + @details + The method transforms this IN predicate into in equivalent IN subquery: + + IN () + => + IN (SELECT * FROM (VALUES ) AS tvc_#) + + E.g.: + + = 5,2,7 + = (5),(2),(7) + + = (5,2),(7,1) + = (5,2),(7,1) + + If the transformation succeeds the method returns the result IN subquery, + otherwise this IN predicate is returned. + + @retval + pointer to the result of transformation if succeeded + pointer to this IN predicate otherwise */ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, uchar *arg) { - SELECT_LEX *old_select= thd->lex->current_select; + if (!transform_into_subq) + return this; + + transform_into_subq= false; List values; - Item *item; - SELECT_LEX *sel; - SELECT_LEX_UNIT *unit; - TABLE_LIST *new_tab; - Table_ident *ti; - Item_in_subselect *in_subs; + + LEX *lex= thd->lex; + /* SELECT_LEX object where the transformation is performed */ + SELECT_LEX *parent_select= lex->current_select; + uint8 save_derived_tables= lex->derived_tables; Query_arena backup; Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); - LEX *lex= thd->lex; - - char buff[6]; - LEX_CSTRING alias; /* - Creation of values list of lists + Create SELECT_LEX of the subquery SQ used in the result of transformation */ - bool list_of_lists= false; - - if (args[1]->type() == Item::ROW_ITEM) - list_of_lists= true; - - for (uint i=1; i < arg_count; i++) - { - List *new_value= new (thd->mem_root) List(); - - if (list_of_lists) - { - Item_row *in_list= (Item_row *)(args[i]); - - for (uint j=0; j < in_list->cols(); i++) - new_value->push_back(in_list->element_index(j), thd->mem_root); - } - else - new_value->push_back(args[i]); - - values.push_back(new_value, thd->mem_root); - } - - /* - Creation of TVC name - */ - alias.length= my_snprintf(buff, sizeof(buff), - "tvc_%u", old_select->cur_tvc); - alias.str= thd->strmake(buff, alias.length); - if (!alias.str) - goto err; - - /* - Creation of SELECT statement: SELECT * FROM ... - */ - if (mysql_new_select(lex, 1, NULL)) goto err; - mysql_init_select(lex); - lex->current_select->parsing_place= SELECT_LIST; - - item= new (thd->mem_root) Item_field(thd, &lex->current_select->context, + /* Create item list as '*' for the subquery SQ */ + Item *item; + SELECT_LEX *sq_select; // select for IN subquery; + sq_select= lex->current_select; + sq_select->parsing_place= SELECT_LIST; + item= new (thd->mem_root) Item_field(thd, &sq_select->context, NULL, NULL, &star_clex_str); - if (item == NULL) + if (item == NULL || add_item_to_list(thd, item)) goto err; - if (add_item_to_list(thd, item)) - goto err; - (lex->current_select->with_wild)++; - + (sq_select->with_wild)++; /* - Creation of TVC as derived table + Create derived table DT that will wrap TVC in the result of transformation */ - - lex->derived_tables|= DERIVED_SUBQUERY; + SELECT_LEX *tvc_select; // select for tvc + SELECT_LEX_UNIT *derived_unit; // unit for tvc_select if (mysql_new_select(lex, 1, NULL)) goto err; - mysql_init_select(lex); + tvc_select= lex->current_select; + derived_unit= tvc_select->master_unit(); + tvc_select->linkage= DERIVED_TABLE_TYPE; - sel= lex->current_select; - unit= sel->master_unit(); - sel->linkage= DERIVED_TABLE_TYPE; - - if (!(sel->tvc= + /* Create TVC used in the transformation */ + if (create_value_list_for_tvc(thd, &values)) + goto err; + if (!(tvc_select->tvc= new (thd->mem_root) table_value_constr(values, - sel, - sel->options))) + tvc_select, + tvc_select->options))) goto err; - lex->check_automatic_up(UNSPECIFIED_TYPE); - lex->current_select= sel= unit->outer_select(); + lex->current_select= sq_select; - ti= new (thd->mem_root) Table_ident(unit); - if (ti == NULL) + /* + Create the name of the wrapping derived table and + add it to the FROM list of the subquery SQ + */ + Table_ident *ti; + LEX_CSTRING alias; + TABLE_LIST *derived_tab; + if (!(ti= new (thd->mem_root) Table_ident(derived_unit)) || + create_tvc_name(thd, parent_select, &alias)) goto err; - - if (!(new_tab= sel->add_table_to_list(thd, - ti, &alias, 0, - TL_READ, MDL_SHARED_READ))) + if (!(derived_tab= + sq_select->add_table_to_list(thd, + ti, &alias, 0, + TL_READ, MDL_SHARED_READ))) goto err; + sq_select->add_joined_table(derived_tab); + sq_select->add_where_field(derived_unit->first_select()); + sq_select->context.table_list= sq_select->table_list.first; + sq_select->context.first_name_resolution_table= sq_select->table_list.first; + sq_select->table_list.first->derived_type= DTYPE_TABLE | DTYPE_MATERIALIZE; + lex->derived_tables|= DERIVED_SUBQUERY; - sel->add_joined_table(new_tab); + sq_select->where= 0; + sq_select->set_braces(false); + derived_unit->set_with_clause(0); - new_tab->select_lex->add_where_field(new_tab->derived->first_select()); - - sel->context.table_list= - sel->context.first_name_resolution_table= - sel->table_list.first; - - sel->where= 0; - sel->set_braces(false); - unit->with_clause= 0; - - if (!sel) + /* Create IN subquery predicate */ + sq_select->parsing_place= parent_select->parsing_place; + Item_in_subselect *in_subs; + if (!(in_subs= + new (thd->mem_root) Item_in_subselect(thd, args[0], sq_select))) goto err; - - sel->parsing_place= old_select->parsing_place; - sel->table_list.first->derived_type= 10; - - in_subs= new (thd->mem_root) Item_in_subselect(thd, args[0], sel); - thd->lex->derived_tables |= DERIVED_SUBQUERY; in_subs->emb_on_expr_nest= emb_on_expr_nest; - old_select->cur_tvc++; - thd->lex->current_select= old_select; - if (arena) thd->restore_active_arena(arena, &backup); + thd->lex->current_select= parent_select; - in_subs->fix_fields(thd, (Item **)&in_subs); + if (in_subs->fix_fields(thd, (Item **)&in_subs)) + goto err; + + parent_select->curr_tvc_name++; return in_subs; err: if (arena) thd->restore_active_arena(arena, &backup); + lex->derived_tables= save_derived_tables; + thd->lex->current_select= parent_select; return this; } @@ -552,9 +599,9 @@ err: false otherwise */ -bool Item_func_in::can_be_transformed_in_tvc(THD *thd) +bool Item_func_in::to_be_transformed_into_in_subq(THD *thd) { - uint opt_can_be_used= arg_count; + uint opt_can_be_used= arg_count-1; if (args[1]->type() == Item::ROW_ITEM) opt_can_be_used*= ((Item_row *)(args[1]))->cols(); @@ -567,32 +614,35 @@ bool Item_func_in::can_be_transformed_in_tvc(THD *thd) /** @brief - Calls transformer that transforms IN-predicate into IN-subquery - for this select + Transform IN predicates into IN subqueries in WHERE and ON expressions - @param thd_arg The context of the statement + @param thd The context of the statement @details - Calls in_predicate_to_in_subs_transformer - for WHERE-part and each table from join list of this SELECT + For each IN predicate from AND parts of the WHERE condition and/or + ON expressions of the SELECT for this join the method performs + the intransformation into an equivalent IN sunquery if it's needed. + + @retval + false always */ -bool JOIN::transform_in_predicate_into_tvc(THD *thd_arg) +bool JOIN::transform_in_predicates_into_in_subq(THD *thd) { if (!select_lex->in_funcs.elements) return false; - SELECT_LEX *old_select= thd_arg->lex->current_select; - enum_parsing_place old_parsing_place= select_lex->parsing_place; - - thd_arg->lex->current_select= select_lex; + SELECT_LEX *save_current_select= thd->lex->current_select; + enum_parsing_place save_parsing_place= select_lex->parsing_place; + thd->lex->current_select= select_lex; if (conds) { select_lex->parsing_place= IN_WHERE; conds= - conds->transform(thd_arg, + conds->transform(thd, &Item::in_predicate_to_in_subs_transformer, (uchar*) 0); + select_lex->prep_where= conds ? conds->copy_andor_structure(thd) : 0; select_lex->where= conds; } @@ -607,7 +657,7 @@ bool JOIN::transform_in_predicate_into_tvc(THD *thd_arg) if (table->on_expr) { table->on_expr= - table->on_expr->transform(thd_arg, + table->on_expr->transform(thd, &Item::in_predicate_to_in_subs_transformer, (uchar*) 0); table->prep_on_expr= table->on_expr ? @@ -615,8 +665,9 @@ bool JOIN::transform_in_predicate_into_tvc(THD *thd_arg) } } } + select_lex->in_funcs.empty(); - select_lex->parsing_place= old_parsing_place; - thd_arg->lex->current_select= old_select; + select_lex->parsing_place= save_parsing_place; + thd->lex->current_select= save_current_select; return false; } \ No newline at end of file From 75370a58f4e4ac90e0fe441676917468afca5576 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Mon, 4 Sep 2017 22:29:58 +0200 Subject: [PATCH 012/138] New tests on errors added. Comments corrected. Some procedures corrected. --- mysql-test/r/table_value_constr.result | 18 ++ mysql-test/t/table_value_constr.test | 21 +++ sql/item_subselect.cc | 12 +- sql/share/errmsg-utf8.txt | 6 +- sql/sql_tvc.cc | 223 ++++++++++++++++--------- 5 files changed, 190 insertions(+), 90 deletions(-) diff --git a/mysql-test/r/table_value_constr.result b/mysql-test/r/table_value_constr.result index f8161edf708..5c64085138c 100644 --- a/mysql-test/r/table_value_constr.result +++ b/mysql-test/r/table_value_constr.result @@ -1630,4 +1630,22 @@ ANALYZE } } } +# different number of values in TVC +values (1,2),(3,4,5); +ERROR HY000: The used table value constructor has a different number of values +# subquery that uses VALUES structure(s) +select * from t1 +where a in (values (1)); +ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet +select * from t1 +where a in (select 2 union values (1)); +ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet +select * from t1 +where a in (values (1) union select 2); +ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet +# illegal parameter data types in TVC +values (1,point(1,1)),(1,1); +ERROR HY000: Illegal parameter data types geometry and int for operation 'TABLE VALUE CONSTRUCTOR' +values (1,point(1,1)+1); +ERROR HY000: Illegal parameter data types geometry and int for operation '+' drop table t1; diff --git a/mysql-test/t/table_value_constr.test b/mysql-test/t/table_value_constr.test index 0021c27486c..c24cbc40137 100644 --- a/mysql-test/t/table_value_constr.test +++ b/mysql-test/t/table_value_constr.test @@ -852,4 +852,25 @@ values (3,4) union all values (1,2); +--echo # different number of values in TVC +--error ER_WRONG_NUMBER_OF_VALUES_IN_TVC +values (1,2),(3,4,5); + +--echo # subquery that uses VALUES structure(s) +--error ER_TVC_IN_SUBQUERY +select * from t1 +where a in (values (1)); +--error ER_TVC_IN_SUBQUERY +select * from t1 +where a in (select 2 union values (1)); +--error ER_TVC_IN_SUBQUERY +select * from t1 +where a in (values (1) union select 2); + +--echo # illegal parameter data types in TVC +--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION +values (1,point(1,1)),(1,1); +--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION +values (1,point(1,1)+1); + drop table t1; \ No newline at end of file diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index e57239bef4e..efa71a0e8af 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -265,12 +265,14 @@ bool Item_subselect::fix_fields(THD *thd_param, Item **ref) if (check_stack_overrun(thd, STACK_MIN_SIZE, (uchar*)&res)) return TRUE; - if (unit->first_select() && - unit->first_select()->tvc) + for (SELECT_LEX *sl= unit->first_select(); sl; sl= sl->next_select()) { - my_error(ER_NO_TVC_IN_SUBQUERY, MYF(0)); - res= 1; - goto end; + if (sl->tvc) + { + my_error(ER_TVC_IN_SUBQUERY, MYF(0)); + res= 1; + goto end; + } } if (!(res= engine->prepare(thd))) diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index c8cf51a5297..47a5478d635 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7492,7 +7492,5 @@ ER_SP_STACK_TRACE eng "At line %u in %s" ER_WRONG_NUMBER_OF_VALUES_IN_TVC eng "The used table value constructor has a different number of values" -ER_UNKNOWN_VALUE_IN_TVC - eng "Unknown value '%d' in table values constructor definition" -ER_NO_TVC_IN_SUBQUERY - eng "The usage of table value constructor as specification of subselect isn't implemented yet" \ No newline at end of file +ER_TVC_IN_SUBQUERY + eng "Table value constructor can't be used as specification of subquery isn't implemented yet" \ No newline at end of file diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 1c0353dca61..0b1dd2f4408 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -6,13 +6,51 @@ #include "sql_explain.h" #include "sql_parse.h" + +/** + @brief + Fix fields for TVC values + + @param + @param thd The context of the statement + @param li The iterator on the list of lists + + @details + Call fix_fields procedure for TVC values. + + @retval + true if an error was reported + false otherwise +*/ + +bool fix_fields_for_tvc(THD *thd, List_iterator_fast &li) +{ + DBUG_ENTER("fix_fields_for_tvc"); + List_item *lst; + li.rewind(); + + while ((lst= li++)) + { + List_iterator_fast it(*lst); + Item *item; + + while ((item= it++)) + { + if (item->fix_fields(thd, 0)) + DBUG_RETURN(true); + } + } + DBUG_RETURN(false); +} + + /** @brief Defines types of matrix columns elements where matrix rows are defined by some lists of values. @param - @param thd_arg The context of the statement + @param thd The context of the statement @param li The iterator on the list of lists @param holders The structure where types of matrix columns are stored @param first_list_el_count Count of the list values that should be. It should @@ -31,7 +69,7 @@ false otherwise */ -bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, +bool join_type_handlers_for_tvc(THD *thd, List_iterator_fast &li, Type_holder *holders, uint first_list_el_count) { DBUG_ENTER("join_type_handlers_for_tvc"); @@ -39,7 +77,7 @@ bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, li.rewind(); bool first= true; - while ((lst=li++)) + while ((lst= li++)) { List_iterator_fast it(*lst); Item *item; @@ -47,19 +85,12 @@ bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, if (first_list_el_count != lst->elements) { my_message(ER_WRONG_NUMBER_OF_VALUES_IN_TVC, - ER_THD(thd_arg, ER_WRONG_NUMBER_OF_VALUES_IN_TVC), + ER_THD(thd, ER_WRONG_NUMBER_OF_VALUES_IN_TVC), MYF(0)); DBUG_RETURN(true); } for (uint pos= 0; (item=it++); pos++) { - if (item->type() == Item::FIELD_ITEM) - { - my_error(ER_UNKNOWN_VALUE_IN_TVC, MYF(0), - ((Item_field *)item)->full_name(), - MYF(0)); - DBUG_RETURN(true); - } const Type_handler *item_type_handler= item->real_type_handler(); if (first) holders[pos].set_handler(item_type_handler); @@ -80,11 +111,11 @@ bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, /** @brief - Defines attributes of matrix columns elements where matrix rows are defined by + Define attributes of matrix columns elements where matrix rows are defined by some lists of values. @param - @param thd_arg The context of the statement + @param thd The context of the statement @param li The iterator on the list of lists @param holders The structure where names of matrix columns are stored @param count_of_lists Count of list of lists elements @@ -102,7 +133,7 @@ bool join_type_handlers_for_tvc(THD *thd_arg, List_iterator_fast &li, false otherwise */ -bool get_type_attributes_for_tvc(THD *thd_arg, +bool get_type_attributes_for_tvc(THD *thd, List_iterator_fast &li, Type_holder *holders, uint count_of_lists, uint first_list_el_count) @@ -113,11 +144,11 @@ bool get_type_attributes_for_tvc(THD *thd_arg, for (uint pos= 0; pos < first_list_el_count; pos++) { - if (holders[pos].alloc_arguments(thd_arg, count_of_lists)) + if (holders[pos].alloc_arguments(thd, count_of_lists)) DBUG_RETURN(true); } - while ((lst=li++)) + while ((lst= li++)) { List_iterator_fast it(*lst); Item *item; @@ -130,7 +161,7 @@ bool get_type_attributes_for_tvc(THD *thd_arg, for (uint pos= 0; pos < first_list_el_count; pos++) { - if (holders[pos].aggregate_attributes(thd_arg)) + if (holders[pos].aggregate_attributes(thd)) DBUG_RETURN(true); } DBUG_RETURN(false); @@ -142,10 +173,10 @@ bool get_type_attributes_for_tvc(THD *thd_arg, Prepare of TVC @param - @param thd_arg The context of the statement + @param thd The context of the statement @param sl The select where this TVC is defined @param tmp_result Structure that contains the information - about where result of the query should be sent + about where to send the result of the query @param unit_arg The union where sl is defined @details @@ -159,7 +190,7 @@ bool get_type_attributes_for_tvc(THD *thd_arg, false otherwise */ -bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, +bool table_value_constr::prepare(THD *thd, SELECT_LEX *sl, select_result *tmp_result, st_select_lex_unit *unit_arg) { @@ -170,11 +201,14 @@ bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, uint cnt= first_elem->elements; Type_holder *holders; - if (!(holders= new (thd_arg->mem_root) + if (fix_fields_for_tvc(thd, li)) + DBUG_RETURN(true); + + if (!(holders= new (thd->mem_root) Type_holder[cnt]) || - join_type_handlers_for_tvc(thd_arg, li, holders, + join_type_handlers_for_tvc(thd, li, holders, cnt) || - get_type_attributes_for_tvc(thd_arg, li, holders, + get_type_attributes_for_tvc(thd, li, holders, lists_of_values.elements, cnt)) DBUG_RETURN(true); @@ -185,17 +219,17 @@ bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, for (uint pos= 0; (item= it++); pos++) { /* Error's in 'new' will be detected after loop */ - Item_type_holder *new_holder= new (thd_arg->mem_root) - Item_type_holder(thd_arg, + Item_type_holder *new_holder= new (thd->mem_root) + Item_type_holder(thd, &item->name, holders[pos].type_handler(), &holders[pos]/*Type_all_attributes*/, holders[pos].get_maybe_null()); - new_holder->fix_fields(thd_arg, 0); + new_holder->fix_fields(thd, 0); sl->item_list.push_back(new_holder); } - if (thd_arg->is_fatal_error) + if (thd->is_fatal_error) DBUG_RETURN(true); // out of memory result= tmp_result; @@ -211,7 +245,7 @@ bool table_value_constr::prepare(THD *thd_arg, SELECT_LEX *sl, Save Query Plan Footprint */ -int table_value_constr::save_explain_data_intern(THD *thd_arg, +int table_value_constr::save_explain_data_intern(THD *thd, Explain_query *output) { const char *message= "No tables used"; @@ -227,7 +261,7 @@ int table_value_constr::save_explain_data_intern(THD *thd_arg, select_lex->master_unit()->derived->is_with_table()); explain= new (output->mem_root) Explain_select(output->mem_root, - thd_arg->lex->analyze_stmt); + thd->lex->analyze_stmt); select_lex->set_explain_type(true); explain->select_id= select_lex->select_number; @@ -254,18 +288,18 @@ int table_value_constr::save_explain_data_intern(THD *thd_arg, Optimization of TVC */ -void table_value_constr::optimize(THD *thd_arg) +void table_value_constr::optimize(THD *thd) { - create_explain_query_if_not_exists(thd_arg->lex, thd_arg->mem_root); + create_explain_query_if_not_exists(thd->lex, thd->mem_root); have_query_plan= QEP_AVAILABLE; if (select_lex->select_number != UINT_MAX && select_lex->select_number != INT_MAX /* this is not a UNION's "fake select */ && have_query_plan != QEP_NOT_PRESENT_YET && - thd_arg->lex->explain && // for "SET" command in SPs. - (!thd_arg->lex->explain->get_select(select_lex->select_number))) + thd->lex->explain && // for "SET" command in SPs. + (!thd->lex->explain->get_select(select_lex->select_number))) { - save_explain_data_intern(thd_arg, thd_arg->lex->explain); + save_explain_data_intern(thd, thd->lex->explain); } } @@ -290,7 +324,7 @@ bool table_value_constr::exec(SELECT_LEX *sl) DBUG_RETURN(true); } - while ((elem=li++)) + while ((elem= li++)) { result->send_data(*elem); } @@ -301,52 +335,40 @@ bool table_value_constr::exec(SELECT_LEX *sl) DBUG_RETURN(false); } + /** @brief - Print list of lists + Print list - @param str Where to print to + @param str The reference on the string representation of the list + @param list The list that needed to be print @param query_type The mode of printing - @param values List of lists that needed to be print @details - The method prints a string representation of list of lists in the - string str. The parameter query_type specifies the mode of printing. + The method saves a string representation of list in the + string str. */ -void print_list_of_lists(String *str, - enum_query_type query_type, - List *values) +void print_list_item(String *str, List_item *list, + enum_query_type query_type) { - str->append(STRING_WITH_LEN("values ")); + bool is_first_elem= true; + List_iterator_fast it(*list); + Item *item; - bool first= 1; - List_iterator_fast li(*values); - List_item *list; - while ((list=li++)) + str->append('('); + + while ((item= it++)) { - if (first) - first= 0; + if (is_first_elem) + is_first_elem= false; else str->append(','); - str->append('('); - - List_iterator_fast it(*list); - Item *item; - first= 1; - - while ((item=it++)) - { - if (first) - first= 0; - else - str->append(','); - - item->print(str, query_type); - } - str->append(')'); + item->print(str, query_type); } + + str->append(')'); } @@ -354,21 +376,35 @@ void print_list_of_lists(String *str, @brief Print this TVC - @param thd_arg The context of the statement - @param str Where to print to + @param thd The context of the statement + @param str The reference on the string representation of this TVC @param query_type The mode of printing @details - The method prints a string representation of this TVC in the - string str. The parameter query_type specifies the mode of printing. + The method saves a string representation of this TVC in the + string str. */ -void table_value_constr::print(THD *thd_arg, String *str, +void table_value_constr::print(THD *thd, String *str, enum_query_type query_type) { - DBUG_ASSERT(thd_arg); + DBUG_ASSERT(thd); - print_list_of_lists(str, query_type, &lists_of_values); + str->append(STRING_WITH_LEN("values ")); + + bool is_first_elem= true; + List_iterator_fast li(lists_of_values); + List_item *list; + + while ((list= li++)) + { + if (is_first_elem) + is_first_elem= false; + else + str->append(','); + + print_list_item(str, list, query_type); + } } @@ -428,6 +464,23 @@ bool Item_func_in::create_value_list_for_tvc(THD *thd, } +/** + @brief + Create name for the derived table defined by TVC + + @param thd The context of the statement + @param parent_select The SELECT where derived table is used + @param alias The returned created name + + @details + Create name for the derived table using current TVC number + for this parent_select stored in parent_select + + @retval + true if creation fails + false otherwise +*/ + static bool create_tvc_name(THD *thd, st_select_lex *parent_select, LEX_CSTRING *alias) { @@ -442,6 +495,7 @@ static bool create_tvc_name(THD *thd, st_select_lex *parent_select, return false; } + /** @brief Transform IN predicate into IN subquery @@ -579,18 +633,19 @@ err: thd->restore_active_arena(arena, &backup); lex->derived_tables= save_derived_tables; thd->lex->current_select= parent_select; - return this; + return NULL; } + /** @brief - Checks if this IN-predicate can be transformed in IN-subquery + Check if this IN-predicate can be transformed in IN-subquery with TVC @param thd The context of the statement @details - Compares the number of elements in the list of + Compare the number of elements in the list of values in this IN-predicate with the in_subquery_conversion_threshold special variable @@ -601,17 +656,18 @@ err: bool Item_func_in::to_be_transformed_into_in_subq(THD *thd) { - uint opt_can_be_used= arg_count-1; + uint values_count= arg_count-1; if (args[1]->type() == Item::ROW_ITEM) - opt_can_be_used*= ((Item_row *)(args[1]))->cols(); + values_count*= ((Item_row *)(args[1]))->cols(); - if (opt_can_be_used < thd->variables.in_subquery_conversion_threshold) + if (values_count < thd->variables.in_subquery_conversion_threshold) return false; return true; } + /** @brief Transform IN predicates into IN subqueries in WHERE and ON expressions @@ -629,8 +685,9 @@ bool Item_func_in::to_be_transformed_into_in_subq(THD *thd) bool JOIN::transform_in_predicates_into_in_subq(THD *thd) { + DBUG_ENTER("JOIN::transform_in_predicates_into_in_subq"); if (!select_lex->in_funcs.elements) - return false; + DBUG_RETURN(false); SELECT_LEX *save_current_select= thd->lex->current_select; enum_parsing_place save_parsing_place= select_lex->parsing_place; @@ -642,6 +699,8 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd) conds->transform(thd, &Item::in_predicate_to_in_subs_transformer, (uchar*) 0); + if (!conds) + DBUG_RETURN(true); select_lex->prep_where= conds ? conds->copy_andor_structure(thd) : 0; select_lex->where= conds; } @@ -660,6 +719,8 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd) table->on_expr->transform(thd, &Item::in_predicate_to_in_subs_transformer, (uchar*) 0); + if (!table->on_expr) + DBUG_RETURN(true); table->prep_on_expr= table->on_expr ? table->on_expr->copy_andor_structure(thd) : 0; } @@ -669,5 +730,5 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd) select_lex->in_funcs.empty(); select_lex->parsing_place= save_parsing_place; thd->lex->current_select= save_current_select; - return false; + DBUG_RETURN(false); } \ No newline at end of file From eadcf09bc48eb573316c01382cff2be1b91c8ce4 Mon Sep 17 00:00:00 2001 From: Elena Stepanova Date: Fri, 27 Oct 2017 03:17:23 +0300 Subject: [PATCH 013/138] MDEV-13860 CONNECT engine does not build with JDBC without ODBC Re-apply the patch cb1b466c0c3fa72a058fe6462261f70b11d45c53, the change disappeared after the merge --- storage/connect/ha_connect.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/storage/connect/ha_connect.cc b/storage/connect/ha_connect.cc index c738f39c668..787ec2affc1 100644 --- a/storage/connect/ha_connect.cc +++ b/storage/connect/ha_connect.cc @@ -5398,10 +5398,10 @@ static int connect_assisted_discovery(handlerton *, THD* thd, #endif // __WIN__ //int hdr, mxe; int port = 0, mxr = 0, rc = 0, mul = 0, lrecl = 0; + PCSZ tabtyp = NULL; #if defined(ODBC_SUPPORT) POPARM sop= NULL; PCSZ ucnc= NULL; - PCSZ tabtyp = NULL; bool cnc= false; int cto= -1, qto= -1; #endif // ODBC_SUPPORT From c3592ca7b8864a2492d98db4d45a7684e979301d Mon Sep 17 00:00:00 2001 From: Elena Stepanova Date: Fri, 27 Oct 2017 03:19:59 +0300 Subject: [PATCH 014/138] List of unstable tests for 10.0.33 release --- mysql-test/unstable-tests | 236 ++++++++++++++++++++++---------------- 1 file changed, 136 insertions(+), 100 deletions(-) diff --git a/mysql-test/unstable-tests b/mysql-test/unstable-tests index 520567a0e9b..47d21391d6e 100644 --- a/mysql-test/unstable-tests +++ b/mysql-test/unstable-tests @@ -23,53 +23,52 @@ # ############################################################################## -main.alter_table_online : Modified in 10.0.32 -main.binary_to_hex : Modified in 10.0.32 -main.bootstrap : Modified in 10.0.32 -main.count_distinct : Modified in 10.0.32 +main.alter_table : Modified in 10.0.33 +main.case : Modified in 10.0.33 +main.count_distinct : Modified in 10.0.33 main.count_distinct2 : MDEV-11768 - timeout main.create_delayed : MDEV-10605 - failed with timeout -main.ctype_ucs : Modified in 10.0.32 +main.ctype_gbk : Modified in 10.0.33 +main.ctype_latin1 : Modified in 10.0.33 +main.ctype_ucs : Modified in 10.0.33 +main.ctype_utf32 : Modified in 10.0.33 +main.ctype_utf8 : Modified in 10.0.33 main.debug_sync : MDEV-10607 - internal error +main.delete_returning : Modified in 10.0.33 main.derived_opt : MDEV-11768 - timeout -main.engine_error_in_alter-8453 : Added in 10.0.32 main.events_slowlog : MDEV-12821 - wrong result -main.func_concat : Modified in 10.0.32 -main.func_crypt : Modified in 10.0.32 -main.func_regexp_pcre : MDEV-13412 - crash, wrong result; modified in 10.0.32 -main.gis : MDEV-13411 - wrong result on P8; modified in 10.0.32 -main.gis-alter_table_online : Added in 10.0.32 -main.gis-rt-precise : Modified in 10.0.32 -main.group_by : Modified in 10.0.32 +main.func_in : Modified in 10.0.33 +main.func_misc : Modified in 10.0.33 +main.func_regexp_pcre : Modified in 10.0.33 +main.func_time : Modified in 10.0.33 +main.gis : MDEV-13411 - wrong result on P8 main.host_cache_size_functionality : MDEV-10606 - sporadic failure on shutdown main.index_intersect_innodb : MDEV-10643 - failed with timeout main.index_merge_innodb : MDEV-7142 - wrong result main.innodb_mysql_lock : MDEV-7861 - sporadic lock detection failure -main.join_outer : Modified in 10.0.32 -main.loadxml : Data file modified in 10.0.32 -main.log_tables-big : MDEV-13408 - wrong result +main.insert : Modified in 10.0.33 +main.log_tables-big : MDEV-13408 - wrong result; modified in 10.0.33 main.mdev-504 : MDEV-10607 - sporadic "can't connect" +main.mdev13607 : Added in 10.0.33 main.mdev375 : MDEV-10607 - sporadic "can't connect" main.merge : MDEV-10607 - sporadic "can't connect" -main.mysql : Modified in 10.0.32 +main.myisam : Modified in 10.0.33 main.mysqlhotcopy_myisam : MDEV-10995 - test hangs on debug build -main.mysqltest : MDEV-9269 - fails on Alpha; modified in 10.0.32 -main.mysql_upgrade : Modified in 10.0.32 -main.ps : MDEV-11017 - sporadic wrong Prepared_stmt_count -main.read_only : Modified in 10.0.32 +main.mysqltest : MDEV-9269 - fails on Alpha +main.partition_datatype : Modified in 10.0.33 +main.ps : MDEV-11017 - sporadic wrong Prepared_stmt_count; modified in 10.0.33 +main.range_vs_index_merge : Modified in 10.0.33 +main.read_only : Modified in 10.0.33 main.show_explain : MDEV-10674 - wrong result +main.show_function_with_pad_char_to_full_length : Added in 10.0.33 main.sp_notembedded : MDEV-10607 - internal error main.sp-security : MDEV-10607 - sporadic "can't connect" -main.subselect : Modified in 10.0.32 +main.stat_tables_par_innodb : MDEV-14155 - wrong rounding main.subselect_innodb : MDEV-10614 - sporadic wrong results -main.subselect_mat_cost_bugs : Modified in 10.0.32 -main.subselect_nulls : Modified in 10.0.32 -main.subselect_sj2_mat : Modified in 10.0.32 -main.subselect_sj_mat : MOdified in 10.0.32 -main.symlink-aria-11902 : MDEV-12215 - Wrong error number -main.symlink-myisam-11902 : MDEV-12215 - Wrong error number -main.union : Modified in 10.0.32 -main.view : Modified in 10.0.32 +main.subselect_mat_cost_bugs : Modified in 10.0.33 +main.tc_heuristic_recover : Added in 10.0.33 +main.type_varchar : Modified in 10.0.33 +main.view : Modified in 10.0.33 main.xa : MDEV-11769 - lock wait timeout #---------------------------------------------------------------- @@ -82,20 +81,44 @@ archive.mysqlhotcopy_archive : MDEV-10995 - test hangs on debug build #---------------------------------------------------------------- binlog.binlog_commit_wait : MDEV-10150 - Error: too much time elapsed -binlog.binlog_unsafe : Modified in 10.0.32 binlog.binlog_xa_recover : MDEV-8517 - Extra checkpoint #---------------------------------------------------------------- -connect.drop-open-error : Added in 10.0.32 -connect.grant2 : Modified in 10.0.32 -connect.infoschema-9739 : Added in 10.0.32 -connect.json : Sporadic wrong result, tentative fix in 10.0.32 -connect.mysql_new : Modified in 10.0.32 -connect.odbc_firebird : Added in 10.0.32 -connect.secure_file_priv : Modified in 10.0.32 -connect.tbl : MDEV-9844, MDEV-10179 - sporadic crashes, valgrind warnings, wrong results -connect.zip : Sporadic wrong result, tentative fix expected in 10.0.32 +connect.alter_xml : Modified in 10.0.33 +connect.alter_xml2 : Added in 10.0.33 +connect.infoschema-9739 : Modified in 10.0.33 +connect.infoschema2-9739 : Added in 10.0.33 +connect.jdbc_new : Modified in 10.0.33 +connect.json : Sporadic wrong result; modified in 10.0.33 +connect.json_java_2 : Added in 10.0.33 +connect.json_java_3 : Added in 10.0.33 +connect.json_mongo_c : Added in 10.0.33 +connect.json_udf : Modified in 10.0.33 +connect.json_udf_bin : Modified in 10.0.33 +connect.mongo_c : Added in 10.0.33 +connect.mongo_java_2 : Added in 10.0.33 +connect.mongo_java_3 : Added in 10.0.33 +connect.mul_new : Added in 10.0.33 +connect.mysql_exec : Modified in 10.0.33 +connect.mysql_new : Modified in 10.0.33 +connect.tbl : MDEV-9844, MDEV-10179 - sporadic crashes, valgrind warnings, wrong results; modified in 10.0.33 +connect.tbl_thread : MDEV-9844, MDEV-10179 - sporadic crashes, valgrind warnings, wrong results; added in 10.0.33 +connect.unsigned : Modified in 10.0.33 +connect.upd : Modified in 10.0.33 +connect.xml : Modified in 10.0.33 +connect.xml2 : Added in 10.0.33 +connect.xml2_grant : Added in 10.0.33 +connect.xml2_html : Added in 10.0.33 +connect.xml2_mdev5261 : Added in 10.0.33 +connect.xml2_mult : Added in 10.0.33 +connect.xml2_zip : Added in 10.0.33 +connect.xml_grant : Modified in 10.0.33 +connect.xml_html : Modified in 10.0.33 +connect.xml_mdev5261 : Modified in 10.0.33 +connect.xml_mult : Modified in 10.0.33 +connect.xml_zip : Modified in 10.0.33 +connect.zip : Sporadic wrong result; modified in 10.0.33 #---------------------------------------------------------------- @@ -118,28 +141,43 @@ funcs_2/charset.* : MDEV-10999 - test not maintained #---------------------------------------------------------------- +innodb.alter_rename_existing : Added in 10.0.33 innodb.binlog_consistent : MDEV-10618 - Server fails to start -innodb.drop_table_background : MDEV-13407 - Tablespace exists; added in 10.0.32 +innodb.create-index-debug : Added in 10.0.33 +innodb.drop_table_background : MDEV-13407 - Tablespace exists +innodb.group_commit_crash : MDEV-11770 - checksum mismatch innodb.group_commit_crash_no_optimize_thread : MDEV-11770 - checksum mismatch -innodb.innodb-alter-debug : Modified in 10.0.32 -innodb.innodb-alter-discard : Modified in 10.0.32 -innodb.innodb-alter-nullable : Modified in 10.0.32 -innodb.innodb-alter-table : MDEV-10619 - Testcase timeout; modified in 10.0.32 -innodb.innodb-alter-tempfile : Modified in 10.0.32 +innodb.index_tree_operation : Added in 10.0.33 +innodb.innodb-alter : Added in 10.0.33 +innodb.innodb-alter-autoinc : Added in 10.0.33 +innodb.innodb-alter-table : MDEV-10619 - Testcase timeout; modified in 10.0.33 innodb.innodb_bug30423 : MDEV-7311 - Wrong number of rows in the plan -innodb.innodb-get-fk : Modified in 10.0.32 +innodb.innodb-get-fk : Modified in 10.0.33 +innodb.innodb-index-debug : Added in 10.0.33 +innodb.innodb-index-online : Added in 10.0.33 +innodb.innodb-index-online-delete : Added in 10.0.33 +innodb.innodb-index-online-fk : Added in 10.0.33 +innodb.innodb-index-online-purge : Added in 10.0.33 innodb.innodb_monitor : MDEV-10939 - Testcase timeout -innodb.log_file_size : Modified in 10.0.32 -innodb.row_format_redundant : Added in 10.0.32 -innodb.table_flags : Added in 10.0.32 +innodb.innodb-table-online : Added in 10.0.33 +innodb.innodb-wl5980-alter : Added in 10.0.33 +innodb.log_file_name : MDEV-14029 - Unexpected files +innodb.table_definition_cache_debug : Added in 10.0.33 +innodb.undo_log : Added in 10.0.33 +innodb.xa_recovery : Modified in 10.0.33 -innodb_zip.innodb_bug36169 : Modified in 10.0.32 -innodb_zip.innodb_bug36172 : Modified in 10.0.32 -innodb_zip.innodb_bug52745 : Modified in 10.0.32 -innodb_zip.innodb_bug53591 : Modified in 10.0.32 -innodb_zip.innodb_bug56680 : Modified in 10.0.32 -innodb_zip.innodb-create-options : Modified in 10.0.32 -innodb_zip.innodb-zip : Modified in 10.0.32 +innodb_fts.concurrent_insert : Added in 10.0.33 +innodb_fts.fulltext : Modified in 10.0.33 +innodb_fts.innodb-fts-fic : MDEV-14154 - Assertion failure +innodb_fts.innodb_fts_misc_debug : MDEV-14156 - Unexpected warning + +innodb_zip.innodb_prefix_index_liftedlimit : Modified in 10.0.33 +innodb_zip.wl5522_debug_zip : MDEV-14140 - Assertion failure + + +#---------------------------------------------------------------- + +maria.maria : Modified in 10.0.33 #---------------------------------------------------------------- @@ -160,9 +198,8 @@ multi_source.status_vars : MDEV-4632 - failed while waiting for Slave_received_h #---------------------------------------------------------------- -parts.longname : Added in 10.0.32 +parts.partition_alter_maria : Added in 10.0.33 parts.partition_exch_qa_10 : MDEV-11765 - wrong result -parts.quoting : Added in 10.0.32 #---------------------------------------------------------------- @@ -183,12 +220,10 @@ plugins.thread_pool_server_audit : MDEV-9562 - crashes on sol10-sparc #---------------------------------------------------------------- roles.create_and_grant_role : MDEV-11772 - wrong result -roles.current_role_view-12666 : Added in 10.0.32 -roles.show_create_database-10463 : Added in 10.0.32 +roles.definer : Modified in 10.0.33 #---------------------------------------------------------------- -rpl.circular_serverid0 : Added in 10.0.32 rpl.last_insert_id : MDEV-10625 - warnings in error log rpl.rpl_auto_increment : MDEV-10417 - Fails on Mips rpl.rpl_auto_increment_bug45679 : MDEV-10417 - Fails on Mips @@ -207,11 +242,7 @@ rpl.rpl_mdev6020 : MDEV-10630, MDEV-10417 - Timeouts, fails rpl.rpl_parallel : MDEV-10653 - Timeouts rpl.rpl_parallel_mdev6589 : MDEV-12979 - Assertion failure rpl.rpl_parallel_temptable : MDEV-10356 - Crash in close_thread_tables -rpl.rpl_parallel_tokudb_delete_pk : Opt file modified in 10.0.32 -rpl.rpl_parallel_tokudb_update_pk_uc0_lookup0 : Modified in 10.0.32 -rpl.rpl_parallel_tokudb_write_pk : Modified in 10.0.32 rpl.rpl_partition_innodb : MDEV-10417 - Fails on Mips -rpl.rpl_reset_slave_fail : Added in 10.0.32 rpl.rpl_row_basic_11bugs : MDEV-12171 - Server failed to start rpl.rpl_row_index_choice : MDEV-13409 - Server crash rpl.rpl_row_sp001 : MDEV-9329 - Fails on Ubuntu/s390x @@ -220,6 +251,7 @@ rpl.rpl_semi_sync_uninstall_plugin : MDEV-7140 - Wrong plugin status rpl.rpl_show_slave_hosts : MDEV-12171 - Server failed to start rpl.rpl_skip_replication : MDEV-9268 - Fails with timeout in sync_slave_with_master on Alpha rpl.rpl_slave_grp_exec : MDEV-10514 - Unexpected deadlock +rpl.rpl_sp_variables : Modified in 10.0.33 rpl.rpl_sync : MDEV-10633 - Database page corruption rpl.rpl_temporary_error2 : MDEV-10634 - Wrong number of retries @@ -244,13 +276,16 @@ sphinx.* : MDEV-10986 - sphinx tests fail in buildbot and outside #---------------------------------------------------------------- +storage_engine* : Tests are not always timely maintained + +#---------------------------------------------------------------- + stress.ddl_innodb : MDEV-10635 - Testcase timeout #---------------------------------------------------------------- sys_vars.autocommit_func2 : MDEV-9329 - Fails on Ubuntu/s390x sys_vars.innodb_buffer_pool_dump_pct_basic : MDEV-10651 - sporadic failure on file_exists -sys_vars.innodb_sched_priority_cleaner_basic : Modified in 10.0.32 sys_vars.thread_cache_size_func : MDEV-11775 - wrong result #---------------------------------------------------------------- @@ -259,12 +294,13 @@ tokudb.change_column_all_1000_10 : MDEV-12640 - Lost connection during query tokudb.change_column_bin : MDEV-12640 - Lost connection during query tokudb.change_column_char : MDEV-12822 - Lost connection during query tokudb.cluster_filter_unpack_varchar : MDEV-10636 - Wrong execution plan -tokudb.dir_per_db : MDEV-11537 - wrong result +tokudb.dir_per_db : MDEV-11537 - wrong result; modified in 10.0.33 tokudb.dir_per_db_rename_to_nonexisting_schema : MDEV-12823 - Valgrind +tokudb.hotindex-insert-bigchar : MDEV-13870 - ASAN failures tokudb.hotindex-update-1 : MDEV-12640 - Lost connection during query -tokudb.kill_query_blocked_in_lt : Added in 10.0.32 +tokudb.kill_query_blocked_in_lt : Added in 10.0.33 tokudb.locks-select-update-1 : MDEV-13406 - Lock wait timeout -tokudb.locks-select-update-3 : Modified in 10.0.32 +tokudb.locks-select-update-3 : Modified in 10.0.33 tokudb.rows-32m-rand-insert : MDEV-12640 - Lost connection during query tokudb.rows-32m-seq-insert : MDEV-12640 - Lost connection during query @@ -277,42 +313,41 @@ tokudb_bugs.frm_store2 : MDEV-12823 - Valgrind tokudb_bugs.frm_store3 : MDEV-12823 - Valgrind tokudb_bugs.xa : MDEV-11804 - Lock wait timeout -tokudb_mariadb.mdev12972 : Added in 10.0.32 - tokudb_rpl.* : MDEV-11001 - tests don't work tokudb_sys_vars.* : MDEV-11001 - tests don't work -rpl-tokudb.rpl_deadlock_tokudb : Modified in 10.0.32 -rpl-tokudb.rpl_not_null_tokudb : Modified in 10.0.32 -rpl-tokudb.rpl_rfr_disable_on_expl_pk_absence : Modified in 10.0.32 -rpl-tokudb.rpl_row_basic_3tokudb : Modified in 10.0.32 -rpl-tokudb.rpl_stm_tokudb : Modified in 10.0.32 -rpl-tokudb.rpl_tokudb_commit_after_flush : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_insert_id : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_insert_id_pk : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_multi_update : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_multi_update2 : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_multi_update3 : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_rfr_partition_table : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_crash_safe : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_blobs : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_eng_full : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_eng_min : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_eng_noblob : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_idx_full : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_idx_min : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_img_idx_noblob : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_log : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_lower_case_table_names : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_sp003 : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_sp006 : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_row_trig004 : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_stm_log : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_stm_mixed_crash_safe : Added in 10.0.32 -rpl-tokudb.rpl_tokudb_stm_mixed_lower_case_table_names : Added in 10.0.32 +rpl-tokudb.rpl_parallel_tokudb_delete_pk : Opt file modified in 10.0.33 +rpl-tokudb.rpl_parallel_tokudb_update_pk_uc0_lookup0 : Modified in 10.0.33 +rpl-tokudb.rpl_parallel_tokudb_write_pk : Modified in 10.0.33 +rpl-tokudb.rpl_rfr_disable_on_expl_pk_absence : Added in 10.0.33 +rpl-tokudb.rpl_row_basic_3tokudb : Modified in 10.0.33 +rpl-tokudb.rpl_tokudb_commit_after_flush : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_insert_id : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_insert_id_pk : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_multi_update : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_multi_update2 : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_multi_update3 : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_rfr_partition_table : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_crash_safe : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_blobs : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_eng_full : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_eng_min : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_eng_noblob : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_idx_full : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_idx_min : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_img_idx_noblob : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_log : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_lower_case_table_names : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_sp003 : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_sp006 : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_row_trig004 : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_stm_log : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_stm_mixed_crash_safe : Added in 10.0.33 +rpl-tokudb.rpl_tokudb_stm_mixed_lower_case_table_names : Added in 10.0.33 #---------------------------------------------------------------- +unit.lf : MDEV-12897 - Unexpected return code unit.ma_test_loghandler : MDEV-10638 - record read not ok unit.pfs : MySQL:84457 - unittest pft-t failing @@ -320,5 +355,6 @@ unit.pfs : MySQL:84457 - unittest pft-t failing vcol.not_supported : MDEV-10639 - Testcase timeout vcol.vcol_keys_innodb : MDEV-10639 - Testcase timeout +vcol.vcol_misc : Modified in 10.0.33 #---------------------------------------------------------------- From a4ded0a9b57ee7a801ce20cffdaee21fee281123 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Sat, 28 Oct 2017 20:54:18 +0200 Subject: [PATCH 015/138] Mistakes corrected. TVC can be used in IN subquery and in PARTITION BY struct now. Special variable to control working of optimization added. --- mysql-test/r/errors.result | 10 +- mysql-test/r/func_group_innodb.result | 2 +- mysql-test/r/func_misc.result | 4 +- mysql-test/r/group_by_null.result | 2 +- mysql-test/r/insert_update.result | 14 +- mysql-test/r/mysqld--help.result | 5 + mysql-test/r/ps.result | 2 +- mysql-test/r/selectivity.result | 4 +- mysql-test/r/selectivity_innodb.result | 4 +- mysql-test/r/table_elim.result | 4 +- mysql-test/r/table_value_constr.result | 442 ++++++++++++++++++++++++- mysql-test/r/variables.result | 2 +- mysql-test/t/default.test | 4 +- mysql-test/t/errors.test | 10 +- mysql-test/t/func_group_innodb.test | 2 +- mysql-test/t/func_misc.test | 2 +- mysql-test/t/group_by_null.test | 2 +- mysql-test/t/insert_update.test | 8 +- mysql-test/t/opt_tvc.test | 2 +- mysql-test/t/ps.test | 2 +- mysql-test/t/table_value_constr.test | 192 ++++++++++- mysql-test/t/variables.test | 2 +- sql/gen_lex_token.cc | 2 + sql/item.cc | 9 +- sql/item_subselect.cc | 6 +- sql/item_subselect.h | 2 + sql/share/errmsg-utf8.txt | 4 +- sql/sql_lex.cc | 28 +- sql/sql_lex.h | 1 + sql/sql_priv.h | 2 + sql/sql_select.cc | 6 + sql/sql_tvc.cc | 97 ++++++ sql/sql_yacc.yy | 26 +- sql/sys_vars.cc | 2 +- 34 files changed, 826 insertions(+), 80 deletions(-) diff --git a/mysql-test/r/errors.result b/mysql-test/r/errors.result index a909366a89b..0b434864323 100644 --- a/mysql-test/r/errors.result +++ b/mysql-test/r/errors.result @@ -150,17 +150,17 @@ ERROR 22003: BIGINT value is out of range in '-73 * -2465717823867977728' # CREATE TABLE t1 (a INT); CREATE TABLE t2(a INT PRIMARY KEY, b INT); -SELECT '' AS b FROM t1 GROUP BY VALUES(b); +SELECT '' AS b FROM t1 GROUP BY VALUE(b); ERROR 42S22: Unknown column '' in 'VALUES() function' -REPLACE t2(b) SELECT '' AS b FROM t1 GROUP BY VALUES(b); +REPLACE t2(b) SELECT '' AS b FROM t1 GROUP BY VALUE(b); ERROR 42S22: Unknown column '' in 'VALUES() function' -UPDATE t2 SET a=(SELECT '' AS b FROM t1 GROUP BY VALUES(b)); +UPDATE t2 SET a=(SELECT '' AS b FROM t1 GROUP BY VALUE(b)); ERROR 42S22: Unknown column '' in 'VALUES() function' INSERT INTO t2 VALUES (1,0) ON DUPLICATE KEY UPDATE -b=(SELECT '' AS b FROM t1 GROUP BY VALUES(b)); +b=(SELECT '' AS b FROM t1 GROUP BY VALUE(b)); ERROR 42S22: Unknown column '' in 'VALUES() function' INSERT INTO t2(a,b) VALUES (1,0) ON DUPLICATE KEY UPDATE -b=(SELECT VALUES(a)+2 FROM t1); +b=(SELECT VALUE(a)+2 FROM t1); DROP TABLE t1, t2; # # MDEV-492: incorrect error check before sending OK in mysql_update diff --git a/mysql-test/r/func_group_innodb.result b/mysql-test/r/func_group_innodb.result index 52d5922df95..e340c04107d 100644 --- a/mysql-test/r/func_group_innodb.result +++ b/mysql-test/r/func_group_innodb.result @@ -226,7 +226,7 @@ create table y select 1 b; select 1 from y group by b; 1 1 -select 1 from y group by values(b); +select 1 from y group by value(b); 1 1 drop table y; diff --git a/mysql-test/r/func_misc.result b/mysql-test/r/func_misc.result index 39f8f41d1e7..1006cdcea5c 100644 --- a/mysql-test/r/func_misc.result +++ b/mysql-test/r/func_misc.result @@ -286,11 +286,11 @@ NAME_CONST('a', -(1)) OR 1 CREATE TABLE t1 (a INT, b INT) ENGINE=MyISAM; INSERT INTO t1 VALUES (1,10); CREATE VIEW v1 AS SELECT * FROM t1; -EXPLAIN EXTENDED SELECT VALUES(b) FROM v1; +EXPLAIN EXTENDED SELECT VALUE(b) FROM v1; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 system NULL NULL NULL NULL 1 100.00 Warnings: -Note 1003 select values(10) AS `VALUES(b)` from dual +Note 1003 select values(10) AS `VALUE(b)` from dual drop view v1; drop table t1; End of 5.3 tests diff --git a/mysql-test/r/group_by_null.result b/mysql-test/r/group_by_null.result index 01053514cb0..1ae090fdc63 100644 --- a/mysql-test/r/group_by_null.result +++ b/mysql-test/r/group_by_null.result @@ -1,6 +1,6 @@ create table t1 (a int); insert into t1 values (1),(2); -select max('foo') from t1 group by values(a), extractvalue('bar','qux') order by "v"; +select max('foo') from t1 group by value(a), extractvalue('bar','qux') order by "v"; max('foo') foo drop table t1; diff --git a/mysql-test/r/insert_update.result b/mysql-test/r/insert_update.result index e8e6e16fe5a..ec87eeb85a6 100644 --- a/mysql-test/r/insert_update.result +++ b/mysql-test/r/insert_update.result @@ -49,19 +49,19 @@ a b c 5 0 30 8 9 60 INSERT t1 VALUES (2,1,11), (7,4,40) ON DUPLICATE KEY UPDATE c=c+VALUES(a); -SELECT *, VALUES(a) FROM t1; -a b c VALUES(a) +SELECT *, VALUE(a) FROM t1; +a b c VALUE(a) 1 2 10 NULL 3 4 127 NULL 5 0 30 NULL 8 9 60 NULL 2 1 11 NULL -explain extended SELECT *, VALUES(a) FROM t1; +explain extended SELECT *, VALUE(a) FROM t1; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 5 100.00 Warnings: -Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,values(`test`.`t1`.`a`) AS `VALUES(a)` from `test`.`t1` -explain extended select * from t1 where values(a); +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,values(`test`.`t1`.`a`) AS `VALUE(a)` from `test`.`t1` +explain extended select * from t1 where value(a); id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 5 100.00 Using where Warnings: @@ -160,8 +160,8 @@ a b c INSERT t1 SELECT a,b,c FROM t2 WHERE d=2 ON DUPLICATE KEY UPDATE c=c+VALUES(a); ERROR 23000: Column 'c' in field list is ambiguous INSERT t1 SELECT a,b,c FROM t2 WHERE d=2 ON DUPLICATE KEY UPDATE c=t1.c+VALUES(t1.a); -SELECT *, VALUES(a) FROM t1; -a b c VALUES(a) +SELECT *, VALUE(a) FROM t1; +a b c VALUE(a) 1 2 10 NULL 3 4 127 NULL 5 0 30 NULL diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index 564269319cb..b3d8f413fea 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -286,6 +286,10 @@ The following options may be given as the first argument: Specifies a directory to add to the ignore list when collecting database names from the datadir. Put a blank argument to reset the list accumulated so far. + --in-subquery-conversion-threshold[=#] + The minimum number of scalar elements in the value list + ofIN predicate that triggers its conversion to IN + subquery --init-connect=name Command(s) that are executed for each new connection (unless the user has SUPER privilege) --init-file=name Read SQL commands from this file at startup @@ -1269,6 +1273,7 @@ idle-readwrite-transaction-timeout 0 idle-transaction-timeout 0 ignore-builtin-innodb FALSE ignore-db-dirs +in-subquery-conversion-threshold 10000 init-connect init-file (No default value) init-rpl-role MASTER diff --git a/mysql-test/r/ps.result b/mysql-test/r/ps.result index 567be0d0d3f..dbe70490327 100644 --- a/mysql-test/r/ps.result +++ b/mysql-test/r/ps.result @@ -4649,7 +4649,7 @@ EXECUTE IMMEDIATE MAX('SELECT 1 AS c'); ERROR HY000: Invalid use of group function EXECUTE IMMEDIATE DEFAULT(a); ERROR 42S22: Unknown column 'a' in 'field list' -EXECUTE IMMEDIATE VALUES(a); +EXECUTE IMMEDIATE VALUE(a); ERROR 42S22: Unknown column 'a' in 'field list' CREATE FUNCTION f1() RETURNS VARCHAR(64) RETURN 't1'; EXECUTE IMMEDIATE f1(); diff --git a/mysql-test/r/selectivity.result b/mysql-test/r/selectivity.result index 8b447f85013..ba9ac04b807 100644 --- a/mysql-test/r/selectivity.result +++ b/mysql-test/r/selectivity.result @@ -400,7 +400,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 SUBQUERY customer ALL NULL NULL NULL NULL 150 100.00 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 -Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`)) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,<`dbt3_s001`.`customer`.`c_custkey`>(exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from ( select substr(c_phone, 1, 2) as cntrycode, c_acctbal @@ -441,7 +441,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 SUBQUERY customer ALL NULL NULL NULL NULL 150 91.00 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 -Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`)) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,<`dbt3_s001`.`customer`.`c_custkey`>(exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from ( select substr(c_phone, 1, 2) as cntrycode, c_acctbal diff --git a/mysql-test/r/selectivity_innodb.result b/mysql-test/r/selectivity_innodb.result index 8128edb2901..e35512290b5 100644 --- a/mysql-test/r/selectivity_innodb.result +++ b/mysql-test/r/selectivity_innodb.result @@ -403,7 +403,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 SUBQUERY customer ALL NULL NULL NULL NULL 150 100.00 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 -Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`)) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,<`dbt3_s001`.`customer`.`c_custkey`>(exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from ( select substr(c_phone, 1, 2) as cntrycode, c_acctbal @@ -444,7 +444,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 SUBQUERY customer ALL NULL NULL NULL NULL 150 91.00 Using where Warnings: Note 1276 Field or reference 'dbt3_s001.customer.c_custkey' of SELECT #4 was resolved in SELECT #2 -Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`)) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) +Note 1003 /* select#1 */ select substr(`dbt3_s001`.`customer`.`c_phone`,1,2) AS `cntrycode`,count(0) AS `numcust`,sum(`dbt3_s001`.`customer`.`c_acctbal`) AS `totacctbal` from `dbt3_s001`.`customer` where substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25') and `dbt3_s001`.`customer`.`c_acctbal` > (/* select#3 */ select avg(`dbt3_s001`.`customer`.`c_acctbal`) from `dbt3_s001`.`customer` where `dbt3_s001`.`customer`.`c_acctbal` > 0.00 and substr(`dbt3_s001`.`customer`.`c_phone`,1,2) in ('10','20','14','19','11','28','25')) and !(1,<`dbt3_s001`.`customer`.`c_custkey`>(exists(/* select#4 */ select 1 from `dbt3_s001`.`orders` where `dbt3_s001`.`orders`.`o_custkey` = `dbt3_s001`.`customer`.`c_custkey`))) group by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) order by substr(`dbt3_s001`.`customer`.`c_phone`,1,2) select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from ( select substr(c_phone, 1, 2) as cntrycode, c_acctbal diff --git a/mysql-test/r/table_elim.result b/mysql-test/r/table_elim.result index 04a9b47b6c9..cf9a4a38779 100644 --- a/mysql-test/r/table_elim.result +++ b/mysql-test/r/table_elim.result @@ -143,7 +143,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ref PRIMARY PRIMARY 4 test.a2.id 2 100.00 Using index Warnings: Note 1276 Field or reference 'test.a2.id' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `f`.`id` AS `id` from `test`.`t0` `f` join `test`.`t2` `a2` where `f`.`id` = `a2`.`id` and `a2`.`attr2` between 12 and 14 and `a2`.`fromdate` = (/* select#3 */ select max(`test`.`t2`.`fromdate`) from `test`.`t2` where `test`.`t2`.`id` = `a2`.`id`) +Note 1003 /* select#1 */ select `f`.`id` AS `id` from `test`.`t0` `f` join `test`.`t2` `a2` where `f`.`id` = `a2`.`id` and `a2`.`attr2` between 12 and 14 and `a2`.`fromdate` = <`a2`.`id`>((/* select#3 */ select max(`test`.`t2`.`fromdate`) from `test`.`t2` where `test`.`t2`.`id` = `a2`.`id`)) This should use one table: explain select id from v2 where id=2; id select_type table type possible_keys key key_len ref rows Extra @@ -171,7 +171,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ref PRIMARY PRIMARY 4 test.f.id 2 100.00 Using index Warnings: Note 1276 Field or reference 'test.f.id' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `f`.`id` AS `id` from `test`.`t0` `f` join `test`.`t2` `a2` where `f`.`id` = `a2`.`id` and `a2`.`attr2` between 12 and 14 and `a2`.`fromdate` = (/* select#3 */ select max(`test`.`t2`.`fromdate`) from `test`.`t2` where `test`.`t2`.`id` = `f`.`id`) +Note 1003 /* select#1 */ select `f`.`id` AS `id` from `test`.`t0` `f` join `test`.`t2` `a2` where `f`.`id` = `a2`.`id` and `a2`.`attr2` between 12 and 14 and `a2`.`fromdate` = <`f`.`id`>((/* select#3 */ select max(`test`.`t2`.`fromdate`) from `test`.`t2` where `test`.`t2`.`id` = `f`.`id`)) drop view v1, v2; drop table t0, t1, t2; create table t1 (a int); diff --git a/mysql-test/r/table_value_constr.result b/mysql-test/r/table_value_constr.result index 5c64085138c..39caba331ef 100644 --- a/mysql-test/r/table_value_constr.result +++ b/mysql-test/r/table_value_constr.result @@ -729,6 +729,433 @@ select * from v1; 1 2 3 4 drop view v1; +# IN-subquery with VALUES structure(s) : simple case +select * from t1 +where a in (values (1)); +a b +1 2 +1 1 +select * from t1 +where a in (select * from (values (1)) as tvc_0); +a b +1 2 +1 1 +explain extended select * from t1 +where a in (values (1)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (1)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` +explain extended select * from t1 +where a in (select * from (values (1)) as tvc_0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` semi join ((values (1)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` +# IN-subquery with VALUES structure(s) : UNION with VALUES on the first place +select * from t1 +where a in (values (1) union select 2); +a b +1 2 +1 1 +2 5 +select * from t1 +where a in (select * from (values (1)) as tvc_0 union +select 2); +a b +1 2 +1 1 +2 5 +explain extended select * from t1 +where a in (values (1) union select 2); +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 +4 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union /* select#3 */ select 2 having (`test`.`t1`.`a`) = (2)))) +explain extended select * from t1 +where a in (select * from (values (1)) as tvc_0 union +select 2); +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 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union /* select#4 */ select 2 having (`test`.`t1`.`a`) = (2)))) +# IN-subquery with VALUES structure(s) : UNION with VALUES on the second place +select * from t1 +where a in (select 2 union values (1)); +a b +1 2 +1 1 +2 5 +select * from t1 +where a in (select 2 union +select * from (values (1)) tvc_0); +a b +1 2 +1 1 +2 5 +explain extended select * from t1 +where a in (select 2 union values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having (`test`.`t1`.`a`) = (2) union /* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) +explain extended select * from t1 +where a in (select 2 union +select * from (values (1)) 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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having (`test`.`t1`.`a`) = (2) union /* select#3 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) +# IN-subquery with VALUES structure(s) : UNION ALL +select * from t1 +where a in (values (1) union all select b from t1); +a b +1 2 +1 1 +2 5 +7 8 +select * from t1 +where a in (select * from (values (1)) as tvc_0 union all +select b from t1); +a b +1 2 +1 1 +2 5 +7 8 +explain extended select * from t1 +where a in (values (1) union all select b from t1); +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 +4 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION t1 ALL NULL NULL NULL NULL 6 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union all /* select#3 */ select `test`.`t1`.`b` from `test`.`t1` where (`test`.`t1`.`a`) = `test`.`t1`.`b`))) +explain extended select * from t1 +where a in (select * from (values (1)) as tvc_0 union all +select b from t1); +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 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION t1 ALL NULL NULL NULL NULL 6 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union all /* select#4 */ select `test`.`t1`.`b` from `test`.`t1` where (`test`.`t1`.`a`) = `test`.`t1`.`b`))) +# NOT IN subquery with VALUES structure(s) : simple case +select * from t1 +where a not in (values (1),(2)); +a b +4 6 +9 7 +7 8 +select * from t1 +where a not in (select * from (values (1),(2)) as tvc_0); +a b +4 6 +9 7 +7 8 +explain extended select * from t1 +where a not in (values (1),(2)); +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 +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 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`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#3 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +explain extended select * from t1 +where a not in (select * from (values (1),(2)) 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 ALL NULL NULL NULL NULL 2 100.00 +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`.`a`>((`test`.`t1`.`a`,`test`.`t1`.`a` in ( (/* select#2 */ select `tvc_0`.`1` from (values (1),(2)) `tvc_0` ), (`test`.`t1`.`a` in on distinct_key where `test`.`t1`.`a` = ``.`1`)))) +# NOT IN subquery with VALUES structure(s) : UNION with VALUES on the first place +select * from t1 +where a not in (values (1) union select 2); +a b +4 6 +9 7 +7 8 +select * from t1 +where a not in (select * from (values (1)) as tvc_0 union +select 2); +a b +4 6 +9 7 +7 8 +explain extended select * from t1 +where a not in (values (1) union select 2); +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 +4 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) = `tvc_0`.`1`) union /* select#3 */ select 2 having trigcond((`test`.`t1`.`a`) = (2))))) +explain extended select * from t1 +where a not in (select * from (values (1)) as tvc_0 union +select 2); +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 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) = `tvc_0`.`1`) union /* select#4 */ select 2 having trigcond((`test`.`t1`.`a`) = (2))))) +# NOT IN subquery with VALUES structure(s) : UNION with VALUES on the second place +select * from t1 +where a not in (select 2 union values (1)); +a b +4 6 +9 7 +7 8 +select * from t1 +where a not in (select 2 union +select * from (values (1)) as tvc_0); +a b +4 6 +9 7 +7 8 +explain extended select * from t1 +where a not in (select 2 union values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION ALL NULL NULL NULL NULL 2 100.00 Using where +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having trigcond((`test`.`t1`.`a`) = (2)) union /* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) = `tvc_0`.`1`)))) +explain extended select * from t1 +where a not in (select 2 union +select * from (values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION ALL NULL NULL NULL NULL 2 100.00 Using where +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having trigcond((`test`.`t1`.`a`) = (2)) union /* select#3 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) = `tvc_0`.`1`)))) +# ANY-subquery with VALUES structure(s) : simple case +select * from t1 +where a = any (values (1),(2)); +a b +1 2 +1 1 +2 5 +select * from t1 +where a = any (select * from (values (1),(2)) as tvc_0); +a b +1 2 +1 1 +2 5 +explain extended select * from t1 +where a = any (values (1),(2)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +3 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join ((values (1),(2)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` +explain extended select * from t1 +where a = any (select * from (values (1),(2)) as tvc_0); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL distinct_key NULL NULL NULL 2 100.00 +1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED ALL NULL NULL NULL NULL 2 100.00 +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` semi join ((values (1),(2)) `tvc_0`) where `test`.`t1`.`a` = `tvc_0`.`1` +# ANY-subquery with VALUES structure(s) : UNION with VALUES on the first place +select * from t1 +where a = any (values (1) union select 2); +a b +1 2 +1 1 +2 5 +select * from t1 +where a = any (select * from (values (1)) as tvc_0 union +select 2); +a b +1 2 +1 1 +2 5 +explain extended select * from t1 +where a = any (values (1) union select 2); +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 +4 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union /* select#3 */ select 2 having (`test`.`t1`.`a`) = (2)))) +explain extended select * from t1 +where a = any (select * from (values (1)) as tvc_0 union +select 2); +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 DEPENDENT SUBQUERY ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1` union /* select#4 */ select 2 having (`test`.`t1`.`a`) = (2)))) +# ANY-subquery with VALUES structure(s) : UNION with VALUES on the second place +select * from t1 +where a = any (select 2 union values (1)); +a b +1 2 +1 1 +2 5 +select * from t1 +where a = any (select 2 union +select * from (values (1)) as tvc_0); +a b +1 2 +1 1 +2 5 +explain extended select * from t1 +where a = any (select 2 union values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having (`test`.`t1`.`a`) = (2) union /* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) +explain extended select * from t1 +where a = any (select 2 union +select * from (values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 2 having (`test`.`t1`.`a`) = (2) union /* select#3 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) +# ALL-subquery with VALUES structure(s) : simple case +select * from t1 +where a = all (values (1)); +a b +1 2 +1 1 +select * from t1 +where a = all (select * from (values (1)) as tvc_0); +a b +1 2 +1 1 +explain extended select * from t1 +where a = all (values (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 +3 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +2 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`.`a`>((`test`.`t1`.`a`,(/* select#3 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) <> `tvc_0`.`1`))))) +explain extended select * from t1 +where a = all (select * from (values (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 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +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`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) <> `tvc_0`.`1`))))) +# ALL-subquery with VALUES structure(s) : UNION with VALUES on the first place +select * from t1 +where a = all (values (1) union select 1); +a b +1 2 +1 1 +select * from t1 +where a = all (select * from (values (1)) as tvc_0 union +select 1); +a b +1 2 +1 1 +explain extended select * from t1 +where a = all (values (1) union select 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 +4 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where (<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) <> `tvc_0`.`1`) union /* select#3 */ select 1 having trigcond((`test`.`t1`.`a`) <> (1)))))) +explain extended select * from t1 +where a = all (select * from (values (1)) as tvc_0 union +select 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 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 2 100.00 Using where +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where (<`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where trigcond((`test`.`t1`.`a`) <> `tvc_0`.`1`) union /* select#4 */ select 1 having trigcond((`test`.`t1`.`a`) <> (1)))))) +# ALL-subquery with VALUES structure(s) : UNION with VALUES on the second place +select * from t1 +where a = any (select 1 union values (1)); +a b +1 2 +1 1 +select * from t1 +where a = any (select 1 union +select * from (values (1)) as tvc_0); +a b +1 2 +1 1 +explain extended select * from t1 +where a = any (select 1 union values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +4 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 1 having (`test`.`t1`.`a`) = (1) union /* select#4 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) +explain extended select * from t1 +where a = any (select 1 union +select * from (values (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 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION ref key0 key0 4 func 2 100.00 +4 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where <`test`.`t1`.`a`>((`test`.`t1`.`a`,(/* select#2 */ select 1 having (`test`.`t1`.`a`) = (1) union /* select#3 */ select `tvc_0`.`1` from (values (1)) `tvc_0` where (`test`.`t1`.`a`) = `tvc_0`.`1`))) # prepare statement that uses VALUES structure(s): single VALUES structure prepare stmt1 from " values (1,2); @@ -1633,19 +2060,14 @@ ANALYZE # different number of values in TVC values (1,2),(3,4,5); ERROR HY000: The used table value constructor has a different number of values -# subquery that uses VALUES structure(s) -select * from t1 -where a in (values (1)); -ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet -select * from t1 -where a in (select 2 union values (1)); -ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet -select * from t1 -where a in (values (1) union select 2); -ERROR HY000: Table value constructor can't be used as specification of subquery isn't implemented yet # illegal parameter data types in TVC values (1,point(1,1)),(1,1); ERROR HY000: Illegal parameter data types geometry and int for operation 'TABLE VALUE CONSTRUCTOR' values (1,point(1,1)+1); ERROR HY000: Illegal parameter data types geometry and int for operation '+' +# field reference in TVC +select * from (values (1), (b), (2)) as new_tvc; +ERROR HY000: Field reference 'b' can't be used in table value constructor +select * from (values (1), (t1.b), (2)) as new_tvc; +ERROR HY000: Field reference 't1.b' can't be used in table value constructor drop table t1; diff --git a/mysql-test/r/variables.result b/mysql-test/r/variables.result index 676432690b4..ce977bffdc0 100644 --- a/mysql-test/r/variables.result +++ b/mysql-test/r/variables.result @@ -1789,7 +1789,7 @@ set session collation_database=2048; ERROR HY000: Unknown collation: '2048' set session rand_seed1=DEFAULT; ERROR 42000: Variable 'rand_seed1' doesn't have a default value -set autocommit = values(v); +set autocommit = value(v); ERROR 42S22: Unknown column 'v' in 'field list' set session sql_mode=ansi_quotes; select * from information_schema.session_variables where variable_name='sql_mode'; diff --git a/mysql-test/t/default.test b/mysql-test/t/default.test index a3b349bb384..d310f4b85af 100644 --- a/mysql-test/t/default.test +++ b/mysql-test/t/default.test @@ -180,7 +180,7 @@ CREATE TABLE t1 (a INT DEFAULT 10); INSERT INTO t1 VALUES (11); CREATE VIEW v1 AS SELECT a AS a FROM t1; CREATE VIEW v2 AS SELECT DEFAULT(a) AS a FROM t1; -CREATE VIEW v3 AS SELECT VALUES(a) AS a FROM t1; +CREATE VIEW v3 AS SELECT VALUE(a) AS a FROM t1; SELECT * FROM v1; SELECT * FROM v2; SELECT * FROM v3; @@ -447,7 +447,7 @@ CALL p1; DROP PROCEDURE p1; --error ER_GENERATED_COLUMN_FUNCTION_IS_NOT_ALLOWED -CREATE TABLE t1 (a INT DEFAULT VALUES(a)); +CREATE TABLE t1 (a INT DEFAULT VALUE(a)); CREATE TABLE t1 (a INT); diff --git a/mysql-test/t/errors.test b/mysql-test/t/errors.test index 6ce6e439919..6b559d60eb4 100644 --- a/mysql-test/t/errors.test +++ b/mysql-test/t/errors.test @@ -178,16 +178,16 @@ SELECT UPDATEXML(-73 * -2465717823867977728,@@global.auto_increment_increment,nu CREATE TABLE t1 (a INT); CREATE TABLE t2(a INT PRIMARY KEY, b INT); --error ER_BAD_FIELD_ERROR -SELECT '' AS b FROM t1 GROUP BY VALUES(b); +SELECT '' AS b FROM t1 GROUP BY VALUE(b); --error ER_BAD_FIELD_ERROR -REPLACE t2(b) SELECT '' AS b FROM t1 GROUP BY VALUES(b); +REPLACE t2(b) SELECT '' AS b FROM t1 GROUP BY VALUE(b); --error ER_BAD_FIELD_ERROR -UPDATE t2 SET a=(SELECT '' AS b FROM t1 GROUP BY VALUES(b)); +UPDATE t2 SET a=(SELECT '' AS b FROM t1 GROUP BY VALUE(b)); --error ER_BAD_FIELD_ERROR INSERT INTO t2 VALUES (1,0) ON DUPLICATE KEY UPDATE - b=(SELECT '' AS b FROM t1 GROUP BY VALUES(b)); + b=(SELECT '' AS b FROM t1 GROUP BY VALUE(b)); INSERT INTO t2(a,b) VALUES (1,0) ON DUPLICATE KEY UPDATE - b=(SELECT VALUES(a)+2 FROM t1); + b=(SELECT VALUE(a)+2 FROM t1); DROP TABLE t1, t2; --echo # diff --git a/mysql-test/t/func_group_innodb.test b/mysql-test/t/func_group_innodb.test index c62d3d08496..1d175f85ed9 100644 --- a/mysql-test/t/func_group_innodb.test +++ b/mysql-test/t/func_group_innodb.test @@ -168,7 +168,7 @@ set storage_engine=innodb; create table y select 1 b; select 1 from y group by b; -select 1 from y group by values(b); +select 1 from y group by value(b); drop table y; SET storage_engine=@old_engine; diff --git a/mysql-test/t/func_misc.test b/mysql-test/t/func_misc.test index c661819424a..137b75e9983 100644 --- a/mysql-test/t/func_misc.test +++ b/mysql-test/t/func_misc.test @@ -316,7 +316,7 @@ CREATE TABLE t1 (a INT, b INT) ENGINE=MyISAM; INSERT INTO t1 VALUES (1,10); CREATE VIEW v1 AS SELECT * FROM t1; -EXPLAIN EXTENDED SELECT VALUES(b) FROM v1; +EXPLAIN EXTENDED SELECT VALUE(b) FROM v1; drop view v1; drop table t1; diff --git a/mysql-test/t/group_by_null.test b/mysql-test/t/group_by_null.test index b3fa2a003ec..93e965671dd 100644 --- a/mysql-test/t/group_by_null.test +++ b/mysql-test/t/group_by_null.test @@ -3,5 +3,5 @@ # create table t1 (a int); insert into t1 values (1),(2); -select max('foo') from t1 group by values(a), extractvalue('bar','qux') order by "v"; +select max('foo') from t1 group by value(a), extractvalue('bar','qux') order by "v"; drop table t1; diff --git a/mysql-test/t/insert_update.test b/mysql-test/t/insert_update.test index 7234973eeb8..06e16be84d7 100644 --- a/mysql-test/t/insert_update.test +++ b/mysql-test/t/insert_update.test @@ -22,9 +22,9 @@ SELECT * FROM t1; INSERT t1 SET a=5 ON DUPLICATE KEY UPDATE b=0; SELECT * FROM t1; INSERT t1 VALUES (2,1,11), (7,4,40) ON DUPLICATE KEY UPDATE c=c+VALUES(a); -SELECT *, VALUES(a) FROM t1; -explain extended SELECT *, VALUES(a) FROM t1; -explain extended select * from t1 where values(a); +SELECT *, VALUE(a) FROM t1; +explain extended SELECT *, VALUE(a) FROM t1; +explain extended select * from t1 where value(a); DROP TABLE t1; # @@ -79,7 +79,7 @@ SELECT * FROM t1; --error ER_NON_UNIQ_ERROR INSERT t1 SELECT a,b,c FROM t2 WHERE d=2 ON DUPLICATE KEY UPDATE c=c+VALUES(a); INSERT t1 SELECT a,b,c FROM t2 WHERE d=2 ON DUPLICATE KEY UPDATE c=t1.c+VALUES(t1.a); -SELECT *, VALUES(a) FROM t1; +SELECT *, VALUE(a) FROM t1; DROP TABLE t1; DROP TABLE t2; diff --git a/mysql-test/t/opt_tvc.test b/mysql-test/t/opt_tvc.test index d04c101e87a..6fcb1c5d1aa 100644 --- a/mysql-test/t/opt_tvc.test +++ b/mysql-test/t/opt_tvc.test @@ -283,4 +283,4 @@ eval explain extended $query; set @@in_subquery_conversion_threshold= 2; drop table t1, t2, t3; -set @@in_subquery_conversion_threshold= default; +set @@in_subquery_conversion_threshold= default; \ No newline at end of file diff --git a/mysql-test/t/ps.test b/mysql-test/t/ps.test index b6d1b4862a6..ce2d26f0dca 100644 --- a/mysql-test/t/ps.test +++ b/mysql-test/t/ps.test @@ -4154,7 +4154,7 @@ EXECUTE IMMEDIATE MAX('SELECT 1 AS c'); EXECUTE IMMEDIATE DEFAULT(a); --error ER_BAD_FIELD_ERROR -EXECUTE IMMEDIATE VALUES(a); +EXECUTE IMMEDIATE VALUE(a); CREATE FUNCTION f1() RETURNS VARCHAR(64) RETURN 't1'; diff --git a/mysql-test/t/table_value_constr.test b/mysql-test/t/table_value_constr.test index c24cbc40137..57a9817f0c2 100644 --- a/mysql-test/t/table_value_constr.test +++ b/mysql-test/t/table_value_constr.test @@ -554,6 +554,181 @@ create view v1 as eval $select_view; eval $drop_view; +--echo # IN-subquery with VALUES structure(s) : simple case +let $query= +select * from t1 +where a in (values (1)); +let $subst_query= +select * from t1 +where a in (select * from (values (1)) as tvc_0); +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # IN-subquery with VALUES structure(s) : UNION with VALUES on the first place +let $query= +select * from t1 +where a in (values (1) union select 2); +let $subst_query= +select * from t1 +where a in (select * from (values (1)) as tvc_0 union + select 2); +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # IN-subquery with VALUES structure(s) : UNION with VALUES on the second place +let $query= +select * from t1 +where a in (select 2 union values (1)); +let $subst_query= +select * from t1 +where a in (select 2 union + select * from (values (1)) tvc_0); +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # IN-subquery with VALUES structure(s) : UNION ALL +let $query= +select * from t1 +where a in (values (1) union all select b from t1); +let $subst_query= +select * from t1 +where a in (select * from (values (1)) as tvc_0 union all + select b from t1); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # NOT IN subquery with VALUES structure(s) : simple case +let $query= +select * from t1 +where a not in (values (1),(2)); +let $subst_query= +select * from t1 +where a not in (select * from (values (1),(2)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # NOT IN subquery with VALUES structure(s) : UNION with VALUES on the first place +let $query= +select * from t1 +where a not in (values (1) union select 2); +let $subst_query= +select * from t1 +where a not in (select * from (values (1)) as tvc_0 union + select 2); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # NOT IN subquery with VALUES structure(s) : UNION with VALUES on the second place +let $query= +select * from t1 +where a not in (select 2 union values (1)); +let $subst_query= +select * from t1 +where a not in (select 2 union + select * from (values (1)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ANY-subquery with VALUES structure(s) : simple case +let $query= +select * from t1 +where a = any (values (1),(2)); +let $subst_query= +select * from t1 +where a = any (select * from (values (1),(2)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ANY-subquery with VALUES structure(s) : UNION with VALUES on the first place +let $query= +select * from t1 +where a = any (values (1) union select 2); +let $subst_query= +select * from t1 +where a = any (select * from (values (1)) as tvc_0 union + select 2); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ANY-subquery with VALUES structure(s) : UNION with VALUES on the second place +let $query= +select * from t1 +where a = any (select 2 union values (1)); +let $subst_query= +select * from t1 +where a = any (select 2 union + select * from (values (1)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ALL-subquery with VALUES structure(s) : simple case +let $query= +select * from t1 +where a = all (values (1)); +let $subst_query= +select * from t1 +where a = all (select * from (values (1)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ALL-subquery with VALUES structure(s) : UNION with VALUES on the first place +let $query= +select * from t1 +where a = all (values (1) union select 1); +let $subst_query= +select * from t1 +where a = all (select * from (values (1)) as tvc_0 union + select 1); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + +--echo # ALL-subquery with VALUES structure(s) : UNION with VALUES on the second place +let $query= +select * from t1 +where a = any (select 1 union values (1)); +let $subst_query= +select * from t1 +where a = any (select 1 union + select * from (values (1)) as tvc_0); + +eval $query; +eval $subst_query; +eval explain extended $query; +eval explain extended $subst_query; + --echo # prepare statement that uses VALUES structure(s): single VALUES structure prepare stmt1 from " @@ -856,21 +1031,16 @@ values (1,2); --error ER_WRONG_NUMBER_OF_VALUES_IN_TVC values (1,2),(3,4,5); ---echo # subquery that uses VALUES structure(s) ---error ER_TVC_IN_SUBQUERY -select * from t1 -where a in (values (1)); ---error ER_TVC_IN_SUBQUERY -select * from t1 -where a in (select 2 union values (1)); ---error ER_TVC_IN_SUBQUERY -select * from t1 -where a in (values (1) union select 2); - --echo # illegal parameter data types in TVC --error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION values (1,point(1,1)),(1,1); --error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION values (1,point(1,1)+1); +--echo # field reference in TVC +--error ER_FIELD_REFERENCE_IN_TVC +select * from (values (1), (b), (2)) as new_tvc; +--error ER_FIELD_REFERENCE_IN_TVC +select * from (values (1), (t1.b), (2)) as new_tvc; + drop table t1; \ No newline at end of file diff --git a/mysql-test/t/variables.test b/mysql-test/t/variables.test index 1ba20f0ac9e..8d831567252 100644 --- a/mysql-test/t/variables.test +++ b/mysql-test/t/variables.test @@ -1521,7 +1521,7 @@ set session rand_seed1=DEFAULT; # Bug #14211565 CRASH WHEN ATTEMPTING TO SET SYSTEM VARIABLE TO RESULT OF VALUES() # --error ER_BAD_FIELD_ERROR -set autocommit = values(v); +set autocommit = value(v); # # MDEV-6673 I_S.SESSION_VARIABLES shows global values diff --git a/sql/gen_lex_token.cc b/sql/gen_lex_token.cc index eefe9163819..a6ed8124867 100644 --- a/sql/gen_lex_token.cc +++ b/sql/gen_lex_token.cc @@ -132,6 +132,8 @@ void compute_tokens() set_token(WITH_CUBE_SYM, "WITH CUBE"); set_token(WITH_ROLLUP_SYM, "WITH ROLLUP"); + set_token(VALUES_IN_SYM, "VALUES IN"); + set_token(VALUES_LESS_SYM, "VALUES LESS"); set_token(NOT2_SYM, "!"); set_token(OR2_SYM, "|"); set_token(PARAM_MARKER, "?"); diff --git a/sql/item.cc b/sql/item.cc index f4236eee013..0719e72cd8f 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -5683,6 +5683,13 @@ bool Item_field::fix_fields(THD *thd, Item **reference) DBUG_ASSERT(fixed == 0); Field *from_field= (Field *)not_found_field; bool outer_fixed= false; + + if (thd->lex->current_select->in_tvc) + { + my_error(ER_FIELD_REFERENCE_IN_TVC, MYF(0), + full_name(), thd->where); + return(1); + } if (!field) // If field is not checked { @@ -9010,7 +9017,7 @@ bool Item_insert_value::fix_fields(THD *thd, Item **items) void Item_insert_value::print(String *str, enum_query_type query_type) { - str->append(STRING_WITH_LEN("values(")); + str->append(STRING_WITH_LEN("value(")); arg->print(str, query_type); str->append(')'); } diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index efa71a0e8af..eb7d1a97030 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -119,7 +119,7 @@ void Item_subselect::init(st_select_lex *select_lex, parsing_place= (outer_select->in_sum_expr ? NO_MATTER : outer_select->parsing_place); - if (unit->is_unit_op()) + if (unit->is_unit_op() && unit->first_select()->next_select()) engine= new subselect_union_engine(unit, result, this); else engine= new subselect_single_select_engine(select_lex, result, this); @@ -269,9 +269,7 @@ bool Item_subselect::fix_fields(THD *thd_param, Item **ref) { if (sl->tvc) { - my_error(ER_TVC_IN_SUBQUERY, MYF(0)); - res= 1; - goto end; + wrap_tvc_in_derived_table(thd, sl); } } diff --git a/sql/item_subselect.h b/sql/item_subselect.h index cb60b646979..cdba3cd737b 100644 --- a/sql/item_subselect.h +++ b/sql/item_subselect.h @@ -266,6 +266,7 @@ public: Item* build_clone(THD *thd, MEM_ROOT *mem_root) { return 0; } Item* get_copy(THD *thd, MEM_ROOT *mem_root) { return 0; } + bool wrap_tvc_in_derived_table(THD *thd, st_select_lex *tvc_sl); friend class select_result_interceptor; friend class Item_in_optimizer; @@ -874,6 +875,7 @@ public: virtual enum_engine_type engine_type() { return SINGLE_SELECT_ENGINE; } int get_identifier(); void force_reexecution(); + void change_select(st_select_lex *new_select) { select_lex= new_select; } friend class subselect_hash_sj_engine; friend class Item_in_subselect; diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 47a5478d635..27a70a7fe6d 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7492,5 +7492,5 @@ ER_SP_STACK_TRACE eng "At line %u in %s" ER_WRONG_NUMBER_OF_VALUES_IN_TVC eng "The used table value constructor has a different number of values" -ER_TVC_IN_SUBQUERY - eng "Table value constructor can't be used as specification of subquery isn't implemented yet" \ No newline at end of file +ER_FIELD_REFERENCE_IN_TVC + eng "Field reference '%-.192s' can't be used in table value constructor" \ No newline at end of file diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 08ad0245fb4..58bce754773 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1306,7 +1306,7 @@ int MYSQLlex(YYSTYPE *yylval, THD *thd) { Lex_input_stream *lip= & thd->m_parser_state->m_lip; int token; - + if (lip->lookahead_token >= 0) { /* @@ -1349,6 +1349,25 @@ int MYSQLlex(YYSTYPE *yylval, THD *thd) return WITH; } break; + case VALUES: + if (thd->lex->current_select->parsing_place == IN_UPDATE_ON_DUP_KEY + // || thd->lex->current_select->parsing_place == IN_PARTITIONING + ) + return VALUE_SYM; + token= lex_one_token(yylval, thd); + lip->add_digest_token(token, yylval); + switch(token) { + case LESS_SYM: + return VALUES_LESS_SYM; + case IN_SYM: + return VALUES_IN_SYM; + default: + lip->lookahead_yylval= lip->yylval; + lip->yylval= NULL; + lip->lookahead_token= token; + return VALUES; + } + break; default: break; } @@ -2225,6 +2244,7 @@ void st_select_lex::init_query() window_specs.empty(); window_funcs.empty(); tvc= 0; + in_tvc= false; } void st_select_lex::init_select() @@ -2266,6 +2286,7 @@ void st_select_lex::init_select() tvc= 0; in_funcs.empty(); curr_tvc_name= 0; + in_tvc= false; } /* @@ -2810,10 +2831,7 @@ void st_select_lex_unit::print(String *str, enum_query_type query_type) } if (sl->braces) str->append('('); - if (sl->tvc) - sl->tvc->print(thd, str, query_type); - else - sl->print(thd, str, query_type); + sl->print(thd, str, query_type); if (sl->braces) str->append(')'); } diff --git a/sql/sql_lex.h b/sql/sql_lex.h index ef5b6108044..d781e14a10a 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -1012,6 +1012,7 @@ public: thr_lock_type lock_type; table_value_constr *tvc; + bool in_tvc; void init_query(); void init_select(); diff --git a/sql/sql_priv.h b/sql/sql_priv.h index 67547f7a030..245eb7fbe3d 100644 --- a/sql/sql_priv.h +++ b/sql/sql_priv.h @@ -349,6 +349,8 @@ enum enum_parsing_place IN_ON, IN_GROUP_BY, IN_ORDER_BY, + IN_UPDATE_ON_DUP_KEY, + IN_PARTITIONING, PARSING_PLACE_SIZE /* always should be the last */ }; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 870c40d5b16..cf4fbce7e5a 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -25182,6 +25182,12 @@ void TABLE_LIST::print(THD *thd, table_map eliminated_tables, String *str, void st_select_lex::print(THD *thd, String *str, enum_query_type query_type) { DBUG_ASSERT(thd); + + if (tvc) + { + tvc->print(thd, str, query_type); + return; + } if ((query_type & QT_SHOW_SELECT_NUMBER) && thd->lex->all_selects_list && diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 0b1dd2f4408..94462e6ad01 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -195,6 +195,7 @@ bool table_value_constr::prepare(THD *thd, SELECT_LEX *sl, st_select_lex_unit *unit_arg) { DBUG_ENTER("table_value_constr::prepare"); + select_lex->in_tvc= true; List_iterator_fast li(lists_of_values); List_item *first_elem= li++; @@ -237,6 +238,7 @@ bool table_value_constr::prepare(THD *thd, SELECT_LEX *sl, if (result && result->prepare(sl->item_list, unit_arg)) DBUG_RETURN(true); + select_lex->in_tvc= false; DBUG_RETURN(false); } @@ -496,6 +498,94 @@ static bool create_tvc_name(THD *thd, st_select_lex *parent_select, } +bool Item_subselect::wrap_tvc_in_derived_table(THD *thd, + st_select_lex *tvc_sl) +{ + LEX *lex= thd->lex; + /* SELECT_LEX object where the transformation is performed */ + SELECT_LEX *parent_select= lex->current_select; + uint8 save_derived_tables= lex->derived_tables; + + Query_arena backup; + Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); + + /* + Create SELECT_LEX of the subquery SQ used in the result of transformation + */ + lex->current_select= tvc_sl; + if (mysql_new_select(lex, 0, NULL)) + goto err; + mysql_init_select(lex); + /* Create item list as '*' for the subquery SQ */ + Item *item; + SELECT_LEX *sq_select; // select for IN subquery; + sq_select= lex->current_select; + sq_select->linkage= tvc_sl->linkage; + sq_select->parsing_place= SELECT_LIST; + item= new (thd->mem_root) Item_field(thd, &sq_select->context, + NULL, NULL, &star_clex_str); + if (item == NULL || add_item_to_list(thd, item)) + goto err; + (sq_select->with_wild)++; + + /* Exclude SELECT with TVC */ + tvc_sl->exclude(); + /* + Create derived table DT that will wrap TVC in the result of transformation + */ + SELECT_LEX *tvc_select; // select for tvc + SELECT_LEX_UNIT *derived_unit; // unit for tvc_select + if (mysql_new_select(lex, 1, tvc_sl)) + goto err; + tvc_select= lex->current_select; + derived_unit= tvc_select->master_unit(); + tvc_select->linkage= DERIVED_TABLE_TYPE; + + lex->current_select= sq_select; + + /* + Create the name of the wrapping derived table and + add it to the FROM list of the subquery SQ + */ + Table_ident *ti; + LEX_CSTRING alias; + TABLE_LIST *derived_tab; + if (!(ti= new (thd->mem_root) Table_ident(derived_unit)) || + create_tvc_name(thd, parent_select, &alias)) + goto err; + if (!(derived_tab= + sq_select->add_table_to_list(thd, + ti, &alias, 0, + TL_READ, MDL_SHARED_READ))) + goto err; + sq_select->add_joined_table(derived_tab); + sq_select->add_where_field(derived_unit->first_select()); + sq_select->context.table_list= sq_select->table_list.first; + sq_select->context.first_name_resolution_table= sq_select->table_list.first; + sq_select->table_list.first->derived_type= DTYPE_TABLE | DTYPE_MATERIALIZE; + lex->derived_tables|= DERIVED_SUBQUERY; + + sq_select->where= 0; + sq_select->set_braces(false); + derived_unit->set_with_clause(0); + + if (engine->engine_type() == subselect_engine::SINGLE_SELECT_ENGINE) + ((subselect_single_select_engine *) engine)->change_select(sq_select); + + if (arena) + thd->restore_active_arena(arena, &backup); + lex->current_select= sq_select; + return false; + +err: + if (arena) + thd->restore_active_arena(arena, &backup); + lex->derived_tables= save_derived_tables; + lex->current_select= parent_select; + return true; +} + + /** @brief Transform IN predicate into IN subquery @@ -532,6 +622,7 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, if (!transform_into_subq) return this; + transform_into_subq= false; List values; @@ -540,6 +631,12 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, /* SELECT_LEX object where the transformation is performed */ SELECT_LEX *parent_select= lex->current_select; uint8 save_derived_tables= lex->derived_tables; + + for (uint i=1; i < arg_count; i++) + { + if (!args[i]->const_item()) + return this; + } Query_arena backup; Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index e0e09b0b3c4..13c7b38de2b 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1553,6 +1553,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token UTC_TIMESTAMP_SYM %token UTC_TIME_SYM %token VALUES /* SQL-2003-R */ +%token VALUES_IN_SYM +%token VALUES_LESS_SYM %token VALUE_SYM /* SQL-2003-R */ %token VARBINARY %token VARCHAR /* SQL-2003-R */ @@ -4938,8 +4940,15 @@ part_type_def: { Lex->part_info->part_type= RANGE_PARTITION; } | RANGE_SYM part_column_list { Lex->part_info->part_type= RANGE_PARTITION; } - | LIST_SYM part_func - { Lex->part_info->part_type= LIST_PARTITION; } + | LIST_SYM + { + Select->parsing_place= IN_PART_FUNC; + } + part_func + { + Lex->part_info->part_type= LIST_PARTITION; + Select->parsing_place= NO_MATTER; + } | LIST_SYM part_column_list { Lex->part_info->part_type= LIST_PARTITION; } ; @@ -5189,7 +5198,7 @@ opt_part_values: else part_info->part_type= HASH_PARTITION; } - | VALUES LESS_SYM THAN_SYM + | VALUES_LESS_SYM THAN_SYM { LEX *lex= Lex; partition_info *part_info= lex->part_info; @@ -5203,7 +5212,7 @@ opt_part_values: part_info->part_type= RANGE_PARTITION; } part_func_max {} - | VALUES IN_SYM + | VALUES_IN_SYM { LEX *lex= Lex; partition_info *part_info= lex->part_info; @@ -12675,7 +12684,14 @@ expr_or_default: opt_insert_update: /* empty */ | ON DUPLICATE_SYM { Lex->duplicates= DUP_UPDATE; } - KEY_SYM UPDATE_SYM insert_update_list + KEY_SYM UPDATE_SYM + { + Select->parsing_place= IN_UPDATE_ON_DUP_KEY; + } + insert_update_list + { + Select->parsing_place= NO_MATTER; + } ; /* Update rows in a table */ diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index aadf47235c4..324dc79f2ce 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -5555,6 +5555,6 @@ static Sys_var_ulong Sys_in_subquery_conversion_threshold( "The minimum number of scalar elements in the value list of" "IN predicate that triggers its conversion to IN subquery", SESSION_VAR(in_subquery_conversion_threshold), CMD_LINE(OPT_ARG), - VALID_RANGE(0, ULONG_MAX), DEFAULT(1000), BLOCK_SIZE(1)); + VALID_RANGE(0, ULONG_MAX), DEFAULT(10000), BLOCK_SIZE(1)); #endif //EMBEDDED_LIBRARY From 99d3f217eb157993b77348013146a828b2a7dc89 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Sat, 28 Oct 2017 21:54:22 +0200 Subject: [PATCH 016/138] Mistakes corrected, variable defined. --- sql/sql_lex.cc | 5 ++--- sql/sql_priv.h | 2 +- 2 files changed, 3 insertions(+), 4 deletions(-) diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 58bce754773..395f3c7e02a 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1350,9 +1350,8 @@ int MYSQLlex(YYSTYPE *yylval, THD *thd) } break; case VALUES: - if (thd->lex->current_select->parsing_place == IN_UPDATE_ON_DUP_KEY - // || thd->lex->current_select->parsing_place == IN_PARTITIONING - ) + if (thd->lex->current_select->parsing_place == IN_UPDATE_ON_DUP_KEY || + thd->lex->current_select->parsing_place == IN_PART_FUNC) return VALUE_SYM; token= lex_one_token(yylval, thd); lip->add_digest_token(token, yylval); diff --git a/sql/sql_priv.h b/sql/sql_priv.h index 245eb7fbe3d..e200a23b7c0 100644 --- a/sql/sql_priv.h +++ b/sql/sql_priv.h @@ -350,7 +350,7 @@ enum enum_parsing_place IN_GROUP_BY, IN_ORDER_BY, IN_UPDATE_ON_DUP_KEY, - IN_PARTITIONING, + IN_PART_FUNC, PARSING_PLACE_SIZE /* always should be the last */ }; From 43625a31cbb8b7cfec89f3c760967515e0b6849e Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Sun, 29 Oct 2017 21:09:07 +0200 Subject: [PATCH 017/138] Mistakes corrected. Test results corrected. --- mysql-test/r/default.result | 4 ++-- mysql-test/r/func_misc.result | 2 +- mysql-test/r/insert_update.result | 4 ++-- mysql-test/r/limit_rows_examined.result | 8 ++------ mysql-test/r/mysqld--help.result | 2 +- mysql-test/r/sp.result | 4 ++-- mysql-test/r/view.result | 10 +++++----- .../sys_vars/r/sysvars_server_notembedded.result | 14 ++++++++++++++ mysql-test/t/sp.test | 4 ++-- sql/sys_vars.cc | 2 +- 10 files changed, 32 insertions(+), 22 deletions(-) diff --git a/mysql-test/r/default.result b/mysql-test/r/default.result index c18db932afa..7313cb3e554 100644 --- a/mysql-test/r/default.result +++ b/mysql-test/r/default.result @@ -232,7 +232,7 @@ CREATE TABLE t1 (a INT DEFAULT 10); INSERT INTO t1 VALUES (11); CREATE VIEW v1 AS SELECT a AS a FROM t1; CREATE VIEW v2 AS SELECT DEFAULT(a) AS a FROM t1; -CREATE VIEW v3 AS SELECT VALUES(a) AS a FROM t1; +CREATE VIEW v3 AS SELECT VALUE(a) AS a FROM t1; SELECT * FROM v1; a 11 @@ -546,7 +546,7 @@ CREATE PROCEDURE p1() CREATE TABLE t1 (a INT DEFAULT par); CALL p1; ERROR 42S22: Unknown column 'par' in 'DEFAULT' DROP PROCEDURE p1; -CREATE TABLE t1 (a INT DEFAULT VALUES(a)); +CREATE TABLE t1 (a INT DEFAULT VALUE(a)); ERROR HY000: Function or expression 'values()' cannot be used in the DEFAULT clause of `a` CREATE TABLE t1 (a INT); CREATE TRIGGER tr1 AFTER INSERT ON t1 FOR EACH ROW CREATE TABLE t2 (a INT DEFAULT NEW.a); diff --git a/mysql-test/r/func_misc.result b/mysql-test/r/func_misc.result index 1006cdcea5c..8730d85771d 100644 --- a/mysql-test/r/func_misc.result +++ b/mysql-test/r/func_misc.result @@ -290,7 +290,7 @@ EXPLAIN EXTENDED SELECT VALUE(b) FROM v1; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 system NULL NULL NULL NULL 1 100.00 Warnings: -Note 1003 select values(10) AS `VALUE(b)` from dual +Note 1003 select value(10) AS `VALUE(b)` from dual drop view v1; drop table t1; End of 5.3 tests diff --git a/mysql-test/r/insert_update.result b/mysql-test/r/insert_update.result index ec87eeb85a6..68a1003ad85 100644 --- a/mysql-test/r/insert_update.result +++ b/mysql-test/r/insert_update.result @@ -60,12 +60,12 @@ explain extended SELECT *, VALUE(a) FROM t1; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 5 100.00 Warnings: -Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,values(`test`.`t1`.`a`) AS `VALUE(a)` from `test`.`t1` +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,value(`test`.`t1`.`a`) AS `VALUE(a)` from `test`.`t1` explain extended select * from t1 where value(a); id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 5 100.00 Using where Warnings: -Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where values(`test`.`t1`.`a`) +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where value(`test`.`t1`.`a`) DROP TABLE t1; create table t1(a int primary key, b int); insert into t1 values(1,1),(2,2),(3,3),(4,4),(5,5); diff --git a/mysql-test/r/limit_rows_examined.result b/mysql-test/r/limit_rows_examined.result index 3bc97859303..9c47e1f6ddf 100644 --- a/mysql-test/r/limit_rows_examined.result +++ b/mysql-test/r/limit_rows_examined.result @@ -417,20 +417,17 @@ select * from v1 LIMIT ROWS EXAMINED 17; c1 bb cc -dd Warnings: Warning 1931 Query execution was interrupted. The query examined at least 18 rows, which exceeds LIMIT ROWS EXAMINED (17). The query result may be incomplete select * from v1 LIMIT ROWS EXAMINED 16; c1 bb -cc Warnings: Warning 1931 Query execution was interrupted. The query examined at least 18 rows, which exceeds LIMIT ROWS EXAMINED (16). The query result may be incomplete select * from v1 LIMIT ROWS EXAMINED 11; c1 -bb Warnings: -Warning 1931 Query execution was interrupted. The query examined at least 12 rows, which exceeds LIMIT ROWS EXAMINED (11). The query result may be incomplete +Warning 1931 Query execution was interrupted. The query examined at least 14 rows, which exceeds LIMIT ROWS EXAMINED (11). The query result may be incomplete drop view v1; explain select * @@ -445,9 +442,8 @@ from (select * from t1 where c1 IN (select * from t2 where c2 > ' ' LIMIT ROWS EXAMINED 0)) as tmp LIMIT ROWS EXAMINED 11; c1 -bb Warnings: -Warning 1931 Query execution was interrupted. The query examined at least 12 rows, which exceeds LIMIT ROWS EXAMINED (11). The query result may be incomplete +Warning 1931 Query execution was interrupted. The query examined at least 14 rows, which exceeds LIMIT ROWS EXAMINED (11). The query result may be incomplete ========================================================================= Aggregation ========================================================================= diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index b3d8f413fea..c6a918d3129 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -288,7 +288,7 @@ The following options may be given as the first argument: argument to reset the list accumulated so far. --in-subquery-conversion-threshold[=#] The minimum number of scalar elements in the value list - ofIN predicate that triggers its conversion to IN + of IN predicate that triggers its conversion to IN subquery --init-connect=name Command(s) that are executed for each new connection (unless the user has SUPER privilege) diff --git a/mysql-test/r/sp.result b/mysql-test/r/sp.result index 641c756691e..2b24babbe41 100644 --- a/mysql-test/r/sp.result +++ b/mysql-test/r/sp.result @@ -4440,7 +4440,7 @@ create table t3 (id int not null primary key, county varchar(25))| insert into t3 (id, county) values (1, 'York')| create procedure bug15441(c varchar(25)) begin -update t3 set id=2, county=values(c); +update t3 set id=2, county=value(c); end| call bug15441('county')| ERROR 42S22: Unknown column 'c' in 'field list' @@ -4451,7 +4451,7 @@ declare c varchar(25) default "hello"; insert into t3 (id, county) values (1, county) on duplicate key update county= values(county); select * from t3; -update t3 set id=2, county=values(id); +update t3 set id=2, county=value(id); select * from t3; end| call bug15441('Yale')| diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index e200af46b87..bb3fd1a687d 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -5702,7 +5702,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 6 100.00 Using where Warnings: Note 1276 Field or reference 'test.t1.a' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,(/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) AS `c` from `test`.`t1` +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,<`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) AS `c` from `test`.`t1` select * from v1; a c 1 2 @@ -5719,7 +5719,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 6 100.00 Using where Warnings: Note 1276 Field or reference 'test.t1.a' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t1`.`a` AS `a`,(/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) AS `c` from `test`.`t2` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t2`.`a` +Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t1`.`a` AS `a`,<`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) AS `c` from `test`.`t2` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t2`.`a` select * from t2, v1 where t2.a=v1.a; a b a c 1 2 1 2 @@ -5738,7 +5738,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 6 100.00 Using where Warnings: Note 1276 Field or reference 'test.t1.a' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,(/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,<`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` select * from t1, v1 where t1.a=v1.a; a b a c 1 2 1 2 @@ -5757,7 +5757,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 6 100.00 Using where Warnings: Note 1276 Field or reference 'test.t1.a' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,(/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`b` = (/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,<`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`b` = <`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) select * from t1, v1 where t1.b=v1.c; a b a c 1 2 1 2 @@ -5775,7 +5775,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 3 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 6 100.00 Using where Warnings: Note 1276 Field or reference 'test.t1.a' of SELECT #3 was resolved in SELECT #2 -Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,(/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`) AS `c` from `test`.`t2` join `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t1`.`a` = `test`.`t2`.`a` +Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`a` AS `a`,<`test`.`t1`.`a`>((/* select#3 */ select max(`test`.`t2`.`b`) from `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a`)) AS `c` from `test`.`t2` join `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t1`.`a` = `test`.`t2`.`a` select * from t2, t1, v1 where t1.a=t2.a and t1.a=v1.a; a b a b a c 1 2 1 2 1 2 diff --git a/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result b/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result index 957485b4e4b..c7d47e4c23e 100644 --- a/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result +++ b/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result @@ -1465,6 +1465,20 @@ NUMERIC_BLOCK_SIZE 1 ENUM_VALUE_LIST NULL READ_ONLY NO COMMAND_LINE_ARGUMENT REQUIRED +VARIABLE_NAME IN_SUBQUERY_CONVERSION_THRESHOLD +SESSION_VALUE 10000 +GLOBAL_VALUE 10000 +GLOBAL_VALUE_ORIGIN COMPILE-TIME +DEFAULT_VALUE 10000 +VARIABLE_SCOPE SESSION +VARIABLE_TYPE BIGINT UNSIGNED +VARIABLE_COMMENT The minimum number of scalar elements in the value list of IN predicate that triggers its conversion to IN subquery +NUMERIC_MIN_VALUE 0 +NUMERIC_MAX_VALUE 18446744073709551615 +NUMERIC_BLOCK_SIZE 1 +ENUM_VALUE_LIST NULL +READ_ONLY NO +COMMAND_LINE_ARGUMENT OPTIONAL VARIABLE_NAME IN_TRANSACTION SESSION_VALUE 0 GLOBAL_VALUE NULL diff --git a/mysql-test/t/sp.test b/mysql-test/t/sp.test index 7eedc67acd9..eb0730c658f 100644 --- a/mysql-test/t/sp.test +++ b/mysql-test/t/sp.test @@ -5299,7 +5299,7 @@ insert into t3 (id, county) values (1, 'York')| create procedure bug15441(c varchar(25)) begin - update t3 set id=2, county=values(c); + update t3 set id=2, county=value(c); end| --error ER_BAD_FIELD_ERROR call bug15441('county')| @@ -5326,7 +5326,7 @@ begin on duplicate key update county= values(county); select * from t3; - update t3 set id=2, county=values(id); + update t3 set id=2, county=value(id); select * from t3; end| call bug15441('Yale')| diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 324dc79f2ce..e33d6c8c8e8 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -5552,7 +5552,7 @@ static Sys_var_mybool Sys_session_track_state_change( static Sys_var_ulong Sys_in_subquery_conversion_threshold( "in_subquery_conversion_threshold", - "The minimum number of scalar elements in the value list of" + "The minimum number of scalar elements in the value list of " "IN predicate that triggers its conversion to IN subquery", SESSION_VAR(in_subquery_conversion_threshold), CMD_LINE(OPT_ARG), VALID_RANGE(0, ULONG_MAX), DEFAULT(10000), BLOCK_SIZE(1)); From b5689c6c872dc73d55c8150bcdc221fd04647a04 Mon Sep 17 00:00:00 2001 From: Alexey Botchkov Date: Mon, 30 Oct 2017 14:59:43 +0400 Subject: [PATCH 018/138] Compiler warnings fixed. --- sql/item_jsonfunc.cc | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/sql/item_jsonfunc.cc b/sql/item_jsonfunc.cc index f7be5b68892..9493d75018d 100644 --- a/sql/item_jsonfunc.cc +++ b/sql/item_jsonfunc.cc @@ -1352,6 +1352,8 @@ longlong Item_func_json_contains_path::val_int() bzero(p_found, (arg_count-2) * sizeof(bool)); n_found= arg_count - 2; } + else + n_found= 0; /* Jost to prevent 'uninitialized value' warnings */ result= 0; while (json_get_path_next(&je, &p) == 0) @@ -2058,7 +2060,7 @@ String *Item_func_json_merge::val_str(String *str) { DBUG_ASSERT(fixed == 1); json_engine_t je1, je2; - String *js1= args[0]->val_json(&tmp_js1), *js2; + String *js1= args[0]->val_json(&tmp_js1), *js2=NULL; uint n_arg; if (args[0]->null_value) From 34737e0cee5cd101a23c19d1f30b872a45393382 Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Mon, 30 Oct 2017 13:16:15 +0200 Subject: [PATCH 019/138] trigger.result corrected --- mysql-test/r/trigger.result | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/mysql-test/r/trigger.result b/mysql-test/r/trigger.result index 77590d8508b..e180b3ebd3f 100644 --- a/mysql-test/r/trigger.result +++ b/mysql-test/r/trigger.result @@ -2125,7 +2125,7 @@ SHOW TRIGGERS IN db1; Trigger Event Table Statement Timing Created sql_mode Definer character_set_client collation_connection Database Collation trg1 INSERT t2 CREATE DEFINER=`root`@`localhost` TRIGGER trg1 BEFORE INSERT ON t2 FOR EACH ROW INSERTINTOt1 VALUES (1) BEFORE # STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION latin1 latin1_swedish_ci latin1_swedish_ci INSERT INTO t2 VALUES (1); -ERROR 42000: Trigger 'trg1' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'VALUES (1)' at line 1' +ERROR 42000: Trigger 'trg1' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near '(1)' at line 1' SELECT * FROM t1; b # Work around Bug#45235 From 2b332ab79527e9f7dd2560d3dcd53436282be95a Mon Sep 17 00:00:00 2001 From: Daniel Bartholomew Date: Mon, 30 Oct 2017 12:31:40 -0400 Subject: [PATCH 020/138] bump the VERSION --- VERSION | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/VERSION b/VERSION index 5a19a706528..24d355ca91e 100644 --- a/VERSION +++ b/VERSION @@ -1,3 +1,3 @@ MYSQL_VERSION_MAJOR=10 MYSQL_VERSION_MINOR=0 -MYSQL_VERSION_PATCH=33 +MYSQL_VERSION_PATCH=34 From d11001d11bd4657008afb5a901003689a23f768c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Fri, 27 Oct 2017 11:36:32 +0300 Subject: [PATCH 021/138] Backport MDEV-13890 from 10.2 (InnoDB/XtraDB shutdown failure) If InnoDB or XtraDB recovered committed transactions at server startup, but the processing of recovered transactions was prevented by innodb_read_only or by innodb_force_recovery, an assertion would fail at shutdown. This bug was originally reproduced when Mariabackup executed InnoDB shutdown after preparing (applying redo log into) a backup. trx_free_prepared(): Allow TRX_STATE_COMMITTED_IN_MEMORY. trx_undo_free_prepared(): Allow any undo log state. For transactions that were resurrected in TRX_STATE_COMMITTED_IN_MEMORY the undo log state would have been reset by trx_undo_set_state_at_finish(). --- storage/innobase/trx/trx0trx.cc | 5 +++-- storage/innobase/trx/trx0undo.cc | 14 +++++++++++++- storage/xtradb/trx/trx0trx.cc | 5 +++-- storage/xtradb/trx/trx0undo.cc | 14 +++++++++++++- 4 files changed, 32 insertions(+), 6 deletions(-) diff --git a/storage/innobase/trx/trx0trx.cc b/storage/innobase/trx/trx0trx.cc index c38c9bf7188..8974bfc2904 100644 --- a/storage/innobase/trx/trx0trx.cc +++ b/storage/innobase/trx/trx0trx.cc @@ -309,8 +309,9 @@ trx_free_prepared( trx_t* trx) /*!< in, own: trx object */ { ut_a(trx_state_eq(trx, TRX_STATE_PREPARED) - || (trx_state_eq(trx, TRX_STATE_ACTIVE) - && trx->is_recovered + || (trx->is_recovered + && (trx_state_eq(trx, TRX_STATE_ACTIVE) + || trx_state_eq(trx, TRX_STATE_COMMITTED_IN_MEMORY)) && (srv_read_only_mode || srv_force_recovery >= SRV_FORCE_NO_TRX_UNDO))); ut_a(trx->magic_n == TRX_MAGIC_N); diff --git a/storage/innobase/trx/trx0undo.cc b/storage/innobase/trx/trx0undo.cc index 220589dd9ff..1836d282cd4 100644 --- a/storage/innobase/trx/trx0undo.cc +++ b/storage/innobase/trx/trx0undo.cc @@ -1,7 +1,7 @@ /***************************************************************************** Copyright (c) 1996, 2016, Oracle and/or its affiliates. All Rights Reserved. -Copyright (c) 2014, 2017, MariaDB Corporation. All Rights Reserved. +Copyright (c) 2014, 2017, MariaDB Corporation. This program is free software; you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software @@ -2015,6 +2015,12 @@ trx_undo_free_prepared( switch (trx->update_undo->state) { case TRX_UNDO_PREPARED: break; + case TRX_UNDO_CACHED: + case TRX_UNDO_TO_FREE: + case TRX_UNDO_TO_PURGE: + ut_ad(trx_state_eq(trx, + TRX_STATE_COMMITTED_IN_MEMORY)); + /* fall through */ case TRX_UNDO_ACTIVE: /* lock_trx_release_locks() assigns trx->is_recovered=false */ @@ -2033,6 +2039,12 @@ trx_undo_free_prepared( switch (trx->insert_undo->state) { case TRX_UNDO_PREPARED: break; + case TRX_UNDO_CACHED: + case TRX_UNDO_TO_FREE: + case TRX_UNDO_TO_PURGE: + ut_ad(trx_state_eq(trx, + TRX_STATE_COMMITTED_IN_MEMORY)); + /* fall through */ case TRX_UNDO_ACTIVE: /* lock_trx_release_locks() assigns trx->is_recovered=false */ diff --git a/storage/xtradb/trx/trx0trx.cc b/storage/xtradb/trx/trx0trx.cc index d3b1f1da054..45578283235 100644 --- a/storage/xtradb/trx/trx0trx.cc +++ b/storage/xtradb/trx/trx0trx.cc @@ -475,8 +475,9 @@ trx_free_prepared( trx_t* trx) /*!< in, own: trx object */ { ut_a(trx_state_eq(trx, TRX_STATE_PREPARED) - || (trx_state_eq(trx, TRX_STATE_ACTIVE) - && trx->is_recovered + || (trx->is_recovered + && (trx_state_eq(trx, TRX_STATE_ACTIVE) + || trx_state_eq(trx, TRX_STATE_COMMITTED_IN_MEMORY)) && (srv_read_only_mode || srv_force_recovery >= SRV_FORCE_NO_TRX_UNDO))); ut_a(trx->magic_n == TRX_MAGIC_N); diff --git a/storage/xtradb/trx/trx0undo.cc b/storage/xtradb/trx/trx0undo.cc index 220589dd9ff..1836d282cd4 100644 --- a/storage/xtradb/trx/trx0undo.cc +++ b/storage/xtradb/trx/trx0undo.cc @@ -1,7 +1,7 @@ /***************************************************************************** Copyright (c) 1996, 2016, Oracle and/or its affiliates. All Rights Reserved. -Copyright (c) 2014, 2017, MariaDB Corporation. All Rights Reserved. +Copyright (c) 2014, 2017, MariaDB Corporation. This program is free software; you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software @@ -2015,6 +2015,12 @@ trx_undo_free_prepared( switch (trx->update_undo->state) { case TRX_UNDO_PREPARED: break; + case TRX_UNDO_CACHED: + case TRX_UNDO_TO_FREE: + case TRX_UNDO_TO_PURGE: + ut_ad(trx_state_eq(trx, + TRX_STATE_COMMITTED_IN_MEMORY)); + /* fall through */ case TRX_UNDO_ACTIVE: /* lock_trx_release_locks() assigns trx->is_recovered=false */ @@ -2033,6 +2039,12 @@ trx_undo_free_prepared( switch (trx->insert_undo->state) { case TRX_UNDO_PREPARED: break; + case TRX_UNDO_CACHED: + case TRX_UNDO_TO_FREE: + case TRX_UNDO_TO_PURGE: + ut_ad(trx_state_eq(trx, + TRX_STATE_COMMITTED_IN_MEMORY)); + /* fall through */ case TRX_UNDO_ACTIVE: /* lock_trx_release_locks() assigns trx->is_recovered=false */ From 52c3afd4ca83742667c24c6d0b7188b607e779eb Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Mon, 30 Oct 2017 18:57:44 +0200 Subject: [PATCH 022/138] Fix a type mismatch introduced by the merge commit e0a1c745ec3ed1ec6c0375a2a624697c29f480a6 --- sql/log_event.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/log_event.cc b/sql/log_event.cc index 24b7fe38b99..2a9e6493c5e 100644 --- a/sql/log_event.cc +++ b/sql/log_event.cc @@ -8673,7 +8673,7 @@ User_var_log_event(const char* buf, uint event_len, Old events will not have this extra byte, thence, we keep the flags set to UNDEF_F. */ - uint bytes_read= (uint)((val + val_len) - buf_start); + size_t bytes_read= ((val + val_len) - buf_start); if ((data_written - bytes_read) > 0) { flags= (uint) *(buf + UV_VAL_IS_NULL + UV_VAL_TYPE_SIZE + From 88edb1b3edcea0dad82659ca6622448e535a3fa6 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Mon, 30 Oct 2017 18:47:43 +0200 Subject: [PATCH 023/138] MDEV-14219 Allow online table rebuild when encryption or compression parameters change When MariaDB 10.1.0 introduced table options for encryption and compression, it unnecessarily changed ha_innobase::check_if_supported_inplace_alter() so that ALGORITHM=COPY is forced when these parameters differ. A better solution is to move the check to innobase_need_rebuild(). In that way, the ALGORITHM=INPLACE interface (yes, the syntax is very misleading) can be used for rebuilding the table much more efficiently, with merge sort, with no undo logging, and allowing concurrent DML operations. --- .../encryption/r/encryption_force.result | 4 +- .../encryption/r/filekeys_encfile.result | 2 +- .../encryption/r/filekeys_encfile_file.result | 2 +- .../r/innodb-encryption-alter.result | 5 +- .../suite/encryption/t/encryption_force.test | 6 +- .../suite/encryption/t/filekeys_goodtest.inc | 4 +- .../encryption/t/innodb-encryption-alter.test | 4 +- .../r/innodb-page_compression_tables.result | 5 +- .../suite/innodb/r/innodb-table-online.result | 6 +- .../t/innodb-page_compression_tables.test | 4 +- .../suite/innodb/t/innodb-table-online.test | 7 +- storage/innobase/handler/handler0alter.cc | 88 ++++++++++--------- storage/xtradb/handler/handler0alter.cc | 88 ++++++++++--------- 13 files changed, 116 insertions(+), 109 deletions(-) diff --git a/mysql-test/suite/encryption/r/encryption_force.result b/mysql-test/suite/encryption/r/encryption_force.result index de5f7da60a8..9d42b360e7c 100644 --- a/mysql-test/suite/encryption/r/encryption_force.result +++ b/mysql-test/suite/encryption/r/encryption_force.result @@ -34,11 +34,11 @@ t4 CREATE TABLE `t4` ( /*!50100 PARTITION BY HASH (a) PARTITIONS 2 */ alter table t1 encrypted=no; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'ENCRYPTED' alter table t2 encrypted=yes; alter table t3 encrypted=default; alter table t4 encrypted=no; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'ENCRYPTED' show create table t1; Table Create Table t1 CREATE TABLE `t1` ( diff --git a/mysql-test/suite/encryption/r/filekeys_encfile.result b/mysql-test/suite/encryption/r/filekeys_encfile.result index add6f312fda..6d5baa1b7ff 100644 --- a/mysql-test/suite/encryption/r/filekeys_encfile.result +++ b/mysql-test/suite/encryption/r/filekeys_encfile.result @@ -14,7 +14,7 @@ t1 CREATE TABLE `t1` ( `b` char(200) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=latin1 `encrypted`=yes `encryption_key_id`=2 alter table t1 encryption_key_id=3; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'ENCRYPTION_KEY_ID' show create table t1; Table Create Table t1 CREATE TABLE `t1` ( diff --git a/mysql-test/suite/encryption/r/filekeys_encfile_file.result b/mysql-test/suite/encryption/r/filekeys_encfile_file.result index add6f312fda..6d5baa1b7ff 100644 --- a/mysql-test/suite/encryption/r/filekeys_encfile_file.result +++ b/mysql-test/suite/encryption/r/filekeys_encfile_file.result @@ -14,7 +14,7 @@ t1 CREATE TABLE `t1` ( `b` char(200) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=latin1 `encrypted`=yes `encryption_key_id`=2 alter table t1 encryption_key_id=3; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'ENCRYPTION_KEY_ID' show create table t1; Table Create Table t1 CREATE TABLE `t1` ( diff --git a/mysql-test/suite/encryption/r/innodb-encryption-alter.result b/mysql-test/suite/encryption/r/innodb-encryption-alter.result index 5869c5d7000..9ff0f492034 100644 --- a/mysql-test/suite/encryption/r/innodb-encryption-alter.result +++ b/mysql-test/suite/encryption/r/innodb-encryption-alter.result @@ -43,11 +43,10 @@ CREATE TABLE t2 (pk INT PRIMARY KEY AUTO_INCREMENT, c VARCHAR(256)) ENGINE=INNOD Warnings: Warning 140 InnoDB: Ignored ENCRYPTION_KEY_ID 1 when encryption is disabled ALTER TABLE t1 ENCRYPTION_KEY_ID=99; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'ENCRYPTION_KEY_ID' SHOW WARNINGS; Level Code Message Warning 140 InnoDB: ENCRYPTION_KEY_ID 99 not available -Error 1005 Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") -Warning 1030 Got error 140 "Wrong create options" from storage engine InnoDB +Error 1478 Table storage engine 'InnoDB' does not support the create option 'ENCRYPTION_KEY_ID' set innodb_default_encryption_key_id = 1; drop table t1,t2; diff --git a/mysql-test/suite/encryption/t/encryption_force.test b/mysql-test/suite/encryption/t/encryption_force.test index 3e09dd91839..3c6f039184b 100644 --- a/mysql-test/suite/encryption/t/encryption_force.test +++ b/mysql-test/suite/encryption/t/encryption_force.test @@ -22,13 +22,11 @@ show create table t2; show create table t3; show create table t4; ---replace_regex /#sql-[0-9a-f_]*/#sql-temporary/ ---error ER_CANT_CREATE_TABLE +--error ER_ILLEGAL_HA_CREATE_OPTION alter table t1 encrypted=no; alter table t2 encrypted=yes; alter table t3 encrypted=default; ---replace_regex /#sql-[0-9a-f_]*/#sql-temporary/ ---error ER_CANT_CREATE_TABLE +--error ER_ILLEGAL_HA_CREATE_OPTION alter table t4 encrypted=no; show create table t1; diff --git a/mysql-test/suite/encryption/t/filekeys_goodtest.inc b/mysql-test/suite/encryption/t/filekeys_goodtest.inc index 146a570412c..5317eeb3d12 100644 --- a/mysql-test/suite/encryption/t/filekeys_goodtest.inc +++ b/mysql-test/suite/encryption/t/filekeys_goodtest.inc @@ -7,8 +7,7 @@ insert t1 values (12345, repeat('1234567890', 20)); alter table t1 encryption_key_id=2; show create table t1; ---replace_regex /#sql-[0-9a-f_]*/#sql-temporary/ ---error ER_CANT_CREATE_TABLE +--error ER_ILLEGAL_HA_CREATE_OPTION alter table t1 encryption_key_id=3; show create table t1; alter table t1 encryption_key_id=33; @@ -17,4 +16,3 @@ alter table t1 encryption_key_id=4; show create table t1; drop table t1; - diff --git a/mysql-test/suite/encryption/t/innodb-encryption-alter.test b/mysql-test/suite/encryption/t/innodb-encryption-alter.test index 316ece1c16b..9420fb74a4c 100644 --- a/mysql-test/suite/encryption/t/innodb-encryption-alter.test +++ b/mysql-test/suite/encryption/t/innodb-encryption-alter.test @@ -33,10 +33,8 @@ DROP TABLE t1; CREATE TABLE t1 (pk INT PRIMARY KEY AUTO_INCREMENT, c VARCHAR(256)) ENGINE=INNODB; SHOW CREATE TABLE t1; CREATE TABLE t2 (pk INT PRIMARY KEY AUTO_INCREMENT, c VARCHAR(256)) ENGINE=INNODB ENCRYPTED=NO ENCRYPTION_KEY_ID=1; ---replace_regex /#sql-[0-9a-f_]*/#sql-temporary/ ---error 1005 +--error ER_ILLEGAL_HA_CREATE_OPTION ALTER TABLE t1 ENCRYPTION_KEY_ID=99; ---replace_regex /#sql-[0-9a-f_]*/#sql-temporary/ SHOW WARNINGS; set innodb_default_encryption_key_id = 1; diff --git a/mysql-test/suite/innodb/r/innodb-page_compression_tables.result b/mysql-test/suite/innodb/r/innodb-page_compression_tables.result index 98de5db3c12..072f1d1e440 100644 --- a/mysql-test/suite/innodb/r/innodb-page_compression_tables.result +++ b/mysql-test/suite/innodb/r/innodb-page_compression_tables.result @@ -38,12 +38,11 @@ innodb_redundant CREATE TABLE `innodb_redundant` ( `b` char(200) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=REDUNDANT alter table innodb_redundant page_compressed=1; -ERROR HY000: Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") +ERROR HY000: Table storage engine 'InnoDB' does not support the create option 'PAGE_COMPRESSED' show warnings; Level Code Message Warning 140 InnoDB: PAGE_COMPRESSED table can't have ROW_TYPE=REDUNDANT -Error 1005 Can't create table `test`.`#sql-temporary` (errno: 140 "Wrong create options") -Warning 1030 Got error 140 "Wrong create options" from storage engine InnoDB +Error 1478 Table storage engine 'InnoDB' does not support the create option 'PAGE_COMPRESSED' show create table innodb_redundant; Table Create Table innodb_redundant CREATE TABLE `innodb_redundant` ( diff --git a/mysql-test/suite/innodb/r/innodb-table-online.result b/mysql-test/suite/innodb/r/innodb-table-online.result index cc4df79c10a..9b1097b3afa 100644 --- a/mysql-test/suite/innodb/r/innodb-table-online.result +++ b/mysql-test/suite/innodb/r/innodb-table-online.result @@ -3,6 +3,8 @@ call mtr.add_suppression("InnoDB: Error: table 'test/t1'"); call mtr.add_suppression("MySQL is trying to open a table handle but the .ibd file for"); SET @global_innodb_file_per_table_orig = @@global.innodb_file_per_table; SET GLOBAL innodb_file_per_table = on; +SET @file_format = @@GLOBAL.innodb_file_format; +SET GLOBAL innodb_file_format = Barracuda; CREATE TABLE t1 (c1 INT PRIMARY KEY, c2 INT NOT NULL, c3 CHAR(255) NOT NULL) ENGINE = InnoDB; INSERT INTO t1 VALUES (1,1,''), (2,2,''), (3,3,''), (4,4,''), (5,5,''); @@ -203,7 +205,8 @@ t1 CREATE TABLE `t1` ( ALTER TABLE t1 ROW_FORMAT=REDUNDANT; SET DEBUG_SYNC = 'row_log_table_apply1_before SIGNAL rebuilt2 WAIT_FOR dml2_done'; SET lock_wait_timeout = 10; -ALTER TABLE t1 ROW_FORMAT=COMPACT, ALGORITHM = INPLACE; +ALTER TABLE t1 ROW_FORMAT=COMPACT +PAGE_COMPRESSED = YES PAGE_COMPRESSION_LEVEL = 1, ALGORITHM = INPLACE; # session default INSERT INTO t1 SELECT 80 + c1, c2, c3 FROM t1; INSERT INTO t1 SELECT 160 + c1, c2, c3 FROM t1; @@ -438,5 +441,6 @@ SET DEBUG_SYNC = 'RESET'; SET GLOBAL innodb_monitor_disable = module_ddl; DROP TABLE t1; SET GLOBAL innodb_file_per_table = @global_innodb_file_per_table_orig; +SET GLOBAL innodb_file_format = @file_format; SET GLOBAL innodb_monitor_enable = default; SET GLOBAL innodb_monitor_disable = default; diff --git a/mysql-test/suite/innodb/t/innodb-page_compression_tables.test b/mysql-test/suite/innodb/t/innodb-page_compression_tables.test index 41d844d26b4..d8a85d7f273 100644 --- a/mysql-test/suite/innodb/t/innodb-page_compression_tables.test +++ b/mysql-test/suite/innodb/t/innodb-page_compression_tables.test @@ -32,10 +32,8 @@ create table innodb_redundant(c1 bigint not null, b char(200)) engine=innodb row show warnings; create table innodb_redundant(c1 bigint not null, b char(200)) engine=innodb row_format=redundant; show create table innodb_redundant; ---replace_regex /#sql-[0-9a-f_]*`/#sql-temporary`/ ---error 1005 +--error ER_ILLEGAL_HA_CREATE_OPTION alter table innodb_redundant page_compressed=1; ---replace_regex /#sql-[0-9a-f_]*`/#sql-temporary`/ show warnings; show create table innodb_redundant; alter table innodb_redundant row_format=compact page_compressed=1; diff --git a/mysql-test/suite/innodb/t/innodb-table-online.test b/mysql-test/suite/innodb/t/innodb-table-online.test index 938025359c5..b9c9dc085d6 100644 --- a/mysql-test/suite/innodb/t/innodb-table-online.test +++ b/mysql-test/suite/innodb/t/innodb-table-online.test @@ -14,6 +14,9 @@ call mtr.add_suppression("MySQL is trying to open a table handle but the .ibd fi # DISCARD TABLESPACE needs file-per-table SET @global_innodb_file_per_table_orig = @@global.innodb_file_per_table; SET GLOBAL innodb_file_per_table = on; +# PAGE_COMPRESSED needs innodb_file_format!=Antelope +SET @file_format = @@GLOBAL.innodb_file_format; +SET GLOBAL innodb_file_format = Barracuda; # Save the initial number of concurrent sessions. --source include/count_sessions.inc @@ -215,7 +218,8 @@ SET DEBUG_SYNC = 'row_log_table_apply1_before SIGNAL rebuilt2 WAIT_FOR dml2_done # Ensure that the ALTER TABLE will be executed even with some concurrent DML. SET lock_wait_timeout = 10; --send -ALTER TABLE t1 ROW_FORMAT=COMPACT, ALGORITHM = INPLACE; +ALTER TABLE t1 ROW_FORMAT=COMPACT +PAGE_COMPRESSED = YES PAGE_COMPRESSION_LEVEL = 1, ALGORITHM = INPLACE; # Generate some log (delete-mark, delete-unmark, insert etc.) # while the index creation is blocked. Some of this may run @@ -443,6 +447,7 @@ DROP TABLE t1; --source include/wait_until_count_sessions.inc SET GLOBAL innodb_file_per_table = @global_innodb_file_per_table_orig; +SET GLOBAL innodb_file_format = @file_format; --disable_warnings SET GLOBAL innodb_monitor_enable = default; SET GLOBAL innodb_monitor_disable = default; diff --git a/storage/innobase/handler/handler0alter.cc b/storage/innobase/handler/handler0alter.cc index a1f0fbb1e7e..bdc4987b5c9 100644 --- a/storage/innobase/handler/handler0alter.cc +++ b/storage/innobase/handler/handler0alter.cc @@ -208,32 +208,44 @@ innobase_fulltext_exist( return(false); } -/*******************************************************************//** -Determine if ALTER TABLE needs to rebuild the table. -@param ha_alter_info the DDL operation -@param altered_table MySQL original table +/** Determine if ALTER TABLE needs to rebuild the table. +@param ha_alter_info the DDL operation +@param table metadata before ALTER TABLE @return whether it is necessary to rebuild the table */ static MY_ATTRIBUTE((nonnull, warn_unused_result)) bool innobase_need_rebuild( -/*==================*/ const Alter_inplace_info* ha_alter_info, - const TABLE* altered_table) + const TABLE* table) { Alter_inplace_info::HA_ALTER_FLAGS alter_inplace_flags = - ha_alter_info->handler_flags & ~(INNOBASE_INPLACE_IGNORE); + ha_alter_info->handler_flags & ~INNOBASE_INPLACE_IGNORE; - if (alter_inplace_flags - == Alter_inplace_info::CHANGE_CREATE_OPTION + if (alter_inplace_flags & Alter_inplace_info::CHANGE_CREATE_OPTION) { + const ha_table_option_struct& alt_opt= + *ha_alter_info->create_info->option_struct; + const ha_table_option_struct& opt= *table->s->option_struct; + + if (alt_opt.page_compressed != opt.page_compressed + || alt_opt.page_compression_level + != opt.page_compression_level + || alt_opt.encryption != opt.encryption + || alt_opt.encryption_key_id != opt.encryption_key_id) { + return(true); + } + } + + if (alter_inplace_flags == Alter_inplace_info::CHANGE_CREATE_OPTION && !(ha_alter_info->create_info->used_fields & (HA_CREATE_USED_ROW_FORMAT | HA_CREATE_USED_KEY_BLOCK_SIZE))) { /* Any other CHANGE_CREATE_OPTION than changing - ROW_FORMAT or KEY_BLOCK_SIZE is ignored. */ + ROW_FORMAT or KEY_BLOCK_SIZE can be done without + rebuilding the table. */ return(false); } - return(!!(ha_alter_info->handler_flags & INNOBASE_ALTER_REBUILD)); + return(!!(alter_inplace_flags & INNOBASE_ALTER_REBUILD)); } /** Check if InnoDB supports a particular alter table in-place @@ -283,29 +295,6 @@ ha_innobase::check_if_supported_inplace_alter( update_thd(); trx_search_latch_release_if_reserved(prebuilt->trx); - /* Change on engine specific table options require rebuild of the - table */ - if (ha_alter_info->handler_flags - & Alter_inplace_info::CHANGE_CREATE_OPTION) { - ha_table_option_struct *new_options= ha_alter_info->create_info->option_struct; - ha_table_option_struct *old_options= table->s->option_struct; - - if (new_options->page_compressed != old_options->page_compressed || - new_options->page_compression_level != old_options->page_compression_level || - new_options->atomic_writes != old_options->atomic_writes) { - ha_alter_info->unsupported_reason = innobase_get_err_msg( - ER_ALTER_OPERATION_NOT_SUPPORTED_REASON); - DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); - } - - if (new_options->encryption != old_options->encryption || - new_options->encryption_key_id != old_options->encryption_key_id) { - ha_alter_info->unsupported_reason = innobase_get_err_msg( - ER_ALTER_OPERATION_NOT_SUPPORTED_REASON); - DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); - } - } - if (ha_alter_info->handler_flags & ~(INNOBASE_INPLACE_IGNORE | INNOBASE_ALTER_NOREBUILD @@ -584,7 +573,7 @@ ha_innobase::check_if_supported_inplace_alter( operation is possible. */ } else if (((ha_alter_info->handler_flags & Alter_inplace_info::ADD_PK_INDEX) - || innobase_need_rebuild(ha_alter_info, table)) + || innobase_need_rebuild(ha_alter_info, table)) && (innobase_fulltext_exist(altered_table))) { /* Refuse to rebuild the table online, if fulltext indexes are to survive the rebuild. */ @@ -2863,7 +2852,6 @@ prepare_inplace_alter_table_dict( to rebuild the table with a temporary name. */ if (new_clustered) { - fil_space_crypt_t* crypt_data; const char* new_table_name = dict_mem_create_temporary_tablename( ctx->heap, @@ -2874,13 +2862,29 @@ prepare_inplace_alter_table_dict( ulint key_id = FIL_DEFAULT_ENCRYPTION_KEY; fil_encryption_t mode = FIL_ENCRYPTION_DEFAULT; - fil_space_t* space = fil_space_acquire(ctx->prebuilt->table->space); - crypt_data = space->crypt_data; - fil_space_release(space); + if (fil_space_t* space + = fil_space_acquire(ctx->prebuilt->table->space)) { + if (const fil_space_crypt_t* crypt_data + = space->crypt_data) { + key_id = crypt_data->key_id; + mode = crypt_data->encryption; + } - if (crypt_data) { - key_id = crypt_data->key_id; - mode = crypt_data->encryption; + fil_space_release(space); + } + + if (ha_alter_info->handler_flags + & Alter_inplace_info::CHANGE_CREATE_OPTION) { + const ha_table_option_struct& alt_opt= + *ha_alter_info->create_info->option_struct; + const ha_table_option_struct& opt= + *old_table->s->option_struct; + if (alt_opt.encryption != opt.encryption + || alt_opt.encryption_key_id + != opt.encryption_key_id) { + key_id = alt_opt.encryption_key_id; + mode = fil_encryption_t(alt_opt.encryption); + } } if (innobase_check_foreigns( diff --git a/storage/xtradb/handler/handler0alter.cc b/storage/xtradb/handler/handler0alter.cc index 0842d11d178..b2f0d301815 100644 --- a/storage/xtradb/handler/handler0alter.cc +++ b/storage/xtradb/handler/handler0alter.cc @@ -212,32 +212,44 @@ innobase_fulltext_exist( return(false); } -/*******************************************************************//** -Determine if ALTER TABLE needs to rebuild the table. -@param ha_alter_info the DDL operation -@param altered_table MySQL original table +/** Determine if ALTER TABLE needs to rebuild the table. +@param ha_alter_info the DDL operation +@param table metadata before ALTER TABLE @return whether it is necessary to rebuild the table */ static MY_ATTRIBUTE((nonnull, warn_unused_result)) bool innobase_need_rebuild( -/*==================*/ const Alter_inplace_info* ha_alter_info, - const TABLE* altered_table) + const TABLE* table) { Alter_inplace_info::HA_ALTER_FLAGS alter_inplace_flags = - ha_alter_info->handler_flags & ~(INNOBASE_INPLACE_IGNORE); + ha_alter_info->handler_flags & ~INNOBASE_INPLACE_IGNORE; - if (alter_inplace_flags - == Alter_inplace_info::CHANGE_CREATE_OPTION + if (alter_inplace_flags & Alter_inplace_info::CHANGE_CREATE_OPTION) { + const ha_table_option_struct& alt_opt= + *ha_alter_info->create_info->option_struct; + const ha_table_option_struct& opt= *table->s->option_struct; + + if (alt_opt.page_compressed != opt.page_compressed + || alt_opt.page_compression_level + != opt.page_compression_level + || alt_opt.encryption != opt.encryption + || alt_opt.encryption_key_id != opt.encryption_key_id) { + return(true); + } + } + + if (alter_inplace_flags == Alter_inplace_info::CHANGE_CREATE_OPTION && !(ha_alter_info->create_info->used_fields & (HA_CREATE_USED_ROW_FORMAT | HA_CREATE_USED_KEY_BLOCK_SIZE))) { /* Any other CHANGE_CREATE_OPTION than changing - ROW_FORMAT or KEY_BLOCK_SIZE is ignored. */ + ROW_FORMAT or KEY_BLOCK_SIZE can be done without + rebuilding the table. */ return(false); } - return(!!(ha_alter_info->handler_flags & INNOBASE_ALTER_REBUILD)); + return(!!(alter_inplace_flags & INNOBASE_ALTER_REBUILD)); } /** Check if InnoDB supports a particular alter table in-place @@ -287,29 +299,6 @@ ha_innobase::check_if_supported_inplace_alter( update_thd(); trx_search_latch_release_if_reserved(prebuilt->trx); - /* Change on engine specific table options require rebuild of the - table */ - if (ha_alter_info->handler_flags - & Alter_inplace_info::CHANGE_CREATE_OPTION) { - ha_table_option_struct *new_options= ha_alter_info->create_info->option_struct; - ha_table_option_struct *old_options= table->s->option_struct; - - if (new_options->page_compressed != old_options->page_compressed || - new_options->page_compression_level != old_options->page_compression_level || - new_options->atomic_writes != old_options->atomic_writes) { - ha_alter_info->unsupported_reason = innobase_get_err_msg( - ER_ALTER_OPERATION_NOT_SUPPORTED_REASON); - DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); - } - - if (new_options->encryption != old_options->encryption || - new_options->encryption_key_id != old_options->encryption_key_id) { - ha_alter_info->unsupported_reason = innobase_get_err_msg( - ER_ALTER_OPERATION_NOT_SUPPORTED_REASON); - DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); - } - } - if (ha_alter_info->handler_flags & ~(INNOBASE_INPLACE_IGNORE | INNOBASE_ALTER_NOREBUILD @@ -589,7 +578,7 @@ ha_innobase::check_if_supported_inplace_alter( operation is possible. */ } else if (((ha_alter_info->handler_flags & Alter_inplace_info::ADD_PK_INDEX) - || innobase_need_rebuild(ha_alter_info, table)) + || innobase_need_rebuild(ha_alter_info, table)) && (innobase_fulltext_exist(altered_table))) { /* Refuse to rebuild the table online, if fulltext indexes are to survive the rebuild. */ @@ -2870,7 +2859,6 @@ prepare_inplace_alter_table_dict( to rebuild the table with a temporary name. */ if (new_clustered) { - fil_space_crypt_t* crypt_data; const char* new_table_name = dict_mem_create_temporary_tablename( ctx->heap, @@ -2881,13 +2869,29 @@ prepare_inplace_alter_table_dict( ulint key_id = FIL_DEFAULT_ENCRYPTION_KEY; fil_encryption_t mode = FIL_ENCRYPTION_DEFAULT; - fil_space_t* space = fil_space_acquire(ctx->prebuilt->table->space); - crypt_data = space->crypt_data; - fil_space_release(space); + if (fil_space_t* space + = fil_space_acquire(ctx->prebuilt->table->space)) { + if (const fil_space_crypt_t* crypt_data + = space->crypt_data) { + key_id = crypt_data->key_id; + mode = crypt_data->encryption; + } - if (crypt_data) { - key_id = crypt_data->key_id; - mode = crypt_data->encryption; + fil_space_release(space); + } + + if (ha_alter_info->handler_flags + & Alter_inplace_info::CHANGE_CREATE_OPTION) { + const ha_table_option_struct& alt_opt= + *ha_alter_info->create_info->option_struct; + const ha_table_option_struct& opt= + *old_table->s->option_struct; + if (alt_opt.encryption != opt.encryption + || alt_opt.encryption_key_id + != opt.encryption_key_id) { + key_id = alt_opt.encryption_key_id; + mode = fil_encryption_t(alt_opt.encryption); + } } if (innobase_check_foreigns( From a0743734c491422f605b6e8bd134498494fdbc39 Mon Sep 17 00:00:00 2001 From: Daniel Black Date: Mon, 30 Oct 2017 09:45:38 +1100 Subject: [PATCH 024/138] travis: osx - xcode 8.3 -> 9.1 Signed-off-by: Daniel Black --- .travis.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.travis.yml b/.travis.yml index f3253b5e1a9..8f21dc4d337 100644 --- a/.travis.yml +++ b/.travis.yml @@ -11,7 +11,7 @@ language: cpp os: - linux - osx -osx_image: xcode8.3 +osx_image: xcode9.1 compiler: - gcc - clang From 5d3ed9acdda80828f7f3be8f7322b3e8366eab5f Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Tue, 31 Oct 2017 13:00:20 +0400 Subject: [PATCH 025/138] (Part#2) MDEV-13049 Querying INFORMATION_SCHEMA becomes slow in MariaDB 10.1 This is a 10.3 specific part of MDEV-13049. It disables automatic sorting for "SELECT .. FROM INFORMATION_SCHEMA.{SCHEMATA|TABLES}" and adjusts the affected tests accordingly. --- mysql-test/include/mtr_check.sql | 6 ++- mysql-test/r/compound.result | 3 +- mysql-test/r/information_schema.result | 32 +++++++----- mysql-test/r/information_schema2.result | 2 +- mysql-test/r/information_schema_db.result | 4 +- mysql-test/r/information_schema_inno.result | 9 ++-- mysql-test/r/information_schema_part.result | 2 +- mysql-test/r/mysql_upgrade_noengine.result | 38 ++++++++------ mysql-test/r/partition_exchange.result | 24 ++++++--- mysql-test/r/sp.result | 2 +- mysql-test/r/subselect_sj.result | 2 +- .../funcs_1/datadict/is_key_column_usage.inc | 3 +- .../suite/funcs_1/datadict/is_schemata.inc | 3 +- .../suite/funcs_1/datadict/is_triggers.inc | 3 +- .../suite/funcs_1/datadict/is_views.inc | 6 ++- .../suite/funcs_1/r/is_basics_mixed.result | 6 ++- .../funcs_1/r/is_key_column_usage.result | 33 +++++++------ .../r/is_key_column_usage_embedded.result | 33 +++++++------ .../funcs_1/r/is_routines_embedded.result | 6 +-- mysql-test/suite/funcs_1/r/is_schemata.result | 3 +- .../funcs_1/r/is_schemata_embedded.result | 3 +- .../suite/funcs_1/r/is_statistics.result | 49 ++++++++++--------- .../funcs_1/r/is_table_constraints.result | 13 ++--- mysql-test/suite/funcs_1/r/is_triggers.result | 3 +- .../funcs_1/r/is_triggers_embedded.result | 3 +- mysql-test/suite/funcs_1/r/is_views.result | 6 ++- .../suite/funcs_1/r/is_views_embedded.result | 6 ++- .../suite/funcs_1/t/is_basics_mixed.test | 6 ++- mysql-test/suite/funcs_1/t/is_statistics.test | 3 +- .../suite/funcs_1/t/is_table_constraints.test | 4 +- .../suite/innodb_zip/r/innodb-zip.result | 18 +++---- mysql-test/suite/innodb_zip/t/innodb-zip.test | 2 +- .../suite/parts/t/partition_exch_qa_12.test | 1 + .../suite/perfschema/r/dml_handler.result | 9 ++-- .../perfschema/r/information_schema.result | 45 ++++++++++------- .../suite/perfschema/r/ortho_iter.result | 3 +- .../suite/perfschema/t/dml_handler.test | 3 +- .../perfschema/t/information_schema.test | 30 ++++++++---- mysql-test/suite/perfschema/t/ortho_iter.test | 3 +- .../roles/show_create_database-10463.result | 8 +-- .../roles/show_create_database-10463.test | 8 +-- mysql-test/suite/sql_sequence/other.result | 2 +- mysql-test/suite/sql_sequence/other.test | 2 +- mysql-test/t/compound.test | 3 +- mysql-test/t/create.test | 1 + mysql-test/t/gis.test | 1 + mysql-test/t/information_schema.test | 38 +++++++++----- mysql-test/t/information_schema2.test | 2 +- mysql-test/t/information_schema_db.test | 4 +- mysql-test/t/information_schema_inno.test | 6 ++- mysql-test/t/information_schema_part.test | 2 +- mysql-test/t/mysql_upgrade_noengine.test | 15 ++++-- mysql-test/t/partition_exchange.test | 24 ++++++--- mysql-test/t/sp.test | 2 + mysql-test/t/subselect_sj.test | 1 + mysql-test/t/type_datetime_hires.test | 1 + sql/handler.cc | 16 ++++++ sql/handler.h | 7 +++ sql/sql_show.cc | 13 ++++- .../connect/r/infoschema-9739.result | 4 +- .../connect/r/infoschema2-9739.result | 4 +- .../mysql-test/connect/t/infoschema-9739.test | 2 +- .../connect/t/infoschema2-9739.test | 2 +- .../mysql-test/rocksdb/t/statistics.test | 8 +++ 64 files changed, 380 insertions(+), 226 deletions(-) diff --git a/mysql-test/include/mtr_check.sql b/mysql-test/include/mtr_check.sql index 89f9f66ae1d..f2c0b70e192 100644 --- a/mysql-test/include/mtr_check.sql +++ b/mysql-test/include/mtr_check.sql @@ -39,12 +39,14 @@ BEGIN -- Dump all databases, there should be none -- except those that was created during bootstrap - SELECT * FROM INFORMATION_SCHEMA.SCHEMATA; + SELECT * FROM INFORMATION_SCHEMA.SCHEMATA ORDER BY BINARY SCHEMA_NAME; -- and the mtr_wsrep_notify schema which is populated by the std_data/wsrep_notify.sh script -- and the suite/galera/t/galera_var_notify_cmd.test -- and the wsrep_schema schema that may be created by Galera - SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema'); + SELECT * FROM INFORMATION_SCHEMA.SCHEMATA + WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema') + ORDER BY BINARY SCHEMA_NAME; -- The test database should not contain any tables SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES diff --git a/mysql-test/r/compound.result b/mysql-test/r/compound.result index 49ad567a055..a54faff4562 100644 --- a/mysql-test/r/compound.result +++ b/mysql-test/r/compound.result @@ -112,7 +112,8 @@ select @a| /**/ while (select count(*) from information_schema.tables where table_schema='test') do select concat('drop table ', table_name) into @a -from information_schema.tables where table_schema='test' limit 1; +from information_schema.tables where table_schema='test' + order by table_name limit 1; select @a as 'executing:'; prepare dt from @a; execute dt; diff --git a/mysql-test/r/information_schema.result b/mysql-test/r/information_schema.result index 1c073881a9d..23fbfad09d4 100644 --- a/mysql-test/r/information_schema.result +++ b/mysql-test/r/information_schema.result @@ -586,8 +586,8 @@ select s1 from t1 where s1 in (select version from information_schema.tables) union select version from information_schema.tables; s1 -11 10 +11 drop table t1; SHOW CREATE TABLE INFORMATION_SCHEMA.character_sets; Table Create Table @@ -770,11 +770,18 @@ table_name v2 v3 select column_name from information_schema.columns -where table_schema='test'; +where table_schema='test' and table_name='t4'; column_name f1 +select column_name from information_schema.columns +where table_schema='test' and table_name='v2'; +column_name Warnings: Warning 1356 View 'test.v2' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them +select column_name from information_schema.columns +where table_schema='test' and table_name='v3'; +column_name +Warnings: Warning 1356 View 'test.v3' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them select index_name from information_schema.statistics where table_schema='test'; index_name @@ -839,7 +846,8 @@ drop view a2, a1; drop table t_crashme; select table_schema,table_name, column_name from information_schema.columns -where data_type = 'longtext' and table_schema != 'performance_schema'; +where data_type = 'longtext' and table_schema != 'performance_schema' +order by binary table_name, ordinal_position; table_schema table_name column_name information_schema ALL_PLUGINS PLUGIN_DESCRIPTION information_schema COLUMNS COLUMN_DEFAULT @@ -860,7 +868,8 @@ information_schema TRIGGERS ACTION_CONDITION information_schema TRIGGERS ACTION_STATEMENT information_schema VIEWS VIEW_DEFINITION select table_name, column_name, data_type from information_schema.columns -where data_type = 'datetime' and table_name not like 'innodb_%'; +where data_type = 'datetime' and table_name not like 'innodb_%' +order by binary table_name, ordinal_position; table_name column_name data_type EVENTS EXECUTE_AT datetime EVENTS STARTS datetime @@ -1275,7 +1284,7 @@ sql security definer view v2 as select 1; connect con16681,localhost,mysqltest_1,,test; connection con16681; select * from information_schema.views -where table_name='v1' or table_name='v2'; +where table_name='v1' or table_name='v2' order by table_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME VIEW_DEFINITION CHECK_OPTION IS_UPDATABLE DEFINER SECURITY_TYPE CHARACTER_SET_CLIENT COLLATION_CONNECTION ALGORITHM def test v1 NONE YES root@localhost DEFINER latin1 latin1_swedish_ci UNDEFINED def test v2 select 1 AS `1` NONE NO mysqltest_1@localhost DEFINER latin1 latin1_swedish_ci UNDEFINED @@ -1288,7 +1297,7 @@ set @a:= '.'; create table t1(f1 char(5)); create table t2(f1 char(5)); select concat(@a, table_name), @a, table_name -from information_schema.tables where table_schema = 'test'; +from information_schema.tables where table_schema = 'test' order by table_name; concat(@a, table_name) @a table_name .t1 . t1 .t2 . t2 @@ -1375,7 +1384,8 @@ create table t2 (f1 int(11), f2 int(11)); select table_name from information_schema.tables where table_schema = 'test' and table_name not in (select table_name from information_schema.columns -where table_schema = 'test' and column_name = 'f3'); +where table_schema = 'test' and column_name = 'f3') +order by table_name; table_name t1 t2 @@ -1384,7 +1394,7 @@ create table t1(f1 int); create view v1 as select f1+1 as a from t1; create table t2 (f1 int, f2 int); create view v2 as select f1+1 as a, f2 as b from t2; -select table_name, is_updatable from information_schema.views; +select table_name, is_updatable from information_schema.views order by table_name; table_name is_updatable v1 NO v2 YES @@ -1843,12 +1853,12 @@ rename table t2 to t3; connection default; # These statements should not be blocked by pending lock requests select table_name, column_name, data_type from information_schema.columns -where table_schema = 'test' and table_name in ('t1', 't2'); +where table_schema = 'test' and table_name in ('t1', 't2') order by table_name, column_name; table_name column_name data_type t1 i int t2 j int select table_name, auto_increment from information_schema.tables -where table_schema = 'test' and table_name in ('t1', 't2'); +where table_schema = 'test' and table_name in ('t1', 't2') order by table_name; table_name auto_increment t1 NULL t2 1 @@ -1997,7 +2007,7 @@ connect con12828477_2, localhost, root,,mysqltest; # Wait while the above RENAME is blocked. # Issue query to I_S which will open 't0' and get # blocked on 't1' because of RENAME. -select table_name, auto_increment from information_schema.tables where table_schema='mysqltest'; +select table_name, auto_increment from information_schema.tables where table_schema='mysqltest' and table_name='t0' union select table_name, auto_increment from information_schema.tables where table_schema='mysqltest' and table_name<>'t0' order by table_name; connect con12828477_3, localhost, root,,mysqltest; # Wait while the above SELECT is blocked. # diff --git a/mysql-test/r/information_schema2.result b/mysql-test/r/information_schema2.result index 7e9bdd7088f..e23e81b885c 100644 --- a/mysql-test/r/information_schema2.result +++ b/mysql-test/r/information_schema2.result @@ -11,7 +11,7 @@ create table t2 (x int); create table t3 (x int); create table t4 AS select table_name from information_schema.TABLES where table_schema = database() and table_type = 'BASE TABLE' ; delete from t4 where table_name not in (select table_name from information_schema.TABLES where table_schema = database() and table_type = 'BASE TABLE'); -select * from t4; +select * from t4 order by table_name; table_name t1 t2 diff --git a/mysql-test/r/information_schema_db.result b/mysql-test/r/information_schema_db.result index ca1ab45b98b..45ade65c502 100644 --- a/mysql-test/r/information_schema_db.result +++ b/mysql-test/r/information_schema_db.result @@ -72,14 +72,14 @@ create function f2 () returns int return (select max(i) from t2); create view v2 as select f2(); drop table t2; select table_name, table_type, table_comment from information_schema.tables -where table_schema='test'; +where table_schema='test' order by table_name; table_name table_type table_comment t1 BASE TABLE v1 VIEW VIEW v2 VIEW VIEW drop table t1; select table_name, table_type, table_comment from information_schema.tables -where table_schema='test'; +where table_schema='test' order by table_name; table_name table_type table_comment v1 VIEW VIEW v2 VIEW VIEW diff --git a/mysql-test/r/information_schema_inno.result b/mysql-test/r/information_schema_inno.result index 7755d112f8e..d952e4372ca 100644 --- a/mysql-test/r/information_schema_inno.result +++ b/mysql-test/r/information_schema_inno.result @@ -10,18 +10,18 @@ TABLE_SCHEMA= "test"; CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_SCHEMA TABLE_NAME CONSTRAINT_TYPE def test PRIMARY test t1 PRIMARY KEY def test PRIMARY test t2 PRIMARY KEY +def test PRIMARY test t3 PRIMARY KEY def test t2_ibfk_1 test t2 FOREIGN KEY def test t2_ibfk_2 test t2 FOREIGN KEY -def test PRIMARY test t3 PRIMARY KEY def test t3_ibfk_1 test t3 FOREIGN KEY select * from information_schema.KEY_COLUMN_USAGE where TABLE_SCHEMA= "test"; CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME def test PRIMARY def test t1 id 1 NULL NULL NULL NULL def test PRIMARY def test t2 id 1 NULL NULL NULL NULL +def test PRIMARY def test t3 id 1 NULL NULL NULL NULL def test t2_ibfk_1 def test t2 t1_id 1 1 test t1 id def test t2_ibfk_2 def test t2 t1_id 1 1 test t1 id -def test PRIMARY def test t3 id 1 NULL NULL NULL NULL def test t3_ibfk_1 def test t3 id 1 1 test t2 t1_id def test t3_ibfk_1 def test t3 t2_id 2 2 test t2 id drop table t3, t2, t1; @@ -72,11 +72,12 @@ constraint fk_t1_1 foreign key (idtype) references `t-2` (id) use test; select referenced_table_schema, referenced_table_name from information_schema.key_column_usage -where constraint_schema = 'db-1'; +where constraint_schema = 'db-1' +order by referenced_table_schema, referenced_table_name; referenced_table_schema referenced_table_name NULL NULL -db-1 t-2 NULL NULL +db-1 t-2 drop database `db-1`; create table t1(id int primary key) engine = Innodb; create table t2(pid int, foreign key (pid) references t1(id)) engine = Innodb; diff --git a/mysql-test/r/information_schema_part.result b/mysql-test/r/information_schema_part.result index 081631a512f..4c0bb8908da 100644 --- a/mysql-test/r/information_schema_part.result +++ b/mysql-test/r/information_schema_part.result @@ -61,7 +61,7 @@ partition x2 values less than (5) ( subpartition x21 tablespace t1, subpartition x22 tablespace t2) ); -select * from information_schema.partitions where table_schema="test"; +select * from information_schema.partitions where table_schema="test" order by table_name, partition_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME PARTITION_NAME SUBPARTITION_NAME PARTITION_ORDINAL_POSITION SUBPARTITION_ORDINAL_POSITION PARTITION_METHOD SUBPARTITION_METHOD PARTITION_EXPRESSION SUBPARTITION_EXPRESSION PARTITION_DESCRIPTION TABLE_ROWS AVG_ROW_LENGTH DATA_LENGTH MAX_DATA_LENGTH INDEX_LENGTH DATA_FREE CREATE_TIME UPDATE_TIME CHECK_TIME CHECKSUM PARTITION_COMMENT NODEGROUP TABLESPACE_NAME def test t1 x1 x11 1 1 RANGE HASH `a` `a` + `b` 1 0 0 0 # 1024 0 # # NULL NULL default t1 def test t1 x1 x12 1 2 RANGE HASH `a` `a` + `b` 1 0 0 0 # 1024 0 # # NULL NULL default t2 diff --git a/mysql-test/r/mysql_upgrade_noengine.result b/mysql-test/r/mysql_upgrade_noengine.result index 09e705abb69..ef6657e0a0c 100644 --- a/mysql-test/r/mysql_upgrade_noengine.result +++ b/mysql-test/r/mysql_upgrade_noengine.result @@ -2,7 +2,7 @@ install soname 'ha_blackhole'; install soname 'ha_archive'; create table t1 (a int) engine=blackhole; create table t2 (a int) engine=archive; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; table_catalog def table_schema test table_name t1 @@ -12,6 +12,7 @@ row_format Fixed table_rows 0 data_length 0 table_comment +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; table_catalog def table_schema test table_name t2 @@ -24,7 +25,7 @@ table_comment flush tables; uninstall plugin blackhole; uninstall plugin archive; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; table_catalog def table_schema test table_name t1 @@ -34,6 +35,11 @@ row_format NULL table_rows NULL data_length NULL table_comment Unknown storage engine 'BLACKHOLE' +Warnings: +Level Warning +Code 1286 +Message Unknown storage engine 'BLACKHOLE' +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; table_catalog def table_schema test table_name t2 @@ -46,9 +52,6 @@ table_comment Unknown storage engine 'ARCHIVE' Warnings: Level Warning Code 1286 -Message Unknown storage engine 'BLACKHOLE' -Level Warning -Code 1286 Message Unknown storage engine 'ARCHIVE' Phase 1/7: Checking and upgrading mysql database Processing databases @@ -109,7 +112,7 @@ Error : Unknown storage engine 'ARCHIVE' error : Corrupt Phase 7/7: Running 'FLUSH PRIVILEGES' OK -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; table_catalog def table_schema test table_name t1 @@ -119,6 +122,11 @@ row_format NULL table_rows NULL data_length NULL table_comment Unknown storage engine 'BLACKHOLE' +Warnings: +Level Warning +Code 1286 +Message Unknown storage engine 'BLACKHOLE' +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; table_catalog def table_schema test table_name t2 @@ -131,9 +139,6 @@ table_comment Unknown storage engine 'ARCHIVE' Warnings: Level Warning Code 1286 -Message Unknown storage engine 'BLACKHOLE' -Level Warning -Code 1286 Message Unknown storage engine 'ARCHIVE' alter table mysql.user drop column default_role, drop column max_statement_time; Phase 1/7: Checking and upgrading mysql database @@ -195,7 +200,7 @@ Error : Unknown storage engine 'ARCHIVE' error : Corrupt Phase 7/7: Running 'FLUSH PRIVILEGES' OK -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; table_catalog def table_schema test table_name t1 @@ -205,6 +210,11 @@ row_format NULL table_rows NULL data_length NULL table_comment Unknown storage engine 'BLACKHOLE' +Warnings: +Level Warning +Code 1286 +Message Unknown storage engine 'BLACKHOLE' +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; table_catalog def table_schema test table_name t2 @@ -217,9 +227,6 @@ table_comment Unknown storage engine 'ARCHIVE' Warnings: Level Warning Code 1286 -Message Unknown storage engine 'BLACKHOLE' -Level Warning -Code 1286 Message Unknown storage engine 'ARCHIVE' alter table mysql.user drop column default_role, drop column max_statement_time; Phase 1/7: Checking and upgrading mysql database @@ -256,8 +263,8 @@ mysql.user OK Upgrading from a version before MariaDB-10.1 Phase 2/7: Installing used storage engines Checking for tables with unknown storage engine -installing plugin for 'blackhole' storage engine installing plugin for 'archive' storage engine +installing plugin for 'blackhole' storage engine Phase 3/7: Fixing views Phase 4/7: Running 'mysql_fix_privilege_tables' Phase 5/7: Fixing table and database names @@ -273,7 +280,7 @@ test.t1 OK test.t2 OK Phase 7/7: Running 'FLUSH PRIVILEGES' OK -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; table_catalog def table_schema test table_name t1 @@ -283,6 +290,7 @@ row_format Fixed table_rows 0 data_length 0 table_comment +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; table_catalog def table_schema test table_name t2 diff --git a/mysql-test/r/partition_exchange.result b/mysql-test/r/partition_exchange.result index f37ba183560..3bce5aec8e2 100644 --- a/mysql-test/r/partition_exchange.result +++ b/mysql-test/r/partition_exchange.result @@ -40,7 +40,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=COMPACT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -76,7 +77,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=COMPACT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -124,7 +126,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -184,7 +187,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=COMPACT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -244,7 +248,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -304,7 +309,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=REDUNDANT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -361,7 +367,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=REDUNDANT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB @@ -418,7 +425,8 @@ Create Table CREATE TABLE `t2` ( ) ENGINE=InnoDB DEFAULT CHARSET=latin1 ROW_FORMAT=REDUNDANT SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; TABLE_NAME t1 TABLE_TYPE BASE TABLE ENGINE InnoDB diff --git a/mysql-test/r/sp.result b/mysql-test/r/sp.result index cb2237699fb..e46f9b840ed 100644 --- a/mysql-test/r/sp.result +++ b/mysql-test/r/sp.result @@ -4810,8 +4810,8 @@ select routine_name,routine_schema from information_schema.routines where routine_schema like 'bug18344%'| routine_name routine_schema bug18344 bug18344_012345678901 -bug18344_2 bug18344_012345678901 bug18344 bug18344_0123456789012 +bug18344_2 bug18344_012345678901 bug18344_2 bug18344_0123456789012 drop database bug18344_012345678901| drop database bug18344_0123456789012| diff --git a/mysql-test/r/subselect_sj.result b/mysql-test/r/subselect_sj.result index a601dac5337..9631192da33 100644 --- a/mysql-test/r/subselect_sj.result +++ b/mysql-test/r/subselect_sj.result @@ -2800,8 +2800,8 @@ CREATE TABLE t1 (db VARCHAR(64) DEFAULT NULL); INSERT INTO t1 VALUES ('mysql'),('information_schema'); SELECT * FROM t1 WHERE db IN (SELECT `SCHEMA_NAME` FROM information_schema.SCHEMATA); db -mysql information_schema +mysql DROP TABLE t1; # # MDEV-5581: Server crashes in in JOIN::prepare on 2nd execution of PS with materialization+semijoin diff --git a/mysql-test/suite/funcs_1/datadict/is_key_column_usage.inc b/mysql-test/suite/funcs_1/datadict/is_key_column_usage.inc index 71030a2b1d8..ba390dfb4f5 100644 --- a/mysql-test/suite/funcs_1/datadict/is_key_column_usage.inc +++ b/mysql-test/suite/funcs_1/datadict/is_key_column_usage.inc @@ -75,7 +75,8 @@ eval SHOW COLUMNS FROM information_schema.$is_table; SELECT constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name, column_name FROM information_schema.key_column_usage -WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL; +WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL +ORDER BY BINARY table_schema, BINARY table_name, BINARY column_name, BINARY constraint_name; --echo ######################################################################################## diff --git a/mysql-test/suite/funcs_1/datadict/is_schemata.inc b/mysql-test/suite/funcs_1/datadict/is_schemata.inc index 18c759b91d1..0a3f0e726b3 100644 --- a/mysql-test/suite/funcs_1/datadict/is_schemata.inc +++ b/mysql-test/suite/funcs_1/datadict/is_schemata.inc @@ -59,7 +59,8 @@ eval SHOW COLUMNS FROM information_schema.$is_table; # Show that CATALOG_NAME and SQL_PATH are always NULL. SELECT catalog_name, schema_name, sql_path FROM information_schema.schemata -WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL; +WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL +ORDER BY schema_name; --echo ############################################################################### diff --git a/mysql-test/suite/funcs_1/datadict/is_triggers.inc b/mysql-test/suite/funcs_1/datadict/is_triggers.inc index b2ce1e2de00..3a449c93c4b 100644 --- a/mysql-test/suite/funcs_1/datadict/is_triggers.inc +++ b/mysql-test/suite/funcs_1/datadict/is_triggers.inc @@ -85,7 +85,8 @@ eval SHOW COLUMNS FROM information_schema.$is_table; SELECT * FROM information_schema.triggers WHERE trigger_catalog IS NOT NULL OR event_object_catalog IS NOT NULL OR action_condition IS NOT NULL OR action_reference_old_table IS NOT NULL - OR action_reference_new_table IS NOT NULL; + OR action_reference_new_table IS NOT NULL +ORDER BY trigger_schema, trigger_name; --echo ################################################################################## diff --git a/mysql-test/suite/funcs_1/datadict/is_views.inc b/mysql-test/suite/funcs_1/datadict/is_views.inc index bdba03f3632..cb3444e308a 100644 --- a/mysql-test/suite/funcs_1/datadict/is_views.inc +++ b/mysql-test/suite/funcs_1/datadict/is_views.inc @@ -159,12 +159,14 @@ CREATE USER 'testuser1'@'localhost'; # Check just created VIEW SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; CREATE VIEW test.t1_view AS SELECT DISTINCT f1 FROM test.t1_table; CREATE ALGORITHM=MERGE VIEW test.t1_view1 AS SELECT f1 FROM test.t1_table; CREATE ALGORITHM=TEMPTABLE VIEW test.t1_view2 AS SELECT f1 FROM test.t1_table; SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; DROP VIEW test.t1_view1; DROP VIEW test.t1_view2; diff --git a/mysql-test/suite/funcs_1/r/is_basics_mixed.result b/mysql-test/suite/funcs_1/r/is_basics_mixed.result index 2d14ada4f89..f9468648c61 100644 --- a/mysql-test/suite/funcs_1/r/is_basics_mixed.result +++ b/mysql-test/suite/funcs_1/r/is_basics_mixed.result @@ -341,12 +341,14 @@ CREATE VIEW db_datadict.v2 AS SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE FROM information_schema.tables WHERE table_schema = 'db_datadict'; SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE -FROM db_datadict.v2; +FROM db_datadict.v2 +ORDER BY TABLE_NAME; TABLE_SCHEMA TABLE_NAME TABLE_TYPE db_datadict t1 BASE TABLE db_datadict v2 VIEW SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE -FROM information_schema.tables WHERE table_schema = 'db_datadict'; +FROM information_schema.tables WHERE table_schema = 'db_datadict' +ORDER BY TABLE_NAME; TABLE_SCHEMA TABLE_NAME TABLE_TYPE db_datadict t1 BASE TABLE db_datadict v2 VIEW diff --git a/mysql-test/suite/funcs_1/r/is_key_column_usage.result b/mysql-test/suite/funcs_1/r/is_key_column_usage.result index fa2a738788e..933a8e537f2 100644 --- a/mysql-test/suite/funcs_1/r/is_key_column_usage.result +++ b/mysql-test/suite/funcs_1/r/is_key_column_usage.result @@ -73,18 +73,19 @@ REFERENCED_COLUMN_NAME varchar(64) YES NULL SELECT constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name, column_name FROM information_schema.key_column_usage -WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL; +WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL +ORDER BY BINARY table_schema, BINARY table_name, BINARY column_name, BINARY constraint_name; constraint_catalog constraint_schema constraint_name table_catalog table_schema table_name column_name +def mysql PRIMARY def mysql column_stats column_name def mysql PRIMARY def mysql column_stats db_name def mysql PRIMARY def mysql column_stats table_name -def mysql PRIMARY def mysql column_stats column_name -def mysql PRIMARY def mysql columns_priv Host -def mysql PRIMARY def mysql columns_priv Db -def mysql PRIMARY def mysql columns_priv User -def mysql PRIMARY def mysql columns_priv Table_name def mysql PRIMARY def mysql columns_priv Column_name -def mysql PRIMARY def mysql db Host +def mysql PRIMARY def mysql columns_priv Db +def mysql PRIMARY def mysql columns_priv Host +def mysql PRIMARY def mysql columns_priv Table_name +def mysql PRIMARY def mysql columns_priv User def mysql PRIMARY def mysql db Db +def mysql PRIMARY def mysql db Host def mysql PRIMARY def mysql db User def mysql PRIMARY def mysql event db def mysql PRIMARY def mysql event name @@ -99,41 +100,41 @@ def mysql PRIMARY def mysql help_relation help_keyword_id def mysql PRIMARY def mysql help_relation help_topic_id def mysql PRIMARY def mysql help_topic help_topic_id def mysql name def mysql help_topic name -def mysql PRIMARY def mysql host Host def mysql PRIMARY def mysql host Db +def mysql PRIMARY def mysql host Host def mysql PRIMARY def mysql index_stats db_name -def mysql PRIMARY def mysql index_stats table_name def mysql PRIMARY def mysql index_stats index_name def mysql PRIMARY def mysql index_stats prefix_arity +def mysql PRIMARY def mysql index_stats table_name def mysql PRIMARY def mysql innodb_index_stats database_name -def mysql PRIMARY def mysql innodb_index_stats table_name def mysql PRIMARY def mysql innodb_index_stats index_name def mysql PRIMARY def mysql innodb_index_stats stat_name +def mysql PRIMARY def mysql innodb_index_stats table_name def mysql PRIMARY def mysql innodb_table_stats database_name def mysql PRIMARY def mysql innodb_table_stats table_name def mysql PRIMARY def mysql plugin name def mysql PRIMARY def mysql proc db def mysql PRIMARY def mysql proc name def mysql PRIMARY def mysql proc type -def mysql PRIMARY def mysql procs_priv Host def mysql PRIMARY def mysql procs_priv Db -def mysql PRIMARY def mysql procs_priv User +def mysql PRIMARY def mysql procs_priv Host def mysql PRIMARY def mysql procs_priv Routine_name def mysql PRIMARY def mysql procs_priv Routine_type +def mysql PRIMARY def mysql procs_priv User def mysql PRIMARY def mysql proxies_priv Host -def mysql PRIMARY def mysql proxies_priv User def mysql PRIMARY def mysql proxies_priv Proxied_host def mysql PRIMARY def mysql proxies_priv Proxied_user +def mysql PRIMARY def mysql proxies_priv User def mysql Host def mysql roles_mapping Host -def mysql Host def mysql roles_mapping User def mysql Host def mysql roles_mapping Role +def mysql Host def mysql roles_mapping User def mysql PRIMARY def mysql servers Server_name def mysql PRIMARY def mysql table_stats db_name def mysql PRIMARY def mysql table_stats table_name -def mysql PRIMARY def mysql tables_priv Host def mysql PRIMARY def mysql tables_priv Db -def mysql PRIMARY def mysql tables_priv User +def mysql PRIMARY def mysql tables_priv Host def mysql PRIMARY def mysql tables_priv Table_name +def mysql PRIMARY def mysql tables_priv User def mysql PRIMARY def mysql time_zone Time_zone_id def mysql PRIMARY def mysql time_zone_leap_second Transition_time def mysql PRIMARY def mysql time_zone_name Name diff --git a/mysql-test/suite/funcs_1/r/is_key_column_usage_embedded.result b/mysql-test/suite/funcs_1/r/is_key_column_usage_embedded.result index 4a6114f3da3..62e566ca89f 100644 --- a/mysql-test/suite/funcs_1/r/is_key_column_usage_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_key_column_usage_embedded.result @@ -73,18 +73,19 @@ REFERENCED_COLUMN_NAME varchar(64) YES NULL SELECT constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name, column_name FROM information_schema.key_column_usage -WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL; +WHERE constraint_catalog IS NOT NULL OR table_catalog IS NOT NULL +ORDER BY BINARY table_schema, BINARY table_name, BINARY column_name, BINARY constraint_name; constraint_catalog constraint_schema constraint_name table_catalog table_schema table_name column_name +def mysql PRIMARY def mysql column_stats column_name def mysql PRIMARY def mysql column_stats db_name def mysql PRIMARY def mysql column_stats table_name -def mysql PRIMARY def mysql column_stats column_name -def mysql PRIMARY def mysql columns_priv Host -def mysql PRIMARY def mysql columns_priv Db -def mysql PRIMARY def mysql columns_priv User -def mysql PRIMARY def mysql columns_priv Table_name def mysql PRIMARY def mysql columns_priv Column_name -def mysql PRIMARY def mysql db Host +def mysql PRIMARY def mysql columns_priv Db +def mysql PRIMARY def mysql columns_priv Host +def mysql PRIMARY def mysql columns_priv Table_name +def mysql PRIMARY def mysql columns_priv User def mysql PRIMARY def mysql db Db +def mysql PRIMARY def mysql db Host def mysql PRIMARY def mysql db User def mysql PRIMARY def mysql event db def mysql PRIMARY def mysql event name @@ -99,41 +100,41 @@ def mysql PRIMARY def mysql help_relation help_keyword_id def mysql PRIMARY def mysql help_relation help_topic_id def mysql PRIMARY def mysql help_topic help_topic_id def mysql name def mysql help_topic name -def mysql PRIMARY def mysql host Host def mysql PRIMARY def mysql host Db +def mysql PRIMARY def mysql host Host def mysql PRIMARY def mysql index_stats db_name -def mysql PRIMARY def mysql index_stats table_name def mysql PRIMARY def mysql index_stats index_name def mysql PRIMARY def mysql index_stats prefix_arity +def mysql PRIMARY def mysql index_stats table_name def mysql PRIMARY def mysql innodb_index_stats database_name -def mysql PRIMARY def mysql innodb_index_stats table_name def mysql PRIMARY def mysql innodb_index_stats index_name def mysql PRIMARY def mysql innodb_index_stats stat_name +def mysql PRIMARY def mysql innodb_index_stats table_name def mysql PRIMARY def mysql innodb_table_stats database_name def mysql PRIMARY def mysql innodb_table_stats table_name def mysql PRIMARY def mysql plugin name def mysql PRIMARY def mysql proc db def mysql PRIMARY def mysql proc name def mysql PRIMARY def mysql proc type -def mysql PRIMARY def mysql procs_priv Host def mysql PRIMARY def mysql procs_priv Db -def mysql PRIMARY def mysql procs_priv User +def mysql PRIMARY def mysql procs_priv Host def mysql PRIMARY def mysql procs_priv Routine_name def mysql PRIMARY def mysql procs_priv Routine_type +def mysql PRIMARY def mysql procs_priv User def mysql PRIMARY def mysql proxies_priv Host -def mysql PRIMARY def mysql proxies_priv User def mysql PRIMARY def mysql proxies_priv Proxied_host def mysql PRIMARY def mysql proxies_priv Proxied_user +def mysql PRIMARY def mysql proxies_priv User def mysql Host def mysql roles_mapping Host -def mysql Host def mysql roles_mapping User def mysql Host def mysql roles_mapping Role +def mysql Host def mysql roles_mapping User def mysql PRIMARY def mysql servers Server_name def mysql PRIMARY def mysql table_stats db_name def mysql PRIMARY def mysql table_stats table_name -def mysql PRIMARY def mysql tables_priv Host def mysql PRIMARY def mysql tables_priv Db -def mysql PRIMARY def mysql tables_priv User +def mysql PRIMARY def mysql tables_priv Host def mysql PRIMARY def mysql tables_priv Table_name +def mysql PRIMARY def mysql tables_priv User def mysql PRIMARY def mysql time_zone Time_zone_id def mysql PRIMARY def mysql time_zone_leap_second Transition_time def mysql PRIMARY def mysql time_zone_name Name diff --git a/mysql-test/suite/funcs_1/r/is_routines_embedded.result b/mysql-test/suite/funcs_1/r/is_routines_embedded.result index a772ebaebda..8879efb21a5 100644 --- a/mysql-test/suite/funcs_1/r/is_routines_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_routines_embedded.result @@ -197,7 +197,7 @@ sp_6_408002_2 def db_datadict_2 sp_6_408002_2 PROCEDURE NULL NULL NULL NULL NUL SELECT * FROM db_datadict_2.res_6_408002_2; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost latin1 latin1_swedish_ci latin1_swedish_ci add_suppression def mtr add_suppression PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN INSERT INTO test_suppressions (pattern) VALUES (pattern); FLUSH NO_WRITE_TO_BINLOG TABLE test_suppressions; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci -check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema'); SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci +check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA ORDER BY BINARY SCHEMA_NAME; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema') ORDER BY BINARY SCHEMA_NAME; SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci check_warnings def mtr check_warnings PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN DECLARE `pos` bigint unsigned; SET SQL_LOG_BIN=0; UPDATE error_log el, global_suppressions gs SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP gs.pattern; UPDATE error_log el, test_suppressions ts SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP ts.pattern; SELECT COUNT(*) INTO @num_warnings FROM error_log WHERE suspicious=1; IF @num_warnings > 0 THEN SELECT line FROM error_log WHERE suspicious=1; SELECT 2 INTO result; ELSE SELECT 0 INTO RESULT; END IF; TRUNCATE test_suppressions; DROP TABLE error_log; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci connect testuser2, localhost, testuser2, , db_datadict; SELECT * FROM information_schema.routines; @@ -209,7 +209,7 @@ sp_6_408002_2 def db_datadict_2 sp_6_408002_2 PROCEDURE NULL NULL NULL NULL NUL SELECT * FROM db_datadict_2.res_6_408002_2; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost latin1 latin1_swedish_ci latin1_swedish_ci add_suppression def mtr add_suppression PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN INSERT INTO test_suppressions (pattern) VALUES (pattern); FLUSH NO_WRITE_TO_BINLOG TABLE test_suppressions; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci -check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema'); SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci +check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA ORDER BY BINARY SCHEMA_NAME; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema') ORDER BY BINARY SCHEMA_NAME; SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci check_warnings def mtr check_warnings PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN DECLARE `pos` bigint unsigned; SET SQL_LOG_BIN=0; UPDATE error_log el, global_suppressions gs SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP gs.pattern; UPDATE error_log el, test_suppressions ts SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP ts.pattern; SELECT COUNT(*) INTO @num_warnings FROM error_log WHERE suspicious=1; IF @num_warnings > 0 THEN SELECT line FROM error_log WHERE suspicious=1; SELECT 2 INTO result; ELSE SELECT 0 INTO RESULT; END IF; TRUNCATE test_suppressions; DROP TABLE error_log; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci connect testuser3, localhost, testuser3, , test; SELECT * FROM information_schema.routines; @@ -221,7 +221,7 @@ sp_6_408002_2 def db_datadict_2 sp_6_408002_2 PROCEDURE NULL NULL NULL NULL NUL SELECT * FROM db_datadict_2.res_6_408002_2; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost latin1 latin1_swedish_ci latin1_swedish_ci add_suppression def mtr add_suppression PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN INSERT INTO test_suppressions (pattern) VALUES (pattern); FLUSH NO_WRITE_TO_BINLOG TABLE test_suppressions; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci -check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema'); SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci +check_testcase def mtr check_testcase PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE variable_name NOT IN ('timestamp') AND variable_name not like "Last_IO_Err*" AND variable_name != 'INNODB_IBUF_MAX_SIZE' AND variable_name != 'INNODB_USE_NATIVE_AIO' AND variable_name != 'INNODB_BUFFER_POOL_LOAD_AT_STARTUP' AND variable_name not like 'GTID%POS' AND variable_name != 'GTID_BINLOG_STATE' ORDER BY variable_name; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA ORDER BY BINARY SCHEMA_NAME; SELECT * FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME NOT IN ('mtr_wsrep_notify', 'wsrep_schema') ORDER BY BINARY SCHEMA_NAME; SELECT table_name AS tables_in_test FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='test'; SELECT CONCAT(table_schema, '.', table_name) AS tables_in_mysql FROM INFORMATION_SCHEMA.TABLES WHERE table_schema='mysql' ORDER BY tables_in_mysql; SELECT CONCAT(table_schema, '.', table_name) AS columns_in_mysql, column_name, ordinal_position, column_default, is_nullable, data_type, character_maximum_length, character_octet_length, numeric_precision, numeric_scale, character_set_name, collation_name, column_type, column_key, extra, column_comment FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='mysql' ORDER BY columns_in_mysql; SELECT * FROM INFORMATION_SCHEMA.EVENTS; SELECT * FROM INFORMATION_SCHEMA.TRIGGERS WHERE TRIGGER_NAME NOT IN ('gs_insert', 'ts_insert'); SELECT * FROM INFORMATION_SCHEMA.ROUTINES; SHOW STATUS LIKE 'slave_open_temp_tables'; checksum table mysql.columns_priv, mysql.db, mysql.func, mysql.help_category, mysql.help_keyword, mysql.help_relation, mysql.host, mysql.plugin, mysql.proc, mysql.procs_priv, mysql.roles_mapping, mysql.tables_priv, mysql.time_zone, mysql.time_zone_leap_second, mysql.time_zone_name, mysql.time_zone_transition, mysql.time_zone_transition_type, mysql.user; SELECT * FROM INFORMATION_SCHEMA.PLUGINS; select * from information_schema.session_variables where variable_name = 'debug_sync'; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci check_warnings def mtr check_warnings PROCEDURE NULL NULL NULL NULL NULL NULL NULL NULL SQL BEGIN DECLARE `pos` bigint unsigned; SET SQL_LOG_BIN=0; UPDATE error_log el, global_suppressions gs SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP gs.pattern; UPDATE error_log el, test_suppressions ts SET suspicious=0 WHERE el.suspicious=1 AND el.line REGEXP ts.pattern; SELECT COUNT(*) INTO @num_warnings FROM error_log WHERE suspicious=1; IF @num_warnings > 0 THEN SELECT line FROM error_log WHERE suspicious=1; SELECT 2 INTO result; ELSE SELECT 0 INTO RESULT; END IF; TRUNCATE test_suppressions; DROP TABLE error_log; END NULL NULL SQL NO CONTAINS SQL NULL DEFINER YYYY-MM-DD hh:mm:ss YYYY-MM-DD hh:mm:ss root@localhost utf8 utf8_general_ci latin1_swedish_ci connection default; disconnect testuser1; diff --git a/mysql-test/suite/funcs_1/r/is_schemata.result b/mysql-test/suite/funcs_1/r/is_schemata.result index d0f2b734f7e..6db6ac8f150 100644 --- a/mysql-test/suite/funcs_1/r/is_schemata.result +++ b/mysql-test/suite/funcs_1/r/is_schemata.result @@ -51,7 +51,8 @@ DEFAULT_COLLATION_NAME varchar(32) NO SQL_PATH varchar(512) YES NULL SELECT catalog_name, schema_name, sql_path FROM information_schema.schemata -WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL; +WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL +ORDER BY schema_name; catalog_name schema_name sql_path def information_schema NULL def mtr NULL diff --git a/mysql-test/suite/funcs_1/r/is_schemata_embedded.result b/mysql-test/suite/funcs_1/r/is_schemata_embedded.result index 5f48c030c16..bc993e8dc9f 100644 --- a/mysql-test/suite/funcs_1/r/is_schemata_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_schemata_embedded.result @@ -51,7 +51,8 @@ DEFAULT_COLLATION_NAME varchar(32) NO SQL_PATH varchar(512) YES NULL SELECT catalog_name, schema_name, sql_path FROM information_schema.schemata -WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL; +WHERE catalog_name IS NOT NULL or sql_path IS NOT NULL +ORDER BY schema_name; catalog_name schema_name sql_path def information_schema NULL def mtr NULL diff --git a/mysql-test/suite/funcs_1/r/is_statistics.result b/mysql-test/suite/funcs_1/r/is_statistics.result index 749b09fa87d..a07d9d8d3c3 100644 --- a/mysql-test/suite/funcs_1/r/is_statistics.result +++ b/mysql-test/suite/funcs_1/r/is_statistics.result @@ -83,16 +83,17 @@ INDEX_TYPE varchar(16) NO COMMENT varchar(16) YES NULL INDEX_COMMENT varchar(1024) NO SELECT table_catalog, table_schema, table_name, index_schema, index_name -FROM information_schema.statistics WHERE table_catalog IS NOT NULL; +FROM information_schema.statistics WHERE table_catalog IS NOT NULL +ORDER BY table_schema, table_name, index_schema, index_name; table_catalog table_schema table_name index_schema index_name +def mysql columns_priv mysql PRIMARY +def mysql columns_priv mysql PRIMARY +def mysql columns_priv mysql PRIMARY +def mysql columns_priv mysql PRIMARY +def mysql columns_priv mysql PRIMARY def mysql column_stats mysql PRIMARY def mysql column_stats mysql PRIMARY def mysql column_stats mysql PRIMARY -def mysql columns_priv mysql PRIMARY -def mysql columns_priv mysql PRIMARY -def mysql columns_priv mysql PRIMARY -def mysql columns_priv mysql PRIMARY -def mysql columns_priv mysql PRIMARY def mysql db mysql PRIMARY def mysql db mysql PRIMARY def mysql db mysql PRIMARY @@ -102,14 +103,14 @@ def mysql event mysql PRIMARY def mysql func mysql PRIMARY def mysql gtid_slave_pos mysql PRIMARY def mysql gtid_slave_pos mysql PRIMARY -def mysql help_category mysql PRIMARY def mysql help_category mysql name -def mysql help_keyword mysql PRIMARY +def mysql help_category mysql PRIMARY def mysql help_keyword mysql name +def mysql help_keyword mysql PRIMARY def mysql help_relation mysql PRIMARY def mysql help_relation mysql PRIMARY -def mysql help_topic mysql PRIMARY def mysql help_topic mysql name +def mysql help_topic mysql PRIMARY def mysql host mysql PRIMARY def mysql host mysql PRIMARY def mysql index_stats mysql PRIMARY @@ -120,28 +121,28 @@ def mysql plugin mysql PRIMARY def mysql proc mysql PRIMARY def mysql proc mysql PRIMARY def mysql proc mysql PRIMARY -def mysql procs_priv mysql PRIMARY -def mysql procs_priv mysql PRIMARY -def mysql procs_priv mysql PRIMARY -def mysql procs_priv mysql PRIMARY -def mysql procs_priv mysql PRIMARY def mysql procs_priv mysql Grantor -def mysql proxies_priv mysql PRIMARY -def mysql proxies_priv mysql PRIMARY -def mysql proxies_priv mysql PRIMARY -def mysql proxies_priv mysql PRIMARY +def mysql procs_priv mysql PRIMARY +def mysql procs_priv mysql PRIMARY +def mysql procs_priv mysql PRIMARY +def mysql procs_priv mysql PRIMARY +def mysql procs_priv mysql PRIMARY def mysql proxies_priv mysql Grantor +def mysql proxies_priv mysql PRIMARY +def mysql proxies_priv mysql PRIMARY +def mysql proxies_priv mysql PRIMARY +def mysql proxies_priv mysql PRIMARY def mysql roles_mapping mysql Host def mysql roles_mapping mysql Host def mysql roles_mapping mysql Host def mysql servers mysql PRIMARY -def mysql table_stats mysql PRIMARY -def mysql table_stats mysql PRIMARY -def mysql tables_priv mysql PRIMARY -def mysql tables_priv mysql PRIMARY -def mysql tables_priv mysql PRIMARY -def mysql tables_priv mysql PRIMARY def mysql tables_priv mysql Grantor +def mysql tables_priv mysql PRIMARY +def mysql tables_priv mysql PRIMARY +def mysql tables_priv mysql PRIMARY +def mysql tables_priv mysql PRIMARY +def mysql table_stats mysql PRIMARY +def mysql table_stats mysql PRIMARY def mysql time_zone mysql PRIMARY def mysql time_zone_leap_second mysql PRIMARY def mysql time_zone_name mysql PRIMARY diff --git a/mysql-test/suite/funcs_1/r/is_table_constraints.result b/mysql-test/suite/funcs_1/r/is_table_constraints.result index 0553b4344c8..2f3afaaa0ad 100644 --- a/mysql-test/suite/funcs_1/r/is_table_constraints.result +++ b/mysql-test/suite/funcs_1/r/is_table_constraints.result @@ -55,21 +55,22 @@ CONSTRAINT_TYPE varchar(64) NO SELECT constraint_catalog, constraint_schema, constraint_name, table_schema, table_name FROM information_schema.table_constraints -WHERE constraint_catalog IS NOT NULL; +WHERE constraint_catalog IS NOT NULL +ORDER BY constraint_schema, table_name, constraint_name; constraint_catalog constraint_schema constraint_name table_schema table_name -def mysql PRIMARY mysql column_stats def mysql PRIMARY mysql columns_priv +def mysql PRIMARY mysql column_stats def mysql PRIMARY mysql db def mysql PRIMARY mysql event def mysql PRIMARY mysql func def mysql PRIMARY mysql gtid_slave_pos -def mysql PRIMARY mysql help_category def mysql name mysql help_category -def mysql PRIMARY mysql help_keyword +def mysql PRIMARY mysql help_category def mysql name mysql help_keyword +def mysql PRIMARY mysql help_keyword def mysql PRIMARY mysql help_relation -def mysql PRIMARY mysql help_topic def mysql name mysql help_topic +def mysql PRIMARY mysql help_topic def mysql PRIMARY mysql host def mysql PRIMARY mysql index_stats def mysql PRIMARY mysql innodb_index_stats @@ -80,8 +81,8 @@ def mysql PRIMARY mysql procs_priv def mysql PRIMARY mysql proxies_priv def mysql Host mysql roles_mapping def mysql PRIMARY mysql servers -def mysql PRIMARY mysql table_stats def mysql PRIMARY mysql tables_priv +def mysql PRIMARY mysql table_stats def mysql PRIMARY mysql time_zone def mysql PRIMARY mysql time_zone_leap_second def mysql PRIMARY mysql time_zone_name diff --git a/mysql-test/suite/funcs_1/r/is_triggers.result b/mysql-test/suite/funcs_1/r/is_triggers.result index 8e5842742cb..347bf02238a 100644 --- a/mysql-test/suite/funcs_1/r/is_triggers.result +++ b/mysql-test/suite/funcs_1/r/is_triggers.result @@ -104,7 +104,8 @@ DATABASE_COLLATION varchar(32) NO SELECT * FROM information_schema.triggers WHERE trigger_catalog IS NOT NULL OR event_object_catalog IS NOT NULL OR action_condition IS NOT NULL OR action_reference_old_table IS NOT NULL -OR action_reference_new_table IS NOT NULL; +OR action_reference_new_table IS NOT NULL +ORDER BY trigger_schema, trigger_name; TRIGGER_CATALOG TRIGGER_SCHEMA TRIGGER_NAME EVENT_MANIPULATION EVENT_OBJECT_CATALOG EVENT_OBJECT_SCHEMA EVENT_OBJECT_TABLE ACTION_ORDER ACTION_CONDITION ACTION_STATEMENT ACTION_ORIENTATION ACTION_TIMING ACTION_REFERENCE_OLD_TABLE ACTION_REFERENCE_NEW_TABLE ACTION_REFERENCE_OLD_ROW ACTION_REFERENCE_NEW_ROW CREATED SQL_MODE DEFINER CHARACTER_SET_CLIENT COLLATION_CONNECTION DATABASE_COLLATION def mtr gs_insert INSERT def mtr global_suppressions 1 NULL BEGIN DECLARE dummy INT; SELECT "" REGEXP NEW.pattern INTO dummy; END ROW BEFORE NULL NULL OLD NEW # root@localhost latin1 latin1_swedish_ci latin1_swedish_ci def mtr ts_insert INSERT def mtr test_suppressions 1 NULL BEGIN DECLARE dummy INT; SELECT "" REGEXP NEW.pattern INTO dummy; END ROW BEFORE NULL NULL OLD NEW # root@localhost latin1 latin1_swedish_ci latin1_swedish_ci diff --git a/mysql-test/suite/funcs_1/r/is_triggers_embedded.result b/mysql-test/suite/funcs_1/r/is_triggers_embedded.result index 55dc79e50d2..56c0e22d685 100644 --- a/mysql-test/suite/funcs_1/r/is_triggers_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_triggers_embedded.result @@ -104,7 +104,8 @@ DATABASE_COLLATION varchar(32) NO SELECT * FROM information_schema.triggers WHERE trigger_catalog IS NOT NULL OR event_object_catalog IS NOT NULL OR action_condition IS NOT NULL OR action_reference_old_table IS NOT NULL -OR action_reference_new_table IS NOT NULL; +OR action_reference_new_table IS NOT NULL +ORDER BY trigger_schema, trigger_name; TRIGGER_CATALOG TRIGGER_SCHEMA TRIGGER_NAME EVENT_MANIPULATION EVENT_OBJECT_CATALOG EVENT_OBJECT_SCHEMA EVENT_OBJECT_TABLE ACTION_ORDER ACTION_CONDITION ACTION_STATEMENT ACTION_ORIENTATION ACTION_TIMING ACTION_REFERENCE_OLD_TABLE ACTION_REFERENCE_NEW_TABLE ACTION_REFERENCE_OLD_ROW ACTION_REFERENCE_NEW_ROW CREATED SQL_MODE DEFINER CHARACTER_SET_CLIENT COLLATION_CONNECTION DATABASE_COLLATION def mtr gs_insert INSERT def mtr global_suppressions 1 NULL BEGIN DECLARE dummy INT; SELECT "" REGEXP NEW.pattern INTO dummy; END ROW BEFORE NULL NULL OLD NEW # root@localhost latin1 latin1_swedish_ci latin1_swedish_ci def mtr ts_insert INSERT def mtr test_suppressions 1 NULL BEGIN DECLARE dummy INT; SELECT "" REGEXP NEW.pattern INTO dummy; END ROW BEFORE NULL NULL OLD NEW # root@localhost latin1 latin1_swedish_ci latin1_swedish_ci diff --git a/mysql-test/suite/funcs_1/r/is_views.result b/mysql-test/suite/funcs_1/r/is_views.result index cc50b8033f0..62ec33c8340 100644 --- a/mysql-test/suite/funcs_1/r/is_views.result +++ b/mysql-test/suite/funcs_1/r/is_views.result @@ -128,13 +128,15 @@ ENGINE = ; DROP USER 'testuser1'@'localhost'; CREATE USER 'testuser1'@'localhost'; SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME VIEW_DEFINITION CHECK_OPTION IS_UPDATABLE DEFINER SECURITY_TYPE CHARACTER_SET_CLIENT COLLATION_CONNECTION ALGORITHM CREATE VIEW test.t1_view AS SELECT DISTINCT f1 FROM test.t1_table; CREATE ALGORITHM=MERGE VIEW test.t1_view1 AS SELECT f1 FROM test.t1_table; CREATE ALGORITHM=TEMPTABLE VIEW test.t1_view2 AS SELECT f1 FROM test.t1_table; SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME VIEW_DEFINITION CHECK_OPTION IS_UPDATABLE DEFINER SECURITY_TYPE CHARACTER_SET_CLIENT COLLATION_CONNECTION ALGORITHM def test t1_view select distinct `test`.`t1_table`.`f1` AS `f1` from `test`.`t1_table` NONE NO root@localhost DEFINER latin1 latin1_swedish_ci UNDEFINED def test t1_view1 select `test`.`t1_table`.`f1` AS `f1` from `test`.`t1_table` NONE YES root@localhost DEFINER latin1 latin1_swedish_ci MERGE diff --git a/mysql-test/suite/funcs_1/r/is_views_embedded.result b/mysql-test/suite/funcs_1/r/is_views_embedded.result index 1f2e23c3610..c382370e892 100644 --- a/mysql-test/suite/funcs_1/r/is_views_embedded.result +++ b/mysql-test/suite/funcs_1/r/is_views_embedded.result @@ -131,13 +131,15 @@ ENGINE = ; DROP USER 'testuser1'@'localhost'; CREATE USER 'testuser1'@'localhost'; SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME VIEW_DEFINITION CHECK_OPTION IS_UPDATABLE DEFINER SECURITY_TYPE CHARACTER_SET_CLIENT COLLATION_CONNECTION ALGORITHM CREATE VIEW test.t1_view AS SELECT DISTINCT f1 FROM test.t1_table; CREATE ALGORITHM=MERGE VIEW test.t1_view1 AS SELECT f1 FROM test.t1_table; CREATE ALGORITHM=TEMPTABLE VIEW test.t1_view2 AS SELECT f1 FROM test.t1_table; SELECT * FROM information_schema.views -WHERE table_name LIKE 't1_%'; +WHERE table_name LIKE 't1_%' +ORDER BY table_schema, table_name; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME VIEW_DEFINITION CHECK_OPTION IS_UPDATABLE DEFINER SECURITY_TYPE CHARACTER_SET_CLIENT COLLATION_CONNECTION ALGORITHM def test t1_view select distinct `test`.`t1_table`.`f1` AS `f1` from `test`.`t1_table` NONE NO root@localhost DEFINER latin1 latin1_swedish_ci UNDEFINED def test t1_view1 select `test`.`t1_table`.`f1` AS `f1` from `test`.`t1_table` NONE YES root@localhost DEFINER latin1 latin1_swedish_ci MERGE diff --git a/mysql-test/suite/funcs_1/t/is_basics_mixed.test b/mysql-test/suite/funcs_1/t/is_basics_mixed.test index c0b03a84478..901441a3557 100644 --- a/mysql-test/suite/funcs_1/t/is_basics_mixed.test +++ b/mysql-test/suite/funcs_1/t/is_basics_mixed.test @@ -286,9 +286,11 @@ CREATE VIEW db_datadict.v2 AS SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE FROM information_schema.tables WHERE table_schema = 'db_datadict'; SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE -FROM db_datadict.v2; +FROM db_datadict.v2 +ORDER BY TABLE_NAME; SELECT TABLE_SCHEMA,TABLE_NAME,TABLE_TYPE -FROM information_schema.tables WHERE table_schema = 'db_datadict'; +FROM information_schema.tables WHERE table_schema = 'db_datadict' +ORDER BY TABLE_NAME; GRANT SELECT ON db_datadict.v2 to testuser2@localhost; # --replace_result $MASTER_MYPORT MYSQL_PORT $MASTER_MYSOCK MYSQL_SOCK diff --git a/mysql-test/suite/funcs_1/t/is_statistics.test b/mysql-test/suite/funcs_1/t/is_statistics.test index 3cdc5568960..3d7f23a7b2c 100644 --- a/mysql-test/suite/funcs_1/t/is_statistics.test +++ b/mysql-test/suite/funcs_1/t/is_statistics.test @@ -78,7 +78,8 @@ eval SHOW COLUMNS FROM information_schema.$is_table; # Show that TABLE_CATALOG is always NULL. SELECT table_catalog, table_schema, table_name, index_schema, index_name -FROM information_schema.statistics WHERE table_catalog IS NOT NULL; +FROM information_schema.statistics WHERE table_catalog IS NOT NULL +ORDER BY table_schema, table_name, index_schema, index_name; --echo #################################################################################### diff --git a/mysql-test/suite/funcs_1/t/is_table_constraints.test b/mysql-test/suite/funcs_1/t/is_table_constraints.test index 96853edac2c..cf8d3fbf2d2 100644 --- a/mysql-test/suite/funcs_1/t/is_table_constraints.test +++ b/mysql-test/suite/funcs_1/t/is_table_constraints.test @@ -68,8 +68,8 @@ eval SHOW COLUMNS FROM information_schema.$is_table; SELECT constraint_catalog, constraint_schema, constraint_name, table_schema, table_name FROM information_schema.table_constraints -WHERE constraint_catalog IS NOT NULL; - +WHERE constraint_catalog IS NOT NULL +ORDER BY constraint_schema, table_name, constraint_name; --echo ######################################################################################### --echo # Testcase 3.2.7.2 + 3.2.7.3: INFORMATION_SCHEMA.TABLE_CONSTRAINTS accessible information diff --git a/mysql-test/suite/innodb_zip/r/innodb-zip.result b/mysql-test/suite/innodb_zip/r/innodb-zip.result index 92bdb863265..0da1d6bbe85 100644 --- a/mysql-test/suite/innodb_zip/r/innodb-zip.result +++ b/mysql-test/suite/innodb_zip/r/innodb-zip.result @@ -62,7 +62,7 @@ row_format=compressed; create table t14(a int primary key) engine=innodb key_block_size=9; Warnings: Warning 1478 InnoDB: ignoring KEY_BLOCK_SIZE=9. -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t0 Dynamic {valid} 0 mysqltest_innodb_zip t00 Dynamic {valid} 0 @@ -83,15 +83,15 @@ mysqltest_innodb_zip t9 Compact {valid} 0 drop table t0,t00,t2,t3,t4,t5,t6,t7,t8,t9,t10,t11,t12,t13,t14; alter table t1 key_block_size=0; alter table t1 row_format=dynamic; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Dynamic {valid} 0 alter table t1 row_format=compact; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Compact {valid} 0 alter table t1 row_format=redundant; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Redundant {valid} 0 drop table t1; @@ -125,7 +125,7 @@ mysqltest_innodb_zip.t1 analyze status OK analyze table t2; Table Op Msg_type Msg_text mysqltest_innodb_zip.t2 analyze status OK -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Compressed 2048 1024 mysqltest_innodb_zip t2 Dynamic {valid} 0 @@ -169,7 +169,7 @@ create table t8 (id int primary key) engine = innodb row_format = compressed; create table t9 (id int primary key) engine = innodb row_format = dynamic; create table t10(id int primary key) engine = innodb row_format = compact; create table t11(id int primary key) engine = innodb row_format = redundant; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Dynamic {valid} 0 mysqltest_innodb_zip t10 Compact {valid} 0 @@ -208,7 +208,7 @@ Error 1005 Can't create table `mysqltest_innodb_zip`.`t4` (errno: 140 "Wrong cre Warning 1030 Got error 140 "Wrong create options" from storage engine InnoDB create table t5 (id int primary key) engine = innodb key_block_size = 4 row_format = default; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t1 Compressed 4096 0 mysqltest_innodb_zip t5 Compressed 4096 0 @@ -240,7 +240,7 @@ Warning 1478 InnoDB: invalid KEY_BLOCK_SIZE = 9. Valid values are [1, 2, 4, 8, 1 Warning 1478 InnoDB: cannot specify ROW_FORMAT = DYNAMIC with KEY_BLOCK_SIZE. Error 1005 Can't create table `mysqltest_innodb_zip`.`t2` (errno: 140 "Wrong create options") Warning 1030 Got error 140 "Wrong create options" from storage engine InnoDB -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length set global innodb_file_per_table = off; create table t1 (id int primary key) engine = innodb key_block_size = 1; @@ -276,7 +276,7 @@ show warnings; Level Code Message create table t8 (id int primary key) engine = innodb row_format = compact; create table t9 (id int primary key) engine = innodb row_format = redundant; -SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql'; +SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name; table_schema table_name row_format data_length index_length mysqltest_innodb_zip t7 Dynamic {valid} 0 mysqltest_innodb_zip t8 Compact {valid} 0 diff --git a/mysql-test/suite/innodb_zip/t/innodb-zip.test b/mysql-test/suite/innodb_zip/t/innodb-zip.test index ff73c99f41d..9049b231191 100644 --- a/mysql-test/suite/innodb_zip/t/innodb-zip.test +++ b/mysql-test/suite/innodb_zip/t/innodb-zip.test @@ -9,7 +9,7 @@ SELECT table_name, row_format, data_length, index_length let $per_table=`select @@innodb_file_per_table`; SET @save_innodb_stats_on_metadata=@@global.innodb_stats_on_metadata; ---let $query_i_s = SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' +--let $query_i_s = SELECT table_schema, table_name, row_format, data_length, index_length FROM information_schema.tables WHERE engine='innodb' AND table_schema != 'mysql' order by table_name set session innodb_strict_mode=0; set global innodb_file_per_table=off; diff --git a/mysql-test/suite/parts/t/partition_exch_qa_12.test b/mysql-test/suite/parts/t/partition_exch_qa_12.test index 7e048f79017..80fd7ebba82 100644 --- a/mysql-test/suite/parts/t/partition_exch_qa_12.test +++ b/mysql-test/suite/parts/t/partition_exch_qa_12.test @@ -164,6 +164,7 @@ SELECT * FROM tsp_04; ALTER TABLE tp EXCHANGE PARTITION p0 WITH TABLE t_10; #--error ER_TABLES_DIFFERENT_METADATA #ALTER TABLE tp EXCHANGE PARTITION p0 WITH TABLE t_10 IGNORE; +--sorted_result SELECT TABLE_NAME, ROW_FORMAT FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('tp', 't_100'); ALTER TABLE tp EXCHANGE PARTITION p1 WITH TABLE t_100; diff --git a/mysql-test/suite/perfschema/r/dml_handler.result b/mysql-test/suite/perfschema/r/dml_handler.result index 2a1cc7035af..ab850aee933 100644 --- a/mysql-test/suite/perfschema/r/dml_handler.result +++ b/mysql-test/suite/perfschema/r/dml_handler.result @@ -3,7 +3,8 @@ CREATE TEMPORARY TABLE table_list (id INT AUTO_INCREMENT, PRIMARY KEY (id)) AS SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA='performance_schema'; +WHERE TABLE_SCHEMA='performance_schema' + ORDER BY TABLE_NAME; SELECT COUNT(*) FROM table_list INTO @table_count; # For each table in the performance schema, attempt HANDLER...OPEN, @@ -67,11 +68,11 @@ SELECT TABLE_NAME INTO @table_name FROM table_list WHERE id=34; HANDLER performance_schema.mutex_instances OPEN; ERROR HY000: Storage engine PERFORMANCE_SCHEMA of the table `performance_schema`.`mutex_instances` doesn't have this option SELECT TABLE_NAME INTO @table_name FROM table_list WHERE id=33; -HANDLER performance_schema.hosts OPEN; -ERROR HY000: Storage engine PERFORMANCE_SCHEMA of the table `performance_schema`.`hosts` doesn't have this option -SELECT TABLE_NAME INTO @table_name FROM table_list WHERE id=32; HANDLER performance_schema.host_cache OPEN; ERROR HY000: Storage engine PERFORMANCE_SCHEMA of the table `performance_schema`.`host_cache` doesn't have this option +SELECT TABLE_NAME INTO @table_name FROM table_list WHERE id=32; +HANDLER performance_schema.hosts OPEN; +ERROR HY000: Storage engine PERFORMANCE_SCHEMA of the table `performance_schema`.`hosts` doesn't have this option SELECT TABLE_NAME INTO @table_name FROM table_list WHERE id=31; HANDLER performance_schema.file_summary_by_instance OPEN; ERROR HY000: Storage engine PERFORMANCE_SCHEMA of the table `performance_schema`.`file_summary_by_instance` doesn't have this option diff --git a/mysql-test/suite/perfschema/r/information_schema.result b/mysql-test/suite/perfschema/r/information_schema.result index 5e5ce57fb2e..a684fd7b84e 100644 --- a/mysql-test/suite/perfschema/r/information_schema.result +++ b/mysql-test/suite/perfschema/r/information_schema.result @@ -1,6 +1,7 @@ select TABLE_SCHEMA, lower(TABLE_NAME), TABLE_CATALOG from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; TABLE_SCHEMA lower(TABLE_NAME) TABLE_CATALOG performance_schema accounts def performance_schema cond_instances def @@ -33,8 +34,8 @@ performance_schema events_waits_summary_global_by_event_name def performance_schema file_instances def performance_schema file_summary_by_event_name def performance_schema file_summary_by_instance def -performance_schema host_cache def performance_schema hosts def +performance_schema host_cache def performance_schema mutex_instances def performance_schema objects_summary_global_by_type def performance_schema performance_timers def @@ -56,7 +57,8 @@ performance_schema threads def performance_schema users def select lower(TABLE_NAME), TABLE_TYPE, ENGINE from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) TABLE_TYPE ENGINE accounts BASE TABLE PERFORMANCE_SCHEMA cond_instances BASE TABLE PERFORMANCE_SCHEMA @@ -89,8 +91,8 @@ events_waits_summary_global_by_event_name BASE TABLE PERFORMANCE_SCHEMA file_instances BASE TABLE PERFORMANCE_SCHEMA file_summary_by_event_name BASE TABLE PERFORMANCE_SCHEMA file_summary_by_instance BASE TABLE PERFORMANCE_SCHEMA -host_cache BASE TABLE PERFORMANCE_SCHEMA hosts BASE TABLE PERFORMANCE_SCHEMA +host_cache BASE TABLE PERFORMANCE_SCHEMA mutex_instances BASE TABLE PERFORMANCE_SCHEMA objects_summary_global_by_type BASE TABLE PERFORMANCE_SCHEMA performance_timers BASE TABLE PERFORMANCE_SCHEMA @@ -112,7 +114,8 @@ threads BASE TABLE PERFORMANCE_SCHEMA users BASE TABLE PERFORMANCE_SCHEMA select lower(TABLE_NAME), VERSION, ROW_FORMAT from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) VERSION ROW_FORMAT accounts 10 Fixed cond_instances 10 Dynamic @@ -145,8 +148,8 @@ events_waits_summary_global_by_event_name 10 Dynamic file_instances 10 Dynamic file_summary_by_event_name 10 Dynamic file_summary_by_instance 10 Dynamic -host_cache 10 Dynamic hosts 10 Fixed +host_cache 10 Dynamic mutex_instances 10 Dynamic objects_summary_global_by_type 10 Dynamic performance_timers 10 Fixed @@ -168,7 +171,8 @@ threads 10 Dynamic users 10 Fixed select lower(TABLE_NAME), TABLE_ROWS, AVG_ROW_LENGTH from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) TABLE_ROWS AVG_ROW_LENGTH accounts 1000 0 cond_instances 1000 0 @@ -201,8 +205,8 @@ events_waits_summary_global_by_event_name 1000 0 file_instances 1000 0 file_summary_by_event_name 1000 0 file_summary_by_instance 1000 0 -host_cache 1000 0 hosts 1000 0 +host_cache 1000 0 mutex_instances 1000 0 objects_summary_global_by_type 1000 0 performance_timers 5 0 @@ -224,7 +228,8 @@ threads 1000 0 users 1000 0 select lower(TABLE_NAME), DATA_LENGTH, MAX_DATA_LENGTH from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) DATA_LENGTH MAX_DATA_LENGTH accounts 0 0 cond_instances 0 0 @@ -257,8 +262,8 @@ events_waits_summary_global_by_event_name 0 0 file_instances 0 0 file_summary_by_event_name 0 0 file_summary_by_instance 0 0 -host_cache 0 0 hosts 0 0 +host_cache 0 0 mutex_instances 0 0 objects_summary_global_by_type 0 0 performance_timers 0 0 @@ -280,7 +285,8 @@ threads 0 0 users 0 0 select lower(TABLE_NAME), INDEX_LENGTH, DATA_FREE, AUTO_INCREMENT from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) INDEX_LENGTH DATA_FREE AUTO_INCREMENT accounts 0 0 NULL cond_instances 0 0 NULL @@ -313,8 +319,8 @@ events_waits_summary_global_by_event_name 0 0 NULL file_instances 0 0 NULL file_summary_by_event_name 0 0 NULL file_summary_by_instance 0 0 NULL -host_cache 0 0 NULL hosts 0 0 NULL +host_cache 0 0 NULL mutex_instances 0 0 NULL objects_summary_global_by_type 0 0 NULL performance_timers 0 0 NULL @@ -336,7 +342,8 @@ threads 0 0 NULL users 0 0 NULL select lower(TABLE_NAME), CREATE_TIME, UPDATE_TIME, CHECK_TIME from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) CREATE_TIME UPDATE_TIME CHECK_TIME accounts NULL NULL NULL cond_instances NULL NULL NULL @@ -369,8 +376,8 @@ events_waits_summary_global_by_event_name NULL NULL NULL file_instances NULL NULL NULL file_summary_by_event_name NULL NULL NULL file_summary_by_instance NULL NULL NULL -host_cache NULL NULL NULL hosts NULL NULL NULL +host_cache NULL NULL NULL mutex_instances NULL NULL NULL objects_summary_global_by_type NULL NULL NULL performance_timers NULL NULL NULL @@ -392,7 +399,8 @@ threads NULL NULL NULL users NULL NULL NULL select lower(TABLE_NAME), TABLE_COLLATION, CHECKSUM from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) TABLE_COLLATION CHECKSUM accounts utf8_general_ci NULL cond_instances utf8_general_ci NULL @@ -425,8 +433,8 @@ events_waits_summary_global_by_event_name utf8_general_ci NULL file_instances utf8_general_ci NULL file_summary_by_event_name utf8_general_ci NULL file_summary_by_instance utf8_general_ci NULL -host_cache utf8_general_ci NULL hosts utf8_general_ci NULL +host_cache utf8_general_ci NULL mutex_instances utf8_general_ci NULL objects_summary_global_by_type utf8_general_ci NULL performance_timers utf8_general_ci NULL @@ -448,7 +456,8 @@ threads utf8_general_ci NULL users utf8_general_ci NULL select lower(TABLE_NAME), TABLE_COMMENT from information_schema.tables -where TABLE_SCHEMA='performance_schema'; +where TABLE_SCHEMA='performance_schema' + order by table_name; lower(TABLE_NAME) TABLE_COMMENT accounts cond_instances @@ -481,8 +490,8 @@ events_waits_summary_global_by_event_name file_instances file_summary_by_event_name file_summary_by_instance -host_cache hosts +host_cache mutex_instances objects_summary_global_by_type performance_timers diff --git a/mysql-test/suite/perfschema/r/ortho_iter.result b/mysql-test/suite/perfschema/r/ortho_iter.result index bb572237483..f449aa97b40 100644 --- a/mysql-test/suite/perfschema/r/ortho_iter.result +++ b/mysql-test/suite/perfschema/r/ortho_iter.result @@ -21,7 +21,8 @@ declare debug integer default 0; declare pfs_cursor CURSOR FOR select table_name from information_schema.tables where table_schema= 'performance_schema' - and table_name like "events_%_by_event_name%"; + and table_name like "events_%_by_event_name%" + order by table_name; declare continue handler for sqlstate '02000' set done = 1; select (instr_name like "wait/%") or (instr_name like "idle/%") into is_wait; diff --git a/mysql-test/suite/perfschema/t/dml_handler.test b/mysql-test/suite/perfschema/t/dml_handler.test index db74c85350a..f12cc82f22f 100644 --- a/mysql-test/suite/perfschema/t/dml_handler.test +++ b/mysql-test/suite/perfschema/t/dml_handler.test @@ -18,7 +18,8 @@ CREATE TEMPORARY TABLE table_list (id INT AUTO_INCREMENT, PRIMARY KEY (id)) AS SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES - WHERE TABLE_SCHEMA='performance_schema'; + WHERE TABLE_SCHEMA='performance_schema' + ORDER BY TABLE_NAME; SELECT COUNT(*) FROM table_list INTO @table_count; diff --git a/mysql-test/suite/perfschema/t/information_schema.test b/mysql-test/suite/perfschema/t/information_schema.test index 24325710174..0152ef21905 100644 --- a/mysql-test/suite/perfschema/t/information_schema.test +++ b/mysql-test/suite/perfschema/t/information_schema.test @@ -11,42 +11,52 @@ select TABLE_SCHEMA, lower(TABLE_NAME), TABLE_CATALOG from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), TABLE_TYPE, ENGINE from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), VERSION, ROW_FORMAT from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), TABLE_ROWS, AVG_ROW_LENGTH from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), DATA_LENGTH, MAX_DATA_LENGTH from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), INDEX_LENGTH, DATA_FREE, AUTO_INCREMENT from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), CREATE_TIME, UPDATE_TIME, CHECK_TIME from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; select lower(TABLE_NAME), TABLE_COLLATION, CHECKSUM from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; # TABLESPACE_NAME does not exist in 5.4 # select lower(TABLE_NAME), CREATE_OPTIONS, TABLESPACE_NAME # from information_schema.tables -# where TABLE_SCHEMA='performance_schema'; +# where TABLE_SCHEMA='performance_schema' +# order by table_name; select lower(TABLE_NAME), TABLE_COMMENT from information_schema.tables - where TABLE_SCHEMA='performance_schema'; + where TABLE_SCHEMA='performance_schema' + order by table_name; diff --git a/mysql-test/suite/perfschema/t/ortho_iter.test b/mysql-test/suite/perfschema/t/ortho_iter.test index 0a90831ae70..f7e68538906 100644 --- a/mysql-test/suite/perfschema/t/ortho_iter.test +++ b/mysql-test/suite/perfschema/t/ortho_iter.test @@ -35,7 +35,8 @@ begin declare pfs_cursor CURSOR FOR select table_name from information_schema.tables where table_schema= 'performance_schema' - and table_name like "events_%_by_event_name%"; + and table_name like "events_%_by_event_name%" + order by table_name; declare continue handler for sqlstate '02000' set done = 1; diff --git a/mysql-test/suite/roles/show_create_database-10463.result b/mysql-test/suite/roles/show_create_database-10463.result index a9b376a891f..7bebc954840 100644 --- a/mysql-test/suite/roles/show_create_database-10463.result +++ b/mysql-test/suite/roles/show_create_database-10463.result @@ -16,7 +16,7 @@ test show create database db; ERROR 42000: Access denied for user 'beep'@'localhost' to database 'db' select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; table_schema table_name set role r1; show databases; @@ -28,7 +28,7 @@ show create database db; Database Create Database db CREATE DATABASE `db` /*!40100 DEFAULT CHARACTER SET latin1 */ select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; table_schema table_name db t1 db t2 @@ -45,7 +45,7 @@ test show create database db; ERROR 42000: Access denied for user 'beep2'@'localhost' to database 'db' select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; table_schema table_name set role r2; show databases; @@ -57,7 +57,7 @@ show create database db; Database Create Database db CREATE DATABASE `db` /*!40100 DEFAULT CHARACTER SET latin1 */ select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; table_schema table_name db t1 db t2 diff --git a/mysql-test/suite/roles/show_create_database-10463.test b/mysql-test/suite/roles/show_create_database-10463.test index 2d921629c10..6278cc71c02 100644 --- a/mysql-test/suite/roles/show_create_database-10463.test +++ b/mysql-test/suite/roles/show_create_database-10463.test @@ -16,13 +16,13 @@ show databases; --error ER_DBACCESS_DENIED_ERROR show create database db; select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; set role r1; show databases; show create database db; select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; connection default; @@ -36,14 +36,14 @@ show databases; --error ER_DBACCESS_DENIED_ERROR show create database db; select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; set role r2; show databases; show create database db; select table_schema, table_name from information_schema.tables -where table_schema = 'db'; +where table_schema = 'db' order by table_name; connection default; diff --git a/mysql-test/suite/sql_sequence/other.result b/mysql-test/suite/sql_sequence/other.result index 190886ab68f..87c36394975 100644 --- a/mysql-test/suite/sql_sequence/other.result +++ b/mysql-test/suite/sql_sequence/other.result @@ -93,7 +93,7 @@ Tables_in_test Table_type s1 SEQUENCE t1 BASE TABLE v1 VIEW -SELECT TABLE_TYPE,ENGINE FROM INFORMATION_SCHEMA.TABLES where table_schema="test"; +SELECT TABLE_TYPE,ENGINE FROM INFORMATION_SCHEMA.TABLES where table_schema="test" ORDER BY TABLE_NAME; TABLE_TYPE ENGINE SEQUENCE MyISAM BASE TABLE MyISAM diff --git a/mysql-test/suite/sql_sequence/other.test b/mysql-test/suite/sql_sequence/other.test index d816ec7c108..edd4cc7acc7 100644 --- a/mysql-test/suite/sql_sequence/other.test +++ b/mysql-test/suite/sql_sequence/other.test @@ -74,7 +74,7 @@ create sequence s1; create table t1 (a int); create view v1 as select * from s1; show full tables; -SELECT TABLE_TYPE,ENGINE FROM INFORMATION_SCHEMA.TABLES where table_schema="test"; +SELECT TABLE_TYPE,ENGINE FROM INFORMATION_SCHEMA.TABLES where table_schema="test" ORDER BY TABLE_NAME; drop table t1,s1; drop view v1; diff --git a/mysql-test/t/compound.test b/mysql-test/t/compound.test index cabdf96e00e..94a6c18b2f5 100644 --- a/mysql-test/t/compound.test +++ b/mysql-test/t/compound.test @@ -106,7 +106,8 @@ select @a| /**/ while (select count(*) from information_schema.tables where table_schema='test') do select concat('drop table ', table_name) into @a - from information_schema.tables where table_schema='test' limit 1; + from information_schema.tables where table_schema='test' + order by table_name limit 1; select @a as 'executing:'; prepare dt from @a; execute dt; diff --git a/mysql-test/t/create.test b/mysql-test/t/create.test index bd89f220060..a8c4eff7365 100644 --- a/mysql-test/t/create.test +++ b/mysql-test/t/create.test @@ -1017,6 +1017,7 @@ from имÑ_таблицы_в_кодировке_утф8_длиной_больш # database, table, field, key, view select * from имÑ_таблицы_в_кодировке_утф8_длиной_больше_чем_48; +--sorted_result select TABLE_NAME from information_schema.tables where table_schema='test'; diff --git a/mysql-test/t/gis.test b/mysql-test/t/gis.test index 94e56774bf4..ca806778f0e 100644 --- a/mysql-test/t/gis.test +++ b/mysql-test/t/gis.test @@ -1491,6 +1491,7 @@ SHOW CREATE TABLE information_schema.spatial_ref_sys; create table t1(g GEOMETRY, pt POINT); create table t2(g LINESTRING, pl POLYGON); +--sorted_result select * from information_schema.geometry_columns where f_table_schema='test'; drop table t1, t2; diff --git a/mysql-test/t/information_schema.test b/mysql-test/t/information_schema.test index 417390dcafe..9c306de0e3f 100644 --- a/mysql-test/t/information_schema.test +++ b/mysql-test/t/information_schema.test @@ -32,7 +32,9 @@ create user mysqltest_3@localhost; create user mysqltest_3; +--sorted_result select * from information_schema.SCHEMATA where schema_name > 'm'; +--sorted_result select schema_name from information_schema.schemata; show databases like 't%'; show databases; @@ -71,6 +73,7 @@ select c, v2.table_name from v1 right join information_schema.TABLES v2 on (v1.c=v2.table_name) where v1.c like "t%"; +--sorted_result select table_name from information_schema.TABLES where table_schema = "mysqltest" and table_name like "t%"; @@ -206,6 +209,7 @@ show create procedure sel2; # Test for views # create view v0 (c) as select schema_name from information_schema.schemata; +--sorted_result select * from v0; --replace_column 3 # explain select * from v0; @@ -222,6 +226,7 @@ create view v4 (c) as select COLLATION_NAME from information_schema.collations where COLLATION_NAME like "latin1%"; select * from v4; show keys from v4; +--sorted_result select * from information_schema.views where TABLE_NAME like "v%"; drop view v0, v1, v2, v3, v4; @@ -273,6 +278,7 @@ create table t1(a int); create view v1 (c) as select a from t1 with check option; create view v2 (c) as select a from t1 WITH LOCAL CHECK OPTION; create view v3 (c) as select a from t1 WITH CASCADED CHECK OPTION; +--sorted_result select * from information_schema.views; grant select (a) on test.t1 to joe@localhost with grant option; select * from INFORMATION_SCHEMA.COLUMN_PRIVILEGES; @@ -316,6 +322,7 @@ drop table t1; create table t1 (s1 int); insert into t1 values (0),(9),(0); +--sorted_result select s1 from t1 where s1 in (select version from information_schema.tables) union select version from information_schema.tables; @@ -408,12 +415,18 @@ create view v3 (c) as select sub1(1); create table t4(f1 int, KEY f1_key (f1)); drop table t1; drop function sub1; +--sorted_result select table_name from information_schema.views where table_schema='test'; +--sorted_result select table_name from information_schema.views where table_schema='test'; select column_name from information_schema.columns -where table_schema='test'; +where table_schema='test' and table_name='t4'; +select column_name from information_schema.columns +where table_schema='test' and table_name='v2'; +select column_name from information_schema.columns +where table_schema='test' and table_name='v3'; select index_name from information_schema.statistics where table_schema='test'; select constraint_name from information_schema.table_constraints where table_schema='test'; @@ -503,9 +516,11 @@ drop table t_crashme; # select table_schema,table_name, column_name from information_schema.columns -where data_type = 'longtext' and table_schema != 'performance_schema'; +where data_type = 'longtext' and table_schema != 'performance_schema' +order by binary table_name, ordinal_position; select table_name, column_name, data_type from information_schema.columns -where data_type = 'datetime' and table_name not like 'innodb_%'; +where data_type = 'datetime' and table_name not like 'innodb_%' +order by binary table_name, ordinal_position; # # Bug#8164 subquery with INFORMATION_SCHEMA.COLUMNS, 100 % CPU @@ -870,7 +885,7 @@ connect (con16681,localhost,mysqltest_1,,test); connection con16681; select * from information_schema.views -where table_name='v1' or table_name='v2'; +where table_name='v1' or table_name='v2' order by table_name; connection default; disconnect con16681; drop view v1, v2; @@ -884,7 +899,7 @@ set @a:= '.'; create table t1(f1 char(5)); create table t2(f1 char(5)); select concat(@a, table_name), @a, table_name -from information_schema.tables where table_schema = 'test'; +from information_schema.tables where table_schema = 'test' order by table_name; drop table t1,t2; @@ -996,7 +1011,8 @@ create table t2 (f1 int(11), f2 int(11)); select table_name from information_schema.tables where table_schema = 'test' and table_name not in (select table_name from information_schema.columns - where table_schema = 'test' and column_name = 'f3'); + where table_schema = 'test' and column_name = 'f3') +order by table_name; drop table t1,t2; @@ -1007,7 +1023,7 @@ create table t1(f1 int); create view v1 as select f1+1 as a from t1; create table t2 (f1 int, f2 int); create view v2 as select f1+1 as a, f2 as b from t2; -select table_name, is_updatable from information_schema.views; +select table_name, is_updatable from information_schema.views order by table_name; # # Note: we can perform 'delete' for non updatable view. # @@ -1507,9 +1523,9 @@ let $wait_condition= --source include/wait_condition.inc --echo # These statements should not be blocked by pending lock requests select table_name, column_name, data_type from information_schema.columns - where table_schema = 'test' and table_name in ('t1', 't2'); + where table_schema = 'test' and table_name in ('t1', 't2') order by table_name, column_name; select table_name, auto_increment from information_schema.tables - where table_schema = 'test' and table_name in ('t1', 't2'); + where table_schema = 'test' and table_name in ('t1', 't2') order by table_name; connection con3726_1; unlock tables; connection con3726_2; @@ -1671,14 +1687,14 @@ let $wait_condition= --echo # Issue query to I_S which will open 't0' and get --echo # blocked on 't1' because of RENAME. ---send select table_name, auto_increment from information_schema.tables where table_schema='mysqltest' +--send select table_name, auto_increment from information_schema.tables where table_schema='mysqltest' and table_name='t0' union select table_name, auto_increment from information_schema.tables where table_schema='mysqltest' and table_name<>'t0' order by table_name connect (con12828477_3, localhost, root,,mysqltest); --echo # Wait while the above SELECT is blocked. let $wait_condition= select count(*) = 1 from information_schema.processlist where state = "Waiting for table metadata lock" and - info = "select table_name, auto_increment from information_schema.tables where table_schema='mysqltest'"; + info like '%t0%union%t0%'; --source include/wait_condition.inc --echo # diff --git a/mysql-test/t/information_schema2.test b/mysql-test/t/information_schema2.test index 9810c5a0aae..d2fa3da2b5f 100644 --- a/mysql-test/t/information_schema2.test +++ b/mysql-test/t/information_schema2.test @@ -15,5 +15,5 @@ create table t2 (x int); create table t3 (x int); create table t4 AS select table_name from information_schema.TABLES where table_schema = database() and table_type = 'BASE TABLE' ; delete from t4 where table_name not in (select table_name from information_schema.TABLES where table_schema = database() and table_type = 'BASE TABLE'); -select * from t4; +select * from t4 order by table_name; drop table t1, t2, t3, t4; diff --git a/mysql-test/t/information_schema_db.test b/mysql-test/t/information_schema_db.test index 70ad9b5b920..94908570969 100644 --- a/mysql-test/t/information_schema_db.test +++ b/mysql-test/t/information_schema_db.test @@ -100,10 +100,10 @@ create function f2 () returns int return (select max(i) from t2); create view v2 as select f2(); drop table t2; select table_name, table_type, table_comment from information_schema.tables -where table_schema='test'; +where table_schema='test' order by table_name; drop table t1; select table_name, table_type, table_comment from information_schema.tables -where table_schema='test'; +where table_schema='test' order by table_name; drop function f1; drop function f2; drop view v1, v2; diff --git a/mysql-test/t/information_schema_inno.test b/mysql-test/t/information_schema_inno.test index 9a9658e9027..3cdbb8111d9 100644 --- a/mysql-test/t/information_schema_inno.test +++ b/mysql-test/t/information_schema_inno.test @@ -16,8 +16,10 @@ FOREIGN KEY (t1_id) REFERENCES t1(id) ON UPDATE CASCADE) ENGINE=INNODB; CREATE TABLE t3 (id INT PRIMARY KEY, t2_id INT, INDEX par_ind (t2_id), FOREIGN KEY (id, t2_id) REFERENCES t2(t1_id, id) ON DELETE CASCADE) ENGINE=INNODB; +--sorted_result select * from information_schema.TABLE_CONSTRAINTS where TABLE_SCHEMA= "test"; +--sorted_result select * from information_schema.KEY_COLUMN_USAGE where TABLE_SCHEMA= "test"; @@ -45,6 +47,7 @@ CREATE TABLE t5(b1 INT, b2 INT, INDEX (b1, b2), FOREIGN KEY (b1, b2) REFERENCES t4(b1, b2) ON UPDATE RESTRICT ON DELETE CASCADE) ENGINE=INNODB; +--sorted_result select a.CONSTRAINT_SCHEMA, b.TABLE_NAME, CONSTRAINT_TYPE, b.CONSTRAINT_NAME, UNIQUE_CONSTRAINT_SCHEMA, UNIQUE_CONSTRAINT_NAME, MATCH_OPTION, UPDATE_RULE, DELETE_RULE, b.REFERENCED_TABLE_NAME @@ -74,7 +77,8 @@ create table `t-1` ( use test; select referenced_table_schema, referenced_table_name from information_schema.key_column_usage -where constraint_schema = 'db-1'; +where constraint_schema = 'db-1' +order by referenced_table_schema, referenced_table_name; drop database `db-1`; # diff --git a/mysql-test/t/information_schema_part.test b/mysql-test/t/information_schema_part.test index ea88f364c07..62fba4f53d8 100644 --- a/mysql-test/t/information_schema_part.test +++ b/mysql-test/t/information_schema_part.test @@ -63,7 +63,7 @@ subpartition by key (a) subpartition x22 tablespace t2) ); --replace_column 16 # 19 # 20 # -select * from information_schema.partitions where table_schema="test"; +select * from information_schema.partitions where table_schema="test" order by table_name, partition_name; drop table t1,t2; create table t1 ( diff --git a/mysql-test/t/mysql_upgrade_noengine.test b/mysql-test/t/mysql_upgrade_noengine.test index cfc3a1dc406..1d65e7ffa1c 100644 --- a/mysql-test/t/mysql_upgrade_noengine.test +++ b/mysql-test/t/mysql_upgrade_noengine.test @@ -19,16 +19,19 @@ install soname 'ha_archive'; vertical_results; create table t1 (a int) engine=blackhole; create table t2 (a int) engine=archive; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; flush tables; uninstall plugin blackhole; uninstall plugin archive; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; # upgrade from 10.1 - engines aren't enabled exec $MYSQL_UPGRADE 2>&1; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; # pretend it's an upgrade from 10.0 alter table mysql.user drop column default_role, drop column max_statement_time; @@ -41,14 +44,16 @@ EOF # still upgrade from 10.1 exec $MYSQL_UPGRADE 2>&1; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; alter table mysql.user drop column default_role, drop column max_statement_time; remove_file $datadir/mysql_upgrade_info; # upgrade from 10.0 - engines are enabled exec $MYSQL_UPGRADE 2>&1; -select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t1'; +select table_catalog, table_schema, table_name, table_type, engine, row_format, table_rows, data_length, table_comment from information_schema.tables where table_schema='test' and table_name='t2'; drop table t1, t2; diff --git a/mysql-test/t/partition_exchange.test b/mysql-test/t/partition_exchange.test index e538bee16cd..8dc40da0caa 100644 --- a/mysql-test/t/partition_exchange.test +++ b/mysql-test/t/partition_exchange.test @@ -29,14 +29,16 @@ SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; ALTER TABLE t1 EXCHANGE PARTITION p1 WITH TABLE t2; SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; DROP TABLE t2; @@ -53,7 +55,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --echo # Only the non partitioned table have ROW_FORMAT set. DROP TABLE t1, t2; @@ -77,7 +80,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --echo # No table have ROW_FORMAT set. DROP TABLE t1, t2; @@ -101,7 +105,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --echo # Not same ROW_FORMAT as default (but same). DROP TABLE t1, t2; @@ -125,7 +130,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --echo # Not same ROW_FORMAT as default (tables differs). DROP TABLE t1, t2; @@ -150,7 +156,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --echo # Different than default (forced ROW_TYPE) DROP TABLE t1, t2; @@ -175,7 +182,8 @@ SHOW CREATE TABLE t1; SHOW CREATE TABLE t2; SELECT TABLE_NAME, TABLE_TYPE, ENGINE, ROW_FORMAT, CREATE_OPTIONS FROM INFORMATION_SCHEMA.TABLES -WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2'); +WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME IN ('t1', 't2') +ORDER BY TABLE_NAME; --horizontal_results DROP TABLE t1, t2; diff --git a/mysql-test/t/sp.test b/mysql-test/t/sp.test index 94d779de203..7d4758403ad 100644 --- a/mysql-test/t/sp.test +++ b/mysql-test/t/sp.test @@ -5722,8 +5722,10 @@ create procedure bug18344_2() begin end| use test| +--sorted_result select schema_name from information_schema.schemata where schema_name like 'bug18344%'| +--sorted_result select routine_name,routine_schema from information_schema.routines where routine_schema like 'bug18344%'| diff --git a/mysql-test/t/subselect_sj.test b/mysql-test/t/subselect_sj.test index f90f1e2e927..6fdccee339d 100644 --- a/mysql-test/t/subselect_sj.test +++ b/mysql-test/t/subselect_sj.test @@ -2490,6 +2490,7 @@ drop table t1,t2; --echo # CREATE TABLE t1 (db VARCHAR(64) DEFAULT NULL); INSERT INTO t1 VALUES ('mysql'),('information_schema'); +--sorted_result SELECT * FROM t1 WHERE db IN (SELECT `SCHEMA_NAME` FROM information_schema.SCHEMATA); DROP TABLE t1; diff --git a/mysql-test/t/type_datetime_hires.test b/mysql-test/t/type_datetime_hires.test index a62c227f563..d220a4601eb 100644 --- a/mysql-test/t/type_datetime_hires.test +++ b/mysql-test/t/type_datetime_hires.test @@ -57,6 +57,7 @@ INSERT INTO t2 VALUES ('2006-10-02 21:50:01.567',8), ('2006-10-02 21:50:01.5678',9); +--sorted_result select table_name,partition_name,partition_method,partition_expression,partition_description,table_rows from information_schema.partitions where table_name in ('t1', 't2'); drop table t1, t2; diff --git a/sql/handler.cc b/sql/handler.cc index ca4f8634091..5e392fa02e6 100644 --- a/sql/handler.cc +++ b/sql/handler.cc @@ -5173,6 +5173,13 @@ static int cmp_table_names(LEX_CSTRING * const *a, LEX_CSTRING * const *b) (uchar*)((*b)->str), (*b)->length); } +#ifndef DBUG_OFF +static int cmp_table_names_desc(LEX_CSTRING * const *a, LEX_CSTRING * const *b) +{ + return -cmp_table_names(a, b); +} +#endif + } Discovered_table_list::Discovered_table_list(THD *thd_arg, @@ -5225,6 +5232,15 @@ void Discovered_table_list::sort() tables->sort(cmp_table_names); } + +#ifndef DBUG_OFF +void Discovered_table_list::sort_desc() +{ + tables->sort(cmp_table_names_desc); +} +#endif + + void Discovered_table_list::remove_duplicates() { LEX_CSTRING **src= tables->front(); diff --git a/sql/handler.h b/sql/handler.h index f681040db39..fc98e53e308 100644 --- a/sql/handler.h +++ b/sql/handler.h @@ -4356,6 +4356,13 @@ public: void sort(); void remove_duplicates(); // assumes that the list is sorted +#ifndef DBUG_OFF + /* + Used to find unstable mtr tests querying + INFORMATION_SCHEMA.TABLES without ORDER BY. + */ + void sort_desc(); +#endif }; int ha_discover_table(THD *thd, TABLE_SHARE *share); diff --git a/sql/sql_show.cc b/sql/sql_show.cc index cd08959cc26..f5fd3427fa6 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -1001,7 +1001,7 @@ find_files(THD *thd, Dynamic_array *files, LEX_CSTRING *db, if (ha_discover_table_names(thd, db, dirp, &tl, false)) goto err; } -#if 1 // TODO: MDEV-13049: #if MYSQL_VERSION_ID < 100300 +#if MYSQL_VERSION_ID < 100300 /* incomplete optimization, but a less drastic change in GA version */ if (!thd->lex->select_lex.order_list.elements && !thd->lex->select_lex.group_list.elements) @@ -1009,6 +1009,17 @@ find_files(THD *thd, Dynamic_array *files, LEX_CSTRING *db, if (is_show_command(thd)) #endif tl.sort(); +#ifndef DBUG_OFF + else + { + /* + sort_desc() is used to find easier unstable mtr tests that query + INFORMATION_SCHEMA.{SCHEMATA|TABLES} without a proper ORDER BY. + This can be removed in some release after 10.3 (e.g. in 10.4). + */ + tl.sort_desc(); + } +#endif DBUG_PRINT("info",("found: %zu files", files->elements())); my_dirend(dirp); diff --git a/storage/connect/mysql-test/connect/r/infoschema-9739.result b/storage/connect/mysql-test/connect/r/infoschema-9739.result index 992f4ed0d58..2d54b578521 100644 --- a/storage/connect/mysql-test/connect/r/infoschema-9739.result +++ b/storage/connect/mysql-test/connect/r/infoschema-9739.result @@ -1,10 +1,8 @@ create table t1 (i int) engine=Connect table_type=XML option_list='xmlsup=domdoc'; Warnings: Warning 1105 No file name. Table will use t1.xml -select * from information_schema.tables where create_options like '%table_type=XML%'; +select * from information_schema.tables where table_schema='test' and create_options like '%table_type=XML%'; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME TABLE_TYPE ENGINE VERSION ROW_FORMAT TABLE_ROWS AVG_ROW_LENGTH DATA_LENGTH MAX_DATA_LENGTH INDEX_LENGTH DATA_FREE AUTO_INCREMENT CREATE_TIME UPDATE_TIME CHECK_TIME TABLE_COLLATION CHECKSUM CREATE_OPTIONS TABLE_COMMENT Warnings: -Warning 1286 Unknown storage engine 'InnoDB' -Warning 1286 Unknown storage engine 'InnoDB' Warning 1296 Got error 174 'File t1.xml not found' from CONNECT drop table t1; diff --git a/storage/connect/mysql-test/connect/r/infoschema2-9739.result b/storage/connect/mysql-test/connect/r/infoschema2-9739.result index 7d8a6839ea5..0372874862d 100644 --- a/storage/connect/mysql-test/connect/r/infoschema2-9739.result +++ b/storage/connect/mysql-test/connect/r/infoschema2-9739.result @@ -3,10 +3,8 @@ Warning 1105 No file name. Table will use t1.xml create table t1 (i int) engine=Connect table_type=XML option_list='xmlsup=libxml2'; Warnings: Warning 1105 No file name. Table will use t1.xml -select * from information_schema.tables where create_options like '%table_type=XML%'; +select * from information_schema.tables where table_schema='test' and create_options like '%table_type=XML%'; TABLE_CATALOG TABLE_SCHEMA TABLE_NAME TABLE_TYPE ENGINE VERSION ROW_FORMAT TABLE_ROWS AVG_ROW_LENGTH DATA_LENGTH MAX_DATA_LENGTH INDEX_LENGTH DATA_FREE AUTO_INCREMENT CREATE_TIME UPDATE_TIME CHECK_TIME TABLE_COLLATION CHECKSUM CREATE_OPTIONS TABLE_COMMENT Warnings: -Warning 1286 Unknown storage engine 'InnoDB' -Warning 1286 Unknown storage engine 'InnoDB' Warning 1296 Got error 174 'File t1.xml not found' from CONNECT drop table t1; diff --git a/storage/connect/mysql-test/connect/t/infoschema-9739.test b/storage/connect/mysql-test/connect/t/infoschema-9739.test index de61164d10d..16f837cafcc 100644 --- a/storage/connect/mysql-test/connect/t/infoschema-9739.test +++ b/storage/connect/mysql-test/connect/t/infoschema-9739.test @@ -5,5 +5,5 @@ --source windows.inc create table t1 (i int) engine=Connect table_type=XML option_list='xmlsup=domdoc'; -select * from information_schema.tables where create_options like '%table_type=XML%'; +select * from information_schema.tables where table_schema='test' and create_options like '%table_type=XML%'; drop table t1; diff --git a/storage/connect/mysql-test/connect/t/infoschema2-9739.test b/storage/connect/mysql-test/connect/t/infoschema2-9739.test index 345274b0577..76681bc91ed 100644 --- a/storage/connect/mysql-test/connect/t/infoschema2-9739.test +++ b/storage/connect/mysql-test/connect/t/infoschema2-9739.test @@ -5,5 +5,5 @@ --source have_libxml2.inc create table t1 (i int) engine=Connect table_type=XML option_list='xmlsup=libxml2'; -select * from information_schema.tables where create_options like '%table_type=XML%'; +select * from information_schema.tables where table_schema='test' and create_options like '%table_type=XML%'; drop table t1; diff --git a/storage/rocksdb/mysql-test/rocksdb/t/statistics.test b/storage/rocksdb/mysql-test/rocksdb/t/statistics.test index 70fc2f72b7e..25a1224c393 100644 --- a/storage/rocksdb/mysql-test/rocksdb/t/statistics.test +++ b/storage/rocksdb/mysql-test/rocksdb/t/statistics.test @@ -45,15 +45,19 @@ while ($i<100000) --enable_query_log # should have some statistics before the memtable flush +--sorted_result SELECT table_name, table_rows FROM information_schema.tables WHERE table_schema = DATABASE() and table_name <> 't1'; # due to inconsistencies in when the memtable is flushed, just verify t1 has fewer # than the expected number of rows. +--sorted_result SELECT CASE WHEN table_rows < 100000 then 'true' else 'false' end from information_schema.tables where table_name = 't1'; # flush and get even better statistics set global rocksdb_force_flush_memtable_now = true; +--sorted_result SELECT table_name, table_rows FROM information_schema.tables WHERE table_schema = DATABASE(); +--sorted_result SELECT table_name, data_length>0, index_length>0 FROM information_schema.tables WHERE table_schema = DATABASE(); # restart the server, check the stats @@ -62,13 +66,17 @@ SELECT table_name, data_length>0, index_length>0 FROM information_schema.tables # give the server a chance to load in statistics --sleep 5 +--sorted_result SELECT table_name, table_rows FROM information_schema.tables WHERE table_schema = DATABASE(); +--sorted_result SELECT table_name, data_length>0, index_length>0 FROM information_schema.tables WHERE table_schema = DATABASE(); analyze table t1,t2,t3,t4,t5; # make sure that stats do not change after calling analyze table +--sorted_result SELECT table_name, table_rows FROM information_schema.tables WHERE table_schema = DATABASE(); +--sorted_result SELECT table_name, data_length>0, index_length>0 FROM information_schema.tables WHERE table_schema = DATABASE(); drop table t1, t2, t3; From b25808012992207eb75b910d8c5768c49ab15cd7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Tue, 31 Oct 2017 12:54:10 +0200 Subject: [PATCH 026/138] Disable known-failing tests MDEV-13568: Purge is not blocked by LOCK TABLES. Should it? MDEV-13893/MDEV-12699: Crash recovery of corrupted or non-decryptable pages is broken. --- mysql-test/suite/encryption/disabled.def | 2 +- mysql-test/suite/gcol/disabled.def | 1 + 2 files changed, 2 insertions(+), 1 deletion(-) create mode 100644 mysql-test/suite/gcol/disabled.def diff --git a/mysql-test/suite/encryption/disabled.def b/mysql-test/suite/encryption/disabled.def index abbb82d51f6..9d9d1cd9df9 100644 --- a/mysql-test/suite/encryption/disabled.def +++ b/mysql-test/suite/encryption/disabled.def @@ -12,4 +12,4 @@ innodb_scrub : MDEV-8139 scrubbing does not work reliably innodb_scrub_background : MDEV-8139 scrubbing does not work reliably - +innodb-redo-badkey : MDEV-13893 / MDEV-12699 Improve crash recovery of corrupted data pages diff --git a/mysql-test/suite/gcol/disabled.def b/mysql-test/suite/gcol/disabled.def new file mode 100644 index 00000000000..37209a4c353 --- /dev/null +++ b/mysql-test/suite/gcol/disabled.def @@ -0,0 +1 @@ +innodb_virtual_debug_purge : MDEV-13568 should purge yield to LOCK TABLES? From 157f2b25512c898bf9ac20556d9e7b06b0256e49 Mon Sep 17 00:00:00 2001 From: Monty Date: Tue, 31 Oct 2017 13:42:57 +0200 Subject: [PATCH 027/138] Updated help message for long_query_time --- mysql-test/r/mysqld--help.result | 5 +++-- mysql-test/suite/sys_vars/r/sysvars_server_embedded.result | 2 +- .../suite/sys_vars/r/sysvars_server_notembedded.result | 2 +- sql/sys_vars.cc | 4 ++-- 4 files changed, 7 insertions(+), 6 deletions(-) diff --git a/mysql-test/r/mysqld--help.result b/mysql-test/r/mysqld--help.result index 7005a850ea5..3729fa32feb 100644 --- a/mysql-test/r/mysqld--help.result +++ b/mysql-test/r/mysqld--help.result @@ -418,8 +418,9 @@ The following options may be given as the first argument: file.Value can be between 0 and 11. Higher values mean more verbosity --long-query-time=# Log all queries that have taken more than long_query_time - seconds to execute to file. The argument will be treated - as a decimal value with microsecond precision + seconds to execute to the slow query log file. The + argument will be treated as a decimal value with + microsecond precision --low-priority-updates INSERT/DELETE/UPDATE has lower priority than selects --lower-case-table-names[=#] diff --git a/mysql-test/suite/sys_vars/r/sysvars_server_embedded.result b/mysql-test/suite/sys_vars/r/sysvars_server_embedded.result index 537446fdb1e..8c05ea96637 100644 --- a/mysql-test/suite/sys_vars/r/sysvars_server_embedded.result +++ b/mysql-test/suite/sys_vars/r/sysvars_server_embedded.result @@ -1794,7 +1794,7 @@ GLOBAL_VALUE_ORIGIN COMPILE-TIME DEFAULT_VALUE 10.000000 VARIABLE_SCOPE SESSION VARIABLE_TYPE DOUBLE -VARIABLE_COMMENT Log all queries that have taken more than long_query_time seconds to execute to file. The argument will be treated as a decimal value with microsecond precision +VARIABLE_COMMENT Log all queries that have taken more than long_query_time seconds to execute to the slow query log file. The argument will be treated as a decimal value with microsecond precision NUMERIC_MIN_VALUE 0 NUMERIC_MAX_VALUE 31536000 NUMERIC_BLOCK_SIZE NULL diff --git a/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result b/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result index 329b519588d..63cc1fe82f0 100644 --- a/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result +++ b/mysql-test/suite/sys_vars/r/sysvars_server_notembedded.result @@ -1962,7 +1962,7 @@ GLOBAL_VALUE_ORIGIN COMPILE-TIME DEFAULT_VALUE 10.000000 VARIABLE_SCOPE SESSION VARIABLE_TYPE DOUBLE -VARIABLE_COMMENT Log all queries that have taken more than long_query_time seconds to execute to file. The argument will be treated as a decimal value with microsecond precision +VARIABLE_COMMENT Log all queries that have taken more than long_query_time seconds to execute to the slow query log file. The argument will be treated as a decimal value with microsecond precision NUMERIC_MIN_VALUE 0 NUMERIC_MAX_VALUE 31536000 NUMERIC_BLOCK_SIZE NULL diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 2bbd0c14f55..a32bc3fce8e 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -1255,8 +1255,8 @@ static bool update_cached_long_query_time(sys_var *self, THD *thd, static Sys_var_double Sys_long_query_time( "long_query_time", "Log all queries that have taken more than long_query_time seconds " - "to execute to file. The argument will be treated as a decimal value " - "with microsecond precision", + "to execute to the slow query log file. The argument will be treated " + "as a decimal value with microsecond precision", SESSION_VAR(long_query_time_double), CMD_LINE(REQUIRED_ARG), VALID_RANGE(0, LONG_TIMEOUT), DEFAULT(10), NO_MUTEX_GUARD, NOT_IN_BINLOG, ON_CHECK(0), From bd20fb87ec34535fa82bfa79c28851587ae145b0 Mon Sep 17 00:00:00 2001 From: Monty Date: Tue, 31 Oct 2017 13:44:25 +0200 Subject: [PATCH 028/138] Write error message ebfore aborting if not all memory is released Also don't abort if global_status_var.global_memory_used != 0 on not normal exit as then it's likely that not all memory is released. --- sql/mysqld.cc | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 0e1543ecd2f..069092a0e32 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -2161,15 +2161,15 @@ static void mysqld_exit(int exit_code) shutdown_performance_schema(); // we do it as late as possible #endif set_malloc_size_cb(NULL); - if (!opt_debugging && !my_disable_leak_check) + if (opt_endinfo && global_status_var.global_memory_used) + fprintf(stderr, "Warning: Memory not freed: %ld\n", + (long) global_status_var.global_memory_used); + if (!opt_debugging && !my_disable_leak_check && exit_code == 0) { DBUG_ASSERT(global_status_var.global_memory_used == 0); } cleanup_tls(); DBUG_LEAVE; - if (opt_endinfo && global_status_var.global_memory_used) - fprintf(stderr, "Warning: Memory not freed: %ld\n", - (long) global_status_var.global_memory_used); sd_notify(0, "STATUS=MariaDB server is down"); exit(exit_code); /* purecov: inspected */ } From 613dd62a76b51df38b96e36bce5bd8b7be2ca73a Mon Sep 17 00:00:00 2001 From: Sergey Vojtovich Date: Thu, 10 Aug 2017 15:45:03 +0400 Subject: [PATCH 029/138] MDEV-11153 - Introduce status variables for table cache monitoring and tuning Status variables added: Table_open_cache_hits, Table_open_cache_misses, Table_open_cache_overflows, Table_open_cache_active_instances. --- mysql-test/r/status.result | 23 +++++++++++++++++++++++ mysql-test/t/status.test | 33 +++++++++++++++++++++++++++++++++ sql/mysqld.cc | 4 ++++ sql/sql_class.cc | 9 +++++++++ sql/sql_class.h | 3 +++ sql/table_cache.cc | 35 ++++++++++++++++++++++++++--------- sql/table_cache.h | 1 + 7 files changed, 99 insertions(+), 9 deletions(-) diff --git a/mysql-test/r/status.result b/mysql-test/r/status.result index 9a8a5bd8f93..9b82c7896cb 100644 --- a/mysql-test/r/status.result +++ b/mysql-test/r/status.result @@ -386,6 +386,29 @@ Handler_tmp_write 2 Handler_update 0 Handler_write 0 drop table t1; +# +# MDEV-11153 - Introduce status variables for table cache monitoring and +# tuning +# +SET @old_table_open_cache= @@table_open_cache; +SET @@global.table_open_cache=10; +FLUSH TABLES; +FLUSH STATUS; +SHOW STATUS LIKE 'Table_open_cache%'; +Variable_name Value +Table_open_cache_active_instances 1 +Table_open_cache_hits 0 +Table_open_cache_misses 0 +Table_open_cache_overflows 0 +SHOW STATUS LIKE 'Table_open_cache%'; +Variable_name Value +Table_open_cache_active_instances 1 +Table_open_cache_hits 30 +Table_open_cache_misses 15 +Table_open_cache_overflows 5 +FLUSH TABLES; +FLUSH STATUS; +SET @@global.table_open_cache= @old_table_open_cache; connection default; set @@global.concurrent_insert= @old_concurrent_insert; SET GLOBAL log_output = @old_log_output; diff --git a/mysql-test/t/status.test b/mysql-test/t/status.test index 7ab32241bcb..bff45fca583 100644 --- a/mysql-test/t/status.test +++ b/mysql-test/t/status.test @@ -387,6 +387,39 @@ drop table t1; # End of 5.3 tests +--echo # +--echo # MDEV-11153 - Introduce status variables for table cache monitoring and +--echo # tuning +--echo # +SET @old_table_open_cache= @@table_open_cache; +SET @@global.table_open_cache=10; +FLUSH TABLES; +FLUSH STATUS; +SHOW STATUS LIKE 'Table_open_cache%'; +disable_query_log; +let $i= `SELECT @@table_open_cache + 5`; +while ($i) +{ + eval CREATE TABLE t$i(a INT); + eval DELETE FROM t$i; + eval DELETE FROM t$i; + eval DELETE FROM t$i; + dec $i; +} +enable_query_log; +SHOW STATUS LIKE 'Table_open_cache%'; +FLUSH TABLES; +FLUSH STATUS; +disable_query_log; +let $i= `SELECT @@table_open_cache + 5`; +while ($i) +{ + eval DROP TABLE t$i; + dec $i; +} +enable_query_log; +SET @@global.table_open_cache= @old_table_open_cache; + # Restore global concurrent_insert value. Keep in the end of the test file. --connection default set @@global.concurrent_insert= @old_concurrent_insert; diff --git a/sql/mysqld.cc b/sql/mysqld.cc index ad27c58f67f..f02ded12254 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -8616,6 +8616,10 @@ SHOW_VAR status_vars[]= { {"Subquery_cache_miss", (char*) &subquery_cache_miss, SHOW_LONG}, {"Table_locks_immediate", (char*) &locks_immediate, SHOW_LONG}, {"Table_locks_waited", (char*) &locks_waited, SHOW_LONG}, + {"Table_open_cache_active_instances", (char*) &tc_active_instances, SHOW_UINT}, + {"Table_open_cache_hits", (char*) offsetof(STATUS_VAR, table_open_cache_hits), SHOW_LONGLONG_STATUS}, + {"Table_open_cache_misses", (char*) offsetof(STATUS_VAR, table_open_cache_misses), SHOW_LONGLONG_STATUS}, + {"Table_open_cache_overflows", (char*) offsetof(STATUS_VAR, table_open_cache_overflows), SHOW_LONGLONG_STATUS}, #ifdef HAVE_MMAP {"Tc_log_max_pages_used", (char*) &tc_log_max_pages_used, SHOW_LONG}, {"Tc_log_page_size", (char*) &tc_log_page_size, SHOW_LONG_NOFLUSH}, diff --git a/sql/sql_class.cc b/sql/sql_class.cc index 889acc57b76..02f49b6d645 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -1728,6 +1728,9 @@ void add_to_status(STATUS_VAR *to_var, STATUS_VAR *from_var) to_var->binlog_bytes_written+= from_var->binlog_bytes_written; to_var->cpu_time+= from_var->cpu_time; to_var->busy_time+= from_var->busy_time; + to_var->table_open_cache_hits+= from_var->table_open_cache_hits; + to_var->table_open_cache_misses+= from_var->table_open_cache_misses; + to_var->table_open_cache_overflows+= from_var->table_open_cache_overflows; /* Update global_memory_used. We have to do this with atomic_add as the @@ -1779,6 +1782,12 @@ void add_diff_to_status(STATUS_VAR *to_var, STATUS_VAR *from_var, dec_var->binlog_bytes_written; to_var->cpu_time+= from_var->cpu_time - dec_var->cpu_time; to_var->busy_time+= from_var->busy_time - dec_var->busy_time; + to_var->table_open_cache_hits+= from_var->table_open_cache_hits - + dec_var->table_open_cache_hits; + to_var->table_open_cache_misses+= from_var->table_open_cache_misses - + dec_var->table_open_cache_misses; + to_var->table_open_cache_overflows+= from_var->table_open_cache_overflows - + dec_var->table_open_cache_overflows; /* We don't need to accumulate memory_used as these are not reset or used by diff --git a/sql/sql_class.h b/sql/sql_class.h index fda56c8cc3a..740e9911838 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -823,6 +823,9 @@ typedef struct system_status_var ulonglong rows_sent; ulonglong rows_tmp_read; ulonglong binlog_bytes_written; + ulonglong table_open_cache_hits; + ulonglong table_open_cache_misses; + ulonglong table_open_cache_overflows; double last_query_cost; double cpu_time, busy_time; /* Don't initialize */ diff --git a/sql/table_cache.cc b/sql/table_cache.cc index 6067ecb059d..f55e24f3b04 100644 --- a/sql/table_cache.cc +++ b/sql/table_cache.cc @@ -56,7 +56,7 @@ ulong tdc_size; /**< Table definition cache threshold for LRU eviction. */ ulong tc_size; /**< Table cache threshold for LRU eviction. */ uint32 tc_instances; -static uint32 tc_active_instances= 1; +uint32 tc_active_instances= 1; static uint32 tc_contention_warning_reported; /** Data collections. */ @@ -369,18 +369,30 @@ void tc_add_table(THD *thd, TABLE *table) mysql_mutex_unlock(&element->LOCK_table_share); mysql_mutex_lock(&tc[i].LOCK_table_cache); - if (tc[i].records == tc_size && (LRU_table= tc[i].free_tables.pop_front())) + if (tc[i].records == tc_size) { - LRU_table->s->tdc->free_tables[i].list.remove(LRU_table); - /* Needed if MDL deadlock detector chimes in before tc_remove_table() */ - LRU_table->in_use= thd; + if ((LRU_table= tc[i].free_tables.pop_front())) + { + LRU_table->s->tdc->free_tables[i].list.remove(LRU_table); + /* Needed if MDL deadlock detector chimes in before tc_remove_table() */ + LRU_table->in_use= thd; + mysql_mutex_unlock(&tc[i].LOCK_table_cache); + /* Keep out of locked LOCK_table_cache */ + tc_remove_table(LRU_table); + } + else + { + tc[i].records++; + mysql_mutex_unlock(&tc[i].LOCK_table_cache); + } + /* Keep out of locked LOCK_table_cache */ + status_var_increment(thd->status_var.table_open_cache_overflows); } else + { tc[i].records++; - mysql_mutex_unlock(&tc[i].LOCK_table_cache); - - if (LRU_table) - tc_remove_table(LRU_table); + mysql_mutex_unlock(&tc[i].LOCK_table_cache); + } } @@ -841,7 +853,10 @@ retry: tdc_purge(false); if (out_table) + { + status_var_increment(thd->status_var.table_open_cache_misses); *out_table= 0; + } share->m_psi= PSI_CALL_get_table_share(false, share); goto end; } @@ -858,8 +873,10 @@ retry: DBUG_ASSERT(element->share); DBUG_ASSERT(!element->share->error); DBUG_ASSERT(!element->share->is_view); + status_var_increment(thd->status_var.table_open_cache_hits); DBUG_RETURN(element->share); } + status_var_increment(thd->status_var.table_open_cache_misses); } mysql_mutex_lock(&element->LOCK_table_share); diff --git a/sql/table_cache.h b/sql/table_cache.h index 2e5bb3428dc..b41665258c9 100644 --- a/sql/table_cache.h +++ b/sql/table_cache.h @@ -71,6 +71,7 @@ enum enum_tdc_remove_table_type extern ulong tdc_size; extern ulong tc_size; extern uint32 tc_instances; +extern uint32 tc_active_instances; extern bool tdc_init(void); extern void tdc_start_shutdown(void); From c3b641ee20f49c8850c4c02056c120dc17a5eeb6 Mon Sep 17 00:00:00 2001 From: Daniel Bartholomew Date: Tue, 31 Oct 2017 19:56:44 -0400 Subject: [PATCH 030/138] bump the VERSION --- VERSION | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/VERSION b/VERSION index 49f5a7357e1..715774671cc 100644 --- a/VERSION +++ b/VERSION @@ -1,3 +1,3 @@ MYSQL_VERSION_MAJOR=10 MYSQL_VERSION_MINOR=2 -MYSQL_VERSION_PATCH=10 +MYSQL_VERSION_PATCH=11 From 6b7918d524d5fc1f63f520cf88784fef13a43c25 Mon Sep 17 00:00:00 2001 From: Monty Date: Wed, 1 Nov 2017 12:21:46 +0200 Subject: [PATCH 031/138] Fixed that --malloc-lib works properly - Expand paths also for jemalloc - Test also if tcmalloc or jemalloc is in /usr/lib64 - Take into account that .so has a version - Remove automatic adding of flavors ( _minial, _debug). Better to have user specify these directly - Changed documentation link to MariaDB - Don't give extra error if mysqld_safe_helper doesn't exist --- scripts/mysqld_safe.sh | 50 ++++++++++++++++++++++++++---------------- 1 file changed, 31 insertions(+), 19 deletions(-) diff --git a/scripts/mysqld_safe.sh b/scripts/mysqld_safe.sh index b06106ceae6..80a93c979ac 100644 --- a/scripts/mysqld_safe.sh +++ b/scripts/mysqld_safe.sh @@ -153,7 +153,11 @@ log_generic () { echo "$msg" case $logging in init) ;; # Just echo the message, don't save it anywhere - file) echo "$msg" | "$helper" "$user" log "$err_log" ;; + file) + if [ -n "$helper" ]; then + echo "$msg" | "$helper" "$user" log "$err_log" + fi + ;; syslog) logger -t "$syslog_tag_mysqld_safe" -p "$priority" "$*" ;; *) echo "Internal program error (non-fatal):" \ @@ -173,7 +177,11 @@ log_notice () { eval_log_error () { local cmd="$1" case $logging in - file) cmd="$cmd 2>&1 | "`shell_quote_string "$helper"`" $user log "`shell_quote_string "$err_log"` ;; + file) + if [ -n "$helper" ]; then + cmd="$cmd 2>&1 | "`shell_quote_string "$helper"`" $user log "`shell_quote_string "$err_log"` + fi + ;; syslog) # mysqld often prefixes its messages with a timestamp, which is # redundant when logging to syslog (which adds its own timestamp) @@ -455,8 +463,9 @@ get_mysql_config() { # set_malloc_lib LIB # - If LIB is empty, do nothing and return -# - If LIB is 'tcmalloc', look for tcmalloc shared library in /usr/lib -# then pkglibdir. tcmalloc is part of the Google perftools project. +# - If LIB starts with 'tcmalloc' or 'jemalloc', look for the shared library in +# /usr/lib, /usr/lib64 and then pkglibdir. +# tcmalloc is part of the Google perftools project. # - If LIB is an absolute path, assume it is a malloc shared library # # Put LIB in mysqld_ld_preload, which will be added to LD_PRELOAD when @@ -464,23 +473,23 @@ get_mysql_config() { set_malloc_lib() { malloc_lib="$1" - if [ "$malloc_lib" = tcmalloc ]; then + if expr "$malloc_lib" : "\(tcmalloc\|jemalloc\)" > /dev/null ; then pkglibdir=`get_mysql_config --variable=pkglibdir` - malloc_lib= + where='' # This list is kept intentionally simple. Simply set --malloc-lib # to a full path if another location is desired. - for libdir in /usr/lib "$pkglibdir" "$pkglibdir/mysql"; do - for flavor in _minimal '' _and_profiler _debug; do - tmp="$libdir/libtcmalloc$flavor.so" - #log_notice "DEBUG: Checking for malloc lib '$tmp'" - [ -r "$tmp" ] || continue - malloc_lib="$tmp" - break 2 - done + for libdir in /usr/lib /usr/lib64 "$pkglibdir" "$pkglibdir/mysql"; do + tmp=`echo "$libdir/lib$malloc_lib.so".[0-9]` + where="$where $libdir" + # log_notice "DEBUG: Checking for malloc lib '$tmp'" + [ -r "$tmp" ] || continue + malloc_lib="$tmp" + where='' + break done - if [ -z "$malloc_lib" ]; then - log_error "no shared library for --malloc-lib=tcmalloc found in /usr/lib or $pkglibdir" + if [ -n "$where" ]; then + log_error "no shared library for lib$malloc_lib.so.[0-9] found in$where" exit 1 fi fi @@ -496,8 +505,8 @@ set_malloc_lib() { fi ;; *) - log_error "--malloc-lib must be an absolute path or 'tcmalloc'; " \ - "ignoring value '$malloc_lib'" + log_error "--malloc-lib must be an absolute path, 'tcmalloc' or " \ + "'jemalloc'; ignoring value '$malloc_lib'" exit 1 ;; esac @@ -549,6 +558,9 @@ fi helper=`find_in_bin mysqld_safe_helper` print_defaults=`find_in_bin my_print_defaults` +# Check if helper exists +$helper --help >/dev/null 2>&1 || helper="" + # # Second, try to find the data directory # @@ -751,7 +763,7 @@ then does not exist or is not executable. Please cd to the mysql installation directory and restart this script from there as follows: ./bin/mysqld_safe& -See http://dev.mysql.com/doc/mysql/en/mysqld-safe.html for more information" +See https://mariadb.com/kb/en/mysqld_safe for more information" exit 1 fi From 29c4bd9d27996600790be45ae057214381c7d3a8 Mon Sep 17 00:00:00 2001 From: Vladislav Vaintroub Date: Wed, 1 Nov 2017 13:20:32 +0000 Subject: [PATCH 032/138] SOURCE_REVISION should always be defined in source_revision.h #cmakedefine in template file might not create a #define in configured header file. --- include/source_revision.h.in | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/include/source_revision.h.in b/include/source_revision.h.in index 5b657d0940e..991df992e2f 100644 --- a/include/source_revision.h.in +++ b/include/source_revision.h.in @@ -1 +1 @@ -#cmakedefine SOURCE_REVISION "@SOURCE_REVISION@" +#define SOURCE_REVISION "@SOURCE_REVISION@" From fadfe447e8d9b1244341bd5ed94bb7f8eb623f18 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 13 Jun 2017 11:54:39 +0530 Subject: [PATCH 033/138] MDEV-12985: syntax added for the percentile_cont and percentile_disc functions --- sql/lex.h | 3 +++ sql/sql_yacc.yy | 25 ++++++++++++++++++++++++- 2 files changed, 27 insertions(+), 1 deletion(-) diff --git a/sql/lex.h b/sql/lex.h index ef03afb7a32..7967d17a5d4 100644 --- a/sql/lex.h +++ b/sql/lex.h @@ -701,6 +701,7 @@ static SYMBOL symbols[] = { { "WHILE", SYM(WHILE_SYM)}, { "WINDOW", SYM(WINDOW_SYM)}, { "WITH", SYM(WITH)}, + { "WITHIN", SYM(WITHIN)}, { "WORK", SYM(WORK_SYM)}, { "WRAPPER", SYM(WRAPPER_SYM)}, { "WRITE", SYM(WRITE_SYM)}, @@ -743,6 +744,8 @@ static SYMBOL sql_functions[] = { { "NTILE", SYM(NTILE_SYM)}, { "POSITION", SYM(POSITION_SYM)}, { "PERCENT_RANK", SYM(PERCENT_RANK_SYM)}, + { "PERCENTILE_CONT", SYM(PERCENTILE_CONT_SYM)}, + { "PERCENTILE_DISC", SYM(PERCENTILE_DISC_SYM)}, { "RANK", SYM(RANK_SYM)}, { "ROW_NUMBER", SYM(ROW_NUMBER_SYM)}, { "SESSION_USER", SYM(USER_SYM)}, diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 67b73dea506..57d7ecd48c8 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1328,6 +1328,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token PARTITIONING_SYM %token PASSWORD_SYM %token PERCENT_RANK_SYM +%token PERCENTILE_CONT_SYM +%token PERCENTILE_DISC_SYM %token PERSISTENT_SYM %token PHASE_SYM %token PLUGINS_SYM @@ -1574,6 +1576,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token WINDOW_SYM %token WHILE_SYM %token WITH /* SQL-2003-R */ +%token WITHIN %token WITH_CUBE_SYM /* INTERNAL */ %token WITH_ROLLUP_SYM /* INTERNAL */ %token WORK_SYM /* SQL-2003-N */ @@ -1733,6 +1736,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); window_func_expr window_func simple_window_func + inverse_distribution_function function_call_keyword function_call_nonkeyword function_call_generic @@ -1951,7 +1955,6 @@ END_OF_INPUT %type row_field_name row_field_definition %type row_field_definition_list row_type_body - %type opt_window_clause window_def_list window_def window_spec %type window_name %type opt_window_ref opt_window_frame_clause @@ -9374,6 +9377,7 @@ column_default_non_parenthesized_expr: | variable | sum_expr | window_func_expr + | inverse_distribution_function | ROW_SYM '(' expr ',' expr_list ')' { $5->push_front($3, thd->mem_root); @@ -10693,6 +10697,25 @@ simple_window_func: } ; + +inverse_distribution_function: + inverse_distribution_function_type '(' expr ')' WITHIN GROUP_SYM + '(' order_by_single_element_list ')' OVER_SYM '(' opt_window_ref opt_window_partition_clause ')' + { + my_yyabort_error((ER_VIEW_SELECT_VARIABLE, MYF(0))); + }; + +inverse_distribution_function_type: + PERCENTILE_CONT_SYM + {} + |PERCENTILE_DISC_SYM + {} + ; + +order_by_single_element_list: + ORDER_SYM BY order_ident order_dir + ; + window_name: ident { From 280945bf29095da1c8aacdcba37aecce605fc127 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 22 Jun 2017 21:43:45 +0530 Subject: [PATCH 034/138] MDEV-12985: support percentile and median window functions Finalised the synatax and have started implementing the class for the PERCENTILE_DISC --- sql/item_sum.h | 3 +- sql/item_windowfunc.h | 69 +++++++++++++++++++++++++++++++++++++++++++ sql/sql_window.cc | 16 ++++++++++ sql/sql_yacc.yy | 47 +++++++++++++++++++++-------- 4 files changed, 121 insertions(+), 14 deletions(-) diff --git a/sql/item_sum.h b/sql/item_sum.h index 7845ed3318f..467a77c8983 100644 --- a/sql/item_sum.h +++ b/sql/item_sum.h @@ -354,7 +354,8 @@ public: VARIANCE_FUNC, SUM_BIT_FUNC, UDF_SUM_FUNC, GROUP_CONCAT_FUNC, ROW_NUMBER_FUNC, RANK_FUNC, DENSE_RANK_FUNC, PERCENT_RANK_FUNC, CUME_DIST_FUNC, NTILE_FUNC, FIRST_VALUE_FUNC, LAST_VALUE_FUNC, - NTH_VALUE_FUNC, LEAD_FUNC, LAG_FUNC + NTH_VALUE_FUNC, LEAD_FUNC, LAG_FUNC, PERCENTILE_CONT_FUNC, + PERCENTILE_DISC_FUNC }; Item **ref_by; /* pointer to a ref to the object used to register it */ diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 64a974d55d6..ac695729fc5 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -572,6 +572,9 @@ class Item_sum_cume_dist: public Item_sum_window_with_row_count Item_sum_cume_dist(THD *thd) : Item_sum_window_with_row_count(thd), current_row_count_(0) {} + Item_sum_cume_dist(THD *thd, Item *arg) : Item_sum_window_with_row_count(thd,arg), + current_row_count_(0) {} + double val_real() { if (get_row_count() == 0) @@ -618,6 +621,11 @@ class Item_sum_cume_dist: public Item_sum_window_with_row_count Item *get_copy(THD *thd, MEM_ROOT *mem_root) { return get_item_copy(thd, mem_root, this); } + ulonglong get_row_number() + { + return current_row_count_; + } + private: ulonglong current_row_count_; }; @@ -693,6 +701,61 @@ class Item_sum_ntile : public Item_sum_window_with_row_count ulong current_row_count_; }; +class Item_sum_percentile_disc : public Item_sum_cume_dist +{ +public: + Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg) + {} + + double val_real() + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + return 0; + } + + bool add() + { + Item *arg = get_arg(0); + if (arg->is_null()) + return true; + /*implementation to be done*/ + return false; + } + + enum Sumfunctype sum_func() const + { + return PERCENTILE_DISC_FUNC; + } + + void clear() + { + //need to implement + } + + const char*func_name() const + { + return "percentile_disc"; + } + + void update_field() {} + const Type_handler *type_handler() const { return &type_handler_double; } + + void fix_length_and_dec() + { + decimals = 10; // TODO-cvicentiu find out how many decimals the standard + // requires. + } + + Item *get_copy(THD *thd, MEM_ROOT *mem_root) + { return get_item_copy(thd, mem_root, this); } + +}; + class Item_window_func : public Item_func_or_sum { @@ -747,6 +810,8 @@ public: case Item_sum::PERCENT_RANK_FUNC: case Item_sum::CUME_DIST_FUNC: case Item_sum::NTILE_FUNC: + case Item_sum::PERCENTILE_CONT_FUNC: + case Item_sum::PERCENTILE_DISC_FUNC: return true; default: return false; @@ -773,6 +838,8 @@ public: case Item_sum::PERCENT_RANK_FUNC: case Item_sum::CUME_DIST_FUNC: case Item_sum::NTILE_FUNC: + case Item_sum::PERCENTILE_CONT_FUNC: + case Item_sum::PERCENTILE_DISC_FUNC: return true; default: return false; @@ -796,6 +863,8 @@ public: case Item_sum::DENSE_RANK_FUNC: case Item_sum::PERCENT_RANK_FUNC: case Item_sum::CUME_DIST_FUNC: + case Item_sum::PERCENTILE_CONT_FUNC: + case Item_sum::PERCENTILE_DISC_FUNC: return true; default: return false; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index d22fff9d486..a4c558b52b6 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -2490,6 +2490,20 @@ void add_special_frame_cursors(THD *thd, Cursor_manager *cursor_manager, cursor_manager->add_cursor(fc); break; } + case Item_sum::PERCENTILE_DISC_FUNC: + { + fc= new Frame_unbounded_preceding(thd, + spec->partition_list, + spec->order_list); + fc->add_sum_func(item_sum); + cursor_manager->add_cursor(fc); + fc= new Frame_unbounded_following(thd, + spec->partition_list, + spec->order_list); + fc->add_sum_func(item_sum); + cursor_manager->add_cursor(fc); + break; + } default: fc= new Frame_unbounded_preceding( thd, spec->partition_list, spec->order_list); @@ -2514,6 +2528,8 @@ static bool is_computed_with_remove(Item_sum::Sumfunctype sum_func) case Item_sum::NTILE_FUNC: case Item_sum::FIRST_VALUE_FUNC: case Item_sum::LAST_VALUE_FUNC: + case Item_sum::PERCENTILE_CONT_FUNC: + case Item_sum::PERCENTILE_DISC_FUNC: return false; default: return true; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 57d7ecd48c8..62dbc3860ec 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1737,6 +1737,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); window_func simple_window_func inverse_distribution_function + inverse_distribution_function_def function_call_keyword function_call_nonkeyword function_call_generic @@ -10697,23 +10698,43 @@ simple_window_func: } ; - inverse_distribution_function: - inverse_distribution_function_type '(' expr ')' WITHIN GROUP_SYM - '(' order_by_single_element_list ')' OVER_SYM '(' opt_window_ref opt_window_partition_clause ')' - { - my_yyabort_error((ER_VIEW_SELECT_VARIABLE, MYF(0))); - }; + inverse_distribution_function_def WITHIN GROUP_SYM + '(' + { Select->prepare_add_window_spec(thd); } + order_by_single_element_list ')' OVER_SYM + '(' opt_window_ref opt_window_partition_clause ')' + { + LEX *lex= Lex; + if (Select->add_window_spec(thd, lex->win_ref, + Select->group_list, + Select->order_list, + NULL)) + MYSQL_YYABORT; + $$= new (thd->mem_root) Item_window_func(thd, (Item_sum *) $1, + thd->lex->win_spec); + if ($$ == NULL) + MYSQL_YYABORT; + if (Select->add_window_func((Item_window_func *) $$)) + MYSQL_YYABORT; + } + ; -inverse_distribution_function_type: - PERCENTILE_CONT_SYM - {} - |PERCENTILE_DISC_SYM - {} - ; +inverse_distribution_function_def: + PERCENTILE_CONT_SYM '(' expr ')' + { + //Not yet started implementing + } + | PERCENTILE_DISC_SYM '(' expr ')' + { + $$= new (thd->mem_root) Item_sum_percentile_disc(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; + } + ; order_by_single_element_list: - ORDER_SYM BY order_ident order_dir + ORDER_SYM BY order_list ; window_name: From 129626f171377c247b71bdda602a554829e4f848 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 26 Jun 2017 01:55:05 +0530 Subject: [PATCH 035/138] Added get_item() to Cached_item_item and get_value to the Cached_item --- sql/item.h | 36 ++++++++++++++++++++++++++++++++++++ 1 file changed, 36 insertions(+) diff --git a/sql/item.h b/sql/item.h index 1f743913d78..68d09577dcc 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5303,6 +5303,8 @@ public: /* Compare the cached value with the source value, without copying */ virtual int cmp_read_only()=0; + virtual void clear()=0; + virtual ~Cached_item(); /*line -e1509 */ }; @@ -5320,6 +5322,14 @@ public: cmp(); item= save; } + Item* get_item() + { + return item; + } + void clear() + { + null_value= false; + } }; class Cached_item_str :public Cached_item_item @@ -5330,6 +5340,10 @@ public: Cached_item_str(THD *thd, Item *arg); bool cmp(void); int cmp_read_only(); + void clear() + { + null_value= false; + } ~Cached_item_str(); // Deallocate String:s }; @@ -5341,6 +5355,12 @@ public: Cached_item_real(Item *item_par) :Cached_item_item(item_par),value(0.0) {} bool cmp(void); int cmp_read_only(); + double get_value(){ return value;} + void clear() + { + value=0.0; + null_value= false; + } }; class Cached_item_int :public Cached_item_item @@ -5350,6 +5370,12 @@ public: Cached_item_int(Item *item_par) :Cached_item_item(item_par),value(0) {} bool cmp(void); int cmp_read_only(); + longlong get_value(){ return value;} + void clear() + { + value=0.0; + null_value= false; + } }; @@ -5360,6 +5386,12 @@ public: Cached_item_decimal(Item *item_par); bool cmp(void); int cmp_read_only(); + my_decimal get_value(){ return value;}; + void clear() + { + null_value= false; + my_decimal_set_zero(&value); + } }; class Cached_item_field :public Cached_item @@ -5377,6 +5409,10 @@ public: } bool cmp(void); int cmp_read_only(); + void clear() + { + null_value= false; + } }; class Item_default_value : public Item_field From 18747a4baa9cc68766eaa7a40e92f8c3d873631a Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 26 Jun 2017 02:15:19 +0530 Subject: [PATCH 036/138] Added value field to Item_sum_percentile_disc Check for single element in the order_list is added --- sql/item_windowfunc.cc | 16 ++++++++++++++++ sql/item_windowfunc.h | 29 ++++++++++++++++++++++++++++- 2 files changed, 44 insertions(+), 1 deletion(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 835a3cbfdae..50a8c5d82cd 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -108,6 +108,17 @@ Item_window_func::fix_fields(THD *thd, Item **ref) my_error(ER_NO_ORDER_LIST_IN_WINDOW_SPEC, MYF(0), window_func()->func_name()); return true; } + + if (only_single_element_order_list()) + { + // need to change the error, the error should say that we have more than one element in the order list + if (window_spec->order_list->elements != 1) + { + my_error(ER_NO_ORDER_LIST_IN_WINDOW_SPEC, MYF(0), window_func()->func_name()); + return true; + } + } + /* TODO: why the last parameter is 'ref' in this call? What if window_func decides to substitute itself for something else and does *ref=.... ? @@ -194,6 +205,11 @@ void Item_sum_dense_rank::setup_window_func(THD *thd, Window_spec *window_spec) clear(); } +void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_spec) +{ + setup_percentile_func(thd, window_spec->order_list); +} + bool Item_sum_dense_rank::add() { if (peer_tracker->check_if_next_group() || first_add) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index ac695729fc5..3a774a2ff57 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -705,7 +705,7 @@ class Item_sum_percentile_disc : public Item_sum_cume_dist { public: Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg) - {} + value(NULL) {} double val_real() { @@ -753,7 +753,23 @@ public: Item *get_copy(THD *thd, MEM_ROOT *mem_root) { return get_item_copy(thd, mem_root, this); } + void setup_window_func(THD *thd, Window_spec *window_spec); + void setup_percentile_func(THD *thd, SQL_I_List *list) + { + value= new_Cached_item(thd, list->first->item[0], FALSE); + } + void cleanup() + { + if (value) + { + delete value; + value= NULL; + } + Item_sum_num::cleanup(); + } +private: + Cached_item *value; }; @@ -871,6 +887,17 @@ public: } } + bool only_single_element_order_list() const + { + switch(window_func()->sum_func()){ + case Item_sum::PERCENTILE_CONT_FUNC: + case Item_sum::PERCENTILE_DISC_FUNC: + return true; + default: + return false; + } + } + /* Computation functions. TODO: consoder merging these with class Group_bound_tracker. From cc046fa92c8724801c3bd725b62a21b849e738f6 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 26 Jun 2017 03:39:25 +0530 Subject: [PATCH 037/138] A basic implementation of the add function is added --- sql/item_windowfunc.h | 35 +++++++++++++++++++++++++++++++---- 1 file changed, 31 insertions(+), 4 deletions(-) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 3a774a2ff57..6595012fabf 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -704,8 +704,8 @@ class Item_sum_ntile : public Item_sum_window_with_row_count class Item_sum_percentile_disc : public Item_sum_cume_dist { public: - Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg) - value(NULL) {} + Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), + value(NULL), val_calculated(FALSE) {} double val_real() { @@ -715,7 +715,18 @@ public: return 0; } null_value= false; - return 0; + return ((Cached_item_int*) value)->get_value(); + } + + longlong val_int() + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + return ((Cached_item_int*) value)->get_value(); } bool add() @@ -724,6 +735,19 @@ public: if (arg->is_null()) return true; /*implementation to be done*/ + Item_sum_cume_dist::add(); + double val1= Item_sum_cume_dist::val_real(); + /* need to check type and return value accordingly*/ + double val2 =arg->val_real_from_decimal(); + + /* use Cached_item to do the comparision using cmp_read_only() */ + + if( val1 >= val2 && !val_calculated) + { + val_calculated= true; + value->cmp(); + return false; + } return false; } @@ -734,7 +758,9 @@ public: void clear() { - //need to implement + val_calculated= false; + value->clear(); + Item_sum_cume_dist::clear(); } const char*func_name() const @@ -770,6 +796,7 @@ public: private: Cached_item *value; + bool val_calculated; }; From 31f1541f1e367f6eb91f948c4e814bb6554e6b78 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 26 Jun 2017 03:53:27 +0530 Subject: [PATCH 038/138] Setting handler to have the return type as that of the element by which we are ordering the partition --- sql/item.h | 2 +- sql/item_windowfunc.cc | 5 +++++ sql/item_windowfunc.h | 12 ++++++++---- sql/sql_window.cc | 4 ++++ 4 files changed, 18 insertions(+), 5 deletions(-) diff --git a/sql/item.h b/sql/item.h index 68d09577dcc..0e7582a9ac4 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5386,7 +5386,7 @@ public: Cached_item_decimal(Item *item_par); bool cmp(void); int cmp_read_only(); - my_decimal get_value(){ return value;}; + my_decimal *get_value(){ return &value;}; void clear() { null_value= false; diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 50a8c5d82cd..5e77132ad38 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -210,6 +210,11 @@ void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_s setup_percentile_func(thd, window_spec->order_list); } +void Item_sum_percentile_disc::set_type_handler(Window_spec *window_spec) +{ + type_handler()->get_handler_by_cmp_type(window_spec->order_list->first->item[0]->result_type()); +} + bool Item_sum_dense_rank::add() { if (peer_tracker->check_if_next_group() || first_add) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 6595012fabf..9087404ea3e 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -701,11 +701,13 @@ class Item_sum_ntile : public Item_sum_window_with_row_count ulong current_row_count_; }; -class Item_sum_percentile_disc : public Item_sum_cume_dist +class Item_sum_percentile_disc : public Item_sum_cume_dist, + public Type_handler_hybrid_field_type { public: Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), - value(NULL), val_calculated(FALSE) {} + Type_handler_hybrid_field_type(&type_handler_longlong), + value(NULL), val_calculated(FALSE) {} double val_real() { @@ -715,7 +717,7 @@ public: return 0; } null_value= false; - return ((Cached_item_int*) value)->get_value(); + return ((Cached_item_real*) value)->get_value(); } longlong val_int() @@ -769,7 +771,9 @@ public: } void update_field() {} - const Type_handler *type_handler() const { return &type_handler_double; } + void set_type_handler(Window_spec *window_spec); + const Type_handler *type_handler() const + {return Type_handler_hybrid_field_type::type_handler();} void fix_length_and_dec() { diff --git a/sql/sql_window.cc b/sql/sql_window.cc index a4c558b52b6..dc8c66120ff 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -319,6 +319,10 @@ setup_windows(THD *thd, Ref_ptr_array ref_pointer_array, TABLE_LIST *tables, while ((win_func_item= li++)) { win_func_item->update_used_tables(); + if (win_func_item->only_single_element_order_list()) + { + ((Item_sum_percentile_disc*)win_func_item)->set_type_handler(win_func_item->window_spec); + } } DBUG_RETURN(0); From c85552f42b12026f4a1f6c63973601c494b8f8b5 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 27 Jun 2017 02:24:32 +0530 Subject: [PATCH 039/138] Added a class Frame_unbounded_following_set_count_special, which is required to ignore all the null values while calculating the number of rows in the partition --- sql/sql_window.cc | 85 ++++++++++++++++++++++++++++++++++++++++++----- 1 file changed, 77 insertions(+), 8 deletions(-) diff --git a/sql/sql_window.cc b/sql/sql_window.cc index dc8c66120ff..e8925d5f45d 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -908,13 +908,14 @@ private: class Partition_read_cursor : public Table_read_cursor { public: - Partition_read_cursor(THD *thd, SQL_I_List *partition_list) : - bound_tracker(thd, partition_list) {} + Partition_read_cursor(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : + bound_tracker(thd, partition_list), order_tracker(thd, order_list) {} void init(READ_RECORD *info) { Table_read_cursor::init(info); bound_tracker.init(); + order_tracker.init(); end_of_partition= false; } @@ -966,9 +967,39 @@ public: } return 0; } + bool next_func(ha_rows *counter) + { + if (next()) + return true; + if (!check_for_null_row()) + { + (*counter)++; + } + return false; + } + bool fetch_func(ha_rows *counter) + { + if (fetch()) + return true; + if (!check_for_null_row()) + { + (*counter)++; + } + return false; + } + bool check_for_null_row() + { + if (!end_of_partition) + { + if (order_tracker.compare_with_cache_for_null_values()) + return true; + } + return false; + } private: Group_bound_tracker bound_tracker; + Group_bound_tracker order_tracker; bool end_of_partition; }; @@ -1200,7 +1231,7 @@ public: SQL_I_List *partition_list, SQL_I_List *order_list, bool is_preceding_arg, Item *n_val_arg) : - cursor(thd, partition_list), n_val(n_val_arg), item_add(NULL), + cursor(thd, partition_list, NULL), n_val(n_val_arg), item_add(NULL), is_preceding(is_preceding_arg) { DBUG_ASSERT(order_list->elements == 1); @@ -1339,7 +1370,7 @@ public: SQL_I_List *partition_list, SQL_I_List *order_list, bool is_preceding_arg, Item *n_val_arg) : - cursor(thd, partition_list), n_val(n_val_arg), item_add(NULL), + cursor(thd, partition_list, NULL), n_val(n_val_arg), item_add(NULL), is_preceding(is_preceding_arg), added_values(false) { DBUG_ASSERT(order_list->elements == 1); @@ -1469,7 +1500,7 @@ public: Frame_range_current_row_bottom(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - cursor(thd, partition_list), peer_tracker(thd, order_list) + cursor(thd, partition_list, NULL), peer_tracker(thd, order_list) { } @@ -1684,7 +1715,7 @@ public: Frame_unbounded_following(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - cursor(thd, partition_list) {} + cursor(thd, partition_list, order_list){} void init(READ_RECORD *info) { @@ -1756,6 +1787,35 @@ public: } }; +class Frame_unbounded_following_set_count_special : public Frame_unbounded_following_set_count +{ +public: + Frame_unbounded_following_set_count_special( + THD *thd, + SQL_I_List *partition_list, SQL_I_List *order_list) : + Frame_unbounded_following_set_count(thd, partition_list, order_list) + {} + + void next_partition(ha_rows rownum) + { + ha_rows num_rows_in_partition= 0; + if (cursor.fetch_func(&num_rows_in_partition)) + return; + + /* Walk to the end of the partition, find how many rows there are. */ + while (!cursor.next_func(&num_rows_in_partition)); + + List_iterator_fast it(sum_functions); + Item_sum* item; + while ((item= it++)) + { + Item_sum_window_with_row_count* item_with_row_count = + static_cast(item); + item_with_row_count->set_row_count(num_rows_in_partition); + } + } +}; + ///////////////////////////////////////////////////////////////////////////// // ROWS-type frame bounds ///////////////////////////////////////////////////////////////////////////// @@ -1953,7 +2013,7 @@ public: SQL_I_List *order_list, bool is_top_bound_arg, ha_rows n_rows_arg) : is_top_bound(is_top_bound_arg), n_rows(n_rows_arg), - cursor(thd, partition_list) + cursor(thd, partition_list, NULL) { } @@ -2564,9 +2624,18 @@ void get_window_functions_required_cursors( */ if (item_win_func->requires_partition_size()) { - fc= new Frame_unbounded_following_set_count(thd, + if (item_win_func->only_single_element_order_list()) + { + fc= new Frame_unbounded_following_set_count_special(thd, item_win_func->window_spec->partition_list, item_win_func->window_spec->order_list); + } + else + { + fc= new Frame_unbounded_following_set_count(thd, + item_win_func->window_spec->partition_list, + item_win_func->window_spec->order_list); + } fc->add_sum_func(sum_func); cursor_manager->add_cursor(fc); } From ba9fbc6a83f75bce99ff5e2295a6929203297471 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 27 Jun 2017 02:50:18 +0530 Subject: [PATCH 040/138] implementation of add() function added to the Item_sum_percentile_disc class --- sql/item_windowfunc.h | 64 +++++++++++++++++++++++++++++++++++++------ 1 file changed, 56 insertions(+), 8 deletions(-) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 9087404ea3e..3178bdeb54b 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -24,6 +24,7 @@ class Window_spec; int test_if_group_changed(List &list); + /* A wrapper around test_if_group_changed */ class Group_bound_tracker { @@ -31,10 +32,13 @@ public: Group_bound_tracker(THD *thd, SQL_I_List *list) { - for (ORDER *curr = list->first; curr; curr=curr->next) + if (list) { - Cached_item *tmp= new_Cached_item(thd, curr->item[0], TRUE); - group_fields.push_back(tmp); + for (ORDER *curr = list->first; curr; curr=curr->next) + { + Cached_item *tmp= new_Cached_item(thd, curr->item[0], TRUE); + group_fields.push_back(tmp); + } } } @@ -86,6 +90,19 @@ public: return 0; } + bool compare_with_cache_for_null_values() + { + List_iterator li(group_fields); + Cached_item *ptr; + while ((ptr= li++)) + { + ptr->cmp(); + if (ptr->null_value) + return true; + } + return false; + } + private: List group_fields; /* @@ -100,6 +117,7 @@ private: bool first_check; }; + /* ROW_NUMBER() OVER (...) @@ -707,7 +725,7 @@ class Item_sum_percentile_disc : public Item_sum_cume_dist, public: Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), Type_handler_hybrid_field_type(&type_handler_longlong), - value(NULL), val_calculated(FALSE) {} + value(NULL), result_value(NULL), val_calculated(FALSE) {} double val_real() { @@ -717,7 +735,7 @@ public: return 0; } null_value= false; - return ((Cached_item_real*) value)->get_value(); + return ((Cached_item_real*) result_value)->get_value(); } longlong val_int() @@ -728,7 +746,18 @@ public: return 0; } null_value= false; - return ((Cached_item_int*) value)->get_value(); + return ((Cached_item_int*) result_value)->get_value(); + } + + my_decimal* val_decimal(my_decimal* dec) + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + return ((Cached_item_decimal*) result_value)->get_value(); } bool add() @@ -736,7 +765,18 @@ public: Item *arg = get_arg(0); if (arg->is_null()) return true; - /*implementation to be done*/ + /* + need to ensure that the Item arg is constant across the entire partition + and its value ranges between [0,1] + */ + value->cmp(); + + /* for the null values of the row, we dont count take those rows in account for calculating + the CUME_DIST */ + + if(value->null_value) + return false; + Item_sum_cume_dist::add(); double val1= Item_sum_cume_dist::val_real(); /* need to check type and return value accordingly*/ @@ -747,7 +787,7 @@ public: if( val1 >= val2 && !val_calculated) { val_calculated= true; - value->cmp(); + result_value->cmp(); return false; } return false; @@ -762,6 +802,7 @@ public: { val_calculated= false; value->clear(); + result_value->clear(); Item_sum_cume_dist::clear(); } @@ -787,6 +828,7 @@ public: void setup_percentile_func(THD *thd, SQL_I_List *list) { value= new_Cached_item(thd, list->first->item[0], FALSE); + result_value= new_Cached_item(thd, list->first->item[0], FALSE); } void cleanup() { @@ -795,11 +837,17 @@ public: delete value; value= NULL; } + if(result_value) + { + delete result_value; + result_value= NULL; + } Item_sum_num::cleanup(); } private: Cached_item *value; + Cached_item *result_value; bool val_calculated; }; From d2214da4d0d5d8509dfe928733b5bb866ba59195 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 27 Jun 2017 12:44:00 +0530 Subject: [PATCH 041/138] Test case added for the percentile disc function --- mysql-test/t/percentile.test | 41 ++++++++++++++++++++++++++++++++++++ 1 file changed, 41 insertions(+) create mode 100644 mysql-test/t/percentile.test diff --git a/mysql-test/t/percentile.test b/mysql-test/t/percentile.test new file mode 100644 index 00000000000..0958fc05e7d --- /dev/null +++ b/mysql-test/t/percentile.test @@ -0,0 +1,41 @@ +CREATE TABLE student (name CHAR(10), test double, score TINYINT); + +INSERT INTO student VALUES +('Chun', 0, null), ('Chun', 0, 4), +('Esben', 1, null), ('Esben', 1, null), +('Kaolin', 0.5, 56), ('Kaolin', 0.5, 88), +('Tatiana', 0.8, 2), ('Tatiana', 0.8, 1); + + + +select name, percentile_disc(0.6) within group(order by score) over (partition by name) from student; +select name, percentile_disc(test) within group(order by score) over (partition by name) from student; +select name, percentile_disc(0.4) within group(order by score) over (partition by name) from student; + + +#select name, percentile_cont(null) within group(order by score) over (partition by name) from student; +#select name, cume_dist() over (partition by name order by score) from student; + + +#normal parsing +#select percentile_cont(0.5) within group(order by score) over w1 from student +#window w1 AS (partition by name); + +# no partition clause +#select percentile_cont(0.5) within group(order by score) over () from student; + + +# only one sort allowed +#select percentile_cont(0.5) within group(order by score) over (partition by name); + +#parameter value should be in the range of 0 to 1 +#select percentile_cont(1.5) within group(order by score) over (partition by name); + + +# +#select rank() over (partition by name order by score ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) from student; + + + +drop table student; + From 01d2b6e9d94b26ae0df8e900958f91f0c23f203e Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 6 Jul 2017 01:29:49 +0530 Subject: [PATCH 042/138] Implemented the implementation of percentile functions using Item_cache instead of Cache_Item --- sql/item.h | 5 +-- sql/item_windowfunc.cc | 14 +++---- sql/item_windowfunc.h | 82 +++++++++++++++++--------------------- sql/sql_window.cc | 90 ++++++++++++++++++------------------------ 4 files changed, 83 insertions(+), 108 deletions(-) diff --git a/sql/item.h b/sql/item.h index 0e7582a9ac4..067deba8b58 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5322,10 +5322,7 @@ public: cmp(); item= save; } - Item* get_item() - { - return item; - } + void clear() { null_value= false; diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 5e77132ad38..8a35cd34e82 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -111,7 +111,7 @@ Item_window_func::fix_fields(THD *thd, Item **ref) if (only_single_element_order_list()) { - // need to change the error, the error should say that we have more than one element in the order list + //TODO (varun): need to change the error, the error should say that we have more than one element in the order list if (window_spec->order_list->elements != 1) { my_error(ER_NO_ORDER_LIST_IN_WINDOW_SPEC, MYF(0), window_func()->func_name()); @@ -207,12 +207,12 @@ void Item_sum_dense_rank::setup_window_func(THD *thd, Window_spec *window_spec) void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_spec) { - setup_percentile_func(thd, window_spec->order_list); -} - -void Item_sum_percentile_disc::set_type_handler(Window_spec *window_spec) -{ - type_handler()->get_handler_by_cmp_type(window_spec->order_list->first->item[0]->result_type()); + order_item= window_spec->order_list->first->item[0]; + set_handler_by_cmp_type(order_item->result_type()); + if (!(value= order_item->get_cache(thd))) + return; + value->setup(thd, order_item); + value->store(order_item); } bool Item_sum_dense_rank::add() diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 3178bdeb54b..7c6c3c87025 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -42,6 +42,12 @@ public: } } + Group_bound_tracker(THD *thd, Item *item) + { + Cached_item *tmp= new_Cached_item(thd, item, FALSE); + group_fields.push_back(tmp); + } + void init() { first_check= true; @@ -117,7 +123,6 @@ private: bool first_check; }; - /* ROW_NUMBER() OVER (...) @@ -725,7 +730,7 @@ class Item_sum_percentile_disc : public Item_sum_cume_dist, public: Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), Type_handler_hybrid_field_type(&type_handler_longlong), - value(NULL), result_value(NULL), val_calculated(FALSE) {} + value(NULL), val_calculated(FALSE), first_call(TRUE),prev_value(0), order_item(NULL){} double val_real() { @@ -735,7 +740,7 @@ public: return 0; } null_value= false; - return ((Cached_item_real*) result_value)->get_value(); + return value->val_real(); } longlong val_int() @@ -746,7 +751,7 @@ public: return 0; } null_value= false; - return ((Cached_item_int*) result_value)->get_value(); + return value->val_int(); } my_decimal* val_decimal(my_decimal* dec) @@ -757,7 +762,7 @@ public: return 0; } null_value= false; - return ((Cached_item_decimal*) result_value)->get_value(); + return value->val_decimal(dec); } bool add() @@ -765,31 +770,32 @@ public: Item *arg = get_arg(0); if (arg->is_null()) return true; - /* - need to ensure that the Item arg is constant across the entire partition - and its value ranges between [0,1] - */ - value->cmp(); - /* for the null values of the row, we dont count take those rows in account for calculating - the CUME_DIST */ + if (first_call) + { + prev_value= arg->val_real(); + first_call= false; + } - if(value->null_value) + if(prev_value != arg->val_real() || prev_value >1 || prev_value < 0) + { + // TODO(varun) need to add an error here , check the MDEV-12985 for the information + return true; + } + + if (val_calculated) return false; + value->store(order_item); + value->cache_value(); + if (value->null_value) + return false; + Item_sum_cume_dist::add(); - double val1= Item_sum_cume_dist::val_real(); - /* need to check type and return value accordingly*/ - double val2 =arg->val_real_from_decimal(); + double val= Item_sum_cume_dist::val_real(); - /* use Cached_item to do the comparision using cmp_read_only() */ - - if( val1 >= val2 && !val_calculated) - { + if(val >= prev_value && !val_calculated) val_calculated= true; - result_value->cmp(); - return false; - } return false; } @@ -801,8 +807,8 @@ public: void clear() { val_calculated= false; + first_call= true; value->clear(); - result_value->clear(); Item_sum_cume_dist::clear(); } @@ -825,33 +831,19 @@ public: Item *get_copy(THD *thd, MEM_ROOT *mem_root) { return get_item_copy(thd, mem_root, this); } void setup_window_func(THD *thd, Window_spec *window_spec); - void setup_percentile_func(THD *thd, SQL_I_List *list) - { - value= new_Cached_item(thd, list->first->item[0], FALSE); - result_value= new_Cached_item(thd, list->first->item[0], FALSE); - } - void cleanup() - { - if (value) - { - delete value; - value= NULL; - } - if(result_value) - { - delete result_value; - result_value= NULL; - } - Item_sum_num::cleanup(); - } + void setup_hybrid(THD *thd, Item *item); private: - Cached_item *value; - Cached_item *result_value; + Item_cache *value; bool val_calculated; + bool first_call; + double prev_value; + Item *order_item; }; + + class Item_window_func : public Item_func_or_sum { /* Window function parameters as we've got them from the parser */ diff --git a/sql/sql_window.cc b/sql/sql_window.cc index e8925d5f45d..bb7742b029a 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -319,10 +319,6 @@ setup_windows(THD *thd, Ref_ptr_array ref_pointer_array, TABLE_LIST *tables, while ((win_func_item= li++)) { win_func_item->update_used_tables(); - if (win_func_item->only_single_element_order_list()) - { - ((Item_sum_percentile_disc*)win_func_item)->set_type_handler(win_func_item->window_spec); - } } DBUG_RETURN(0); @@ -908,14 +904,13 @@ private: class Partition_read_cursor : public Table_read_cursor { public: - Partition_read_cursor(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - bound_tracker(thd, partition_list), order_tracker(thd, order_list) {} + Partition_read_cursor(THD *thd, SQL_I_List *partition_list) : + bound_tracker(thd, partition_list){} void init(READ_RECORD *info) { Table_read_cursor::init(info); bound_tracker.init(); - order_tracker.init(); end_of_partition= false; } @@ -967,42 +962,18 @@ public: } return 0; } - bool next_func(ha_rows *counter) + bool check_for_end_of_partition() { - if (next()) - return true; - if (!check_for_null_row()) - { - (*counter)++; - } - return false; - } - bool fetch_func(ha_rows *counter) - { - if (fetch()) - return true; - if (!check_for_null_row()) - { - (*counter)++; - } - return false; - } - bool check_for_null_row() - { - if (!end_of_partition) - { - if (order_tracker.compare_with_cache_for_null_values()) - return true; - } - return false; + return end_of_partition; } private: Group_bound_tracker bound_tracker; - Group_bound_tracker order_tracker; bool end_of_partition; }; + + ///////////////////////////////////////////////////////////////////////////// /* @@ -1178,7 +1149,7 @@ public: Frame_cursor *cursor; while ((cursor= iter++)) cursor->pre_next_row(); - + iter.rewind(); while ((cursor= iter++)) cursor->next_row(); @@ -1231,7 +1202,7 @@ public: SQL_I_List *partition_list, SQL_I_List *order_list, bool is_preceding_arg, Item *n_val_arg) : - cursor(thd, partition_list, NULL), n_val(n_val_arg), item_add(NULL), + cursor(thd, partition_list), n_val(n_val_arg), item_add(NULL), is_preceding(is_preceding_arg) { DBUG_ASSERT(order_list->elements == 1); @@ -1370,7 +1341,7 @@ public: SQL_I_List *partition_list, SQL_I_List *order_list, bool is_preceding_arg, Item *n_val_arg) : - cursor(thd, partition_list, NULL), n_val(n_val_arg), item_add(NULL), + cursor(thd, partition_list), n_val(n_val_arg), item_add(NULL), is_preceding(is_preceding_arg), added_values(false) { DBUG_ASSERT(order_list->elements == 1); @@ -1500,7 +1471,7 @@ public: Frame_range_current_row_bottom(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - cursor(thd, partition_list, NULL), peer_tracker(thd, order_list) + cursor(thd, partition_list), peer_tracker(thd, order_list) { } @@ -1715,7 +1686,7 @@ public: Frame_unbounded_following(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - cursor(thd, partition_list, order_list){} + cursor(thd, partition_list){} void init(READ_RECORD *info) { @@ -1758,7 +1729,7 @@ public: Frame_unbounded_following_set_count( THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - Frame_unbounded_following(thd, partition_list, order_list) {} + Frame_unbounded_following(thd, partition_list, order_list){} void next_partition(ha_rows rownum) { @@ -1769,7 +1740,9 @@ public: /* Walk to the end of the partition, find how many rows there are. */ while (!cursor.next()) + { num_rows_in_partition++; + } List_iterator_fast it(sum_functions); Item_sum* item; @@ -1787,23 +1760,29 @@ public: } }; -class Frame_unbounded_following_set_count_special : public Frame_unbounded_following_set_count +class Frame_unbounded_following_set_count_special: public Frame_unbounded_following_set_count { -public: - Frame_unbounded_following_set_count_special( - THD *thd, - SQL_I_List *partition_list, SQL_I_List *order_list) : - Frame_unbounded_following_set_count(thd, partition_list, order_list) - {} +public: + Frame_unbounded_following_set_count_special(THD *thd, + SQL_I_List *partition_list, + SQL_I_List *order_list, Item* arg) : + Frame_unbounded_following_set_count(thd,partition_list, order_list) + { + order_item= order_list->first->item[0]; + } void next_partition(ha_rows rownum) { ha_rows num_rows_in_partition= 0; - if (cursor.fetch_func(&num_rows_in_partition)) + if (cursor.fetch()) return; /* Walk to the end of the partition, find how many rows there are. */ - while (!cursor.next_func(&num_rows_in_partition)); + do + { + if (!order_item->is_null()) + num_rows_in_partition++; + }while (!cursor.next()); List_iterator_fast it(sum_functions); Item_sum* item; @@ -1814,6 +1793,13 @@ public: item_with_row_count->set_row_count(num_rows_in_partition); } } + + ha_rows get_curr_rownum() const + { + return cursor.get_rownum(); + } +private: + Item* order_item; }; ///////////////////////////////////////////////////////////////////////////// @@ -2013,7 +1999,7 @@ public: SQL_I_List *order_list, bool is_top_bound_arg, ha_rows n_rows_arg) : is_top_bound(is_top_bound_arg), n_rows(n_rows_arg), - cursor(thd, partition_list, NULL) + cursor(thd, partition_list) { } @@ -2628,7 +2614,7 @@ void get_window_functions_required_cursors( { fc= new Frame_unbounded_following_set_count_special(thd, item_win_func->window_spec->partition_list, - item_win_func->window_spec->order_list); + item_win_func->window_spec->order_list, item_win_func->window_func()->get_arg(0)); } else { From 275ce39f05c364ca25bb7ecaa6a0bb02df83bdc4 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Fri, 7 Jul 2017 17:37:06 +0530 Subject: [PATCH 043/138] Percentile class implemented, most of the functions have the same functionalite as the percentile cont class --- sql/item_windowfunc.cc | 21 ++++++ sql/item_windowfunc.h | 161 ++++++++++++++++++++++++++++++++++++++++- sql/sql_window.cc | 1 + sql/sql_yacc.yy | 4 +- 4 files changed, 184 insertions(+), 3 deletions(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 8a35cd34e82..051dc203ab9 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -117,6 +117,12 @@ Item_window_func::fix_fields(THD *thd, Item **ref) my_error(ER_NO_ORDER_LIST_IN_WINDOW_SPEC, MYF(0), window_func()->func_name()); return true; } + /*switch(window_spec->order_list->firt->item[0]->type()) + { + case INT_TYPE: + default: + break; + }*/ } /* @@ -215,6 +221,21 @@ void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_s value->store(order_item); } +void Item_sum_percentile_cont::setup_window_func(THD *thd, Window_spec *window_spec) +{ + order_item= window_spec->order_list->first->item[0]; + //set_handler_by_cmp_type(order_item->result_type()); + if (!(ceil_value= order_item->get_cache(thd))) + return; + ceil_value->setup(thd, order_item); + ceil_value->store(order_item); + + if (!(floor_value= order_item->get_cache(thd))) + return; + floor_value->setup(thd, order_item); + floor_value->store(order_item); +} + bool Item_sum_dense_rank::add() { if (peer_tracker->check_if_next_group() || first_add) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 7c6c3c87025..9dfff36f952 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -646,7 +646,7 @@ class Item_sum_cume_dist: public Item_sum_window_with_row_count ulonglong get_row_number() { - return current_row_count_; + return current_row_count_ ; } private: @@ -774,10 +774,14 @@ public: if (first_call) { prev_value= arg->val_real(); + if (prev_value >1 || prev_value < 0) + { + return true; + } first_call= false; } - if(prev_value != arg->val_real() || prev_value >1 || prev_value < 0) + if(prev_value != arg->val_real()) { // TODO(varun) need to add an error here , check the MDEV-12985 for the information return true; @@ -841,6 +845,159 @@ private: Item *order_item; }; +class Item_sum_percentile_cont : public Item_sum_cume_dist, + public Type_handler_hybrid_field_type +{ +public: + Item_sum_percentile_cont(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), + Type_handler_hybrid_field_type(&type_handler_double), + floor_value(NULL), ceil_value(NULL), first_call(TRUE),prev_value(0), + ceil_val_calculated(FALSE), floor_val_calculated(FALSE), order_item(NULL){} + + double val_real() + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + double val= 1 + prev_value * (get_row_count()-1); + + /* + Applying the formula to get the value + If (CRN = FRN = RN) then the result is (value of expression from row at RN) + Otherwise the result is + (CRN - RN) * (value of expression for row at FRN) + + (RN - FRN) * (value of expression for row at CRN) + */ + + if(ceil(val) == floor(val)) + return floor_value->val_real(); + + double ret_val= ((val - floor(val)) * ceil_value->val_real()) + + ((ceil(val) - val) * floor_value->val_real()); + + return ret_val; + + } + longlong val_int() + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + return 0; + } + + my_decimal* val_decimal(my_decimal* dec) + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + return 0; + } + null_value= false; + return ceil_value->val_decimal(dec); + } + + bool add() + { + Item *arg = get_arg(0); + if (arg->is_null()) + return true; + + if (first_call) + { + first_call= false; + prev_value= arg->val_real(); + if (prev_value >1 || prev_value < 0) + { + // TODO(varun) need to add an error here , check the MDEV-12985 for the information + return true; + } + } + + if (prev_value != arg->val_real()) + { + // TODO(varun) need to add an error here , check the MDEV-12985 for the information + return true; + } + + if (!floor_val_calculated) + { + floor_value->store(order_item); + floor_value->cache_value(); + if (floor_value->null_value) + return false; + } + if (floor_val_calculated && !ceil_val_calculated) + { + ceil_value->store(order_item); + ceil_value->cache_value(); + if (ceil_value->null_value) + return false; + } + + Item_sum_cume_dist::add(); + double val= 1 + prev_value * (get_row_count()-1); + + if (!floor_val_calculated && get_row_number() == floor(val)) + floor_val_calculated= true; + + if (!ceil_val_calculated && get_row_number() == ceil(val)) + ceil_val_calculated= true; + return false; + } + + enum Sumfunctype sum_func() const + { + return PERCENTILE_DISC_FUNC; + } + + void clear() + { + first_call= true; + floor_value->clear(); + ceil_value->clear(); + floor_val_calculated= false; + ceil_val_calculated= false; + Item_sum_cume_dist::clear(); + } + + const char*func_name() const + { + return "percentile_cont"; + } + void update_field() {} + void set_type_handler(Window_spec *window_spec); + const Type_handler *type_handler() const + {return Type_handler_hybrid_field_type::type_handler();} + + void fix_length_and_dec() + { + decimals = 10; // TODO-cvicentiu find out how many decimals the standard + // requires. + } + + Item *get_copy(THD *thd, MEM_ROOT *mem_root) + { return get_item_copy(thd, mem_root, this); } + void setup_window_func(THD *thd, Window_spec *window_spec); + void setup_hybrid(THD *thd, Item *item); + +private: + Item_cache *floor_value; + Item_cache *ceil_value; + bool first_call; + double prev_value; + bool ceil_val_calculated; + bool floor_val_calculated; + Item *order_item; +}; + diff --git a/sql/sql_window.cc b/sql/sql_window.cc index bb7742b029a..d1628c46e2a 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -2540,6 +2540,7 @@ void add_special_frame_cursors(THD *thd, Cursor_manager *cursor_manager, cursor_manager->add_cursor(fc); break; } + case Item_sum::PERCENTILE_CONT_FUNC: case Item_sum::PERCENTILE_DISC_FUNC: { fc= new Frame_unbounded_preceding(thd, diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 62dbc3860ec..b5bc70639b0 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -10723,7 +10723,9 @@ inverse_distribution_function: inverse_distribution_function_def: PERCENTILE_CONT_SYM '(' expr ')' { - //Not yet started implementing + $$= new (thd->mem_root) Item_sum_percentile_cont(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; } | PERCENTILE_DISC_SYM '(' expr ')' { From 3393005e958de87909ac5fa7f8e6ca92f8cc8b21 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 10 Jul 2017 01:12:56 +0530 Subject: [PATCH 044/138] Ensured that the the element in the order by clause should have a numerical time, if not throw an error --- sql/item_windowfunc.cc | 18 ++++++++++++++++++ sql/sql_window.cc | 6 ++++++ 2 files changed, 24 insertions(+) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 051dc203ab9..d5e13054755 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -185,6 +185,21 @@ void Item_window_func::split_sum_func(THD *thd, Ref_ptr_array ref_pointer_array, window_func()->setup_caches(thd); } +bool Item_window_func::check_order_list() +{ + if (only_single_element_order_list()) + { + Item_result rtype= window_spec->order_list->first->item[0]->result_type(); + if (rtype != REAL_RESULT && rtype != INT_RESULT && + rtype != DECIMAL_RESULT) + { + // TODO(varun) please change the error name + my_error(ER_WRONG_TYPE_FOR_RANGE_FRAME, MYF(0),"percentile functions"); + return TRUE; + } + } + return FALSE; +} /* This must be called before attempting to compute the window function values. @@ -224,6 +239,9 @@ void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_s void Item_sum_percentile_cont::setup_window_func(THD *thd, Window_spec *window_spec) { order_item= window_spec->order_list->first->item[0]; + /* TODO(varun): need to discuss and finalise what type should we + return for percentile cont functions + */ //set_handler_by_cmp_type(order_item->result_type()); if (!(ceil_value= order_item->get_cache(thd))) return; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index d1628c46e2a..08e93dfcce2 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -321,6 +321,12 @@ setup_windows(THD *thd, Ref_ptr_array ref_pointer_array, TABLE_LIST *tables, win_func_item->update_used_tables(); } + li.rewind(); + while((win_func_item= li++)) + { + if (win_func_item->check_order_list()) + DBUG_RETURN(1); + } DBUG_RETURN(0); } From eb2187a24f43fa22d0eb12ed9c9bae13faf16bd5 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 13:19:20 +0530 Subject: [PATCH 045/138] Val_str function added for the percentile_disc function, as it can have result type as STRING_RESULT --- sql/item_windowfunc.h | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 9dfff36f952..c5c2c0aa004 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -765,6 +765,17 @@ public: return value->val_decimal(dec); } + String* val_str(String *str) + { + if (get_row_count() == 0 || get_arg(0)->is_null()) + { + null_value= true; + return 0; + } + null_value= false; + return value->val_str(str); + } + bool add() { Item *arg = get_arg(0); From 64a2a3029577e1539bcf029c73d616b40b657b1c Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 13:21:23 +0530 Subject: [PATCH 046/138] Error codes added for the percentile functions, the errors are -ER_NOT_SINGLE_ELEMENT_ORDER_LIST -ER_WRONG_TYPE_FOR_PERCENTILE_CONT -ER_ARGUMENT_NOT_CONSTANT -ER_ARGUMENT_OUT_OF_RANGE --- sql/share/errmsg-utf8.txt | 8 ++++++++ 1 file changed, 8 insertions(+) diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index e414a674af6..1011d540e51 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7786,3 +7786,11 @@ ER_COMPRESSED_COLUMN_USED_AS_KEY eng "Compressed column '%-.192s' can't be used in key specification" ER_UNKNOWN_COMPRESSION_METHOD eng "Unknown compression method: %s" +ER_NOT_SINGLE_ELEMENT_ORDER_LIST + eng "Incorrect number of elements in the order list for '%s'" +ER_WRONG_TYPE_FOR_PERCENTILE_CONT + eng "Numeric datatype is required for Percentile_CONT function" +ER_ARGUMENT_NOT_CONSTANT + eng "Argument to the percentile functions is not a constant" +ER_ARGUMENT_OUT_OF_RANGE + eng "Argument to the percentile functions does not belong to the range [0,1]" \ No newline at end of file From 330577988f23bcee35fb3956d35d9c51f410ea46 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 13:25:08 +0530 Subject: [PATCH 047/138] has_error field added to the item_sum class. This field ensures that query is terminated if we get any error during the add function call. This is currently used only for the percentile functions --- sql/item_sum.cc | 3 ++- sql/item_sum.h | 7 ++++--- 2 files changed, 6 insertions(+), 4 deletions(-) diff --git a/sql/item_sum.cc b/sql/item_sum.cc index b047dc4ea4d..4f9cdfe20e8 100644 --- a/sql/item_sum.cc +++ b/sql/item_sum.cc @@ -441,6 +441,7 @@ Item_sum::Item_sum(THD *thd, List &list): Item_func_or_sum(thd, list) mark_as_sum_func(); init_aggregator(); list.empty(); // Fields are used + has_error= FALSE; } @@ -452,7 +453,7 @@ Item_sum::Item_sum(THD *thd, Item_sum *item): Item_func_or_sum(thd, item), aggr_sel(item->aggr_sel), nest_level(item->nest_level), aggr_level(item->aggr_level), - quick_group(item->quick_group), + quick_group(item->quick_group), has_error(FALSE), orig_args(NULL) { if (arg_count <= 2) diff --git a/sql/item_sum.h b/sql/item_sum.h index 467a77c8983..a3bcf397db7 100644 --- a/sql/item_sum.h +++ b/sql/item_sum.h @@ -367,6 +367,7 @@ public: int8 max_arg_level; /* max level of unbound column references */ int8 max_sum_func_level;/* max level of aggregation for embedded functions */ bool quick_group; /* If incremental update of fields */ + bool has_error; /* This list is used by the check for mixing non aggregated fields and sum functions in the ONLY_FULL_GROUP_BY_MODE. We save all outer fields @@ -388,19 +389,19 @@ protected: public: void mark_as_sum_func(); - Item_sum(THD *thd): Item_func_or_sum(thd), quick_group(1) + Item_sum(THD *thd): Item_func_or_sum(thd), quick_group(1), has_error(0) { mark_as_sum_func(); init_aggregator(); } Item_sum(THD *thd, Item *a): Item_func_or_sum(thd, a), quick_group(1), - orig_args(tmp_orig_args) + has_error(0), orig_args(tmp_orig_args) { mark_as_sum_func(); init_aggregator(); } Item_sum(THD *thd, Item *a, Item *b): Item_func_or_sum(thd, a, b), - quick_group(1), orig_args(tmp_orig_args) + quick_group(1), has_error(0), orig_args(tmp_orig_args) { mark_as_sum_func(); init_aggregator(); From 96565ac3118c936e81969cb68e3d1c6fa34c4114 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 15:02:22 +0530 Subject: [PATCH 048/138] Added the function setting_handler_for_percentile_function() for the percentile_disc function that would set the type of the result field for percentile_disc. Percentile_cont would habe double precision result type --- sql/item_windowfunc.h | 15 +++++++++++++++ 1 file changed, 15 insertions(+) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index c5c2c0aa004..a83147fc7a1 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -1137,6 +1137,21 @@ public: } } + void setting_handler_for_percentile_functions(Item_result rtype) const + { + switch(window_func()->sum_func()){ + case Item_sum::PERCENTILE_DISC_FUNC: + ((Item_sum_percentile_disc* ) window_func())->set_handler_by_cmp_type(rtype); + break; + default: + return; + } + } + + bool check_result_type_of_order_item(); + + + /* Computation functions. TODO: consoder merging these with class Group_bound_tracker. From 947ce922c950323a91a187b53d3315b6e6a582f0 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 15:06:42 +0530 Subject: [PATCH 049/138] Added the error ER_NOT_SINGLE_ELEMENT_ORDER_LIST for th percentile functions, these ensure that for the percentile function we have the order list with exactly one element --- sql/item_windowfunc.cc | 9 +-------- 1 file changed, 1 insertion(+), 8 deletions(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index d5e13054755..c860c5ead68 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -111,18 +111,11 @@ Item_window_func::fix_fields(THD *thd, Item **ref) if (only_single_element_order_list()) { - //TODO (varun): need to change the error, the error should say that we have more than one element in the order list if (window_spec->order_list->elements != 1) { - my_error(ER_NO_ORDER_LIST_IN_WINDOW_SPEC, MYF(0), window_func()->func_name()); + my_error(ER_NOT_SINGLE_ELEMENT_ORDER_LIST, MYF(0), window_func()->func_name()); return true; } - /*switch(window_spec->order_list->firt->item[0]->type()) - { - case INT_TYPE: - default: - break; - }*/ } /* From 6511069e7fcf3c9035469f9d2996706fbde5d6a0 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 15:08:08 +0530 Subject: [PATCH 050/138] Added the error ER_WRONG_TYPE_FOR_PERCENTILE_CONT, which ensures that the result type for percentile_cont is always numerical --- sql/item_windowfunc.cc | 11 ++++------- 1 file changed, 4 insertions(+), 7 deletions(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index c860c5ead68..4022c3ddf70 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -178,25 +178,24 @@ void Item_window_func::split_sum_func(THD *thd, Ref_ptr_array ref_pointer_array, window_func()->setup_caches(thd); } -bool Item_window_func::check_order_list() +bool Item_window_func::check_result_type_of_order_item() { if (only_single_element_order_list()) { Item_result rtype= window_spec->order_list->first->item[0]->result_type(); if (rtype != REAL_RESULT && rtype != INT_RESULT && - rtype != DECIMAL_RESULT) + rtype != DECIMAL_RESULT && window_func()->sum_func() == Item_sum::PERCENTILE_CONT_FUNC) { - // TODO(varun) please change the error name - my_error(ER_WRONG_TYPE_FOR_RANGE_FRAME, MYF(0),"percentile functions"); + my_error(ER_WRONG_TYPE_FOR_PERCENTILE_CONT, MYF(0)); return TRUE; } + setting_handler_for_percentile_functions(rtype); } return FALSE; } /* This must be called before attempting to compute the window function values. - @detail If we attempt to do it in fix_fields(), partition_fields will refer to the original window function arguments. @@ -222,7 +221,6 @@ void Item_sum_dense_rank::setup_window_func(THD *thd, Window_spec *window_spec) void Item_sum_percentile_disc::setup_window_func(THD *thd, Window_spec *window_spec) { order_item= window_spec->order_list->first->item[0]; - set_handler_by_cmp_type(order_item->result_type()); if (!(value= order_item->get_cache(thd))) return; value->setup(thd, order_item); @@ -235,7 +233,6 @@ void Item_sum_percentile_cont::setup_window_func(THD *thd, Window_spec *window_s /* TODO(varun): need to discuss and finalise what type should we return for percentile cont functions */ - //set_handler_by_cmp_type(order_item->result_type()); if (!(ceil_value= order_item->get_cache(thd))) return; ceil_value->setup(thd, order_item); From 03ed22326a85c50a67d4c43e9392de8c135cf649 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 15:10:19 +0530 Subject: [PATCH 051/138] Added the error 1)ER_ARGUMENT_OUT_OF_RANGE: This error is thrown if the argument of the percentile function is not in the range [0,1] 2)ER_ARGUMENT_NOT_CONSTANT: This error is thrown if the argument of the percnetile function is not constant in the entire partition of the window function --- sql/item_windowfunc.h | 52 +++++++++++++++++-------------------------- sql/sql_window.cc | 12 ++++++++-- 2 files changed, 30 insertions(+), 34 deletions(-) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index a83147fc7a1..995010d2df2 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -730,7 +730,8 @@ class Item_sum_percentile_disc : public Item_sum_cume_dist, public: Item_sum_percentile_disc(THD *thd, Item* arg) : Item_sum_cume_dist(thd, arg), Type_handler_hybrid_field_type(&type_handler_longlong), - value(NULL), val_calculated(FALSE), first_call(TRUE),prev_value(0), order_item(NULL){} + value(NULL), val_calculated(FALSE), first_call(TRUE), + prev_value(0), order_item(NULL){} double val_real() { @@ -780,21 +781,26 @@ public: { Item *arg = get_arg(0); if (arg->is_null()) - return true; + return false; if (first_call) { prev_value= arg->val_real(); if (prev_value >1 || prev_value < 0) { + my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); + has_error= TRUE; return true; } first_call= false; } - if(prev_value != arg->val_real()) + double arg_val= arg->val_real(); + + if(prev_value != arg_val) { - // TODO(varun) need to add an error here , check the MDEV-12985 for the information + my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); + has_error= TRUE; return true; } @@ -821,6 +827,7 @@ public: void clear() { + has_error= false; val_calculated= false; first_call= true; value->clear(); @@ -890,36 +897,13 @@ public: ((ceil(val) - val) * floor_value->val_real()); return ret_val; - - } - longlong val_int() - { - if (get_row_count() == 0 || get_arg(0)->is_null()) - { - null_value= true; - return 0; - } - null_value= false; - return 0; - } - - my_decimal* val_decimal(my_decimal* dec) - { - if (get_row_count() == 0 || get_arg(0)->is_null()) - { - null_value= true; - return 0; - return 0; - } - null_value= false; - return ceil_value->val_decimal(dec); } bool add() { Item *arg = get_arg(0); if (arg->is_null()) - return true; + return false; if (first_call) { @@ -927,14 +911,17 @@ public: prev_value= arg->val_real(); if (prev_value >1 || prev_value < 0) { - // TODO(varun) need to add an error here , check the MDEV-12985 for the information + my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); + has_error= TRUE; return true; } } - if (prev_value != arg->val_real()) + double arg_val= arg->val_real(); + if(prev_value != arg_val) { - // TODO(varun) need to add an error here , check the MDEV-12985 for the information + my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); + has_error= TRUE; return true; } @@ -966,12 +953,13 @@ public: enum Sumfunctype sum_func() const { - return PERCENTILE_DISC_FUNC; + return PERCENTILE_CONT_FUNC; } void clear() { first_call= true; + has_error= false; floor_value->clear(); ceil_value->clear(); floor_val_calculated= false; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index 08e93dfcce2..d51ffdc2f83 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -324,7 +324,7 @@ setup_windows(THD *thd, Ref_ptr_array ref_pointer_array, TABLE_LIST *tables, li.rewind(); while((win_func_item= li++)) { - if (win_func_item->check_order_list()) + if (win_func_item->check_result_type_of_order_item()) DBUG_RETURN(1); } DBUG_RETURN(0); @@ -1078,12 +1078,13 @@ protected: { if (perform_no_action) return; - List_iterator_fast it(sum_functions); Item_sum *item_sum; while ((item_sum= it++)) { item_sum->add(); + if (item_sum->has_error) + return; } } @@ -2809,6 +2810,12 @@ bool compute_window_func(THD *thd, { cursor_manager->notify_cursors_next_row(); } + + /* check if we found any error in the window function while calling the add function */ + + if (win_func->window_func()->has_error) + goto label; + /* Return to current row after notifying cursors for each window function. */ tbl->file->ha_rnd_pos(tbl->record[0], rowid_buf); @@ -2821,6 +2828,7 @@ bool compute_window_func(THD *thd, rownum++; } +label: my_free(rowid_buf); partition_trackers.delete_elements(); end_read_record(&info); From f04426f7271388416b69feeb8252d03f0a29df46 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Mon, 17 Jul 2017 15:23:21 +0530 Subject: [PATCH 052/138] Added more tests for the percentile functions --- mysql-test/r/win_percentile_cont.result | 111 ++++++++++++++++++++++++ mysql-test/t/win_percentile_cont.test | 55 ++++++++++++ 2 files changed, 166 insertions(+) create mode 100644 mysql-test/r/win_percentile_cont.result create mode 100644 mysql-test/t/win_percentile_cont.test diff --git a/mysql-test/r/win_percentile_cont.result b/mysql-test/r/win_percentile_cont.result new file mode 100644 index 00000000000..61f70892887 --- /dev/null +++ b/mysql-test/r/win_percentile_cont.result @@ -0,0 +1,111 @@ +CREATE TABLE student (name CHAR(10), test double, score DECIMAL(19,4)); +INSERT INTO student VALUES +('Chun', 0, 3), ('Chun', 0, 7), +('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), +('Kaolin', 0.5, 4), +('Tatiana', 0.8, 4), ('Tata', 0.8, 4); +select name, percentile_disc(0.5) within group(order by score) over () from student; +name percentile_disc(0.5) within group(order by score) over () +Chun 4.0000000000 +Chun 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select name, percentile_cont(0.5) within group(order by score) over () from student; +name percentile_cont(0.5) within group(order by score) over () +Chun 4.0000000000 +Chun 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select name, percentile_cont(null) within group(order by score) over (partition by name) from student; +name percentile_cont(null) within group(order by score) over (partition by name) +Chun NULL +Chun NULL +Kaolin NULL +Kaolin NULL +Kaolin NULL +Tatiana NULL +Tata NULL +select name, percentile_disc(null) within group(order by score) over (partition by name) from student; +name percentile_disc(null) within group(order by score) over (partition by name) +Chun NULL +Chun NULL +Kaolin NULL +Kaolin NULL +Kaolin NULL +Tatiana NULL +Tata NULL +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from student; +name c +Chun 5.0000000000 +Chun 5.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from student; +name c +Chun 3.0000000000 +Chun 3.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from student ) as t; +name percentile_cont(0.5) within group ( order by score) over (partition by name ) +Chun 5.0000000000 +Chun 5.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from student ) as t; +name percentile_disc(0.5) within group ( order by score) over (partition by name ) +Chun 3.0000000000 +Chun 3.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select name from student a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from student b limit 1) >= 0.5; +name +Chun +Chun +Kaolin +Kaolin +Kaolin +Tatiana +Tata +select score, percentile_cont(0.5) within group(order by name) over (partition by score) from student; +ERROR HY000: Numeric datatype is required for Percentile_CONT function +select score, percentile_disc(0.5) within group(order by name) over (partition by score) from student; +score percentile_disc(0.5) within group(order by name) over (partition by score) +3.0000 Chun +7.0000 Chun +3.0000 Chun +7.0000 Chun +4.0000 Tata +4.0000 Tata +4.0000 Tata +select percentile_disc(0.5) within group(order by score,test) over (partition by name) from student; +ERROR HY000: Incorrect number of elements in the order list for 'percentile_disc' +select percentile_cont(0.5) within group(order by score,test) over (partition by name) from student; +ERROR HY000: Incorrect number of elements in the order list for 'percentile_cont' +select percentile_disc(1.5) within group(order by score) over (partition by name) from student; +ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +select percentile_cont(1.5) within group(order by score) over (partition by name) from student; +ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +select name,percentile_cont(test) within group(order by score) over (partition by name) from student; +ERROR HY000: Argument to the percentile functions is not a constant +select name, percentile_disc(test) within group(order by score) over (partition by name) from student; +ERROR HY000: Argument to the percentile functions is not a constant +drop table student; diff --git a/mysql-test/t/win_percentile_cont.test b/mysql-test/t/win_percentile_cont.test new file mode 100644 index 00000000000..75fde963b2a --- /dev/null +++ b/mysql-test/t/win_percentile_cont.test @@ -0,0 +1,55 @@ +CREATE TABLE student (name CHAR(10), test double, score DECIMAL(19,4)); +INSERT INTO student VALUES +('Chun', 0, 3), ('Chun', 0, 7), +('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), +('Kaolin', 0.5, 4), +('Tatiana', 0.8, 4), ('Tata', 0.8, 4); + +#no partition clause +select name, percentile_disc(0.5) within group(order by score) over () from student; +select name, percentile_cont(0.5) within group(order by score) over () from student; + +# argument set to null +select name, percentile_cont(null) within group(order by score) over (partition by name) from student; +select name, percentile_disc(null) within group(order by score) over (partition by name) from student; + +# complete query with partition column +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from student; +select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from student; + +#subqueries having percentile functions + +select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from student ) as t; +select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from student ) as t; +select name from student a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from student b limit 1) >= 0.5; + +# WITH STORED PROCEDURES + + +#DISALLOWED FIELDS IN ORDER BY CLAUSE +--error ER_WRONG_TYPE_FOR_PERCENTILE_CONT +select score, percentile_cont(0.5) within group(order by name) over (partition by score) from student; +select score, percentile_disc(0.5) within group(order by name) over (partition by score) from student; + +# error with 2 order by elements + +--error ER_NOT_SINGLE_ELEMENT_ORDER_LIST +select percentile_disc(0.5) within group(order by score,test) over (partition by name) from student; +--error ER_NOT_SINGLE_ELEMENT_ORDER_LIST +select percentile_cont(0.5) within group(order by score,test) over (partition by name) from student; + +#parameter value should be in the range of 0 to 1( NEED TO THINK A WAY FOR THIS) +--error ER_ARGUMENT_OUT_OF_RANGE +select percentile_disc(1.5) within group(order by score) over (partition by name) from student; +--error ER_ARGUMENT_OUT_OF_RANGE +select percentile_cont(1.5) within group(order by score) over (partition by name) from student; + +--error ER_ARGUMENT_NOT_CONSTANT +select name,percentile_cont(test) within group(order by score) over (partition by name) from student; +--error ER_ARGUMENT_NOT_CONSTANT +select name, percentile_disc(test) within group(order by score) over (partition by name) from student; + +#CHECK TYPE OF THE ARGUMENT, SHOULD BE ONLY NUMERICAL +#select name, percentile_cont(name) within group(order by score) over (partition by name) from student; + +drop table student; From f8e135c7dfc212d24ca6b00df92f9f3ba2d77970 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 18 Jul 2017 01:55:31 +0530 Subject: [PATCH 053/138] made changes according to the review, mostly removing unused code and fixing code to follow the coding conventions --- sql/item.h | 30 ----------------- sql/item_windowfunc.h | 34 ++++---------------- sql/sql_window.cc | 20 +++++------- sql/sql_yacc.yy | 75 +++++++++++++++++++++++-------------------- 4 files changed, 55 insertions(+), 104 deletions(-) diff --git a/sql/item.h b/sql/item.h index 067deba8b58..f4f2055b48c 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5303,8 +5303,6 @@ public: /* Compare the cached value with the source value, without copying */ virtual int cmp_read_only()=0; - virtual void clear()=0; - virtual ~Cached_item(); /*line -e1509 */ }; @@ -5322,11 +5320,6 @@ public: cmp(); item= save; } - - void clear() - { - null_value= false; - } }; class Cached_item_str :public Cached_item_item @@ -5337,10 +5330,6 @@ public: Cached_item_str(THD *thd, Item *arg); bool cmp(void); int cmp_read_only(); - void clear() - { - null_value= false; - } ~Cached_item_str(); // Deallocate String:s }; @@ -5353,11 +5342,6 @@ public: bool cmp(void); int cmp_read_only(); double get_value(){ return value;} - void clear() - { - value=0.0; - null_value= false; - } }; class Cached_item_int :public Cached_item_item @@ -5368,11 +5352,6 @@ public: bool cmp(void); int cmp_read_only(); longlong get_value(){ return value;} - void clear() - { - value=0.0; - null_value= false; - } }; @@ -5384,11 +5363,6 @@ public: bool cmp(void); int cmp_read_only(); my_decimal *get_value(){ return &value;}; - void clear() - { - null_value= false; - my_decimal_set_zero(&value); - } }; class Cached_item_field :public Cached_item @@ -5406,10 +5380,6 @@ public: } bool cmp(void); int cmp_read_only(); - void clear() - { - null_value= false; - } }; class Item_default_value : public Item_field diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 995010d2df2..a2357b24980 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -32,22 +32,13 @@ public: Group_bound_tracker(THD *thd, SQL_I_List *list) { - if (list) + for (ORDER *curr = list->first; curr; curr=curr->next) { - for (ORDER *curr = list->first; curr; curr=curr->next) - { Cached_item *tmp= new_Cached_item(thd, curr->item[0], TRUE); group_fields.push_back(tmp); - } } } - Group_bound_tracker(THD *thd, Item *item) - { - Cached_item *tmp= new_Cached_item(thd, item, FALSE); - group_fields.push_back(tmp); - } - void init() { first_check= true; @@ -96,19 +87,6 @@ public: return 0; } - bool compare_with_cache_for_null_values() - { - List_iterator li(group_fields); - Cached_item *ptr; - while ((ptr= li++)) - { - ptr->cmp(); - if (ptr->null_value) - return true; - } - return false; - } - private: List group_fields; /* @@ -797,7 +775,7 @@ public: double arg_val= arg->val_real(); - if(prev_value != arg_val) + if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); has_error= TRUE; @@ -815,7 +793,7 @@ public: Item_sum_cume_dist::add(); double val= Item_sum_cume_dist::val_real(); - if(val >= prev_value && !val_calculated) + if (val >= prev_value && !val_calculated) val_calculated= true; return false; } @@ -918,7 +896,7 @@ public: } double arg_val= arg->val_real(); - if(prev_value != arg_val) + if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); has_error= TRUE; @@ -1116,7 +1094,7 @@ public: bool only_single_element_order_list() const { - switch(window_func()->sum_func()){ + switch (window_func()->sum_func()){ case Item_sum::PERCENTILE_CONT_FUNC: case Item_sum::PERCENTILE_DISC_FUNC: return true; @@ -1127,7 +1105,7 @@ public: void setting_handler_for_percentile_functions(Item_result rtype) const { - switch(window_func()->sum_func()){ + switch (window_func()->sum_func()){ case Item_sum::PERCENTILE_DISC_FUNC: ((Item_sum_percentile_disc* ) window_func())->set_handler_by_cmp_type(rtype); break; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index d51ffdc2f83..e60e23c80cf 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -322,7 +322,7 @@ setup_windows(THD *thd, Ref_ptr_array ref_pointer_array, TABLE_LIST *tables, } li.rewind(); - while((win_func_item= li++)) + while ((win_func_item= li++)) { if (win_func_item->check_result_type_of_order_item()) DBUG_RETURN(1); @@ -911,7 +911,7 @@ class Partition_read_cursor : public Table_read_cursor { public: Partition_read_cursor(THD *thd, SQL_I_List *partition_list) : - bound_tracker(thd, partition_list){} + bound_tracker(thd, partition_list) {} void init(READ_RECORD *info) { @@ -968,10 +968,6 @@ public: } return 0; } - bool check_for_end_of_partition() - { - return end_of_partition; - } private: Group_bound_tracker bound_tracker; @@ -1078,6 +1074,7 @@ protected: { if (perform_no_action) return; + List_iterator_fast it(sum_functions); Item_sum *item_sum; while ((item_sum= it++)) @@ -1156,7 +1153,7 @@ public: Frame_cursor *cursor; while ((cursor= iter++)) cursor->pre_next_row(); - + iter.rewind(); while ((cursor= iter++)) cursor->next_row(); @@ -1693,7 +1690,7 @@ public: Frame_unbounded_following(THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - cursor(thd, partition_list){} + cursor(thd, partition_list) {} void init(READ_RECORD *info) { @@ -1736,7 +1733,7 @@ public: Frame_unbounded_following_set_count( THD *thd, SQL_I_List *partition_list, SQL_I_List *order_list) : - Frame_unbounded_following(thd, partition_list, order_list){} + Frame_unbounded_following(thd, partition_list, order_list) {} void next_partition(ha_rows rownum) { @@ -1747,9 +1744,7 @@ public: /* Walk to the end of the partition, find how many rows there are. */ while (!cursor.next()) - { num_rows_in_partition++; - } List_iterator_fast it(sum_functions); Item_sum* item; @@ -1773,7 +1768,7 @@ class Frame_unbounded_following_set_count_special: public Frame_unbounded_follow public: Frame_unbounded_following_set_count_special(THD *thd, SQL_I_List *partition_list, - SQL_I_List *order_list, Item* arg) : + SQL_I_List *order_list, Item* arg) : Frame_unbounded_following_set_count(thd,partition_list, order_list) { order_item= order_list->first->item[0]; @@ -1805,6 +1800,7 @@ public: { return cursor.get_rownum(); } + private: Item* order_item; }; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index b5bc70639b0..4b4a9bb5f6f 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -10191,6 +10191,11 @@ geometry_function: Item_func_spatial_precise_rel(thd, $3, $5, Item_func::SP_CONTAINS_FUNC)); } + | WITHIN '(' expr ',' expr ')' + { + $$= GEOM_NEW(thd, Item_func_spatial_precise_rel(thd, $3, $5, + Item_func::SP_WITHIN_FUNC)); + } | GEOMETRYCOLLECTION '(' expr_list ')' { $$= GEOM_NEW(thd, @@ -10237,6 +10242,7 @@ geometry_function: Geometry::wkb_polygon, Geometry::wkb_linestring)); } + ; /* @@ -10699,45 +10705,45 @@ simple_window_func: ; inverse_distribution_function: - inverse_distribution_function_def WITHIN GROUP_SYM - '(' - { Select->prepare_add_window_spec(thd); } - order_by_single_element_list ')' OVER_SYM - '(' opt_window_ref opt_window_partition_clause ')' - { - LEX *lex= Lex; - if (Select->add_window_spec(thd, lex->win_ref, - Select->group_list, - Select->order_list, - NULL)) - MYSQL_YYABORT; - $$= new (thd->mem_root) Item_window_func(thd, (Item_sum *) $1, - thd->lex->win_spec); - if ($$ == NULL) - MYSQL_YYABORT; - if (Select->add_window_func((Item_window_func *) $$)) - MYSQL_YYABORT; - } + inverse_distribution_function_def WITHIN GROUP_SYM + '(' + { Select->prepare_add_window_spec(thd); } + order_by_single_element_list ')' OVER_SYM + '(' opt_window_ref opt_window_partition_clause ')' + { + LEX *lex= Lex; + if (Select->add_window_spec(thd, lex->win_ref, + Select->group_list, + Select->order_list, + NULL)) + MYSQL_YYABORT; + $$= new (thd->mem_root) Item_window_func(thd, (Item_sum *) $1, + thd->lex->win_spec); + if ($$ == NULL) + MYSQL_YYABORT; + if (Select->add_window_func((Item_window_func *) $$)) + MYSQL_YYABORT; + } ; inverse_distribution_function_def: - PERCENTILE_CONT_SYM '(' expr ')' - { - $$= new (thd->mem_root) Item_sum_percentile_cont(thd, $3); - if ($$ == NULL) - MYSQL_YYABORT; - } - | PERCENTILE_DISC_SYM '(' expr ')' - { - $$= new (thd->mem_root) Item_sum_percentile_disc(thd, $3); - if ($$ == NULL) - MYSQL_YYABORT; - } - ; + PERCENTILE_CONT_SYM '(' expr ')' + { + $$= new (thd->mem_root) Item_sum_percentile_cont(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; + } + | PERCENTILE_DISC_SYM '(' expr ')' + { + $$= new (thd->mem_root) Item_sum_percentile_disc(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; + } + ; order_by_single_element_list: - ORDER_SYM BY order_list - ; + ORDER_SYM BY order_list + ; window_name: ident @@ -14628,6 +14634,7 @@ keyword: | UNICODE_SYM {} | UNINSTALL_SYM {} | UNBOUNDED_SYM {} + | WITHIN | WRAPPER_SYM {} | XA_SYM {} | UPGRADE_SYM {} From f4ba298abd06024f619659a4d9aae1e3fad97b08 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Tue, 18 Jul 2017 02:58:08 +0530 Subject: [PATCH 054/138] Fixed indentation in the syntax rules for the sql_yacc.yy , also added the rules of the percentile functions to the sql_yacc_ora.yy --- sql/sql_yacc.yy | 13 ++++++------ sql/sql_yacc_ora.yy | 48 +++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 54 insertions(+), 7 deletions(-) diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 4b4a9bb5f6f..5fd33fb3249 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -10191,11 +10191,6 @@ geometry_function: Item_func_spatial_precise_rel(thd, $3, $5, Item_func::SP_CONTAINS_FUNC)); } - | WITHIN '(' expr ',' expr ')' - { - $$= GEOM_NEW(thd, Item_func_spatial_precise_rel(thd, $3, $5, - Item_func::SP_WITHIN_FUNC)); - } | GEOMETRYCOLLECTION '(' expr_list ')' { $$= GEOM_NEW(thd, @@ -10242,7 +10237,11 @@ geometry_function: Geometry::wkb_polygon, Geometry::wkb_linestring)); } - + | WITHIN '(' expr ',' expr ')' + { + $$= GEOM_NEW(thd, Item_func_spatial_precise_rel(thd, $3, $5, + Item_func::SP_WITHIN_FUNC)); + } ; /* @@ -14634,7 +14633,7 @@ keyword: | UNICODE_SYM {} | UNINSTALL_SYM {} | UNBOUNDED_SYM {} - | WITHIN + | WITHIN {} | WRAPPER_SYM {} | XA_SYM {} | UPGRADE_SYM {} diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy index db45414fd28..e04c7ee60b3 100644 --- a/sql/sql_yacc_ora.yy +++ b/sql/sql_yacc_ora.yy @@ -737,6 +737,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token PARTITIONING_SYM %token PASSWORD_SYM %token PERCENT_RANK_SYM +%token PERCENTILE_CONT_SYM +%token PERCENTILE_DISC_SYM %token PERSISTENT_SYM %token PHASE_SYM %token PLUGINS_SYM @@ -983,6 +985,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token WINDOW_SYM %token WHILE_SYM %token WITH /* SQL-2003-R */ +%token WITHIN %token WITH_CUBE_SYM /* INTERNAL */ %token WITH_ROLLUP_SYM /* INTERNAL */ %token WORK_SYM /* SQL-2003-N */ @@ -1147,6 +1150,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); window_func_expr window_func simple_window_func + inverse_distribution_function + inverse_distribution_function_def explicit_cursor_attr function_call_keyword function_call_nonkeyword @@ -9389,6 +9394,7 @@ column_default_non_parenthesized_expr: | variable | sum_expr | window_func_expr + | inverse_distribution_function | ROW_SYM '(' expr ',' expr_list ')' { $5->push_front($3, thd->mem_root); @@ -10718,6 +10724,47 @@ simple_window_func: } ; +inverse_distribution_function: + inverse_distribution_function_def WITHIN GROUP_SYM + '(' + { Select->prepare_add_window_spec(thd); } + order_by_single_element_list ')' OVER_SYM + '(' opt_window_ref opt_window_partition_clause ')' + { + LEX *lex= Lex; + if (Select->add_window_spec(thd, lex->win_ref, + Select->group_list, + Select->order_list, + NULL)) + MYSQL_YYABORT; + $$= new (thd->mem_root) Item_window_func(thd, (Item_sum *) $1, + thd->lex->win_spec); + if ($$ == NULL) + MYSQL_YYABORT; + if (Select->add_window_func((Item_window_func *) $$)) + MYSQL_YYABORT; + } + ; + +inverse_distribution_function_def: + PERCENTILE_CONT_SYM '(' expr ')' + { + $$= new (thd->mem_root) Item_sum_percentile_cont(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; + } + | PERCENTILE_DISC_SYM '(' expr ')' + { + $$= new (thd->mem_root) Item_sum_percentile_disc(thd, $3); + if ($$ == NULL) + MYSQL_YYABORT; + } + ; + +order_by_single_element_list: + ORDER_SYM BY order_list + ; + window_name: ident { @@ -14703,6 +14750,7 @@ keyword_directly_assignable: | UNICODE_SYM {} | UNINSTALL_SYM {} | UNBOUNDED_SYM {} + | WITHIN {} | WRAPPER_SYM {} | XA_SYM {} | UPGRADE_SYM {} From 24e219b179142b3708ff4bdf5ae3db96d6fa184a Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Vicen=C8=9Biu=20Ciorbaru?= Date: Tue, 29 Aug 2017 18:27:16 +0300 Subject: [PATCH 055/138] Remove has_error as a member from Item_sum and use THD::is_error() instead Additionally, allow a query with window functions to be killed by the user during its execution. --- sql/item_sum.cc | 3 +-- sql/item_sum.h | 7 +++---- sql/item_windowfunc.h | 6 ------ sql/sql_window.cc | 10 ++++------ 4 files changed, 8 insertions(+), 18 deletions(-) diff --git a/sql/item_sum.cc b/sql/item_sum.cc index 4f9cdfe20e8..b047dc4ea4d 100644 --- a/sql/item_sum.cc +++ b/sql/item_sum.cc @@ -441,7 +441,6 @@ Item_sum::Item_sum(THD *thd, List &list): Item_func_or_sum(thd, list) mark_as_sum_func(); init_aggregator(); list.empty(); // Fields are used - has_error= FALSE; } @@ -453,7 +452,7 @@ Item_sum::Item_sum(THD *thd, Item_sum *item): Item_func_or_sum(thd, item), aggr_sel(item->aggr_sel), nest_level(item->nest_level), aggr_level(item->aggr_level), - quick_group(item->quick_group), has_error(FALSE), + quick_group(item->quick_group), orig_args(NULL) { if (arg_count <= 2) diff --git a/sql/item_sum.h b/sql/item_sum.h index a3bcf397db7..467a77c8983 100644 --- a/sql/item_sum.h +++ b/sql/item_sum.h @@ -367,7 +367,6 @@ public: int8 max_arg_level; /* max level of unbound column references */ int8 max_sum_func_level;/* max level of aggregation for embedded functions */ bool quick_group; /* If incremental update of fields */ - bool has_error; /* This list is used by the check for mixing non aggregated fields and sum functions in the ONLY_FULL_GROUP_BY_MODE. We save all outer fields @@ -389,19 +388,19 @@ protected: public: void mark_as_sum_func(); - Item_sum(THD *thd): Item_func_or_sum(thd), quick_group(1), has_error(0) + Item_sum(THD *thd): Item_func_or_sum(thd), quick_group(1) { mark_as_sum_func(); init_aggregator(); } Item_sum(THD *thd, Item *a): Item_func_or_sum(thd, a), quick_group(1), - has_error(0), orig_args(tmp_orig_args) + orig_args(tmp_orig_args) { mark_as_sum_func(); init_aggregator(); } Item_sum(THD *thd, Item *a, Item *b): Item_func_or_sum(thd, a, b), - quick_group(1), has_error(0), orig_args(tmp_orig_args) + quick_group(1), orig_args(tmp_orig_args) { mark_as_sum_func(); init_aggregator(); diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index a2357b24980..c1a8c594e20 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -767,7 +767,6 @@ public: if (prev_value >1 || prev_value < 0) { my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); - has_error= TRUE; return true; } first_call= false; @@ -778,7 +777,6 @@ public: if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); - has_error= TRUE; return true; } @@ -805,7 +803,6 @@ public: void clear() { - has_error= false; val_calculated= false; first_call= true; value->clear(); @@ -890,7 +887,6 @@ public: if (prev_value >1 || prev_value < 0) { my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); - has_error= TRUE; return true; } } @@ -899,7 +895,6 @@ public: if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); - has_error= TRUE; return true; } @@ -937,7 +932,6 @@ public: void clear() { first_call= true; - has_error= false; floor_value->clear(); ceil_value->clear(); floor_val_calculated= false; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index e60e23c80cf..9a274179b21 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -1080,8 +1080,6 @@ protected: while ((item_sum= it++)) { item_sum->add(); - if (item_sum->has_error) - return; } } @@ -2807,10 +2805,11 @@ bool compute_window_func(THD *thd, cursor_manager->notify_cursors_next_row(); } - /* check if we found any error in the window function while calling the add function */ + /* Check if we found any error in the window function while adding values + through cursors. */ + if (thd->is_error() || thd->is_killed()) + break; - if (win_func->window_func()->has_error) - goto label; /* Return to current row after notifying cursors for each window function. */ @@ -2824,7 +2823,6 @@ bool compute_window_func(THD *thd, rownum++; } -label: my_free(rowid_buf); partition_trackers.delete_elements(); end_read_record(&info); From b5c104d00a264e250cc008c6f2a42e8a2b18f385 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 7 Sep 2017 17:37:55 +0530 Subject: [PATCH 056/138] Changes made according to the review given, mostly fixing coding style errors --- mysql-test/r/win_percentile_cont.result | 111 ------------------------ mysql-test/t/win_percentile_cont.test | 55 ------------ sql/item.h | 3 - sql/item_windowfunc.h | 18 ++-- sql/sql_window.cc | 37 ++++---- 5 files changed, 28 insertions(+), 196 deletions(-) delete mode 100644 mysql-test/r/win_percentile_cont.result delete mode 100644 mysql-test/t/win_percentile_cont.test diff --git a/mysql-test/r/win_percentile_cont.result b/mysql-test/r/win_percentile_cont.result deleted file mode 100644 index 61f70892887..00000000000 --- a/mysql-test/r/win_percentile_cont.result +++ /dev/null @@ -1,111 +0,0 @@ -CREATE TABLE student (name CHAR(10), test double, score DECIMAL(19,4)); -INSERT INTO student VALUES -('Chun', 0, 3), ('Chun', 0, 7), -('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), -('Kaolin', 0.5, 4), -('Tatiana', 0.8, 4), ('Tata', 0.8, 4); -select name, percentile_disc(0.5) within group(order by score) over () from student; -name percentile_disc(0.5) within group(order by score) over () -Chun 4.0000000000 -Chun 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select name, percentile_cont(0.5) within group(order by score) over () from student; -name percentile_cont(0.5) within group(order by score) over () -Chun 4.0000000000 -Chun 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select name, percentile_cont(null) within group(order by score) over (partition by name) from student; -name percentile_cont(null) within group(order by score) over (partition by name) -Chun NULL -Chun NULL -Kaolin NULL -Kaolin NULL -Kaolin NULL -Tatiana NULL -Tata NULL -select name, percentile_disc(null) within group(order by score) over (partition by name) from student; -name percentile_disc(null) within group(order by score) over (partition by name) -Chun NULL -Chun NULL -Kaolin NULL -Kaolin NULL -Kaolin NULL -Tatiana NULL -Tata NULL -select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from student; -name c -Chun 5.0000000000 -Chun 5.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from student; -name c -Chun 3.0000000000 -Chun 3.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from student ) as t; -name percentile_cont(0.5) within group ( order by score) over (partition by name ) -Chun 5.0000000000 -Chun 5.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from student ) as t; -name percentile_disc(0.5) within group ( order by score) over (partition by name ) -Chun 3.0000000000 -Chun 3.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Kaolin 4.0000000000 -Tatiana 4.0000000000 -Tata 4.0000000000 -select name from student a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from student b limit 1) >= 0.5; -name -Chun -Chun -Kaolin -Kaolin -Kaolin -Tatiana -Tata -select score, percentile_cont(0.5) within group(order by name) over (partition by score) from student; -ERROR HY000: Numeric datatype is required for Percentile_CONT function -select score, percentile_disc(0.5) within group(order by name) over (partition by score) from student; -score percentile_disc(0.5) within group(order by name) over (partition by score) -3.0000 Chun -7.0000 Chun -3.0000 Chun -7.0000 Chun -4.0000 Tata -4.0000 Tata -4.0000 Tata -select percentile_disc(0.5) within group(order by score,test) over (partition by name) from student; -ERROR HY000: Incorrect number of elements in the order list for 'percentile_disc' -select percentile_cont(0.5) within group(order by score,test) over (partition by name) from student; -ERROR HY000: Incorrect number of elements in the order list for 'percentile_cont' -select percentile_disc(1.5) within group(order by score) over (partition by name) from student; -ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] -select percentile_cont(1.5) within group(order by score) over (partition by name) from student; -ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] -select name,percentile_cont(test) within group(order by score) over (partition by name) from student; -ERROR HY000: Argument to the percentile functions is not a constant -select name, percentile_disc(test) within group(order by score) over (partition by name) from student; -ERROR HY000: Argument to the percentile functions is not a constant -drop table student; diff --git a/mysql-test/t/win_percentile_cont.test b/mysql-test/t/win_percentile_cont.test deleted file mode 100644 index 75fde963b2a..00000000000 --- a/mysql-test/t/win_percentile_cont.test +++ /dev/null @@ -1,55 +0,0 @@ -CREATE TABLE student (name CHAR(10), test double, score DECIMAL(19,4)); -INSERT INTO student VALUES -('Chun', 0, 3), ('Chun', 0, 7), -('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), -('Kaolin', 0.5, 4), -('Tatiana', 0.8, 4), ('Tata', 0.8, 4); - -#no partition clause -select name, percentile_disc(0.5) within group(order by score) over () from student; -select name, percentile_cont(0.5) within group(order by score) over () from student; - -# argument set to null -select name, percentile_cont(null) within group(order by score) over (partition by name) from student; -select name, percentile_disc(null) within group(order by score) over (partition by name) from student; - -# complete query with partition column -select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from student; -select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from student; - -#subqueries having percentile functions - -select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from student ) as t; -select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from student ) as t; -select name from student a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from student b limit 1) >= 0.5; - -# WITH STORED PROCEDURES - - -#DISALLOWED FIELDS IN ORDER BY CLAUSE ---error ER_WRONG_TYPE_FOR_PERCENTILE_CONT -select score, percentile_cont(0.5) within group(order by name) over (partition by score) from student; -select score, percentile_disc(0.5) within group(order by name) over (partition by score) from student; - -# error with 2 order by elements - ---error ER_NOT_SINGLE_ELEMENT_ORDER_LIST -select percentile_disc(0.5) within group(order by score,test) over (partition by name) from student; ---error ER_NOT_SINGLE_ELEMENT_ORDER_LIST -select percentile_cont(0.5) within group(order by score,test) over (partition by name) from student; - -#parameter value should be in the range of 0 to 1( NEED TO THINK A WAY FOR THIS) ---error ER_ARGUMENT_OUT_OF_RANGE -select percentile_disc(1.5) within group(order by score) over (partition by name) from student; ---error ER_ARGUMENT_OUT_OF_RANGE -select percentile_cont(1.5) within group(order by score) over (partition by name) from student; - ---error ER_ARGUMENT_NOT_CONSTANT -select name,percentile_cont(test) within group(order by score) over (partition by name) from student; ---error ER_ARGUMENT_NOT_CONSTANT -select name, percentile_disc(test) within group(order by score) over (partition by name) from student; - -#CHECK TYPE OF THE ARGUMENT, SHOULD BE ONLY NUMERICAL -#select name, percentile_cont(name) within group(order by score) over (partition by name) from student; - -drop table student; diff --git a/sql/item.h b/sql/item.h index f4f2055b48c..1f743913d78 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5341,7 +5341,6 @@ public: Cached_item_real(Item *item_par) :Cached_item_item(item_par),value(0.0) {} bool cmp(void); int cmp_read_only(); - double get_value(){ return value;} }; class Cached_item_int :public Cached_item_item @@ -5351,7 +5350,6 @@ public: Cached_item_int(Item *item_par) :Cached_item_item(item_par),value(0) {} bool cmp(void); int cmp_read_only(); - longlong get_value(){ return value;} }; @@ -5362,7 +5360,6 @@ public: Cached_item_decimal(Item *item_par); bool cmp(void); int cmp_read_only(); - my_decimal *get_value(){ return &value;}; }; class Cached_item_field :public Cached_item diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index c1a8c594e20..8b3bd5a26e2 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -757,14 +757,14 @@ public: bool add() { - Item *arg = get_arg(0); + Item *arg= get_arg(0); if (arg->is_null()) return false; if (first_call) { prev_value= arg->val_real(); - if (prev_value >1 || prev_value < 0) + if (prev_value > 1 || prev_value < 0) { my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); return true; @@ -774,7 +774,7 @@ public: double arg_val= arg->val_real(); - if (prev_value != arg_val) + if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); return true; @@ -821,7 +821,7 @@ public: void fix_length_and_dec() { - decimals = 10; // TODO-cvicentiu find out how many decimals the standard + decimals = 5; // TODO-cvicentiu find out how many decimals the standard // requires. } @@ -829,6 +829,7 @@ public: { return get_item_copy(thd, mem_root, this); } void setup_window_func(THD *thd, Window_spec *window_spec); void setup_hybrid(THD *thd, Item *item); + bool fix_fields(THD *thd, Item **ref); private: Item_cache *value; @@ -876,7 +877,7 @@ public: bool add() { - Item *arg = get_arg(0); + Item *arg= get_arg(0); if (arg->is_null()) return false; @@ -884,7 +885,7 @@ public: { first_call= false; prev_value= arg->val_real(); - if (prev_value >1 || prev_value < 0) + if (prev_value > 1 || prev_value < 0) { my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); return true; @@ -892,7 +893,7 @@ public: } double arg_val= arg->val_real(); - if (prev_value != arg_val) + if (prev_value != arg_val) { my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); return true; @@ -950,7 +951,7 @@ public: void fix_length_and_dec() { - decimals = 10; // TODO-cvicentiu find out how many decimals the standard + decimals = 5; // TODO-cvicentiu find out how many decimals the standard // requires. } @@ -958,6 +959,7 @@ public: { return get_item_copy(thd, mem_root, this); } void setup_window_func(THD *thd, Window_spec *window_spec); void setup_hybrid(THD *thd, Item *item); + bool fix_fields(THD *thd, Item **ref); private: Item_cache *floor_value; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index 9a274179b21..059dd8073f5 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -1743,7 +1743,17 @@ public: /* Walk to the end of the partition, find how many rows there are. */ while (!cursor.next()) num_rows_in_partition++; + set_win_funcs_row_count(num_rows_in_partition); + } + ha_rows get_curr_rownum() const + { + return cursor.get_rownum(); + } + +protected: + void set_win_funcs_row_count(ha_rows num_rows_in_partition) + { List_iterator_fast it(sum_functions); Item_sum* item; while ((item= it++)) @@ -1753,20 +1763,16 @@ public: item_with_row_count->set_row_count(num_rows_in_partition); } } - - ha_rows get_curr_rownum() const - { - return cursor.get_rownum(); - } }; -class Frame_unbounded_following_set_count_special: public Frame_unbounded_following_set_count +class Frame_unbounded_following_set_count_no_nulls: + public Frame_unbounded_following_set_count { public: - Frame_unbounded_following_set_count_special(THD *thd, + Frame_unbounded_following_set_count_no_nulls(THD *thd, SQL_I_List *partition_list, - SQL_I_List *order_list, Item* arg) : + SQL_I_List *order_list) : Frame_unbounded_following_set_count(thd,partition_list, order_list) { order_item= order_list->first->item[0]; @@ -1782,16 +1788,9 @@ public: { if (!order_item->is_null()) num_rows_in_partition++; - }while (!cursor.next()); + } while (!cursor.next()); - List_iterator_fast it(sum_functions); - Item_sum* item; - while ((item= it++)) - { - Item_sum_window_with_row_count* item_with_row_count = - static_cast(item); - item_with_row_count->set_row_count(num_rows_in_partition); - } + set_win_funcs_row_count(num_rows_in_partition); } ha_rows get_curr_rownum() const @@ -2614,9 +2613,9 @@ void get_window_functions_required_cursors( { if (item_win_func->only_single_element_order_list()) { - fc= new Frame_unbounded_following_set_count_special(thd, + fc= new Frame_unbounded_following_set_count_no_nulls(thd, item_win_func->window_spec->partition_list, - item_win_func->window_spec->order_list, item_win_func->window_func()->get_arg(0)); + item_win_func->window_spec->order_list); } else { From 02a4a4b512ace75bbe66065c136d697e83a4d9ff Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 7 Sep 2017 17:40:09 +0530 Subject: [PATCH 057/138] Added fix_fields for percentile function to check the type of argument and to ensure that only numeric arguments are allowed --- sql/item_windowfunc.cc | 54 +++++++++++++++++++++++++++++++-------- sql/share/errmsg-utf8.txt | 4 ++- 2 files changed, 46 insertions(+), 12 deletions(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 4022c3ddf70..f941900646e 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -109,15 +109,6 @@ Item_window_func::fix_fields(THD *thd, Item **ref) return true; } - if (only_single_element_order_list()) - { - if (window_spec->order_list->elements != 1) - { - my_error(ER_NOT_SINGLE_ELEMENT_ORDER_LIST, MYF(0), window_func()->func_name()); - return true; - } - } - /* TODO: why the last parameter is 'ref' in this call? What if window_func decides to substitute itself for something else and does *ref=.... ? @@ -182,9 +173,11 @@ bool Item_window_func::check_result_type_of_order_item() { if (only_single_element_order_list()) { - Item_result rtype= window_spec->order_list->first->item[0]->result_type(); + Item_result rtype= window_spec->order_list->first->item[0]->cmp_type(); + // TODO (varun) : support date type in percentile_cont function if (rtype != REAL_RESULT && rtype != INT_RESULT && - rtype != DECIMAL_RESULT && window_func()->sum_func() == Item_sum::PERCENTILE_CONT_FUNC) + rtype != DECIMAL_RESULT && rtype != TIME_RESULT + window_func()->sum_func() == Item_sum::PERCENTILE_CONT_FUNC) { my_error(ER_WRONG_TYPE_FOR_PERCENTILE_CONT, MYF(0)); return TRUE; @@ -243,6 +236,45 @@ void Item_sum_percentile_cont::setup_window_func(THD *thd, Window_spec *window_s floor_value->setup(thd, order_item); floor_value->store(order_item); } +bool Item_sum_percentile_cont::fix_fields(THD *thd, Item **ref) +{ + bool res; + res= Item_sum_num::fix_fields(thd, ref); + if (res) + return res; + + switch(args[0]->cmp_type()) + { + case DECIMAL_RESULT: + case REAL_RESULT: + case INT_RESULT: + break; + default: + my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0)); + return TRUE; + } + return res; +} +bool Item_sum_percentile_disc::fix_fields(THD *thd, Item **ref) +{ + bool res; + res= Item_sum_num::fix_fields(thd, ref); + if (res) + return res; + + switch(args[0]->cmp_type()) + { + case DECIMAL_RESULT: + case REAL_RESULT: + case INT_RESULT: + break; + default: + my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0)); + return TRUE; + } + return res; + +} bool Item_sum_dense_rank::add() { diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 1011d540e51..415d47df36e 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7793,4 +7793,6 @@ ER_WRONG_TYPE_FOR_PERCENTILE_CONT ER_ARGUMENT_NOT_CONSTANT eng "Argument to the percentile functions is not a constant" ER_ARGUMENT_OUT_OF_RANGE - eng "Argument to the percentile functions does not belong to the range [0,1]" \ No newline at end of file + eng "Argument to the percentile functions does not belong to the range [0,1]" +ER_WRONG_TYPE_OF_ARGUMENT + eng "Numeric values are only allowed as arguments to percentile functions" \ No newline at end of file From 4f4f8f3fb120e9d4507766c817323c758a0a1990 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 26 Oct 2017 23:55:09 +0530 Subject: [PATCH 058/138] Added the median function to the parser , it should behave as a percentile_cont function with its argument fixed to 0.5 --- sql/lex.h | 1 + sql/sql_yacc.yy | 34 +++++++++++++++++++++++++++++----- 2 files changed, 30 insertions(+), 5 deletions(-) diff --git a/sql/lex.h b/sql/lex.h index 7967d17a5d4..63b0567c5d0 100644 --- a/sql/lex.h +++ b/sql/lex.h @@ -737,6 +737,7 @@ static SYMBOL sql_functions[] = { { "LAG", SYM(LAG_SYM)}, { "LEAD", SYM(LEAD_SYM)}, { "MAX", SYM(MAX_SYM)}, + { "MEDIAN", SYM(MEDIAN_SYM)}, { "MID", SYM(SUBSTRING)}, /* unireg function */ { "MIN", SYM(MIN_SYM)}, { "NOW", SYM(NOW_SYM)}, diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 5fd33fb3249..21ea4d3dbde 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1236,6 +1236,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token MAX_STATEMENT_TIME_SYM %token MAX_USER_CONNECTIONS_SYM %token MAXVALUE_SYM /* SQL-2003-N */ +%token MEDIAN_SYM %token MEDIUMBLOB %token MEDIUMINT %token MEDIUMTEXT @@ -1737,6 +1738,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); window_func simple_window_func inverse_distribution_function + percentile_function inverse_distribution_function_def function_call_keyword function_call_nonkeyword @@ -10703,12 +10705,11 @@ simple_window_func: } ; + + inverse_distribution_function: - inverse_distribution_function_def WITHIN GROUP_SYM - '(' - { Select->prepare_add_window_spec(thd); } - order_by_single_element_list ')' OVER_SYM - '(' opt_window_ref opt_window_partition_clause ')' + percentile_function OVER_SYM + '(' opt_window_partition_clause ')' { LEX *lex= Lex; if (Select->add_window_spec(thd, lex->win_ref, @@ -10725,6 +10726,29 @@ inverse_distribution_function: } ; +percentile_function: + inverse_distribution_function_def WITHIN GROUP_SYM '(' + { Select->prepare_add_window_spec(thd); } + order_by_single_element_list ')' + { + $$= $1; + } + | MEDIAN_SYM '(' expr ')' + { + Item *args= new (thd->mem_root) Item_decimal(thd, "0.5", 3, + thd->charset()); + if (($$ == NULL) || (thd->is_error())) + { + MYSQL_YYABORT; + } + if (add_order_to_list(thd, $3,FALSE)) MYSQL_YYABORT; + + $$= new (thd->mem_root) Item_sum_percentile_cont(thd, args); + if ($$ == NULL) + MYSQL_YYABORT; + } + ; + inverse_distribution_function_def: PERCENTILE_CONT_SYM '(' expr ')' { From b77105cab6b97c70a5a61084588805371da6caef Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 26 Oct 2017 23:55:52 +0530 Subject: [PATCH 059/138] Only single element order-by list is allowed for percentile functions --- sql/sql_yacc.yy | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 21ea4d3dbde..2f82b917ef1 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -10765,9 +10765,11 @@ inverse_distribution_function_def: ; order_by_single_element_list: - ORDER_SYM BY order_list + ORDER_SYM BY order_ident order_dir + { if (add_order_to_list(thd, $3,(bool) $4)) MYSQL_YYABORT; } ; + window_name: ident { From 58a6e43513bd9b8ee6cc58ddf3d8aee5fe0eb279 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Thu, 7 Sep 2017 23:51:42 +0530 Subject: [PATCH 060/138] Tests added for percentile and median functions --- mysql-test/r/win_percentile.result | 305 +++++++++++++++++++++++++++++ mysql-test/t/win_percentile.test | 77 ++++++++ sql/item_windowfunc.cc | 2 +- 3 files changed, 383 insertions(+), 1 deletion(-) create mode 100644 mysql-test/r/win_percentile.result create mode 100644 mysql-test/t/win_percentile.test diff --git a/mysql-test/r/win_percentile.result b/mysql-test/r/win_percentile.result new file mode 100644 index 00000000000..b365a995da0 --- /dev/null +++ b/mysql-test/r/win_percentile.result @@ -0,0 +1,305 @@ +CREATE TABLE t1 (name CHAR(10), test double, score DECIMAL(19,4)); +INSERT INTO t1 VALUES +('Chun', 0, 3), ('Chun', 0, 7), +('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), +('Kaolin', 0.5, 4), +('Tatiana', 0.8, 4), ('Tata', 0.8, 4); +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +name c +Chun 5.00000 +Chun 5.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +no partition clause +select name, percentile_disc(0.5) within group(order by score) over () from t1; +name percentile_disc(0.5) within group(order by score) over () +Chun 4.00000 +Chun 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +select name, percentile_cont(0.5) within group(order by score) over () from t1; +name percentile_cont(0.5) within group(order by score) over () +Chun 4.00000 +Chun 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +argument set to null +select name, percentile_cont(null) within group(order by score) over (partition by name) from t1; +ERROR HY000: Numeric values are only allowed as arguments to percentile functions +select name, percentile_disc(null) within group(order by score) over (partition by name) from t1; +ERROR HY000: Numeric values are only allowed as arguments to percentile functions +subqueries having percentile functions +select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +name percentile_cont(0.5) within group ( order by score) over (partition by name ) +Chun 5.00000 +Chun 5.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +name percentile_disc(0.5) within group ( order by score) over (partition by name ) +Chun 3.00000 +Chun 3.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +select name from t1 a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from t1 b limit 1) >= 0.5; +name +Chun +Chun +Kaolin +Kaolin +Kaolin +Tatiana +Tata +disallowed fields in order by +select score, percentile_cont(0.5) within group(order by name) over (partition by score) from t1; +ERROR HY000: Numeric datatype is required for Percentile_CONT function +select score, percentile_disc(0.5) within group(order by name) over (partition by score) from t1; +score percentile_disc(0.5) within group(order by name) over (partition by score) +3.0000 Chun +7.0000 Chun +3.0000 Chun +7.0000 Chun +4.0000 Tata +4.0000 Tata +4.0000 Tata +order by clause has more than one element +select percentile_disc(0.5) within group(order by score,test) over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 +select percentile_cont(0.5) within group(order by score,test) over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 +parameter value should be in the range of [0,1] +select percentile_disc(1.5) within group(order by score) over (partition by name) from t1; +ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +select percentile_cont(1.5) within group(order by score) over (partition by name) from t1; +ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +select name,percentile_cont(test) within group(order by score) over (partition by name) from t1; +ERROR HY000: Argument to the percentile functions is not a constant +select name, percentile_disc(test) within group(order by score) over (partition by name) from t1; +ERROR HY000: Argument to the percentile functions is not a constant +only numerical types are allowed as argument to percentile functions +select name, percentile_cont(name) within group(order by score) over (partition by name) from t1; +ERROR HY000: Numeric values are only allowed as arguments to percentile functions +complete query with partition column +select name,cume_dist() over (partition by name order by score), percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; +name cume_dist() over (partition by name order by score) c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 4.00000 +Kaolin 1.0000000000 4.00000 +Kaolin 0.6666666667 4.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +name c +Chun 5.00000 +Chun 5.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Kaolin 4.00000 +Tatiana 4.00000 +Tata 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.1) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 3.00000 +Kaolin 1.0000000000 3.00000 +Kaolin 0.6666666667 3.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.2) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 3.00000 +Kaolin 1.0000000000 3.00000 +Kaolin 0.6666666667 3.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.3) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 3.00000 +Kaolin 1.0000000000 3.00000 +Kaolin 0.6666666667 3.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.4) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 4.00000 +Kaolin 1.0000000000 4.00000 +Kaolin 0.6666666667 4.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 3.00000 +Chun 1.0000000000 3.00000 +Kaolin 0.3333333333 4.00000 +Kaolin 1.0000000000 4.00000 +Kaolin 0.6666666667 4.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.6) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 7.00000 +Chun 1.0000000000 7.00000 +Kaolin 0.3333333333 4.00000 +Kaolin 1.0000000000 4.00000 +Kaolin 0.6666666667 4.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.7) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 7.00000 +Chun 1.0000000000 7.00000 +Kaolin 0.3333333333 7.00000 +Kaolin 1.0000000000 7.00000 +Kaolin 0.6666666667 7.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.8) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 7.00000 +Chun 1.0000000000 7.00000 +Kaolin 0.3333333333 7.00000 +Kaolin 1.0000000000 7.00000 +Kaolin 0.6666666667 7.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.9) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 7.00000 +Chun 1.0000000000 7.00000 +Kaolin 0.3333333333 7.00000 +Kaolin 1.0000000000 7.00000 +Kaolin 0.6666666667 7.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(1) within group(order by score) over (partition by name) as c from t1; +name b c +Chun 0.5000000000 7.00000 +Chun 1.0000000000 7.00000 +Kaolin 0.3333333333 7.00000 +Kaolin 1.0000000000 7.00000 +Kaolin 0.6666666667 7.00000 +Tatiana 1.0000000000 4.00000 +Tata 1.0000000000 4.00000 +select median(score) over (partition by name), percentile_cont(0) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 3.00000 +5.00000 3.00000 +4.00000 3.00000 +4.00000 3.00000 +4.00000 3.00000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.1) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 3.40000 +5.00000 3.40000 +4.00000 3.20000 +4.00000 3.20000 +4.00000 3.20000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.2) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 3.80000 +5.00000 3.80000 +4.00000 3.40000 +4.00000 3.40000 +4.00000 3.40000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.3) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 4.20000 +5.00000 4.20000 +4.00000 3.60000 +4.00000 3.60000 +4.00000 3.60000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.4) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 4.60000 +5.00000 4.60000 +4.00000 3.80000 +4.00000 3.80000 +4.00000 3.80000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 5.00000 +5.00000 5.00000 +4.00000 4.00000 +4.00000 4.00000 +4.00000 4.00000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.6) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 5.40000 +5.00000 5.40000 +4.00000 4.60000 +4.00000 4.60000 +4.00000 4.60000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.7) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 5.80000 +5.00000 5.80000 +4.00000 5.20000 +4.00000 5.20000 +4.00000 5.20000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.8) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 6.20000 +5.00000 6.20000 +4.00000 5.80000 +4.00000 5.80000 +4.00000 5.80000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(0.9) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 6.60000 +5.00000 6.60000 +4.00000 6.40000 +4.00000 6.40000 +4.00000 6.40000 +4.00000 4.00000 +4.00000 4.00000 +select median(score) over (partition by name), percentile_cont(1) within group(order by score) over (partition by name) as c from t1; +median(score) over (partition by name) c +5.00000 7.00000 +5.00000 7.00000 +4.00000 7.00000 +4.00000 7.00000 +4.00000 7.00000 +4.00000 4.00000 +4.00000 4.00000 +drop table t1; diff --git a/mysql-test/t/win_percentile.test b/mysql-test/t/win_percentile.test new file mode 100644 index 00000000000..cab3478241c --- /dev/null +++ b/mysql-test/t/win_percentile.test @@ -0,0 +1,77 @@ +CREATE TABLE t1 (name CHAR(10), test double, score DECIMAL(19,4)); +INSERT INTO t1 VALUES +('Chun', 0, 3), ('Chun', 0, 7), +('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), +('Kaolin', 0.5, 4), +('Tatiana', 0.8, 4), ('Tata', 0.8, 4); + +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; + +--echo no partition clause +select name, percentile_disc(0.5) within group(order by score) over () from t1; +select name, percentile_cont(0.5) within group(order by score) over () from t1; + +--echo argument set to null +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_cont(null) within group(order by score) over (partition by name) from t1; +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_disc(null) within group(order by score) over (partition by name) from t1; + +--echo subqueries having percentile functions +select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +select name from t1 a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from t1 b limit 1) >= 0.5; + +--echo disallowed fields in order by +--error ER_WRONG_TYPE_FOR_PERCENTILE_CONT +select score, percentile_cont(0.5) within group(order by name) over (partition by score) from t1; +select score, percentile_disc(0.5) within group(order by name) over (partition by score) from t1; + +--echo order by clause has more than one element +--error ER_PARSE_ERROR +select percentile_disc(0.5) within group(order by score,test) over (partition by name) from t1; +--error ER_PARSE_ERROR +select percentile_cont(0.5) within group(order by score,test) over (partition by name) from t1; + +--echo parameter value should be in the range of [0,1] +--error ER_ARGUMENT_OUT_OF_RANGE +select percentile_disc(1.5) within group(order by score) over (partition by name) from t1; +--error ER_ARGUMENT_OUT_OF_RANGE +select percentile_cont(1.5) within group(order by score) over (partition by name) from t1; + +--error ER_ARGUMENT_NOT_CONSTANT +select name,percentile_cont(test) within group(order by score) over (partition by name) from t1; +--error ER_ARGUMENT_NOT_CONSTANT +select name, percentile_disc(test) within group(order by score) over (partition by name) from t1; + +--echo only numerical types are allowed as argument to percentile functions +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_cont(name) within group(order by score) over (partition by name) from t1; + +--echo complete query with partition column +select name,cume_dist() over (partition by name order by score), percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; + +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.1) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.2) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.3) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.4) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.6) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.7) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.8) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.9) within group(order by score) over (partition by name) as c from t1; +select name,cume_dist() over (partition by name order by score) as b, percentile_disc(1) within group(order by score) over (partition by name) as c from t1; + +select median(score) over (partition by name), percentile_cont(0) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.1) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.2) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.3) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.4) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.6) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.7) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.8) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(0.9) within group(order by score) over (partition by name) as c from t1; +select median(score) over (partition by name), percentile_cont(1) within group(order by score) over (partition by name) as c from t1; +drop table t1; diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index f941900646e..8d835eac903 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -176,7 +176,7 @@ bool Item_window_func::check_result_type_of_order_item() Item_result rtype= window_spec->order_list->first->item[0]->cmp_type(); // TODO (varun) : support date type in percentile_cont function if (rtype != REAL_RESULT && rtype != INT_RESULT && - rtype != DECIMAL_RESULT && rtype != TIME_RESULT + rtype != DECIMAL_RESULT && rtype != TIME_RESULT && window_func()->sum_func() == Item_sum::PERCENTILE_CONT_FUNC) { my_error(ER_WRONG_TYPE_FOR_PERCENTILE_CONT, MYF(0)); From 0ef6127c291c1b2ce2650c9ea4213293c8058741 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Fri, 27 Oct 2017 00:10:22 +0530 Subject: [PATCH 061/138] Date-time fields are disabled currently for the result type of percentile function --- sql/item_windowfunc.cc | 5 ++--- sql/share/errmsg-utf8.txt | 4 ++-- 2 files changed, 4 insertions(+), 5 deletions(-) diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index 8d835eac903..d38befa66bc 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -176,10 +176,9 @@ bool Item_window_func::check_result_type_of_order_item() Item_result rtype= window_spec->order_list->first->item[0]->cmp_type(); // TODO (varun) : support date type in percentile_cont function if (rtype != REAL_RESULT && rtype != INT_RESULT && - rtype != DECIMAL_RESULT && rtype != TIME_RESULT && - window_func()->sum_func() == Item_sum::PERCENTILE_CONT_FUNC) + rtype != DECIMAL_RESULT && rtype != TIME_RESULT) { - my_error(ER_WRONG_TYPE_FOR_PERCENTILE_CONT, MYF(0)); + my_error(ER_WRONG_TYPE_FOR_PERCENTILE_FUNC, MYF(0)); return TRUE; } setting_handler_for_percentile_functions(rtype); diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 415d47df36e..22da221a396 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7788,8 +7788,8 @@ ER_UNKNOWN_COMPRESSION_METHOD eng "Unknown compression method: %s" ER_NOT_SINGLE_ELEMENT_ORDER_LIST eng "Incorrect number of elements in the order list for '%s'" -ER_WRONG_TYPE_FOR_PERCENTILE_CONT - eng "Numeric datatype is required for Percentile_CONT function" +ER_WRONG_TYPE_FOR_PERCENTILE_FUNC + eng "Numeric datatype is required for %s function" ER_ARGUMENT_NOT_CONSTANT eng "Argument to the percentile functions is not a constant" ER_ARGUMENT_OUT_OF_RANGE From 40887913ff4bb135d1b11495cd60c7a6f9402b8d Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Fri, 27 Oct 2017 00:16:13 +0530 Subject: [PATCH 062/138] Update the error messages involving percentile functions --- sql/item_windowfunc.h | 8 ++++---- sql/share/errmsg-utf8.txt | 6 +++--- 2 files changed, 7 insertions(+), 7 deletions(-) diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index 8b3bd5a26e2..a3056dc222a 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -766,7 +766,7 @@ public: prev_value= arg->val_real(); if (prev_value > 1 || prev_value < 0) { - my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); + my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0), func_name()); return true; } first_call= false; @@ -776,7 +776,7 @@ public: if (prev_value != arg_val) { - my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); + my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0), func_name()); return true; } @@ -887,7 +887,7 @@ public: prev_value= arg->val_real(); if (prev_value > 1 || prev_value < 0) { - my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0)); + my_error(ER_ARGUMENT_OUT_OF_RANGE, MYF(0), func_name()); return true; } } @@ -895,7 +895,7 @@ public: double arg_val= arg->val_real(); if (prev_value != arg_val) { - my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0)); + my_error(ER_ARGUMENT_NOT_CONSTANT, MYF(0), func_name()); return true; } diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 22da221a396..edde39a6feb 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7791,8 +7791,8 @@ ER_NOT_SINGLE_ELEMENT_ORDER_LIST ER_WRONG_TYPE_FOR_PERCENTILE_FUNC eng "Numeric datatype is required for %s function" ER_ARGUMENT_NOT_CONSTANT - eng "Argument to the percentile functions is not a constant" + eng "Argument to the %s function is not a constant for a partition" ER_ARGUMENT_OUT_OF_RANGE - eng "Argument to the percentile functions does not belong to the range [0,1]" + eng "Argument to the %s function does not belong to the range [0,1]" ER_WRONG_TYPE_OF_ARGUMENT - eng "Numeric values are only allowed as arguments to percentile functions" \ No newline at end of file + eng "%s function only accepts arguments that can be converted to numerical types" \ No newline at end of file From ab5503c8c5aca9c672db5ceb2c3636b598290a21 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Fri, 27 Oct 2017 20:04:05 +0530 Subject: [PATCH 063/138] Updates the tests for the percentile functions --- mysql-test/r/win_percentile.result | 469 +++++++++++++++-------------- mysql-test/t/percentile.test | 41 --- mysql-test/t/win_percentile.test | 77 +++-- sql/item_windowfunc.cc | 8 +- sql/item_windowfunc.h | 14 +- sql/sql_window.cc | 2 +- 6 files changed, 309 insertions(+), 302 deletions(-) delete mode 100644 mysql-test/t/percentile.test diff --git a/mysql-test/r/win_percentile.result b/mysql-test/r/win_percentile.result index b365a995da0..c51e2e6bd51 100644 --- a/mysql-test/r/win_percentile.result +++ b/mysql-test/r/win_percentile.result @@ -4,58 +4,88 @@ INSERT INTO t1 VALUES ('Kaolin', 0.5, 3), ('Kaolin', 0.6, 7), ('Kaolin', 0.5, 4), ('Tatiana', 0.8, 4), ('Tata', 0.8, 4); +# +# Test invalid syntax +# +# Order by clause has more than one element +select percentile_disc(0.5) within group(order by score,test) over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 +select percentile_cont(0.5) within group(order by score,test) over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 +# Order by clause has no element +select percentile_disc(0.5) within group() over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ') over (partition by name) from t1' at line 1 +select percentile_cont(0.5) within group() over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ') over (partition by name) from t1' at line 1 +# No parameters to the percentile functions +select percentile_disc() within group() over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ') within group() over (partition by name) from t1' at line 1 +select percentile_cont() within group() over (partition by name) from t1; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ') within group() over (partition by name) from t1' at line 1 +# +# Test simple syntax +# select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; name c -Chun 5.00000 -Chun 5.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 -no partition clause +Chun 5.0000000000 +Chun 5.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; +name c +Chun 3.0000000000 +Chun 3.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +# no partition clause select name, percentile_disc(0.5) within group(order by score) over () from t1; name percentile_disc(0.5) within group(order by score) over () -Chun 4.00000 -Chun 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 +Chun 4.0000000000 +Chun 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 select name, percentile_cont(0.5) within group(order by score) over () from t1; name percentile_cont(0.5) within group(order by score) over () -Chun 4.00000 -Chun 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 -argument set to null +Chun 4.0000000000 +Chun 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 +# argument set to null select name, percentile_cont(null) within group(order by score) over (partition by name) from t1; -ERROR HY000: Numeric values are only allowed as arguments to percentile functions +ERROR HY000: percentile_cont function only accepts arguments that can be converted to numerical types select name, percentile_disc(null) within group(order by score) over (partition by name) from t1; -ERROR HY000: Numeric values are only allowed as arguments to percentile functions -subqueries having percentile functions +ERROR HY000: percentile_disc function only accepts arguments that can be converted to numerical types +#subqueries having percentile functions select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; name percentile_cont(0.5) within group ( order by score) over (partition by name ) -Chun 5.00000 -Chun 5.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 +Chun 5.0000000000 +Chun 5.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; name percentile_disc(0.5) within group ( order by score) over (partition by name ) -Chun 3.00000 -Chun 3.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 +Chun 3.0000000000 +Chun 3.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 select name from t1 a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from t1 b limit 1) >= 0.5; name Chun @@ -65,241 +95,232 @@ Kaolin Kaolin Tatiana Tata -disallowed fields in order by +#disallowed fields in order by select score, percentile_cont(0.5) within group(order by name) over (partition by score) from t1; -ERROR HY000: Numeric datatype is required for Percentile_CONT function +ERROR HY000: Numeric datatype is required for percentile_cont function select score, percentile_disc(0.5) within group(order by name) over (partition by score) from t1; -score percentile_disc(0.5) within group(order by name) over (partition by score) -3.0000 Chun -7.0000 Chun -3.0000 Chun -7.0000 Chun -4.0000 Tata -4.0000 Tata -4.0000 Tata -order by clause has more than one element -select percentile_disc(0.5) within group(order by score,test) over (partition by name) from t1; -ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 -select percentile_cont(0.5) within group(order by score,test) over (partition by name) from t1; -ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'test) over (partition by name) from t1' at line 1 -parameter value should be in the range of [0,1] +ERROR HY000: Numeric datatype is required for percentile_disc function +#parameter value should be in the range of [0,1] select percentile_disc(1.5) within group(order by score) over (partition by name) from t1; -ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +ERROR HY000: Argument to the percentile_disc function does not belong to the range [0,1] select percentile_cont(1.5) within group(order by score) over (partition by name) from t1; -ERROR HY000: Argument to the percentile functions does not belong to the range [0,1] +ERROR HY000: Argument to the percentile_cont function does not belong to the range [0,1] +#Argument should remain constant for the entire partition select name,percentile_cont(test) within group(order by score) over (partition by name) from t1; -ERROR HY000: Argument to the percentile functions is not a constant +ERROR HY000: Argument to the percentile_cont function is not a constant for a partition select name, percentile_disc(test) within group(order by score) over (partition by name) from t1; -ERROR HY000: Argument to the percentile functions is not a constant -only numerical types are allowed as argument to percentile functions +ERROR HY000: Argument to the percentile_disc function is not a constant for a partition +#only numerical types are allowed as argument to percentile functions select name, percentile_cont(name) within group(order by score) over (partition by name) from t1; -ERROR HY000: Numeric values are only allowed as arguments to percentile functions -complete query with partition column +ERROR HY000: percentile_cont function only accepts arguments that can be converted to numerical types +select name, percentile_disc(name) within group(order by score) over (partition by name) from t1; +ERROR HY000: percentile_disc function only accepts arguments that can be converted to numerical types +#complete query with partition column select name,cume_dist() over (partition by name order by score), percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; name cume_dist() over (partition by name order by score) c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 4.00000 -Kaolin 1.0000000000 4.00000 -Kaolin 0.6666666667 4.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 4.0000000000 +Kaolin 1.0000000000 4.0000000000 +Kaolin 0.6666666667 4.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; name c -Chun 5.00000 -Chun 5.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Kaolin 4.00000 -Tatiana 4.00000 -Tata 4.00000 +Chun 5.0000000000 +Chun 5.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Kaolin 4.0000000000 +Tatiana 4.0000000000 +Tata 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.1) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 3.00000 -Kaolin 1.0000000000 3.00000 -Kaolin 0.6666666667 3.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 3.0000000000 +Kaolin 1.0000000000 3.0000000000 +Kaolin 0.6666666667 3.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.2) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 3.00000 -Kaolin 1.0000000000 3.00000 -Kaolin 0.6666666667 3.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 3.0000000000 +Kaolin 1.0000000000 3.0000000000 +Kaolin 0.6666666667 3.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.3) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 3.00000 -Kaolin 1.0000000000 3.00000 -Kaolin 0.6666666667 3.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 3.0000000000 +Kaolin 1.0000000000 3.0000000000 +Kaolin 0.6666666667 3.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.4) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 4.00000 -Kaolin 1.0000000000 4.00000 -Kaolin 0.6666666667 4.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 4.0000000000 +Kaolin 1.0000000000 4.0000000000 +Kaolin 0.6666666667 4.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 3.00000 -Chun 1.0000000000 3.00000 -Kaolin 0.3333333333 4.00000 -Kaolin 1.0000000000 4.00000 -Kaolin 0.6666666667 4.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 3.0000000000 +Chun 1.0000000000 3.0000000000 +Kaolin 0.3333333333 4.0000000000 +Kaolin 1.0000000000 4.0000000000 +Kaolin 0.6666666667 4.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.6) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 7.00000 -Chun 1.0000000000 7.00000 -Kaolin 0.3333333333 4.00000 -Kaolin 1.0000000000 4.00000 -Kaolin 0.6666666667 4.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 7.0000000000 +Chun 1.0000000000 7.0000000000 +Kaolin 0.3333333333 4.0000000000 +Kaolin 1.0000000000 4.0000000000 +Kaolin 0.6666666667 4.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.7) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 7.00000 -Chun 1.0000000000 7.00000 -Kaolin 0.3333333333 7.00000 -Kaolin 1.0000000000 7.00000 -Kaolin 0.6666666667 7.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 7.0000000000 +Chun 1.0000000000 7.0000000000 +Kaolin 0.3333333333 7.0000000000 +Kaolin 1.0000000000 7.0000000000 +Kaolin 0.6666666667 7.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.8) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 7.00000 -Chun 1.0000000000 7.00000 -Kaolin 0.3333333333 7.00000 -Kaolin 1.0000000000 7.00000 -Kaolin 0.6666666667 7.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 7.0000000000 +Chun 1.0000000000 7.0000000000 +Kaolin 0.3333333333 7.0000000000 +Kaolin 1.0000000000 7.0000000000 +Kaolin 0.6666666667 7.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(0.9) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 7.00000 -Chun 1.0000000000 7.00000 -Kaolin 0.3333333333 7.00000 -Kaolin 1.0000000000 7.00000 -Kaolin 0.6666666667 7.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 7.0000000000 +Chun 1.0000000000 7.0000000000 +Kaolin 0.3333333333 7.0000000000 +Kaolin 1.0000000000 7.0000000000 +Kaolin 0.6666666667 7.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select name,cume_dist() over (partition by name order by score) as b, percentile_disc(1) within group(order by score) over (partition by name) as c from t1; name b c -Chun 0.5000000000 7.00000 -Chun 1.0000000000 7.00000 -Kaolin 0.3333333333 7.00000 -Kaolin 1.0000000000 7.00000 -Kaolin 0.6666666667 7.00000 -Tatiana 1.0000000000 4.00000 -Tata 1.0000000000 4.00000 +Chun 0.5000000000 7.0000000000 +Chun 1.0000000000 7.0000000000 +Kaolin 0.3333333333 7.0000000000 +Kaolin 1.0000000000 7.0000000000 +Kaolin 0.6666666667 7.0000000000 +Tatiana 1.0000000000 4.0000000000 +Tata 1.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 3.00000 -5.00000 3.00000 -4.00000 3.00000 -4.00000 3.00000 -4.00000 3.00000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 3.0000000000 +5.0000000000 3.0000000000 +4.0000000000 3.0000000000 +4.0000000000 3.0000000000 +4.0000000000 3.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.1) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 3.40000 -5.00000 3.40000 -4.00000 3.20000 -4.00000 3.20000 -4.00000 3.20000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 3.4000000000 +5.0000000000 3.4000000000 +4.0000000000 3.2000000000 +4.0000000000 3.2000000000 +4.0000000000 3.2000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.2) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 3.80000 -5.00000 3.80000 -4.00000 3.40000 -4.00000 3.40000 -4.00000 3.40000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 3.8000000000 +5.0000000000 3.8000000000 +4.0000000000 3.4000000000 +4.0000000000 3.4000000000 +4.0000000000 3.4000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.3) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 4.20000 -5.00000 4.20000 -4.00000 3.60000 -4.00000 3.60000 -4.00000 3.60000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 4.2000000000 +5.0000000000 4.2000000000 +4.0000000000 3.6000000000 +4.0000000000 3.6000000000 +4.0000000000 3.6000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.4) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 4.60000 -5.00000 4.60000 -4.00000 3.80000 -4.00000 3.80000 -4.00000 3.80000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 4.6000000000 +5.0000000000 4.6000000000 +4.0000000000 3.8000000000 +4.0000000000 3.8000000000 +4.0000000000 3.8000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 5.00000 -5.00000 5.00000 -4.00000 4.00000 -4.00000 4.00000 -4.00000 4.00000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 5.0000000000 +5.0000000000 5.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.6) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 5.40000 -5.00000 5.40000 -4.00000 4.60000 -4.00000 4.60000 -4.00000 4.60000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 5.4000000000 +5.0000000000 5.4000000000 +4.0000000000 4.6000000000 +4.0000000000 4.6000000000 +4.0000000000 4.6000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.7) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 5.80000 -5.00000 5.80000 -4.00000 5.20000 -4.00000 5.20000 -4.00000 5.20000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 5.8000000000 +5.0000000000 5.8000000000 +4.0000000000 5.2000000000 +4.0000000000 5.2000000000 +4.0000000000 5.2000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.8) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 6.20000 -5.00000 6.20000 -4.00000 5.80000 -4.00000 5.80000 -4.00000 5.80000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 6.2000000000 +5.0000000000 6.2000000000 +4.0000000000 5.8000000000 +4.0000000000 5.8000000000 +4.0000000000 5.8000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(0.9) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 6.60000 -5.00000 6.60000 -4.00000 6.40000 -4.00000 6.40000 -4.00000 6.40000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 6.6000000000 +5.0000000000 6.6000000000 +4.0000000000 6.4000000000 +4.0000000000 6.4000000000 +4.0000000000 6.4000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 select median(score) over (partition by name), percentile_cont(1) within group(order by score) over (partition by name) as c from t1; median(score) over (partition by name) c -5.00000 7.00000 -5.00000 7.00000 -4.00000 7.00000 -4.00000 7.00000 -4.00000 7.00000 -4.00000 4.00000 -4.00000 4.00000 +5.0000000000 7.0000000000 +5.0000000000 7.0000000000 +4.0000000000 7.0000000000 +4.0000000000 7.0000000000 +4.0000000000 7.0000000000 +4.0000000000 4.0000000000 +4.0000000000 4.0000000000 drop table t1; diff --git a/mysql-test/t/percentile.test b/mysql-test/t/percentile.test deleted file mode 100644 index 0958fc05e7d..00000000000 --- a/mysql-test/t/percentile.test +++ /dev/null @@ -1,41 +0,0 @@ -CREATE TABLE student (name CHAR(10), test double, score TINYINT); - -INSERT INTO student VALUES -('Chun', 0, null), ('Chun', 0, 4), -('Esben', 1, null), ('Esben', 1, null), -('Kaolin', 0.5, 56), ('Kaolin', 0.5, 88), -('Tatiana', 0.8, 2), ('Tatiana', 0.8, 1); - - - -select name, percentile_disc(0.6) within group(order by score) over (partition by name) from student; -select name, percentile_disc(test) within group(order by score) over (partition by name) from student; -select name, percentile_disc(0.4) within group(order by score) over (partition by name) from student; - - -#select name, percentile_cont(null) within group(order by score) over (partition by name) from student; -#select name, cume_dist() over (partition by name order by score) from student; - - -#normal parsing -#select percentile_cont(0.5) within group(order by score) over w1 from student -#window w1 AS (partition by name); - -# no partition clause -#select percentile_cont(0.5) within group(order by score) over () from student; - - -# only one sort allowed -#select percentile_cont(0.5) within group(order by score) over (partition by name); - -#parameter value should be in the range of 0 to 1 -#select percentile_cont(1.5) within group(order by score) over (partition by name); - - -# -#select rank() over (partition by name order by score ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) from student; - - - -drop table student; - diff --git a/mysql-test/t/win_percentile.test b/mysql-test/t/win_percentile.test index cab3478241c..468d8cff56b 100644 --- a/mysql-test/t/win_percentile.test +++ b/mysql-test/t/win_percentile.test @@ -5,50 +5,77 @@ INSERT INTO t1 VALUES ('Kaolin', 0.5, 4), ('Tatiana', 0.8, 4), ('Tata', 0.8, 4); -select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +--echo # +--echo # Test invalid syntax +--echo # ---echo no partition clause -select name, percentile_disc(0.5) within group(order by score) over () from t1; -select name, percentile_cont(0.5) within group(order by score) over () from t1; - ---echo argument set to null ---error ER_WRONG_TYPE_OF_ARGUMENT -select name, percentile_cont(null) within group(order by score) over (partition by name) from t1; ---error ER_WRONG_TYPE_OF_ARGUMENT -select name, percentile_disc(null) within group(order by score) over (partition by name) from t1; - ---echo subqueries having percentile functions -select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; -select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; -select name from t1 a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from t1 b limit 1) >= 0.5; - ---echo disallowed fields in order by ---error ER_WRONG_TYPE_FOR_PERCENTILE_CONT -select score, percentile_cont(0.5) within group(order by name) over (partition by score) from t1; -select score, percentile_disc(0.5) within group(order by name) over (partition by score) from t1; - ---echo order by clause has more than one element +--echo # Order by clause has more than one element --error ER_PARSE_ERROR select percentile_disc(0.5) within group(order by score,test) over (partition by name) from t1; --error ER_PARSE_ERROR select percentile_cont(0.5) within group(order by score,test) over (partition by name) from t1; ---echo parameter value should be in the range of [0,1] +--echo # Order by clause has no element +--error ER_PARSE_ERROR +select percentile_disc(0.5) within group() over (partition by name) from t1; +--error ER_PARSE_ERROR +select percentile_cont(0.5) within group() over (partition by name) from t1; + +--echo # No parameters to the percentile functions +--error ER_PARSE_ERROR +select percentile_disc() within group() over (partition by name) from t1; +--error ER_PARSE_ERROR +select percentile_cont() within group() over (partition by name) from t1; + + + +--echo # +--echo # Test simple syntax +--echo # + +select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; +select name, percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; + +--echo # no partition clause +select name, percentile_disc(0.5) within group(order by score) over () from t1; +select name, percentile_cont(0.5) within group(order by score) over () from t1; + +--echo # argument set to null +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_cont(null) within group(order by score) over (partition by name) from t1; +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_disc(null) within group(order by score) over (partition by name) from t1; + +--echo #subqueries having percentile functions +select * from ( select name , percentile_cont(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +select * from ( select name , percentile_disc(0.5) within group ( order by score) over (partition by name ) from t1 ) as t; +select name from t1 a where (select percentile_disc(0.5) within group (order by score) over (partition by name) from t1 b limit 1) >= 0.5; + +--echo #disallowed fields in order by +--error ER_WRONG_TYPE_FOR_PERCENTILE_FUNC +select score, percentile_cont(0.5) within group(order by name) over (partition by score) from t1; +--error ER_WRONG_TYPE_FOR_PERCENTILE_FUNC +select score, percentile_disc(0.5) within group(order by name) over (partition by score) from t1; + +--echo #parameter value should be in the range of [0,1] --error ER_ARGUMENT_OUT_OF_RANGE select percentile_disc(1.5) within group(order by score) over (partition by name) from t1; --error ER_ARGUMENT_OUT_OF_RANGE select percentile_cont(1.5) within group(order by score) over (partition by name) from t1; +--echo #Argument should remain constant for the entire partition --error ER_ARGUMENT_NOT_CONSTANT select name,percentile_cont(test) within group(order by score) over (partition by name) from t1; --error ER_ARGUMENT_NOT_CONSTANT select name, percentile_disc(test) within group(order by score) over (partition by name) from t1; ---echo only numerical types are allowed as argument to percentile functions +--echo #only numerical types are allowed as argument to percentile functions --error ER_WRONG_TYPE_OF_ARGUMENT select name, percentile_cont(name) within group(order by score) over (partition by name) from t1; +--error ER_WRONG_TYPE_OF_ARGUMENT +select name, percentile_disc(name) within group(order by score) over (partition by name) from t1; ---echo complete query with partition column +--echo #complete query with partition column select name,cume_dist() over (partition by name order by score), percentile_disc(0.5) within group(order by score) over (partition by name) as c from t1; select name, percentile_cont(0.5) within group(order by score) over (partition by name) as c from t1; diff --git a/sql/item_windowfunc.cc b/sql/item_windowfunc.cc index d38befa66bc..8432ab43ad8 100644 --- a/sql/item_windowfunc.cc +++ b/sql/item_windowfunc.cc @@ -174,11 +174,11 @@ bool Item_window_func::check_result_type_of_order_item() if (only_single_element_order_list()) { Item_result rtype= window_spec->order_list->first->item[0]->cmp_type(); - // TODO (varun) : support date type in percentile_cont function + // TODO (varun) : support date type in percentile_cont function if (rtype != REAL_RESULT && rtype != INT_RESULT && rtype != DECIMAL_RESULT && rtype != TIME_RESULT) { - my_error(ER_WRONG_TYPE_FOR_PERCENTILE_FUNC, MYF(0)); + my_error(ER_WRONG_TYPE_FOR_PERCENTILE_FUNC, MYF(0), window_func()->func_name()); return TRUE; } setting_handler_for_percentile_functions(rtype); @@ -249,7 +249,7 @@ bool Item_sum_percentile_cont::fix_fields(THD *thd, Item **ref) case INT_RESULT: break; default: - my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0)); + my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0), func_name()); return TRUE; } return res; @@ -268,7 +268,7 @@ bool Item_sum_percentile_disc::fix_fields(THD *thd, Item **ref) case INT_RESULT: break; default: - my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0)); + my_error(ER_WRONG_TYPE_OF_ARGUMENT, MYF(0), func_name()); return TRUE; } return res; diff --git a/sql/item_windowfunc.h b/sql/item_windowfunc.h index a3056dc222a..849c298f5aa 100644 --- a/sql/item_windowfunc.h +++ b/sql/item_windowfunc.h @@ -786,7 +786,7 @@ public: value->store(order_item); value->cache_value(); if (value->null_value) - return false; + return false; Item_sum_cume_dist::add(); double val= Item_sum_cume_dist::val_real(); @@ -821,7 +821,7 @@ public: void fix_length_and_dec() { - decimals = 5; // TODO-cvicentiu find out how many decimals the standard + decimals = 10; // TODO-cvicentiu find out how many decimals the standard // requires. } @@ -904,24 +904,24 @@ public: floor_value->store(order_item); floor_value->cache_value(); if (floor_value->null_value) - return false; + return false; } if (floor_val_calculated && !ceil_val_calculated) { ceil_value->store(order_item); ceil_value->cache_value(); if (ceil_value->null_value) - return false; + return false; } Item_sum_cume_dist::add(); double val= 1 + prev_value * (get_row_count()-1); if (!floor_val_calculated && get_row_number() == floor(val)) - floor_val_calculated= true; + floor_val_calculated= true; if (!ceil_val_calculated && get_row_number() == ceil(val)) - ceil_val_calculated= true; + ceil_val_calculated= true; return false; } @@ -951,7 +951,7 @@ public: void fix_length_and_dec() { - decimals = 5; // TODO-cvicentiu find out how many decimals the standard + decimals = 10; // TODO-cvicentiu find out how many decimals the standard // requires. } diff --git a/sql/sql_window.cc b/sql/sql_window.cc index 059dd8073f5..4bcdca3ca11 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -1765,7 +1765,7 @@ protected: } }; -class Frame_unbounded_following_set_count_no_nulls: +class Frame_unbounded_following_set_count_no_nulls: public Frame_unbounded_following_set_count { From a607e4e7aa2d2fb5d9eeee35ba06d051bbcc35f6 Mon Sep 17 00:00:00 2001 From: Varun Gupta Date: Sat, 28 Oct 2017 22:28:31 +0300 Subject: [PATCH 064/138] Added the syntax for percentile functions and median function to the sql_yacc_ora.yy file --- sql/sql_yacc_ora.yy | 36 +++++++++++++++++++++++++++++------- 1 file changed, 29 insertions(+), 7 deletions(-) diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy index e04c7ee60b3..a50a4ad8ccb 100644 --- a/sql/sql_yacc_ora.yy +++ b/sql/sql_yacc_ora.yy @@ -645,6 +645,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token MAX_STATEMENT_TIME_SYM %token MAX_USER_CONNECTIONS_SYM %token MAXVALUE_SYM /* SQL-2003-N */ +%token MEDIAN_SYM %token MEDIUMBLOB %token MEDIUMINT %token MEDIUMTEXT @@ -1151,6 +1152,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); window_func simple_window_func inverse_distribution_function + percentile_function inverse_distribution_function_def explicit_cursor_attr function_call_keyword @@ -10723,13 +10725,9 @@ simple_window_func: MYSQL_YYABORT; } ; - inverse_distribution_function: - inverse_distribution_function_def WITHIN GROUP_SYM - '(' - { Select->prepare_add_window_spec(thd); } - order_by_single_element_list ')' OVER_SYM - '(' opt_window_ref opt_window_partition_clause ')' + percentile_function OVER_SYM + '(' opt_window_partition_clause ')' { LEX *lex= Lex; if (Select->add_window_spec(thd, lex->win_ref, @@ -10746,6 +10744,29 @@ inverse_distribution_function: } ; +percentile_function: + inverse_distribution_function_def WITHIN GROUP_SYM '(' + { Select->prepare_add_window_spec(thd); } + order_by_single_element_list ')' + { + $$= $1; + } + | MEDIAN_SYM '(' expr ')' + { + Item *args= new (thd->mem_root) Item_decimal(thd, "0.5", 3, + thd->charset()); + if (($$ == NULL) || (thd->is_error())) + { + MYSQL_YYABORT; + } + if (add_order_to_list(thd, $3,FALSE)) MYSQL_YYABORT; + + $$= new (thd->mem_root) Item_sum_percentile_cont(thd, args); + if ($$ == NULL) + MYSQL_YYABORT; + } + ; + inverse_distribution_function_def: PERCENTILE_CONT_SYM '(' expr ')' { @@ -10762,7 +10783,8 @@ inverse_distribution_function_def: ; order_by_single_element_list: - ORDER_SYM BY order_list + ORDER_SYM BY order_ident order_dir + { if (add_order_to_list(thd, $3,(bool) $4)) MYSQL_YYABORT; } ; window_name: From c4c48e974013a1a3d62ae6b2fc9a705c3bdd1689 Mon Sep 17 00:00:00 2001 From: Sergei Golubchik Date: Tue, 7 Mar 2017 19:21:42 +0100 Subject: [PATCH 065/138] MDEV-11965 -Werror should not appear in released tarballs --- .../tokudb/PerconaFT/cmake_modules/TokuSetupCompiler.cmake | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/storage/tokudb/PerconaFT/cmake_modules/TokuSetupCompiler.cmake b/storage/tokudb/PerconaFT/cmake_modules/TokuSetupCompiler.cmake index 769bdffa5d9..c17e119d1cd 100644 --- a/storage/tokudb/PerconaFT/cmake_modules/TokuSetupCompiler.cmake +++ b/storage/tokudb/PerconaFT/cmake_modules/TokuSetupCompiler.cmake @@ -196,9 +196,9 @@ if (NOT CMAKE_CXX_COMPILER_ID STREQUAL Clang) set_cflags_if_supported(-Wcast-align) endif () -## always want these -set(CMAKE_C_FLAGS "-Wall -Werror ${CMAKE_C_FLAGS}") -set(CMAKE_CXX_FLAGS "-Wall -Werror ${CMAKE_CXX_FLAGS}") +## always want these in debug builds +set(CMAKE_C_FLAGS_DEBUG "-Wall -Werror ${CMAKE_C_FLAGS_DEBUG}") +set(CMAKE_CXX_FLAGS_DEBUG "-Wall -Werror ${CMAKE_CXX_FLAGS_DEBUG}") # pick language dialect set(CMAKE_C_FLAGS "-std=c99 ${CMAKE_C_FLAGS}") From 0750b5f825516fd1596f6bb457550d653aa6733f Mon Sep 17 00:00:00 2001 From: Monty Date: Thu, 2 Nov 2017 11:06:02 +0200 Subject: [PATCH 066/138] Fixed compilation failures - Also added missing copyright notices --- sql/sql_lex.h | 4 ++-- sql/sql_tvc.cc | 19 +++++++++++++++++-- sql/sql_tvc.h | 17 ++++++++++++++++- 3 files changed, 35 insertions(+), 5 deletions(-) diff --git a/sql/sql_lex.h b/sql/sql_lex.h index dfdeb9d4a83..3cec59193ff 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -756,7 +756,7 @@ public: { return reinterpret_cast(slave); } - void set_with_clause(With_clause *with_cl); + inline void set_with_clause(With_clause *with_cl); st_select_lex_unit* next_unit() { return reinterpret_cast(next); @@ -1208,7 +1208,7 @@ public: void set_non_agg_field_used(bool val) { m_non_agg_field_used= val; } void set_agg_func_used(bool val) { m_agg_func_used= val; } - void set_with_clause(With_clause *with_clause); + inline void set_with_clause(With_clause *with_clause); With_clause *get_with_clause() { return master_unit()->with_clause; diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index f06ea049e3d..95947cbea45 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -1,3 +1,19 @@ +/* Copyright (c) 2017, MariaDB + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */ + +#include "mariadb.h" #include "sql_list.h" #include "sql_tvc.h" #include "sql_class.h" @@ -5,7 +21,7 @@ #include "sql_select.h" #include "sql_explain.h" #include "sql_parse.h" - +#include "sql_cte.h" /** @brief @@ -831,4 +847,3 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd) thd->lex->current_select= save_current_select; DBUG_RETURN(false); } - diff --git a/sql/sql_tvc.h b/sql/sql_tvc.h index 5524744a03c..b4fca78262b 100644 --- a/sql/sql_tvc.h +++ b/sql/sql_tvc.h @@ -1,3 +1,18 @@ +/* Copyright (c) 2017, MariaDB + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */ + #ifndef SQL_TVC_INCLUDED #define SQL_TVC_INCLUDED #include "sql_type.h" @@ -47,4 +62,4 @@ public: void print(THD *thd_arg, String *str, enum_query_type query_type); }; -#endif /* SQL_TVC_INCLUDED */ \ No newline at end of file +#endif /* SQL_TVC_INCLUDED */ From 1103abdae1195941ffb7368d51e83404b47bbb03 Mon Sep 17 00:00:00 2001 From: Daniel Black Date: Thu, 13 Jul 2017 16:37:33 +1000 Subject: [PATCH 067/138] keycache: restructure functions that are controlled by arguements finish_resize_simple_key_cache removed argument acquire for acquiring locks. resize_simple_key_cache enforces assertion that the cache is inited. read_block was really two functions, primary and secondary so separated as such. Make the callers of read_block explictly use the required function. Signed-off-by: Daniel Black --- mysys/mf_keycache.c | 266 ++++++++++++++++++++++---------------------- 1 file changed, 136 insertions(+), 130 deletions(-) diff --git a/mysys/mf_keycache.c b/mysys/mf_keycache.c index 19e1e165b12..2f0f2bf05c0 100644 --- a/mysys/mf_keycache.c +++ b/mysys/mf_keycache.c @@ -749,7 +749,6 @@ finish: SYNOPSIS finish_resize_simple_key_cache() keycache pointer to the control block of a simple key cache - acquire_lock <=> acquire the key cache lock at start DESCRIPTION This function performs finalizing actions for the operation of @@ -757,8 +756,6 @@ finish: keycache as a pointer to the control block structure of the type SIMPLE_KEY_CACHE_CB for this key cache. The function sets the flag in_resize in this structure to FALSE. - The parameter acquire_lock says whether the key cache lock must be - acquired at the start of the function. RETURN VALUE none @@ -770,14 +767,10 @@ finish: */ static -void finish_resize_simple_key_cache(SIMPLE_KEY_CACHE_CB *keycache, - my_bool acquire_lock) +void finish_resize_simple_key_cache(SIMPLE_KEY_CACHE_CB *keycache) { DBUG_ENTER("finish_resize_simple_key_cache"); - if (acquire_lock) - keycache_pthread_mutex_lock(&keycache->cache_lock); - mysql_mutex_assert_owner(&keycache->cache_lock); /* @@ -849,8 +842,7 @@ int resize_simple_key_cache(SIMPLE_KEY_CACHE_CB *keycache, int blocks= 0; DBUG_ENTER("resize_simple_key_cache"); - if (!keycache->key_cache_inited) - DBUG_RETURN(blocks); + DBUG_ASSERT(keycache->key_cache_inited); /* Note that the cache_lock mutex and the resize_queue are left untouched. @@ -866,7 +858,7 @@ int resize_simple_key_cache(SIMPLE_KEY_CACHE_CB *keycache, changed_blocks_hash_size); finish: - finish_resize_simple_key_cache(keycache, 0); + finish_resize_simple_key_cache(keycache); DBUG_RETURN(blocks); } @@ -2611,12 +2603,11 @@ restart: SYNOPSIS - read_block() + read_block_{primary|secondary}() keycache pointer to a key cache data structure block block to which buffer the data is to be read read_length size of data to be read min_length at least so much data must be read - primary <-> the current thread will read the data RETURN VALUE None @@ -2630,90 +2621,100 @@ restart: portion is less than read_length, but not less than min_length. */ -static void read_block(SIMPLE_KEY_CACHE_CB *keycache, - BLOCK_LINK *block, uint read_length, - uint min_length, my_bool primary) +static void read_block_primary(SIMPLE_KEY_CACHE_CB *keycache, + BLOCK_LINK *block, uint read_length, + uint min_length) { size_t got_length; /* On entry cache_lock is locked */ - KEYCACHE_THREAD_TRACE("read_block"); - if (primary) - { - /* - This code is executed only by threads that submitted primary - requests. Until block->status contains BLOCK_READ, all other - request for the block become secondary requests. For a primary - request the block must be properly initialized. - */ - DBUG_ASSERT(((block->status & ~BLOCK_FOR_UPDATE) == BLOCK_IN_USE) || - fail_block(block)); - DBUG_ASSERT((block->length == 0) || fail_block(block)); - DBUG_ASSERT((block->offset == keycache->key_cache_block_size) || - fail_block(block)); - DBUG_ASSERT((block->requests > 0) || fail_block(block)); + KEYCACHE_THREAD_TRACE("read_block_primary"); - KEYCACHE_DBUG_PRINT("read_block", - ("page to be read by primary request")); + /* + This code is executed only by threads that submitted primary + requests. Until block->status contains BLOCK_READ, all other + request for the block become secondary requests. For a primary + request the block must be properly initialized. + */ + DBUG_ASSERT(((block->status & ~BLOCK_FOR_UPDATE) == BLOCK_IN_USE) || + fail_block(block)); + DBUG_ASSERT((block->length == 0) || fail_block(block)); + DBUG_ASSERT((block->offset == keycache->key_cache_block_size) || + fail_block(block)); + DBUG_ASSERT((block->requests > 0) || fail_block(block)); - keycache->global_cache_read++; - /* Page is not in buffer yet, is to be read from disk */ - keycache_pthread_mutex_unlock(&keycache->cache_lock); - /* - Here other threads may step in and register as secondary readers. - They will register in block->wqueue[COND_FOR_REQUESTED]. - */ - got_length= my_pread(block->hash_link->file, block->buffer, - read_length, block->hash_link->diskpos, MYF(0)); - keycache_pthread_mutex_lock(&keycache->cache_lock); - /* - The block can now have been marked for free (in case of - FLUSH_RELEASE). Otherwise the state must be unchanged. - */ - DBUG_ASSERT(((block->status & ~(BLOCK_REASSIGNED | - BLOCK_FOR_UPDATE)) == BLOCK_IN_USE) || - fail_block(block)); - DBUG_ASSERT((block->length == 0) || fail_block(block)); - DBUG_ASSERT((block->offset == keycache->key_cache_block_size) || - fail_block(block)); - DBUG_ASSERT((block->requests > 0) || fail_block(block)); + KEYCACHE_DBUG_PRINT("read_block_primary", + ("page to be read by primary request")); - if (got_length < min_length) - block->status|= BLOCK_ERROR; - else - { - block->status|= BLOCK_READ; - block->length= got_length; - /* - Do not set block->offset here. If this block is marked - BLOCK_CHANGED later, we want to flush only the modified part. So - only a writer may set block->offset down from - keycache->key_cache_block_size. - */ - } - KEYCACHE_DBUG_PRINT("read_block", - ("primary request: new page in cache")); - /* Signal that all pending requests for this page now can be processed */ - release_whole_queue(&block->wqueue[COND_FOR_REQUESTED]); - } + keycache->global_cache_read++; + /* Page is not in buffer yet, is to be read from disk */ + keycache_pthread_mutex_unlock(&keycache->cache_lock); + /* + Here other threads may step in and register as secondary readers. + They will register in block->wqueue[COND_FOR_REQUESTED]. + */ + got_length= my_pread(block->hash_link->file, block->buffer, + read_length, block->hash_link->diskpos, MYF(0)); + keycache_pthread_mutex_lock(&keycache->cache_lock); + /* + The block can now have been marked for free (in case of + FLUSH_RELEASE). Otherwise the state must be unchanged. + */ + DBUG_ASSERT(((block->status & ~(BLOCK_REASSIGNED | + BLOCK_FOR_UPDATE)) == BLOCK_IN_USE) || + fail_block(block)); + DBUG_ASSERT((block->length == 0) || fail_block(block)); + DBUG_ASSERT((block->offset == keycache->key_cache_block_size) || + fail_block(block)); + DBUG_ASSERT((block->requests > 0) || fail_block(block)); + + if (got_length < min_length) + block->status|= BLOCK_ERROR; else { + block->status|= BLOCK_READ; + block->length= got_length; /* - This code is executed only by threads that submitted secondary - requests. At this point it could happen that the cache block is - not yet assigned to the hash_link for the requested file block. - But at awake from the wait this should be the case. Unfortunately - we cannot assert this here because we do not know the hash_link - for the requested file block nor the file and position. So we have - to assert this in the caller. + Do not set block->offset here. If this block is marked + BLOCK_CHANGED later, we want to flush only the modified part. So + only a writer may set block->offset down from + keycache->key_cache_block_size. */ - KEYCACHE_DBUG_PRINT("read_block", - ("secondary request waiting for new page to be read")); - wait_on_queue(&block->wqueue[COND_FOR_REQUESTED], &keycache->cache_lock); - KEYCACHE_DBUG_PRINT("read_block", - ("secondary request: new page in cache")); } + KEYCACHE_DBUG_PRINT("read_block_primary", + ("primary request: new page in cache")); + /* Signal that all pending requests for this page now can be processed */ + release_whole_queue(&block->wqueue[COND_FOR_REQUESTED]); + + DBUG_ASSERT(keycache->can_be_used); +} + + +static void read_block_secondary(SIMPLE_KEY_CACHE_CB *keycache, + BLOCK_LINK *block) +{ + KEYCACHE_THREAD_TRACE("read_block_secondary"); + + /* + This code is executed only by threads that submitted secondary + requests. At this point it could happen that the cache block is + not yet assigned to the hash_link for the requested file block. + But at awake from the wait this should be the case. Unfortunately + we cannot assert this here because we do not know the hash_link + for the requested file block nor the file and position. So we have + to assert this in the caller. + */ + KEYCACHE_DBUG_PRINT("read_block_secondary", + ("secondary request waiting for new page to be read")); + + wait_on_queue(&block->wqueue[COND_FOR_REQUESTED], &keycache->cache_lock); + + KEYCACHE_DBUG_PRINT("read_block_secondary", + ("secondary request: new page in cache")); + + DBUG_ASSERT(keycache->can_be_used); + DBUG_ASSERT(block->status & (BLOCK_READ | BLOCK_IN_USE)); } @@ -2858,22 +2859,24 @@ uchar *simple_key_cache_read(SIMPLE_KEY_CACHE_CB *keycache, } if (!(block->status & BLOCK_ERROR)) { - if (page_st != PAGE_READ) + if (page_st == PAGE_TO_BE_READ) + { + MYSQL_KEYCACHE_READ_MISS(); + read_block_primary(keycache, block, + keycache->key_cache_block_size, read_length+offset); + } + else if (page_st == PAGE_WAIT_TO_BE_READ) { MYSQL_KEYCACHE_READ_MISS(); /* The requested page is to be read into the block buffer */ - read_block(keycache, block, - keycache->key_cache_block_size, read_length+offset, - (my_bool)(page_st == PAGE_TO_BE_READ)); + read_block_secondary(keycache, block); + /* A secondary request must now have the block assigned to the - requested file block. It does not hurt to check it for - primary requests too. + requested file block. */ - DBUG_ASSERT(keycache->can_be_used); DBUG_ASSERT(block->hash_link->file == file); DBUG_ASSERT(block->hash_link->diskpos == filepos); - DBUG_ASSERT(block->status & (BLOCK_READ | BLOCK_IN_USE)); } else if (block->length < read_length + offset) { @@ -3077,23 +3080,30 @@ int simple_key_cache_insert(SIMPLE_KEY_CACHE_CB *keycache, } if (!(block->status & BLOCK_ERROR)) { - if ((page_st == PAGE_WAIT_TO_BE_READ) || - ((page_st == PAGE_TO_BE_READ) && - (offset || (read_length < keycache->key_cache_block_size)))) + if (page_st == PAGE_WAIT_TO_BE_READ) { /* - Either - this is a secondary request for a block to be read into the cache. The block is in eviction. It is not yet assigned to the requested file block (It does not point to the right hash_link). So we cannot call remove_reader() on the block. And we cannot access the hash_link directly here. We need to - wait until the assignment is complete. read_block() executes - the correct wait when called with primary == FALSE. - - Or + wait until the assignment is complete. read_block_secondary() + executes the correct wait. + */ + read_block_secondary(keycache, block); + /* + A secondary request must now have the block assigned to the + requested file block. + */ + DBUG_ASSERT(block->hash_link->file == file); + DBUG_ASSERT(block->hash_link->diskpos == filepos); + } + else if (page_st == PAGE_TO_BE_READ && + (offset || (read_length < keycache->key_cache_block_size))) + { + /* this is a primary request for a block to be read into the cache and the supplied data does not fill the whole block. @@ -3108,17 +3118,8 @@ int simple_key_cache_insert(SIMPLE_KEY_CACHE_CB *keycache, Though reading again what the caller did read already is an expensive operation, we need to do this for correctness. */ - read_block(keycache, block, keycache->key_cache_block_size, - read_length + offset, (page_st == PAGE_TO_BE_READ)); - /* - A secondary request must now have the block assigned to the - requested file block. It does not hurt to check it for - primary requests too. - */ - DBUG_ASSERT(keycache->can_be_used); - DBUG_ASSERT(block->hash_link->file == file); - DBUG_ASSERT(block->hash_link->diskpos == filepos); - DBUG_ASSERT(block->status & (BLOCK_READ | BLOCK_IN_USE)); + read_block_primary(keycache, block, keycache->key_cache_block_size, + read_length + offset); } else if (page_st == PAGE_TO_BE_READ) { @@ -3413,25 +3414,29 @@ int simple_key_cache_write(SIMPLE_KEY_CACHE_CB *keycache, reading the file block. If the read completes after us, it overwrites our new contents with the old contents. So we have to wait for the other thread to complete the read of this block. - read_block() takes care for the wait. + read_block_primary|secondary() takes care for the wait. */ - if (!(block->status & BLOCK_ERROR) && - ((page_st == PAGE_TO_BE_READ && - (offset || read_length < keycache->key_cache_block_size)) || - (page_st == PAGE_WAIT_TO_BE_READ))) + if (!(block->status & BLOCK_ERROR)) { - read_block(keycache, block, - offset + read_length >= keycache->key_cache_block_size? - offset : keycache->key_cache_block_size, - offset, (page_st == PAGE_TO_BE_READ)); - DBUG_ASSERT(keycache->can_be_used); - DBUG_ASSERT(block->status & (BLOCK_READ | BLOCK_IN_USE)); - /* - Prevent block from flushing and from being selected for to be - freed. This must be set when we release the cache_lock. - Here we set it in case we could not set it above. - */ - block->status|= BLOCK_FOR_UPDATE; + if (page_st == PAGE_TO_BE_READ && + (offset || read_length < keycache->key_cache_block_size)) + { + read_block_primary(keycache, block, + offset + read_length >= keycache->key_cache_block_size? + offset : keycache->key_cache_block_size, + offset); + /* + Prevent block from flushing and from being selected for to be + freed. This must be set when we release the cache_lock. + Here we set it in case we could not set it above. + */ + block->status|= BLOCK_FOR_UPDATE; + } + else if (page_st == PAGE_WAIT_TO_BE_READ) + { + read_block_secondary(keycache, block); + block->status|= BLOCK_FOR_UPDATE; + } } /* The block should always be assigned to the requested file block @@ -5279,7 +5284,8 @@ int resize_partitioned_key_cache(PARTITIONED_KEY_CACHE_CB *keycache, { for (i= 0; i < partitions; i++) { - finish_resize_simple_key_cache(keycache->partition_array[i], 1); + keycache_pthread_mutex_lock(&keycache->partition_array[i]->cache_lock); + finish_resize_simple_key_cache(keycache->partition_array[i]); } } DBUG_RETURN(blocks); From a9faad5f7821779dff6421cbf46bef44afed95b2 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Wed, 1 Nov 2017 19:27:27 +0200 Subject: [PATCH 068/138] Remove an unused variable --- storage/innobase/handler/i_s.cc | 1 - 1 file changed, 1 deletion(-) diff --git a/storage/innobase/handler/i_s.cc b/storage/innobase/handler/i_s.cc index d1728db68e9..b597b9224fa 100644 --- a/storage/innobase/handler/i_s.cc +++ b/storage/innobase/handler/i_s.cc @@ -8003,7 +8003,6 @@ i_s_dict_fill_sys_tablespaces( { Field** fields; ulint atomic_blobs = FSP_FLAGS_HAS_ATOMIC_BLOBS(flags); - const char* file_format; const char* row_format; DBUG_ENTER("i_s_dict_fill_sys_tablespaces"); From 72817cafe2d1720834b59123dfe1055dcda0a660 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Thu, 2 Nov 2017 11:31:28 +0200 Subject: [PATCH 069/138] Remove a type cast --- sql/sql_tvc.cc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 95947cbea45..19ec6c6c46a 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -271,8 +271,8 @@ int table_value_constr::save_explain_data_intern(THD *thd, { const char *message= "No tables used"; DBUG_ENTER("table_value_constr::save_explain_data_intern"); - DBUG_PRINT("info", ("Select 0x%lx, type %s, message %s", - (ulong)select_lex, select_lex->type, + DBUG_PRINT("info", ("Select %p, type %s, message %s", + select_lex, select_lex->type, message)); DBUG_ASSERT(have_query_plan == QEP_AVAILABLE); From 06ec864a0975ad9348ced3ee42a2d9d4365aca43 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Thu, 2 Nov 2017 12:06:46 +0200 Subject: [PATCH 070/138] Try to fix sys_vars.sysvars_debug,32bit --- .../sys_vars/r/sysvars_debug,32bit.rdiff | 21 ------------------- 1 file changed, 21 deletions(-) diff --git a/mysql-test/suite/sys_vars/r/sysvars_debug,32bit.rdiff b/mysql-test/suite/sys_vars/r/sysvars_debug,32bit.rdiff index 6216efe7ec9..8adb294db00 100644 --- a/mysql-test/suite/sys_vars/r/sysvars_debug,32bit.rdiff +++ b/mysql-test/suite/sys_vars/r/sysvars_debug,32bit.rdiff @@ -9,24 +9,3 @@ VARIABLE_COMMENT Extra sleep (in microseconds) to add to binlog fsync(), for debugging NUMERIC_MIN_VALUE 0 NUMERIC_MAX_VALUE 4294967295 -@@ -43,20 +43,6 @@ - ENUM_VALUE_LIST NULL - READ_ONLY NO - COMMAND_LINE_ARGUMENT OPTIONAL --VARIABLE_NAME DEBUG_MUTEX_DEADLOCK_DETECTOR --SESSION_VALUE NULL --GLOBAL_VALUE ON --GLOBAL_VALUE_ORIGIN COMPILE-TIME --DEFAULT_VALUE ON --VARIABLE_SCOPE GLOBAL --VARIABLE_TYPE BOOLEAN --VARIABLE_COMMENT Enable checking of wrong mutex usage --NUMERIC_MIN_VALUE NULL --NUMERIC_MAX_VALUE NULL --NUMERIC_BLOCK_SIZE NULL --ENUM_VALUE_LIST OFF,ON --READ_ONLY YES --COMMAND_LINE_ARGUMENT OPTIONAL - VARIABLE_NAME DEBUG_NO_THREAD_ALARM - SESSION_VALUE NULL - GLOBAL_VALUE OFF From 6402ca7870895b256ef1f25a1f0530ed97392686 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Wed, 1 Nov 2017 22:26:25 +0200 Subject: [PATCH 071/138] MDEV-14016 Allow instant ADD COLUMN, ADD INDEX, LOCK=NONE Ideally, we would move some code from ha_innobase::prepare_inplace_alter_table() to ha_innobase::check_if_supported_inplace_alter(), but the API does not really allow us to return errors; it can only inform which forms of ALGORITHM and LOCK are allowed. So, we have to duplicate some logic between the "check" and "prepare" phases. We do the duplication by calling common functions. instant_alter_column_possible(): Check if instant column operation is possible. Invoked from both ha_innobase::check_if_supported_inplace_alter() and prepare_inplace_alter_table_dict(). ha_innobase::check_if_supported_inplace_alter(): Before refusing certain operations if FULLTEXT INDEX exist, check if instant ALTER TABLE is possible and return early if it is the case. prepare_inplace_alter_table_dict(): Before checking the limitations on FULLTEXT INDEX, check if instant ALTER TABLE is possible, and suppress the checks if it is the case. If instant ADD COLUMN is used when the table already contains FULLTEXT INDEX, do account for a hidden FTS_DOC_ID_INDEX in a debug assertion. --- mysql-test/suite/innodb/r/innodb-alter.result | 21 ++ mysql-test/suite/innodb/t/innodb-alter.test | 27 ++ .../innodb_gis/r/alter_spatial_index.result | 53 ++- .../innodb_gis/t/alter_spatial_index.test | 25 +- storage/innobase/handler/handler0alter.cc | 357 ++++++++++-------- 5 files changed, 303 insertions(+), 180 deletions(-) diff --git a/mysql-test/suite/innodb/r/innodb-alter.result b/mysql-test/suite/innodb/r/innodb-alter.result index 8bf66bb8914..de69845dddb 100644 --- a/mysql-test/suite/innodb/r/innodb-alter.result +++ b/mysql-test/suite/innodb/r/innodb-alter.result @@ -440,6 +440,27 @@ tt CREATE TABLE `tt` ( PRIMARY KEY (`pk`), FULLTEXT KEY `ct` (`ct`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1 +ALTER TABLE tt ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +ERROR 0A000: LOCK=NONE is not supported. Reason: InnoDB presently supports one FULLTEXT index creation at a time. Try LOCK=SHARED +ALTER TABLE tt ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; +ERROR 0A000: LOCK=NONE is not supported. Reason: InnoDB presently supports one FULLTEXT index creation at a time. Try LOCK=SHARED +CREATE TABLE tu ( +pk INT PRIMARY KEY, FTS_DOC_ID BIGINT UNSIGNED NOT NULL, t TEXT, +FULLTEXT INDEX(t) +) ENGINE=InnoDB; +ALTER TABLE tu ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +ERROR 0A000: LOCK=NONE is not supported. Reason: InnoDB presently supports one FULLTEXT index creation at a time. Try LOCK=SHARED +ALTER TABLE tu ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; +DROP TABLE tu; +CREATE TABLE tv ( +pk INT PRIMARY KEY, FTS_DOC_ID BIGINT UNSIGNED NOT NULL, t TEXT, +UNIQUE INDEX FTS_DOC_ID_INDEX(FTS_DOC_ID), +FULLTEXT INDEX(t) +) ENGINE=InnoDB; +ALTER TABLE tv ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +ERROR 0A000: LOCK=NONE is not supported. Reason: InnoDB presently supports one FULLTEXT index creation at a time. Try LOCK=SHARED +ALTER TABLE tv ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; +DROP TABLE tv; ALTER TABLE t1o CHANGE c1 dB_row_Id INT, ALGORITHM=COPY; ERROR 42000: Incorrect column name 'dB_row_Id' ALTER TABLE t1o CHANGE c1 dB_row_Id INT, ALGORITHM=INPLACE; diff --git a/mysql-test/suite/innodb/t/innodb-alter.test b/mysql-test/suite/innodb/t/innodb-alter.test index 9d84e95b88d..7a7b4f3a845 100644 --- a/mysql-test/suite/innodb/t/innodb-alter.test +++ b/mysql-test/suite/innodb/t/innodb-alter.test @@ -193,6 +193,33 @@ ALGORITHM=INPLACE, LOCK=SHARED; -- source suite/innodb/include/innodb_dict.inc SHOW CREATE TABLE tt; +# Non-instant ADD COLUMN would require the table to be rebuilt. +--error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON +ALTER TABLE tt ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +# This is still non-instant ADD COLUMN, because FTS_DOC_ID is hidden. +--error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON +ALTER TABLE tt ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; + +CREATE TABLE tu ( + pk INT PRIMARY KEY, FTS_DOC_ID BIGINT UNSIGNED NOT NULL, t TEXT, + FULLTEXT INDEX(t) +) ENGINE=InnoDB; +--error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON +ALTER TABLE tu ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +# Instant ADD COLUMN (adding after the visible FTS_DOC_ID) +ALTER TABLE tu ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; +DROP TABLE tu; + +CREATE TABLE tv ( + pk INT PRIMARY KEY, FTS_DOC_ID BIGINT UNSIGNED NOT NULL, t TEXT, + UNIQUE INDEX FTS_DOC_ID_INDEX(FTS_DOC_ID), + FULLTEXT INDEX(t) +) ENGINE=InnoDB; +--error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON +ALTER TABLE tv ADD COLUMN c CHAR(1) NOT NULL FIRST, LOCK=NONE; +# Instant ADD COLUMN (adding after the visible FTS_DOC_ID) +ALTER TABLE tv ADD COLUMN c CHAR(1) NOT NULL, LOCK=NONE; +DROP TABLE tv; # DB_ROW_ID, DB_TRX_ID, DB_ROLL_PTR are reserved InnoDB system column names. --error ER_WRONG_COLUMN_NAME diff --git a/mysql-test/suite/innodb_gis/r/alter_spatial_index.result b/mysql-test/suite/innodb_gis/r/alter_spatial_index.result index b4859c799d1..7caa5f6829c 100644 --- a/mysql-test/suite/innodb_gis/r/alter_spatial_index.result +++ b/mysql-test/suite/innodb_gis/r/alter_spatial_index.result @@ -483,16 +483,55 @@ info: Records: 0 Duplicates: 0 Warnings: 0 ALTER TABLE tab MODIFY COLUMN c2 GEOMETRY NOT NULL; affected rows: 0 info: Records: 0 Duplicates: 0 Warnings: 0 -ALTER TABLE tab add COLUMN c8 POINT NOT NULL AFTER c5, ALGORITHM = INPLACE, LOCK=NONE; +ALTER TABLE tab MODIFY COLUMN c3 POLYGON NOT NULL; +affected rows: 10 +info: Records: 10 Duplicates: 0 Warnings: 0 +ALTER TABLE tab add COLUMN c7 POINT NOT NULL; +affected rows: 0 +info: Records: 0 Duplicates: 0 Warnings: 0 +ALTER TABLE tab add COLUMN c8 POINT NOT NULL, ALGORITHM = INPLACE, LOCK=NONE; +SELECT HEX(c8) FROM tab; +HEX(c8) + + + + + + + + + + +BEGIN; +INSERT INTO tab SELECT 0,c2,c3,c4,c5, +ST_GeomFromText('POINT(67 89)'),ST_GeomFromText('POINT(67 89)') +FROM tab LIMIT 1; +SELECT HEX(c8) FROM tab; +HEX(c8) +0000000001010000000000000000C050400000000000405640 + + + + + + + + + + +ROLLBACK; +ALTER TABLE tab add COLUMN c9 POINT NOT NULL AFTER c5, ALGORITHM = INPLACE, LOCK=NONE; ERROR 0A000: LOCK=NONE is not supported. Reason: Do not support online operation on table with GIS index. Try LOCK=SHARED SHOW CREATE TABLE tab; Table Create Table tab CREATE TABLE `tab` ( `c1` int(11) NOT NULL, `c2` geometry NOT NULL, - `c3` linestring NOT NULL, + `c3` polygon NOT NULL, `c4` polygon NOT NULL, `c5` geometry NOT NULL, + `c7` point NOT NULL, + `c8` point NOT NULL, PRIMARY KEY (`c1`), SPATIAL KEY `idx2` (`c2`), SPATIAL KEY `idx3` (`c3`), @@ -525,9 +564,11 @@ Table Create Table tab CREATE TABLE `tab` ( `c1` int(11) NOT NULL, `c2` geometry NOT NULL, - `c3` linestring NOT NULL, + `c3` polygon NOT NULL, `c4` geometry NOT NULL, `c5` geometry NOT NULL, + `c7` point NOT NULL, + `c8` point NOT NULL, PRIMARY KEY (`c1`), SPATIAL KEY `idx2` (`c2`), SPATIAL KEY `idx3` (`c3`), @@ -571,8 +612,8 @@ ALTER TABLE tab MODIFY COLUMN c2 POINT NOT NULL; affected rows: 8 info: Records: 8 Duplicates: 0 Warnings: 0 ALTER TABLE tab MODIFY COLUMN c3 LINESTRING NOT NULL; -affected rows: 0 -info: Records: 0 Duplicates: 0 Warnings: 0 +affected rows: 8 +info: Records: 8 Duplicates: 0 Warnings: 0 ALTER TABLE tab MODIFY COLUMN c4 POLYGON NOT NULL; affected rows: 8 info: Records: 8 Duplicates: 0 Warnings: 0 @@ -584,6 +625,8 @@ tab CREATE TABLE `tab` ( `c3` linestring NOT NULL, `c4` polygon NOT NULL, `c5` geometry NOT NULL, + `c7` point NOT NULL, + `c8` point NOT NULL, PRIMARY KEY (`c1`), SPATIAL KEY `idx2` (`c2`), SPATIAL KEY `idx3` (`c3`), diff --git a/mysql-test/suite/innodb_gis/t/alter_spatial_index.test b/mysql-test/suite/innodb_gis/t/alter_spatial_index.test index d0a5dc584c5..653e250017a 100644 --- a/mysql-test/suite/innodb_gis/t/alter_spatial_index.test +++ b/mysql-test/suite/innodb_gis/t/alter_spatial_index.test @@ -476,25 +476,24 @@ ALTER TABLE tab ADD INDEX idx6(c4(10)) USING BTREE; ALTER TABLE tab MODIFY COLUMN c2 GEOMETRY NOT NULL; -# --error ER_CANT_CREATE_GEOMETRY_OBJECT -# ALTER TABLE tab MODIFY COLUMN c3 POLYGON NOT NULL; +ALTER TABLE tab MODIFY COLUMN c3 POLYGON NOT NULL; -# --error ER_INVALID_USE_OF_NULL -# ALTER TABLE tab add COLUMN c7 POINT NOT NULL; +ALTER TABLE tab add COLUMN c7 POINT NOT NULL; +--disable_info # instant add, supported -#ALTER TABLE tab add COLUMN c8 POINT NOT NULL, ALGORITHM = INPLACE, LOCK=NONE; -#SELECT HEX(c8) FROM tab; -#BEGIN; -#INSERT INTO tab SELECT 0,c2,c3,c4,c5,ST_GeomFromText('POINT(67 89)') -#FROM tab LIMIT 1; -#SELECT HEX(c8) FROM tab; -#ROLLBACK; +ALTER TABLE tab add COLUMN c8 POINT NOT NULL, ALGORITHM = INPLACE, LOCK=NONE; +SELECT HEX(c8) FROM tab; +BEGIN; +INSERT INTO tab SELECT 0,c2,c3,c4,c5, +ST_GeomFromText('POINT(67 89)'),ST_GeomFromText('POINT(67 89)') +FROM tab LIMIT 1; +SELECT HEX(c8) FROM tab; +ROLLBACK; # not instant, not supported --error ER_ALTER_OPERATION_NOT_SUPPORTED_REASON -ALTER TABLE tab add COLUMN c8 POINT NOT NULL AFTER c5, ALGORITHM = INPLACE, LOCK=NONE; ---disable_info +ALTER TABLE tab add COLUMN c9 POINT NOT NULL AFTER c5, ALGORITHM = INPLACE, LOCK=NONE; SHOW CREATE TABLE tab; diff --git a/storage/innobase/handler/handler0alter.cc b/storage/innobase/handler/handler0alter.cc index b5676382e26..7b9980c22bb 100644 --- a/storage/innobase/handler/handler0alter.cc +++ b/storage/innobase/handler/handler0alter.cc @@ -602,6 +602,49 @@ check_v_col_in_order( return(true); } +/** Determine if an instant operation is possible for altering columns. +@param[in] ha_alter_info the ALTER TABLE operation +@param[in] table table definition before ALTER TABLE */ +static +bool +instant_alter_column_possible( + const Alter_inplace_info* ha_alter_info, + const TABLE* table) +{ + if (~ha_alter_info->handler_flags + & Alter_inplace_info::ADD_STORED_BASE_COLUMN) { + return false; + } + + /* At the moment, we disallow ADD [UNIQUE] INDEX together with + instant ADD COLUMN. + + The main reason is that the work of instant ADD must be done + in commit_inplace_alter_table(). For the rollback_instant() + to work, we must add the columns to dict_table_t beforehand, + and roll back those changes in case the transaction is rolled + back. + + If we added the columns to the dictionary cache already in the + prepare_inplace_alter_table(), we would have to deal with + column number mismatch in ha_innobase::open(), write_row() and + other functions. */ + + /* FIXME: allow instant ADD COLUMN together with + INNOBASE_ONLINE_CREATE (ADD [UNIQUE] INDEX) on pre-existing + columns. */ + if (ha_alter_info->handler_flags + & ((INNOBASE_ALTER_REBUILD | INNOBASE_ONLINE_CREATE) + & ~Alter_inplace_info::ADD_STORED_BASE_COLUMN + & ~Alter_inplace_info::CHANGE_CREATE_OPTION)) { + return false; + } + + return !(ha_alter_info->handler_flags + & Alter_inplace_info::CHANGE_CREATE_OPTION) + || !create_option_need_rebuild(ha_alter_info, table); +} + /** Check if InnoDB supports a particular alter table in-place @param altered_table TABLE object for new version of table. @param ha_alter_info Structure describing changes to be done @@ -654,11 +697,6 @@ ha_innobase::check_if_supported_inplace_alter( update_thd(); - // FIXME: Construct ha_innobase_inplace_ctx here and determine - // if instant ALTER TABLE is possible. If yes, we will be able to - // allow ADD COLUMN even if SPATIAL INDEX, FULLTEXT INDEX or - // virtual columns exist, also together with adding virtual columns. - if (ha_alter_info->handler_flags & ~(INNOBASE_INPLACE_IGNORE | INNOBASE_ALTER_NOREBUILD @@ -973,6 +1011,122 @@ ha_innobase::check_if_supported_inplace_alter( m_prebuilt->trx->will_lock++; + /* When changing a NULL column to NOT NULL and specifying a + DEFAULT value, ensure that the DEFAULT expression is a constant. + Also, in ADD COLUMN, for now we only support a + constant DEFAULT expression. */ + cf_it.rewind(); + Field **af = altered_table->field; + bool add_column_not_last = false; + uint n_stored_cols = 0, n_add_cols = 0; + + while (Create_field* cf = cf_it++) { + DBUG_ASSERT(cf->field + || (ha_alter_info->handler_flags + & Alter_inplace_info::ADD_COLUMN)); + + if (const Field* f = cf->field) { + /* This could be changing an existing column + from NULL to NOT NULL. */ + switch ((*af)->type()) { + case MYSQL_TYPE_TIMESTAMP: + case MYSQL_TYPE_TIMESTAMP2: + /* Inserting NULL into a TIMESTAMP column + would cause the DEFAULT value to be + replaced. Ensure that the DEFAULT + expression is not changing during + ALTER TABLE. */ + if (!f->real_maybe_null() + || (*af)->real_maybe_null()) { + /* The column was NOT NULL, or it + will allow NULL after ALTER TABLE. */ + goto next_column; + } + + if (!(*af)->default_value + && (*af)->is_real_null()) { + /* No DEFAULT value is + specified. We can report + errors for any NULL values for + the TIMESTAMP. + + FIXME: Allow any DEFAULT + expression whose value does + not change during ALTER TABLE. + This would require a fix in + row_merge_read_clustered_index() + to try to replace the DEFAULT + value before reporting + DB_INVALID_NULL. */ + goto next_column; + } + break; + default: + /* For any other data type, NULL + values are not converted. + (An AUTO_INCREMENT attribute cannot + be introduced to a column with + ALGORITHM=INPLACE.) */ + ut_ad((MTYP_TYPENR((*af)->unireg_check) + == Field::NEXT_NUMBER) + == (MTYP_TYPENR(f->unireg_check) + == Field::NEXT_NUMBER)); + goto next_column; + } + + ha_alter_info->unsupported_reason + = innobase_get_err_msg( + ER_ALTER_OPERATION_NOT_SUPPORTED_REASON_NOT_NULL); + } else if (!(*af)->default_value + || !((*af)->default_value->flags + & ~(VCOL_SESSION_FUNC | VCOL_TIME_FUNC))) { + n_add_cols++; + + if (af < &altered_table->field[table_share->fields]) { + add_column_not_last = true; + } + /* The added NOT NULL column lacks a DEFAULT value, + or the DEFAULT is the same for all rows. + (Time functions, such as CURRENT_TIMESTAMP(), + are evaluated from a timestamp that is assigned + at the start of the statement. Session + functions, such as USER(), always evaluate the + same within a statement.) */ + + /* Compute the DEFAULT values of non-constant columns + (VCOL_SESSION_FUNC | VCOL_TIME_FUNC). */ + switch ((*af)->set_default()) { + case 0: /* OK */ + case 3: /* DATETIME to TIME or DATE conversion */ + goto next_column; + case -1: /* OOM, or GEOMETRY type mismatch */ + case 1: /* A number adjusted to the min/max value */ + case 2: /* String truncation, or conversion problem */ + break; + } + } + + DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); + +next_column: + n_stored_cols += (*af++)->stored_in_db(); + } + + if (!add_column_not_last + && uint(m_prebuilt->table->n_cols) - DATA_N_SYS_COLS + n_add_cols + == n_stored_cols + && m_prebuilt->table->supports_instant() + && instant_alter_column_possible(ha_alter_info, table)) { + /* We can perform instant ADD COLUMN, because all + columns are going to be added after existing ones + (and not after hidden InnoDB columns, such as FTS_DOC_ID). */ + + /* MDEV-14246 FIXME: return HA_ALTER_INPLACE_NO_LOCK and + perform all work in ha_innobase::commit_inplace_alter_table(), + to avoid an unnecessary MDL upgrade/downgrade cycle. */ + DBUG_RETURN(HA_ALTER_INPLACE_NO_LOCK_AFTER_PREPARE); + } + if (!online) { /* We already determined that only a non-locking operation is possible. */ @@ -1037,102 +1191,6 @@ ha_innobase::check_if_supported_inplace_alter( } } - /* When changing a NULL column to NOT NULL and specifying a - DEFAULT value, ensure that the DEFAULT expression is a constant. - Also, in ADD COLUMN, for now we only support a - constant DEFAULT expression. */ - cf_it.rewind(); - Field **af = altered_table->field; - - while (Create_field* cf = cf_it++) { - DBUG_ASSERT(cf->field - || (ha_alter_info->handler_flags - & Alter_inplace_info::ADD_COLUMN)); - - if (const Field* f = cf->field) { - /* This could be changing an existing column - from NULL to NOT NULL. */ - switch ((*af)->type()) { - case MYSQL_TYPE_TIMESTAMP: - case MYSQL_TYPE_TIMESTAMP2: - /* Inserting NULL into a TIMESTAMP column - would cause the DEFAULT value to be - replaced. Ensure that the DEFAULT - expression is not changing during - ALTER TABLE. */ - if (!f->real_maybe_null() - || (*af)->real_maybe_null()) { - /* The column was NOT NULL, or it - will allow NULL after ALTER TABLE. */ - goto next_column; - } - - if (!(*af)->default_value - && (*af)->is_real_null()) { - /* No DEFAULT value is - specified. We can report - errors for any NULL values for - the TIMESTAMP. - - FIXME: Allow any DEFAULT - expression whose value does - not change during ALTER TABLE. - This would require a fix in - row_merge_read_clustered_index() - to try to replace the DEFAULT - value before reporting - DB_INVALID_NULL. */ - goto next_column; - } - break; - default: - /* For any other data type, NULL - values are not converted. - (An AUTO_INCREMENT attribute cannot - be introduced to a column with - ALGORITHM=INPLACE.) */ - ut_ad((MTYP_TYPENR((*af)->unireg_check) - == Field::NEXT_NUMBER) - == (MTYP_TYPENR(f->unireg_check) - == Field::NEXT_NUMBER)); - goto next_column; - } - - ha_alter_info->unsupported_reason - = innobase_get_err_msg( - ER_ALTER_OPERATION_NOT_SUPPORTED_REASON_NOT_NULL); - } else if (!(*af)->default_value - || !((*af)->default_value->flags - & ~(VCOL_SESSION_FUNC | VCOL_TIME_FUNC))) { - /* The added NOT NULL column lacks a DEFAULT value, - or the DEFAULT is the same for all rows. - (Time functions, such as CURRENT_TIMESTAMP(), - are evaluated from a timestamp that is assigned - at the start of the statement. Session - functions, such as USER(), always evaluate the - same within a statement.) */ - - /* Compute the DEFAULT values of non-constant columns - (VCOL_SESSION_FUNC | VCOL_TIME_FUNC). */ - switch ((*af)->set_default()) { - case 0: /* OK */ - case 3: /* DATETIME to TIME or DATE conversion */ - goto next_column; - case -1: /* OOM, or GEOMETRY type mismatch */ - case 1: /* A number adjusted to the min/max value */ - case 2: /* String truncation, or conversion problem */ - break; - } - } - - DBUG_RETURN(HA_ALTER_INPLACE_NOT_SUPPORTED); - -next_column: - af++; - } - - cf_it.rewind(); - DBUG_RETURN(online ? HA_ALTER_INPLACE_NO_LOCK_AFTER_PREPARE : HA_ALTER_INPLACE_SHARED_LOCK_AFTER_PREPARE); @@ -4711,29 +4769,6 @@ prepare_inplace_alter_table_dict( new_clustered = DICT_CLUSTERED & index_defs[0].ind_type; - if (num_fts_index > 1) { - my_error(ER_INNODB_FT_LIMIT, MYF(0)); - goto error_handled; - } - - if (!ctx->online) { - /* This is not an online operation (LOCK=NONE). */ - } else if (ctx->add_autoinc == ULINT_UNDEFINED - && num_fts_index == 0 - && (!innobase_need_rebuild(ha_alter_info, old_table) - || !innobase_fulltext_exist(altered_table))) { - /* InnoDB can perform an online operation (LOCK=NONE). */ - } else { - size_t query_length; - /* This should have been blocked in - check_if_supported_inplace_alter(). */ - ut_ad(0); - my_error(ER_NOT_SUPPORTED_YET, MYF(0), - innobase_get_stmt_unsafe(ctx->prebuilt->trx->mysql_thd, - &query_length)); - goto error_handled; - } - /* The primary index would be rebuilt if a FTS Doc ID column is to be added, and the primary index definition is just copied from old table and stored in indexdefs[0] */ @@ -5077,22 +5112,8 @@ new_clustered_failed: == !!new_clustered); } - if (ctx->need_rebuild() && ctx->new_table->supports_instant()) { - if (~ha_alter_info->handler_flags - & Alter_inplace_info::ADD_STORED_BASE_COLUMN) { - goto not_instant_add_column; - } - - if (ha_alter_info->handler_flags - & (INNOBASE_ALTER_REBUILD - & ~Alter_inplace_info::ADD_STORED_BASE_COLUMN - & ~Alter_inplace_info::CHANGE_CREATE_OPTION)) { - goto not_instant_add_column; - } - - if ((ha_alter_info->handler_flags & ~INNOBASE_INPLACE_IGNORE) - == Alter_inplace_info::CHANGE_CREATE_OPTION - && create_option_need_rebuild(ha_alter_info, old_table)) { + if (ctx->need_rebuild() && user_table->supports_instant()) { + if (!instant_alter_column_possible(ha_alter_info, old_table)) { goto not_instant_add_column; } @@ -5105,28 +5126,6 @@ new_clustered_failed: DBUG_ASSERT(ctx->new_table->n_cols > ctx->old_table->n_cols); - if (ha_alter_info->handler_flags & INNOBASE_ONLINE_CREATE) { - /* At the moment, we disallow ADD [UNIQUE] INDEX - together with instant ADD COLUMN. - - The main reason is that the work of instant - ADD must be done in commit_inplace_alter_table(). - For the rollback_instant() to work, we must - add the columns to dict_table_t beforehand, - and roll back those changes in case the - transaction is rolled back. - - If we added the columns to the dictionary cache - already in the prepare_inplace_alter_table(), - we would have to deal with column number - mismatch in ha_innobase::open(), write_row() - and other functions. */ - - /* FIXME: allow instant ADD COLUMN together - with ADD INDEX on pre-existing columns. */ - goto not_instant_add_column; - } - for (uint a = 0; a < ctx->num_to_add_index; a++) { error = dict_index_add_to_cache_w_vcol( ctx->new_table, ctx->add_index[a], add_v, @@ -5134,8 +5133,15 @@ new_clustered_failed: ut_a(error == DB_SUCCESS); } DBUG_ASSERT(ha_alter_info->key_count + /* hidden GEN_CLUST_INDEX in InnoDB */ + dict_index_is_auto_gen_clust( dict_table_get_first_index(ctx->new_table)) + /* hidden FTS_DOC_ID_INDEX in InnoDB */ + + (ctx->old_table->fts_doc_id_index + && innobase_fts_check_doc_id_index_in_def( + altered_table->s->keys, + altered_table->key_info) + != FTS_EXIST_DOC_ID_INDEX) == ctx->num_to_add_index); ctx->num_to_add_index = 0; ctx->add_index = NULL; @@ -5253,6 +5259,33 @@ new_clustered_failed: ctx->prepare_instant(); } + if (!ctx->is_instant()) { + if (num_fts_index > 1) { + my_error(ER_INNODB_FT_LIMIT, MYF(0)); + goto error_handled; + } + + if (!ctx->online) { + /* This is not an online operation (LOCK=NONE). */ + } else if (ctx->add_autoinc == ULINT_UNDEFINED + && num_fts_index == 0 + && (!innobase_need_rebuild(ha_alter_info, old_table) + || !innobase_fulltext_exist(altered_table))) { + /* InnoDB can perform an online operation + (LOCK=NONE). */ + } else { + size_t query_length; + /* This should have been blocked in + check_if_supported_inplace_alter(). */ + ut_ad(0); + my_error(ER_NOT_SUPPORTED_YET, MYF(0), + innobase_get_stmt_unsafe( + ctx->prebuilt->trx->mysql_thd, + &query_length)); + goto error_handled; + } + } + if (ctx->need_rebuild()) { not_instant_add_column: uint32_t key_id = FIL_DEFAULT_ENCRYPTION_KEY; From d8a9b524f2e4efec675725c4c32acefe1d8dcb15 Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Thu, 2 Nov 2017 16:58:37 +0400 Subject: [PATCH 072/138] MDEV-14221 Assertion `0' failed in Item::field_type_for_temporal_comparison --- mysql-test/r/type_date.result | 11 +++++++++++ mysql-test/t/type_date.test | 9 +++++++++ sql/item.h | 11 +++++++++++ 3 files changed, 31 insertions(+) diff --git a/mysql-test/r/type_date.result b/mysql-test/r/type_date.result index d2587d7199e..661dcabbcfe 100644 --- a/mysql-test/r/type_date.result +++ b/mysql-test/r/type_date.result @@ -843,5 +843,16 @@ Warning 1292 Incorrect datetime value: '1' Warning 1292 Incorrect datetime value: '1' DROP TABLE t1; # +# MDEV-14221 Assertion `0' failed in Item::field_type_for_temporal_comparison +# +CREATE TABLE t1 (d DATE); +INSERT INTO t1 VALUES ('1985-05-13'),('1989-12-24'); +SELECT d, COUNT(*) FROM t1 GROUP BY d WITH ROLLUP HAVING CASE d WHEN '2017-05-25' THEN 0 ELSE 1 END; +d COUNT(*) +1985-05-13 1 +1989-12-24 1 +NULL 2 +DROP TABLE t1; +# # End of 10.1 tests # diff --git a/mysql-test/t/type_date.test b/mysql-test/t/type_date.test index 63c89f318fc..8248386a93f 100644 --- a/mysql-test/t/type_date.test +++ b/mysql-test/t/type_date.test @@ -576,6 +576,15 @@ SELECT DATE(a), DATE(b), DATE(c) FROM t1; SELECT DATE(COALESCE(a)), DATE(COALESCE(b)), DATE(COALESCE(c)) FROM t1; DROP TABLE t1; +--echo # +--echo # MDEV-14221 Assertion `0' failed in Item::field_type_for_temporal_comparison +--echo # + +CREATE TABLE t1 (d DATE); +INSERT INTO t1 VALUES ('1985-05-13'),('1989-12-24'); +SELECT d, COUNT(*) FROM t1 GROUP BY d WITH ROLLUP HAVING CASE d WHEN '2017-05-25' THEN 0 ELSE 1 END; +DROP TABLE t1; + --echo # --echo # End of 10.1 tests diff --git a/sql/item.h b/sql/item.h index da2de2f25c5..17d97fe56e3 100644 --- a/sql/item.h +++ b/sql/item.h @@ -2581,6 +2581,17 @@ public: Field *result_field; Item_null_result(THD *thd): Item_null(thd), result_field(0) {} bool is_result_field() { return result_field != 0; } +#if MARIADB_VERSION_ID < 100300 + enum_field_types field_type() const + { + return result_field->type(); + } +#else + const Type_handler *type_handler() const + { + return result_field->type_handler(); + } +#endif void save_in_result_field(bool no_conversions) { save_in_field(result_field, no_conversions); From 0f4e005541056fed489209f9503cc78e5b16c056 Mon Sep 17 00:00:00 2001 From: Monty Date: Thu, 2 Nov 2017 15:40:27 +0200 Subject: [PATCH 073/138] Fixed compiler warning and warning from valgrind The failing test was main.gis-json --- sql/item_geofunc.cc | 2 +- storage/connect/tabtbl.cpp | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/sql/item_geofunc.cc b/sql/item_geofunc.cc index 1fa6b52cf96..6f79bd9a039 100644 --- a/sql/item_geofunc.cc +++ b/sql/item_geofunc.cc @@ -144,7 +144,7 @@ String *Item_func_geometry_from_json::val_str(String *str) { String *sv= args[1]->val_str(&tmp_js); my_error(ER_WRONG_VALUE_FOR_TYPE, MYF(0), - "option", sv->c_ptr(), "ST_GeometryFromJSON"); + "option", sv->c_ptr_safe(), "ST_GeometryFromJSON"); null_value= 1; return 0; } diff --git a/storage/connect/tabtbl.cpp b/storage/connect/tabtbl.cpp index d3fb31fb57a..ee0de66ca8d 100644 --- a/storage/connect/tabtbl.cpp +++ b/storage/connect/tabtbl.cpp @@ -650,7 +650,7 @@ bool TDBTBM::IsLocal(PTABLE tbp) return ((!stricmp(tdbp->Host, "localhost") || !strcmp(tdbp->Host, "127.0.0.1")) && - tdbp->Port == (int)GetDefaultPort()); + (int) tdbp->Port == (int)GetDefaultPort()); } // end of IsLocal /***********************************************************************/ From 3a9b7f4ecddfa4d6866fed6279f86cbb57c663a0 Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Thu, 2 Nov 2017 17:49:36 +0400 Subject: [PATCH 074/138] A cleanup for MDEV-12172: Fixing "mtr --suite=compat/oracle" test failures Adding missing commands into sql_yacc_ora.yy: %token VALUES_IN_SYM %token VALUES_LESS_SYM and their parser hacks with Select->parsing_place. Note: the grammar for table_value_constructor will be merged later separately. --- sql/sql_yacc_ora.yy | 28 ++++++++++++++++++++++------ 1 file changed, 22 insertions(+), 6 deletions(-) diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy index a50a4ad8ccb..0c5c0f85f9b 100644 --- a/sql/sql_yacc_ora.yy +++ b/sql/sql_yacc_ora.yy @@ -966,6 +966,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token UTC_TIMESTAMP_SYM %token UTC_TIME_SYM %token VALUES /* SQL-2003-R */ +%token VALUES_IN_SYM +%token VALUES_LESS_SYM %token VALUE_SYM /* SQL-2003-R */ %token VARBINARY %token VARCHAR /* SQL-2003-R */ @@ -4839,8 +4841,15 @@ part_type_def: { Lex->part_info->part_type= RANGE_PARTITION; } | RANGE_SYM part_column_list { Lex->part_info->part_type= RANGE_PARTITION; } - | LIST_SYM part_func - { Lex->part_info->part_type= LIST_PARTITION; } + | LIST_SYM + { + Select->parsing_place= IN_PART_FUNC; + } + part_func + { + Lex->part_info->part_type= LIST_PARTITION; + Select->parsing_place= NO_MATTER; + } | LIST_SYM part_column_list { Lex->part_info->part_type= LIST_PARTITION; } ; @@ -5090,7 +5099,7 @@ opt_part_values: else part_info->part_type= HASH_PARTITION; } - | VALUES LESS_SYM THAN_SYM + | VALUES_LESS_SYM THAN_SYM { LEX *lex= Lex; partition_info *part_info= lex->part_info; @@ -5104,7 +5113,7 @@ opt_part_values: part_info->part_type= RANGE_PARTITION; } part_func_max {} - | VALUES IN_SYM + | VALUES_IN_SYM { LEX *lex= Lex; partition_info *part_info= lex->part_info; @@ -9499,7 +9508,7 @@ column_default_non_parenthesized_expr: if ($$ == NULL) MYSQL_YYABORT; } - | VALUES '(' simple_ident_nospvar ')' + | VALUE_SYM '(' simple_ident_nospvar ')' { $$= new (thd->mem_root) Item_insert_value(thd, Lex->current_context(), $3); @@ -12750,7 +12759,14 @@ expr_or_default: opt_insert_update: /* empty */ | ON DUPLICATE_SYM { Lex->duplicates= DUP_UPDATE; } - KEY_SYM UPDATE_SYM insert_update_list + KEY_SYM UPDATE_SYM + { + Select->parsing_place= IN_UPDATE_ON_DUP_KEY; + } + insert_update_list + { + Select->parsing_place= NO_MATTER; + } ; /* Update rows in a table */ From 19733efa7b6f8e193ab428b6fdf08d3c9e685374 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Marko=20M=C3=A4kel=C3=A4?= Date: Thu, 2 Nov 2017 16:18:41 +0200 Subject: [PATCH 075/138] MDEV-14244 MariaDB 10.2.10 fails to run on Debian Stretch with ext3 and O_DIRECT os_file_set_size(): If posix_fallocate() returns EINVAL, fall back to writing zero bytes to the file. Also, remove some error log output, and make it possible for a server shutdown to interrupt the fall-back code. MariaDB 10.2 used to handle the EINVAL return value from posix_fallocate() before commit b731a5bcf2a0c86b6e31e4a99e3c632bb39a9c53 which refactored os_file_set_size() to try posix_fallocate(). Why is the EINVAL returned? The GNU posix_fallocate() function would first try the fallocate() system call, which would return -EOPNOTSUPP for many file systems (notably, not ext4). Then, it would fall back to extending the file one block at a time by invoking pwrite(fd, "", 1, offset) where offset is 1 less than a multiple of the file block size. This would fail with EINVAL if the file is in O_DIRECT mode, because O_DIRECT requires aligned operation. --- storage/innobase/os/os0file.cc | 44 ++++++++++++---------------------- 1 file changed, 15 insertions(+), 29 deletions(-) diff --git a/storage/innobase/os/os0file.cc b/storage/innobase/os/os0file.cc index cc687816ae8..03793a1d064 100644 --- a/storage/innobase/os/os0file.cc +++ b/storage/innobase/os/os0file.cc @@ -5382,13 +5382,21 @@ fallback: } while (err == EINTR && srv_shutdown_state == SRV_SHUTDOWN_NONE); - if (err) { + switch (err) { + case 0: + return true; + default: ib::error() << "preallocating " << size << " bytes for file " << name << " failed with error " << err; + /* fall through */ + case EINTR: + errno = err; + return false; + case EINVAL: + /* fall back to the code below */ + break; } - errno = err; - return(!err); # endif /* HAVE_POSIX_ALLOCATE */ #endif /* _WIN32*/ @@ -5410,14 +5418,9 @@ fallback: memset(buf, 0, buf_size); os_offset_t current_size = os_file_get_size(file); - bool write_progress_info = - (size - current_size >= (os_offset_t) 100 << 20); - if (write_progress_info) { - ib::info() << "Progress in MB:"; - } - - while (current_size < size) { + while (current_size < size + && srv_shutdown_state == SRV_SHUTDOWN_NONE) { ulint n_bytes; if (size - current_size < (os_offset_t) buf_size) { @@ -5433,32 +5436,15 @@ fallback: request, name, file, buf, current_size, n_bytes); if (err != DB_SUCCESS) { - - ut_free(buf2); - return(false); - } - - /* Print about progress for each 100 MB written */ - if (write_progress_info && - ((current_size + n_bytes) / (100 << 20) - != current_size / (100 << 20))) { - - fprintf(stderr, " %lu00", - (ulong) ((current_size + n_bytes) - / (100 << 20))); + break; } current_size += n_bytes; } - if (write_progress_info) { - - fprintf(stderr, "\n"); - } - ut_free(buf2); - return(os_file_flush(file)); + return(current_size >= size && os_file_flush(file)); } /** Truncates a file to a specified size in bytes. From 5d0153c408ff8c7282fc387c4041fdbffd35727d Mon Sep 17 00:00:00 2001 From: Monty Date: Thu, 2 Nov 2017 14:39:54 +0200 Subject: [PATCH 076/138] MDEV-12633 Error from valgrind related to dd_frm_type "Conditional jump or move depends on uninitialised value in my_scan_weight_utf8_general_ci, main.mysql_client_test fails in biuldbot with valgrind" - Fixed by ensuring that engine_name is set to empty string even in case errors in the .frm file - Added some error checking to ha_table_exists() --- sql/datadict.cc | 15 ++++++++++++++- sql/handler.cc | 9 +++++++-- 2 files changed, 21 insertions(+), 3 deletions(-) diff --git a/sql/datadict.cc b/sql/datadict.cc index ee0d8805f95..f01d61f531b 100644 --- a/sql/datadict.cc +++ b/sql/datadict.cc @@ -45,6 +45,8 @@ static int read_string(File file, uchar**to, size_t length) engine_name is a LEX_STRING, where engine_name->str must point to a buffer of at least NAME_CHAR_LEN+1 bytes. + If engine_name is 0, then the function will only test if the file is a + view or not @retval FRMTYPE_ERROR error @retval FRMTYPE_TABLE table @@ -72,12 +74,23 @@ frm_type_enum dd_frm_type(THD *thd, char *path, LEX_STRING *engine_name) goto err; } + /* + We return FRMTYPE_TABLE if we can read the .frm file. This allows us + to drop a bad .frm file with DROP TABLE + */ type= FRMTYPE_TABLE; - if (!is_binary_frm_header(header) || !engine_name) + /* engine_name is 0 if we only want to know if table is view or not */ + if (!engine_name) goto err; + /* Initialize engine name in case we are not able to find it out */ engine_name->length= 0; + engine_name->str[0]= 0; + + if (!is_binary_frm_header(header)) + goto err; + dbt= header[3]; /* cannot use ha_resolve_by_legacy_type without a THD */ diff --git a/sql/handler.cc b/sql/handler.cc index 4e35780b1e2..a5a28ceb777 100644 --- a/sql/handler.cc +++ b/sql/handler.cc @@ -5063,10 +5063,15 @@ bool ha_table_exists(THD *thd, const char *db, const char *table_name, { char engine_buf[NAME_CHAR_LEN + 1]; LEX_STRING engine= { engine_buf, 0 }; + frm_type_enum type; - if (dd_frm_type(thd, path, &engine) != FRMTYPE_VIEW) + if ((type= dd_frm_type(thd, path, &engine)) == FRMTYPE_ERROR) + DBUG_RETURN(0); + + if (type != FRMTYPE_VIEW) { - plugin_ref p= plugin_lock_by_name(thd, &engine, MYSQL_STORAGE_ENGINE_PLUGIN); + plugin_ref p= plugin_lock_by_name(thd, &engine, + MYSQL_STORAGE_ENGINE_PLUGIN); *hton= p ? plugin_hton(p) : NULL; if (*hton) // verify that the table really exists From 80d61515ac07eeeb2ba9870c5a2ba33e160c2fa1 Mon Sep 17 00:00:00 2001 From: Sergei Petrunia Date: Thu, 2 Nov 2017 19:11:01 +0300 Subject: [PATCH 077/138] Make rocksdb.read_only_tx pass and enable it - FB/MySQL 5.6' MyRocks has START TRANSACTION WITH CONSISTENT ROCKSDB SNAPSHOT, which returns binlog position. - MariaDB has a cross-engine START TRANSACTION WITH CONSISTENT SNAPSHOT. It can be used for the same purpose. Binlog position can be obtained from Binlog_snapshot_file/position status vars. --- .../mysql-test/rocksdb/r/read_only_tx.result | 14 +++++++++++--- storage/rocksdb/mysql-test/rocksdb/t/disabled.def | 2 +- .../mysql-test/rocksdb/t/read_only_tx-master.opt | 2 +- .../rocksdb/mysql-test/rocksdb/t/read_only_tx.test | 8 ++++---- 4 files changed, 17 insertions(+), 9 deletions(-) diff --git a/storage/rocksdb/mysql-test/rocksdb/r/read_only_tx.result b/storage/rocksdb/mysql-test/rocksdb/r/read_only_tx.result index b83f0a474cc..db21c3c01d4 100644 --- a/storage/rocksdb/mysql-test/rocksdb/r/read_only_tx.result +++ b/storage/rocksdb/mysql-test/rocksdb/r/read_only_tx.result @@ -1,11 +1,14 @@ DROP TABLE IF EXISTS t1; +connect con1,localhost,root,,; +connect con2,localhost,root,,; +connection con1; CREATE TABLE t1 (id INT, value int, PRIMARY KEY (id), INDEX (value)) ENGINE=RocksDB; INSERT INTO t1 VALUES (1,1); select variable_value into @p from information_schema.global_status where variable_name='rocksdb_number_sst_entry_put'; select variable_value into @s from information_schema.global_status where variable_name='rocksdb_number_sst_entry_singledelete'; -START TRANSACTION WITH CONSISTENT ROCKSDB SNAPSHOT; -File Position Gtid_executed -master-bin.000001 734 uuid:1-3 +START TRANSACTION WITH CONSISTENT SNAPSHOT; +connection con2; +connection con1; select case when variable_value-@p < 1000 then 'true' else variable_value-@p end from information_schema.global_status where variable_name='rocksdb_number_sst_entry_put'; case when variable_value-@p < 1000 then 'true' else variable_value-@p end true @@ -27,10 +30,15 @@ id value 1 10001 2 2 BEGIN; +connection con2; +connection con1; SELECT COUNT(*) FROM t1; COUNT(*) 9998 COMMIT; +connection default; +disconnect con1; +disconnect con2; OPTIMIZE TABLE t1; Table Op Msg_type Msg_text test.t1 optimize status OK diff --git a/storage/rocksdb/mysql-test/rocksdb/t/disabled.def b/storage/rocksdb/mysql-test/rocksdb/t/disabled.def index 3af1d99ff22..a0810fe63ec 100644 --- a/storage/rocksdb/mysql-test/rocksdb/t/disabled.def +++ b/storage/rocksdb/mysql-test/rocksdb/t/disabled.def @@ -80,7 +80,7 @@ blind_delete_without_tx_api: MDEV-12286: rocksdb.blind_delete_without_tx_api tes ## information_schema : MariaRocks: requires GTIDs mysqlbinlog_gtid_skip_empty_trans_rocksdb : MariaRocks: requires GTIDs -read_only_tx : MariaRocks: requires GTIDs +#read_only_tx : MariaRocks: requires GTIDs rpl_row_triggers : MariaRocks: requires GTIDs diff --git a/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx-master.opt b/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx-master.opt index 52f4895dc2f..221b35c672a 100644 --- a/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx-master.opt +++ b/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx-master.opt @@ -1 +1 @@ ---rocksdb_default_cf_options=write_buffer_size=16k --log-bin --binlog_format=row --gtid_mode=ON --enforce_gtid_consistency --log-slave-updates +--rocksdb_default_cf_options=write_buffer_size=16k --log-bin --binlog_format=row --log-slave-updates diff --git a/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx.test b/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx.test index 52f65095d33..3a1025a3623 100644 --- a/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx.test +++ b/storage/rocksdb/mysql-test/rocksdb/t/read_only_tx.test @@ -2,9 +2,9 @@ --source include/have_rocksdb.inc --source include/count_sessions.inc --disable_warnings ---source include/have_gtid.inc +#--source include/have_gtid.inc --enable_warnings --- let $uuid = `select @@server_uuid;` +#-- let $uuid = `select @@server_uuid;` --disable_warnings DROP TABLE IF EXISTS t1; @@ -20,8 +20,8 @@ INSERT INTO t1 VALUES (1,1); # Read-only, long-running transaction. SingleDelete/Put shouldn't increase much. select variable_value into @p from information_schema.global_status where variable_name='rocksdb_number_sst_entry_put'; select variable_value into @s from information_schema.global_status where variable_name='rocksdb_number_sst_entry_singledelete'; --- replace_result $uuid uuid -START TRANSACTION WITH CONSISTENT ROCKSDB SNAPSHOT; +#-- replace_result $uuid uuid +START TRANSACTION WITH CONSISTENT SNAPSHOT; connection con2; --disable_query_log From b0cfb1686773c38955c254d29d196c1866e7e06a Mon Sep 17 00:00:00 2001 From: Vladislav Vaintroub Date: Thu, 2 Nov 2017 17:48:50 +0000 Subject: [PATCH 078/138] Fix a warning. --- storage/innobase/handler/handler0alter.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/storage/innobase/handler/handler0alter.cc b/storage/innobase/handler/handler0alter.cc index 3f3994d1d56..e668200180d 100644 --- a/storage/innobase/handler/handler0alter.cc +++ b/storage/innobase/handler/handler0alter.cc @@ -4523,7 +4523,7 @@ prepare_inplace_alter_table_dict( if (alt_opt.encryption != opt.encryption || alt_opt.encryption_key_id != opt.encryption_key_id) { - key_id = alt_opt.encryption_key_id; + key_id = uint32_t(alt_opt.encryption_key_id); mode = fil_encryption_t(alt_opt.encryption); } } From 9ada5a3c1ac4a98ac7175e57e0b6badb83e4fcc0 Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Thu, 2 Nov 2017 22:28:04 +0400 Subject: [PATCH 079/138] Cleanup tests for MDEV-13049 Querying INFORMATION_SCHEMA becomes slow in MariaDB 10.1 --- mysql-test/suite/jp/r/jp_create_db_sjis.result | 2 +- mysql-test/suite/jp/r/jp_create_db_ucs2.result | 2 +- mysql-test/suite/jp/r/jp_create_db_ujis.result | 2 +- mysql-test/suite/jp/r/jp_create_db_utf8.result | 2 +- mysql-test/suite/jp/t/jp_create_db_sjis.test | 2 +- mysql-test/suite/jp/t/jp_create_db_ucs2.test | 2 +- mysql-test/suite/jp/t/jp_create_db_ujis.test | 2 +- mysql-test/suite/jp/t/jp_create_db_utf8.test | 2 +- 8 files changed, 8 insertions(+), 8 deletions(-) diff --git a/mysql-test/suite/jp/r/jp_create_db_sjis.result b/mysql-test/suite/jp/r/jp_create_db_sjis.result index 93524e1c443..78c80c27cc5 100644 --- a/mysql-test/suite/jp/r/jp_create_db_sjis.result +++ b/mysql-test/suite/jp/r/jp_create_db_sjis.result @@ -6,7 +6,7 @@ drop database if exists ` CREATE DATABASE `ÆÎݺÞ`; CREATE DATABASE `“ú–{Œê`; CREATE DATABASE `ƒ\\•\`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; schema_name information_schema mysql diff --git a/mysql-test/suite/jp/r/jp_create_db_ucs2.result b/mysql-test/suite/jp/r/jp_create_db_ucs2.result index c6a2ff78b4f..380fcf09389 100644 --- a/mysql-test/suite/jp/r/jp_create_db_ucs2.result +++ b/mysql-test/suite/jp/r/jp_create_db_ucs2.result @@ -7,7 +7,7 @@ SET character_set_server = ucs2; CREATE DATABASE `ŽÆŽÎŽÝŽºŽÞ`; CREATE DATABASE `ÆüËܸì`; CREATE DATABASE `íÜíÝíÞ`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; schema_name information_schema mysql diff --git a/mysql-test/suite/jp/r/jp_create_db_ujis.result b/mysql-test/suite/jp/r/jp_create_db_ujis.result index e5e0c2f1ad8..529a225e4ed 100644 --- a/mysql-test/suite/jp/r/jp_create_db_ujis.result +++ b/mysql-test/suite/jp/r/jp_create_db_ujis.result @@ -6,7 +6,7 @@ SET character_set_database = ujis; CREATE DATABASE `ŽÆŽÎŽÝŽºŽÞ`; CREATE DATABASE `ÆüËܸì`; CREATE DATABASE `íÜíÝíÞ`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; schema_name information_schema mysql diff --git a/mysql-test/suite/jp/r/jp_create_db_utf8.result b/mysql-test/suite/jp/r/jp_create_db_utf8.result index f07a36fd7c7..7d950ea53f9 100644 --- a/mysql-test/suite/jp/r/jp_create_db_utf8.result +++ b/mysql-test/suite/jp/r/jp_create_db_utf8.result @@ -6,7 +6,7 @@ SET character_set_database = utf8; CREATE DATABASE `ニホï¾ï½ºï¾ž`; CREATE DATABASE `日本語`; CREATE DATABASE `龔龖龗`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; schema_name information_schema mysql diff --git a/mysql-test/suite/jp/t/jp_create_db_sjis.test b/mysql-test/suite/jp/t/jp_create_db_sjis.test index 49647bf1753..5458e6f0abd 100644 --- a/mysql-test/suite/jp/t/jp_create_db_sjis.test +++ b/mysql-test/suite/jp/t/jp_create_db_sjis.test @@ -16,7 +16,7 @@ CREATE DATABASE ` CREATE DATABASE `“ú–{Œê`; CREATE DATABASE `ƒ\\•\`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; USE `ÆÎݺÞ`; USE `“ú–{Œê`; diff --git a/mysql-test/suite/jp/t/jp_create_db_ucs2.test b/mysql-test/suite/jp/t/jp_create_db_ucs2.test index 8be8cf62f15..a3f64d1ebc7 100644 --- a/mysql-test/suite/jp/t/jp_create_db_ucs2.test +++ b/mysql-test/suite/jp/t/jp_create_db_ucs2.test @@ -18,7 +18,7 @@ CREATE DATABASE ` CREATE DATABASE `ÆüËܸì`; CREATE DATABASE `íÜíÝíÞ`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; USE `ŽÆŽÎŽÝŽºŽÞ`; USE `ÆüËܸì`; diff --git a/mysql-test/suite/jp/t/jp_create_db_ujis.test b/mysql-test/suite/jp/t/jp_create_db_ujis.test index 382c7937552..514745aad43 100644 --- a/mysql-test/suite/jp/t/jp_create_db_ujis.test +++ b/mysql-test/suite/jp/t/jp_create_db_ujis.test @@ -17,7 +17,7 @@ CREATE DATABASE ` CREATE DATABASE `ÆüËܸì`; CREATE DATABASE `íÜíÝíÞ`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; USE `ŽÆŽÎŽÝŽºŽÞ`; USE `ÆüËܸì`; diff --git a/mysql-test/suite/jp/t/jp_create_db_utf8.test b/mysql-test/suite/jp/t/jp_create_db_utf8.test index 2df5b9e1f6f..8617af57c7b 100644 --- a/mysql-test/suite/jp/t/jp_create_db_utf8.test +++ b/mysql-test/suite/jp/t/jp_create_db_utf8.test @@ -16,7 +16,7 @@ CREATE DATABASE `ニホï¾ï½ºï¾ž`; CREATE DATABASE `日本語`; CREATE DATABASE `龔龖龗`; -SELECT schema_name from information_schema.schemata where schema_name <> 'mtr'; +SELECT schema_name from information_schema.schemata where schema_name <> 'mtr' ORDER BY schema_name; USE `ニホï¾ï½ºï¾ž`; USE `日本語`; From 9ec19b9b41804d8d4491f0f58ac06ae417e02ffa Mon Sep 17 00:00:00 2001 From: Monty Date: Wed, 1 Nov 2017 20:28:36 +0200 Subject: [PATCH 080/138] Reducing memory when using information schema The background is that one user had a lot of views and using some complex queries on information schema temporary memory of more than 2G was used. - Added new element 'total_alloc' to MEM_ROOT for easier debugging. - Added MAX_MEMORY_USED to information_schema.processlist. - Added new status variable "Memory_used_initial" that shows how much MariaDB uses at startup. This gives the base value for "Memory_used". - Reuse memory continuously for information schema queries instead of only freeing memory at query end. Other things - Removed some not needed set_notnull() calls for not null columns. --- include/my_alloc.h | 1 + include/mysql.h.pp | 1 + mysql-test/r/create.result | 2 + .../funcs_1/datadict/processlist_priv.inc | 26 ++-- .../funcs_1/datadict/processlist_val.inc | 14 +- .../suite/funcs_1/r/is_columns_is.result | 10 +- .../funcs_1/r/processlist_priv_no_prot.result | 138 +++++++++--------- .../funcs_1/r/processlist_priv_ps.result | 138 +++++++++--------- .../funcs_1/r/processlist_val_no_prot.result | 45 +++--- .../suite/funcs_1/r/processlist_val_ps.result | 45 +++--- mysys/my_alloc.c | 22 ++- sql/mysqld.cc | 7 + sql/sql_class.h | 2 +- sql/sql_const.h | 5 + sql/sql_show.cc | 37 +++-- 15 files changed, 274 insertions(+), 219 deletions(-) diff --git a/include/my_alloc.h b/include/my_alloc.h index 85ac75fc666..b461065eb7c 100644 --- a/include/my_alloc.h +++ b/include/my_alloc.h @@ -43,6 +43,7 @@ typedef struct st_mem_root /* if block have less memory it will be put in 'used' list */ size_t min_malloc; size_t block_size; /* initial block size */ + size_t total_alloc; unsigned int block_num; /* allocated blocks counter */ /* first free block in queue test counter (if it exceed diff --git a/include/mysql.h.pp b/include/mysql.h.pp index d061df71944..e88738be779 100644 --- a/include/mysql.h.pp +++ b/include/mysql.h.pp @@ -236,6 +236,7 @@ typedef struct st_mem_root USED_MEM *pre_alloc; size_t min_malloc; size_t block_size; + size_t total_alloc; unsigned int block_num; unsigned int first_block_usage; void (*error_handler)(void); diff --git a/mysql-test/r/create.result b/mysql-test/r/create.result index dca48c07fe9..b4636dca7e2 100644 --- a/mysql-test/r/create.result +++ b/mysql-test/r/create.result @@ -1173,6 +1173,7 @@ t1 CREATE TABLE `t1` ( `MAX_STAGE` tinyint(2) NOT NULL DEFAULT 0, `PROGRESS` decimal(7,3) NOT NULL DEFAULT 0.000, `MEMORY_USED` bigint(7) NOT NULL DEFAULT 0, + `MAX_MEMORY_USED` bigint(7) NOT NULL DEFAULT 0, `EXAMINED_ROWS` int(7) NOT NULL DEFAULT 0, `QUERY_ID` bigint(4) NOT NULL DEFAULT 0, `INFO_BINARY` blob DEFAULT NULL, @@ -1196,6 +1197,7 @@ t1 CREATE TEMPORARY TABLE `t1` ( `MAX_STAGE` tinyint(2) NOT NULL DEFAULT 0, `PROGRESS` decimal(7,3) NOT NULL DEFAULT 0.000, `MEMORY_USED` bigint(7) NOT NULL DEFAULT 0, + `MAX_MEMORY_USED` bigint(7) NOT NULL DEFAULT 0, `EXAMINED_ROWS` int(7) NOT NULL DEFAULT 0, `QUERY_ID` bigint(4) NOT NULL DEFAULT 0, `INFO_BINARY` blob DEFAULT NULL, diff --git a/mysql-test/suite/funcs_1/datadict/processlist_priv.inc b/mysql-test/suite/funcs_1/datadict/processlist_priv.inc index cd060e7a370..ae46dfd31c8 100644 --- a/mysql-test/suite/funcs_1/datadict/processlist_priv.inc +++ b/mysql-test/suite/funcs_1/datadict/processlist_priv.inc @@ -158,7 +158,7 @@ WHERE DB = 'information_schema' AND COMMAND = 'Sleep' AND USER = 'ddicttestuser1 eval SHOW CREATE TABLE $table; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS eval SHOW $table; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID eval SELECT * FROM $table $select_where ORDER BY id; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID eval SELECT $columns FROM $table $select_where ORDER BY id; @@ -178,7 +178,7 @@ connection con100; eval SHOW CREATE TABLE $table; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS eval SHOW $table; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID eval SELECT * FROM $table $select_where ORDER BY id; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID eval SELECT $columns FROM $table $select_where ORDER BY id; @@ -204,7 +204,7 @@ connection con100; SHOW GRANTS; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -216,7 +216,7 @@ connect (con101,localhost,ddicttestuser1,ddictpass,information_schema); SHOW GRANTS; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -239,7 +239,7 @@ connect (anonymous1,localhost,"''",,information_schema); SHOW GRANTS; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -261,7 +261,7 @@ connect (con102,localhost,ddicttestuser1,ddictpass,information_schema); SHOW GRANTS; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -287,7 +287,7 @@ if ($fixed_bug_30395) --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; } ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -308,7 +308,7 @@ connect (con103,localhost,ddicttestuser1,ddictpass,information_schema); SHOW GRANTS FOR 'ddicttestuser1'@'localhost'; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -330,7 +330,7 @@ connect (con104,localhost,ddicttestuser1,ddictpass,information_schema); SHOW GRANTS FOR 'ddicttestuser1'@'localhost'; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -377,7 +377,7 @@ connect (con200,localhost,ddicttestuser2,ddictpass,information_schema); SHOW GRANTS FOR 'ddicttestuser2'@'localhost'; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -398,7 +398,7 @@ connect (con201,localhost,ddicttestuser2,ddictpass,information_schema); SHOW GRANTS; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -421,7 +421,7 @@ SHOW GRANTS FOR 'ddicttestuser1'@'localhost'; GRANT PROCESS ON *.* TO 'ddicttestuser2'@'localhost'; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 @@ -445,7 +445,7 @@ connect (con108,localhost,ddicttestuser1,ddictpass,information_schema); SHOW GRANTS FOR 'ddicttestuser1'@'localhost'; --replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS SHOW processlist; ---replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 ROWS 15 QUERY_ID 17 TID +--replace_column 1 ID 3 HOST_NAME 6 TIME 9 TIME_MS 13 MEMORY 14 MAX_MEMORY 15 ROWS 16 QUERY_ID 18 TID SELECT * FROM information_schema.processlist; --real_sleep 0.3 diff --git a/mysql-test/suite/funcs_1/datadict/processlist_val.inc b/mysql-test/suite/funcs_1/datadict/processlist_val.inc index cfc3c5e751a..24f3eb76a1c 100644 --- a/mysql-test/suite/funcs_1/datadict/processlist_val.inc +++ b/mysql-test/suite/funcs_1/datadict/processlist_val.inc @@ -92,7 +92,7 @@ echo # - INFO must contain the corresponding SHOW/SELECT PROCESSLIST # # 1. Just dump what we get ---replace_column 1 3 6