共计 7399 个字符,预计需要花费 19 分钟才能阅读完成。
index range scan(索引范围扫描):
1. 对于 unique index 来说,如果 where 条件后面出现了 <,> ,between …and… 的时候,那么就可能执行 index range scan, 如果 where 条件后面是 =,那么就会执行 index unique scan。
2. 对于 none unique index 来说 如果 where 条件后面出现了 =,>,<,betweed…and… 的时候,就有可能执行 index range scan。
3. 对于组合索引来说,如果 where 条件后面出现了组合索引的引导列,那么可能执行 index range scan。
index fast full scan(索引快速全扫描):
如果 select 语句后面中的列都被包含在组合索引中,而且 where 后面没有出现组合索引的引导列,并且需要检索出大部分数据,那么这个时候可能执行 index fast full scan。index fast full scan 发生的条件:
1. 必须是组合索引?。2. 引导列不在 where 条件中
index skip scan(索引跳跃式扫描)
当查询可以通过组合索引得到结果,而且返回结果很少,并且 where 条件中没有包含索引引导列的时候,可能执行 index skip scan
索引跳跃式扫描发生的条件:
1. 必须是组合索引。
2. 引导列没有出现在 where 条件中
-eg1
SQL> create table test as select * from dba_objects;
Table created.
SQL> create unique index ind_id on test(object_id);
Index created.
SQL> create index ind_owner on test(owner);
Index created.
SQL> create index ooo on test(owner,object_name,object_type);
Index created.
SQL> exec dbms_stats.gather_table_stats(‘SCOTT’,’TEST’);
PL/SQL procedure successfully completed.
SQL> set autot trace
SQL> select owner from test where object_id=10;
Execution Plan
———————————————————-
Plan hash value: 2544773305
——————————————————————————–
——
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time
|
——————————————————————————–
——
| 0 | SELECT STATEMENT | | 1 | 11 | 2 (0)| 00:0
0:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| TEST | 1 | 11 | 2 (0)| 00:0
0:01 |
|* 2 | INDEX UNIQUE SCAN | IND_ID | 1 | | 1 (0)| 00:0
0:01 |
——————————————————————————–
——
Predicate Information (identified by operation id):
—————————————————
2 – access(“OBJECT_ID”=10)
Statistics
———————————————————-
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
524 bytes sent via SQL*Net to client
524 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
SQL> select owner from test where object_id<10;
8 rows selected.
Execution Plan
———————————————————-
Plan hash value: 1361604213
——————————————————————————–
——
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time
|
——————————————————————————–
——
| 0 | SELECT STATEMENT | | 8 | 88 | 3 (0)| 00:0
0:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| TEST | 8 | 88 | 3 (0)| 00:0
0:01 |
|* 2 | INDEX RANGE SCAN | IND_ID | 8 | | 2 (0)| 00:0
0:01 |
——————————————————————————–
——
Predicate Information (identified by operation id):
—————————————————
2 – access(“OBJECT_ID”<10)
Statistics
———————————————————-
1 recursive calls
0 db block gets
5 consistent gets
0 physical reads
0 redo size
609 bytes sent via SQL*Net to client
524 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
8 rows processed
对于唯一索引,发生 index range scan 的时候就是返回多行记录,where 后面有 <,>,between..and 等返回扫描
SQL> select owner from test where owner=’SCOTT’;
Execution Plan
———————————————————-
Plan hash value: 2280863269
——————————————————————————
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
——————————————————————————
| 0 | SELECT STATEMENT | | 3613 | 21678 | 9 (0)| 00:00:01 |
|* 1 | INDEX RANGE SCAN| IND_OWNER | 3613 | 21678 | 9 (0)| 00:00:01 |
——————————————————————————
Predicate Information (identified by operation id):
—————————————————
1 – access(“OWNER”=’SCOTT’)
Statistics
———————————————————-
1 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
526 bytes sent via SQL*Net to client
524 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
对于非唯一索引,即使 where 后面是 = 条件,但也可能返回多行,也是 index range scan 扫描
SQL> select object_name,object_type from test where owner=’SCOTT’;
Execution Plan
———————————————————-
Plan hash value: 2845720098
————————————————————————-
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
————————————————————————-
| 0 | SELECT STATEMENT | | 3613 | 141K| 28 (0)| 00:00:01 |
|* 1 | INDEX RANGE SCAN| OOO | 3613 | 141K| 28 (0)| 00:00:01 |
————————————————————————-
Predicate Information (identified by operation id):
—————————————————
1 – access(“OWNER”=’SCOTT’)
Statistics
———————————————————-
1 recursive calls
0 db block gets
4 consistent gets
0 physical reads
0 redo size
610 bytes sent via SQL*Net to client
524 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
因为这个索引不是唯一索引,where 后面的列用到了索引 000,所以进行 index range scan
SQL> select owner, object_name,object_type from test where object_name=’EMP’ ;
no rows selected
Execution Plan
———————————————————-
Plan hash value: 1799988433
————————————————————————-
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
————————————————————————-
| 0 | SELECT STATEMENT | | 2 | 80 | 26 (0)| 00:00:01 |
|* 1 | INDEX SKIP SCAN | OOO | 2 | 80 | 26 (0)| 00:00:01 |
————————————————————————-
Predicate Information (identified by operation id):
—————————————————
1 – access(“OBJECT_NAME”=’EMP’)
filter(“OBJECT_NAME”=’EMP’)
Statistics
———————————————————-
1 recursive calls
0 db block gets
28 consistent gets
0 physical reads
0 redo size
479 bytes sent via SQL*Net to client
513 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed
上面的查询可以通过索引 000 来得到,并且 where 后面没有用到索引列,而且返回的行数很少(。)所以 cbo 选择 index skip scan
select owner, object_name,object_type from test where object_type=’INDEX’;
Execution Plan
———————————————————-
Plan hash value: 3464522019
—————————————————————————–
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
—————————————————————————–
| 0 | SELECT STATEMENT | | 1971 | 78840 | 168 (1)| 00:00:03 |
|* 1 | INDEX FAST FULL SCAN| OOO | 1971 | 78840 | 168 (1)| 00:00:03 |
—————————————————————————–
Predicate Information (identified by operation id):
—————————————————
1 – filter(“OBJECT_TYPE”=’INDEX’)
Statistics
———————————————————-
0 recursive calls
0 db block gets
957 consistent gets
0 physical reads
0 redo size
199834 bytes sent via SQL*Net to client
4253 bytes received via SQL*Net from client
341 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
5088 rows processed
同上,但是这里返回行数较多,cbo 选择了 index fast full scan,避免了全表扫描
更多 Oracle 相关信息见 Oracle 专题页面 https://www.linuxidc.com/topicnews.aspx?tid=12
: