Bug #52784 Non optimal execution plan when using "NULL-safe not equal" on partitioned table
Submitted: 13 Apr 2010 14:02 Modified: 13 Apr 2010 14:37
Reporter: Christian Sauer Email Updates:
Status: Verified Impact on me:
None 
Category:MySQL Server: Optimizer Severity:S3 (Non-critical)
Version:5.1.43, 5.6.99-m4 OS:Any
Assigned to: CPU Architecture:Any
Tags: NULL-safe NOT equal, partitions

[13 Apr 2010 14:02] Christian Sauer
Description:
When using "NULL-safe not equal" comparisons on partitioned tables, all partitions are being searched - even though MySQL knows better when using a normal "not equal" comparison.

How to repeat:
CREATE TABLE t1 ( a INT NOT NULL ) PARTITION BY LIST ( a ) ( PARTITION p0 VALUES IN (0), PARTITION p1 VALUES IN (1), PARTITION p2 VALUES IN (2) );

EXPLAIN PARTITIONS SELECT * FROM t1 WHERE NOT a <=> 0;
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key  | key_len | ref  | rows | Extra       |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
|  1 | SIMPLE      | t1    | p0,p1,p2   | ALL  | NULL          | NULL | NULL    | NULL |    3 | Using where |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+

-- Non optimal execution plan, searching all partitions.

EXPLAIN PARTITIONS SELECT * FROM t1 WHERE NOT a = 0;
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key  | key_len | ref  | rows | Extra       |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
|  1 | SIMPLE      | t1    | p1,p2      | ALL  | NULL          | NULL | NULL    | NULL |    3 | Using where |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+

-- Now the plan is much better.
[13 Apr 2010 14:40] Valeriy Kravchuk
Verified just as described (also on mysql-next-mr):

openxs@ubuntu:/home2/openxs/dbs/next-mr$ bin/mysql --no-defaults -uroot test
Reading table information for completion of table and column names
You can turn off this feature to get a quicker startup with -A

Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.6.99-m4-debug Source distribution

Copyright (c) 2000, 2010, Oracle and/or its affiliates. All rights reserved.
This software comes with ABSOLUTELY NO WARRANTY. This is free software,
and you are welcome to modify and redistribute it under the GPL v2 license

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql> CREATE TABLE t1 ( a INT NOT NULL ) PARTITION BY LIST ( a ) ( PARTITION p0 VALUES IN (0),
    -> PARTITION p1 VALUES IN (1), PARTITION p2 VALUES IN (2) );
Query OK, 0 rows affected (0.04 sec)

mysql> insert into t1 values(1), (2), (NULL);
Query OK, 3 rows affected, 1 warning (0.01 sec)
Records: 3  Duplicates: 0  Warnings: 1

mysql> show warnings\G
*************************** 1. row ***************************
  Level: Warning
   Code: 1048
Message: Column 'a' cannot be null
1 row in set (0.00 sec)

So, server "knows" that NULL value is NOT allowed for this column, but still:

mysql> EXPLAIN PARTITIONS SELECT * FROM t1 WHERE NOT a <=> 0;
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key  | key_len | ref  | rows | Extra       |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
|  1 | SIMPLE      | t1    | p0,p1,p2   | ALL  | NULL          | NULL | NULL    | NULL |    5 | Using where |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+-------------+
1 row in set (0.00 sec)

uses all partitions. While semantically the same (in this case) condition:

mysql> EXPLAIN PARTITIONS SELECT * FROM t1 WHERE NOT a <> 0;
+----+-------------+-------+------------+--------+---------------+------+---------+------+------+-------+
| id | select_type | table | partitions | type   | possible_keys | key  | key_len | ref  | rows | Extra |
+----+-------------+-------+------------+--------+---------------+------+---------+------+------+-------+
|  1 | SIMPLE      | t1    | p0         | system | NULL          | NULL | NULL    | NULL |    1 |       |
+----+-------------+-------+------------+--------+---------------+------+---------+------+------+-------+
1 row in set (0.00 sec)

allows partition prunning to happen. I see nothing in the manual that explains why partition prunning should NOT work here, so I consider this a bug (not just a feature request).