Skip to content

Commit 60ebf3f

Browse files
MDEV-37407 Wrong result with LATERAL DERIVED
This is backported from MDEV-37057 for MariaDB 10.11 When populating the structure spl_opt_info for a TABLE, and evaluating a key_field for inclusion in spl_opt_info->added_key_fields, the null_rejecting attribute may be incorrectly set. Originally, this attribute was assumed to be TRUE, then it was changed Item *real= key_field->val->real_item(); if ((real->type() == Item::FIELD_ITEM) && ((Item_field*)real)->field->maybe_null()) added_key_field->null_rejecting= true; else added_key_field->null_rejecting= false; which also incorrectly assumed that the added key field depended on whether the field was able to set to null. The correct setting for this attribute is simply to pass it through from the key being evaluated. The result of an incorrect value is, in this test case, incorrect equality conditions being pushed into our (lateral) derived table, excluding rows that might legitimately contain NULL and thus returning a wrong result. Reviewed by Dave Gosselin (dave.gosselin@mariadb.com), PR#4236
1 parent dfb22d9 commit 60ebf3f

File tree

3 files changed

+78
-8
lines changed

3 files changed

+78
-8
lines changed

mysql-test/main/derived_split_innodb.result

Lines changed: 35 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -967,5 +967,40 @@ id select_type table type possible_keys key key_len ref rows Extra
967967
2 DERIVED t10 index grp_id grp_id 5 NULL 10000 Using index; Using temporary; Using filesort
968968
drop table t1,t2, t10;
969969
drop view v1;
970+
#
971+
# MDEV-37407 Wrong result with LATERAL DERIVED
972+
#
973+
CREATE TABLE t1 (
974+
a int NOT NULL,
975+
b int default null,
976+
amount decimal DEFAULT NULL,
977+
KEY t1_IDX (a,b) USING BTREE
978+
) ENGINE=INNODB;
979+
CREATE TABLE t2 (
980+
a int NOT NULL,
981+
b int default null,
982+
name varchar(50) DEFAULT NULL,
983+
KEY t2_IDX (a,b) USING BTREE
984+
) ENGINE=INNODB;
985+
INSERT INTO t1 VALUES
986+
(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000),
987+
(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000);
988+
INSERT INTO t2 VALUES
989+
(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL),
990+
(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL);
991+
# Must use Split-Materialized:
992+
explain $query;
993+
id select_type table type possible_keys key key_len ref rows Extra
994+
1 PRIMARY t2 range t2_IDX t2_IDX 4 NULL 1 Using index condition
995+
1 PRIMARY <derived2> ref key0 key0 10 test.t2.a,test.t2.b 2 Using where
996+
2 LATERAL DERIVED t1 ref t1_IDX t1_IDX 9 test.t2.a,test.t2.b 1
997+
$query;
998+
a b name total_amt
999+
1 NULL A 10
1000+
# Compare with correct result:
1001+
set statement optimizer_switch='split_materialized=off' for $query;
1002+
a b name total_amt
1003+
1 NULL A 10
1004+
DROP TABLE t1,t2;
9701005
# End of 10.11 tests
9711006
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

mysql-test/main/derived_split_innodb.test

Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -578,5 +578,47 @@ where
578578
drop table t1,t2, t10;
579579
drop view v1;
580580

581+
--echo #
582+
--echo # MDEV-37407 Wrong result with LATERAL DERIVED
583+
--echo #
584+
585+
CREATE TABLE t1 (
586+
a int NOT NULL,
587+
b int default null,
588+
amount decimal DEFAULT NULL,
589+
KEY t1_IDX (a,b) USING BTREE
590+
) ENGINE=INNODB;
591+
592+
CREATE TABLE t2 (
593+
a int NOT NULL,
594+
b int default null,
595+
name varchar(50) DEFAULT NULL,
596+
KEY t2_IDX (a,b) USING BTREE
597+
) ENGINE=INNODB;
598+
599+
INSERT INTO t1 VALUES
600+
(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000),
601+
(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000);
602+
603+
INSERT INTO t2 VALUES
604+
(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL),
605+
(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL);
606+
607+
let $query=
608+
SELECT t2.a,t2.b,t2.name,t.total_amt FROM t2
609+
LEFT JOIN
610+
(
611+
SELECT a, b, sum(amount) total_amt FROM t1 GROUP BY a, b
612+
) AS t ON t2.a=t.a and t2.b<=>t.b
613+
WHERE t2.a < 2;
614+
615+
--echo # Must use Split-Materialized:
616+
evalp explain $query;
617+
evalp $query;
618+
--echo # Compare with correct result:
619+
evalp set statement optimizer_switch='split_materialized=off' for $query;
620+
621+
DROP TABLE t1,t2;
622+
581623
--echo # End of 10.11 tests
582624
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

sql/opt_split.cc

Lines changed: 1 addition & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -630,14 +630,7 @@ void TABLE::add_splitting_info_for_key_field(KEY_FIELD *key_field)
630630
added_key_field->level= 0;
631631
added_key_field->optimize= KEY_OPTIMIZE_EQ;
632632
added_key_field->eq_func= true;
633-
634-
Item *real= key_field->val->real_item();
635-
if ((real->type() == Item::FIELD_ITEM) &&
636-
((Item_field*)real)->field->maybe_null())
637-
added_key_field->null_rejecting= true;
638-
else
639-
added_key_field->null_rejecting= false;
640-
633+
added_key_field->null_rejecting= key_field->null_rejecting;
641634
added_key_field->cond_guard= NULL;
642635
added_key_field->sj_pred_no= UINT_MAX;
643636
return;

0 commit comments

Comments
 (0)