Partitioning
in Oracle 9i
Since partitioning is such an integral part of VLDB the remainder
of this article will focus on how to partition, specifically, the
partitioning of tables in an Oracle 9i. The complete article will cover:
When To Partition
There are two main reasons to use partitioning in a VLDB environment.
These reasons are related to management and performance improvement.
Partitioning offers:
- Management at the individual partition level for data loads, index
creation and rebuilding, and backup/recovery. This can result in less
down time because only individual partitions being actively managed are
unavailable.
- Increased query performance by selecting only from the relevant
partitions.
This weeding out process eliminates the partitions that do not contain
the data needed by the query through a technique called partition
pruning.
The decision about exactly when to use partitioning is rather
subjective. Some general guidelines that Oracle suggest are listed
below.
Use partitioning:
- When a table reaches a "large" size. Large being defined relative to
your environment. Tables greater than 2GB should always be considered
for partitioning.
- When performance benefits outweigh the additional management issues
related to partitioning.
- When the archiving of data is on a schedule and is repetitive. For
instance, data warehouses usually hold data for a specific amount of
time (rolling window). Old data is then rolled off to be archived.
Take a moment and evaluate the criteria above to make sure that
partitioning is advantageous for your environment. In larger
environments
partitioning is worth the time to investigate and implement.
Different Methods of
Partitioning
Oracle 9i, Release 2 has five partitioning methods for tables. They are
listed in the table below with a brief description
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 |
For partitioning of indexes, there are global and local indexes.
Global indexes provide greater flexibility by allowing indexes to be
independent of the partition method used on the table. This allows for
the global index to reference different partitions of a single table.
Local indexes (while less flexible than global) are easier to manage.
Local indexes are mapped to a specific partition. This one-to-one
relationship
between local index partitions and table partitions allows Oracle the
ability to manage local indexes.
The use of the ENABLE ROW MOVEMENT clause is included in all of the
examples of table partitioning to allow row movement if the partition
key is updated.
Range Partitioning
Range partitioning was the first partitioning method supported by
Oracle in Oracle 8. For example,
business transactions can be partitioned by various versions of date
(start date, transaction date, close date, or date of payment). Range
partitioning can also be performed on part numbers, serial numbers or
any other ranges that can be discovered. The example provided for range
partition will be on a table named PARTITION_BY_RANGE, the actual
partitioning is on the following columns BIRTH_YYYY, BIRTH_MM, and
BIRTH_DD. Each partition is assigned to its own tablespace. The last
partition is the "catch all" partition.
By using MAXVALUE the last partition will contain all the records with
values over the second to last partition
-- RANGE_ME.SQL
-- PARTITION BY RANGE ON BIRTH DATES
CREATE TABLE PARTITION_BY_RANGE
( FIRST_NAME VARCHAR2(10),
MIDDLE_INIT VARCHAR2(1),
LAST_NAME VARCHAR2(10),
BIRTH_MM INT NOT NULL,
BIRTH_DD INT NOT NULL,
BIRTH_YYYY INT NOT NULL)
PARTITION BY RANGE (BIRTH_YYYY, BIRTH_MM, BIRTH_DD)
(PARTITION DOBS_IN_1971_OR_BEFORE VALUES LESS THAN (1972, 01 ,01)
TABLESPACE
TS01,
PARTITION
DOBS_IN_1972
VALUES LESS THAN (1973, 01 ,01)
TABLESPACE TS02,
PARTITION
DOBS_IN_1973
VALUES LESS THAN (1974, 01 ,01)
TABLESPACE TS03,
PARTITION
DOBS_IN_1974
VALUES LESS THAN (1975, 01 ,01)
TABLESPACE TS04,
PARTITION DOBS_IN_1975_OR_LATER VALUES LESS THAN
(MAXVALUE, MAXVALUE, MAXVALUE) TABLESPACE TS05)
ENABLE ROW MOVEMENT;
-- CHECK TO SEE IF THE PARTITIONS ARE CORRECTLY BUILT
SELECT TABLE_NAME, PARTITION_NAME, HIGH_VALUE, TABLESPACE_NAME
FROM USER_TAB_PARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_RANGE'
ORDER BY TABLESPACE_NAME;
-- Insert Data Into Each Partition
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1969', 'A',
'SMITH_1969',
09, 20, 1969);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1970', 'A',
'SMITH_1970',
09, 20, 1970);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1971', 'A',
'SMITH_1971',
09, 20, 1971);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1972', 'A',
'SMITH_1972',
09, 20, 1972);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1973', 'A',
'SMITH_1973',
09, 20, 1973);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1974', 'A',
'SMITH_1974',
09, 20, 1974);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1975', 'A',
'SMITH_1975',
09, 20, 1975);
INSERT INTO PARTITION_BY_RANGE VALUES ('FRED_1976', 'A',
'SMITH_1976',
09, 20, 1976);
COMMIT;
-- Confirmation that everything is in the proper place
SELECT * FROM PARTITION_BY_RANGE;
SELECT * FROM PARTITION_BY_RANGE PARTITION (DOBS_IN_1971_OR_BEFORE);
SELECT * FROM PARTITION_BY_RANGE PARTITION (DOBS_IN_1972);
SELECT * FROM PARTITION_BY_RANGE PARTITION (DOBS_IN_1973);
SELECT * FROM PARTITION_BY_RANGE PARTITION (DOBS_IN_1974);
SELECT * FROM PARTITION_BY_RANGE PARTITION (DOBS_IN_1975_OR_LATER);
Hash Partitioning
Oracle's hash partitioning distributes data by applying a proprietary
hashing algorithm to the partition key and then assigning the data to
the appropriate partition. By using hash partitioning, DBA's can
partition
data that may not have any logical ranges. Also, DBA's do not have to
know anything about the actual data itself. Oracle handles all of the
distribution of data once the partition key is identified.
Please note that the data may not appear to be distributed evenly
because of the limited number of inserts applied to the table
A brief explanation of the code follows. The PARTITION BY HASH line is
where the partition key is identified. In this example the partition
key is AGE. Once the hashing algorithm is applied each record is
distributed
to a partition. Each partition is specifically assigned to its own
tablespace
-- HASH_ME.SQL
-- PARTITION BY HASH ON AGE
CREATE TABLE PARTITION_BY_HASH
(FIRST_NAME VARCHAR2(10),
MIDDLE_INIT VARCHAR2(1),
LAST_NAME
VARCHAR2(10),
AGE
INT NOT NULL)
PARTITION BY HASH (AGE)
(PARTITION P1_AGE TABLESPACE TS01,
PARTITION P2_AGE TABLESPACE TS02,
PARTITION P3_AGE TABLESPACE TS03,
PARTITION P4_AGE TABLESPACE TS04)
ENABLE ROW MOVEMENT;
-- CHECK TO SEE IF THE PARTITIONS ARE CORRECTLY BUILT
SELECT TABLE_NAME, PARTITION_NAME, TABLESPACE_NAME
FROM USER_TAB_PARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_HASH'
ORDER BY TABLESPACE_NAME;
-- Insert Data Into Each Partition
INSERT INTO PARTITION_BY_HASH VALUES ('MIKE', 'F', 'SMITH',
45);
INSERT INTO PARTITION_BY_HASH VALUES ('JANE', 'R', 'SMITH',
50);
INSERT INTO PARTITION_BY_HASH VALUES ('NICK', 'R', 'SMITH',
55);
INSERT INTO PARTITION_BY_HASH VALUES ('KIMM', 'B', 'SMITH',
60);
INSERT INTO PARTITION_BY_HASH VALUES ('FRED', 'A', 'SMITH',
70);
INSERT INTO PARTITION_BY_HASH VALUES ('BILL', 'B', 'SMITH',
80);
INSERT INTO PARTITION_BY_HASH VALUES ('JOHN', 'C', 'SMITH',
90);
INSERT INTO PARTITION_BY_HASH VALUES ('DAVE', 'D', 'SMITH', 100);
COMMIT;
-- Confirmation that data is being spread between the partitions
SELECT * FROM PARTITION_BY_HASH ORDER BY AGE;
SELECT * FROM PARTITION_BY_HASH PARTITION (P1_AGE);
SELECT * FROM PARTITION_BY_HASH PARTITION (P2_AGE);
SELECT * FROM PARTITION_BY_HASH PARTITION (P3_AGE);
SELECT * FROM PARTITION_BY_HASH PARTITION (P4_AGE);
List Partitioning
List partitioning was added as a partitioning method in Oracle 9i,
Release 1. List partitioning allows for partitions to reflect
real-world groupings (e.g.. business units and territory regions). List
partitioning
differs from range partition in that the groupings in list partitioning
are not side-by-side or in a logical range. List partitioning gives the
DBA the ability to group together seemingly unrelated data into a
specific
partition. The LIST_ME.SQL script provides an example of a list
partition
table. Note the last partition with the DEFAULT value. This DEFAULT
value
is new in Oracle 9i, Release 2.
A brief explanation of the code follows. The PARTITION BY LIST line is
where the partition key is identified. In this example, the partition
key is STATE. Each partition is explicitly named, contains a specific
grouping of VALUES and is contained in its own tablespace. The last
partition
with the DEFAULT is the "catch all" partition. This catch all partition
should be queried periodically to make sure that proper data is being
entered.
-- LIST_ME.SQL
-- PARTITION BY LIST ON STATE
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;
-- CHECK TO SEE PARTITIONS ARE CORRECTLY BUILT
SELECT TABLE_NAME, PARTITION_NAME, HIGH_VALUE, TABLESPACE_NAME
FROM USER_TAB_PARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_LIST'
ORDER BY TABLESPACE_NAME;
-- Insert Data Into Each Partition
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;
-- Confirmation that data is in the proper partitions
select * from PARTITION_BY_LIST;
select * from PARTITION_BY_LIST partition (depts_in_north);
select * from PARTITION_BY_LIST partition (depts_in_east);
select * from PARTITION_BY_LIST partition (depts_in_south);
select * from PARTITION_BY_LIST partition (depts_in_west);
select * from PARTITION_BY_LIST partition (depts_with_no_region);
Composite
Range-Hash
Partitioning
Composite range-hash partitioning combines both the ease of range
partitioning and the benefits of hashing for data placement, striping,
and parallelism. Range-hash partitioning is slightly harder to
implement.
But, with the example provided and a detailed explanation of the code
one can easily learn how to use this powerful partitioning method.
I suggest that, when you actually try to build a range-hash partition
table, you do it in the following steps:
1. Determine the partition key for the range.
2. Design a range partition table.
3. Determine the partition key for the hash.
4. Create the SUBPARTITION BY HASH clause.
5. Create the SUBPARTITION TEMPLATE.
Do Steps 1 and 2 first. Then you can insert the code created in Steps 3
-5 in the range partition table syntax.
The RANGE_HASH_ME.SQL script provides an example of a composite range-hash partition table. A brief explanation of the code follows. The PARTITION BY RANGE clause is where we shall begin. The partition key is (BIRTH_YYYY, BIRTH_MM, BIRTH_DD) for the partition. Next, the SUBPARTITION BY HASH clause indicates what the partition key is for the subpartition (in this case FIRST_NAME, MIDDLE_INIT, LAST_NAME). A SUBPARTITION TEMPLATE then defines the subpartition names and their respective tablespace. Subpartitions are automatically named by Oracle by concatenating the partition name, an underscore, and the subpartition name from the template. Remember that the total length of the subpartition name should not be longer than thirty characters including the underscore.
-- RANGE_HASH_ME.SQL
-- PARTITION BY RANGE HASH
CREATE TABLE PARTITION_BY_RANGE_HASH
( FIRST_NAME VARCHAR2(10),
MIDDLE_INIT VARCHAR2(1),
LAST_NAME VARCHAR2(10),
BIRTH_MM INT NOT NULL,
BIRTH_DD INT NOT
NULL,
BIRTH_YYYY INT NOT NULL)
TABLESPACE USERS
PARTITION BY RANGE (BIRTH_YYYY, BIRTH_MM, BIRTH_DD)
SUBPARTITION BY HASH(FIRST_NAME, MIDDLE_INIT,
LAST_NAME)
SUBPARTITION TEMPLATE(
SUBPARTITION SP1 TABLESPACE TS01,
SUBPARTITION SP2 TABLESPACE TS02,
SUBPARTITION SP3 TABLESPACE TS03,
SUBPARTITION SP4 TABLESPACE TS04,
SUBPARTITION SP5 TABLESPACE TS05)
(PARTITION DOBS_IN_1971_OR_BEFORE VALUES LESS THAN (1972, 01 ,01),
PARTITION
DOBS_IN_1972
VALUES LESS THAN (1973, 01 ,01),
PARTITION
DOBS_IN_1973
VALUES LESS THAN (1974, 01 ,01),
PARTITION
DOBS_IN_1974
VALUES LESS THAN (1975, 01 ,01),
PARTITION DOBS_IN_1975_OR_LATER VALUES LESS THAN
(MAXVALUE, MAXVALUE, MAXVALUE))
ENABLE ROW MOVEMENT;
-- CHECK TO SEE IF THE PARTITIONS ARE CORRECTLY BUILT AN IN THE
PROPER TABLESPACE
SELECT TABLE_NAME, PARTITION_NAME, SUBPARTITION_NAME,
TABLESPACE_NAME
FROM USER_TAB_SUBPARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_RANGE_HASH';
-- INSERT DATA INTO EACH PARTITION
-- DATA FOR PARTITION DOBS_IN_1971_OR_BEFORE
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1966', 'A',
'SMITH_1966', 09, 20, 1966);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1967', 'A',
'SMITH_1967', 09, 20, 1967);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1968', 'A',
'SMITH_1968', 09, 20, 1968);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1969', 'A',
'SMITH_1969', 09, 20, 1969);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1970', 'A',
'SMITH_1970', 09, 20, 1970);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1971', 'A',
'SMITH_1971', 05, 16, 1971);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1971', 'A',
'SMITH_1971', 06, 17, 1971);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1971', 'A',
'SMITH_1971', 07, 18, 1971);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1971', 'A',
'SMITH_1971', 08, 19, 1971);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('FRED_1971', 'A',
'SMITH_1971', 09, 20, 1971);
-- DATA FOR PARTITION DOBS_IN_1972
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('BILL_1972', 'B',
'SMITH_1972', 05, 16, 1972);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('BILL_1972', 'B',
'SMITH_1972', 06, 17, 1972);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('BILL_1972', 'B',
'SMITH_1972', 07, 18, 1972);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('BILL_1972', 'B',
'SMITH_1972', 08, 19, 1972);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('BILL_1972', 'B',
'SMITH_1972', 09, 20, 1972);
-- DATA FOR PARTITION DOBS_IN_1973
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('JOHN_1973', 'C',
'SMITH_1973', 05, 16, 1973);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('JOHN_1973', 'C',
'SMITH_1973', 06, 17, 1973);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('JOHN_1973', 'C',
'SMITH_1973', 07, 18, 1973);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('JOHN_1973', 'C',
'SMITH_1973', 08, 19, 1973);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('JOHN_1973', 'C',
'SMITH_1973', 09, 20, 1973);
-- DATA FOR PARTITION DOBS_IN_1974
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1974', 'D',
'SMITH_1974', 05, 16, 1974);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1974', 'D',
'SMITH_1974', 06, 17, 1974);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1974', 'D',
'SMITH_1974', 07, 18, 1974);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1974', 'D',
'SMITH_1974', 08, 19, 1974);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1974', 'D',
'SMITH_1974', 09, 20, 1974);
-- DATA FOR PARTITION DOBS_IN_1975_OR_LATER
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1975', 'D',
'SMITH_1975', 09, 20, 1975);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1976', 'D',
'SMITH_1976', 09, 20, 1976);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1976', 'D',
'SMITH_1976', 09, 20, 1977);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1976', 'D',
'SMITH_1976', 09, 20, 1978);
INSERT INTO PARTITION_BY_RANGE_HASH VALUES ('DAVE_1976', 'D',
'SMITH_1976', 09, 20, 1979);
COMMIT;
-- CONFIRMATION THAT DATA IS BEING SPREAD BETWEEN THE PARTITIONS
SELECT * FROM PARTITION_BY_RANGE_HASH;
SELECT * FROM PARTITION_BY_RANGE_HASH PARTITION
(DOBS_IN_1971_OR_BEFORE)
ORDER BY BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_HASH PARTITION
(DOBS_IN_1972)
ORDER BY BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_HASH PARTITION
(DOBS_IN_1973)
ORDER BY BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_HASH PARTITION
(DOBS_IN_1974)
ORDER BY BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_HASH PARTITION
(DOBS_IN_1975_OR_LATER)
ORDER BY BIRTH_YYYY;
Composite
Range-List
Partitioning
Composite range-list partitioning combines both the ease of range
partitioning and the benefits of list partitioning at the subpartition
level. Like range-hash partitioning, range-list partitioning needs to
be carefully designed. The time used to properly design a range-list
partition table pays off during the actual creation of the table. The
RANGE_LIST_ME.SQL script provides an example of a composite range-list
partition table. A brief explanation of the code follows. The PARTITION
BY RANGE clause
identifies the partition key (BIRTH_YYYY, BIRTH_MM, BIRTH_DD). A
SUBPARTITION
TEMPLATE then defines the subpartition names and their respective
tablespace.
Subpartitions are automatically named by Oracle by concatenating the
partition name, an underscore, and the subpartition name from the
template.
Remember that the total length of the subpartition name should not be
longer than thirty characters including the underscore.
When building a range-list partition table you may want to refer to
the steps mentioned at the end of the Composite Range-List section. The
only difference is in Step 4. Instead of "Create the SUBPARTITION
BY HASH clause" it would read, "Create the SUBPARTITION BY LIST clause"
for the range-list partition table.
-- RANGE_LIST_ME.SQL
-- PARTITION BY RANGE LIST (RANGE ON BIRTH DATES LIST BY STATE)
CREATE TABLE PARTITION_BY_RANGE_LIST
( FIRST_NAME VARCHAR2(10),
MIDDLE_INIT VARCHAR2(1),
LAST_NAME VARCHAR2(10),
BIRTH_MM INT NOT NULL,
BIRTH_DD INT NOT NULL,
BIRTH_YYYY INT NOT NULL,
STATE
VARCHAR2(2) NOT NULL)
TABLESPACE USERS
PARTITION BY RANGE (BIRTH_YYYY, BIRTH_MM, BIRTH_DD)
SUBPARTITION BY LIST (STATE)
SUBPARTITION TEMPLATE
(SUBPARTITION IN_NORTH VALUES
('AK')
TABLESPACE TS01,
SUBPARTITION IN_EAST VALUES ('NY', 'NJ', 'VA',
'CT') TABLESPACE TS02,
SUBPARTITION IN_SOUTH VALUES ('TX', 'MS', 'GA', 'KY')
TABLESPACE TS03,
SUBPARTITION IN_WEST VALUES ('CA', 'AZ', 'OR',
'NV') TABLESPACE TS04,
SUBPARTITION NO_STATE VALUES
(DEFAULT)
TABLESPACE TS05)
(PARTITION DOBS_IN_1971_OR_B4 VALUES LESS THAN
(1972, 01 ,01),
PARTITION
DOBS_IN_1972
VALUES LESS THAN (1973, 01 ,01),
PARTITION
DOBS_IN_1973
VALUES LESS THAN (1974, 01 ,01),
PARTITION
DOBS_IN_1974
VALUES LESS THAN (1975, 01 ,01),
PARTITION DOBS_IN_1975_TO_MAX VALUES LESS THAN
(MAXVALUE,
MAXVALUE, MAXVALUE))
ENABLE ROW MOVEMENT;
-- CHECK TO SEE IF THE PARTITIONS ARE CORRECTLY BUILT AN IN THE
PROPER TABLESPACE
SELECT TABLE_NAME, PARTITION_NAME, SUBPARTITION_NAME,
TABLESPACE_NAME
FROM USER_TAB_SUBPARTITIONS
WHERE TABLE_NAME = 'PARTITION_BY_RANGE_LIST';
-- Insert Data Into Each Partition
-- DATA FOR DOBS_IN_1971_OR_BEFORE
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1970, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1970, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1970, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1970, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1970, 'HI');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1971, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1971, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1971, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1971, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1971, 'HI');
-- DATA FOR DOBS_IN_1972
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1972, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1972, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1972, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1972, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1972, 'HI');
-- DATA FOR DOBS_IN_1973
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1973, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1973, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1973, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1973, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1973, 'HI');
-- DATA FOR DOBS_IN_1974
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1974, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1974, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1974, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1974, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1974, 'HI');
-- DATA FOR DOBS_IN_1975_OR_LATER
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1975, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1975, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1975, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1975, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1975, 'HI');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 01,
01, 1976, 'AK');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 02,
02, 1976, 'NY');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 03,
03, 1976, 'TX');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 04,
04, 1976, 'CA');
INSERT INTO PARTITION_BY_RANGE_LIST VALUES ('FN', 'M', 'LN', 05,
05, 1976, 'HI');
COMMIT;
-- Confirmation that data is being spread between the partitions
SELECT * FROM PARTITION_BY_RANGE_LIST ORDER BY STATE,
BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_LIST PARTITION
(DOBS_IN_1971_OR_B4)
ORDER BY BIRTH_YYYY;
SELECT * FROM PARTITION_BY_RANGE_LIST PARTITION
(DOBS_IN_1972);
SELECT * FROM PARTITION_BY_RANGE_LIST PARTITION
(DOBS_IN_1973);
SELECT * FROM PARTITION_BY_RANGE_LIST PARTITION
(DOBS_IN_1974);
SELECT * FROM PARTITION_BY_RANGE_LIST PARTITION
(DOBS_IN_1975_TO_MAX)
ORDER BY BIRTH_YYYY;
Globally Partitioned Indexes
There are two types of global indexes, non-partitioned and partitioned.
Global non-partitioned indexes are those that are commonly used in OLTP
databases. The syntax for a globally non-partitioned index is the
exactly
same syntax used for a "regular" index on a non-partitioned table.
Example:
-- GNPI_ME.SQL
-- GLOBAL NONPARTITION INDEX ON PARTITION_BY_RANGE
-- (SIMILAR TO REGULAR INDEX USED ON NONPARTITION TABLES) IN MOST
OLTP ENVIRONMENTS
CREATE INDEX PARTITION_BY_RANGE_GNPI ON PARTITION_BY_RANGE
(LAST_NAME)
TABLESPACE ITS01;
The other type of global index is the one that is partitioned.
Globally partitioned indexes at this time can only be ranged
partitioned
and has similar syntactical structure to that of a range-partitioned
table. Note that a globally partitioned index can be applied to any
type
of partitioned table. Each partition of the globally partitioned index
can and may refer to one or more partitions at the table level. Example:
-- GPI_ME.SQL
-- GLOBAL PARTITION INDEX ON PARTITION_BY_RANGE
CREATE INDEX PARTITION_BY_RANGE_GPI ON PARTITION_BY_RANGE
(BIRTH_YYYY,
BIRTH_MM, BIRTH_DD)
GLOBAL PARTITION BY RANGE (BIRTH_YYYY, BIRTH_MM, BIRTH_DD)
(PARTITION DOBS_IN_1971_OR_BEFORE_GPI VALUES LESS THAN (1972, 01
,01)
TABLESPACE ITS01,
PARTITION
DOBS_IN_1972_GPI
VALUES LESS THAN (1973, 01 ,01)
TABLESPACE
ITS02,
PARTITION
DOBS_IN_1973_GPI
VALUES LESS THAN (1974, 01 ,01)
TABLESPACE
ITS03,
PARTITION
DOBS_IN_1974_GPI
VALUES LESS THAN (1975, 01 ,01)
TABLESPACE
ITS04,
PARTITION DOBS_IN_1975_OR_LATER_GPI VALUES LESS THAN
(MAXVALUE, MAXVALUE, MAXVALUE) TABLESPACE ITS05);
The maintenance on globally partitioned indexes is a little bit more
involved compared to the maintenance on locally partitioned indexes.
Global indexes need to be rebuilt when there is DDL activity on the
underlying table. The reason why they must be rebuilt is that DDL
activity
often causes the global indexes to be usually marked as UNUSABLE. To
correct this problem there are two options to choose from:
- Use ALTER INDEX <index_name> REBUILD;
- Or use UPDATE GLOBAL INDEX clause when using ALTER TABLE.
The syntax for the ALTER INDEX statement is relatively
straightforward
so we will only focus on the UPDATE GLOBAL INDEX clause of the ALTER
TABLE statement. The UPDATE GLOBAL INDEX is between the partition
specification
and the parallel clause. The partition specification can be any of the
following:
- ADD PARTITION | SUBPARTITION (hash only)
- COALESCE PARTITION | SUBPARTITION
- DROP PARTITION
- EXCHANGE PARTITION | SUBPARTITION
- MERGE PARTITION
- MOVE PARTITION | SUBPARTITION
- SPLIT PARTITION
- TUNCATE PARTITION | SUBPARTITION
For example:
ALTER TABLE <TABLE_NAME>
<PARTITION SPECIFICATION>
UPDATE GLOBAL INDEX
PARALLEL (DEGREE #)
Locally Partitioned Indexes
Locally partitioned indexes are for the most part very straightforward.
The following script shows examples of this type of index. In the
script,
locally partitioned indexes are created on three differently
partitioned
tables (range, hash, and list).
-- LPI_ME.SQL
CREATE INDEX PARTITION_BY_RANGE_LI ON PARTITION_BY_RANGE
(LAST_NAME)
LOCAL
(PARTITION RANGE_LIP_10 TABLESPACE ITS01,
PARTITION RANGE_LIP_20 TABLESPACE ITS02,
PARTITION RANGE_LIP_30 TABLESPACE ITS03,
PARTITION RANGE_LIP_40 TABLESPACE ITS04,
PARTITION RANGE_LIP_50 TABLESPACE ITS05);
CREATE INDEX PARTITION_BY_HASH_LI ON PARTITION_BY_HASH (LAST_NAME)
LOCAL
(PARTITION HASH_LIP_10 TABLESPACE ITS01,
PARTITION HASH_LIP_20 TABLESPACE ITS02,
PARTITION HASH_LIP_30 TABLESPACE ITS03,
PARTITION HASH_LIP_40 TABLESPACE ITS04);
CREATE INDEX PARTITION_BY_LIST_LI ON PARTITION_BY_LIST (STATE) LOCAL
(PARTITION LIST_LIP_10 TABLESPACE ITS01,
PARTITION LIST_LIP_20 TABLESPACE ITS02,
PARTITION LIST_LIP_30 TABLESPACE ITS03,
PARTITION LIST_LIP_40 TABLESPACE ITS04,
PARTITION LIST_LIP_50 TABLESPACE ITS05);
Extra time should be allocated when creating locally partitioned
indexes on range-hash or range-list partitioned tables. There are a
couple
reasons that extra time is needed for this type of index. One of the
reasons is a decision needs to be made on what the index will be
referencing
in regards to a range-hash or range-list partitioned tables. A locally
partitioned index can be created to point to either partition level or
subpartition level.
The following script is the example for the creation of two locally
partitioned indexes. This scripts show how to create a locally
partitioned
index on both a range-hash and range-list partitioned tables at the
partition
level. Each of the partitions of the locally partitioned indexes is
assigned
to its own tablespace for improved performance
-- LPI4CPT1_ME.SQL INDEXES REFERCING THE
PARTITION
LEVEL
-- USE EITHER LOCAL PARTITIONED INDEX ON THE PARTITION LEVEL OR
SUBPARTITION LEVEL
-- BUT NOT BOTH ON THE SAME INDEX COLUMN
-- FOR COMPOSITE RANGE_HASH LOCAL PARTITIONED INDEX ON THE
PARTITION
LEVEL
CREATE INDEX PARTITION_BY_RANGE_HASH_LIP ON PARTITION_BY_RANGE_HASH
(LAST_NAME) LOCAL
(PARTITION RANGE_HASH_LIP_10 TABLESPACE ITS01,
PARTITION RANGE_HASH_LIP_20 TABLESPACE ITS02,
PARTITION RANGE_HASH_LIP_30 TABLESPACE ITS03,
PARTITION RANGE_HASH_LIP_40 TABLESPACE ITS03,
PARTITION RANGE_HASH_LIP_50 TABLESPACE ITS04);
-- USE EITHER LOCAL PARTITIONED INDEX ON THE PARTITION LEVEL OR
SUBPARTITION LEVEL
-- BUT NOT BOTH ON THE SAME INDEX COLUMN
-- FOR COMPOSITE RANGE_LIST LOCAL PARTITIONED INDEX ON THE
PARTITION
LEVEL
CREATE INDEX PARTITION_BY_RANGE_LIST_LIP ON PARTITION_BY_RANGE_LIST
(LAST_NAME) LOCAL
(PARTITION RANGE_LIST_LIP_01 TABLESPACE ITS01,
PARTITION RANGE_LIST_LIP_02 TABLESPACE ITS02,
PARTITION RANGE_LIST_LIP_03 TABLESPACE ITS03,
PARTITION RANGE_LIST_LIP_04 TABLESPACE ITS04,
PARTITION RANGE_LIST_LIP_05 TABLESPACE ITS05
);
When creating a locally partitioned index one needs to keep in mind the
number of subpartitions of the range-hash or range-list partitioned
table being indexed. Reason being, is that the locally partitioned
index
will need to reference each subpartition of the range-hash or
range-list
partitioned table. So, for the locally partitioned index created by
LPI4CPT2_ME.SQL,
this mean that one index references twenty-five different
subpartitions.
For a visual representation of this refer to Figure 4. Script
LPI4CPT3_ME.SQL
is provided as an example of locally partitioned index on a range-list
partition table.
-- LOCAL COMPOSITE INDEXES REFERCING THE SUBPARTITION LEVEL
-- LPI4CPT2_ME.SQL
-- USE EITHER LOCAL PARTITIONED INDEX ON THE PARTITION LEVEL OR
SUBPARTITION LEVEL
-- BUT NOT BOTH ON THE SAME INDEX COLUMN
-- FOR COMPOSITE RANGE_HASH LOCAL PARTITIONED INDEX ON THE
SUBPARTITION
LEVEL
CREATE INDEX PARTITION_BY_RANGE_HASH_LISP ON
PARTITION_BY_RANGE_HASH
(LAST_NAME) LOCAL
(PARTITION
RANGE_HASH_LISP_10
TABLESPACE ITS05
(SUBPARTITION RANGE_HASH_LISP_10_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_HASH_LISP_10_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_HASH_LISP_10_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_HASH_LISP_10_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_HASH_LISP_10_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_HASH_LISP_20
TABLESPACE ITS04
(SUBPARTITION RANGE_HASH_LISP_20_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_HASH_LISP_20_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_HASH_LISP_20_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_HASH_LISP_20_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_HASH_LISP_20_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_HASH_LISP_30
TABLESPACE ITS03
(SUBPARTITION RANGE_HASH_LISP_30_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_HASH_LISP_30_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_HASH_LISP_30_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_HASH_LISP_30_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_HASH_LISP_30_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_HASH_LISP_40
TABLESPACE ITS02
(SUBPARTITION RANGE_HASH_LISP_40_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_HASH_LISP_40_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_HASH_LISP_40_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_HASH_LISP_40_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_HASH_LISP_40_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_HASH_LISP_50
TABLESPACE ITS01
(SUBPARTITION RANGE_HASH_LISP_50_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_HASH_LISP_50_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_HASH_LISP_50_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_HASH_LISP_50_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_HASH_LISP_50_SP50 TABLESPACE
ITS05
)
);
-- LPI4CPT3_ME.SQL INDEXES REFERCING THE
SUBPARTITION
LEVEL
-- FOR COMPOSITE RANGE_LIST LOCAL PARTITIONED INDEX ON THE
SUBPARTITION
LEVEL
CREATE INDEX PARTITION_BY_RANGE_LIST_LISP ON
PARTITION_BY_RANGE_LIST
(LAST_NAME) LOCAL
(PARTITION
RANGE_LIST_LISP_10
TABLESPACE ITS05
(SUBPARTITION RANGE_LIST_LISP_10_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_LIST_LISP_10_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_LIST_LISP_10_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_LIST_LISP_10_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_LIST_LISP_10_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_LIST_LISP_20
TABLESPACE ITS04
(SUBPARTITION RANGE_LIST_LISP_20_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_LIST_LISP_20_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_LIST_LISP_20_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_LIST_LISP_20_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_LIST_LISP_20_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_LIST_LISP_30
TABLESPACE ITS03
(SUBPARTITION RANGE_LIST_LISP_30_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_LIST_LISP_30_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_LIST_LISP_30_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_LIST_LISP_30_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_LIST_LISP_30_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_LIST_LISP_40
TABLESPACE ITS02
(SUBPARTITION RANGE_LIST_LISP_40_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_LIST_LISP_40_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_LIST_LISP_40_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_LIST_LISP_40_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_LIST_LISP_40_SP50 TABLESPACE
ITS05
),
PARTITION
RANGE_LIST_LISP_50
TABLESPACE ITS01
(SUBPARTITION RANGE_LIST_LISP_50_SP10 TABLESPACE ITS01 ,
SUBPARTITION RANGE_LIST_LISP_50_SP20 TABLESPACE ITS02 ,
SUBPARTITION RANGE_LIST_LISP_50_SP30 TABLESPACE ITS03 ,
SUBPARTITION RANGE_LIST_LISP_50_SP40 TABLESPACE ITS04 ,
SUBPARTITION RANGE_LIST_LISP_50_SP50 TABLESPACE
ITS05
)
);
Note: At this time Oracle has not implemented a SUBPARTITION TEMPLATE
clause for the creation of locally partitioned indexes on range-hash or
range-list partition tables. This means that you need to type
everything out as in the examples in LPI4CPT2_ME.SQL and
LPI4CPT3_ME.SQL.
Maintenance of locally partitioned indexes is much easier than the
maintenance of globally partitioned indexes. Whenever there is DDL
activity on the underlying indexed table Oracle rebuilds the locally
partitioned index.
This automatic rebuilding of locally partitioned indexes is one reason
why most DBAs prefer locally partitioned indexes.
When to Use Which Partitioning
Method
There are five different table partitioning methods (range, hash, list,
range-hash and range-list) and three for indexes (global
non-partitioned,
global partitioned and locally partitioned). So, the obvious question
is: "When do I use which combination of table and index partitioning?"
There is no concrete answer for that question. However, here are some
general guidelines on mixing and matching table and index partitioning.
- First determine if you need to partition the table.
- Next decide which table partitioning method is right for your
situation.
- Determine how volatile the data is.
o How often are
there inserts, updates and deletes?
- Choose your indexing strategy: global or local partitioned indexes.
o Each type has
its own maintenance consideration.
In identifying tables which would benefit from partitioning, consider
the following:
- Choose very large tables which grow rapidly, become fragmented
quickly, and present maintenance challenges which could be alleviated
by separate partition maintenance
- Tables which have new data loaded regularly but are static thereafter
- Summary tables, historical tables used in Decision Support Systems
- Tables with data which has a logical partition column (date, code,
type, etc)
When to Use the
Range Partitioning Method
Use range partitioning to map rows to partitions based on
ranges of column values. This type of partitioning is useful when
dealing with data that has logical ranges into which it can be
distributed; for example, months of the year. Performance is best when
the data evenly distributes across the range. If partitioning by range
causes partitions to vary dramatically in size because of unequal
distribution, you may want to consider one of the other methods of
partitioning.
When creating range partitions, you must specify:
When to Use the
Hash Partitioning Method
Use hash partitioning if your data does not easily lend
itself to range partitioning, but you would like to partition for
performance and manageability reasons. Hash partitioning provides a
method of evenly distributing data across a specified number of
partitions. Rows are mapped into partitions based on a hash value of
the partitioning key. Creating and using hash partitions gives you a
highly tunable method of data placement, because you can influence
availability and performance by spreading these evenly sized partitions
across I/O devices (striping).
To create hash partitions you specify the following:
The following example creates a hash-partitioned table.
The partitioning column is id
, four partitions are
created and assigned system generated names, and they are placed in
four named tablespaces (gear1
, gear2
, ...).
CREATE TABLE scubagear
(id NUMBER,
name VARCHAR2 (60))
PARTITION BY HASH (id)
PARTITIONS 4
STORE IN (gear1, gear2, gear3, gear4);
When to Use the
List Partitioning Method
se list partitioning when you require explicit control
over how rows map to partitions. You can specify a list of discrete
values for the partitioning column in the description for each
partition. This is different from range partitioning, where a range of
values is associated with a partition, and from hash partitioning,
where the user has no control of the row to partition mapping. The list
partitioning method is specifically designed for
modeling data distributions that follow discrete values. This cannot be
easily done by range or hash partitioning because:
Further, list partitioning allows unordered and unrelated sets of data to be grouped and organized together very naturally.
Unlike the range and hash partitioning methods, multi-column partitioning is not supported for list partitioning. If a table is partitioned by list, the partitioning key can consist only of a single column of the table. Otherwise all columns that can be partitioned by the range or hash methods can be partitioned by the list partitioning method. When creating list partitions, you must specify:
When to Use the
Composite Range-Hash Partitioning Method
Range-hash partitioning partitions data using the range
method, and within each partition, subpartitions it using the hash
method. These composite partitions are ideal for both historical data
and striping, and provide improved manageability of range partitioning
and data placement, as well as the parallelism advantages of hash
partitioning.
The following statement creates a range-hash partitioned
table. In this example, three range partitions are created, each
containing eight subpartitions. Because the subpartitions are not
named, system generated names are assigned, but the STORE IN
clause distributes them across the 4 specified tablespaces (ts1
,
...,ts4
).
CREATE TABLE scubagear (equipno NUMBER, equipname VARCHAR(32), price NUMBER)
PARTITION BY RANGE (equipno) SUBPARTITION BY HASH(equipname)
SUBPARTITIONS 8 STORE IN (ts1, ts2, ts3, ts4)
(PARTITION p1 VALUES LESS THAN (1000),
PARTITION p2 VALUES LESS THAN (2000),
PARTITION p3 VALUES LESS THAN (MAXVALUE));
The partitions of a range-hash partitioned table are logical structures only, as their data is stored in the segments of their subpartitions. As with partitions, these subpartitions share the same logical attributes. Unlike range partitions in a range-partitioned table, the subpartitions cannot have different physical attributes from the owning partition, although they are not required to reside in the same tablespace.
When to Use the Composite
Range-List Partitioning Method
Like the composite range-hash partitioning method, the
composite range-list partitioning method provides for partitioning
based on a two level hierarchy. The first level of partitioning is
based on a range of values, as for range partitioning; the second level
is based on discrete values, as for list partitioning. This form of
composite partitioning is well suited for historical data, but allows
you to further group the rows of data based on unordered or unrelated
column values.
When creating range-list partitions, you specify the following:
* If I'm going to delete a tablespace with partitions:
alter table xxx truncate partition part_name
alter table xxx drop partition part_name
drop tablespace xxx
* Moving Partitions = Alter table xxx move partition part_name tablespace tbscpc_name
* Adding Partitions in the middle = Alter table xxx split partition part_name
* Split Partitions = Alter table xxx split partition part_vieja
as (values) into (partition new_name, partition new_name);
* Convert a Partition in a full table = alter table xx
exchange
partition part_name with table_new_no_part
* The views USER_TAB_PARTITIONS y USER_IND_PARTITIONS will show the range of partitions
* To Analyze a partition table or a partition index::
analyxe table xxx partition (part_name) compute statistics;
analyze index xxx partitio (part_name)compute;
* It's better to analyze the tables by partitions
* To import/export partition you should use table_name:part_name