Commit 441fa005 authored by Igor Babaev's avatar Igor Babaev

Fixed bug mdev-11488.

The patch for bug mdev-10882 tried to fix it by providing an
implementation of the virtual method build_clone for the class
Item_cache. It's turned out that it is not easy provide a valid
implementation for Item_cache::build_clone(). At the same time
if the condition that can be pushed into a materialized view
contains a cached item this item can be substituted for a basic
constant of the same value. In such a way we can avoid building
proper clones for Item_cache objects when constructing pushdown
conditions.
parent e9ada862
......@@ -7766,3 +7766,377 @@ EXPLAIN
}
DROP VIEW v;
DROP TABLE t;
#
# MDEV-11488: pushdown of the predicate with cached value
#
CREATE TABLE t1 (i INT) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1),(3),(2);
CREATE TABLE t2 (j INT, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3),(4);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
3
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 3)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = 3)"
}
}
}
}
}
}
UPDATE t2 SET j = 2 WHERE j = 3;
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
2
DROP TABLE t1,t2;
CREATE TABLE t1 (i FLOAT) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1.5),(3.2),(2.71);
CREATE TABLE t2 (j FLOAT, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3.2),(2.71);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
2.71
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 2.7100000381469727)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = 2.7100000381469727)"
}
}
}
}
}
}
DROP TABLE t1,t2;
CREATE TABLE t1 (i DECIMAL(10,2)) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1.5),(3.21),(2.47);
CREATE TABLE t2 (j DECIMAL(10,2), KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3.21),(4.55);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
3.21
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 3.21)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = 3.21)"
}
}
}
}
}
}
DROP TABLE t1,t2;
CREATE TABLE t1 (i VARCHAR(32)) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('cc'),('aa'),('ddd');
CREATE TABLE t2 (j VARCHAR(16), KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('bbb'),('aa');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
aa
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 'aa')",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = 'aa')"
}
}
}
}
}
}
DROP TABLE t1,t2;
CREATE TABLE t1 (i DATETIME) ENGINE=MyISAM;
INSERT INTO t1 VALUES
('2008-09-27 00:34:58'),('2007-05-28 00:00:00'), ('2009-07-25 09:21:20');
CREATE TABLE t2 (j DATETIME, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES
('2007-05-28 00:00:00'), ('2010-08-25 00:00:00');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
2007-05-28 00:00:00
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 2007-05-28 00:00:00)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = TIMESTAMP'2007-05-28 00:00:00')"
}
}
}
}
}
}
DROP TABLE t1,t2;
CREATE TABLE t1 (i DATE) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('2008-09-27'),('2007-05-28'), ('2009-07-25');
CREATE TABLE t2 (j DATE, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('2007-05-28'), ('2010-08-25');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
2007-05-28
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 2007-05-28)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = TIMESTAMP'2007-05-28 00:00:00')"
}
}
}
}
}
}
DROP TABLE t1,t2;
CREATE TABLE t1 (i TIME) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('00:34:58'),('10:00:02'), ('09:21:20');
CREATE TABLE t2 (j TIME, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('10:00:02'), ('11:00:10');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
i
10:00:02
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<subquery3>",
"access_type": "system",
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 3,
"table": {
"message": "Select tables optimized away"
}
}
}
},
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(sq.i = 10:00:02)",
"materialized": {
"query_block": {
"select_id": 2,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "(t1.i = TIME'10:00:02')"
}
}
}
}
}
}
DROP TABLE t1,t2;
......@@ -1166,4 +1166,110 @@ SELECT * FROM v AS v1, v AS v2
DROP VIEW v;
DROP TABLE t;
--echo #
--echo # MDEV-11488: pushdown of the predicate with cached value
--echo #
CREATE TABLE t1 (i INT) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1),(3),(2);
CREATE TABLE t2 (j INT, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3),(4);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
UPDATE t2 SET j = 2 WHERE j = 3;
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i FLOAT) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1.5),(3.2),(2.71);
CREATE TABLE t2 (j FLOAT, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3.2),(2.71);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i DECIMAL(10,2)) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1.5),(3.21),(2.47);
CREATE TABLE t2 (j DECIMAL(10,2), KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES (3.21),(4.55);
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i VARCHAR(32)) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('cc'),('aa'),('ddd');
CREATE TABLE t2 (j VARCHAR(16), KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('bbb'),('aa');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i DATETIME) ENGINE=MyISAM;
INSERT INTO t1 VALUES
('2008-09-27 00:34:58'),('2007-05-28 00:00:00'), ('2009-07-25 09:21:20');
CREATE TABLE t2 (j DATETIME, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES
('2007-05-28 00:00:00'), ('2010-08-25 00:00:00');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i DATE) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('2008-09-27'),('2007-05-28'), ('2009-07-25');
CREATE TABLE t2 (j DATE, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('2007-05-28'), ('2010-08-25');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
CREATE TABLE t1 (i TIME) ENGINE=MyISAM;
INSERT INTO t1 VALUES ('00:34:58'),('10:00:02'), ('09:21:20');
CREATE TABLE t2 (j TIME, KEY(j)) ENGINE=MyISAM;
INSERT INTO t2 VALUES ('10:00:02'), ('11:00:10');
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
EXPLAIN FORMAT=JSON
SELECT * FROM ( SELECT DISTINCT * FROM t1 ) AS sq
WHERE i IN ( SELECT MIN(j) FROM t2 );
DROP TABLE t1,t2;
......@@ -9406,6 +9406,17 @@ int Item_cache_int::save_in_field(Field *field, bool no_conversions)
}
Item *Item_cache_int::convert_to_basic_const_item(THD *thd)
{
Item *new_item;
DBUG_ASSERT(value_cached || example != 0);
new_item= null_value ?
(Item*) new (thd->mem_root) Item_null(thd) :
(Item*) new (thd->mem_root) Item_int(thd, val_int(), max_length);
return new_item;
}
Item_cache_temporal::Item_cache_temporal(THD *thd,
enum_field_types field_type_arg):
Item_cache_int(thd, field_type_arg)
......@@ -9561,6 +9572,23 @@ Item *Item_cache_temporal::clone_item(THD *thd)
}
Item *Item_cache_temporal::convert_to_basic_const_item(THD *thd)
{
Item *new_item;
DBUG_ASSERT(value_cached || example != 0);
if (null_value)
new_item= (Item*) new (thd->mem_root) Item_null(thd);
else
{
MYSQL_TIME ltime;
unpack_time(val_datetime_packed(), &ltime);
new_item= (Item*) new (thd->mem_root) Item_datetime_literal(thd, &ltime,
decimals);
}
return new_item;
}
bool Item_cache_real::cache_value()
{
if (!example)
......@@ -9609,6 +9637,18 @@ my_decimal *Item_cache_real::val_decimal(my_decimal *decimal_val)
}
Item *Item_cache_real::convert_to_basic_const_item(THD *thd)
{
Item *new_item;
DBUG_ASSERT(value_cached || example != 0);
new_item= null_value ?
(Item*) new (thd->mem_root) Item_null(thd) :
(Item*) new (thd->mem_root) Item_float(thd, val_real(),
decimals);
return new_item;
}
bool Item_cache_decimal::cache_value()
{
if (!example)
......@@ -9660,6 +9700,19 @@ my_decimal *Item_cache_decimal::val_decimal(my_decimal *val)
}
Item *Item_cache_decimal::convert_to_basic_const_item(THD *thd)
{
Item *new_item;
my_decimal decimal_value;
my_decimal *result= val_decimal(&decimal_value);
DBUG_ASSERT(value_cached || example != 0);
new_item= null_value ?
(Item*) new (thd->mem_root) Item_null(thd) :
(Item*) new (thd->mem_root) Item_decimal(thd, result);
return new_item;
}
bool Item_cache_str::cache_value()
{
if (!example)
......@@ -9739,6 +9792,26 @@ bool Item_cache_row::allocate(THD *thd, uint num)
}
Item *Item_cache_str::convert_to_basic_const_item(THD *thd)
{
Item *new_item;
char buff[MAX_FIELD_WIDTH];
String tmp(buff, sizeof(buff), value->charset());
String *result= val_str(&tmp);
DBUG_ASSERT(value_cached || example != 0);
if (null_value)
new_item= (Item*) new (thd->mem_root) Item_null(thd);
else
{
uint length= result->length();
char *tmp_str= thd->strmake(result->ptr(), length);
new_item= new (thd->mem_root) Item_string(thd, tmp_str, length,
result->charset());
}
return new_item;
}
bool Item_cache_row::setup(THD *thd, Item *item)
{
example= item;
......
......@@ -5422,15 +5422,14 @@ class Item_cache: public Item_basic_constant,
example->split_sum_func2(thd, ref_pointer_array, fields, &example, flags);
}
Item *get_example() const { return example; }
Item* build_clone(THD *thd, MEM_ROOT *mem_root)
{
Item_cache *copy= (Item_cache *) get_copy(thd, mem_root);
if (!copy)
return 0;
if (!( copy->example= example->build_clone(thd, mem_root)))
return 0;
return copy;
}
virtual Item *convert_to_basic_const_item(THD *thd) { return 0; };
Item *derived_field_transformer_for_having(THD *thd, uchar *arg)
{ return convert_to_basic_const_item(thd); }
Item *derived_field_transformer_for_where(THD *thd, uchar *arg)
{ return convert_to_basic_const_item(thd); }
Item *derived_grouping_field_transformer_for_where(THD *thd, uchar *arg)
{ return convert_to_basic_const_item(thd); }
};
......@@ -5451,6 +5450,7 @@ class Item_cache_int: public Item_cache
enum Item_result result_type() const { return INT_RESULT; }
bool cache_value();
int save_in_field(Field *field, bool no_conversions);
Item *convert_to_basic_const_item(THD *thd);
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{ return get_item_copy<Item_cache_int>(thd, mem_root, this); }
};
......@@ -5477,6 +5477,7 @@ class Item_cache_temporal: public Item_cache_int
Important when storing packed datetime values.
*/
Item *clone_item(THD *thd);
Item *convert_to_basic_const_item(THD *thd);
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{ return get_item_copy<Item_cache_temporal>(thd, mem_root, this); }
};
......@@ -5495,6 +5496,7 @@ class Item_cache_real: public Item_cache
my_decimal *val_decimal(my_decimal *);
enum Item_result result_type() const { return REAL_RESULT; }
bool cache_value();
Item *convert_to_basic_const_item(THD *thd);
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{ return get_item_copy<Item_cache_real>(thd, mem_root, this); }
};
......@@ -5513,6 +5515,7 @@ class Item_cache_decimal: public Item_cache
my_decimal *val_decimal(my_decimal *);
enum Item_result result_type() const { return DECIMAL_RESULT; }
bool cache_value();
Item *convert_to_basic_const_item(THD *thd);
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{ return get_item_copy<Item_cache_decimal>(thd, mem_root, this); }
};
......@@ -5541,6 +5544,7 @@ class Item_cache_str: public Item_cache
CHARSET_INFO *charset() const { return value->charset(); };
int save_in_field(Field *field, bool no_conversions);
bool cache_value();
Item *convert_to_basic_const_item(THD *thd);
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{ return get_item_copy<Item_cache_str>(thd, mem_root, this); }
};
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment