From 7977a0c86734dd2912c89433048b563232bc5942 Mon Sep 17 00:00:00 2001 From: "igor@rurik.mysql.com" <> Date: Sat, 6 May 2006 23:48:13 -0700 Subject: [PATCH 1/2] Fixed bug #14927. A query with a group by and having clauses could return a wrong result set if the having condition contained a constant conjunct evaluated to FALSE. It happened because the pushdown condition for table with grouping columns lost its constant conjuncts. Pushdown conditions are always built by the function make_cond_for_table that ignores constant conjuncts. This is apparently not correct when constant false conjuncts are present. --- mysql-test/r/having.result | 17 +++++++++++++++++ mysql-test/t/having.test | 16 ++++++++++++++++ sql/sql_lex.cc | 2 ++ sql/sql_lex.h | 1 + sql/sql_prepare.cc | 10 ++++++++-- sql/sql_select.cc | 28 +++++++++++++++++++--------- 6 files changed, 63 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/having.result b/mysql-test/r/having.result index 9730f9f81bf..ccd1f0e61e7 100644 --- a/mysql-test/r/having.result +++ b/mysql-test/r/having.result @@ -141,3 +141,20 @@ SUM(a) 6 4 DROP TABLE t1; +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES (1), (2), (1), (3), (2), (1); +SELECT a FROM t1 GROUP BY a HAVING a > 1; +a +2 +3 +SELECT a FROM t1 GROUP BY a HAVING 1 != 1 AND a > 1; +a +SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; +x a +EXPLAIN SELECT a FROM t1 GROUP BY a HAVING 1 != 1 AND a > 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible HAVING +EXPLAIN SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible HAVING +DROP table t1; diff --git a/mysql-test/t/having.test b/mysql-test/t/having.test index 3dd9ace6a1b..8b39e3bd454 100644 --- a/mysql-test/t/having.test +++ b/mysql-test/t/having.test @@ -135,4 +135,20 @@ SELECT SUM(a) FROM t1 GROUP BY a HAVING SUM(a); DROP TABLE t1; +# +# Bug #14927: HAVING clause containing constant false conjunct +# + +CREATE TABLE t1 (a int); +INSERT INTO t1 VALUES (1), (2), (1), (3), (2), (1); + +SELECT a FROM t1 GROUP BY a HAVING a > 1; +SELECT a FROM t1 GROUP BY a HAVING 1 != 1 AND a > 1; +SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; + +EXPLAIN SELECT a FROM t1 GROUP BY a HAVING 1 != 1 AND a > 1; +EXPLAIN SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; + +DROP table t1; + # End of 4.1 tests diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 16641ad6dd5..7348816ea27 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1074,6 +1074,7 @@ void st_select_lex::init_query() item_list.empty(); join= 0; where= 0; + having= 0; olap= UNSPECIFIED_OLAP_TYPE; having_fix_field= 0; resolve_mode= NOMATTER_MODE; @@ -1081,6 +1082,7 @@ void st_select_lex::init_query() ref_pointer_array= 0; select_n_having_items= 0; prep_where= 0; + prep_having= 0; subquery_in_having= explicit_limit= 0; parsing_place= NO_MATTER; is_item_list_lookup= 0; diff --git a/sql/sql_lex.h b/sql/sql_lex.h index bd79a194122..35f02db6cf9 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -422,6 +422,7 @@ public: char *db, *db1, *table1, *db2, *table2; /* For outer join using .. */ Item *where, *having; /* WHERE & HAVING clauses */ Item *prep_where; /* saved WHERE clause for prepared statement processing */ + Item *prep_having;/* saved HAVING clause for prepared statement processing */ enum olap_type olap; SQL_LIST table_list, group_list; /* FROM & GROUP BY clauses */ List item_list; /* list of fields & expressions */ diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index 741d84eab44..2d9e80df63c 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1667,10 +1667,11 @@ int mysql_stmt_prepare(THD *thd, char *packet, uint packet_length, for (; sl; sl= sl->next_select_in_list()) { /* - Save WHERE clause pointers, because they may be changed + Save WHERE, HAVING clause pointers, because they may be changed during query optimisation. */ sl->prep_where= sl->where; + sl->prep_having= sl->having; /* Switch off a temporary flag that prevents evaluation of subqueries in statement prepare. @@ -1696,13 +1697,18 @@ static void reset_stmt_for_execute(Prepared_statement *stmt) /* remove option which was put by mysql_explain_union() */ sl->options&= ~SELECT_DESCRIBE; /* - Copy WHERE clause pointers to avoid damaging they by optimisation + Copy WHERE, HAVING clause pointers to avoid damaging they by optimisation */ if (sl->prep_where) { sl->where= sl->prep_where->copy_andor_structure(thd); sl->where->cleanup(); } + if (sl->prep_having) + { + sl->having= sl->prep_having->copy_andor_structure(thd); + sl->having->cleanup(); + } DBUG_ASSERT(sl->join == 0); ORDER *order; /* Fix GROUP list */ diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 4995a164226..57fb9738612 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -501,12 +501,24 @@ JOIN::optimize() DBUG_RETURN(1); } - if (cond_value == Item::COND_FALSE || - (!unit->select_limit_cnt && !(select_options & OPTION_FOUND_ROWS))) - { /* Impossible cond */ - zero_result_cause= "Impossible WHERE"; - error= 0; - DBUG_RETURN(0); + { + Item::cond_result having_value; + having= optimize_cond(thd, having, &having_value); + if (thd->net.report_error) + { + error= 1; + DBUG_PRINT("error",("Error from optimize_cond")); + DBUG_RETURN(1); + } + + if (cond_value == Item::COND_FALSE || having_value == Item::COND_FALSE || + (!unit->select_limit_cnt && !(select_options & OPTION_FOUND_ROWS))) + { /* Impossible cond */ + zero_result_cause= having_value == Item::COND_FALSE ? + "Impossible HAVING" : "Impossible WHERE"; + error= 0; + DBUG_RETURN(0); + } } /* Optimize count(*), min() and max() */ @@ -4612,10 +4624,8 @@ optimize_cond(THD *thd, COND *conds, Item::cond_result *cond_value) DBUG_EXECUTE("info", print_where(conds, "after remove");); } else - { *cond_value= Item::COND_TRUE; - select->prep_where= 0; - } + DBUG_RETURN(conds); } From b70efcacec451e659878e40787e10af40436dc5d Mon Sep 17 00:00:00 2001 From: "igor@rurik.mysql.com" <> Date: Sun, 7 May 2006 16:14:43 -0700 Subject: [PATCH 2/2] Post-merge fixes. --- mysql-test/r/rpl_user_variables.result | 59 +++++++++++++------------- sql/sql_lex.cc | 2 +- sql/sql_prepare.cc | 27 ++++++------ 3 files changed, 46 insertions(+), 42 deletions(-) diff --git a/mysql-test/r/rpl_user_variables.result b/mysql-test/r/rpl_user_variables.result index 8af2c3e0b22..45618688a33 100644 --- a/mysql-test/r/rpl_user_variables.result +++ b/mysql-test/r/rpl_user_variables.result @@ -76,35 +76,36 @@ abcn1n2 NULL NULL NULL -show binlog events from 141; -Log_name Pos Event_type Server_id Orig_log_pos Info -slave-bin.000001 141 User var 2 141 @`i1`=12345678901234 -slave-bin.000001 184 User var 2 184 @`i2`=-12345678901234 -slave-bin.000001 227 User var 2 227 @`i3`=0 -slave-bin.000001 270 User var 2 270 @`i4`=-1 -slave-bin.000001 313 Query 1 313 use `test`; insert into t1 values (@i1), (@i2), (@i3), (@i4) -slave-bin.000001 396 User var 2 396 @`r1`=12.5 -slave-bin.000001 439 User var 2 439 @`r2`=-12.5 -slave-bin.000001 482 Query 1 482 use `test`; insert into t1 values (@r1), (@r2) -slave-bin.000001 551 User var 2 551 @`s1`=_latin1 0x5468697320697320612074657374 COLLATE latin1_swedish_ci -slave-bin.000001 600 User var 2 600 @`s2`=_latin1 "" COLLATE latin1_swedish_ci -slave-bin.000001 635 User var 2 635 @`s3`=_latin1 0x61626327646566 COLLATE latin1_swedish_ci -slave-bin.000001 677 User var 2 677 @`s4`=_latin1 0x6162635C646566 COLLATE latin1_swedish_ci -slave-bin.000001 719 User var 2 719 @`s5`=_latin1 0x61626327646566 COLLATE latin1_swedish_ci -slave-bin.000001 761 Query 1 761 use `test`; insert into t1 values (@s1), (@s2), (@s3), (@s4), (@s5) -slave-bin.000001 851 User var 2 851 @`n1`=NULL -slave-bin.000001 877 Query 1 877 use `test`; insert into t1 values (@n1) -slave-bin.000001 939 User var 2 939 @`n2`=NULL -slave-bin.000001 965 Query 1 965 use `test`; insert into t1 values (@n2) -slave-bin.000001 1027 Query 1 1027 use `test`; insert into t1 values (@a:=0), (@a:=@a+1), (@a:=@a+1) -slave-bin.000001 1115 User var 2 1115 @`a`=2 -slave-bin.000001 1157 Query 1 1157 use `test`; insert into t1 values (@a+(@b:=@a+1)) -slave-bin.000001 1229 User var 2 1229 @`q`=_latin1 0x616263 COLLATE latin1_swedish_ci -slave-bin.000001 1266 Query 1 1266 use `test`; insert t1 values (@q), (@q:=concat(@q, 'n1')), (@q:=concat(@q, 'n2')) -slave-bin.000001 1370 User var 2 1370 @`a`=5 -slave-bin.000001 1412 Query 1 1412 use `test`; insert into t1 values (@a),(@a) -slave-bin.000001 1478 User var 2 1478 @`a`=NULL -slave-bin.000001 1503 Query 1 1503 use `test`; insert into t1 values (@a),(@a),(@a*5) +show binlog events from 98; +Log_name Pos Event_type Server_id End_log_pos Info +slave-bin.000001 # Query 1 # use `test`; create table t1(n char(30)) +slave-bin.000001 # User var 2 # @`i1`=12345678901234 +slave-bin.000001 # User var 2 # @`i2`=-12345678901234 +slave-bin.000001 # User var 2 # @`i3`=0 +slave-bin.000001 # User var 2 # @`i4`=-1 +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@i1), (@i2), (@i3), (@i4) +slave-bin.000001 # User var 2 # @`r1`=12.5 +slave-bin.000001 # User var 2 # @`r2`=-12.5 +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@r1), (@r2) +slave-bin.000001 # User var 2 # @`s1`=_latin1 0x5468697320697320612074657374 COLLATE latin1_swedish_ci +slave-bin.000001 # User var 2 # @`s2`=_latin1 "" COLLATE latin1_swedish_ci +slave-bin.000001 # User var 2 # @`s3`=_latin1 0x61626327646566 COLLATE latin1_swedish_ci +slave-bin.000001 # User var 2 # @`s4`=_latin1 0x6162635C646566 COLLATE latin1_swedish_ci +slave-bin.000001 # User var 2 # @`s5`=_latin1 0x61626327646566 COLLATE latin1_swedish_ci +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@s1), (@s2), (@s3), (@s4), (@s5) +slave-bin.000001 # User var 2 # @`n1`=NULL +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@n1) +slave-bin.000001 # User var 2 # @`n2`=NULL +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@n2) +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@a:=0), (@a:=@a+1), (@a:=@a+1) +slave-bin.000001 # User var 2 # @`a`=2 +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@a+(@b:=@a+1)) +slave-bin.000001 # User var 2 # @`q`=_latin1 0x616263 COLLATE latin1_swedish_ci +slave-bin.000001 # Query 1 # use `test`; insert t1 values (@q), (@q:=concat(@q, 'n1')), (@q:=concat(@q, 'n2')) +slave-bin.000001 # User var 2 # @`a`=5 +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@a),(@a) +slave-bin.000001 # User var 2 # @`a`=NULL +slave-bin.000001 # Query 1 # use `test`; insert into t1 values (@a),(@a),(@a*5) insert into t1 select * FROM (select @var1 union select @var2) AS t2; drop table t1; stop slave; diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 927be007ba2..c4c72910265 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1145,7 +1145,7 @@ void st_select_lex::init_query() cond_count= with_wild= 0; conds_processed_with_permanent_arena= 0; ref_pointer_array= 0; - select_n_having_items= 0;} + select_n_having_items= 0; subquery_in_having= explicit_limit= 0; is_item_list_lookup= 0; first_execution= 1; diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index d615b6528e2..103a0b9e54e 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1965,6 +1965,7 @@ static const char *get_dynamic_sql_string(LEX *lex, uint *query_len) memcpy(query_str, var_value->ptr(), var_value->length()); query_str[len]= '\0'; // Safety (mostly for debug) *query_len= len; + } else { query_str= lex->prepared_stmt_code.str; @@ -2084,19 +2085,20 @@ void reinit_stmt_before_use(THD *thd, LEX *lex) sl->exclude_from_table_unique_test= FALSE; /* - Copy WHERE, HAVING clause pointers to avoid damaging them by optimisation + Copy WHERE, HAVING clause pointers to avoid damaging them + by optimisation */ - if (sl->prep_where) - { - sl->where= sl->prep_where->copy_andor_structure(thd); - sl->where->cleanup(); - } - if (sl->prep_having) - { - sl->having= sl->prep_having->copy_andor_structure(thd); - sl->having->cleanup(); - } - DBUG_ASSERT(sl->join == 0); + if (sl->prep_where) + { + sl->where= sl->prep_where->copy_andor_structure(thd); + sl->where->cleanup(); + } + if (sl->prep_having) + { + sl->having= sl->prep_having->copy_andor_structure(thd); + sl->having->cleanup(); + } + DBUG_ASSERT(sl->join == 0); ORDER *order; /* Fix GROUP list */ for (order= (ORDER *)sl->group_list.first; order; order= order->next) @@ -2104,6 +2106,7 @@ void reinit_stmt_before_use(THD *thd, LEX *lex) /* Fix ORDER list */ for (order= (ORDER *)sl->order_list.first; order; order= order->next) order->item= &order->item_ptr; + } { SELECT_LEX_UNIT *unit= sl->master_unit(); unit->unclean();