Skip to content

Commit ec495bf

Browse files
MDEV-36215: Avoid wrong result due to table elimination
There was a Wrong result due to Table Elimination when 'unique_col IS NULL' condition is supplied in the left-join query. An index on an unique_col was created for the table, and it is being used in the plan. As the query was a left join, no fields from the right table were projected. The right table was getting wrongly eliminated although multiple rows from the right could be matched to a single row from the left with the condition `unique_col IS NULL'. This PR addresses the problem by including an additional check before eliminating a table in check_equality() function of opt_table_elimination.cc
1 parent 4f7faa4 commit ec495bf

File tree

3 files changed

+105
-0
lines changed

3 files changed

+105
-0
lines changed

mysql-test/main/table_elim.result

Lines changed: 57 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -362,6 +362,7 @@ id select_type table type possible_keys key key_len ref rows Extra
362362
explain select t1.a from t1 left join t3 on t3.pk1=t1.a and t3.pk2 IS NULL;
363363
id select_type table type possible_keys key key_len ref rows Extra
364364
1 SIMPLE t1 ALL NULL NULL NULL NULL 4
365+
1 SIMPLE t3 ref pk1 pk1 10 test.t1.a,const 2 Using where; Using index
365366
drop table t1,t2,t3;
366367
#
367368
# Multi-equality tests
@@ -1031,3 +1032,59 @@ DROP VIEW v;
10311032
#
10321033
# End of 10.10 tests
10331034
#
1035+
#
1036+
# MDEV-36215: Table elimination wrongly done
1037+
#
1038+
CREATE TABLE t1(null_col INT, notnull_col INT NOT NULL);
1039+
CREATE TABLE t2(unique_col INT, UNIQUE(unique_col));
1040+
INSERT INTO t1 VALUES (1,100), (NULL, 101);
1041+
INSERT INTO t2 VALUES (NULL), (NULL);
1042+
# Test with 'unique_col IS NULL'
1043+
# Here, table t2 should not be eliminated:
1044+
explain
1045+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
1046+
id select_type table type possible_keys key key_len ref rows Extra
1047+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2
1048+
1 SIMPLE t2 ref unique_col unique_col 5 const 2 Using where; Using index
1049+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
1050+
null_col
1051+
1
1052+
1
1053+
NULL
1054+
NULL
1055+
# Check without table elimination:
1056+
set statement optimizer_switch='table_elimination=off' for
1057+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
1058+
null_col
1059+
1
1060+
1
1061+
NULL
1062+
NULL
1063+
# Test with 'unique_col <=> nullable_col'
1064+
# t2 must not be eliminated:
1065+
explain
1066+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
1067+
id select_type table type possible_keys key key_len ref rows Extra
1068+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2
1069+
1 SIMPLE t2 ref unique_col unique_col 5 test.t1.null_col 2 Using where; Using index
1070+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
1071+
null_col
1072+
1
1073+
NULL
1074+
NULL
1075+
# Check without table elimination:
1076+
set statement optimizer_switch='table_elimination=off' for
1077+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
1078+
null_col
1079+
1
1080+
NULL
1081+
NULL
1082+
# Table t2 will be eliminated:
1083+
explain
1084+
select t1.null_col from t1 left join t2 on (t2.unique_col<=>t1.notnull_col);
1085+
id select_type table type possible_keys key key_len ref rows Extra
1086+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2
1087+
DROP TABLE t1, t2;
1088+
#
1089+
# End of 10.11 tests
1090+
#

mysql-test/main/table_elim.test

Lines changed: 41 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -799,3 +799,44 @@ DROP VIEW v;
799799
--echo #
800800
--echo # End of 10.10 tests
801801
--echo #
802+
803+
--echo #
804+
--echo # MDEV-36215: Table elimination wrongly done
805+
--echo #
806+
807+
CREATE TABLE t1(null_col INT, notnull_col INT NOT NULL);
808+
CREATE TABLE t2(unique_col INT, UNIQUE(unique_col));
809+
INSERT INTO t1 VALUES (1,100), (NULL, 101);
810+
INSERT INTO t2 VALUES (NULL), (NULL);
811+
812+
813+
--echo # Test with 'unique_col IS NULL'
814+
--echo # Here, table t2 should not be eliminated:
815+
explain
816+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
817+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
818+
819+
--echo # Check without table elimination:
820+
set statement optimizer_switch='table_elimination=off' for
821+
select t1.null_col from t1 left join t2 on (t2.unique_col is null);
822+
823+
--echo # Test with 'unique_col <=> nullable_col'
824+
--echo # t2 must not be eliminated:
825+
explain
826+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
827+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
828+
829+
--echo # Check without table elimination:
830+
set statement optimizer_switch='table_elimination=off' for
831+
select t1.null_col from t1 left join t2 on t1.null_col<=>t2.unique_col;
832+
833+
--echo # Table t2 will be eliminated:
834+
explain
835+
select t1.null_col from t1 left join t2 on (t2.unique_col<=>t1.notnull_col);
836+
837+
838+
DROP TABLE t1, t2;
839+
840+
--echo #
841+
--echo # End of 10.11 tests
842+
--echo #

sql/opt_table_elimination.cc

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1596,6 +1596,13 @@ void check_equality(Dep_analysis_context *ctx, Dep_module_expr **eq_mod,
15961596
if (field->can_optimize_outer_join_table_elimination(cond, right) !=
15971597
Data_type_compatibility::OK)
15981598
return;
1599+
/*
1600+
UNIQUE indexes over nullable columns may have duplicate NULL values.
1601+
This means, a condition like "field IS NULL" or "field <=> right_expr"
1602+
may match multiple rows. Dis-qualify such conditions.
1603+
*/
1604+
if (field->real_maybe_null() && right->maybe_null())
1605+
return;
15991606
Dep_value_field *field_val;
16001607
if ((field_val= ctx->get_field_value(field)))
16011608
add_module_expr(ctx, eq_mod, and_level, field_val, right, NULL);

0 commit comments

Comments
 (0)