【背景】公司业务系统的数据增长很快,需要进行定期进行归档,其中有些数据用分区表进行存储,归档完之后释放了大量的空间,之前已经有文档介绍普通表进行shrink操作的步骤,本文档记录对Oracle分区表和复合分区表进行shrink的操作; 测试环境的搭建】
Oracle数据库版本:11.2.0.3
分区表的创建 CREATE TABLE SCOTT.PTABLE (
GG1DM VARCHAR2(9 BYTE),
SL NUMBER(18,4) ,
DJBH VARCHAR2(20 BYTE)
)
NOCOMPRESS
PARTITION BY LIST (GG1DM)
SUBPARTITION BY range (SL)
(
PARTITION PTABLE_P1 VALUES ('07')
(
SUBPARTITION PTABLE1_SUB1 VALUES less than (50) ,
SUBPARTITION PTABLE1_SUB2 VALUES less than (100),
SUBPARTITION PTABLE1_SUB3 VALUES less than (150),
SUBPARTITION PTABLE1_SUB4 VALUES less than (250)
)
,
PARTITION PTABLE_P2 VALUES ('08')
(SUBPARTITION PTABLE2_SUB1 VALUES less than (50) ,
SUBPARTITION PTABLE2_SUB2 VALUES less than (100),
SUBPARTITION PTABLE2_SUB3 VALUES less than (150),
SUBPARTITION PTABLE2_SUB4 VALUES less than (250)
),
PARTITION PTABLE_P3 VALUES ('09')
( SUBPARTITION PTABLE3_SUB1 VALUES less than (50) ,
SUBPARTITION PTABLE3_SUB2 VALUES less than (100),
SUBPARTITION PTABLE3_SUB3 VALUES less than (150),
SUBPARTITION PTABLE3_SUB4 VALUES less than (250)
)
) 插入数据后需要更新统计信息: analyze table PTABLE compute statistics; 分区表的查询
select t3.table_name, t3.partition_name,t3.high_value,t3.num_rows,t3.blocks,t3.empty_blocks,t3.last_analyzed
from dba_tab_partitions t3 where t3.table_name='PTABLE' order by t3.num_rows desc
子分区表信息的查询 select t3.partition_name,t3.subpartition_name,t3.high_value,t3.num_rows,t3.blocks,t3.empty_blocks,t3.last_analyzed
from dba_tab_subpartitions t3 where t3.table_name='PTABLE' order by t3.num_rows desc
【进行删除数据的测试】 DELETE FROM SCOTT.PTABLE WHERE GG1DM='07' AND SL<=50 删除PTABLE1_SUB1里面的数据
analyze table PTABLE compute statistics; 进行统计信息的更新;
然后查看此时子分区的高水位线情况 select t3.partition_name,t3.subpartition_name,t3.high_value,t3.num_rows,t3.blocks,t3.empty_blocks,t3.last_analyzed from dba_tab_subpartitions t3 where t3.table_name='PTABLE' order by t3.num_rows desc 当前PTABLE_P1表的数据是0,但是HMW线还是没有变;
【进行高水位线的回收】 alter table PTABLE enable row movement; #开启行迁移 alter table PTABLE MODIFY SUBPARTITION PTABLE1_SUB1 shrink space; #进行子分区空间的收缩
analyze table PTABLE compute statistics; #再次更新统计信息
select t3.partition_name,t3.subpartition_name,t3.high_value,t3.num_rows,t3.blocks,t3.empty_blocks,t3.last_analyzed
from dba_tab_subpartitions t3 where t3.table_name='PTABLE' order by t3.num_rows desc; #查看子分区的情况
|