环境介绍:
SQL> create table tobj (
2 id number,
3 name varchar2(128)
4 )
5 partition by range(id)
6 (
7 partition p01 values less than(500),
8 partition p02 values less than(1000),
9 partition p03 values less than(1500),
10 partition p04 values less than(2000),
11 partition p05 values less than(2500),
12 partition p06 values less than(3000),
13 partition p07 values less than(4000),
14 partition p08 values less than(5000)
15 );
Table created.
SQL> insert into tobj (id,name) select object_id,object_name from dba_objects where object_id<5000;
4996 rows created.
SQL> commit;
Commit complete.
SQL> create index ind_id on tobj(id) local;
Index created.
select index_owner,index_name,partition_name,status,tablespace_name
from dba_ind_partitions where index_name='IND_ID';

2.3 正常情况下SQL语句的执行
SQL> select * from tobj where id =3009;
ID NAME
-------------------- --------------------------------------------------------------------------------------------------------------------------------
3009 GV_$RSRC_PLAN_HISTORY
Execution Plan
----------------------------------------------------------
Plan hash value: 15562560
---------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 79 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE | | 1 | 79 | 2 (0)| 00:00:01 | 7 | 7 |
| 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| TOBJ | 1 | 79 | 2 (0)| 00:00:01 | 7 | 7 |
|* 3 | INDEX RANGE SCAN | IND_ID | 1 | | 1 (0)| 00:00:01 | 7 | 7 |
---------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("ID"=3009)
2.4 异常情况下SQL语句的执行
SQL> create table tobj_sw (
2 id number,
3 name varchar2(128)
4 );
Table created.
SQL> insert into tobj_sw (id,name) select object_id,object_name from dba_objects where object_id>5000 and object_id<8000;
2988 rows created.
SQL> commit;
Commit complete.
SQL> alter table tobj add partition p09 values less than('8000');
Table altered.
SQL> select partition_name from user_tab_partitions where table_name='TOBJ';
PARTITION_NAME
--------------------------------------------------------------------------------
P01
P02
P03
P04
P05
P06
P07
P08
P09
9 rows selected.
select
index_owner,index_name,partition_name,status,tablespace_name
from dba_ind_partitions where index_name='IND_ID';

SQL> alter table tobj exchange partition p09 with table tobj_sw;
Table altered.
SQL> select count(*) from tobj_sw;
COUNT(*)
----------
0
SQL> select count(*) from tobj;
COUNT(*)
----------
7984
select
index_owner,index_name,partition_name,status,tablespace_name
from dba_ind_partitions where index_name='IND_ID';

SQL> set autotrace on
SQL> select * from tobj where id =5009;
ID NAME
-------------------- --------------------------------------------------------------------------------------------------------------------------------
5009 DBA_LOCKDOWN_PROFILES
Execution Plan
----------------------------------------------------------
Plan hash value: 4166245901
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 79 | 5 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE| | 1 | 79 | 5 (0)| 00:00:01 | 9 | 9 |
|* 2 | TABLE ACCESS FULL | TOBJ | 1 | 79 | 5 (0)| 00:00:01 | 9 | 9 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("ID"=5009)
SQL> select * from tobj where id =4009;
ID NAME
-------------------- --------------------------------------------------------------------------------------------------------------------------------
4009 GV$HANG_STATISTICS
Execution Plan
----------------------------------------------------------
Plan hash value: 15562560
---------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 79 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE | | 1 | 79 | 2 (0)| 00:00:01 | 8 | 8 |
| 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| TOBJ | 1 | 79 | 2 (0)| 00:00:01 | 8 | 8 |
|* 3 | INDEX RANGE SCAN | IND_ID | 1 | | 1 (0)| 00:00:01 | 8 | 8 |
---------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("ID"=4009)
看结果,不在新分区里的数据,走的是索引扫描。
SQL> create table tobj_sw2 (
2 id number,
3 name varchar2(128)
4 );
Table created.
SQL> insert into tobj_sw2 (id,name) select object_id,object_name from dba_objects where object_id>8000 and object_id<10000;
1993 rows created.
SQL> commit;
Commit complete.
SQL> alter table tobj add partition p10 values less than('10000');
Table altered.
SQL> create index ind_id2 on tobj_sw2(id);
Index created.
SQL> select partition_name from user_tab_partitions where table_name='TOBJ';
PARTITION_NAME
--------------------------------------------------------------------------------
P01
P02
P03
P04
P05
P06
P07
P08
P09
P10
10 rows selected.
select
index_owner,index_name,partition_name,status,tablespace_name
from dba_ind_partitions where index_name='IND_ID';

SQL> alter table tobj exchange partition p10 with table tobj_sw2 including indexes;
Table altered.
select index_owner,index_name,partition_name,status,tablespace_name
from dba_ind_partitions where index_name='IND_ID';

SQL> set autotrace on
SQL> select * from tobj where id =8009;
ID NAME
-------------------- --------------------------------------------------------------------------------------------------------------------------------
8009 ALL_RULES
Execution Plan
----------------------------------------------------------
Plan hash value: 15562560
---------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 79 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE | | 1 | 79 | 2 (0)| 00:00:01 | 10 | 10 |
| 2 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| TOBJ | 1 | 79 | 2 (0)| 00:00:01 | 10 | 10 |
|* 3 | INDEX RANGE SCAN | IND_ID | 1 | | 1 (0)| 00:00:01 | 10 | 10 |
---------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("ID"=8009)
总 结:

本文作者:胡 伟(上海新炬中北团队)
本文来源:“IT那活儿”公众号

文章转载自IT那活儿,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




