Commit 24a0a74f authored by Varun Gupta's avatar Varun Gupta

MDEV-16307: Incorrect results when using BNLH join instead of BNL join with views

In this issue we are using derived_with_keys optimization and we are using these keys to do a hash join which is incorrect.
We cannot create keys for dervied tables whose keyparts have types are of BLOB or TEXT type. TEXT or BLOB  columns can only be
indexed over a specified length.
parent 90cb7212
......@@ -1023,6 +1023,7 @@ INSERT INTO t2 VALUES (NULL),(NULL);
CREATE TABLE t3 (c VARCHAR(1024) CHARACTER SET utf8, d INT) ENGINE=MyISAM;
CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v3 AS SELECT * FROM t3;
INSERT INTO t3 VALUES ('abc',NULL),('def',4);
set @save_join_cache_level= @@join_cache_level;
SET join_cache_level= 8;
explain
SELECT * FROM v1, t2, v3 WHERE a = c AND b = d;
......@@ -1052,4 +1053,36 @@ i
drop procedure pr;
drop view v1;
drop table t1;
set @@join_cache_level= @save_join_cache_level;
#
# MDEV-16307: Incorrect results when using BNLH join instead of BNL join with views
#
CREATE TABLE t1 (c1 text, c2 int);
INSERT INTO t1 VALUES ('a',1), ('c',3), ('g',7), ('d',4), ('c',3);
CREATE TABLE t2 (c1 text, c2 int);
INSERT INTO t2 VALUES ('b',2), ('c',3);
CREATE ALGORITHM=TEMPTABLE VIEW v1 AS SELECT * FROM t1;
explain SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join)
2 DERIVED t1 ALL NULL NULL NULL NULL 5
SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
c1 c2 c1 c2
c 3 c 3
c 3 c 3
set @save_join_cache_level= @@join_cache_level;
set @@join_cache_level=4;
explain SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where
1 PRIMARY <derived2> hash_ALL NULL #hash#$hj 3 test.t2.c1 5 Using where; Using join buffer (flat, BNLH join)
2 DERIVED t1 ALL NULL NULL NULL NULL 5
SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
c1 c2 c1 c2
c 3 c 3
c 3 c 3
drop table t1,t2;
drop view v1;
set @@join_cache_level= @save_join_cache_level;
# end of 5.5
......@@ -880,6 +880,7 @@ CREATE TABLE t3 (c VARCHAR(1024) CHARACTER SET utf8, d INT) ENGINE=MyISAM;
CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v3 AS SELECT * FROM t3;
INSERT INTO t3 VALUES ('abc',NULL),('def',4);
set @save_join_cache_level= @@join_cache_level;
SET join_cache_level= 8;
explain
SELECT * FROM v1, t2, v3 WHERE a = c AND b = d;
......@@ -902,5 +903,25 @@ call pr(2);
drop procedure pr;
drop view v1;
drop table t1;
set @@join_cache_level= @save_join_cache_level;
--echo #
--echo # MDEV-16307: Incorrect results when using BNLH join instead of BNL join with views
--echo #
CREATE TABLE t1 (c1 text, c2 int);
INSERT INTO t1 VALUES ('a',1), ('c',3), ('g',7), ('d',4), ('c',3);
CREATE TABLE t2 (c1 text, c2 int);
INSERT INTO t2 VALUES ('b',2), ('c',3);
CREATE ALGORITHM=TEMPTABLE VIEW v1 AS SELECT * FROM t1;
explain SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
set @save_join_cache_level= @@join_cache_level;
set @@join_cache_level=4;
explain SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
SELECT v1.c1, v1.c2, t2.c1, t2.c2 FROM v1, t2 WHERE v1.c1=t2.c1;
drop table t1,t2;
drop view v1;
set @@join_cache_level= @save_join_cache_level;
--echo # end of 5.5
......@@ -6060,6 +6060,14 @@ void TABLE::create_key_part_by_field(KEY_PART_INFO *key_part_info,
The function checks whether a possible key satisfies the constraints
imposed on the keys of any temporary table.
We need to filter out BLOB columns here, because ref access optimizer creates
KEYUSE objects for equalities for non-key columns for two puproses:
1. To discover possible keys for derived_with_keys optimization
2. To do hash joins
For the purpose of #1, KEYUSE objects are not created for "blob_column=..." .
However, they might be created for #2. In order to catch that case, we filter
them out here.
@return TRUE if the key is valid
@return FALSE otherwise
*/
......@@ -6075,11 +6083,12 @@ bool TABLE::check_tmp_key(uint key, uint key_parts,
{
uint fld_idx= next_field_no(arg);
reg_field= field + fld_idx;
if ((*reg_field)->type() == MYSQL_TYPE_BLOB)
return FALSE;
uint fld_store_len= (uint16) (*reg_field)->key_length();
if ((*reg_field)->real_maybe_null())
fld_store_len+= HA_KEY_NULL_LENGTH;
if ((*reg_field)->type() == MYSQL_TYPE_BLOB ||
(*reg_field)->real_type() == MYSQL_TYPE_VARCHAR ||
if ((*reg_field)->real_type() == MYSQL_TYPE_VARCHAR ||
(*reg_field)->type() == MYSQL_TYPE_GEOMETRY)
fld_store_len+= HA_KEY_BLOB_LENGTH;
key_len+= fld_store_len;
......
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