指示优化器的方法与目标的hints:
ALL_ROWS -- 基于代价的优化器,以吞吐量为目标
FIRST_ROWS(n) -- 基于代价的优化器,以响应时间为目标
CHOOSE -- 根据是否有统计信息,选择不同的优化器
RULE -- 使用基于规则的优化器
例子:
SELECT /*+ FIRST_ROWS(10) */ employee_id, last_name, salary, job_id
FROM employees
WHERE department_id = 20;
SELECT /*+ CHOOSE */ employee_id, last_name, salary, job_id
FROM employees
WHERE employee_id = 7566;
SELECT /*+ RULE */ employee_id, last_name, salary, job_id
FROM employees
WHERE employee_id = 7566;
指示存储路径的hints:
FULL /*+ FULL ( table ) */
指定该表使用全表扫描
ROWID /*+ ROWID ( table ) */
指定对该表使用rowid存取方法,该提示用的较少
INDEX /*+ INDEX ( table [index]) */
使用该表上指定的索引对表进行索引扫描
INDEX_FFS /*+ INDEX_FFS ( table [index]) */
使用快速全表扫描
NO_INDEX /*+ NO_INDEX ( table [index]) */
不使用该表上指定的索引进行存取,仍然可以使用其它的索引进行索引扫描
SELECT /*+ FULL(e) */ employee_id, last_name
FROM employees e
WHERE last_name LIKE :b1;
SELECT /*+ROWID(employees)*/ *
FROM employees
WHERE rowid > ''AAAAtkAABAAAFNTAAA'' AND employee_id = 155;
SELECT /*+ INDEX(A sex_index) use sex_index because there are few
male patients */ A.name, A.height, A.weight
FROM patients A
WHERE A.sex = ’m’;
SELECT /*+NO_INDEX(employees emp_empid)*/ employee_id
FROM employees
WHERE employee_id > 200;
指示连接顺序的hints:
ORDERED /*+ ORDERED */
按from 字句中表的顺序从左到右的连接
STAR /*+ STAR */
指示优化器使用星型查询
SELECT /*+ORDERED */ o.order_id, c.customer_id, l.unit_price * l.quantity
FROM customers c, order_items l, orders o
WHERE c.cust_last_name = :b1
AND o.customer_id = c.customer_id
AND o.order_id = l.order_id;
/*+ ORDERED USE_NL(FACTS) INDEX(facts fact_concat) */
指示连接类型的hints:
USE_NL /*+ USE_NL ( table [,table, ...] ) */
使用嵌套连接
USE_MERGE /*+ USE_MERGE ( table [,table, ...]) */
使用排序- -合并连接
USE_HASH /*+ USE_HASH ( table [,table, ...]) */
使用HASH连接
注意:如果表有alias(别名),则上面的table指的是表的别名,而不是真实的表名
具体的测试实例:
create table A(col1 number(4,0),col2 number(4,0), col4 char(30));
create table B(col1 number(4,0),col3 number(4,0), name_b char(30));
create table C(col2 number(4,0),col3 number(4,0), name_c char(30));
select A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 MERGE JOIN
2 1 SORT (JOIN)
3 2 MERGE JOIN
4 3 SORT (JOIN)
5 4 TABLE ACCESS (FULL) OF ''B''
6 3 SORT (JOIN)
7 6 TABLE ACCESS (FULL) OF ''A''
8 1 SORT (JOIN)
9 8 TABLE ACCESS (FULL) OF ''C''
select /*+ ORDERED */ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=1 Bytes=110)
1 0 HASH JOIN (Cost=5 Card=1 Bytes=110)
2 1 HASH JOIN (Cost=3 Card=1 Bytes=84)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=1 Bytes=26)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=82 Bytes=4756)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=1 Bytes=26)
select /*+ ORDERED USE_NL (A C)*/ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=4 Card=1 Bytes=110)
1 0 HASH JOIN (Cost=4 Card=1 Bytes=110)
2 1 NESTED LOOPS (Cost=2 Card=1 Bytes=84)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=1 Bytes=26)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=82 Bytes=4756)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=1 Bytes=26)
创建索引:
create index inx_col12A on a(col1,col2);
select A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 MERGE JOIN
2 1 SORT (JOIN)
3 2 NESTED LOOPS
4 3 TABLE ACCESS (FULL) OF ''B''
5 3 TABLE ACCESS (BY INDEX ROWID) OF ''A''
6 5 INDEX (RANGE SCAN) OF ''INX_COL12A'' (NON-UNIQUE)
7 1 SORT (JOIN)
8 7 TABLE ACCESS (FULL) OF ''C''
select /*+ ORDERED */ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=1 Bytes=110)
1 0 HASH JOIN (Cost=5 Card=1 Bytes=110)
2 1 HASH JOIN (Cost=3 Card=1 Bytes=84)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=1 Bytes=26)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=82 Bytes=4756)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=1 Bytes=26)
select /*+ ORDERED USE_NL (A C)*/ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=4 Card=1 Bytes=110)
1 0 HASH JOIN (Cost=4 Card=1 Bytes=110)
2 1 NESTED LOOPS (Cost=2 Card=1 Bytes=84)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=1 Bytes=26)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=82 Bytes=4756)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=1 Bytes=26)
select /*+ USE_NL (A C)*/ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
我们这个查询的意思是让A、C表做NL连接,并且让A表作为内表,但是从执行计划来看,没有达到我们的目的。
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=3 Card=1 Bytes=110)
1 0 NESTED LOOPS (Cost=3 Card=1 Bytes=110)
2 1 MERGE JOIN (CARTESIAN) (Cost=2 Card=1 Bytes=52)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=1 Bytes=26)
4 2 SORT (JOIN) (Cost=1 Card=1 Bytes=26)
5 4 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=1 Bytes=26)
6 1 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=82 Bytes=4756)
对对象进行分析后:
analyze table a compute statistics;
analyze table b compute statistics;
analyze table c compute statistics;
analyze index inx_col12A compute statistics;
select A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=8 Bytes=336)
1 0 HASH JOIN (Cost=5 Card=8 Bytes=336)
2 1 MERGE JOIN (CARTESIAN) (Cost=3 Card=8 Bytes=64)
3 2 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
4 2 SORT (JOIN) (Cost=2 Card=4 Bytes=16)
5 4 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
6 1 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
select /*+ ORDERED */ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=9 Bytes=378)
1 0 HASH JOIN (Cost=5 Card=9 Bytes=378)
2 1 HASH JOIN (Cost=3 Card=30 Bytes=1140)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
select /*+ ORDERED USE_NL (A C)*/ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=7 Card=9 Bytes=378)
1 0 HASH JOIN (Cost=7 Card=9 Bytes=378)
2 1 NESTED LOOPS (Cost=5 Card=30 Bytes=1140)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
select /*+ USE_NL (A C)*/ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=7 Card=9 Bytes=378)
1 0 HASH JOIN (Cost=7 Card=9 Bytes=378)
2 1 NESTED LOOPS (Cost=5 Card=30 Bytes=1140)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
select /*+ ORDERED USE_NL (A B C) */ A.col4
from C , A , B
where C.col3 = 5 and A.col1 = B.col1 and A.col2 = C.col2
and B.col3 = 10;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=35 Card=9 Bytes=378)
1 0 NESTED LOOPS (Cost=35 Card=9 Bytes=378)
2 1 NESTED LOOPS (Cost=5 Card=30 Bytes=1140)
3 2 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
4 2 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
5 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
对于这个查询我无论如何也没有得到类似下面这样的执行计划:
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=35 Card=9 Bytes=378)
1 0 NESTED LOOPS (Cost=35 Card=9 Bytes=378)
2 1 TABLE ACCESS (FULL) OF ''B'' (Cost=1 Card=2 Bytes=8)
3 1 NESTED LOOPS (Cost=5 Card=30 Bytes=1140)
4 3 TABLE ACCESS (FULL) OF ''C'' (Cost=1 Card=4 Bytes=16)
5 3 TABLE ACCESS (FULL) OF ''A'' (Cost=1 Card=30 Bytes=1020)
从上面的这些例子我们可以看出:通过给语句添加HINTS,让其按照我们的意愿执行,有时是一件很困难的事情,需要不断的尝试各种不同的hints。对于USE_NL与USE_HASH提示,建议同ORDERED提示一起使用,否则不容易指定那个表为驱动表。
通过分析SQL语句的执行计划优化SQL之七
0
相关文章