暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

ANSI hinting

原创 胡佳伟 2020-03-31
767

原文作者:Jonathan lewis
原文地址:https://jonathanlewis.wordpress.com/2020/03/22/ansi-hinting/

ANSI hinting

— Jonathan Lewis @ 8:32 pm GMT Mar 22,2020

在过去,我有偶然说一些“ANSI”类型SQL会在标记或分辨查询模块上增加额外的复杂度–意思是很难准确得使用hint。这是篇文章会说明优化器如何首先将“ANSI”SQL转换为“Oracle”语法。我将会使用经典的Oracle格式写一个简单的4表的关联查询,并观察执行计划中的query block names 和 fully qualified table aliases部分;然后我将它转换为等效的ANSI标准并再次查看同上的部分。最后我将用经典的Oracle格式重写这个查询,重现在ANSI格式中得到的query block names和fully qualified table aliases部分。

我们从创建四个表及索引开始(使用我已经用了好几年进行了各种测试的脚本,但是我将展示的结果来自19c)

rem rem Script: ansi_hint_3.sql rem Author: Jonathan Lewis rem Dated: June 2014 rem create table t1 as select trunc((rownum-1)/4) t1_n1, trunc((rownum-1)/4) t1_n2, case mod(rownum,20) when 0 then rownum else -1 end flagged1, rpad(rownum,180) t1_v1 from all_objects where rownum <= 3000 --> comment to avoid wordpress format issue ; create table t2 as select mod(rownum,200) t2_n1, mod(rownum,200) t2_n2, case mod(rownum,20) when 0 then rownum else -1 end flagged2, rpad(rownum,180) t2_v1 from all_objects where rownum <= 3000 --> comment to avoid wordpress format issue ; create table t3 as select trunc((rownum-1)/4) t3_n1, trunc((rownum-1)/4) t3_n2, case mod(rownum,20) when 0 then rownum else -1 end flagged3, rpad(rownum,180) t3_v1 from all_objects where rownum <= 3000 --> comment to avoid wordpress format issue ; create table t4 as select trunc((rownum-1)/4) t4_n1, trunc((rownum-1)/4) t4_n2, case mod(rownum,20) when 0 then rownum else -1 end flagged4, rpad(rownum,180) t4_v1 from all_objects where rownum <= 3000 --> comment to avoid wordpress format issue ; create index t1_i1 on t1(t1_n1); create index t2_i1 on t2(t2_n1); create index t3_i1 on t3(t3_n1); create index t4_i1 on t4(t4_n1);

然后我们检查一个简单语句的执行计划,它看起来像一个单一的命名查询块:

explain plan for select /*+ qb_name(main) */ * from t1, t2, t3, t4 where t2.t2_n1 = t1.t1_n2 and t3.t3_n1 = t2.t2_n2 and t4.t4_n1 = t3.t3_n2 ; select * from table(dbms_xplan.display(null,null,'outline alias')); PLAN_TABLE_OUTPUT ------------------------------------------------------------------------------------ Plan hash value: 3619951144 ----------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 192K| 140M| 61 (22)| 00:00:01 | |* 1 | HASH JOIN | | 192K| 140M| 61 (22)| 00:00:01 | | 2 | TABLE ACCESS FULL | T4 | 3000 | 565K| 13 (8)| 00:00:01 | |* 3 | HASH JOIN | | 48000 | 26M| 41 (13)| 00:00:01 | | 4 | TABLE ACCESS FULL | T3 | 3000 | 565K| 13 (8)| 00:00:01 | |* 5 | HASH JOIN | | 12000 | 4500K| 26 (8)| 00:00:01 | | 6 | TABLE ACCESS FULL| T2 | 3000 | 559K| 13 (8)| 00:00:01 | | 7 | TABLE ACCESS FULL| T1 | 3000 | 565K| 13 (8)| 00:00:01 | ----------------------------------------------------------------------------- Query Block Name / Object Alias (identified by operation id): ------------------------------------------------------------- 1 - MAIN 2 - MAIN / T4@MAIN 4 - MAIN / T3@MAIN 6 - MAIN / T2@MAIN 7 - MAIN / T1@MAIN Outline Data ------------- /*+ BEGIN_OUTLINE_DATA SWAP_JOIN_INPUTS(@"MAIN" "T4"@"MAIN") SWAP_JOIN_INPUTS(@"MAIN" "T3"@"MAIN") SWAP_JOIN_INPUTS(@"MAIN" "T2"@"MAIN") USE_HASH(@"MAIN" "T4"@"MAIN") USE_HASH(@"MAIN" "T3"@"MAIN") USE_HASH(@"MAIN" "T2"@"MAIN") LEADING(@"MAIN" "T1"@"MAIN" "T2"@"MAIN" "T3"@"MAIN" "T4"@"MAIN") FULL(@"MAIN" "T4"@"MAIN") FULL(@"MAIN" "T3"@"MAIN") FULL(@"MAIN" "T2"@"MAIN") FULL(@"MAIN" "T1"@"MAIN") OUTLINE_LEAF(@"MAIN") ALL_ROWS DB_VERSION('19.1.0') OPTIMIZER_FEATURES_ENABLE('19.1.0') IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T4"."T4_N1"="T3"."T3_N2") 3 - access("T3"."T3_N1"="T2"."T2_N2") 5 - access("T2"."T2_N1"="T1"."T1_N2")

请注意,在Query Block Name / Object Alias 信息中,所有4个表都是“来源”的,或者有“@MAIN”限定的别名,在最终计划中,所有表都在名为MAIN的查询块中使用。
现在看看基本的ANSI等价语句:

explain plan for select /*+ qb_name(main) */ * from t1 join t2 on t2.t2_n1 = t1.t1_n2 join t3 on t3.t3_n1 = t2.t2_n2 join t4 on t4.t4_n1 = t3.t3_n2 ; select * from table(dbms_xplan.display(null,null,'outline alias')); PLAN_TABLE_OUTPUT ------------------------------------------------------------------------------------ Plan hash value: 3619951144 ----------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 192K| 140M| 61 (22)| 00:00:01 | |* 1 | HASH JOIN | | 192K| 140M| 61 (22)| 00:00:01 | | 2 | TABLE ACCESS FULL | T4 | 3000 | 565K| 13 (8)| 00:00:01 | |* 3 | HASH JOIN | | 48000 | 26M| 41 (13)| 00:00:01 | | 4 | TABLE ACCESS FULL | T3 | 3000 | 565K| 13 (8)| 00:00:01 | |* 5 | HASH JOIN | | 12000 | 4500K| 26 (8)| 00:00:01 | | 6 | TABLE ACCESS FULL| T2 | 3000 | 559K| 13 (8)| 00:00:01 | | 7 | TABLE ACCESS FULL| T1 | 3000 | 565K| 13 (8)| 00:00:01 | ----------------------------------------------------------------------------- Query Block Name / Object Alias (identified by operation id): ------------------------------------------------------------- 1 - SEL$43767242 2 - SEL$43767242 / T4@SEL$3 4 - SEL$43767242 / T3@SEL$2 6 - SEL$43767242 / T2@SEL$1 7 - SEL$43767242 / T1@SEL$1 Outline Data ------------- /*+ BEGIN_OUTLINE_DATA SWAP_JOIN_INPUTS(@"SEL$43767242" "T4"@"SEL$3") SWAP_JOIN_INPUTS(@"SEL$43767242" "T3"@"SEL$2") SWAP_JOIN_INPUTS(@"SEL$43767242" "T2"@"SEL$1") USE_HASH(@"SEL$43767242" "T4"@"SEL$3") USE_HASH(@"SEL$43767242" "T3"@"SEL$2") USE_HASH(@"SEL$43767242" "T2"@"SEL$1") LEADING(@"SEL$43767242" "T1"@"SEL$1" "T2"@"SEL$1" "T3"@"SEL$2" "T4"@"SEL$3") FULL(@"SEL$43767242" "T4"@"SEL$3") FULL(@"SEL$43767242" "T3"@"SEL$2") FULL(@"SEL$43767242" "T2"@"SEL$1") FULL(@"SEL$43767242" "T1"@"SEL$1") OUTLINE(@"SEL$1") OUTLINE(@"SEL$2") MERGE(@"SEL$1" >"SEL$2") OUTLINE(@"SEL$58A6D7F6") OUTLINE(@"SEL$3") MERGE(@"SEL$58A6D7F6" >"SEL$3") OUTLINE(@"SEL$9E43CB6E") OUTLINE(@"MAIN") MERGE(@"SEL$9E43CB6E" >"MAIN") OUTLINE_LEAF(@"SEL$43767242") ALL_ROWS DB_VERSION('19.1.0') OPTIMIZER_FEATURES_ENABLE('19.1.0') IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T4"."T4_N1"="T3"."T3_N2") 3 - access("T3"."T3_N1"="T2"."T2_N2") 5 - access("T2"."T2_N1"="T1"."T1_N2")

查看Plan Hash Value–它为您提供了一个强有力的证据,表明执行计划是相同的,并且仔细检查计划的主体和谓词信息,确认这两个查询以完全相同的方式操作,并且花费完全相同的成本。但是在查询块和表别名方面有很大的区别。

Query Block Name / Alias Alias 信息告诉我们,查询块“main”已经消失,查询完全是从内部产生的名为SEL$43767242的查询块运行的;此外,我们可以看到表t1和t2似乎来自于一个名为sel$1的查询块,而t3来自于sel$2,t4来自于sel$3。

最后,这里是一个凌乱的Oracle格式的语句,用于重现ANSI中的查询块名和表别名:

explain plan for select /*+ qb_name(main) */ * from ( select /*+ qb_name(sel$3) */ * from ( select /*+ qb_name(sel$2) */ * from ( select /*+ qb_name(sel$1) */ * from t1, t2 where t2.t2_n1 = t1.t1_n2 ) v1, t3 where t3.t3_n1 = v1.t2_n2 ) v2, t4 where t4.t4_n1 = v2.t3_n2 ) ; select * from table(dbms_xplan.display(null,null,'outline alias')); PLAN_TABLE_OUTPUT ------------------------------------------------------------------------------------ Plan hash value: 3619951144 ----------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 192K| 140M| 61 (22)| 00:00:01 | |* 1 | HASH JOIN | | 192K| 140M| 61 (22)| 00:00:01 | | 2 | TABLE ACCESS FULL | T4 | 3000 | 565K| 13 (8)| 00:00:01 | |* 3 | HASH JOIN | | 48000 | 26M| 41 (13)| 00:00:01 | | 4 | TABLE ACCESS FULL | T3 | 3000 | 565K| 13 (8)| 00:00:01 | |* 5 | HASH JOIN | | 12000 | 4500K| 26 (8)| 00:00:01 | | 6 | TABLE ACCESS FULL| T2 | 3000 | 559K| 13 (8)| 00:00:01 | | 7 | TABLE ACCESS FULL| T1 | 3000 | 565K| 13 (8)| 00:00:01 | ----------------------------------------------------------------------------- Query Block Name / Object Alias (identified by operation id): ------------------------------------------------------------- 1 - SEL$43767242 2 - SEL$43767242 / T4@SEL$3 4 - SEL$43767242 / T3@SEL$2 6 - SEL$43767242 / T2@SEL$1 7 - SEL$43767242 / T1@SEL$1 Outline Data ------------- /*+ BEGIN_OUTLINE_DATA SWAP_JOIN_INPUTS(@"SEL$43767242" "T4"@"SEL$3") SWAP_JOIN_INPUTS(@"SEL$43767242" "T3"@"SEL$2") SWAP_JOIN_INPUTS(@"SEL$43767242" "T2"@"SEL$1") USE_HASH(@"SEL$43767242" "T4"@"SEL$3") USE_HASH(@"SEL$43767242" "T3"@"SEL$2") USE_HASH(@"SEL$43767242" "T2"@"SEL$1") LEADING(@"SEL$43767242" "T1"@"SEL$1" "T2"@"SEL$1" "T3"@"SEL$2" "T4"@"SEL$3") FULL(@"SEL$43767242" "T4"@"SEL$3") FULL(@"SEL$43767242" "T3"@"SEL$2") FULL(@"SEL$43767242" "T2"@"SEL$1") FULL(@"SEL$43767242" "T1"@"SEL$1") OUTLINE(@"SEL$1") OUTLINE(@"SEL$2") MERGE(@"SEL$1" >"SEL$2") OUTLINE(@"SEL$58A6D7F6") OUTLINE(@"SEL$3") MERGE(@"SEL$58A6D7F6" >"SEL$3") OUTLINE(@"SEL$9E43CB6E") OUTLINE(@"MAIN") MERGE(@"SEL$9E43CB6E" >"MAIN") OUTLINE_LEAF(@"SEL$43767242") ALL_ROWS DB_VERSION('19.1.0') OPTIMIZER_FEATURES_ENABLE('19.1.0') IGNORE_OPTIM_EMBEDDED_HINTS END_OUTLINE_DATA */ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T4"."T4_N1"="T3"."T3_N2") 3 - access("T3"."T3_N1"="T2"."T2_N2") 5 - access("T2"."T2_N1"="T1"."T1_N2")

再次快速检查Plan Hash Value,确认这个凌乱的查询与前一个ANSI转换的查询匹配,并且确认计划主体和Query Block Name / Object Alias信息在命名上完全匹配。

任何时间你写ANSI语法,这种分层嵌套的内联视图就在你的查询上发生了,并且在任何其他转换发生之前–有时(虽然很少在最近版本的Oracle)这可能导致在随后的查询转换中出现意外的限制。

然而,除了“意外”之外,“ANSI重写”的最大问题来自所有额外查询块的副作用。除了最简单的情况下,如果你想应用优化器提示修复一个问题,那你必须更努力些来找出需要使用的查询块名称–你不能为你写的查询中的每个查询块创建有意义的名称。幸运的是,如果你查看的是在查询中添加hint/ * + no_query_transformation * /后的执行计划,那这会简单一点,因为这会倾向于按你的查询语句来一步一步“翻译”出执行计划(当然,除了ANSI转换)。这可能足以识别使用ANSI语法时优化器最开始的基本级别的查询块。

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论