create table t1 as select * from sys.dba_objects;
select * from t1 where owner='SYS' and OBJECT_TYPE='TABLE' and object_id >= 3000 and object_id <= 6000 ;
--测试1
create index t1_idx1 on t1(owner,object_id,OBJECT_TYPE);
SQL> select * from t1 where owner='SYS' and OBJECT_TYPE='TABLE' and object_id >= 3000 and object_id <= 6000 ;
Execution Plan
----------------------------------------------------------
Plan hash value: 1009994977
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 264 | 3 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID BATCHED| T1 | 2 | 264 | 3 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T1_IDX1 | 2 | | 2 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("OWNER"='SYS' AND "OBJECT_ID">=3000 AND "OBJECT_TYPE"='TABLE' AND
"OBJECT_ID"<=6000)
filter("OBJECT_TYPE"='TABLE')
Statistics
----------------------------------------------------------
55 recursive calls
122 db block gets
71 consistent gets
7 physical reads
32080 redo size
3018 bytes sent via SQL*Net to client
465 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
3 rows processed
--测试2
drop index t1_idx1;
create index t1_idx2 on t1(object_id,owner,OBJECT_TYPE);
SQL> select * from t1 where owner='SYS' and OBJECT_TYPE='TABLE' and object_id >= 3000 and object_id <= 6000 ;
Execution Plan
----------------------------------------------------------
Plan hash value: 26955123
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 264 | 15 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID BATCHED| T1 | 2 | 264 | 15 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T1_IDX2 | 2 | | 14 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("OBJECT_ID">=3000 AND "OWNER"='SYS' AND "OBJECT_TYPE"='TABLE' AND
"OBJECT_ID"<=6000)
filter("OBJECT_TYPE"='TABLE' AND "OWNER"='SYS')
Statistics
----------------------------------------------------------
5 recursive calls
0 db block gets
19 consistent gets
13 physical reads
768 redo size
3018 bytes sent via SQL*Net to client
466 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
3 rows processed
--测试3
drop index t1_idx2;
create index t1_idx3 on t1(owner,OBJECT_TYPE,object_id);
SQL> select * from t1 where owner='SYS' and OBJECT_TYPE='TABLE' and object_id >= 3000 and object_id <= 6000 ;
Execution Plan
----------------------------------------------------------
Plan hash value: 3017946
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 264 | 3 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID BATCHED| T1 | 2 | 264 | 3 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T1_IDX3 | 2 | | 2 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("OWNER"='SYS' AND "OBJECT_TYPE"='TABLE' AND "OBJECT_ID">=3000 AND
"OBJECT_ID"<=6000)
Statistics
----------------------------------------------------------
5 recursive calls
0 db block gets
7 consistent gets
1 physical reads
120 redo size
3018 bytes sent via SQL*Net to client
466 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
3 rows processed
SQL>
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




