GreatSQL社区

搜索

GreatSQL社区

【GreatSQL优化器-06】条件过滤导致选择非最佳

GreatSQL社区 已有 71 次阅读2024-12-11 10:20 |系统分类:原理&产品解读

【GreatSQL优化器-06】条件过滤导致选择非最佳

一、condition_fanout_filter导致计划非最佳

GreatSQL 的优化器对于 join 的表需要根据行数和 cost 来确定最后哪张表先执行哪张表后执行,这里面就涉及到预估满足条件的表数据,condition_fanout_filter会根据一系列方法计算出一个数据过滤百分比,这个比百分比就是 filtered 系数,这个值区间在[0,1],值越小代表过滤效果越好。用这个系数乘以总的行数就可以得出最后需要扫描的表行数的数量,可以大幅节省开销和执行时间。

这个功能是由OPTIMIZER_SWITCH_COND_FANOUT_FILTER这个OPTIMIZER_SWITCH来控制的,默认是打开的。因此一般情况下不需要特意去关闭,但是如果遇到执行特别慢的一些情况可以考虑关闭。

下面用一个例子来说明condition_fanout_filter有可能导致选择错误的情况:

# 创建2张表,都只在第二列创建索引,其中t3的最后一列也创建一个索引。
CREATE TABLE t3 (ccc1 INT, ccc2 int,ccc3 datetime(6));
INSERT INTO t3 VALUES (1,2,'2021-03-25 16:44:00.123456'),(2,10,'2021-03-25 16:44:00.123456'),(3,4,'2022-03-25 16:44:00.123456'),(4,6,'2023-03-25 16:44:00.123456'),(null,7,'2024-03-25 16:44:00.123456'),(4,3,'2024-04-25 16:44:00.123456'),(null,8,'2025-03-25 16:44:00.123456'),(3,4,'2022-06-25 16:44:00.123456'),(5,4,'2021-11-25 16:44:00.123456');
CREATE TABLE t4 (d1 INT, d2 int, d3 varchar(100));
INSERT INTO t4 VALUES (1,2,'aa1'),(2,1,'bb1'),(2,3,'cc1'),(3,3,'cc1'),(4,2,'ff1'),(4,4,'ert'),(4,2,'f5fg'),(null,2,'ee'),(5,30,'cc1'),(5,4,'fcc1'),(4,10,'cc1'),(6,4,'ccd1'),(null,1,'fee'),(1,2,'aa1'),(2,1,'bb1'),(2,3,'cc1'),(3,3,'cc1'),(4,2,'ff1'),(4,4,'ert'),(4,2,'f5fg'),(null,2,'ee'),(5,30,'cc1'),(5,4,'fcc1'),(4,10,'cc1'),(6,4,'ccd1'),(null,1,'fee'),(1,2,'aa1'),(2,1,'bb1'),(2,3,'cc1'),(3,3,'cc1'),(4,2,'ff1'),(4,4,'ert'),(4,2,'f5fg'),(null,2,'ee'),(5,30,'cc1'),(5,4,'fcc1'),(4,10,'cc1'),(6,4,'ccd1'),(null,1,'fee');
CREATE INDEX idx3_2 ON t3(ccc2);
CREATE INDEX idx3_3 ON t3(ccc3);
CREATE INDEX idx4_2 ON t4(d2);

执行一个join命令,where条件涉及的列不含t4的索引列,但是包含t3的索引列。
首先查看条件过滤开启的情况,结果是t4先执行全表扫描,预估的扫描行数为39 * 33.33%=13行,而t3执行ref索引扫描,行数为1 * 11.11%=0.1行,总行数为2行

greatsql> EXPLAIN SELECT * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+----+-------------+-------+------------+------+---------------+--------+---------+-----------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key    | key_len | ref       | rows | filtered | Extra       |
+----+-------------+-------+------------+------+---------------+--------+---------+-----------+------+----------+-------------+
|  1 | SIMPLE      | t4    | NULL       | ALL  | idx4_2        | NULL   | NULL    | NULL      |   39 |    33.33 | Using where |
|  1 | SIMPLE      | t3    | NULL       | ref  | idx3_2,idx3_3 | idx3_2 | 5       | db1.t4.d2 |    1 |    11.11 | Using where |
+----+-------------+-------+------------+------+---------------+--------+---------+-----------+------+----------+-------------+

接着查看条件过滤关闭的情况,结果是t3先执行范围扫描,预估的扫描行数为6 * 100%=6行,而t4执行ref索引扫描,行数为6 * 100%=6行,总行数为39行。

greatsql> EXPLAIN SELECT /*+ set_var(optimizer_switch='condition_fanout_filter=off') */ * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
| id | select_type | table | partitions | type  | possible_keys | key    | key_len | ref         | rows | filtered | Extra                              |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
|  1 | SIMPLE      | t3    | NULL       | range | idx3_2,idx3_3 | idx3_3 | 9       | NULL        |    6 |   100.00 | Using index condition; Using where |
|  1 | SIMPLE      | t4    | NULL       | ref   | idx4_2        | idx4_2 | 5       | db1.t3.ccc2 |    6 |   100.00 | Using where                        |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+

接下来关掉condition_fanout_filter然后强制用t4 & t3来连接,对比一下计算出来的cost实际达到多少。从下面2个结果可以看出,t4走了全表扫描实际的cost达到21.70,是估计值的2倍多。

greatsql> EXPLAIN FORMAT=TREE SELECT * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| EXPLAIN                                                                                                                                                                                                                                                                                                                                                        |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| -> Nested loop inner join  (cost=10.00 rows=2)
    -> Filter: ((t4.d1 < 5) and (t4.d2 is not null))  (cost=4.15 rows=13)
        -> Table scan on t4  (cost=4.15 rows=39)
    -> Filter: ((t3.ccc1 = t4.d1) and (t3.ccc3 < TIMESTAMP'2023-11-15 00:00:00'))  (cost=0.32 rows=0.1)
        -> Index lookup on t3 using idx3_2 (ccc2=t4.d2)  (cost=0.32 rows=1)
 |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+

greatsql> EXPLAIN FORMAT=TREE SELECT /*+ set_var(optimizer_switch='condition_fanout_filter=off') qb_name(qb1) JOIN_ORDER(@qb1 t4,t3) */ * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| EXPLAIN                                                                                                                                                                                                                                                                                                                                                       |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| -> Nested loop inner join  (cost=21.70 rows=50)
    -> Filter: ((t4.d1 < 5) and (t4.d2 is not null))  (cost=4.15 rows=39)
        -> Table scan on t4  (cost=4.15 rows=39)
    -> Filter: ((t3.ccc1 = t4.d1) and (t3.ccc3 < TIMESTAMP'2023-11-15 00:00:00'))  (cost=0.32 rows=1)
        -> Index lookup on t3 using idx3_2 (ccc2=t4.d2)  (cost=0.32 rows=1)
 |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+

以上例子因为condition_fanout_filter的设置不同而导致选择了不同的驱动表,最后的扫描行为也不一样。但是明显先执行t3的索引范围扫描比t4的全表扫描效率高,因此这个例子可以看出condition_fanout_filter的预估过滤百分比有更多主观性,最终可能导致错误的优化路径。

附表:join_type访问方法的类型

join_type访问方法的类型说明
JT_UNKNOWN无效
JT_SYSTEM表只有一行,比如select * from (select 1)
JT_CONST表最多只有一行满足,比如WHERE table.pk = 3
JT_EQ_REF=符号用在唯一索引
JT_REF=符号用在非唯一索引
JT_ALL全表扫描
JT_RANGE范围扫描
JT_INDEX_SCAN索引扫描
JT_FTFulltext索引扫描
JT_REF_OR_NULL包含null值,比如"WHERE col = ... OR col IS NULL
JT_INDEX_MERGE一张表执行多次范围扫描最后合并结果
以上各类扫描方式由快到慢排序为:system > const > eq_ref > ref > range > index > ALL

二、不关condition_fanout_filter的解决办法

如果不关闭condition_fanout_filter有没有办法强制指定连接顺序呢?答案是有的。一共如下3个方法,可以按照自己的需要进行灵活操作。

1、使用 qb_name 提示词来指定连接顺序

greatsql> EXPLAIN SELECT /*+ qb_name(qb1) JOIN_ORDER(@qb1 t3,t4) */ * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
| id | select_type | table | partitions | type  | possible_keys | key    | key_len | ref         | rows | filtered | Extra                              |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
|  1 | SIMPLE      | t3    | NULL       | range | idx3_2,idx3_3 | idx3_3 | 9       | NULL        |    6 |   100.00 | Using index condition; Using where |
|  1 | SIMPLE      | t4    | NULL       | ref   | idx4_2        | idx4_2 | 5       | db1.t3.ccc2 |    6 |     3.33 | Using where                        |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+

2、在所有 WHERE 条件列上建立索引

greatsql> CREATE INDEX idx4_1 ON t4(d1);

greatsql> EXPLAIN SELECT * FROM t4 join t3 ON t4.d1=t3.ccc1 and t4.d2=t3.ccc2 where t4.d1<5 and t3.ccc3 < '2023-11-15';
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
| id | select_type | table | partitions | type  | possible_keys | key    | key_len | ref         | rows | filtered | Extra                              |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
|  1 | SIMPLE      | t3    | NULL       | range | idx3_2,idx3_3 | idx3_3 | 9       | NULL        |    6 |   100.00 | Using index condition; Using where |
|  1 | SIMPLE      | t4    | NULL       | ref   | idx4_2,idx4_1 | idx4_1 | 5       | db1.t3.ccc1 |    5 |    16.67 | Using where                        |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+

3、用 JOIN_FIXED_ORDER hint 加上表顺序来强制连接顺序。

greatsql> EXPLAIN SELECT /*+ qb_name(qb1) JOIN_FIXED_ORDER(@qb1) */ * FROM t3 join t4 ON t4.d1=t3.ccc1 AND t4.d2=t3.ccc2 WHERE t4.d1<5 AND t3.ccc3 < '2023-11-15';
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
| id | select_type | table | partitions | type  | possible_keys | key    | key_len | ref         | rows | filtered | Extra                              |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+
|  1 | SIMPLE      | t3    | NULL       | range | idx3_2,idx3_3 | idx3_3 | 9       | NULL        |    6 |   100.00 | Using index condition; Using where |
|  1 | SIMPLE      | t4    | NULL       | ref   | idx4_2        | idx4_2 | 5       | db1.t3.ccc2 |    6 |     3.33 | Using where                        |
+----+-------------+-------+------------+-------+---------------+--------+---------+-------------+------+----------+------------------------------------+

三、如何排查类似问题

从以上例子看出,打开条件过滤有时并不总是能提高性能,优化器可能会高估条件过滤的影响,个别场景下使用条件过滤反而会导致性能下降。GreatSQL的condition_fanout_filter参数默认是打开的,因此需要自己来判断是否需要这个功能。一般来说,遇到以下场景需要特别注意条件过滤错估的情况。

情况解决办法
join连接表有大表,并且条件列没有索引join连接的字段如果没有索引,应当先加上索引,以便优化器能够掌握字段值的分布情况,更准确的预估行数。
join表有特别大的表和小表判断表的join顺序是否合适,通过改变表的join顺序,让更小的表作为驱动表。可以考虑使用hint,强制优化器使用指定的表join顺序。
运行sql前先使用explain提前查看执行计划,判断条件过滤结果是否合理如果不使用条件过滤,性能会更好,那么可以关闭会话级条件过滤功能。

四、总结

这节用了一个例子展示了条件过滤误判的情况,知道了打开条件过滤有时并不总是能提高性能,优化器可能会高估条件过滤的影响,个别场景下使用条件过滤反而会导致性能下降。GreatSQL的condition_fanout_filter参数默认是打开的,因此需要自己来判断是否需要这个功能。


评论 (0 个评论)

facelist

您需要登录后才可以评论 登录 | 立即注册

合作电话:010-64087828

社区邮箱:greatsql@greatdb.com

社区公众号
社区小助手
QQ群
GMT+8, 2024-12-22 00:11 , Processed in 0.015384 second(s), 9 queries , Redis On.
返回顶部