|
从Oracle8开始,提供了从分区交换的功能,如一个分区或子分区与一个非分区表交换、一个hash分区与另一个表的hash子分区交换等等,详细的交换方式可以参考官方文档。
基本语法:ALTER TABLE...EXCHANGE PARTITION
实验环境:11.2.0.4
1
2
3
4
5
6
7
8
9
| zx@ORCL>select * from v$version;
BANNER
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
PL/SQL Release 11.2.0.4.0 - Production
CORE 11.2.0.4.0 Production
TNS for Linux: Version 11.2.0.4.0 - Production
NLSRTL Version 11.2.0.4.0 - Production
|
一、测试分区交换
创建测试表
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
| --分区表
zx@ORCL>create table t1
2 ( id number(2),
3 name varchar2(15))
4 tablespace tt
5 partition by range (id)
6 (partition p1 values less than (10),
7 partition p2 values less than (20),
8 partition p3 values less than (30));
Table created.
--非分区表
zx@ORCL>create table t2 (id number(2), name varchar2(15)) tablespace users;
Table created.
--插入测试数据
zx@ORCL>insert into t1 values (1, '1');
1 row created.
zx@ORCL>insert into t1 values (11, '11');
1 row created.
zx@ORCL>insert into t1 values (21, '21');
1 row created.
zx@ORCL>insert into t2 values (2, '2');
1 row created.
zx@ORCL>commit;
Commit complete.
zx@ORCL>select * from t1;
ID NAME
---------- ---------------------------------------------
1 1
11 11
21 21
zx@ORCL>select * from t2;
ID NAME
---------- ---------------------------------------------
2 2
--查看表存储表空间
--t2在USERS表空间,t1各个分区都在TT表空间
zx@ORCL>col segment_name for a20
zx@ORCL>col partition_name for a15
zx@ORCL>col tablespace_name for a15
zx@ORCL>select segment_name,partition_name,tablespace_name from dba_segments where segment_name in ('T1','T2');
SEGMENT_NAME PARTITION_NAME TABLESPACE_NAME
-------------------- --------------- ---------------
T2 USERS
T1 P3 TT
T1 P2 TT
T1 P1 TT
--查看各表的extent信息
zx@ORCL>select SEGMENT_NAME,BLOCK_ID,BLOCKS,TABLESPACE_NAME from dba_extents where segment_name='T2';
SEGMENT_NAME BLOCK_ID BLOCKS TABLESPACE_NAME
-------------------- ---------- ---------- ---------------
T2 192 8 USERS
zx@ORCL>select SEGMENT_NAME,PARTITION_NAME,BLOCK_ID,BLOCKS,TABLESPACE_NAME from dba_extents where segment_name='T1';
SEGMENT_NAME PARTITION_NAME BLOCK_ID BLOCKS TABLESPACE_NAME
-------------------- --------------- ---------- ---------- ---------------
T1 P2 21376 1024 TT
T1 P3 22400 1024 TT
T1 P1 20352 1024 TT
|
t1分区p1与t2表交换分区
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
| --分区
zx@ORCL>alter table t1 exchange partition p1 with table t2;
Table altered.
zx@ORCL>select * from t2;
ID NAME
---------- ---------------------------------------------
1 1
zx@ORCL>select * from t1;
ID NAME
---------- ---------------------------------------------
2 2
11 11
21 21
|
可以看到p1分区里的数据交换到了t2表里,而t2表里里的数据也存储到了t1表中。再次查看各表所在的表空间和extent
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
| --查看表空间
zx@ORCL>select segment_name,partition_name,tablespace_name from dba_segments where segment_name in ('T1','T2');
SEGMENT_NAME PARTITION_NAME TABLESPACE_NAME
-------------------- --------------- ---------------
T2 TT
T1 P3 TT
T1 P2 TT
T1 P1 USERS
--查看extent
zx@ORCL>select SEGMENT_NAME,BLOCK_ID,BLOCKS,TABLESPACE_NAME from dba_extents where segment_name='T2';
SEGMENT_NAME BLOCK_ID BLOCKS TABLESPACE_NAME
-------------------- ---------- ---------- ---------------
T2 20352 1024 TT
zx@ORCL>select SEGMENT_NAME,PARTITION_NAME,BLOCK_ID,BLOCKS,TABLESPACE_NAME from dba_extents where segment_name='T1';
SEGMENT_NAME PARTITION_NAME BLOCK_ID BLOCKS TABLESPACE_NAME
-------------------- --------------- ---------- ---------- ---------------
T1 P1 192 8 USERS
T1 P2 21376 1024 TT
T1 P3 22400 1024 TT
|
从结果看到T2已经到了TT表空间,而T1的P1分区移动到了USERS表空间,而且P1分区与T2表的extent也做了交换,可以推断实际表里的数据没有移动位置,只是把数据字典里的相关信息做了更换。
二、再看看交换分区对于分区表的索引的影响
在分区表中创建索引
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
| --全局索引
zx@ORCL>create index idx_t1_id on t1(id) ;
Index created.
--分区索引
zx@ORCL>create index idx_t1_name on t1(name) local;
Index created.
zx@ORCL>select index_name,status from user_indexes where index_name like 'IDX_T1%';
INDEX_NAME STATUS
------------------------------------------------------------------------------------------ ------------------------
IDX_T1_ID VALID
IDX_T1_NAME N/A
zx@ORCL>select index_name,partition_name,status from user_ind_partitions where index_name like 'IDX_T1%';
INDEX_NAME PARTITION_NAME STATUS
------------------------------------------------------------------------------------------ --------------- ------------------------
IDX_T1_NAME P1 USABLE
IDX_T1_NAME P2 USABLE
IDX_T1_NAME P3 USABLE
|
交换分区查看是否对索引有影响
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
| zx@ORCL>alter table t1 exchange partition p1 with table t2;
Table altered.
zx@ORCL>select index_name,status from user_indexes where index_name like 'IDX_T1%';
INDEX_NAME STATUS
------------------------------------------------------------------------------------------ ------------------------
IDX_T1_NAME N/A
IDX_T1_ID UNUSABLE
zx@ORCL>select index_name,partition_name,status from user_ind_partitions where index_name like 'IDX_T1%';
INDEX_NAME PARTITION_NAME STATUS
------------------------------------------------------------------------------------------ --------------- ------------------------
IDX_T1_NAME P1 UNUSABLE
IDX_T1_NAME P2 USABLE
IDX_T1_NAME P3 USABLE
|
看到全局索引IDX_T1_ID失效了,分区P1对应的分区索引也失效了,但其他分区的分区没有受到影响
交换分区时加入 UPDATE INDEXES子句
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
| zx@ORCL>alter index idx_t1_id rebuild;
Index altered.
zx@ORCL>alter index idx_t1_name rebuild partition p1;
Index altered.
zx@ORCL>select index_name,status from user_indexes where index_name like 'IDX_T1%';
INDEX_NAME STATUS
------------------------------------------------------------------------------------------ ------------------------
IDX_T1_NAME N/A
IDX_T1_ID VALID
zx@ORCL>select index_name,partition_name,status from user_ind_partitions where index_name like 'IDX_T1%';
INDEX_NAME PARTITION_NAME STATUS
------------------------------------------------------------------------------------------ --------------- ------------------------
IDX_T1_NAME P1 USABLE
IDX_T1_NAME P2 USABLE
IDX_T1_NAME P3 USABLE
zx@ORCL>alter table t1 exchange partition p1 with table t2 update indexes ;
Table altered.
zx@ORCL>select index_name,status from user_indexes where index_name like 'IDX_T1%';
INDEX_NAME STATUS
------------------------------------------------------------------------------------------ ------------------------
IDX_T1_NAME N/A
IDX_T1_ID VALID
zx@ORCL>select index_name,partition_name,status from user_ind_partitions where index_name like 'IDX_T1%';
INDEX_NAME PARTITION_NAME STATUS
------------------------------------------------------------------------------------------ --------------- ------------------------
IDX_T1_NAME P1 UNUSABLE
IDX_T1_NAME P2 USABLE
IDX_T1_NAME P3 USABLE
|
可以看到全局索引没有受影响,但是分区索引仍然失效。
更多信息参考官方文档:http://docs.oracle.com/cd/E11882 ... min002.htm#i1107555
|
|