Skip to content

Commit 8edcb9e

Browse files
Ole John Askedahlerlend
authored andcommitted
Bug#29402481 INCORRECT RESULT FROM OUTER JOIN QUERIES
Results from outer joined tables may contain a non-NULL row where a NULL extended row is expected. A regression introduced as part of patch for bug#27808758, eliminated predicate terms from join-conditions as the predicate was incorrectly considered to be 'covered' by another (equal) predicate term joining preceding tables. However, we failed to considder that rows from the preceeding tables could have been NULL-complemented if the preceeding join was an outer join. Thus, by removing the 'duplicated' predicate terms, we got false equality matches on the NULL-complimented rows. This patch adds the missing code for calculating which previous tables which are possibly NULL-extended to reduce_cond_for_table(). Based on the NULL-extended-abilities of the table, we skip the predicate term elimination logic (test_if_ref()) if the resulting row could have been NULL extended at the time of evaluating the predicate. Reviewed by : Roy Lyseng <[email protected]> (cherry picked from commit 385720505f45833324ec8da8e6cf99ff7f2f3feb)
1 parent 330f44e commit 8edcb9e

File tree

5 files changed

+141
-9
lines changed

5 files changed

+141
-9
lines changed

mysql-test/r/join_outer.result

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3306,3 +3306,31 @@ EXECUTE prep_stmt ;
33063306
Warnings:
33073307
Warning 1292 Truncated incorrect DOUBLE value: 'Z'
33083308
DROP TABLE t1,t2;
3309+
#
3310+
# Bug#29402481: INCORRECT RESULT FROM OUTER JOIN QUERIES
3311+
#
3312+
CREATE TABLE t1 (
3313+
pk int primary key auto_increment,
3314+
col_int_unique int unique
3315+
) ENGINE=InnoDB;
3316+
INSERT INTO t1(col_int_unique) values (6),(7);
3317+
CREATE TABLE t2 (
3318+
pk int primary key auto_increment,
3319+
col_int_key int(11) DEFAULT NULL,
3320+
col_int_unique int(11) DEFAULT NULL,
3321+
UNIQUE KEY `ix2` (col_int_key,col_int_unique),
3322+
KEY col_int_key (col_int_key)
3323+
) ENGINE=InnoDB;
3324+
CREATE TABLE t3 (
3325+
pk int NOT NULL
3326+
) ENGINE=InnoDB;
3327+
INSERT INTO t3(pk) values (6),(7);
3328+
SELECT STRAIGHT_JOIN t1.col_int_unique, t2.col_int_key, t3.pk
3329+
FROM
3330+
(t1 LEFT JOIN t2 ON t1.col_int_unique = t2.col_int_key)
3331+
LEFT JOIN t3 ON t3.pk = t1.col_int_unique AND
3332+
t1.col_int_unique = t2.col_int_key;
3333+
col_int_unique col_int_key pk
3334+
6 NULL NULL
3335+
7 NULL NULL
3336+
DROP TABLE t1,t2,t3;

mysql-test/r/join_outer_bka.result

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3307,4 +3307,32 @@ EXECUTE prep_stmt ;
33073307
Warnings:
33083308
Warning 1292 Truncated incorrect DOUBLE value: 'Z'
33093309
DROP TABLE t1,t2;
3310+
#
3311+
# Bug#29402481: INCORRECT RESULT FROM OUTER JOIN QUERIES
3312+
#
3313+
CREATE TABLE t1 (
3314+
pk int primary key auto_increment,
3315+
col_int_unique int unique
3316+
) ENGINE=InnoDB;
3317+
INSERT INTO t1(col_int_unique) values (6),(7);
3318+
CREATE TABLE t2 (
3319+
pk int primary key auto_increment,
3320+
col_int_key int(11) DEFAULT NULL,
3321+
col_int_unique int(11) DEFAULT NULL,
3322+
UNIQUE KEY `ix2` (col_int_key,col_int_unique),
3323+
KEY col_int_key (col_int_key)
3324+
) ENGINE=InnoDB;
3325+
CREATE TABLE t3 (
3326+
pk int NOT NULL
3327+
) ENGINE=InnoDB;
3328+
INSERT INTO t3(pk) values (6),(7);
3329+
SELECT STRAIGHT_JOIN t1.col_int_unique, t2.col_int_key, t3.pk
3330+
FROM
3331+
(t1 LEFT JOIN t2 ON t1.col_int_unique = t2.col_int_key)
3332+
LEFT JOIN t3 ON t3.pk = t1.col_int_unique AND
3333+
t1.col_int_unique = t2.col_int_key;
3334+
col_int_unique col_int_key pk
3335+
6 NULL NULL
3336+
7 NULL NULL
3337+
DROP TABLE t1,t2,t3;
33103338
set optimizer_switch=default;

mysql-test/r/join_outer_bka_nixbnl.result

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3305,4 +3305,32 @@ EXECUTE prep_stmt ;
33053305
Warnings:
33063306
Warning 1292 Truncated incorrect DOUBLE value: 'Z'
33073307
DROP TABLE t1,t2;
3308+
#
3309+
# Bug#29402481: INCORRECT RESULT FROM OUTER JOIN QUERIES
3310+
#
3311+
CREATE TABLE t1 (
3312+
pk int primary key auto_increment,
3313+
col_int_unique int unique
3314+
) ENGINE=InnoDB;
3315+
INSERT INTO t1(col_int_unique) values (6),(7);
3316+
CREATE TABLE t2 (
3317+
pk int primary key auto_increment,
3318+
col_int_key int(11) DEFAULT NULL,
3319+
col_int_unique int(11) DEFAULT NULL,
3320+
UNIQUE KEY `ix2` (col_int_key,col_int_unique),
3321+
KEY col_int_key (col_int_key)
3322+
) ENGINE=InnoDB;
3323+
CREATE TABLE t3 (
3324+
pk int NOT NULL
3325+
) ENGINE=InnoDB;
3326+
INSERT INTO t3(pk) values (6),(7);
3327+
SELECT STRAIGHT_JOIN t1.col_int_unique, t2.col_int_key, t3.pk
3328+
FROM
3329+
(t1 LEFT JOIN t2 ON t1.col_int_unique = t2.col_int_key)
3330+
LEFT JOIN t3 ON t3.pk = t1.col_int_unique AND
3331+
t1.col_int_unique = t2.col_int_key;
3332+
col_int_unique col_int_key pk
3333+
6 NULL NULL
3334+
7 NULL NULL
3335+
DROP TABLE t1,t2,t3;
33083336
set optimizer_switch=default;

mysql-test/t/join_outer.test

Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2300,3 +2300,48 @@ EXECUTE prep_stmt ;
23002300
EXECUTE prep_stmt ;
23012301

23022302
DROP TABLE t1,t2;
2303+
2304+
2305+
--echo #
2306+
--echo # Bug#29402481: INCORRECT RESULT FROM OUTER JOIN QUERIES
2307+
--echo #
2308+
2309+
CREATE TABLE t1 (
2310+
pk int primary key auto_increment,
2311+
col_int_unique int unique
2312+
) ENGINE=InnoDB;
2313+
2314+
INSERT INTO t1(col_int_unique) values (6),(7);
2315+
2316+
CREATE TABLE t2 (
2317+
pk int primary key auto_increment,
2318+
col_int_key int(11) DEFAULT NULL,
2319+
col_int_unique int(11) DEFAULT NULL,
2320+
UNIQUE KEY `ix2` (col_int_key,col_int_unique),
2321+
KEY col_int_key (col_int_key)
2322+
) ENGINE=InnoDB;
2323+
2324+
# t2 intentionally left empty. Insert of values not matching
2325+
# join-cond would have had the same effect.
2326+
2327+
CREATE TABLE t3 (
2328+
pk int NOT NULL
2329+
) ENGINE=InnoDB;
2330+
2331+
INSERT INTO t3(pk) values (6),(7);
2332+
2333+
# Test case check that last predicate term in join condition for t3
2334+
# 't1.col_int_unique = t2.col_int_key', is not eliminated in optimizer
2335+
# by test_if_ref(), even if it is 'covered' by the REF join condition
2336+
# used by t2: t2 rows may be NULL-complimented when t3 join-cond
2337+
# is evaluated, thus it is needed to exclude match on 't2.col_int_key'
2338+
# being NULL.
2339+
2340+
SELECT STRAIGHT_JOIN t1.col_int_unique, t2.col_int_key, t3.pk
2341+
FROM
2342+
(t1 LEFT JOIN t2 ON t1.col_int_unique = t2.col_int_key)
2343+
LEFT JOIN t3 ON t3.pk = t1.col_int_unique AND
2344+
t1.col_int_unique = t2.col_int_key;
2345+
2346+
2347+
DROP TABLE t1,t2,t3;

sql/sql_optimizer.cc

Lines changed: 12 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -8352,19 +8352,13 @@ static Item *reduce_cond_for_table(Item *cond, table_map null_extended) {
83528352
- for the execution phase, all possible execution methods must test
83538353
ref->null_rejecting.
83548354
*/
8355-
if (func->used_tables() & null_extended) {
8356-
/*
8357-
Refering null-extended tables voids the test_if_ref() logic,
8358-
keep predicate.
8359-
*/
8360-
DBUG_RETURN(cond);
8361-
}
8362-
83638355
Item *left_item = func->arguments()[0]->real_item();
83648356
Item *right_item = func->arguments()[1]->real_item();
83658357
if ((left_item->type() == Item::FIELD_ITEM &&
8358+
!(left_item->used_tables() & null_extended) &&
83668359
test_if_ref(down_cast<Item_field *>(left_item), right_item)) ||
83678360
(right_item->type() == Item::FIELD_ITEM &&
8361+
!(right_item->used_tables() & null_extended) &&
83688362
test_if_ref(down_cast<Item_field *>(right_item), left_item))) {
83698363
DBUG_RETURN(nullptr);
83708364
}
@@ -8413,7 +8407,16 @@ bool JOIN::finalize_table_conditions() {
84138407
Opt_trace_object trace_cond(trace);
84148408
trace_cond.add_utf8_table(best_ref[i]->table_ref);
84158409
trace_cond.add("original_table_condition", condition);
8416-
condition = reduce_cond_for_table(condition, table_map(0));
8410+
8411+
/*
8412+
Calculate the set of possibly NULL extended tables when 'condition'
8413+
is evaluated. As it is evaluated on a found row from table, that
8414+
table is subtracted from the nullable tables. Note that a FOUND_MATCH
8415+
trigger is a special case, handled in reduce_cond_for_table().
8416+
*/
8417+
const table_map null_extended =
8418+
select_lex->outer_join & ~best_ref[i]->table_ref->map();
8419+
condition = reduce_cond_for_table(condition, null_extended);
84178420
if (condition != nullptr) condition->update_used_tables();
84188421

84198422
/*

0 commit comments

Comments
 (0)