- 性能提升: Select语句只检索本分区的记录,减少了记录总数,可有效的提升了查询性能。另外,可以通过表空间将分区映射到不同的物理磁盘上,分散设备IO,提升性能;
- 分区运维:可以针对不同分区,管理数据的加载、索引的创建(以及重建)、数据备份与恢复。因为可针对分区的管理,所以可以有效的降低了分区间的干扰、影响。
- Tables greater than 2GB should always be considered for partitioning.
- Tables containing historical data, in which new data is added into the newest partition. A typical example is a historical table where only the current month's data is updatable and the other 11 months are read only.
Tip: 计算表大小的SQL
SELECT B.OWNER, B.TABLESPACE_NAME, B.TABLE_NAME, ROUND (SUM (BYTES) / 1024 / 1024 / 1024, 6) GIGS FROM SYS.DBA_EXTENTS A, SYS.DBA_TABLES B WHERE ((B.TABLESPACE_NAME = A.TABLESPACE_NAME) AND (B.OWNER = UPPER ('&OWNER')) AND (B.TABLE_NAME = '&TABLE')) GROUP BY B.OWNER, B.TABLESPACE_NAME, B.TABLE_NAME; |
Partitioning Method |
Brief Description |
Used when there are logical ranges of data. Possible usage: dates, part numbers, and serial numbers |
|
Used to spread data evenly over partitions. Possible usage: data has no logical groupings |
|
Used to list together unrelated data into partitions. Possible usage: a number of states list partitioned into a region |
|
Used to range partition first, then spreads data into hash partitions. Possible usage: range partition by date of birth then hash partition by name; store the results into the hash partitions |
|
Used to range partition first, then spreads data into list partitions.Possible usage: range partition by date of birth then list partition by state, then store the results into the list partitions |
create tablespace invoices_2011 datafile 'e:\app\TianPan\oradata\tbs02.dbf' size 50m;
create tablespace invoices_2012 datafile 'e:\app\TianPan\oradata\tbs03.dbf' size 50m;
create tablespace invoices_2013 datafile 'e:\app\TianPan\oradata\tbs04.dbf' size 50m;
--创建Range类型的分区表
CREATE TABLE Invoices(
Invoice_NO VARCHAR2(10),
Invoice_Creation_Day DATE,
Invoice_Data VARCHAR2(30)
)
PARTITION BY RANGE(Invoice_Creation_Day)
(
PARTITION part01 VALUES LESS THAN(TO_DATE('2010-12-31 00:00:00','yyyy-mm-dd hh24:mi:ss')) TABLESPACE invoices_2010,
PARTITION part02 VALUES LESS THAN(TO_DATE('2011-12-31 00:00:00','yyyy-mm-dd hh24:mi:ss')) TABLESPACE invoices_2011,
PARTITION part03 VALUES LESS THAN(TO_DATE('2012-12-31 00:00:00','yyyy-mm-dd hh24:mi:ss')) TABLESPACE invoices_2012,
PARTITION part04 VALUES LESS THAN (MAXVALUE) TABLESPACE invoices_2013
);
--按年插入测试数据
insert into Invoices values('1',TO_DATE('2010-06-10 00:00:00','yyyy-mm-dd hh24:mi:ss'), '2010 invoice');
insert into Invoices values('2',TO_DATE('2011-07-20 00:00:00','yyyy-mm-dd hh24:mi:ss'), '2011 invoice');
insert into Invoices values('3',TO_DATE('2012-08-25 00:00:00','yyyy-mm-dd hh24:mi:ss'), '2012 invoice');
insert into Invoices values('4',TO_DATE('2013-08-25 00:00:00','yyyy-mm-dd hh24:mi:ss'), '2013 invoice');
commit;
--查询确认,是不是数据被存储到正确的分区
INVOICE_NO INVOICE_CREATION_DAY INVOICE_DATA
---------- -------------------- ------------------------------
1 2010/6/10 2010 invoice
2 2011/7/20 2011 invoice
3 2012/8/25 2012 invoice
4 2013/8/25 2013 invoice
SQL> select * from Invoices partition(part01);
INVOICE_NO INVOICE_CREATION_DAY INVOICE_DATA
---------- -------------------- ------------------------------
1 2010/6/10 2010 invoice
SQL> select * from Invoices partition(part02);
INVOICE_NO INVOICE_CREATION_DAY INVOICE_DATA
---------- -------------------- ------------------------------
2 2011/7/20 2011 invoice
create tablespace TS01 datafile 'e:\app\TianPan\oradata\list\tbs01.dbf' size 50m;
create tablespace TS02 datafile 'e:\app\TianPan\oradata\list\tbs02.dbf' size 50m;
create tablespace TS03 datafile 'e:\app\TianPan\oradata\list\tbs03.dbf' size 50m;
create tablespace TS04 datafile 'e:\app\TianPan\oradata\list\tbs04.dbf' size 50m;
create tablespace TS05 datafile 'e:\app\TianPan\oradata\list\tbs05.dbf' size 50m;
--把不同的州划分到不同的分区(表空间)中
CREATE TABLE PARTITION_BY_LIST
(DEPTID NUMBER,
DEPTNAME VARCHAR2(15),
STATE VARCHAR2(2) ,
CONSTRAINT PARTITION_BY_LIST_PK PRIMARY KEY (DEPTID))
PARTITION BY LIST (STATE)
(PARTITION DEPTS_IN_NORTH VALUES ('AK') TABLESPACE TS01,
PARTITION DEPTS_IN_EAST VALUES ('NY', 'NJ', 'VA', 'CT') TABLESPACE TS02,
PARTITION DEPTS_IN_SOUTH VALUES ('TX', 'MS', 'GA', 'KY') TABLESPACE TS03,
PARTITION DEPTS_IN_WEST VALUES ('CA', 'AZ', 'OR', 'NV') TABLESPACE TS04,
PARTITION DEPTS_WITH_NO_REGION VALUES (DEFAULT) TABLESPACE TS05)
ENABLE ROW MOVEMENT;
--检查分区是否创建正确
SELECT TABLE_NAME, PARTITION_NAME, HIGH_VALUE, TABLESPACE_NAME
FROM USER_TAB_PARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_LIST'
ORDER BY TABLESPACE_NAME;
--插入测试数据
INSERT INTO PARTITION_BY_LIST (DEPTID, DEPTNAME, STATE) VALUES (1,'ANCHORAGE' , 'AK');
INSERT INTO PARTITION_BY_LIST (DEPTID, DEPTNAME, STATE) VALUES (2,'NEW YORK' , 'NY');
INSERT INTO PARTITION_BY_LIST (DEPTID, DEPTNAME, STATE) VALUES (3,'DALLAS' , 'TX');
INSERT INTO PARTITION_BY_LIST (DEPTID, DEPTNAME, STATE) VALUES (4,'LOS ANGELES', 'CA');
INSERT INTO PARTITION_BY_LIST (DEPTID, DEPTNAME, STATE) VALUES (5,'WAIKIKI' , 'HI');
COMMIT;
--查询确认,是不是数据被存储到正确的分区
SQL> select * from PARTITION_BY_LIST;
DEPTID DEPTNAME STATE
---------- --------------- -----
1 ANCHORAGE AK
2 NEW YORK NY
3 DALLAS TX
4 LOS ANGELES CA
5 WAIKIKI HI
SQL> select * from PARTITION_BY_LIST partition (depts_in_north);
DEPTID DEPTNAME STATE
---------- --------------- -----
1 ANCHORAGE AK
SQL> select * from PARTITION_BY_LIST partition (depts_in_east);
DEPTID DEPTNAME STATE
---------- --------------- -----
2 NEW YORK NY
SQL> select * from PARTITION_BY_LIST partition (depts_with_no_region);
DEPTID DEPTNAME STATE
---------- --------------- -----
5 WAIKIKI HI
SELECT * FROM dba_part_indexes;
SELECT * FROM dba_ind_partitions WHERE index_name = '<index_name>';
Export: Release 11.2.0.1.0 - Production on Fri Jan 9 16:18:05 2015
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Export done in ZHS16GBK character set and AL16UTF16 NCHAR character set
About to export specified tables via Conventional Path ...
. . exporting table INVOICES
. . exporting partition PART01 1 rows exported
. . exporting partition PART02 1 rows exported
. . exporting partition PART03 1 rows exported
. . exporting partition PART04 1 rows exported
Export terminated successfully without warnings.
分区表导出
Export: Release 11.2.0.1.0 - Production on Fri Jan 9 16:21:04 2015
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Export done in ZHS16GBK character set and AL16UTF16 NCHAR character set
About to export specified tables via Conventional Path ...
. . exporting table INVOICES
. . exporting partition PART03 1 rows exported
Export terminated successfully without warnings.
全表导入
expdp scott/tiger directory=dmp dumpfile=tb_pt.dmp logfile=tb_pb.log tables=tb_pt parallel=3
导出多个分区
expdp scott/tiger directory=dmp dumpfile=tb_pts.dmp logfile=tb_pt.log tables=(tb_pt:sal_16,tb_pt:sal_other) parallel=2
导入单个分区
impdp scott/tiger directory=dmp dumpfile=tb_pts.dmp logfile=tb_pt_imp.log tables=tb_pt:sal_other skip_unusable_indexes=y table_exists_action=replace
导入整个表
impdp scott/tiger directory=dmp dumpfile=tb_pt.dmp logfile=tb_pt_fullimp.log tables=tb_pt skip_unusable_indexes=y table_exists_action=replace