From aa3578aa8a56b53318860c55c6f1d4163d36b069 Mon Sep 17 00:00:00 2001 From: Rex Johnston Date: Mon, 23 Jun 2025 15:05:44 +1100 Subject: [PATCH] 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 --- mysql-test/main/derived_split_innodb.result | 35 +++++++++++++++++ mysql-test/main/derived_split_innodb.test | 43 +++++++++++++++++++++ sql/opt_split.cc | 9 +---- 3 files changed, 79 insertions(+), 8 deletions(-) diff --git a/mysql-test/main/derived_split_innodb.result b/mysql-test/main/derived_split_innodb.result index 327f3c247c1..fc8f6551d49 100644 --- a/mysql-test/main/derived_split_innodb.result +++ b/mysql-test/main/derived_split_innodb.result @@ -963,4 +963,39 @@ cnt 6 DROP TABLE t1; # End of 10.4 tests +# +# MDEV-37057 Wrong result with LATERAL DERIVED +# +CREATE TABLE t1 ( +a int NOT NULL, +b int default null, +amount decimal DEFAULT NULL, +KEY t1_IDX (a,b) USING BTREE +) ENGINE=INNODB; +CREATE TABLE t2 ( +a int NOT NULL, +b int default null, +name varchar(50) DEFAULT NULL, +KEY t2_IDX (a,b) USING BTREE +) ENGINE=INNODB; +INSERT INTO t1 VALUES +(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000), +(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000); +INSERT INTO t2 VALUES +(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL), +(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL); +# Must use Split-Materialized: +explain $query; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 range t2_IDX t2_IDX 4 NULL 1 Using index condition +1 PRIMARY ref key0 key0 10 test.t2.a,test.t2.b 1 Using where +2 LATERAL DERIVED t1 ref t1_IDX t1_IDX 9 test.t2.a,test.t2.b 1 +$query; +a b name total_amt +1 NULL A 10 +# Compare with correct result: +set statement optimizer_switch='split_materialized=off' for $query; +a b name total_amt +1 NULL A 10 +DROP TABLE t1,t2; SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent; diff --git a/mysql-test/main/derived_split_innodb.test b/mysql-test/main/derived_split_innodb.test index f0498834254..b5a985a0453 100644 --- a/mysql-test/main/derived_split_innodb.test +++ b/mysql-test/main/derived_split_innodb.test @@ -561,4 +561,47 @@ DROP TABLE t1; --echo # End of 10.4 tests +--echo # +--echo # MDEV-37057 Wrong result with LATERAL DERIVED +--echo # + +CREATE TABLE t1 ( + a int NOT NULL, + b int default null, + amount decimal DEFAULT NULL, + KEY t1_IDX (a,b) USING BTREE +) ENGINE=INNODB; + +CREATE TABLE t2 ( + a int NOT NULL, + b int default null, + name varchar(50) DEFAULT NULL, + KEY t2_IDX (a,b) USING BTREE +) ENGINE=INNODB; + +INSERT INTO t1 VALUES +(1, NULL, 10.0000), (2, 2, 20.0000), (3, 3, 30.0000), (4, 4, 40.0000), +(5, 5, NULL), (6, 6, NULL), (7, 7, 70.0000), (8, 8, 80.0000); + +INSERT INTO t2 VALUES +(1, NULL, 'A'), (2,2, 'B'), (3,3, 'C'), (4,4, 'D'), (5,5, NULL), (6,6, NULL), +(7,7, 'E'), (8,8, 'F'), (9,9, 'G'), (10,10,'H'), (11,11, NULL), (12,12, NULL); + +let $query= +SELECT t2.a,t2.b,t2.name,t.total_amt FROM t2 +LEFT JOIN +( + SELECT a, b, sum(amount) total_amt FROM t1 GROUP BY a, b +) AS t ON t2.a=t.a and t2.b<=>t.b +WHERE t2.a < 2; + +--echo # Must use Split-Materialized: +evalp explain $query; +evalp $query; +--echo # Compare with correct result: +evalp set statement optimizer_switch='split_materialized=off' for $query; + +DROP TABLE t1,t2; + +# End of 11.4 tests; SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent; diff --git a/sql/opt_split.cc b/sql/opt_split.cc index 627572ac17a..1fc69b65714 100644 --- a/sql/opt_split.cc +++ b/sql/opt_split.cc @@ -626,14 +626,7 @@ void TABLE::add_splitting_info_for_key_field(KEY_FIELD *key_field) added_key_field->level= 0; added_key_field->optimize= KEY_OPTIMIZE_EQ; added_key_field->eq_func= true; - - 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; - + added_key_field->null_rejecting= key_field->null_rejecting; added_key_field->cond_guard= NULL; added_key_field->sj_pred_no= UINT_MAX; return;