If you want to make use of Oracle's cunning Star Transformation feature then you need to be aware of the fact that the star transformation logic - as the name implies - assumes that you are using a proper star schema.
Here is a nice example of what can happen if you attempt to use star transformation but your model obviously doesn't really correspond to what Oracle expects:
drop table d;
purge table d;
drop table t;
purge table t;
create table t
as
select
rownum as id
, mod(rownum, 100) + 1 as fk1
, 1000 + mod(rownum, 10) + 1 as fk2
, 2000 + mod(rownum, 100) + 1 as fk3
, rpad('x', 100) as filler
from
dual
connect by
level <= 1000000
;
exec dbms_stats.gather_table_stats(null, 't')
create bitmap index t_fk1 on t (fk1);
create bitmap index t_fk2 on t (fk2);
create bitmap index t_fk3 on t (fk3);
create table d
as
select
rownum as id
, case when rownum between 1 and 100 then 'Y' else 'N' end as is_flag_d1
, case when rownum between 1001 and 1010 then 'Y' else 'N' end as is_flag_d2
, case when rownum between 2001 and 2100 then 'Y' else 'N' end as is_flag_d3
, rpad('x', 100) as vc1
from
dual
connect by
level <= 10000
;
exec dbms_stats.gather_table_stats(null, 'd', method_opt => 'FOR ALL COLUMNS SIZE 1 FOR COLUMNS SIZE 254 IS_FLAG_D1, IS_FLAG_D2, IS_FLAG_D3');
This is a simplified example of a model where multiple, potentially small, dimensions are stored in a single physical table and the separate dimensions are represented by views that filter the corresponding dimension data from the base table.
So we have a fact table with one million rows and a "collection" dimension table that holds three dimensions, among others.
In order to enable the star transformation bitmap indexes on the foreign keys of the fact table are created.
The dimension table has histograms on the flag columns to tell the optimizer about the non-uniform distribution of the column data.
Now imagine a query where we query the fact table (and possibly do some filtering on the fact table by other means like other dimensions or direct filtering on the fact table) but need to join these three dimensions just for displaying purpose - the dimensions itself are not filtered so the join will not filter out any data.
Let's first have a look at an execution plan of such a simply query with star transformation disabled:
select /*+ no_star_transformation */
count(*)
from
t f
, (select * from d where is_flag_d1 = 'Y') d1
, (select * from d where is_flag_d2 = 'Y') d2
, (select * from d where is_flag_d3 = 'Y') d3
where
f.fk1 = d1.id
and f.fk2 = d2.id
and f.fk3 = d3.id
;
SQL> explain plan for
2 select /*+ no_star_transformation */
3 count(*)
4 from
5 t f
6 , (select * from d where is_flag_d1 = 'Y') d1
7 , (select * from d where is_flag_d2 = 'Y') d2
8 , (select * from d where is_flag_d3 = 'Y') d3
9 where
10 f.fk1 = d1.id
11 and f.fk2 = d2.id
12 and f.fk3 = d3.id
13 ;
Explained.
SQL>
SQL> select * from table(dbms_xplan.display(format => 'BASIC +ROWS +PREDICATE'));
Plan hash value: 77569906
----------------------------------------------
| Id | Operation | Name | Rows |
----------------------------------------------
| 0 | SELECT STATEMENT | | 1 |
| 1 | SORT AGGREGATE | | 1 |
|* 2 | HASH JOIN | | 940K|
|* 3 | TABLE ACCESS FULL | D | 100 |
|* 4 | HASH JOIN | | 945K|
|* 5 | TABLE ACCESS FULL | D | 100 |
|* 6 | HASH JOIN | | 950K|
|* 7 | TABLE ACCESS FULL| D | 10 |
| 8 | TABLE ACCESS FULL| T | 1000K|
----------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("F"."FK3"="D"."ID")
3 - filter("IS_FLAG_D3"='Y')
4 - access("F"."FK1"="D"."ID")
5 - filter("IS_FLAG_D1"='Y')
6 - access("F"."FK2"="D"."ID")
7 - filter("IS_FLAG_D2"='Y')
So clearly the optimizer got it quite right - the join to the dimensions is not going to filter out significantly - the slight reduction in rows comes from the calculations based on the histograms generated.
But now try the same again with star transformation enabled:
SQL> explain plan for
2 select /*+ star_transformation opt_param('star_transformation_enabled', 'temp_disable') */
3 count(*)
4 from
5 t f
6 , (select * from d where is_flag_d1 = 'Y') d1
7 , (select * from d where is_flag_d2 = 'Y') d2
8 , (select * from d where is_flag_d3 = 'Y') d3
9 where
10 f.fk1 = d1.id
11 and f.fk2 = d2.id
12 and f.fk3 = d3.id
13 ;
Explained.
SQL>
SQL> select * from table(dbms_xplan.display(format => 'BASIC +ROWS +PREDICATE'));
Plan hash value: 459231705
----------------------------------------------------------
| Id | Operation | Name | Rows |
----------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 |
| 1 | SORT AGGREGATE | | 1 |
|* 2 | HASH JOIN | | 9 |
|* 3 | HASH JOIN | | 9 |
|* 4 | HASH JOIN | | 10 |
|* 5 | TABLE ACCESS FULL | D | 10 |
| 6 | TABLE ACCESS BY INDEX ROWID | T | 10 |
| 7 | BITMAP CONVERSION TO ROWIDS| | |
| 8 | BITMAP AND | | |
| 9 | BITMAP MERGE | | |
| 10 | BITMAP KEY ITERATION | | |
|* 11 | TABLE ACCESS FULL | D | 100 |
|* 12 | BITMAP INDEX RANGE SCAN| T_FK1 | |
| 13 | BITMAP MERGE | | |
| 14 | BITMAP KEY ITERATION | | |
|* 15 | TABLE ACCESS FULL | D | 100 |
|* 16 | BITMAP INDEX RANGE SCAN| T_FK3 | |
| 17 | BITMAP MERGE | | |
| 18 | BITMAP KEY ITERATION | | |
|* 19 | TABLE ACCESS FULL | D | 10 |
|* 20 | BITMAP INDEX RANGE SCAN| T_FK2 | |
|* 21 | TABLE ACCESS FULL | D | 100 |
|* 22 | TABLE ACCESS FULL | D | 100 |
----------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("F"."FK3"="D"."ID")
3 - access("F"."FK1"="D"."ID")
4 - access("F"."FK2"="D"."ID")
5 - filter("IS_FLAG_D2"='Y')
11 - filter("IS_FLAG_D1"='Y')
12 - access("F"."FK1"="D"."ID")
15 - filter("IS_FLAG_D3"='Y')
16 - access("F"."FK3"="D"."ID")
19 - filter("IS_FLAG_D2"='Y')
20 - access("F"."FK2"="D"."ID")
21 - filter("IS_FLAG_D1"='Y')
22 - filter("IS_FLAG_D3"='Y')
What an astonishing result: Not only Oracle will try now to access all rows of the fact table by single-block random I/O, which by itself can be a disaster for larger real-life fact tables, in particular when dealing with Exadata features like Smart Scans which are only possible with multi-block direct-path reads, but furthermore if this was part of a more complex execution plan look at the cardinality estimates: They are off by five orders of magnitude - very likely a receipt for disaster for any step following afterwards.
The point here is simple: The Star Transformation calculation model obviously doesn't cope with the "collection" of dimensions in a single table very well, but assumes a dimensional model where each dimension is stored in separate table(s). If you don't adhere to that model the calculation will be badly wrong and the results possibly disastrous.
Here the Star Transformation assumes a filtering on dimension tables that are effectively no filter but this is something the current calculation model is not aware of. If you put the three dimensions in separate tables no "artificial" filter is required and hence the calculation won't be mislead.
Of course one could argue that the star transformation optimization seems to do a poor job since the normal optimization based on the same input data produces a much better estimate, but at least for the time being that's the way this transformation works and the model chosen better reflects this.
参考至:http://oracle-randolf.blogspot.com/2011/11/star-transformation-and-cardinality.html
如有错误,欢迎指正
邮箱:czmcj@163.com
- 浏览: 4410244 次
- 性别:
- 来自: 厦门
文章分类
- 全部博客 (634)
- Oracle日常管理 (142)
- Oracle体系架构 (45)
- Oracle Tuning (52)
- Oracle故障诊断 (35)
- RAC/DG/OGG (64)
- Oracle11g New Features (48)
- DataWarehouse (15)
- SQL, PL/SQL (14)
- DB2日常管理 (9)
- Weblogic (11)
- Shell (19)
- AIX (12)
- Linux/Unix高可用性 (11)
- Linux/Unix日常管理 (66)
- Linux桌面应用 (37)
- Windows (2)
- 生活和工作 (13)
- 私人记事 (0)
- Python (9)
- CBO (15)
- Cognos (2)
- ORACLE 12c New Feature (2)
- PL/SQL (2)
- SQL (1)
- C++ (2)
- Hadoop大数据 (5)
- 机器学习 (3)
- 非技术 (1)
最新评论
-
di1984HIT:
xuexilee!!!
Oracle 11g R2 RAC高可用连接特性 – SCAN详解 -
aneyes123:
谢谢非常有用那
PL/SQL的存储过程和函数(原创) -
jcjcjc:
写的很详细
Oracle中Hint深入理解(原创) -
di1984HIT:
学习了,学习了
Linux NTP配置详解 (Network Time Protocol) -
avalonzst:
大写的赞..
AIX内存概述(原创)
发表评论
-
Oracle Redo 并行机制
2017-04-07 11:31 986Redo log 是用于恢复和一个高级特性的重要数据,一个r ... -
Append Values and how not to break the database
2015-09-29 20:12 745With the advent of the /*+ APP ... -
基于案例学习sql优化第6周脚本
2015-04-13 04:29 0===============BEGIN=========== ... -
Oracle表高水平位的优化与监控
2015-02-13 09:21 2223高水平位虚高的案例 --构造表drop table t p ... -
Oracle行迁移和行链接详解(原创)
2015-02-13 09:00 12152行迁移成 因:当发出u ... -
Parse CPU to Parse Elapsd%的理解
2015-01-19 13:59 1439Parse CPU to Parse Elapsd%是指sq ... -
ALTER INDEX COALESCE: 10g Improvements
2014-08-02 21:34 928I thought it might be worth me ... -
Differences and Similarities Between Index Coalesce and Shrink Space
2014-08-02 21:21 956As already discussed, ALTER IN ... -
Alter index coalesce VS shrink space
2014-08-02 17:56 101910g中引入了对索引的shrink功能,索引shrink操 ... -
SQL Plan Management Creating SQL plan baselines(原创)
2014-08-01 23:56 1359SQL Plan Management SQL Plan ... -
WITH Clause : Subquery Factoring
2014-07-23 08:43 1185Subquery Factoring The WIT ... -
Query Transformations : Subquery unnesting(原创)
2014-07-23 08:42 2904Subquery Unnesting Subqueries ... -
Automating Parallelism
2014-07-17 17:49 834Parallel query, the essence of ... -
Parallel Execution: Large/Shared Pool and ORA-4031 (文档 ID 238680.1)
2014-07-17 17:47 2100Applies toOracle Database - En ... -
Optimizer Transformations: Star Transformation
2014-06-30 07:32 783Star transformation was intro ... -
Optimizer statistics-driven direct path read decision for full table scans
2014-06-06 16:09 1078Hello all fellow Oracle geeks ... -
Cut out from Ask Tom-- Thanks for the question regarding "10053", version 9.2.6
2014-03-09 23:38 1435You AskedDear tom,A. your new ... -
ORACLE SQL TUNING各种技巧及复杂实例
2014-02-25 23:17 6514一.优化器模式ORACLE的优化器共有3种:a. RULE ... -
Oracle Predicate Pushing(原创)
2014-02-22 21:17 4622IntroductionThe join predicate ... -
SQL Tuning : Setup Sample Schema
2014-02-22 20:25 1115STEP 1 : Setup userCREATE USER ...
相关推荐
HTML5 and CSS3 Transition, Transformation, and Animation will introduce any developer or designer to this new, exciting, and world-changing technology. Using practical and easy-to-follow examples, ...
在“视频游戏开发系列课程(5):Transformation and Collision of Sprites”中,我们探讨了游戏制作中的两个关键概念:精灵的变换(Transformation)和碰撞检测(Collision Detection)。这两个技术对于构建任何2D或...
Informatica Union Transformation 组件详解 Informatica Union Transformation 组件是 PowerCenter 的一个重要组件,用于将多个输入源合并到一起,类似于 SQL 语句的 UNION ALL 语句。下面是 Union Transformation...
SE(3)变换参数化与在流形上的优化教程 这篇技术报告主要关注于SE(3)空间中的刚体变换参数化以及在流形上的优化方法。SE(3)是三维空间中的特殊欧几里得群,包含了平移和旋转两种变换,广泛应用于机器人学、计算机...
《Schiff - Laplace Transformation Theory And Applications (Utm, Springer,1999)》是Springer出版社为本科生数学系列教材之一,主要介绍了拉普拉斯变换的基础理论及在工程实践中的广泛应用。该书面向初学者,力求...
##### 3.2 斜轴梅卡托和霍丁斜轴梅卡托投影(Oblique Mercator and Hotine Oblique Mercator) 斜轴梅卡托投影主要用于处理具有特殊定向需求的区域,如沿河流或道路的地带。其转换公式较为复杂,通常需要数值方法来...
HTML5 and CSS3 Transition, Transformation, and Animation 英文无水印原版pdf pdf所有页面使用FoxitReader、PDF-XChangeViewer、SumatraPDF和Firefox测试都可以打开 本资源转载自网络,如有侵权,请联系上传者...
Gray scale enhancement methods
产业转型升级中的碳排放问题研究,周婷婷,毛春梅,文章首先介绍产业转型升级的研究背景和相关研究成果。其次介绍产业转型升级的基本概念和理论基础。再次提出三大产业的碳排放计算
《Ni40.0Mn47.3Sn10.9Sb1.8合金条带的马氏体相变及磁热效应研究》这篇论文深入探讨了一种特殊的金属合金——Ni40.0Mn47.3Sn10.9Sb1.8的马氏体相变(Martensitic Transformation, MT)及其磁热效应(Magnetocaloric ...
Crocidolite induces cell transformation and p53 gene mutation in BALB/c-3T3 cells Teratogenesis, Carcinogenesis, and Mutagenesis 20:273–281 (2000) TCM 273 :copyright: 2000 Wiley-Liss, Inc. ...
(2+1)维广义浅水波方程的Lax对,Darbuox变换和孤子解,闻小永,高以天,利用奇异流形方法构造了(2+1)维广义浅水波方程的Lax和相关的Darbuox变换,通过使用得到的Darbuox变换,得到了该方程的一次和二次迭代解以及
Cyber Physical Systems(CPS) are composed with ... The model transformation from AADL to Modelica provides an efficient way to unify the CPS model that helps to verify the properties of the whole model.
欧拉角、四元数和变换矩阵是航天领域的核心数学工具,广泛用于航天器的姿态描述和控制。本文将根据NASA相关的技术文献,详细介绍这些概念及其在航天器中的应用。 欧拉角是描述三维空间中物体的方向的一种方法,通过...
《Windows 模拟Mac OS Yosemite:Yosemite Transformation Pack 3.0详解》 在数字化的世界里,用户界面(UI)的设计对于操作系统体验至关重要。苹果公司的Mac OS Yosemite以其优雅、直观的用户界面赢得了众多用户的...
基于符号计算构建一个谱可变的修正Kadomtsev-Petviashvili方程的Darboux变换与Grammian解,李娟,张海强,在本文中,研究了一个具有双Painleve分支的谱可变的修正Kadomtsev-Petviashvili方程。利用符号计算与广义的...
从给定的文件信息来看,主要讨论的是网络者2009年的一次演讲BRKBBA-2010,主题是下一代移动网络(NG Mobile Networks)的架构转变与向IP(互联网协议)的演进。以下是根据标题、描述、标签以及部分内容中提炼出的...
这篇论文主要探讨了(Ti36Ni49Hf15)100-xYx系列高温形状记忆合金的微观结构、马氏体相变行为以及力学性能。形状记忆合金是一种特殊的金属材料,具备在一定温度范围内进行可逆相变的能力,这种相变导致材料在加热或...