Skip to content

Commit aa3578a

Browse files
MDEV-37057 Wrong result with LATERAL DERIVED
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. Approved by Sergei Petrunia, PR#4140
1 parent dbeef00 commit aa3578a

File tree

3 files changed

+79
-8
lines changed

3 files changed

+79
-8
lines changed

mysql-test/main/derived_split_innodb.result

Lines changed: 35 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -963,4 +963,39 @@ cnt
963963
6
964964
DROP TABLE t1;
965965
# End of 10.4 tests
966+
#
967+
# MDEV-37057 Wrong result with LATERAL DERIVED
968+
#
969+
CREATE TABLE t1 (
970+
a int NOT NULL,
971+
b int default null,
972+
amount decimal DEFAULT NULL,
973+
KEY t1_IDX (a,b) USING BTREE
974+
) ENGINE=INNODB;
975+
CREATE TABLE t2 (
976+
a int NOT NULL,
977+
b int default null,
978+
name varchar(50) DEFAULT NULL,
979+
KEY t2_IDX (a,b) USING BTREE
980+
) ENGINE=INNODB;
981+
INSERT INTO t1 VALUES
982+
(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000),
983+
(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000);
984+
INSERT INTO t2 VALUES
985+
(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL),
986+
(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL);
987+
# Must use Split-Materialized:
988+
explain $query;
989+
id select_type table type possible_keys key key_len ref rows Extra
990+
1 PRIMARY t2 range t2_IDX t2_IDX 4 NULL 1 Using index condition
991+
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
993+
$query;
994+
a b name total_amt
995+
1 NULL A 10
996+
# Compare with correct result:
997+
set statement optimizer_switch='split_materialized=off' for $query;
998+
a b name total_amt
999+
1 NULL A 10
1000+
DROP TABLE t1,t2;
9661001
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

mysql-test/main/derived_split_innodb.test

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -561,4 +561,47 @@ DROP TABLE t1;
561561

562562
--echo # End of 10.4 tests
563563

564+
--echo #
565+
--echo # MDEV-37057 Wrong result with LATERAL DERIVED
566+
--echo #
567+
568+
CREATE TABLE t1 (
569+
a int NOT NULL,
570+
b int default null,
571+
amount decimal DEFAULT NULL,
572+
KEY t1_IDX (a,b) USING BTREE
573+
) ENGINE=INNODB;
574+
575+
CREATE TABLE t2 (
576+
a int NOT NULL,
577+
b int default null,
578+
name varchar(50) DEFAULT NULL,
579+
KEY t2_IDX (a,b) USING BTREE
580+
) ENGINE=INNODB;
581+
582+
INSERT INTO t1 VALUES
583+
(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000),
584+
(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000);
585+
586+
INSERT INTO t2 VALUES
587+
(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL),
588+
(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL);
589+
590+
let $query=
591+
SELECT t2.a,t2.b,t2.name,t.total_amt FROM t2
592+
LEFT JOIN
593+
(
594+
SELECT a, b, sum(amount) total_amt FROM t1 GROUP BY a, b
595+
) AS t ON t2.a=t.a and t2.b<=>t.b
596+
WHERE t2.a < 2;
597+
598+
--echo # Must use Split-Materialized:
599+
evalp explain $query;
600+
evalp $query;
601+
--echo # Compare with correct result:
602+
evalp set statement optimizer_switch='split_materialized=off' for $query;
603+
604+
DROP TABLE t1,t2;
605+
606+
# End of 11.4 tests;
564607
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
@@ -626,14 +626,7 @@ void TABLE::add_splitting_info_for_key_field(KEY_FIELD *key_field)
626626
added_key_field->level= 0;
627627
added_key_field->optimize= KEY_OPTIMIZE_EQ;
628628
added_key_field->eq_func= true;
629-
630-
Item *real= key_field->val->real_item();
631-
if ((real->type() == Item::FIELD_ITEM) &&
632-
((Item_field*)real)->field->maybe_null())
633-
added_key_field->null_rejecting= true;
634-
else
635-
added_key_field->null_rejecting= false;
636-
629+
added_key_field->null_rejecting= key_field->null_rejecting;
637630
added_key_field->cond_guard= NULL;
638631
added_key_field->sj_pred_no= UINT_MAX;
639632
return;

0 commit comments

Comments
 (0)