1. 创建分区表
create table range_part_range(id number, deal_date date, contents varchar2(1000))
partition by range(deal_date)
(
partition p1 values less than (to_date('2015-01-21', 'yyyy-mm-dd')),
partition p2 values less than (to_date('2015-01-22', 'yyyy-mm-dd')),
partition p3 values less than (to_date('2015-01-23', 'yyyy-mm-dd')),
partition p_max values less than (maxvalue)
);
partition by range(deal_date)
(
partition p1 values less than (to_date('2015-01-21', 'yyyy-mm-dd')),
partition p2 values less than (to_date('2015-01-22', 'yyyy-mm-dd')),
partition p3 values less than (to_date('2015-01-23', 'yyyy-mm-dd')),
partition p_max values less than (maxvalue)
);
插入记录
insert into range_part_range values(1, to_date('2015-01-21', 'yyyy-mm-dd'), 'a');
insert into range_part_range values(2, to_date('2015-01-22', 'yyyy-mm-dd'), 'b');
insert into range_part_range values(3, to_date('2015-01-23', 'yyyy-mm-dd'), 'c');
检索记录
select count(*) from range_part_range;
COUNT(*)
----------
3
----------
3
select count(*) from range_part_range partition(p1);
COUNT(*)
----------
0
----------
0
select count(*) from range_part_range partition(p2);
COUNT(*)
----------
1
----------
1
select count(*) from range_part_range partition(p3);
COUNT(*)
----------
1
----------
1
select count(*) from range_part_range partition(p_max);
COUNT(*)
----------
1
----------
1
2. 创建普通表,用于分区交换
create table range_tbl (id number, deal_date date, contents varchar2(1000));
插入记录
insert into range_tbl values(1000, to_date('2015-01-25', 'yyyy-mm-dd'), 'j');
3. 执行分区交换
alter table range_part_range exchange partition p3 with table range_tbl
*
ERROR at line 1:
ORA-14099: all rows in table do not qualify for specified partition
*
ERROR at line 1:
ORA-14099: all rows in table do not qualify for specified partition
注意:此处range_tbl中的数据明显不是在p3分区的范围之内,而是在p_max分区范围内,因此报了错。
4. 解决方案一:换一个正确的分区
alter table range_part_range exchange partition p_max with table range_tbl;
select * from range_tbl;中记录现在是原来p_max的记录,
select * from range_part_range partition(p_max);中记录现在是原来range_tbl的记录。
解决方案二:使用without validation
alter table range_part_range exchange partition p3 with table range_tbl without validation;
select * from range_tbl;中记录现在是原来p3的记录,
select * from range_part_range partition(p3);中记录现在是原来range_tbl的记录。
总结:
1. 对于交换分区,普通表中若有数据,要确保其值在交换的分区范围内,否则会提示错误。
2. 尽量不要用without validation,这样会绕开校验,像上例,p3分区会包含一个不在其分区范围内的数据,有可能扰乱了分区的目的。