|
--把kingstar.emp表的数据迁移到kingstar.EMP_partition分区表中
--创建数据源表结构
drop table kingstar.emp;
create table kingstar.emp as select * from scott.emp where 1=2;
alter table kingstar.EMP
add constraint PK_EMP primary key (EMPNO)
using index
tablespace USERS
pctfree 10
initrans 2
maxtrans 255
storage
(
initial 64K
minextents 1
maxextents unlimited
);
truncate table kingstar.emp;
--插入数据
insert into kingstar.emp values (1,' 蔡浪','D',0,to_date('20080801 12:22:13','yyyymmdd hh24:mi:ss'),1000,1000,10);
insert into kingstar.emp values (2,' 蔡星','D',1,to_date('20080901 13:23:12','yyyymmdd hh24:mi:ss'),5000,5000,10);
commit;
--查看迁移表中的数据
select * from kingstar.emp;
1 1 蔡浪 D 0 2008-8-1 12:22:13 1000.00 1000.00 10
2 2 蔡星 D 1 2008-9-1 13:23:12 5000.00 5000.00 10
--创建分区表 结构与kingstar.emp一样
-- Create table
create table kingstar.EMP_partition
(
EMPNO NUMBER(4),
ENAME VARCHAR2(10),
JOB VARCHAR2(9),
MGR NUMBER(4),
HIREDATE DATE,
SAL NUMBER(7,2),
COMM NUMBER(7,2),
DEPTNO NUMBER(2)
)
tablespace KINGSTAR
partition by range(hiredate)
(partition emp_max values less than(maxvalue))--由于交换数据时需指定分区,所以这里不做详细分区,数据交换完后进行分区的拆分
;
--进行数据交换
alter table kingstar.EMP_partition exchange partition emp_max with table kingstar.emp;
--查分区表数据
select * from kingstar.EMP_partition;
1 1 蔡浪 D 0 2008-8-1 12:22:13 1000.00 1000.00 10
2 2 蔡星 D 1 2008-9-1 13:23:12 5000.00 5000.00 10
--查源表数据已被清空
select * from kingstar.emp;
--往源表插数据,索引失效
insert into kingstar.emp values (1,' 蔡浪','D',0,to_date('20080801 12:22:13','yyyymmdd hh24:mi:ss'),1000,1000,10);
insert into kingstar.emp values (2,' 蔡星','D',1,to_date('20080901 13:23:12','yyyymmdd hh24:mi:ss'),5000,5000,10);
第 1 行出现错误:
ORA-01502: 索引 'KINGSTAR.PK_EMP' 或这类索引的分区处于不可用状态
--索引重建
alter index kingstar.pk_emp rebuild ;
--再插入数据可以完成
insert into kingstar.emp values (1,' 蔡浪','D',0,to_date('20080801 12:22:13','yyyymmdd hh24:mi:ss'),1000,1000,10);
insert into kingstar.emp values (2,' 蔡星','D',1,to_date('20080901 13:23:12','yyyymmdd hh24:mi:ss'),5000,5000,10);
--查询数据
select * from kingstar.emp;
1 1 蔡浪 D 0 2008-8-1 12:22:13 1000.00 1000.00 10
2 2 蔡星 D 1 2008-9-1 13:23:12 5000.00 5000.00 10
--拆分分区,只能将一个分区插成两个分区,并且指定插分后的第一个分区的内容如to_date('200809','YYYYMM')就是该分区emp_200808存放200808这个月数据
--也就是相当于定义分区时的 partition emp_200808 values less then(to_date('200809','yyyymm'))
-- into (partition emp_200810,partition emp_maxes); 指定拆分出来的less than 的分区名字和maxvalue的分区名字
alter table kingstar.emp_partition split partition emp_max at(to_date('200809','YYYYMM')) into (partition emp_200808,partition emp_max);
alter table kingstar.emp_partition split partition emp_max at(to_date('200810','YYYYMM')) into (partition emp_200809,partition emp_max);
alter table kingstar.emp_partition split partition emp_max at(to_date('200811','YYYYMM')) into (partition emp_200810,partition emp_upper);
alter table kingstar.emp_partition split partition emp_upper at(to_date('200812','YYYYMM')) into (partition emp_200811,partition emp_max);
--查询分区数据
select * from kingstar.emp_partition partition(emp_200808);
1 1 蔡浪 D 0 2008-8-1 12:22:13 1000.00 1000.00 10
--修改分区名字
alter table kingstar.emp_partition rename partition emp_max to emp_upper; |
|