Skip to content

Commit

Permalink
MDEV-21184 Assertion `used_tables_cache == 0' failed in Item_func::fi…
Browse files Browse the repository at this point in the history
…x_fields

           with condition_pushdown_from_having

This bug could manifest itself for queries with GROUP BY and HAVING clauses
when the HAVING clause was a conjunctive condition that depended
exclusively on grouping fields and at least one conjunct contained an
equality of the form fld=sq where fld is a grouping field and sq is a
constant subquery.
In this case the optimizer tries to perform a pushdown of the HAVING
condition into WHERE. To construct the pushable condition the optimizer
first transforms all multiple equalities in HAVING into simple equalities.
This has to be done for a proper processing of the pushed conditions
in WHERE. The multiple equalities at all AND/OR levels must be converted
to simple equalities because any multiple equality may refer to a multiple
equality at the upper level.
Before this patch the conversion was performed like this:
  multiple_equality(x,f1,...,fn) => x=f1 and ... and x=fn.
When an equality item for x=fi was constructed both the items for x and fi
were cloned. If x happened to be a constant subquery that could not be
cloned the conversion failed. If the conversions of multiple equalities
previously performed had succeeded then the whole condition became in an
inconsistent state that could cause different failures.
The solution provided by the patch is:
1. to use a different conversion rule if x is a constant
  multiple_equality(x,f1,...,fn) => f1=x and f2=f1 and ... and fn=f1
2. not to clone x if it's a constant.
Such conversions cannot fail and besides the result of the conversion
preserves the equivalence of f1,...,fn that can be used for other
optimizations.
This patch also made sure that expensive predicates are not pushed from
HAVING to WHERE.
  • Loading branch information
igorbabaev committed Jan 15, 2020
1 parent 6a8a4c1 commit 1c97cd3
Show file tree
Hide file tree
Showing 8 changed files with 280 additions and 58 deletions.
8 changes: 4 additions & 4 deletions mysql-test/main/derived_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -8937,13 +8937,13 @@ EXPLAIN
"materialized": {
"query_block": {
"select_id": 2,
"having_condition": "t1.b = 1 and max_c > 37 and max_c > 30",
"having_condition": "max_c > 37 and max_c > 30",
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "t1.a = 1"
"attached_condition": "t1.a = 1 and t1.b = 1"
}
}
}
Expand Down Expand Up @@ -9012,13 +9012,13 @@ EXPLAIN
"materialized": {
"query_block": {
"select_id": 2,
"having_condition": "t1.b = 1 and max_c > 37 and max_c > 30",
"having_condition": "max_c > 37 and max_c > 30",
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "t1.a = 1 and t1.d = 1"
"attached_condition": "t1.a = 1 and t1.b = 1 and t1.d = 1"
}
}
}
Expand Down
148 changes: 148 additions & 0 deletions mysql-test/main/having_cond_pushdown.result
Original file line number Diff line number Diff line change
Expand Up @@ -4776,3 +4776,151 @@ WHERE t1.a = 3 AND (t1.a < 2 AND t1.b > 3) GROUP BY t1.a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
DROP TABLE t1;
#
# MDEV-21184: Constant subquery in condition movable to WHERE
#
CREATE TABLE t1(a int, b int);
INSERT INTO t1 VALUES
(1,10), (2,20), (1,11), (1,15), (2,20), (1,10), (2,21);
CREATE TABLE t2 (c INT);
INSERT INTO t2 VALUES (2),(3);
EXPLAIN FORMAT=JSON SELECT a FROM t1 GROUP BY a HAVING a = 8 OR a = ( SELECT MIN(c) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"filesort": {
"sort_key": "t1.a",
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a = 8 or t1.a = (subquery#2)"
},
"subqueries": [
{
"query_block": {
"select_id": 2,
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 2,
"filtered": 100
}
}
}
]
}
}
}
}
SELECT a FROM t1 GROUP BY a HAVING a = 8 OR a = ( SELECT MIN(c) FROM t2 );
a
2
EXPLAIN FORMAT=JSON SELECT a FROM t1 GROUP BY a,b
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and b < 20;
EXPLAIN
{
"query_block": {
"select_id": 1,
"filesort": {
"sort_key": "t1.a, t1.b",
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "(t1.a = 8 or t1.a = (subquery#2)) and t1.b < 20"
},
"subqueries": [
{
"query_block": {
"select_id": 2,
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 2,
"filtered": 100
}
}
}
]
}
}
}
}
SELECT a FROM t1 GROUP BY a,b
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and b < 20;
a
EXPLAIN FORMAT=JSON SELECT a FROM t1 GROUP BY a
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and SUM(b) > 20;
EXPLAIN
{
"query_block": {
"select_id": 1,
"having_condition": "sum(t1.b) > 20",
"filesort": {
"sort_key": "t1.a",
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a = 8 or t1.a = (subquery#2)"
},
"subqueries": [
{
"query_block": {
"select_id": 2,
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 2,
"filtered": 100
}
}
}
]
}
}
}
}
SELECT a FROM t1 GROUP BY a
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and SUM(b) > 20;
a
2
EXPLAIN FORMAT=JSON SELECT a FROM t1 GROUP BY a HAVING a = ( SELECT MIN(c) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 7,
"filtered": 100,
"attached_condition": "t1.a = (subquery#2)"
},
"subqueries": [
{
"query_block": {
"select_id": 2,
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 2,
"filtered": 100
}
}
}
]
}
}
SELECT a FROM t1 GROUP BY a HAVING a = ( SELECT MIN(c) FROM t2 );
a
2
DROP TABLE t1,t2;
39 changes: 39 additions & 0 deletions mysql-test/main/having_cond_pushdown.test
Original file line number Diff line number Diff line change
Expand Up @@ -1401,3 +1401,42 @@ EXPLAIN SELECT t1.a,MAX(t1.b),t1.c FROM t1
WHERE t1.a = 3 AND (t1.a < 2 AND t1.b > 3) GROUP BY t1.a;

DROP TABLE t1;

--echo #
--echo # MDEV-21184: Constant subquery in condition movable to WHERE
--echo #

CREATE TABLE t1(a int, b int);
INSERT INTO t1 VALUES
(1,10), (2,20), (1,11), (1,15), (2,20), (1,10), (2,21);

CREATE TABLE t2 (c INT);
INSERT INTO t2 VALUES (2),(3);

let $q=
SELECT a FROM t1 GROUP BY a HAVING a = 8 OR a = ( SELECT MIN(c) FROM t2 );

eval EXPLAIN FORMAT=JSON $q;
eval $q;

let $q=
SELECT a FROM t1 GROUP BY a,b
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and b < 20;

eval EXPLAIN FORMAT=JSON $q;
eval $q;

let $q=
SELECT a FROM t1 GROUP BY a
HAVING ( a = 8 OR a = ( SELECT MIN(c) FROM t2 ) ) and SUM(b) > 20;

eval EXPLAIN FORMAT=JSON $q;
eval $q;

let $q=
SELECT a FROM t1 GROUP BY a HAVING a = ( SELECT MIN(c) FROM t2 );

eval EXPLAIN FORMAT=JSON $q;
eval $q;

DROP TABLE t1,t2;
14 changes: 13 additions & 1 deletion sql/item.cc
Original file line number Diff line number Diff line change
Expand Up @@ -7353,7 +7353,7 @@ Item *Item::build_pushable_cond(THD *thd,
List<Item> equalities;
Item *new_cond= NULL;
if (((Item_equal *)this)->create_pushable_equalities(thd, &equalities,
checker, arg) ||
checker, arg, true) ||
(equalities.elements == 0))
return 0;

Expand Down Expand Up @@ -10555,3 +10555,15 @@ void Item::register_in(THD *thd)
next= thd->free_list;
thd->free_list= this;
}


bool Item::cleanup_excluding_immutables_processor (void *arg)
{
if (!(get_extraction_flag() == IMMUTABLE_FL))
return cleanup_processor(arg);
else
{
clear_extraction_flag();
return false;
}
}
7 changes: 5 additions & 2 deletions sql/item.h
Original file line number Diff line number Diff line change
Expand Up @@ -152,8 +152,10 @@ bool mark_unsupported_function(const char *w1, const char *w2,
#define NO_EXTRACTION_FL (1 << 6)
#define FULL_EXTRACTION_FL (1 << 7)
#define DELETION_FL (1 << 8)
#define SUBSTITUTION_FL (1 << 9)
#define EXTRACTION_MASK (NO_EXTRACTION_FL | FULL_EXTRACTION_FL | DELETION_FL)
#define IMMUTABLE_FL (1 << 9)
#define SUBSTITUTION_FL (1 << 10)
#define EXTRACTION_MASK \
(NO_EXTRACTION_FL | FULL_EXTRACTION_FL | DELETION_FL | IMMUTABLE_FL)

extern const char *item_empty_name;

Expand Down Expand Up @@ -1867,6 +1869,7 @@ class Item: public Value_source,
virtual bool cleanup_processor(void *arg);
virtual bool cleanup_excluding_fields_processor (void *arg)
{ return cleanup_processor(arg); }
bool cleanup_excluding_immutables_processor (void *arg);
virtual bool cleanup_excluding_const_fields_processor (void *arg)
{ return cleanup_processor(arg); }
virtual bool collect_item_field_processor(void *arg) { return 0; }
Expand Down
Loading

0 comments on commit 1c97cd3

Please sign in to comment.