复制
-- Oracle-- Having 并入 Where(不支持)SQL> SELECT * FROM emp where dept_id=100 HAVING salary > 5000;SELECT * FROM emp where dept_id=100 HAVING salary > 5000 *ERROR at line 1:ORA-00979: not a GROUP BY expression--去除冗余括号SQL> SELECT * FROM emp WHERE ((dept_id=2));--------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 102 | 2856 | 15 (0)| 00:00:01 ||* 1 | TABLE ACCESS FULL| EMP | 102 | 2856 | 15 (0)| 00:00:01 |--------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("DEPT_ID"=2) -- 常量传递(支持)SQL> select * from emp where dept_id=10 and emp_id=dept_id;--------------------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 1 | 28 | 2 (0)| 00:00:01 ||* 1 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 28 | 2 (0)| 00:00:01 ||* 2 | INDEX UNIQUE SCAN | EMP_PK | 1 | | 1 (0)| 00:00:01 |--------------------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("DEPT_ID"=10) 2 - access("EMP_ID"=10) -- 消除死码(支持)SQL> select * from emp where (0>1) or dept_id=10;--------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 98 | 2744 | 15 (0)| 00:00:01 ||* 1 | TABLE ACCESS FULL| EMP | 98 | 2744 | 15 (0)| 00:00:01 |--------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("DEPT_ID"=10) -- 表达式计算(支持)SQL> select * from emp where dept_id=1+2;--------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 107 | 2996 | 15 (0)| 00:00:01 ||* 1 | TABLE ACCESS FULL| EMP | 107 | 2996 | 15 (0)| 00:00:01 |--------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("DEPT_ID"=3) -- 等式变换(不支持)SQL> select * from emp where -dept_id=-10;--------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 100 | 2800 | 15 (0)| 00:00:01 ||* 1 | TABLE ACCESS FULL| EMP | 100 | 2800 | 15 (0)| 00:00:01 |--------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter((-"DEPT_ID")=(-10)) -- 不等式转换(支持)SQL> select * from emp where salary >1100 and salary>2000;----------------------------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |----------------------------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 1 | 28 | 4 (0)| 00:00:01 || 1 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 28 | 4 (0)| 00:00:01 ||* 2 | INDEX RANGE SCAN | IDX_EMP_SALARY | 1 | | 2 (0)| 00:00:01 |----------------------------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 2 - access("SALARY">2000) --谓词传递闭包(支持)SQL> select * from emp where emp_id>dept_id and dept_id>900;----------------------------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |----------------------------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 1 | 28 | 3 (0)| 00:00:01 ||* 1 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 28 | 3 (0)| 00:00:01 ||* 2 | INDEX RANGE SCAN | IDX_EMP_DEPTID | 1 | | 2 (0)| 00:00:01 |----------------------------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("EMP_ID">900 AND "EMP_ID">"DEPT_ID") 2 - access("DEPT_ID">900) -- 等价合取范式(支持)SQL> select * from emp where (0>1) and dept_id=10;---------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |---------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 1 | 28 | 0 (0)| ||* 1 | FILTER | | | | | ||* 2 | TABLE ACCESS FULL| EMP | 98 | 2744 | 15 (0)| 00:00:01 |---------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter(NULL IS NOT NULL) 2 - filter("DEPT_ID"=10) -- AND 操作符交换(不支持)SQL> select * from emp where dept_id+emp_id=1000 and salary>900;--------------------------------------------------------------------------| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |--------------------------------------------------------------------------| 0 | SELECT STATEMENT | | 90 | 2520 | 15 (0)| 00:00:01 ||* 1 | TABLE ACCESS FULL| EMP | 90 | 2520 | 15 (0)| 00:00:01 |--------------------------------------------------------------------------Predicate Information (identified by operation id):--------------------------------------------------- 1 - filter("DEPT_ID"+"EMP_ID"=1000 AND "SALARY">900) -- DM-- Having 并入 Where(不支持)SQL> explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000;explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000;[-4028]:Error in line: 1Invalid having item.
--去除冗余括号(支持)SQL> explain SELECT * FROM emp WHERE ((dept_id=2));1 #NSET2: [1, 250, 163]2 #PRJT2: [1, 250, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 250, 163]; EMP.DEPT_ID = var1 SLCT_PUSHDOWN(TRUE)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP) NEED_SLCT(TRUE); btr_scan(1) -- 常量传递(不支持)SQL> explain select * from emp where dept_id=10 and emp_id=dept_id;1 #NSET2: [1, 1, 163]2 #PRJT2: [1, 1, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 1, 163]; EMP.DEPT_ID = var14 #BLKUP2: [1, 1, 163]; INDEX33555485(EMP)5 #SSEK2: [1, 1, 163]; scan_type(ASC), INDEX33555485(EMP), scan_range[exp_cast(10),exp_cast(10)], is_global(0) -- 消除死码(支持)SQL> explain select * from emp where (0>1) or dept_id=10;1 #NSET2: [1, 250, 163]2 #PRJT2: [1, 250, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 250, 163]; EMP.DEPT_ID = var1 SLCT_PUSHDOWN(TRUE)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP) NEED_SLCT(TRUE); btr_scan(1) -- 表达式计算(支持)SQL> explain select * from emp where dept_id=1+2;1 #NSET2: [1, 250, 163]2 #PRJT2: [1, 250, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 250, 163]; EMP.DEPT_ID = var2 SLCT_PUSHDOWN(TRUE)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP) NEED_SLCT(TRUE); btr_scan(1) -- 等式变换(不支持)SQL> explain select * from emp where -dept_id=-10;1 #NSET2: [1, 250, 163]2 #PRJT2: [1, 250, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 250, 163]; -EMP.DEPT_ID = var2 SLCT_PUSHDOWN(TRUE)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP) NEED_SLCT(TRUE); btr_scan(1) -- 不等式转换(支持)SQL> explain select * from emp where salary >1100 and salary>2000;1 #NSET2: [1, 1, 163]2 #PRJT2: [1, 1, 163]; exp_num(6), is_atom(FALSE)3 #BLKUP2: [1, 1, 163]; IDX_EMP_SALARY(EMP)4 #SSEK2: [1, 1, 163]; scan_type(ASC), IDX_EMP_SALARY(EMP), scan_range(exp_cast(2000),max], is_global(0)
--谓词传递闭包(不支持)SQL> explain select * from emp where emp_id>dept_id and dept_id>900;1 #NSET2: [1, 25, 163]2 #PRJT2: [1, 25, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 25, 163]; (EMP.DEPT_ID > var1 AND EMP.EMP_ID > EMP.DEPT_ID) SLCT_PUSHDOWN(TRUE)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP) NEED_SLCT(TRUE); btr_scan(1) -- 等价合取范式(支持)SQL> explain select * from emp where (0>1) and dept_id=10;1 #NSET2: [1, 1, 163]2 #PRJT2: [1, 1, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 1, 163]; FALSE4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP); btr_scan(1) -- AND 操作符交换(支持)SQL> explain select * from emp where dept_id+emp_id=1000 and salary>900;1 #NSET2: [1, 225, 163]2 #PRJT2: [1, 225, 163]; exp_num(6), is_atom(FALSE)3 #SLCT2: [1, 225, 163]; (EMP.SALARY > var1 AND EMP.DEPT_ID+EMP.EMP_ID = var2)4 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP); btr_scan(1)
-- MySQL
-- Having 并入 Where(未改写)mysql> explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000;+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 10.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.00 sec)
mysql> show warnings;+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (`testdb`.`emp`.`dept_id` = 100) having (`testdb`.`emp`.`salary` > 5000) |+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
--去除冗余括号mysql> explain SELECT * FROM emp WHERE ((dept_id=2));+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 10.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.00 sec)
mysql> show warnings;+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message |+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (`testdb`.`emp`.`dept_id` = 2) |+-------+------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- 常量传递(支持)mysql> explain select * from emp where dept_id=10 and emp_id=dept_id;+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-----------------------------------------------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-----------------------------------------------------+| 1 | SIMPLE | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | Impossible WHERE noticed after reading const tables |+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-----------------------------------------------------+
-- 消除死码(支持)mysql> explain select * from emp where (0>1) or dept_id=10;+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 10.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.00 sec)
mysql> show warnings;+-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (`testdb`.`emp`.`dept_id` = 10) |+-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- 表达式计算(支持)mysql> explain select * from emp where dept_id=1+2;+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 10.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.00 sec)
mysql> show warnings;+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (`testdb`.`emp`.`dept_id` = <cache>((1 + 2))) |+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- 等式变换(不支持)mysql> explain select * from emp where -dept_id=-10;+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 100.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.01 sec)
mysql> show warnings;+-------+------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (-(`testdb`.`emp`.`dept_id`) = <cache>(-(10))) |+-------+------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- 不等式转换(不支持)mysql> explain select * from emp where salary >1100 and salary>2000;+----+-------------+-------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+| 1 | SIMPLE | emp | NULL | range | idx_emp_salary | idx_emp_salary | 5 | NULL | 421 | 100.00 | Using index condition |+----+-------------+-------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+1 row in set, 1 warning (0.01 sec)
mysql> show warnings;+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where ((`testdb`.`emp`.`salary` > 1100) and (`testdb`.`emp`.`salary` > 2000)) |+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
--谓词传递闭包(不支持)mysql> explain select * from emp where emp_id>dept_id and dept_id>900;+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 10117 | 11.11 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.01 sec)
mysql> show warnings;+-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where ((`testdb`.`emp`.`emp_id` > `testdb`.`emp`.`dept_id`) and (`testdb`.`emp`.`dept_id` > 900)) |+-------+------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- 等价合取范式(支持)mysql> explain select * from emp where (0>1) and dept_id=10;+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+| 1 | SIMPLE | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | NULL | Impossible WHERE |+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+------------------+1 row in set, 1 warning (0.00 sec)
mysql> show warnings;+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where false |+-------+------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- AND 操作符交换(支持)mysql> explain select * from emp where dept_id+emp_id=1000 and salary>900;+----+-------------+-------+------------+------+----------------+------+---------+------+-------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+----------------+------+---------+------+-------+----------+-------------+| 1 | SIMPLE | emp | NULL | ALL | idx_emp_salary | NULL | NULL | NULL | 10117 | 88.96 | Using where |+----+-------------+-------+------------+------+----------------+------+---------+------+-------+----------+-------------+1 row in set, 1 warning (0.01 sec)
mysql> show warnings;+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Level | Code | Message |+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+| Note | 1003 | /* select#1 */ select `testdb`.`emp`.`emp_id` AS `emp_id`,`testdb`.`emp`.`dept_id` AS `dept_id`,`testdb`.`emp`.`emp_name` AS `emp_name`,`testdb`.`emp`.`birthday` AS `birthday`,`testdb`.`emp`.`salary` AS `salary` from `testdb`.`emp` where (((`testdb`.`emp`.`dept_id` + `testdb`.`emp`.`emp_id`) = 1000) and (`testdb`.`emp`.`salary` > 900)) |+-------+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
-- KingBase-- Having 并入 Where(不支持)TEST=# explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000;ERROR: column "emp.emp_id" must appear in the GROUP BY clause or be used in an aggregate function
--去除冗余括号TEST=# explain SELECT * FROM emp WHERE ((dept_id=2)); QUERY PLAN-------------------------------------------------------------------------- Gather (cost=1000.00..17401.03 rows=10167 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..15384.33 rows=4236 width=42) Filter: (dept_id = 2::numeric)
-- 常量传递(支持)TEST=# explain select * from emp where dept_id=10 and emp_id=dept_id; QUERY PLAN------------------------------------------------------------------- Index Scan using EMP_PK on emp (cost=0.42..8.45 rows=1 width=42) Index Cond: (emp_id = 10::numeric) Filter: (dept_id = 10::numeric) -- 消除死码(支持)TEST=# explain select * from emp where (0>1) or dept_id=10; QUERY PLAN-------------------------------------------------------------------------- Gather (cost=1000.00..17377.63 rows=9933 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..15384.33 rows=4139 width=42) Filter: (dept_id = 10::numeric)
-- 表达式计算(支持)TEST=# explain select * from emp where dept_id=1+2; QUERY PLAN-------------------------------------------------------------------------- Gather (cost=1000.00..17447.63 rows=10633 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..15384.33 rows=4430 width=42) Filter: (dept_id = 3::numeric)
-- 等式变换(不支持)TEST=# explain select * from emp where -dept_id=-10; QUERY PLAN-------------------------------------------------------------------------- Gather (cost=1000.00..17926.00 rows=5000 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..16426.00 rows=2083 width=42) Filter: ((- dept_id) = -10::numeric)
-- 不等式转换(支持)TEST=# explain select * from emp where salary >1100 and salary>2000; QUERY PLAN--------------------------------------------------------------------------- Index Scan using idx_emp_salary on emp (cost=0.42..8.44 rows=1 width=42) Index Cond: (salary > 2000::double precision)
-- 谓词传递闭包(不支持)TEST=# explain select * from emp where emp_id>dept_id and dept_id>900; QUERY PLAN------------------------------------------------------------------------ Gather (cost=1000.00..17429.00 rows=30 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..16426.00 rows=12 width=42) Filter: ((emp_id > dept_id) AND (dept_id > 900::numeric))
-- 等价合取范式(支持)TEST=# explain select * from emp where (0>1) and dept_id=10; QUERY PLAN------------------------------------------ Result (cost=0.00..0.00 rows=0 width=0) One-Time Filter: false
-- AND 操作符交换(支持)TEST=# explain select * from emp where dept_id+emp_id=1000 and salary>900; QUERY PLAN------------------------------------------------------------------------------------------------- Gather (cost=1000.00..18919.77 rows=4521 width=42) Workers Planned: 2 -> Parallel Seq Scan on emp (cost=0.00..17467.67 rows=1884 width=42) Filter: ((salary > 900::double precision) AND ((dept_id + emp_id) = 1000::numeric)) -- YashanDB-- Having 并入 Where(不支持)SQL> explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000[1:52]YAS-04316 not a single-group group function
--去除冗余括号(支持)SQL> explain SELECT * FROM emp WHERE ((dept_id=2));+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 89| 46( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID" = 2) -- 常量传递(不支持)SQL> explain select * from emp where dept_id=10 and emp_id=dept_id;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 1| 47( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."EMP_ID" = "EMP"."DEPT_ID" AND 10 = "EMP"."DEPT_ID") -- 消除死码(支持)SQL> explain select * from emp where (0>1) or dept_id=10;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 99| 46( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID" = 10) -- 表达式计算(支持)SQL> explain select * from emp where dept_id=1+2;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 114| 46( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID" = 3) -- 等式变换(支持)SQL> explain select * from emp where -dept_id=-10;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 99| 46( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID" = 10) -- 不等式转换(支持)SQL> explain select * from emp where salary >1100 and salary>2000;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | || 1 | TABLE ACCESS BY INDEX ROWID | EMP | TESTUSER | 1| 1( 0)| ||* 2 | INDEX RANGE SCAN | IDX_EMP_SALARY | TESTUSER | 1| 1( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 2 - Predicate : access("EMP"."SALARY" > 2000) --谓词传递闭包(支持)SQL> explain select * from emp where emp_id>dept_id and dept_id>900;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 1| 47( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID" > 900 AND "EMP"."EMP_ID" > 900 AND "EMP"."EMP_ID" > "EMP"."DEPT_ID") -- 等价合取范式(支持)SQL> explain select * from emp where (0>1) and dept_id=10;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | RESULT | | | | 1( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter(FALSE) -- AND 操作符交换(不支持)SQL> explain select * from emp where dept_id+emp_id=1000 and salary>900;+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+| 0 | SELECT STATEMENT | | | | | ||* 1 | TABLE ACCESS FULL | EMP | TESTUSER | 10| 47( 0)| |+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+Operation Information (identified by operation id):--------------------------------------------------- 1 - Predicate : filter("EMP"."DEPT_ID"+"EMP"."EMP_ID" = 1000 AND "EMP"."SALARY" > 900) -- Vastbase-- Having 并入 Where(不支持)vastbase=> explain SELECT * FROM emp where dept_id=100 HAVING salary > 5000;ERROR: column "emp.emp_id" must appear in the GROUP BY clause or be used in an aggregate functionLINE 1: explain SELECT * FROM emp where dept_id=100 HAVING salary > ...
--去除冗余括号(支持)vastbase=> explain SELECT * FROM emp WHERE ((dept_id=2)); QUERY PLAN-------------------------------------------------------- Seq Scan on emp (cost=0.00..243.00 rows=106 width=44) Filter: (dept_id = 2::number)
-- 常量传递(支持)vastbase=> explain select * from emp where dept_id=10 and emp_id=dept_id; QUERY PLAN------------------------------------------------------------------- Index Scan using emp_pk on emp (cost=0.00..8.27 rows=1 width=44) Index Cond: (emp_id = 10::number) Filter: (dept_id = 10::number) -- 消除死码(支持)vastbase=> explain select * from emp where (0>1) or dept_id=10; QUERY PLAN------------------------------------------------------- Seq Scan on emp (cost=0.00..243.00 rows=91 width=44) Filter: (dept_id = 10::number)
-- 表达式计算(支持)vastbase=> explain select * from emp where dept_id=1+2; QUERY PLAN------------------------------------------------------- Seq Scan on emp (cost=0.00..243.00 rows=91 width=44) Filter: (dept_id = 3::number)
-- 等式变换(不支持)vastbase=> explain select * from emp where -dept_id=-10; QUERY PLAN------------------------------------------------------- Seq Scan on emp (cost=0.00..268.00 rows=50 width=44) Filter: ((- dept_id) = (-10)::number)
-- 不等式转换(不支持)vastbase=> explain select * from emp where salary >1100 and salary>2000; QUERY PLAN----------------------------------------------------------------------------------------- Index Scan using idx_emp_salary on emp (cost=0.00..8.27 rows=1 width=44) Index Cond: ((salary > 1100::double precision) AND (salary > 2000::double precision))
-- 谓词传递闭包(不支持)vastbase=> explain select * from emp where emp_id>dept_id and dept_id>900; QUERY PLAN------------------------------------------------------------ Seq Scan on emp (cost=0.00..268.00 rows=1 width=44) Filter: ((emp_id > dept_id) AND (dept_id > 900::number))
-- 等价合取范式(支持)vastbase=> explain select * from emp where (0>1) and dept_id=10; QUERY PLAN------------------------------------------------------------ Result (cost=0.00..218.00 rows=1 width=44) One-Time Filter: false -> Seq Scan on emp (cost=0.00..218.00 rows=1 width=44)
-- AND 操作符交换(支持)vastbase=> explain select * from emp where dept_id+emp_id=1000 and salary>900; QUERY PLAN-------------------------------------------------------------------------------------- Seq Scan on emp (cost=0.00..293.00 rows=45 width=44) Filter: ((salary > 900::double precision) AND ((dept_id + emp_id) = 1000::number))1.2.3.4.5.6.7.8.9.10.11.12.13.14.15.16.17.18.19.20.21.22.23.24.25.26.27.28.29.30.31.32.33.34.35.36.37.38.39.40.41.