您好,登錄后才能下訂單哦!
從Oracle8開始,提供了從分區交換的功能,如一個分區或子分區與一個非分區表交換、一個hash分區與另一個表的hash子分區交換等等,詳細的交換方式可以參考官方文檔。
基本語法:ALTER TABLE...EXCHANGE PARTITION
實驗環境:11.2.0.4
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
一、測試分區交換
創建測試表
--分區表 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表交換分區
--分區 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
--查看表空間 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也做了交換,可以推斷實際表里的數據沒有移動位置,只是把數據字典里的相關信息做了更換。
二、再看看交換分區對于分區表的索引的影響
在分區表中創建索引
--全局索引 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
交換分區查看是否對索引有影響
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子句
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_01/server.112/e25523/part_admin002.htm#i1107555
免責聲明:本站發布的內容(圖片、視頻和文字)以原創、轉載和分享為主,文章觀點不代表本網站立場,如果涉及侵權請聯系站長郵箱:is@yisu.com進行舉報,并提供相關證據,一經查實,將立刻刪除涉嫌侵權內容。