Skip to content

Commit a7d8c97

Browse files
MDEV-37230 Incorrect handling of NULL join conditions when using split-materialized
During the optimization phase, when determining whether or not to materialize a derived table all at once or in groups (split materialization), all key equalities that reference the derived table have their cond Items pushed into JOIN::spl_opt_info->inj_cond_list. From there they are filtered (tables in join prefix) and injected into the JOIN conditions (in JOIN::inject_best_splitting_cond()), where they might be removed because they are involved ref access and they aren't needed. These pushed items conditions were always Item_func_eq, whether or or the key usage specifies null safe equality (<=>) or not. The fix is to create an Item_func_equal condition when the key equality is specified using <=>. approved by Sergei Petrunia (sergey@mariadb.com) PR#4198
1 parent aa3578a commit a7d8c97

File tree

3 files changed

+309
-3
lines changed

3 files changed

+309
-3
lines changed

mysql-test/main/derived_split_innodb.result

Lines changed: 239 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -989,7 +989,7 @@ explain $query;
989989
id select_type table type possible_keys key key_len ref rows Extra
990990
1 PRIMARY t2 range t2_IDX t2_IDX 4 NULL 1 Using index condition
991991
1 PRIMARY <derived2> ref key0 key0 10 test.t2.a,test.t2.b 1 Using where
992-
2 LATERAL DERIVED t1 ref t1_IDX t1_IDX 9 test.t2.a,test.t2.b 1
992+
2 LATERAL DERIVED t1 ref t1_IDX t1_IDX 9 test.t2.a,test.t2.b 1 Using index condition
993993
$query;
994994
a b name total_amt
995995
1 NULL A 10
@@ -998,4 +998,242 @@ set statement optimizer_switch='split_materialized=off' for $query;
998998
a b name total_amt
999999
1 NULL A 10
10001000
DROP TABLE t1,t2;
1001+
#
1002+
# MDEV-37230 Incorrect handling of NULL join conditions when using
1003+
# split-materialized
1004+
#
1005+
create table t1
1006+
(
1007+
a int not null,
1008+
b int,
1009+
c int,
1010+
d int,
1011+
amount decimal,
1012+
key t1_ix1 (a,b)
1013+
) engine=innodb;
1014+
insert into t1 values (0, NULL, 0, NULL, 10.0000), (1, 1, 1, 1, 10.0000),
1015+
(2, 2, 2, 2, 20.0000), (3, 3, 3, 3, 30.0000), (4, 4, 4, 4, 40.0000),
1016+
(5, 5, 5, 5, NULL), (6, 6, 6, 6, NULL), (7, 7, 7, 7, 70.0000),
1017+
(8, 8, 8, 8, 80.0000);
1018+
create table t2
1019+
(
1020+
a int NOT NULL,
1021+
b int,
1022+
name varchar(50),
1023+
key t2_ix1 (a,b)
1024+
) engine=innodb;
1025+
insert into t2 values (0, NULL, 'a'), (1, NULL, 'A'), (2, 2, 'B'), (3,3, 'C'),
1026+
(4,4, 'D'), (5,5, NULL), (6,6, NULL), (7,7, 'E'), (8,8, 'F'), (9,9, 'G'),
1027+
(10,10,'H'), (11,11, NULL), (12,12, NULL);
1028+
create table t3
1029+
(
1030+
a int not null,
1031+
b int,
1032+
description varchar(50),
1033+
key t3_ix1 (a,b)
1034+
);
1035+
insert into t3 values (1, 1, 'bar'),(2,2,'buz'),(0,NULL, 'gold');
1036+
insert into t3 select seq, seq, 'junk' from seq_3_to_13;
1037+
analyze table t1, t2, t3;
1038+
Table Op Msg_type Msg_text
1039+
test.t1 analyze status Engine-independent statistics collected
1040+
test.t1 analyze status OK
1041+
test.t2 analyze status Engine-independent statistics collected
1042+
test.t2 analyze status OK
1043+
test.t3 analyze status Engine-independent statistics collected
1044+
test.t3 analyze status OK
1045+
set optimizer_switch='default';
1046+
set statement optimizer_switch='split_materialized=on' for explain format=json select * from t1
1047+
join t2 on t1.a = t2.a and t1.b <=> t2.b
1048+
join
1049+
(
1050+
select a, b, description from t3 group by a, b
1051+
) dt on dt.a = t1.a and dt.b <=> t1.b and dt.b <=> t2.b
1052+
where dt.a < 1;
1053+
EXPLAIN
1054+
{
1055+
"query_block": {
1056+
"select_id": 1,
1057+
"cost": "REPLACED",
1058+
"nested_loop": [
1059+
{
1060+
"table": {
1061+
"table_name": "t1",
1062+
"access_type": "range",
1063+
"possible_keys": ["t1_ix1"],
1064+
"key": "t1_ix1",
1065+
"key_length": "4",
1066+
"used_key_parts": ["a"],
1067+
"loops": 1,
1068+
"rows": 1,
1069+
"cost": "REPLACED",
1070+
"filtered": 100,
1071+
"index_condition": "t1.a < 1"
1072+
}
1073+
},
1074+
{
1075+
"table": {
1076+
"table_name": "t2",
1077+
"access_type": "ref",
1078+
"possible_keys": ["t2_ix1"],
1079+
"key": "t2_ix1",
1080+
"key_length": "9",
1081+
"used_key_parts": ["a", "b"],
1082+
"ref": ["test.t1.a", "test.t1.b"],
1083+
"loops": 1,
1084+
"rows": 1,
1085+
"cost": "REPLACED",
1086+
"filtered": 100,
1087+
"index_condition": "t1.b <=> t2.b"
1088+
}
1089+
},
1090+
{
1091+
"table": {
1092+
"table_name": "<derived3>",
1093+
"access_type": "ref",
1094+
"possible_keys": ["key0"],
1095+
"key": "key0",
1096+
"key_length": "9",
1097+
"used_key_parts": ["a", "b"],
1098+
"ref": ["test.t1.a", "test.t1.b"],
1099+
"loops": 1,
1100+
"rows": 1,
1101+
"cost": "REPLACED",
1102+
"filtered": 100,
1103+
"attached_condition": "dt.b <=> t1.b and dt.b <=> t2.b",
1104+
"materialized": {
1105+
"lateral": 1,
1106+
"query_block": {
1107+
"select_id": 3,
1108+
"cost": "REPLACED",
1109+
"nested_loop": [
1110+
{
1111+
"table": {
1112+
"table_name": "t3",
1113+
"access_type": "ref",
1114+
"possible_keys": ["t3_ix1"],
1115+
"key": "t3_ix1",
1116+
"key_length": "9",
1117+
"used_key_parts": ["a", "b"],
1118+
"ref": ["test.t1.a", "test.t1.b"],
1119+
"loops": 1,
1120+
"rows": 1,
1121+
"cost": "REPLACED",
1122+
"filtered": 100,
1123+
"index_condition": "t3.a < 1 and t3.b <=> t1.b and t3.b <=> t2.b and t3.a = t2.a"
1124+
}
1125+
}
1126+
]
1127+
}
1128+
}
1129+
}
1130+
}
1131+
]
1132+
}
1133+
}
1134+
set statement optimizer_switch='split_materialized=on' for select * from t1
1135+
join t2 on t1.a = t2.a and t1.b <=> t2.b
1136+
join
1137+
(
1138+
select a, b, description from t3 group by a, b
1139+
) dt on dt.a = t1.a and dt.b <=> t1.b and dt.b <=> t2.b
1140+
where dt.a < 1;
1141+
a b c d amount a b name a b description
1142+
0 NULL 0 NULL 10 0 NULL a 0 NULL gold
1143+
set statement optimizer_switch='split_materialized=off' for explain format=json select * from t1
1144+
join t2 on t1.a = t2.a and t1.b <=> t2.b
1145+
join
1146+
(
1147+
select a, b, description from t3 group by a, b
1148+
) dt on dt.a = t1.a and dt.b <=> t1.b and dt.b <=> t2.b
1149+
where dt.a < 1;
1150+
EXPLAIN
1151+
{
1152+
"query_block": {
1153+
"select_id": 1,
1154+
"cost": "REPLACED",
1155+
"nested_loop": [
1156+
{
1157+
"table": {
1158+
"table_name": "t1",
1159+
"access_type": "range",
1160+
"possible_keys": ["t1_ix1"],
1161+
"key": "t1_ix1",
1162+
"key_length": "4",
1163+
"used_key_parts": ["a"],
1164+
"loops": 1,
1165+
"rows": 1,
1166+
"cost": "REPLACED",
1167+
"filtered": 100,
1168+
"index_condition": "t1.a < 1"
1169+
}
1170+
},
1171+
{
1172+
"table": {
1173+
"table_name": "t2",
1174+
"access_type": "ref",
1175+
"possible_keys": ["t2_ix1"],
1176+
"key": "t2_ix1",
1177+
"key_length": "9",
1178+
"used_key_parts": ["a", "b"],
1179+
"ref": ["test.t1.a", "test.t1.b"],
1180+
"loops": 1,
1181+
"rows": 1,
1182+
"cost": "REPLACED",
1183+
"filtered": 100,
1184+
"index_condition": "t1.b <=> t2.b"
1185+
}
1186+
},
1187+
{
1188+
"table": {
1189+
"table_name": "<derived3>",
1190+
"access_type": "ref",
1191+
"possible_keys": ["key0"],
1192+
"key": "key0",
1193+
"key_length": "9",
1194+
"used_key_parts": ["a", "b"],
1195+
"ref": ["test.t1.a", "test.t1.b"],
1196+
"loops": 1,
1197+
"rows": 1,
1198+
"cost": "REPLACED",
1199+
"filtered": 100,
1200+
"attached_condition": "dt.b <=> t1.b and dt.b <=> t2.b",
1201+
"materialized": {
1202+
"query_block": {
1203+
"select_id": 3,
1204+
"cost": "REPLACED",
1205+
"nested_loop": [
1206+
{
1207+
"table": {
1208+
"table_name": "t3",
1209+
"access_type": "range",
1210+
"possible_keys": ["t3_ix1"],
1211+
"key": "t3_ix1",
1212+
"key_length": "4",
1213+
"used_key_parts": ["a"],
1214+
"loops": 1,
1215+
"rows": 1,
1216+
"cost": "REPLACED",
1217+
"filtered": 100,
1218+
"index_condition": "t3.a < 1"
1219+
}
1220+
}
1221+
]
1222+
}
1223+
}
1224+
}
1225+
}
1226+
]
1227+
}
1228+
}
1229+
set statement optimizer_switch='split_materialized=off' for select * from t1
1230+
join t2 on t1.a = t2.a and t1.b <=> t2.b
1231+
join
1232+
(
1233+
select a, b, description from t3 group by a, b
1234+
) dt on dt.a = t1.a and dt.b <=> t1.b and dt.b <=> t2.b
1235+
where dt.a < 1;
1236+
a b c d amount a b name a b description
1237+
0 NULL 0 NULL 10 0 NULL a 0 NULL gold
1238+
drop table t1, t2, t3;
10011239
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

mysql-test/main/derived_split_innodb.test

Lines changed: 62 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -603,5 +603,67 @@ evalp set statement optimizer_switch='split_materialized=off' for $query;
603603

604604
DROP TABLE t1,t2;
605605

606+
--echo #
607+
--echo # MDEV-37230 Incorrect handling of NULL join conditions when using
608+
--echo # split-materialized
609+
--echo #
610+
611+
create table t1
612+
(
613+
a int not null,
614+
b int,
615+
c int,
616+
d int,
617+
amount decimal,
618+
key t1_ix1 (a,b)
619+
) engine=innodb;
620+
621+
insert into t1 values (0, NULL, 0, NULL, 10.0000), (1, 1, 1, 1, 10.0000),
622+
(2, 2, 2, 2, 20.0000), (3, 3, 3, 3, 30.0000), (4, 4, 4, 4, 40.0000),
623+
(5, 5, 5, 5, NULL), (6, 6, 6, 6, NULL), (7, 7, 7, 7, 70.0000),
624+
(8, 8, 8, 8, 80.0000);
625+
626+
create table t2
627+
(
628+
a int NOT NULL,
629+
b int,
630+
name varchar(50),
631+
key t2_ix1 (a,b)
632+
) engine=innodb;
633+
634+
insert into t2 values (0, NULL, 'a'), (1, NULL, 'A'), (2, 2, 'B'), (3,3, 'C'),
635+
(4,4, 'D'), (5,5, NULL), (6,6, NULL), (7,7, 'E'), (8,8, 'F'), (9,9, 'G'),
636+
(10,10,'H'), (11,11, NULL), (12,12, NULL);
637+
638+
create table t3
639+
(
640+
a int not null,
641+
b int,
642+
description varchar(50),
643+
key t3_ix1 (a,b)
644+
);
645+
insert into t3 values (1, 1, 'bar'),(2,2,'buz'),(0,NULL, 'gold');
646+
insert into t3 select seq, seq, 'junk' from seq_3_to_13;
647+
648+
let $q=
649+
select * from t1
650+
join t2 on t1.a = t2.a and t1.b <=> t2.b
651+
join
652+
(
653+
select a, b, description from t3 group by a, b
654+
) dt on dt.a = t1.a and dt.b <=> t1.b and dt.b <=> t2.b
655+
where dt.a < 1;
656+
657+
analyze table t1, t2, t3;
658+
set optimizer_switch='default';
659+
--source include/analyze-format.inc
660+
eval set statement optimizer_switch='split_materialized=on' for explain format=json $q;
661+
eval set statement optimizer_switch='split_materialized=on' for $q;
662+
--source include/analyze-format.inc
663+
eval set statement optimizer_switch='split_materialized=off' for explain format=json $q;
664+
eval set statement optimizer_switch='split_materialized=off' for $q;
665+
666+
drop table t1, t2, t3;
667+
606668
# End of 11.4 tests;
607669
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

sql/opt_split.cc

Lines changed: 8 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -605,13 +605,19 @@ void TABLE::add_splitting_info_for_key_field(KEY_FIELD *key_field)
605605
THD *thd= in_use;
606606
Item *left_item= spl_field->producing_item->build_clone(thd);
607607
Item *right_item= key_field->val->build_clone(thd);
608-
Item_func_eq *eq_item= 0;
608+
Item_bool_func *eq_item= 0;
609609
if (left_item && right_item)
610610
{
611611
right_item->walk(&Item::set_fields_as_dependent_processor,
612612
false, join->select_lex);
613613
right_item->update_used_tables();
614-
eq_item= new (thd->mem_root) Item_func_eq(thd, left_item, right_item);
614+
615+
// Item_func::EQUAL_FUNC is null-safe, others can use Item_func_eq()
616+
if (key_field->cond->type() == Item::FUNC_ITEM &&
617+
((Item_func*)key_field->cond)->functype() == Item_func::EQUAL_FUNC)
618+
eq_item= new (thd->mem_root) Item_func_equal(thd, left_item, right_item);
619+
else
620+
eq_item= new (thd->mem_root) Item_func_eq(thd, left_item, right_item);
615621
}
616622
if (!eq_item)
617623
return;

0 commit comments

Comments
 (0)