Oracle 11gR2 List-Range分区实验

一、实验目的

     採用List-Range分区,对主分区指定表空间或者对子分区指定表空的不同情况,測试例如以下内容:

1、对List主分区不指定表空间。对Range子分区指定表空间,数据实际存储在哪个表空间;追加List主分区不指定Range子分区和指定Range子分区时,Oracle怎样创建相关子分区;

2、对List主分区指定表空间,对Range子分区不指定表空间。数据实际存储在哪个表空间;追加List主分区不指定Range子分区和指定Range子分区时,Oracle怎样创建相关子分区;


二、实验环境

操作系统:Window 7 旗舰版 x64

Cpu:Intel i5-2520M 2.50GHz X 2 

内存:10G

Oracle版本号:Release 11.2.0.1.0


三、List指定表空间測试

3.1、创建表空间

CREATE TABLESPACE "TS_3512860010" DATAFILE 'D:APPORADATAORCLTS_3512860010.dbf' SIZE 50M AUTOEXTEND ON NEXT16K MAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;

CREATE TABLESPACE "TS_3512860005" DATAFILE 'D:APPORADATAORCLTS_3512860005.dbf' SIZE 50M AUTOEXTEND ON NEXT16K MAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;

CREATE TABLESPACE "TS_3512834993" DATAFILE 'D:APPORADATAORCLTS_3512834993.dbf' SIZE 50M AUTOEXTEND ON NEXT16K MAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;


3.2、两个List两个Range測试

3.2.1、 创建分区

drop table LST_RNG_LIST cascade constraints;

/*==============================================================*/

/* Table: LST_RNG_LIST                                        */

/*==============================================================*/

create table LST_RNG_LIST

(

   AUTO_ID            VARCHAR2(36)         not null,

   SALE_NO            VARCHAR2(36)         not null,

   POS_CODE           VARCHAR2(10),

   POS_NAME           VARCHAR2(30),

   TOTAL_AMOUNT        NUMBER(18,2),

   SALE_DATE           DATE,

   REMARK             VARCHAR2(500),

   constraint PK_LST_RNG_LISTprimary key (AUTO_ID)

)

partition by list

 (POS_CODE)

 subpartition by range

 (SALE_DATE)

       subpartition template (

           subpartition SP_20150726

           values less than (TO_DATE('2015-07-26','YYYY-MM-DD')),

           subpartition SP_20150802

           values less than (TO_DATE('2015-08-02','YYYY-MM-DD'))

       )

    (

       partition

            P_3512860010

           values ('3512860010')

 tablespace TS_3512860010,

       partition

            P_3512860005

           values ('3512860005')

 tablespace TS_3512860005

    );

comment on column LST_RNG_LIST.AUTO_ID is

'自己主动编号';

comment on column LST_RNG_LIST.SALE_NO is

'销售单号';

comment on column LST_RNG_LIST.POS_CODE is

'商户代码';

comment on column LST_RNG_LIST.POS_NAME is

'商户名称';

comment on column LST_RNG_LIST.TOTAL_AMOUNTis

'销售总额';

comment on column LST_RNG_LIST.SALE_DATE is

'销售日期';

comment on column LST_RNG_LIST.REMARK is

'备注';

3.2.2、查看分区

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions

where table_name='LST_RNG_LIST';



查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions

where table_name='LST_RNG_LIST';


Range子分区所属表空间自己主动归入List分区所属表空间


3.2.3、插入数据

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507260001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-07-26','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507290001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-07-29','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201508010001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-08-01','YYYY-MM-DD'),NULL);

  

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507260001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-07-26','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507290001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-07-29','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201508010001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-08-01','YYYY-MM-DD'),NULL);

commit;


3.2.4、查看数据

查看分区数据 

select * from LST_RNG_LIST partition(P_3512860010);

select * from LST_RNG_LIST partition(P_3512860005);

select * from LST_RNG_LIST subpartition(P_3512860010_SP_20150726);

select * from LST_RNG_LIST subpartition(P_3512834993_SP_20150802);

收集分区统计信息

begin

dbms_stats.gather_table_stats(ownname=>'WKOD_VERIFY',granularity =>'all',tabname=>'LST_RNG_LIST',cascade=>true);

end;

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_LIST';


num_rows=5,LST_PNG_LIST表分别在两个表空间中有5条数据


查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_LIST';



3.2.5、追加分区

方式一:追加主分区

alter table LST_RNG_LIST add partitionP_3512834993 values ('3512834993') tablespace TS_3512834993

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions

where table_name='LST_RNG_LIST';



查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions

where table_name='LST_RNG_LIST';


默认依照表创建时子分区的的分区规则,自己主动生成两个子分区(红色框内)


删除加入的List分区

alter table LST_RNG_LIST drop partitionP_3512834993;

相应的子分区会自己主动被drop掉。


方式二:追加主分区及其子分区

alter table LST_RNG_LIST add partition P_3512834993 values ('3512834993') tablespace TS_3512834993

(subpartition P_3512834993_SP_20150726 values less than (TO_DATE('2015-07-26','YYYY-MM-DD')))

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions

where table_name='LST_RNG_LIST';

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions

where table_name='LST_RNG_LIST';


依照设定的子分区创建range子分区


3.3、两个List一个Range測试

3.3.1、创建分区

drop table LST_RNG_LIST cascade constraints;

/*==============================================================*/

/* Table: LST_RNG_LIST                                        */

/*==============================================================*/

create table LST_RNG_LIST

(

   AUTO_ID            VARCHAR2(36)         not null,

   SALE_NO            VARCHAR2(36)         not null,

   POS_CODE            VARCHAR2(10),

   POS_NAME           VARCHAR2(30),

   TOTAL_AMOUNT        NUMBER(18,2),

   SALE_DATE           DATE,

   REMARK             VARCHAR2(500),

   constraint PK_LST_RNG_LISTprimary key (AUTO_ID)

)

partition by list

 (POS_CODE)

 subpartition by range

 (SALE_DATE)

       subpartition template (

           subpartition SP_20150726

           values less than (TO_DATE('2015-07-26','YYYY-MM-DD'))

       )

    (

       partition

            P_3512860010

           values ('3512860010')

 tablespace TS_3512860010,

       partition

            P_3512860005

           values ('3512860005')

 tablespace TS_3512860005

    );

comment on column LST_RNG_LIST.AUTO_ID is

'自己主动编号';

comment on column LST_RNG_LIST.SALE_NO is

'销售单号';

comment on column LST_RNG_LIST.POS_CODE is

'商户代码';

comment on column LST_RNG_LIST.POS_NAME is

'商户名称';

comment on column LST_RNG_LIST.TOTAL_AMOUNTis

'销售总额';

comment on column LST_RNG_LIST.SALE_DATE is

'销售日期';

comment on column LST_RNG_LIST.REMARK is

'备注';


3.3.2、查看分区

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions

where table_name='LST_RNG_LIST';


 

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions

where table_name='LST_RNG_LIST';


Range子分区所属表空间自己主动归入List分区所属表空间


3.3.3、插入数据

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_LIST(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

commit;


3.3.4、查看数据

查看分区数据 

select * from LST_RNG_LIST partition(P_3512860010);

select * from LST_RNG_LIST partition(P_3512860005);

select * from LST_RNG_LIST subpartition(P_3512860010_SP_20150726);

--select * from LST_RNG_LIST subpartition(P_3512834993_SP_20150802);

收集分区统计信息

begin

dbms_stats.gather_table_stats(ownname=>'WKOD_VERIFY',granularity =>'all',tabname=>'LST_RNG_LIST',cascade=>true);

end;

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_LIST';


num_rows=2。LST_PNG_LIST表分别在两个表空间中有2条数据


查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_LIST';



3.3.5、追加分区

方式一:追加主分区

alter table LST_RNG_LIST add partition P_3512834993 values ('3512834993')  tablespace TS_3512834993

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_LIST';


查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_LIST';


默认依照表创建时子分区的的分区规则,自己主动生成一个子分区(红色框内)

删除加入的List分区

alter table LST_RNG_LIST drop partitionP_3512834993;

相应的子分区会自己主动被drop掉。



方式二:追加主分区及其子分区

alter table LST_RNG_LIST add partition P_3512834993 values ('3512834993') tablespace TS_3512834993

(subpartition P_3512834993_SP_20150802values less than (TO_DATE('2015-08-02','YYYY-MM-DD')))

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_LIST';


查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_LIST';


依照设定的子分区创建range子分区


四、Range指定表空间測试

4.1、创建表空间

CREATE TABLESPACE "TS_20150726" DATAFILE 'D:APPORADATAORCLTS_20150726.dbf' SIZE 50M AUTOEXTEND ON NEXT 16KMAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;

CREATE TABLESPACE "TS_20150802" DATAFILE 'D:APPORADATAORCLTS_20150802.dbf' SIZE 50M AUTOEXTEND ON NEXT 16KMAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;

CREATE TABLESPACE "TS_20150809" DATAFILE 'D:APPORADATAORCLTS_20150809.dbf' SIZE 50M AUTOEXTEND ON NEXT 16KMAXSIZE UNLIMITED LOGGING EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENTAUTO;


4.2、两个List两个Range測试

4.2.1、创建分区表

drop table LST_RNG_RANGE cascade constraints;

/*==============================================================*/

/* Table:LST_RNG_RANGE                                        */

/*==============================================================*/

create table LST_RNG_RANGE 

(

  AUTO_ID             VARCHAR2(36)         not null,

  SALE_NO             VARCHAR2(36)         not null,

  POS_CODE            VARCHAR2(10),

  POS_NAME            VARCHAR2(30),

  TOTAL_AMOUNT         NUMBER(18,2),

  SALE_DATE           DATE,

  REMARK              VARCHAR2(500),

   constraint PK_LST_RNG_RANGEprimary key (AUTO_ID)

)

partition by list

 (POS_CODE)

 subpartition by range

 (SALE_DATE)

       subpartition template (

           subpartition SP_20150726

           values less than (TO_DATE('2015-07-26','YYYY-MM-DD'))

 tablespace TS_20150726,

           subpartition SP_20150802

           values less than (TO_DATE('2015-08-02','YYYY-MM-DD'))

 tablespace TS_20150802

       )

    (

       partition

            P_3512860010

           values ('3512860010'),

       partition

            P_3512860005

           values ('3512860005')

    );

comment on column LST_RNG_RANGE.AUTO_ID is

'自己主动编号';

comment on column LST_RNG_RANGE.SALE_NO is

'销售单号';

comment on column LST_RNG_RANGE.POS_CODE is

'商户代码';

comment on column LST_RNG_RANGE.POS_NAME is

'商户名称';

comment on column LST_RNG_RANGE.TOTAL_AMOUNT is

'销售总额';

comment on column LST_RNG_RANGE.SALE_DATE is

'销售日期';

comment on column LST_RNG_RANGE.REMARK is

'备注';


4.2.2、查看分区

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


未指定表空间的主分区,默认使用当前用户所在的表空间。 

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


Range子分区存放于指定的表空间中


4.2.3、插入数据

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507260001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-07-26','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507290001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-07-29','YYYY-MM-DD'),NULL);

INSERT INTOLST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201508010001','3512860010','全味食品商贸有限公司','1132.23',TO_DATE('2015-08-01','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507260001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-07-26','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507290001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-07-29','YYYY-MM-DD'),NULL);


INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201508010001','3512860005','新干线贸易有限公司','1132.23',TO_DATE('2015-08-01','YYYY-MM-DD'),NULL);


commit;


4.2.4、查看数据

查看分区数据 

select * from LST_RNG_RANGE partition(P_3512860010);

select * from LST_RNG_RANGE partition(P_3512860005);

select * from LST_RNG_RANGE subpartition(P_3512860010_SP_20150726);

select * from LST_RNG_RANGE subpartition(P_3512860005_SP_20150726);

select * from LST_RNG_RANGE subpartition(P_3512860010_SP_20150802);

select * from LST_RNG_RANGE subpartition(P_3512860005_SP_20150802);

收集分区统计信息

begin

dbms_stats.gather_table_stats(ownname=>'WKOD_VERIFY',granularity =>'all',tabname=>'LST_RNG_RANGE',cascade=>true);

end;

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


num_rows=5,LST_PNG_RANGE表的两个主分区在当前用户所在的表空间中有各5条数据

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


4.2.5、追加分区

方式一:追加主分区

alter table LST_RNG_RANGE add partition P_3512834993 values ('3512834993')

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


主分区所属表空间为当前用户所在的表空间

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


默认依照表创建时子分区的的分区规则,自己主动生成两个子分区(红色框内)。且分区相应表空间与原来一致

删除加入的List分区

alter table LST_RNG_RANGE drop partition P_3512834993;

相应的子分区会自己主动被drop掉。


方式二:追加主分区及其子分区

alter table LST_RNG_RANGE add partition P_3512834993 values ('3512834993')

(subpartition P_3512834993_SP_20150802 values less than (TO_DATE('2015-08-02','YYYY-MM-DD'))  tablespace TS_20150809)

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


主分区所属表空间为当前用户所在的表空间

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


依照设定的子分区所属的表空间创建range子分区


4.3、两个List一个Range測试

drop table LST_RNG_RANGE cascade constraints;

/*==============================================================*/

/* Table:LST_RNG_RANGE                                        */

/*==============================================================*/

create table LST_RNG_RANGE 

(

  AUTO_ID             VARCHAR2(36)         not null,

  SALE_NO             VARCHAR2(36)         not null,

  POS_CODE            VARCHAR2(10),

   POS_NAME            VARCHAR2(30),

  TOTAL_AMOUNT         NUMBER(18,2),

  SALE_DATE           DATE,

  REMARK              VARCHAR2(500),

   constraint PK_LST_RNG_RANGEprimary key (AUTO_ID)

)

partition by list

 (POS_CODE)

 subpartition by range

 (SALE_DATE)

       subpartition template (

           subpartition SP_20150726

           values less than (TO_DATE('2015-07-26','YYYY-MM-DD'))

 tablespace TS_20150726

       )

    (

       partition

            P_3512860010

           values ('3512860010'),

       partition

            P_3512860005

           values ('3512860005')

    );

comment on column LST_RNG_RANGE.AUTO_ID is

'自己主动编号';

comment on column LST_RNG_RANGE.SALE_NO is

'销售单号';

comment on column LST_RNG_RANGE.POS_CODE is

'商户代码';

comment on column LST_RNG_RANGE.POS_NAME is

'商户名称';

comment on column LST_RNG_RANGE.TOTAL_AMOUNT is

'销售总额';

comment on column LST_RNG_RANGE.SALE_DATE is

'销售日期';

comment on column LST_RNG_RANGE.REMARK is

'备注';


4.3.2、查看分区

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


未指定表空间的主分区,默认使用当前用户所在的表空间。 

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


Range子分区存放于指定的表空间中


4.3.3、插入数据

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860005','新干线贸易有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507240001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-24','YYYY-MM-DD'),NULL);

INSERT INTO LST_RNG_RANGE(AUTO_ID,SALE_NO,POS_CODE,POS_NAME,TOTAL_AMOUNT,SALE_DATE,REMARK)

VALUES(SYS_GUID(),'SN201507250001','3512860010','全味食品商贸有限公司','100.78',TO_DATE('2015-07-25','YYYY-MM-DD'),NULL);

commit;


4.3.4、查看数据

查看分区数据 

select * from LST_RNG_RANGE partition(P_3512860010);

select * from LST_RNG_RANGE partition(P_3512860005);

select * from LST_RNG_RANGE subpartition(P_3512860010_SP_20150726);

select * from LST_RNG_RANGE subpartition(P_3512860005_SP_20150726);

收集分区统计信息

begin

dbms_stats.gather_table_stats(ownname=>'WKOD_VERIFY',granularity =>'all',tabname=>'LST_RNG_RANGE',cascade=>true);

end;

查看主分组

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


num_rows=2,LST_PNG_RANGE表的两个主分区在当前用户所在的表空间中各有2条数据

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


两个分区在同一个表空间中,每一个分区中都存在两条数据


4.3.5、追加分区

方式一:追加主分区

alter table LST_RNG_RANGE add partition P_3512834993 values ('3512834993')

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


主分区所属表空间为当前用户所在的表空间

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


默认依照表创建时子分区的的分区规则,自己主动生成一个子分区(红色框内),且分区相应表空间与原来一致

删除加入的List分区

alter table LST_RNG_RANGE drop partition P_3512834993;

相应的子分区会自己主动被drop掉。


方式二:追加主分区及其子分区

alter table LST_RNG_RANGE add partition P_3512834993 values ('3512834993')

(subpartition P_3512834993_SP_20150802 values less than (TO_DATE('2015-08-02','YYYY-MM-DD'))  tablespace TS_20150809)

查看分区

select partition_position,table_name,partition_name,high_value,tablespace_name,num_rows

from user_tab_partitions 

where table_name='LST_RNG_RANGE';


主分区所属表空间为当前用户所在的表空间

查看子分区

select subpartition_position,table_name,partition_name,subpartition_name,high_value,tablespace_name,num_rows

from user_tab_subpartitions 

where table_name='LST_RNG_RANGE';


依照设定的子分区所属的表空间创建range子分区



五、实验结论

一、List-Range组合分区下。在List指定表空间,Range不指定表空间。Oracle自己主动将Range子分区存放于相应的List表空间中。

二、追加分区时候。在不指定子分区的情况下,Oracle默认依照表创建时的分区方式,对新追加的List分区下的子分区进行分区;

三、List-Range组合分区,全部表的数据实际存放在子分区所在的表空间。


附:

1、DROP TABLE

drop table LST_RNG_RANGE;

--并不是真删,而是置DROP标志,相关分区也依旧存在

select * from user_recyclebin;

实际清空

purge table LST_RNG_RANGE;


2、查看数据记录所在表空间

SELECT B.TABLESPACE_NAME

FROM DBA_DATA_FILES B

WHERE B.FILE_ID = (SELECTDBMS_ROWID.ROWID_RELATIVE_FNO(ROWID) FILE_ID

                  FROM LST_RNG_RANGE A

                  WHERE A.SALE_NO='SN201507260001');


3、经常使用分区表相关语句


--显示数据库全部分区表的信息:
select * from DBA_PART_TABLES;


--显示当前用户可訪问的全部分区表信息:
select * from ALL_PART_TABLES;


--显示当前用户全部分区表的信息:
select * from USER_PART_TABLES;


--显示表分区信息 显示数据库全部分区表的具体分区信息:
select * from DBA_TAB_PARTITIONS;


--显示当前用户可訪问的全部分区表的具体分区信息:
select * from ALL_TAB_PARTITIONS;


--显示当前用户全部分区表的具体分区信息:
select * from USER_TAB_PARTITIONS;


--显示子分区信息 显示数据库全部组合分区表的子分区信息:
select * from DBA_TAB_SUBPARTITIONS;


--显示当前用户可訪问的全部组合分区表的子分区信息:
select * from ALL_TAB_SUBPARTITIONS;


--显示当前用户全部组合分区表的子分区信息:
select * from USER_TAB_SUBPARTITIONS;


--显示分区列 显示数据库全部分区表的分区列信息:
select * from DBA_PART_KEY_COLUMNS;


--显示当前用户可訪问的全部分区表的分区列信息:
select * from ALL_PART_KEY_COLUMNS;


--显示当前用户全部分区表的分区列信息:
select * from USER_PART_KEY_COLUMNS;


--显示子分区列 显示数据库全部分区表的子分区列信息:
select * from DBA_SUBPART_KEY_COLUMNS;


--显示当前用户可訪问的全部分区表的子分区列信息:
select * from ALL_SUBPART_KEY_COLUMNS;


--显示当前用户全部分区表的子分区列信息:
select * from USER_SUBPART_KEY_COLUMNS;


--如何查询出oracle数据库中全部的的分区表
select * from user_tables a where a.partitioned='YES';


--删除一个表的数据是
truncate table table_name;


--删除分区表一个分区的数据是
alter table table_name truncate partition p5;


原文地址:https://www.cnblogs.com/wzjhoutai/p/7102133.html