Skip to content

Commit 645191a

Browse files
committed
MDEV-19778 Wrong Result on Left Outer Join with Subquery right on true
and WHERE filter afterwards This patch complements the patch fixing the bug MDEV-6892. The latter properly handled queries that used mergeable views returning constant columns as inner tables of outer joins and whose where clause contained predicates referring to these columns if the predicates of happened not to be equality predicates. Otherwise the server still could return wrong result sets for such queries. Besides the fix for MDEV-6892 prevented some possible conversions of outer joins to inner joins for such queries. This patch corrected the function check_simple_equality() to handle properly conjunctive equalities of the where clause that refer to the constant columns of mergeable views used as inner tables of an outer join. The patch also changed the code of Item_direct_view_ref::not_null_tables(). This change allowed to take into account predicates containing references to constant columns of mergeable views when converting outer joins into inner joins.
1 parent 15065a2 commit 645191a

File tree

10 files changed

+126
-6
lines changed

10 files changed

+126
-6
lines changed

mysql-test/r/derived.result

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -578,6 +578,15 @@ select x.id, message from (select id from t1) x left join
578578
(select id, 1 as message from t2) y on x.id=y.id
579579
where coalesce(message,0) <> 0;
580580
id message
581+
explain extended
582+
select x.id, message from (select id from t1) x left join
583+
(select id, 1 as message from t2) y on x.id=y.id
584+
where message <> 0;
585+
id select_type table type possible_keys key key_len ref rows filtered Extra
586+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
587+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
588+
Warnings:
589+
Note 1003 select `test`.`t1`.`id` AS `id`,1 AS `message` from `test`.`t1` join `test`.`t2` where (`test`.`t2`.`id` = `test`.`t1`.`id`)
581590
drop table t1,t2;
582591
#
583592
# MDEV-7827: Assertion `!table || (!table->read_set ||

mysql-test/r/derived_view.result

Lines changed: 57 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3041,3 +3041,60 @@ id select_type table type possible_keys key key_len ref rows Extra
30413041
7 DERIVED p9 ALL NULL NULL NULL NULL 550 Using where; Using join buffer (incremental, BNL join)
30423042
7 DERIVED p10 ALL NULL NULL NULL NULL 550 Using where; Using join buffer (incremental, BNL join)
30433043
DROP TABLE t1, t2;
3044+
#
3045+
# MDEV-19778: equality condition for mergeable view returning constants
3046+
# in its columns and used as inner table of outer join
3047+
#
3048+
create table t1 (pk int, a int);
3049+
insert into t1 values (1,7), (2,3), (3,2), (4,3);
3050+
create table t2 (b int);
3051+
insert into t2 values (5), (1), (NULL), (3);
3052+
create table t3 (c int);
3053+
insert into t3 values (1), (8);
3054+
create view v1 as
3055+
select 3 as d, t2.b from t2;
3056+
select * from t1 left join v1 on t1.pk <= 2 where t1.a=v1.d;
3057+
pk a d b
3058+
2 3 3 5
3059+
2 3 3 1
3060+
2 3 3 NULL
3061+
2 3 3 3
3062+
explain extended select * from t1 left join v1 on t1.pk <= 2 where t1.a=v1.d;
3063+
id select_type table type possible_keys key key_len ref rows filtered Extra
3064+
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 100.00 Using where
3065+
1 SIMPLE t2 ALL NULL NULL NULL NULL 4 100.00 Using join buffer (flat, BNL join)
3066+
Warnings:
3067+
Note 1003 select `test`.`t1`.`pk` AS `pk`,`test`.`t1`.`a` AS `a`,3 AS `d`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where ((`test`.`t1`.`a` = 3) and (`test`.`t1`.`pk` <= 2))
3068+
select * from t1 left join (select 3 as d, t2.b from t2) dt on t1.pk <= 2
3069+
where t1.a=dt.d;
3070+
pk a d b
3071+
2 3 3 5
3072+
2 3 3 1
3073+
2 3 3 NULL
3074+
2 3 3 3
3075+
explain extended select * from t1 left join (select 3 as d, t2.b from t2) dt on t1.pk <= 2
3076+
where t1.a=dt.d;
3077+
id select_type table type possible_keys key key_len ref rows filtered Extra
3078+
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 100.00 Using where
3079+
1 SIMPLE t2 ALL NULL NULL NULL NULL 4 100.00 Using join buffer (flat, BNL join)
3080+
Warnings:
3081+
Note 1003 select `test`.`t1`.`pk` AS `pk`,`test`.`t1`.`a` AS `a`,3 AS `d`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where ((`test`.`t1`.`a` = 3) and (`test`.`t1`.`pk` <= 2))
3082+
select * from t1 left join (v1,t3) on t1.pk <= 2 where t1.a=v1.d;
3083+
pk a d b c
3084+
2 3 3 5 1
3085+
2 3 3 5 8
3086+
2 3 3 1 1
3087+
2 3 3 1 8
3088+
2 3 3 NULL 1
3089+
2 3 3 NULL 8
3090+
2 3 3 3 1
3091+
2 3 3 3 8
3092+
explain extended select * from t1 left join (v1,t3) on t1.pk <= 2 where t1.a=v1.d;
3093+
id select_type table type possible_keys key key_len ref rows filtered Extra
3094+
1 SIMPLE t3 ALL NULL NULL NULL NULL 2 100.00
3095+
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 100.00 Using where; Using join buffer (flat, BNL join)
3096+
1 SIMPLE t2 ALL NULL NULL NULL NULL 4 100.00 Using join buffer (incremental, BNL join)
3097+
Warnings:
3098+
Note 1003 select `test`.`t1`.`pk` AS `pk`,`test`.`t1`.`a` AS `a`,3 AS `d`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`c` AS `c` from `test`.`t1` join `test`.`t2` join `test`.`t3` where ((`test`.`t1`.`a` = 3) and (`test`.`t1`.`pk` <= 2))
3099+
drop view v1;
3100+
drop table t1,t2,t3;

mysql-test/r/func_group.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1981,6 +1981,7 @@ NULL
19811981
Warnings:
19821982
Warning 1292 Truncated incorrect INTEGER value: 'j'
19831983
Warning 1292 Truncated incorrect INTEGER value: 'j'
1984+
Warning 1292 Truncated incorrect INTEGER value: 'j'
19841985

19851986
EXPLAIN
19861987
SELECT MIN(t2.pk)
@@ -1995,6 +1996,7 @@ id select_type table type possible_keys key key_len ref rows Extra
19951996
Warnings:
19961997
Warning 1292 Truncated incorrect INTEGER value: 'j'
19971998
Warning 1292 Truncated incorrect INTEGER value: 'j'
1999+
Warning 1292 Truncated incorrect INTEGER value: 'j'
19982000

19992001
#
20002002
# 2) Test that subquery materialization is setup for query with

mysql-test/r/subselect_cache.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3130,6 +3130,7 @@ WHERE table1 .`col_varchar_key` ) field10
31303130
Warnings:
31313131
Warning 1292 Truncated incorrect DOUBLE value: 'f'
31323132
Warning 1292 Truncated incorrect DOUBLE value: 'f'
3133+
Warning 1292 Truncated incorrect DOUBLE value: 'f'
31333134
SET @@optimizer_switch = 'subquery_cache=on';
31343135
/* cache is on */ SELECT COUNT( DISTINCT table2 .`col_int_key` ) , (
31353136
SELECT SUBQUERY2_t1 .`col_int_key`
@@ -3146,6 +3147,7 @@ WHERE table1 .`col_varchar_key` ) field10
31463147
Warnings:
31473148
Warning 1292 Truncated incorrect DOUBLE value: 'f'
31483149
Warning 1292 Truncated incorrect DOUBLE value: 'f'
3150+
Warning 1292 Truncated incorrect DOUBLE value: 'f'
31493151
drop table t1,t2,t3,t4;
31503152
set @@optimizer_switch= default;
31513153
#launchpad BUG#611625

mysql-test/t/derived.test

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -502,6 +502,10 @@ insert into t2 values(4),(5),(6);
502502
select x.id, message from (select id from t1) x left join
503503
(select id, 1 as message from t2) y on x.id=y.id
504504
where coalesce(message,0) <> 0;
505+
explain extended
506+
select x.id, message from (select id from t1) x left join
507+
(select id, 1 as message from t2) y on x.id=y.id
508+
where message <> 0;
505509
drop table t1,t2;
506510

507511
--echo #

mysql-test/t/derived_view.test

Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2194,3 +2194,37 @@ JOIN
21942194
) gp_20 ON gp_20.id=t2.id ;
21952195

21962196
DROP TABLE t1, t2;
2197+
2198+
--echo #
2199+
--echo # MDEV-19778: equality condition for mergeable view returning constants
2200+
--echo # in its columns and used as inner table of outer join
2201+
--echo #
2202+
2203+
create table t1 (pk int, a int);
2204+
insert into t1 values (1,7), (2,3), (3,2), (4,3);
2205+
create table t2 (b int);
2206+
insert into t2 values (5), (1), (NULL), (3);
2207+
create table t3 (c int);
2208+
insert into t3 values (1), (8);
2209+
2210+
create view v1 as
2211+
select 3 as d, t2.b from t2;
2212+
2213+
let $q=
2214+
select * from t1 left join v1 on t1.pk <= 2 where t1.a=v1.d;
2215+
eval $q;
2216+
eval explain extended $q;
2217+
2218+
let $q=
2219+
select * from t1 left join (select 3 as d, t2.b from t2) dt on t1.pk <= 2
2220+
where t1.a=dt.d;
2221+
eval $q;
2222+
eval explain extended $q;
2223+
2224+
let $q=
2225+
select * from t1 left join (v1,t3) on t1.pk <= 2 where t1.a=v1.d;
2226+
eval $q;
2227+
eval explain extended $q;
2228+
2229+
drop view v1;
2230+
drop table t1,t2,t3;

sql/item.cc

Lines changed: 8 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -9814,11 +9814,14 @@ table_map Item_direct_view_ref::used_tables() const
98149814

98159815
table_map Item_direct_view_ref::not_null_tables() const
98169816
{
9817-
return get_depended_from() ?
9818-
0 :
9819-
((view->is_merged_derived() || view->merged || !view->table) ?
9820-
(*ref)->not_null_tables() :
9821-
view->table->map);
9817+
if (get_depended_from())
9818+
return 0;
9819+
if (!( view->merged || !view->table))
9820+
return view->table->map;
9821+
TABLE *tab= get_null_ref_table();
9822+
if (tab == NO_NULL_TABLE || (*ref)->used_tables())
9823+
return (*ref)->not_null_tables();
9824+
return get_null_ref_table()->map;
98229825
}
98239826

98249827
/*

sql/item.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3382,6 +3382,7 @@ class Item_direct_view_ref :public Item_direct_ref
33823382
void update_used_tables();
33833383
table_map not_null_tables() const;
33843384
bool const_item() const { return used_tables() == 0; }
3385+
TABLE *get_null_ref_table() const { return null_ref_table; }
33853386
bool walk(Item_processor processor, bool walk_subquery, uchar *arg)
33863387
{
33873388
return (*ref)->walk(processor, walk_subquery, arg) ||

sql/item_func.cc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -226,6 +226,7 @@ Item_func::fix_fields(THD *thd, Item **ref)
226226
with_field= with_field || item->with_field;
227227
used_tables_cache|= item->used_tables();
228228
const_item_cache&= item->const_item();
229+
not_null_tables_cache|= item->not_null_tables();
229230
with_subselect|= item->has_subquery();
230231
}
231232
}

sql/sql_select.cc

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1030,7 +1030,6 @@ JOIN::optimize()
10301030
DBUG_RETURN(1); /* purecov: inspected */
10311031
/* dump_TABLE_LIST_graph(select_lex, select_lex->leaf_tables); */
10321032
select_lex->update_used_tables();
1033-
10341033
}
10351034

10361035
eval_select_list_used_tables();
@@ -1092,6 +1091,8 @@ JOIN::optimize()
10921091

10931092
sel->where= conds;
10941093

1094+
select_lex->update_used_tables();
1095+
10951096
if (arena)
10961097
thd->restore_active_arena(arena, &backup);
10971098
}
@@ -11763,13 +11764,19 @@ static bool check_simple_equality(Item *left_item, Item *right_item,
1176311764
{
1176411765
if (((Item_ref*)left_item)->get_depended_from())
1176511766
return FALSE;
11767+
if (((Item_direct_view_ref*)left_item)->get_null_ref_table() !=
11768+
NO_NULL_TABLE && !left_item->real_item()->used_tables())
11769+
return FALSE;
1176611770
left_item= left_item->real_item();
1176711771
}
1176811772
if (right_item->type() == Item::REF_ITEM &&
1176911773
((Item_ref*)right_item)->ref_type() == Item_ref::VIEW_REF)
1177011774
{
1177111775
if (((Item_ref*)right_item)->get_depended_from())
1177211776
return FALSE;
11777+
if (((Item_direct_view_ref*)right_item)->get_null_ref_table() !=
11778+
NO_NULL_TABLE && !right_item->real_item()->used_tables())
11779+
return FALSE;
1177311780
right_item= right_item->real_item();
1177411781
}
1177511782
if (left_item->type() == Item::FIELD_ITEM &&

0 commit comments

Comments
 (0)