Needless look-ups for NULL keys in equi-joins

Bug #731069 reported by Igor Babaev
6
This bug affects 1 person
Affects Status Importance Assigned to Milestone
MariaDB
Confirmed
Low
Igor Babaev

Bug Description

If the join condition is of the form <t2.key>=<t1.no_key>, then the server performs no index look-ups for the values of t1,no_key that are NULLS when joining tables t1 and t2.
However if the condition is of the form <t2.key>=<expression>(<t1.no_key>) the look-ups for NULL keys are
performed.

This can be seen from the following example:
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (7), (4), (1), (NULL), (5), (2), (1), (NULL), (9);

MariaDB [test]> EXPLAIN SELECT * FROM t1,t2 WHERE t2.a=t1.a;
+----+-------------+-------+------+---------------+------+---------+-----------+------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+------+---------------+------+---------+-----------+------+-------------+
| 1 | SIMPLE | t1 | ALL | NULL | NULL | NULL | NULL | 5 | Using where |
| 1 | SIMPLE | t2 | ref | idx | idx | 5 | test.t1.a | 2 | Using index |
+----+-------------+-------+------+---------------+------+---------+-----------+------+-------------+
2 rows in set (0.00 sec)

MariaDB [test]> FLUSH STATUS;
Query OK, 0 rows affected (0.00 sec)

MariaDB [test]> SELECT * FROM t1,t2 WHERE t2.a=t1.a;
+------+------+
| a | a |
+------+------+
| 1 | 1 |
| 1 | 1 |
| 2 | 2 |
+------+------+
3 rows in set (0.00 sec)

MariaDB [test]> SHOW STATUS LIKE 'Handler_read%';
+-----------------------+-------+
| Variable_name | Value |
+-----------------------+-------+
| Handler_read_first | 0 |
| Handler_read_key | 2 |
| Handler_read_next | 3 |
| Handler_read_prev | 0 |
| Handler_read_rnd | 0 |
| Handler_read_rnd_next | 6 |
+-----------------------+-------+
6 rows in set (0.00 sec)

MariaDB [test]> EXPLAIN SELECT * FROM t1,t2 WHERE t2.a=t1.a+0;
+----+-------------+-------+------+---------------+------+---------+------+------+--------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+------+---------------+------+---------+------+------+--------------------------+
| 1 | SIMPLE | t1 | ALL | NULL | NULL | NULL | NULL | 5 | |
| 1 | SIMPLE | t2 | ref | idx | idx | 5 | func | 2 | Using where; Using index |
+----+-------------+-------+------+---------------+------+---------+------+------+--------------------------+
2 rows in set (0.00 sec)

MariaDB [test]> FLUSH STATUS;
Query OK, 0 rows affected (0.00 sec)

MariaDB [test]> SELECT * FROM t1,t2 WHERE t2.a=t1.a+0;
+------+------+
| a | a |
+------+------+
| 1 | 1 |
| 1 | 1 |
| 2 | 2 |
+------+------+
3 rows in set (0.00 sec)

MariaDB [test]> SHOW STATUS LIKE 'Handler_read%';
+-----------------------+-------+
| Variable_name | Value |
+-----------------------+-------+
| Handler_read_first | 0 |
| Handler_read_key | 5 |
| Handler_read_next | 9 |
| Handler_read_prev | 0 |
| Handler_read_rnd | 0 |
| Handler_read_rnd_next | 6 |
+-----------------------+-------+
6 rows in set (0.00 sec)

Revision history for this message
Igor Babaev (igorb-seattle) wrote :

This is an optimization problem. That's why I set the importance to 'Low'.

Changed in maria:
milestone: none → 5.3
status: New → Confirmed
importance: Undecided → Low
assignee: nobody → Igor Babaev (igorb-seattle)
description: updated
Changed in maria:
milestone: 5.3 → none
To post a comment you must log in.
This report contains Public information  
Everyone can see this information.

Other bug subscribers

Remote bug watches

Bug watches keep track of this bug in other bug trackers.