Bug #118870 Constant conditions in SQL with derived views are not passed.
Submitted: 21 Aug 2:22 Modified: 21 Aug 2:33
Reporter: SONGHUA ZHENG Email Updates:
Status: Closed Impact on me:
None 
Category:MySQL Server: Optimizer Severity:S3 (Non-critical)
Version:8.0.43 MySQL Community Server - GPL OS:Linux (Rocky Linux release 8.8 (Green Obsidian))
Assigned to: CPU Architecture:Any
Tags: optimizer_switch, transitive predicate

[21 Aug 2:22] SONGHUA ZHENG
Description:
in the mysql the Constant conditions in SQL with derived views are not passed.

How to repeat:
root@localhost:employees>create table c1(id int ,n varchar(10) ) ;
Query OK, 0 rows affected (0.16 sec)

root@localhost:employees>create table c2(id int ,n varchar(10) ) ;
Query OK, 0 rows affected (0.12 sec)

root@localhost:employees>create index idx_c1 on c1(id) ;
Query OK, 0 rows affected (0.10 sec)
Records: 0  Duplicates: 0  Warnings: 0

root@localhost:employees>create index idx_c2 on c2(id) ;

root@localhost:employees>insert into a1 values(1,'a1'),(2,'a2'),(3,'a3');
Query OK, 3 rows affected (0.02 sec)
Records: 3  Duplicates: 0  Warnings: 0

root@localhost:employees>insert into a2 values(1,'a1'),(2,'a2'),(3,'a3');
Query OK, 3 rows affected (0.06 sec)
Records: 3  Duplicates: 0  Warnings: 0

root@localhost:employees>desc  select * from c1 d join  c2  e on d.id = e.id where d.id=1 ;
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key    | key_len | ref   | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
|  1 | SIMPLE      | d     | NULL       | ref  | idx_c1        | idx_c1 | 4       | const |    1 |   100.00 | NULL  |
|  1 | SIMPLE      | e     | NULL       | ref  | idx_c2        | idx_c2 | 4       | const |    1 |   100.00 | NULL  |
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
2 rows in set, 1 warning (0.01 sec)

root@localhost:employees>show warnings \G
*************************** 1. row ***************************
  Level: Note
   Code: 1003
Message: /* select#1 */ select `employees`.`d`.`id` AS `id`,`employees`.`d`.`n` AS `n`,`employees`.`e`.`id` AS `id`,`employees`.`e`.`n` AS `n` from `employees`.`c1` `d` join `employees`.`c2` `e` where ((`employees`.`d`.`id` = 1) and (`employees`.`e`.`id` = 1))
1 row in set (0.00 sec)

root@localhost:employees>desc  select * from c1 d join  c2  e on d.id = e.id where e.id=1 ;
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key    | key_len | ref   | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
|  1 | SIMPLE      | d     | NULL       | ref  | idx_c1        | idx_c1 | 4       | const |    1 |   100.00 | NULL  |
|  1 | SIMPLE      | e     | NULL       | ref  | idx_c2        | idx_c2 | 4       | const |    1 |   100.00 | NULL  |
+----+-------------+-------+------------+------+---------------+--------+---------+-------+------+----------+-------+
2 rows in set, 1 warning (0.00 sec)

root@localhost:employees>show warnings \G
*************************** 1. row ***************************
  Level: Note
   Code: 1003
Message: /* select#1 */ select `employees`.`d`.`id` AS `id`,`employees`.`d`.`n` AS `n`,`employees`.`e`.`id` AS `id`,`employees`.`e`.`n` AS `n` from `employees`.`c1` `d` join `employees`.`c2` `e` where ((`employees`.`d`.`id` = 1) and (`employees`.`e`.`id` = 1))
1 row in set (0.01 sec)

###################################

root@localhost:employees>desc select * from c1 d join ( select * from c2 e union all select * from  c2 e1 ) e on d.id = e.id where d.id=1 ;
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
| id | select_type | table      | partitions | type | possible_keys | key         | key_len | ref   | rows | filtered | Extra |
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
|  1 | PRIMARY     | d          | NULL       | ref  | idx_c1        | idx_c1      | 4       | const |    1 |   100.00 | NULL  |
|  1 | PRIMARY     | <derived2> | NULL       | ref  | <auto_key0>   | <auto_key0> | 4       | const |    1 |   100.00 | NULL  |
|  2 | DERIVED     | e          | NULL       | ALL  | NULL          | NULL        | NULL    | NULL  |    3 |   100.00 | NULL  |
|  3 | UNION       | e1         | NULL       | ALL  | NULL          | NULL        | NULL    | NULL  |    3 |   100.00 | NULL  |
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
4 rows in set, 1 warning (0.00 sec)

root@localhost:employees>show warnings \G
*************************** 1. row ***************************
  Level: Note
   Code: 1003
Message: /* select#1 */ select `employees`.`d`.`id` AS `id`,`employees`.`d`.`n` AS `n`,`e`.`id` AS `id`,`e`.`n` AS `n` from `employees`.`c1` `d` join (/* select#2 */ select `employees`.`e`.`id` AS `id`,`employees`.`e`.`n` AS `n` from `employees`.`c2` `e` union all /* select#3 */ select `employees`.`e1`.`id` AS `id`,`employees`.`e1`.`n` AS `n` from `employees`.`c2` `e1`) `e` where ((`employees`.`d`.`id` = 1) and (`e`.`id` = 1))
1 row in set (0.00 sec)

root@localhost:employees>desc select * from c1 d join ( select * from c2 e union all select * from  c2 e1 ) e on d.id = e.id where e.id=1 ;
+----+-------------+------------+------------+------+---------------+-------------+---------+----------------+------+----------+-------+
| id | select_type | table      | partitions | type | possible_keys | key         | key_len | ref            | rows | filtered | Extra |
+----+-------------+------------+------------+------+---------------+-------------+---------+----------------+------+----------+-------+
|  1 | PRIMARY     | d          | NULL       | ALL  | idx_c1        | NULL        | NULL    | NULL           |    3 |   100.00 | NULL  |
|  1 | PRIMARY     | <derived2> | NULL       | ref  | <auto_key0>   | <auto_key0> | 4       | employees.d.id |    2 |   100.00 | NULL  |
|  2 | DERIVED     | e          | NULL       | ref  | idx_c2        | idx_c2      | 4       | const          |    1 |   100.00 | NULL  |
|  3 | UNION       | e1         | NULL       | ref  | idx_c2        | idx_c2      | 4       | const          |    1 |   100.00 | NULL  |
+----+-------------+------------+------------+------+---------------+-------------+---------+----------------+------+----------+-------+
4 rows in set, 1 warning (0.00 sec)

root@localhost:employees>show warnings \G
*************************** 1. row ***************************
  Level: Note
   Code: 1003
Message: /* select#1 */ select `employees`.`d`.`id` AS `id`,`employees`.`d`.`n` AS `n`,`e`.`id` AS `id`,`e`.`n` AS `n` from `employees`.`c1` `d` join (/* select#2 */ select `employees`.`e`.`id` AS `id`,`employees`.`e`.`n` AS `n` from `employees`.`c2` `e` where (`employees`.`e`.`id` = 1) union all /* select#3 */ select `employees`.`e1`.`id` AS `id`,`employees`.`e1`.`n` AS `n` from `employees`.`c2` `e1` where (`employees`.`e1`.`id` = 1)) `e` where (`e`.`id` = `employees`.`d`.`id`)
1 row in set (0.00 sec)
[21 Aug 2:25] SONGHUA ZHENG
i wanted to 
root@localhost:employees>desc select * from c1 d join ( select * from c2 e union all select * from  c2 e1 ) e on d.id = e.id where e.id=1 and d.id=1 ;
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
| id | select_type | table      | partitions | type | possible_keys | key         | key_len | ref   | rows | filtered | Extra |
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
|  1 | PRIMARY     | d          | NULL       | ref  | idx_c1        | idx_c1      | 4       | const |    1 |   100.00 | NULL  |
|  1 | PRIMARY     | <derived2> | NULL       | ref  | <auto_key0>   | <auto_key0> | 4       | const |    1 |   100.00 | NULL  |
|  2 | DERIVED     | e          | NULL       | ref  | idx_c2        | idx_c2      | 4       | const |    1 |   100.00 | NULL  |
|  3 | UNION       | e1         | NULL       | ref  | idx_c2        | idx_c2      | 4       | const |    1 |   100.00 | NULL  |
+----+-------------+------------+------------+------+---------------+-------------+---------+-------+------+----------+-------+
4 rows in set, 1 warning (0.01 sec)

root@localhost:employees>show warnings \G
*************************** 1. row ***************************
  Level: Note
   Code: 1003
Message: /* select#1 */ select `employees`.`d`.`id` AS `id`,`employees`.`d`.`n` AS `n`,`e`.`id` AS `id`,`e`.`n` AS `n` from `employees`.`c1` `d` join (/* select#2 */ select `employees`.`e`.`id` AS `id`,`employees`.`e`.`n` AS `n` from `employees`.`c2` `e` where (`employees`.`e`.`id` = 1) union all /* select#3 */ select `employees`.`e1`.`id` AS `id`,`employees`.`e1`.`n` AS `n` from `employees`.`c2` `e1` where (`employees`.`e1`.`id` = 1)) `e` where ((`employees`.`d`.`id` = 1) and (`e`.`id` = 1))
1 row in set (0.00 sec)
[21 Aug 2:26] SONGHUA ZHENG
root@localhost:employees>\s
--------------
/data/mysql-8.0.43/engn001/masvc01/DXDBD/mysql/bin/mysql  Ver 8.0.43 for Linux on x86_64 (MySQL Community Server - GPL)

Connection id:          8
Current database:       employees
Current user:           root@localhost
SSL:                    Not in use
Current pager:          stdout
Using outfile:          ''
Using delimiter:        ;
Server version:         8.0.43 MySQL Community Server - GPL
Protocol version:       10
Connection:             Localhost via UNIX socket
Server characterset:    utf8mb4
Db     characterset:    utf8mb4
Client characterset:    utf8mb4
Conn.  characterset:    utf8mb4
UNIX socket:            /data/mysql-8.0.43/engn001/masvc01/DXDBD/mysql/mysql.sock
Binary data as:         Hexadecimal
Uptime:                 1 hour 25 min 29 sec

Threads: 1  Questions: 128  Slow queries: 0  Opens: 205  Flush tables: 3  Open tables: 122  Queries per second avg: 0.024