语言
<< 返回文章列表

Oracle 12.2新特性:多列列表分区和外部表分区

2017年12月26日
盖国强
1115

自动的列表分区创建
在线的普通表转换分区表
支持只读分区和读写分区混合
以下介绍的三个特性同样是12.2新增的:
多列列表分区、外部表分区、维护过滤

而对于多列列表分区的支持,也是大家关注已久的特性,先看一下脚本(在 livesql.oracle.com 测试执行,推荐动手实践):
CREATE TABLE dba_by_db_in_yhem
 (dbalic           NUMBER, 
  username         VARCHAR2(20),
  dbcat            VARCHAR2(4),
  region           VARCHAR2(10)
 )
 PARTITION BY LIST (dbcat, region)
 (
  PARTITION north_part VALUES (('ORCL','BEIJING'), ('ORCL','TIANJIN')),
  PARTITION south_part VALUES (('DB2','SHENZHEN'), ('DB2','GUANGZHOU')),
  PARTITION west_part  VALUES (('SQL','CHENGDU'),('ORCL','CHENGDU'),('DB2','KUNMING')),
  PARTITION east_part  VALUES ('ORCL','SHANGHAI'),
  PARTITION rest VALUES (DEFAULT)
 );
insert into  dba_by_db_in_yhem values(1,'EYGLE','ORCL','BEIJING');
insert into  dba_by_db_in_yhem values(2,'KAMUS','ORCL','BEIJING');
insert into  dba_by_db_in_yhem values(3,'LAOXIONG','SQL','CHENGDU');
insert into  dba_by_db_in_yhem values(4,'ORA-600','DB2','GUANGZHOU');
insert into  dba_by_db_in_yhem values(5,'YANGTINGKUN','ALL','BEIJING');

select * from dba_by_db_in_yhem partition (north_part);
select * from dba_by_db_in_yhem partition (south_part);
select * from dba_by_db_in_yhem partition (west_part);
select * from dba_by_db_in_yhem partition (east_part);
select * from dba_by_db_in_yhem partition (rest);

现在Oracle支持通过多列定义列表分区,最多支持16个列值定义,这极大的丰富了列表分区的适用场景。
image.png

为了简化维护操作,12.2 增加了维护过滤特性 - Filtered Partition on Maintenance Operations,也就是说,在执行分区的Move、Split和Merge等操作时,可以选择对数据进行过滤,通过一个 INCLUDING ROWS 进行限制。

继续前面的测试用例,当MOVE时指定保留分区中区域为「BEIJING」的数据后,『TIANJIN』的数据则被移除了:
insert into  dba_by_db_in_yhem values(6,'SECOOLER','ORCL','TIANJIN');
select * from dba_by_db_in_yhem partition (north_part);
ALTER TABLE dba_by_db_in_yhem MOVE PARTITION north_part
INCLUDING ROWS WHERE REGION = 'BEIJING';
select * from dba_by_db_in_yhem partition (north_part);
image.png

    在12.2中,Oracle还支持外部表分区,类似如下的语法展示了这一特性的用途,对于一个统一的外部表,可以通过分区指向不同的外部文件,不同文件可以用于存储已经分类的数据,从而更加灵活的使用外部表:
CREATE TABLE sales (loc_id number, prod_id number, cust_id number, amount_sold number, quantity_sold number)
 ORGANIZATION EXTERNAL
 (TYPE oracle_loader
  DEFAULT DIRECTORY load_d1
  ACCESS PARAMETERS
  ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII
    NOBADFILE
    LOGFILE log_dir:'sales.log'
    FIELDS TERMINATED BY ","
   )
 )
  REJECT LIMIT UNLIMITED
 PARTITION BY RANGE (loc_id)
 (PARTITION p1 VALUES LESS THAN (1000) LOCATION ('california.txt'),
  PARTITION p2 VALUES LESS THAN (2000) DEFAULT DIRECTORY load_d2 LOCATION ('washington.txt'),
  PARTITION p3 VALUES LESS THAN (3000))


了解了Oracle这些新的变化,将有助于我们深入和灵活的去使用Oracle数据库。