Oracle® Database Administrator's Guide 10g Release 2 (10.2) Part Number B14231-02 |
|
|
View PDF |
This chapter describes various aspects of managing partitioned tables and indexes, and contains the following topics:
Modern enterprises frequently run mission-critical databases containing upwards of several hundred gigabytes and, in many cases, several terabytes of data. These enterprises are challenged by the support and maintenance requirements of very large databases (VLDB), and must devise methods to meet those challenges.
One way to meet VLDB demands is to create and use partitioned tables and indexes. Partitioned tables allow your data to be broken down into smaller, more manageable pieces called partitions. Partitioning can also bring better performance, because many queries can prune (ignore) partitions that, according to the WHERE
clause, won't have the requested rows, thereby reducing the amount of data to be scanned to produce a result set. Partitions can be further broken down into subpartitions for finer levels of manageability and improved performance. Indexes can be partitioned in similar fashion.
Each partition is stored in its own segment and can be managed individually. It can function independently of the other partitions, thus providing a structure that can be better tuned for availability and performance.
If you are using parallel execution, partitions provide another means of parallelization. Operations on partitioned tables and indexes are performed in parallel by assigning different parallel execution servers to different partitions of the table or index.
Partitions and subpartitions of a table or index all share the same logical attributes. For example, all partitions (or subpartitions) in a table share the same column and constraint definitions, and all partitions (or subpartitions) of an index share the same index options. They can, however, have different physical attributes (such as TABLESPACE
).
Although you are not required to keep each table or index partition (or subpartition) in a separate tablespace, it is to your advantage to do so. Storing partitions in separate tablespaces enables you to:
Reduce the possibility of data corruption in multiple partitions
Back up and recover each partition independently
Control the mapping of partitions to disk drives (important for balancing I/O load)
Improve manageability, availability, and performance
Partitioning is transparent to existing applications and standard DML statements run against partitioned tables. However, an application can be programmed to take advantage of partitioning by using partition-extended table or index names in DML.
The maximum number of partitions or subpartitions that a table may have is 1024K-1.
You can use SQL*Loader and the import and export utilities to load or unload data stored in partitioned tables. These utilities are all partition and subpartition aware.
See Also:
Chapter 14, "Managing Space for Schema Objects" is recommended reading before attempting tasks described in this chapter.
Oracle Database Concepts contains more information about partitioning. Before the first time you attempt to create a partitioned table or index, or perform maintenance operations on any partitioned table, it is recommended that you review the information contained in that book.
Oracle Database Data Warehousing Guide and Oracle Database Concepts contain information about parallel execution
Oracle Database Utilities describes SQL*Loader and the import and export utilities.
There are several partitioning methods offered by Oracle Database:
Range partitioning
Hash partitioning
List partitioning
Composite range-hash partitioning
Composite range-list partitioning
Indexes, as well as tables, can be partitioned. A global index can be partitioned by the range or hash method, and it can be defined on any type of partitioned, or non-partitioned, table. It can require more maintenance than a local index.
A local index is constructed so that it reflects the structure of the underlying table. It is equipartitioned with the underlying table, meaning that it is partitioned on the same columns as the underlying table, creates the same number of partitions or subpartitions, and gives them the same partition bounds as corresponding partitions of the underlying table. For local indexes, index partitioning is maintained automatically when partitions are affected by maintenance activity. This ensures that the index remains equipartitioned with the underlying table.
The following sections can help you decide on a partitioning method appropriate for your needs:
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:
Partitioning method: range
Partitioning column(s)
Partition descriptions identifying partition bounds
The example below creates a table of four partitions, one for each quarter of sales. The columns sale_year
, sale_month
, and sale_day
are the partitioning columns, while their values constitute the partitioning key of a specific row. The VALUES LESS THAN
clause determines the partition bound: rows with partitioning key values that compare less than the ordered list of values specified by the clause are stored in the partition. Each partition is given a name (sales_q1
, sales_q2
, ...), and each partition is contained in a separate tablespace (tsa
, tsb
, ...).
CREATE TABLE sales ( invoice_no NUMBER, sale_year INT NOT NULL, sale_month INT NOT NULL, sale_day INT NOT NULL ) PARTITION BY RANGE (sale_year, sale_month, sale_day) ( PARTITION sales_q1 VALUES LESS THAN (1999, 04, 01) TABLESPACE tsa, PARTITION sales_q2 VALUES LESS THAN (1999, 07, 01) TABLESPACE tsb, PARTITION sales_q3 VALUES LESS THAN (1999, 10, 01) TABLESPACE tsc, PARTITION sales_q4 VALUES LESS THAN (2000, 01, 01) TABLESPACE tsd );
A row with sale_year=1999
, sale_month=8
, and sale_day=1
has a partitioning key of (1999, 8, 1)
and would be stored in partition sales_q3
.
See Also:
"Using Multicolumn Partitioning Keys"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:
Partitioning method: hash
Partitioning column(s)
Number of partitions or individual partition descriptions
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);
See Also:
"Using Multicolumn Partitioning Keys"Use 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:
Range partitioning assumes a natural range of values for the partitioning column. It is not possible to group together out-of-range values partitions.
Hash partitioning allows no control over the distribution of data because the data is distributed over the various partitions using the system hash function. Again, this makes it impossible to logically group together discrete values for the partitioning columns into partitions.
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, multicolumn 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:
Partitioning method: list
Partitioning column
Partition descriptions, each specifying a list of literal values (a value list), which are the discrete values of the partitioning column that qualify a row to be included in the partition
The following example creates a list-partitioned table. It creates table q1_sales_by_region
which is partitioned by regions consisting of groups of states.
CREATE TABLE q1_sales_by_region (deptno number, deptname varchar2(20), quarterly_sales number(10, 2), state varchar2(2)) PARTITION BY LIST (state) (PARTITION q1_northwest VALUES ('OR', 'WA'), PARTITION q1_southwest VALUES ('AZ', 'UT', 'NM'), PARTITION q1_northeast VALUES ('NY', 'VM', 'NJ'), PARTITION q1_southeast VALUES ('FL', 'GA'), PARTITION q1_northcentral VALUES ('SD', 'WI'), PARTITION q1_southcentral VALUES ('OK', 'TX'));
A row is mapped to a partition by checking whether the value of the partitioning column for a row matches a value in the value list that describes the partition.
For example, some sample rows are inserted as follows:
(10, 'accounting', 100, 'WA') maps to partition q1_northwest
(20, 'R&D', 150, 'OR') maps to partition q1_northwest
(30, 'sales', 100, 'FL') maps to partition q1_southeast
(40, 'HR', 10, 'TX') maps to partition q1_southwest
(50, 'systems engineering', 10, 'CA') does not map to any partition in the table and raises an error
Unlike range partitioning, with list partitioning, there is no apparent sense of order between partitions. You can also specify a default partition into which rows that do not map to any other partition are mapped. If a default partition were specified in the preceding example, the state CA would map to that partition.
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.
When creating range-hash partitions, you specify the following:
Partitioning method: range
Partitioning column(s)
Partition descriptions identifying partition bounds
Subpartitioning method: hash
Subpartitioning column(s)
Number of subpartitions for each partition or descriptions of subpartitions
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.
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 lets you further group the rows of data based on unordered or unrelated column values.
When creating range-list partitions, you specify the following:
Partitioning method: range
Partitioning column(s)
Partition descriptions identifying partition bounds
Subpartitioning method: list
Subpartitioning column
Subpartition descriptions, each specifying a list of literal values (a value list), which are the discrete values of the subpartitioning column that qualify a row to be included in the subpartition
The following example illustrates how range-list partitioning might be used. The example tracks sales data of products by quarters and within each quarter, groups it by specified states.
CREATE TABLE quarterly_regional_sales (deptno number, item_no varchar2(20), txn_date date, txn_amount number, state varchar2(2)) TABLESPACE ts4 PARTITION BY RANGE (txn_date) SUBPARTITION BY LIST (state) (PARTITION q1_1999 VALUES LESS THAN (TO_DATE('1-APR-1999','DD-MON-YYYY')) (SUBPARTITION q1_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q1_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q1_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q1_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q1_1999_northcentral VALUES ('SD', 'WI'), SUBPARTITION q1_1999_southcentral VALUES ('OK', 'TX') ), PARTITION q2_1999 VALUES LESS THAN ( TO_DATE('1-JUL-1999','DD-MON-YYYY')) (SUBPARTITION q2_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q2_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q2_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q2_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q2_1999_northcentral VALUES ('SD', 'WI'), SUBPARTITION q2_1999_southcentral VALUES ('OK', 'TX') ), PARTITION q3_1999 VALUES LESS THAN (TO_DATE('1-OCT-1999','DD-MON-YYYY')) (SUBPARTITION q3_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q3_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q3_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q3_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q3_1999_northcentral VALUES ('SD', 'WI'), SUBPARTITION q3_1999_southcentral VALUES ('OK', 'TX') ), PARTITION q4_1999 VALUES LESS THAN ( TO_DATE('1-JAN-2000','DD-MON-YYYY')) (SUBPARTITION q4_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q4_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q4_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q4_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q4_1999_northcentral VALUES ('SD', 'WI'), SUBPARTITION q4_1999_southcentral VALUES ('OK', 'TX') ) );
A row is mapped to a partition by checking whether the value of the partitioning column for a row falls within a specific partition range. The row is then mapped to a subpartition within that partition by identifying the subpartition whose descriptor value list contains a value matching the subpartition column value.
For example, some sample rows are inserted as follows:
(10, 4532130, '23-Jan-1999', 8934.10, 'WA') maps to subpartition q1_1999_northwest
(20, 5671621, '15-May-1999', 49021.21, 'OR') maps to subpartition q2_1999_northwest
(30, 9977612, '07-Sep-1999', 30987.90, 'FL') maps to subpartition q3_1999_southeast
(40, 9977612, '29-Nov-1999', 67891.45, 'TX') maps to subpartition q4_1999_southcentral
(40, 4532130, '5-Jan-2000', 897231.55, 'TX') does not map to any partition in the table and raises an error
(50, 5671621, '17-Dec-1999', 76123.35, 'CA') does not map to any subpartition in the table and raises an error
The partitions of a range-list partitioned table are logical structures only, as their data is stored in the segments of their subpartitions. The list subpartitions have the same characteristics as list partitions. You can specify a default subpartition, just as you specify a default partition for list partitioning.
Creating a partitioned table or index is very similar to creating a non-partitioned table or index (as described in Chapter 15, "Managing Tables"), but you include a partitioning clause. The partitioning clause, and subclauses, that you include depend upon the type of partitioning you want to achieve.
You can partition both regular (heap organized) tables and index-organized tables, except for those containing LONG
or LONG RAW
columns. You can create non-partitioned global indexes, range or hash-partitioned global indexes, and local indexes on partitioned tables.
When you create (or alter) a partitioned table, a row movement clause, either ENABLE ROW MOVEMENT
or DISABLE ROW MOVEMENT
can be specified. This clause either enables or disables the migration of a row to a new partition if its key is updated. The default is DISABLE ROW MOVEMENT
.
The following sections present details and examples of creating partitions for the various types of partitioned tables and indexes:
Using Subpartition Templates to Describe Composite Partitioned Tables
Partitioning Restrictions for Multiple Block Sizes
See Also:
Oracle Database SQL Reference for the exact syntax of the partitioning clauses for creating and altering partitioned tables and indexes, any restrictions on their use, and specific privileges required for creating and altering tables
Oracle Database Application Developer's Guide - Large Objects for information specific to creating partitioned tables containing columns with LOB
s or other objects stored as LOB
s
Oracle Database Application Developer's Guide - Object-Relational Features for information specific to creating tables with object types, nested tables, or VARRAYs.
The PARTITION BY RANGE
clause of the CREATE TABLE
statement specifies that the table or index is to be range-partitioned. The PARTITION
clauses identify the individual partition ranges, and optional subclauses of a PARTITION
clause can specify physical and other attributes specific to a partition segment. If not overridden at the partition level, partitions inherit the attributes of their underlying table.
In this example, more complexity is added to the example presented earlier for a range-partitioned table. Storage parameters and a LOGGING
attribute are specified at the table level. These replace the corresponding defaults inherited from the tablespace level for the table itself, and are inherited by the range partitions. However, because there was little business in the first quarter, the storage attributes for partition sales_q1
are made smaller. The ENABLE ROW MOVEMENT
clause is specified to allow the migration of a row to a new partition if an update to a key value is made that would place the row in a different partition.
CREATE TABLE sales ( invoice_no NUMBER, sale_year INT NOT NULL, sale_month INT NOT NULL, sale_day INT NOT NULL ) STORAGE (INITIAL 100K NEXT 50K) LOGGING PARTITION BY RANGE ( sale_year, sale_month, sale_day) ( PARTITION sales_q1 VALUES LESS THAN ( 1999, 04, 01 ) TABLESPACE tsa STORAGE (INITIAL 20K, NEXT 10K), PARTITION sales_q2 VALUES LESS THAN ( 1999, 07, 01 ) TABLESPACE tsb, PARTITION sales_q3 VALUES LESS THAN ( 1999, 10, 01 ) TABLESPACE tsc, PARTITION sales q4 VALUES LESS THAN ( 2000, 01, 01 ) TABLESPACE tsd) ENABLE ROW MOVEMENT;
The rules for creating range-partitioned global indexes are similar to those for creating range-partitioned tables. The following is an example of creating a range-partitioned global index on sales_month
for the table created in the preceding example. Each index partition is named but is stored in the default tablespace for the index.
CREATE INDEX month_ix ON sales(sales_month) GLOBAL PARTITION BY RANGE(sales_month) (PARTITION pm1_ix VALUES LESS THAN (2) PARTITION pm2_ix VALUES LESS THAN (3) PARTITION pm3_ix VALUES LESS THAN (4) PARTITION pm4_ix VALUES LESS THAN (5) PARTITION pm5_ix VALUES LESS THAN (6) PARTITION pm6_ix VALUES LESS THAN (7) PARTITION pm7_ix VALUES LESS THAN (8) PARTITION pm8_ix VALUES LESS THAN (9) PARTITION pm9_ix VALUES LESS THAN (10) PARTITION pm10_ix VALUES LESS THAN (11) PARTITION pm11_ix VALUES LESS THAN (12) PARTITION pm12_ix VALUES LESS THAN (MAXVALUE));
Note:
If your enterprise has or will have databases using different character sets, use caution when partitioning on character columns, because the sort sequence of characters is not identical in all character sets. For more information, see Oracle Database Globalization Support Guide.The PARTITION BY HASH
clause of the CREATE TABLE
statement identifies that the table is to be hash-partitioned. The PARTITIONS
clause can then be used to specify the number of partitions to create, and optionally, the tablespaces to store them in. Alternatively, you can use PARTITION
clauses to name the individual partitions and their tablespaces.
The only attribute you can specify for hash partitions is TABLESPACE
. All of the hash partitions of a table must share the same segment attributes (except TABLESPACE
), which are inherited from the table level.
The following examples illustrate two methods of creating a hash-partitioned table named dept
. In the first example the number of partitions is specified, but system generated names are assigned to them and they are stored in the default tablespace of the table.
CREATE TABLE dept (deptno NUMBER, deptname VARCHAR(32)) PARTITION BY HASH(deptno) PARTITIONS 16;
In this second example, names of individual partitions, and tablespaces in which they are to reside, are specified. The initial extent size for each hash partition (segment) is also explicitly stated at the table level, and all partitions inherit this attribute.
CREATE TABLE dept (deptno NUMBER, deptname VARCHAR(32)) STORAGE (INITIAL 10K) PARTITION BY HASH(deptno) (PARTITION p1 TABLESPACE ts1, PARTITION p2 TABLESPACE ts2, PARTITION p3 TABLESPACE ts1, PARTITION p4 TABLESPACE ts3);
If you create a local index for this table, the database constructs the index so that it is equipartitioned with the underlying table. The database also ensures that the index is maintained automatically when maintenance operations are performed on the underlying table. The following is an example of creating a local index on the table dept
:
CREATE INDEX loc_dept_ix ON dept(deptno) LOCAL;
You can optionally name the hash partitions and tablespaces into which the local index partitions are to be stored, but if you do not do so, the database uses the name of the corresponding base partition as the index partition name, and stores the index partition in the same tablespace as the table partition.
Hash partitioned global indexes can improve the performance of indexes where a small number of leaf blocks in the index have high contention in multiuser OLTP environments. Queries involving the equality and IN
predicates on the index partitioning key can efficiently use hash-partitioned global indexes.
The syntax for creating a hash partitioned global index is similar to that used for a hash partitioned table. For example, the following statement creates a hash-partitioned global index:
CREATE INDEX hgidx ON tab (c1,c2,c3) GLOBAL PARTITION BY HASH (c1,c2) (PARTITION p1 TABLESPACE tbs_1, PARTITION p2 TABLESPACE tbs_2, PARTITION p3 TABLESPACE tbs_3, PARTITION p4 TABLESPACE tbs_4);
The semantics for creating list partitions are very similar to those for creating range partitions. However, to create list partitions, you specify a PARTITION BY LIST
clause in the CREATE TABLE
statement, and the PARTITION
clauses specify lists of literal values, which are the discrete values of the partitioning columns that qualify rows to be included in the partition. For list partitioning, the partitioning key can only be a single column name from the table.
Available only with list partitioning, you can use the keyword DEFAULT
to describe the value list for a partition. This identifies a partition that will accommodate rows that do not map into any of the other partitions.
As for range partitions, optional subclauses of a PARTITION
clause can specify physical and other attributes specific to a partition segment. If not overridden at the partition level, partitions inherit the attributes of their parent table.
The following example creates table sales_by_region
and partitions it using the list method. The first two PARTITION
clauses specify physical attributes, which override the table-level defaults. The remaining PARTITION
clauses do not specify attributes and those partitions inherit their physical attributes from table-level defaults. A default partition is specified.
CREATE TABLE sales_by_region (item# INTEGER, qty INTEGER, store_name VARCHAR(30), state_code VARCHAR(2), sale_date DATE) STORAGE(INITIAL 10K NEXT 20K) TABLESPACE tbs5 PARTITION BY LIST (state_code) ( PARTITION region_east VALUES ('MA','NY','CT','NH','ME','MD','VA','PA','NJ') STORAGE (INITIAL 20K NEXT 40K PCTINCREASE 50) TABLESPACE tbs8, PARTITION region_west VALUES ('CA','AZ','NM','OR','WA','UT','NV','CO') NOLOGGING, PARTITION region_south VALUES ('TX','KY','TN','LA','MS','AR','AL','GA'), PARTITION region_central VALUES ('OH','ND','SD','MO','IL','MI','IA'), PARTITION region_null VALUES (NULL), PARTITION region_unknown VALUES (DEFAULT) );
To create a range-hash partitioned table, you start by using the PARTITION BY RANGE
clause of a CREATE TABLE
statement. Next, you specify a SUBPARTITION BY HASH
clause that follows similar syntax and rules as the PARTITION BY HASH
clause. The individual PARTITION
and SUBPARTITION
or SUBPARTITIONS
clauses, and optionally a SUBPARTITION TEMPLATE
clause, follow.
Attributes specified for a range partition apply to all subpartitions of that partition. You can specify different attributes for each range partition, and you can specify a STORE IN
clause at the partition level if the list of tablespaces across which the subpartitions of that partition should be spread is different from those of other partitions. All of this is illustrated in the following example.
CREATE TABLE emp (deptno NUMBER, empname VARCHAR(32), grade NUMBER) PARTITION BY RANGE(deptno) SUBPARTITION BY HASH(empname) SUBPARTITIONS 8 STORE IN (ts1, ts3, ts5, ts7) (PARTITION p1 VALUES LESS THAN (1000), PARTITION p2 VALUES LESS THAN (2000) STORE IN (ts2, ts4, ts6, ts8), PARTITION p3 VALUES LESS THAN (MAXVALUE) (SUBPARTITION p3_s1 TABLESPACE ts4, SUBPARTITION p3_s2 TABLESPACE ts5));
To learn how using a subpartition template can simplify the specification of a composite partitioned table, see "Using Subpartition Templates to Describe Composite Partitioned Tables".
The following statement is an example of creating a local index on the emp
table where the index segments are spread across tablespaces ts7
, ts8
, and ts9
.
CREATE INDEX emp_ix ON emp(deptno) LOCAL STORE IN (ts7, ts8, ts9);
This local index is equipartitioned with the base table as follows:
It consists of as many partitions as the base table.
Each index partition consists of as many subpartitions as the corresponding base table partition.
Index entries for rows in a given subpartition of the base table are stored in the corresponding subpartition of the index.
The concept of range-list partitioning is similar to that of the other composite partitioning method, range-hash, but this time you specify that the subpartitions are to be list rather than hash. Specifically, after the CREATE TABLE...PARTITION BY RANGE
clause, you include a SUBPARTITION BY LIST
clause that follows similar syntax and rules as the PARTITION BY LIST
clause. The individual PARTITION
and SUBPARTITION
clauses, and optionally a SUBPARTITION TEMPLATE
clause, follow.
The range partitions of the composite partitioned table are described as for non-composite range partitioned tables. This allows that optional subclauses of a PARTITION
clause can specify physical and other attributes, including tablespace, specific to a partition segment. If not overridden at the partition level, partitions inherit the attributes of their underlying table.
The list subpartition descriptions, in the SUBPARTITION
clauses, are described as for non-composite list partitions, except the only physical attribute that can be specified is a tablespace (optional). Subpartitions inherit all other physical attributes from the partition description.
The following example of creates a table that specifies a tablespace at the partition and subpartition levels. The number of subpartitions within each partition varies, and default subpartitions are specified.
CREATE TABLE sample_regional_sales (deptno number, item_no varchar2(20), txn_date date, txn_amount number, state varchar2(2)) PARTITION BY RANGE (txn_date) SUBPARTITION BY LIST (state) (PARTITION q1_1999 VALUES LESS THAN (TO_DATE('1-APR-1999','DD-MON-YYYY')) TABLESPACE tbs_1 (SUBPARTITION q1_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q1_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q1_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q1_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q1_others VALUES (DEFAULT) TABLESPACE tbs_4 ), PARTITION q2_1999 VALUES LESS THAN ( TO_DATE('1-JUL-1999','DD-MON-YYYY')) TABLESPACE tbs_2 (SUBPARTITION q2_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q2_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q2_1999_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q2_1999_southeast VALUES ('FL', 'GA'), SUBPARTITION q2_1999_northcentral VALUES ('SD', 'WI'), SUBPARTITION q2_1999_southcentral VALUES ('OK', 'TX') ), PARTITION q3_1999 VALUES LESS THAN (TO_DATE('1-OCT-1999','DD-MON-YYYY')) TABLESPACE tbs_3 (SUBPARTITION q3_1999_northwest VALUES ('OR', 'WA'), SUBPARTITION q3_1999_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q3_others VALUES (DEFAULT) TABLESPACE tbs_4 ), PARTITION q4_1999 VALUES LESS THAN ( TO_DATE('1-JAN-2000','DD-MON-YYYY')) TABLESPACE tbs_4 );
This example results in the following subpartition descriptions:
All subpartitions inherit their physical attributes, other than tablespace, from tablespace level defaults. This is because the only physical attribute that has been specified for partitions or subpartitions is tablespace. There are no table level physical attributes specified, thus tablespace level defaults are inherited at all levels.
The first 4 subpartitions of partition q1_1999
are all contained in tbs_1
, except for the subpartition q1_others
, which is stored in tbs_4
and contains all rows that do not map to any of the other partitions.
The 6 subpartitions of partition q2_1999
are all stored in tbs_2
.
The first 2 subpartitions of partition q3_1999
are all contained in tbs_3
, except for the subpartition q3_others
, which is stored in tbs_4
and contains all rows that do not map to any of the other partitions.
There is no subpartition description for partition q4_1999
. This results in one default subpartition being created and stored in tbs_4
. The subpartition name is system generated in the form SYS_SUBP
n
.
To learn how using a subpartition template can simplify the specification of a composite partitioned table, see "Using Subpartition Templates to Describe Composite Partitioned Tables".
You can create subpartitions in a composite partitioned table using a subpartition template. A subpartition template simplifies the specification of subpartitions by not requiring that a subpartition descriptor be specified for every partition in the table. Instead, you describe subpartitions only once in a template, then apply that subpartition template to every partition in the table.
The subpartition template is used whenever a subpartition descriptor is not specified for a partition. If a subpartition descriptor is specified, then it is used instead of the subpartition template for that partition. If no subpartition template is specified, and no subpartition descriptor is supplied for a partition, then a single default subpartition is created.
In the case of range-hash partitioned tables, the subpartition template can describe the subpartitions in detail, or it can specify just the number of hash subpartitions.
The following example creates a range-hash partitioned table using a subpartition template:
CREATE TABLE emp_sub_template (deptno NUMBER, empname VARCHAR(32), grade NUMBER) PARTITION BY RANGE(deptno) SUBPARTITION BY HASH(empname) SUBPARTITION TEMPLATE (SUBPARTITION a TABLESPACE ts1, SUBPARTITION b TABLESPACE ts2, SUBPARTITION c TABLESPACE ts3, SUBPARTITION d TABLESPACE ts4 ) (PARTITION p1 VALUES LESS THAN (1000), PARTITION p2 VALUES LESS THAN (2000), PARTITION p3 VALUES LESS THAN (MAXVALUE) );
This example produces the following table description:
Every partition has four subpartitions as described in the subpartition template.
Each subpartition has a tablespace specified. It is required that if a tablespace is specified for one subpartition in a subpartition template, then one must be specified for all.
The names of the subpartitions are generated by concatenating the partition name with the subpartition name in the form:
partition name_subpartition name
The following query displays the subpartition names and tablespaces:
SQL> SELECT TABLESPACE_NAME, PARTITION_NAME, SUBPARTITION_NAME 2 FROM DBA_TAB_SUBPARTITIONS WHERE TABLE_NAME='EMP_SUB_TEMPLATE' 3 ORDER BY TABLESPACE_NAME; TABLESPACE_NAME PARTITION_NAME SUBPARTITION_NAME --------------- --------------- ------------------ TS1 P1 P1_A TS1 P2 P2_A TS1 P3 P3_A TS2 P1 P1_B TS2 P2 P2_B TS2 P3 P3_B TS3 P1 P1_C TS3 P2 P2_C TS3 P3 P3_C TS4 P1 P1_D TS4 P2 P2_D TS4 P3 P3_D 12 rows selected.
The following example, for a range-list partitioned table, illustrates how using a subpartition template can help you stripe data across tablespaces. In this example a table is created where the table subpartitions are vertically striped, meaning that subpartition n from every partition is in the same tablespace.
CREATE TABLE stripe_regional_sales ( deptno number, item_no varchar2(20), txn_date date, txn_amount number, state varchar2(2)) PARTITION BY RANGE (txn_date) SUBPARTITION BY LIST (state) SUBPARTITION TEMPLATE (SUBPARTITION northwest VALUES ('OR', 'WA') TABLESPACE tbs_1, SUBPARTITION southwest VALUES ('AZ', 'UT', 'NM') TABLESPACE tbs_2, SUBPARTITION northeast VALUES ('NY', 'VM', 'NJ') TABLESPACE tbs_3, SUBPARTITION southeast VALUES ('FL', 'GA') TABLESPACE tbs_4, SUBPARTITION midwest VALUES ('SD', 'WI') TABLESPACE tbs_5, SUBPARTITION south VALUES ('AL', 'AK') TABLESPACE tbs_6, SUBPARTITION others VALUES (DEFAULT ) TABLESPACE tbs_7 ) (PARTITION q1_1999 VALUES LESS THAN ( TO_DATE('01-APR-1999','DD-MON-YYYY')), PARTITION q2_1999 VALUES LESS THAN ( TO_DATE('01-JUL-1999','DD-MON-YYYY')), PARTITION q3_1999 VALUES LESS THAN ( TO_DATE('01-OCT-1999','DD-MON-YYYY')), PARTITION q4_1999 VALUES LESS THAN ( TO_DATE('1-JAN-2000','DD-MON-YYYY')) );
If you specified the tablespaces at the partition level (for example, tbs_1
for partition q1_1999
, tbs_2
for partition q1_1999
, tbs_3
for partition q3_1999
, and tbs_4
for partition q4_1999
) and not in the subpartition template, then the table would be horizontally striped. All subpartitions would be in the tablespace of the owning partition.
For range- and hash-partitioned tables, you can specify up to 16 partitioning key columns. Multicolumn partitioning should be used when the partitioning key is composed of several columns and subsequent columns define a higher granularity than the preceding ones. The most common scenario is a decomposed DATE
or TIMESTAMP
key, consisting of separated columns, for year, month, and day.
In evaluating multicolumn partitioning keys, the database uses the second value only if the first value cannot uniquely identify a single target partition, and uses the third value only if the first and second do not determine the correct partition, and so forth. A value cannot determine the correct partition only when a partition bound exactly matches that value and the same bound is defined for the next partition. The nth column will therefore be investigated only when all previous (n-1) values of the multicolumn key exactly match the (n-1) bounds of a partition. A second column, for example, will be evaluated only if the first column exactly matches the partition boundary value. If all column values exactly match all of the bound values for a partition, the database will determine that the row does not fit in this partition and will consider the next partition for a match.
In the case of nondeterministic boundary definitions (successive partitions with identical values for at least one column), the partition boundary value becomes an inclusive value, representing a "less than or equal to" boundary. This is in contrast to deterministic boundaries, where the values are always regarded as "less than" boundaries.
The following example illustrates the column evaluation for a multicolumn range-partitioned table, storing the actual DATE
information in three separate columns: year
, month
, and date
. The partitioning granularity is a calendar quarter. The partitioned table being evaluated is created as follows:
CREATE TABLE sales_demo ( year NUMBER, month NUMBER, day NUMBER, amount_sold NUMBER) PARTITION BY RANGE (year,month) (PARTITION before2001 VALUES LESS THAN (2001,1), PARTITION q1_2001 VALUES LESS THAN (2001,4), PARTITION q2_2001 VALUES LESS THAN (2001,7), PARTITION q3_2001 VALUES LESS THAN (2001,10), PARTITION q4_2001 VALUES LESS THAN (2002,1), PARTITION future VALUES LESS THAN (MAXVALUE,0)); REM 12-DEC-2000 INSERT INTO sales_demo VALUES(2000,12,12, 1000); REM 17-MAR-2001 INSERT INTO sales_demo VALUES(2001,3,17, 2000); REM 1-NOV-2001 INSERT INTO sales_demo VALUES(2001,11,1, 5000); REM 1-JAN-2002 INSERT INTO sales_demo VALUES(2002,1,1, 4000);
The year value for 12-DEC-2000 satisfied the first partition, before2001
, so no further evaluation is needed:
SELECT * FROM sales_demo PARTITION(before2001); YEAR MONTH DAY AMOUNT_SOLD ---------- ---------- ---------- ----------- 2000 12 12 1000
The information for 17-MAR-2001 is stored in partition q1_2001
. The first partitioning key column, year
, does not by itself determine the correct partition, so the second partition key column, month
, must be evaluated.
SELECT * FROM sales_demo PARTITION(q1_2001); YEAR MONTH DAY AMOUNT_SOLD ---------- ---------- ---------- ----------- 2001 3 17 2000
Following the same determination rule as for the previous record, the second column, month
, determines partition q4_2001
as correct partition for 1-NOV-2001:
SELECT * FROM sales_demo PARTITION(q4_2001); YEAR MONTH DAY AMOUNT_SOLD ---------- ---------- ---------- ----------- 2001 11 1 5000
The partition for 01-JAN-2002 is determined by evaluating only the year
column, which indicates the future
partition:
SELECT * FROM sales_demo PARTITION(future); YEAR MONTH DAY AMOUNT_SOLD ---------- ---------- ---------- ----------- 2002 1 1 4000
If the database encounters MAXVALUE
in one of the partition key columns, all other values of subsequent columns become irrelevant. That is, a definition of partition future
in the preceding example, having a bound of (MAXVALUE
,0) is equivalent to a bound of (MAXVALUE
,100) or a bound of (MAXVALUE
,MAXVALUE
).
The following example illustrates the use of a multicolumn partitioned approach for table supplier_parts
, storing the information about which suppliers deliver which parts. To distribute the data in equal-sized partitions, it is not sufficient to partition the table based on the supplier_id
, because some suppliers might provide hundreds of thousands of parts, while others provide only a few specialty parts. Instead, you partition the table on (supplier_id
, partnum
) to manually enforce equal-sized partitions.
CREATE TABLE supplier_parts ( supplier_id NUMBER, partnum NUMBER, price NUMBER) PARTITION BY RANGE (supplier_id, partnum) (PARTITION p1 VALUES LESS THAN (10,100), PARTITION p2 VALUES LESS THAN (10,200), PARTITION p3 VALUES LESS THAN (MAXVALUE,MAXVALUE));
The following three records are inserted into the table:
INSERT INTO supplier_parts VALUES (5,5, 1000); INSERT INTO supplier_parts VALUES (5,150, 1000); INSERT INTO supplier_parts VALUES (10,100, 1000);
The first two records are inserted into partition p1
, uniquely identified by supplier_id
. However, the third record is inserted into partition p2
; it matches all range boundary values of partition p1
exactly and the database therefore considers the following partition for a match. The value of partnum
satisfies the criteria < 200, so it is inserted into partition p2
.
SELECT * FROM supplier_parts PARTITION (p1); SUPPLIER_ID PARTNUM PRICE ----------- ---------- ---------- 5 5 1000 5 150 1000 SELECT * FROM supplier_parts PARTITION (p2); SUPPLIER_ID PARTNUM PRICE ----------- ---------- ---------- 10 100 1000
Every row with supplier_id
< 10 will be stored in partition p1
, regardless of the partnum
value. The column partnum
will be evaluated only if supplier_id
=10, and the corresponding rows will be inserted into partition p1
, p2
, or even into p3
when partnum
>=200. To achieve equal-sized partitions for ranges of supplier_parts
, you could choose a composite range-hash partitioned table, range partitioned by supplier_id
, hash subpartitioned by partnum
.
Defining the partition boundaries for multicolumn partitioned tables must obey some rules. For example, consider a table that is range partitioned on three columns a
, b
, and c
. The individual partitions have range values represented as follows:
P0(a0, b0, c0) P1(a1, b1, c1) P2(a2, b2, c2) … Pn(an, bn, cn)
The range values you provide for each partition must follow these rules:
a0
must be less than or equal to a1
, and a1
must be less than or equal to a2
, and so on.
If a0
=a1
, then b0
must be less than or equal to b1
. If a0
< a1
, then b0
and b1
can have any values. If b0
=b1
, then c0
must be less than or equal to c1
. If b0
<b1
, then c0
and c1
can have any values, and so on.
If a1
=a2
, then b1
must be less than or equal to b2
. If a1
<a2
, then b1
and b2
can have any values. If b1
=b2
, then c1
must be less than or equal to c2
. If b1
<b2
, then c0
and c1
can have any values, and so on.
For heap-organized partitioned tables, you can compress some or all partitions using table compression. The compression attribute can be declared for a tablespace, a table, or a partition of a table. Whenever the compress attribute is not specified, it is inherited like any other storage attribute.
The following example creates a list-partitioned table with one compressed partition costs_old
. The compression attribute for the table and all other partitions is inherited from the tablespace level.
CREATE TABLE costs_demo ( prod_id NUMBER(6), time_id DATE, unit_cost NUMBER(10,2), unit_price NUMBER(10,2)) PARTITION BY RANGE (time_id) (PARTITION costs_old VALUES LESS THAN (TO_DATE('01-JAN-2003', 'DD-MON-YYYY')) COMPRESS, PARTITION costs_q1_2003 VALUES LESS THAN (TO_DATE('01-APR-2003', 'DD-MON-YYYY')), PARTITION costs_q2_2003 VALUES LESS THAN (TO_DATE('01-JUN-2003', 'DD-MON-YYYY')), PARTITION costs_recent VALUES LESS THAN (MAXVALUE));
You can compress some or all partitions of a B-tree index using key compression. Key compression is applicable only to B-tree indexes. Bitmap indexes are stored in a compressed manner by default. Index using key compression eliminates repeated occurrences of key column prefix values, thus saving space and I/O.
The following example creates a local partitioned index with all partitions except the most recent one compressed:
CREATE INDEX i_cost1 ON costs_demo (prod_id) COMPRESS LOCAL (PARTITION costs_old, PARTITION costs_q1_2003, PARTITION costs_q2_2003, PARTITION costs_recent NOCOMPRESS);
You cannot specify COMPRESS
(or NOCOMPRESS
) explicitly for an index subpartition. All index subpartitions of a given partition inherit the key compression setting from the parent partition.
To modify the key compression attribute for all subpartitions of a given partition, you must first issue an ALTER INDEX...MODIFY PARTITION
statement and then rebuild all subpartitions. The MODIFY PARTITION
clause will mark all index subpartitions as UNUSABLE
.
For index-organized tables, you can use the range, list, or hash partitioning method. The semantics for creating partitioned index-organized tables is similar to that for regular tables with these differences:
When you create the table you specify the ORGANIZATION INDEX
clause, and INCLUDING
and OVERFLOW
clauses as necessary.
The PARTITION
or PARTITIONS
clauses can have OVERFLOW
subclauses that allow you to specify attributes of the overflow segments at the partition level.
Specifying an OVERFLOW
clause results in the overflow data segments themselves being equipartitioned with the primary key index segments. Thus, for partitioned index-organized tables with overflow, each partition has an index segment and an overflow data segment.
For index-organized tables, the set of partitioning columns must be a subset of the primary key columns. Because rows of an index-organized table are stored in the primary key index for the table, the partitioning criterion has an effect on the availability. By choosing the partition key to be a subset of the primary key, an insert operation only needs to verify uniqueness of the primary key in a single partition, thereby maintaining partition independence.
Support for secondary indexes on index-organized tables is similar to the support for regular tables. Because of the logical nature of the secondary indexes, global indexes on index-organized tables remain usable for certain operations where they would be marked UNUSABLE for regular tables.
See Also:
Oracle Database Concepts for more information about index-organized tables
You can partition index-organized tables, and their secondary indexes, by the range method. In the following example, a range-partitioned index-organized table sales
is created. The INCLUDING
clause specifies all columns after week_no
are stored in an overflow segment. There is one overflow segment for each partition, all stored in the same tablespace (overflow_here
). Optionally, OVERFLOW TABLESPACE
could be specified at the individual partition level, in which case some or all of the overflow segments could have separate TABLESPACE
attributes.
CREATE TABLE sales(acct_no NUMBER(5), acct_name CHAR(30), amount_of_sale NUMBER(6), week_no INTEGER, sale_details VARCHAR2(1000), PRIMARY KEY (acct_no, acct_name, week_no)) ORGANIZATION INDEX INCLUDING week_no OVERFLOW TABLESPACE overflow_here PARTITION BY RANGE (week_no) (PARTITION VALUES LESS THAN (5) TABLESPACE ts1, PARTITION VALUES LESS THAN (9) TABLESPACE ts2 OVERFLOW TABLESPACE overflow_ts2, ... PARTITION VALUES LESS THAN (MAXVALUE) TABLESPACE ts13);
Another option for partitioning index-organized tables is to use the list method. In the following example the index-organized table, sales
, is partitioned by the list method. This example uses the example
tablespace, which is part of the sample schemas in your seed database. Normally you would specify different tablespace storage for different partitions.
CREATE TABLE sales(acct_no NUMBER(5), acct_name CHAR(30), amount_of_sale NUMBER(6), week_no INTEGER, sale_details VARCHAR2(1000), PRIMARY KEY (acct_no, acct_name, week_no)) ORGANIZATION INDEX INCLUDING week_no OVERFLOW TABLESPACE example PARTITION BY LIST (week_no) (PARTITION VALUES (1, 2, 3, 4) TABLESPACE example, PARTITION VALUES (5, 6, 7, 8) TABLESPACE example OVERFLOW TABLESPACE example, PARTITION VALUES (DEFAULT) TABLESPACE example);
The other option for partitioning index-organized tables is to use the hash method. In the following example the index-organized table, sales
, is partitioned by the hash method.
CREATE TABLE sales(acct_no NUMBER(5), acct_name CHAR(30), amount_of_sale NUMBER(6), week_no INTEGER, sale_details VARCHAR2(1000), PRIMARY KEY (acct_no, acct_name, week_no)) ORGANIZATION INDEX INCLUDING week_no OVERFLOW PARTITION BY HASH (week_no) PARTITIONS 16 STORE IN (ts1, ts2, ts3, ts4) OVERFLOW STORE IN (ts3, ts6, ts9);
Note:
A well-designed hash function is intended to distribute rows in a well-balanced fashion among the partitions. Therefore, updating the primary key column(s) of a row is very likely to move that row to a different partition. Oracle recommends that you explicitly specify theENABLE ROW MOVEMENT
clause when creating a hash-partitioned index-organized table with a changeable partitioning key. The default is that ENABLE ROW MOVEMENT
is disabled.Use caution when creating partitioned objects in a database with tablespaces of multiple block size. The storage of partitioned objects in such tablespaces is subject to some restrictions. Specifically, all partitions of the following entities must reside in tablespaces of the same block size:
Conventional tables
Indexes
Primary key index segments of index-organized tables
Overflow segments of index-organized tables
LOB
columns stored out of line
Therefore:
For each conventional table, all partitions of that table must be stored in tablespaces with the same block size.
For each index-organized table, all primary key index partitions must reside in tablespaces of the same block size, and all overflow partitions of that table must reside in tablespaces of the same block size. However, index partitions and overflow partitions can reside in tablespaces of different block size.
For each index (global or local), each partition of that index must reside in tablespaces of the same block size. However, partitions of different indexes defined on the same object can reside in tablespaces of different block sizes.
For each LOB
column, each partition of that column must be stored in tablespaces of equal block sizes. However, different LOB
columns can be stored in tablespaces of different block sizes.
When you create or alter a partitioned table or index, all tablespaces you explicitly specify for the partitions and subpartitions of each entity must be of the same block size. If you do not explicitly specify tablespace storage for an entity, the tablespaces the database uses by default must be of the same block size. Therefore you must be aware of the default tablespaces at each level of the partitioned object.
This section describes how to perform partition and subpartition maintenance operations for both tables and indexes.
Table 17-1 lists maintenance operations that can be performed on table partitions (or subpartitions) and, for each type of partitioning, lists the specific clause of the ALTER TABLE
statement that is used to perform that maintenance operation.
Table 17-1 ALTER TABLE Maintenance Operations for Table Partitions
Maintenance Operation | Range | Hash | List | Composite: Range/Hash | Composite: Range/List |
---|---|---|---|---|---|
|
|
|
|
|
|
n/a |
|
n/a |
|
n/a |
|
|
n/a |
|
|
|
|
|
|
|
|
|
|
|
n/a |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
n/a |
n/a |
|
n/a |
|
|
n/a |
n/a |
|
n/a |
|
|
n/a |
n/a |
n/a |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
n/a |
|
|
|
|
|
|
|
|
|
Note:
The first time you use table compression to introduce a compressed partition into a partitioned table that has bitmap indexes and that currently contains only uncompressed partitions, you must do the following:Either drop all existing bitmap indexes and bitmap index partitions, or mark them UNUSABLE
.
Set the table compression attribute.
Rebuild the indexes.
These actions are independent of whether any partitions contain data and of the operation that introduces the compressed partition.
This does not apply to partitioned tables with B-tree indexes or to partitioned index-organized tables.
For more information, see the Oracle Database Data Warehousing Guide.
Table 17-2 lists maintenance operations that can be performed on index partitions, and indicates on which type of index (global or local) they can be performed. The ALTER INDEX
clause used for the maintenance operation is shown.
Global indexes do not reflect the structure of the underlying table. If partitioned, they can be partitioned by range or hash. Partitioned global indexes share some, but not all, of the partition maintenance operations that can be performed on partitioned tables.
Because local indexes reflect the underlying structure of the table, partitioning is maintained automatically when table partitions and subpartitions are affected by maintenance activity. Therefore, partition maintenance on local indexes is less necessary and there are fewer options.
Table 17-2 ALTER INDEX Maintenance Operations for Index Partitions
Maintenance Operation | Type of Index | Type of Index Partitioning | ||
---|---|---|---|---|
Range | Hash and List | Composite | ||
Global |
|
|
- |
|
Local |
n/a |
n/a |
n/a |
|
Global |
|
- |
- |
|
Local |
n/a |
n/a |
n/a |
|
Global |
|
- |
- |
|
Local |
|
|
|
|
Global |
|
- |
- |
|
Local |
|
|
|
|
Global |
|
- |
- |
|
Local |
|
|
|
|
Global |
|
- |
- |
|
Local |
|
|
|
|
Global |
|
- |
- |
|
Local |
n/a |
n/a |
n/a |
Note:
The following sections discuss maintenance operations on partitioned tables. Where the usability of indexes or index partitions affected by the maintenance operation is discussed, consider the following:Only indexes and index partitions that are not empty are candidates for being marked UNUSABLE
. If they are empty, the USABLE
/UNUSABLE
status is left unchanged.
Only indexes or index partitions with USABLE
status are updated by subsequent DML.
Before discussing the individual maintenance operations for partitioned tables and indexes, it is important to discuss the effects of the UPDATE
INDEXES
clause that can be specified in the ALTER
TABLE
statement.
By default, many table maintenance operations on partitioned tables invalidate (mark UNUSABLE
) the corresponding indexes or index partitions. You must then rebuild the entire index or, in the case of a global index, each of its partitions. The database lets you override this default behavior if you specify UPDATE
INDEXES
in your ALTER
TABLE
statement for the maintenance operation. Specifying this clause tells the database to update the index at the time it executes the maintenance operation DDL statement. This provides the following benefits:
The index is updated in conjunction with the base table operation. You are not required to later and independently rebuild the index.
The index is more highly available, because it does not get marked UNUSABLE
. The index remains available even while the partition DDL is executing and it can be used to access unaffected partitions in the table.
You need not look up the names of all invalid indexes to rebuild them.
Optional clauses for local indexes let you specify physical and storage characteristics for updated local indexes and their partitions.
You can specify physical attributes, tablespace storage, and logging for each partition of each local index. Alternatively, you can specify only the PARTITION
keyword and let the database update the partition attributes as follows:
For operations on a single table partition (such as MOVE
PARTITION
and SPLIT
PARTITION
), the corresponding index partition inherits the attributes of the affected index partition. The database does not generate names for new index partitions, so any new index partitions resulting from this operation inherit their names from the corresponding new table partition.
For MERGE
PARTITION
operations, the resulting local index partition inherits its name from the resulting table partition and inherits its attributes from the local index.
For a composite-partitioned index, you can specify tablespace storage for each subpartition.
The following operations support the UPDATE
INDEXES
clause:
ADD
PARTITION
| SUBPARTITION
COALESCE
PARTITION
| SUBPARTITION
DROP
PARTITION
| SUBPARTITION
EXCHANGE
PARTITION
| SUBPARTITION
MERGE
PARTITION
| SUBPARTITION
MOVE
PARTITION
| SUBPARTITION
SPLIT
PARTITION
| SUBPARTITION
TRUNCATE
PARTITION
| SUBPARTITION
SKIP_UNUSABLE_INDEXES Initialization Parameter
SKIP_UNUSABLE_INDEXES
, which in Release 9.x and earlier was a session parameter, is an initialization parameter in Release 10.x and later, with a default value of TRUE
. This setting disables error reporting of indexes and index partitions marked UNUSABLE
. If you do not want the database to choose an alternative execution plan to avoid the unusable elements, you should set this parameter to FALSE
.
Considerations when Updating Indexes Automatically
The following implications are worth noting when you specify UPDATE
INDEXES
:
The partition DDL statement takes longer to execute, because indexes that were previously marked UNUSABLE
are updated. However, you must compare this increase with the time it takes to execute DDL without updating indexes, and then rebuild all indexes. A rule of thumb is that it is faster to update indexes if the size of the partition is less that 5% of the size of the table.
The DROP
, TRUNCATE
, and EXCHANGE
operations are no longer fast operations. Again, you must compare the time it takes to do the DDL and then rebuild all indexes.
When you update a table with a global index:
The index is updated in place. The updates to the index are logged, and redo and undo records are generated. In contrast, if you rebuild an entire global index, you can do so in NOLOGGING
mode.
Rebuilding the entire index manually creates a more efficient index, because it is more compact with space better utilized.
The UPDATE INDEXES
clause is not supported for index-organized tables. However, the UPDATE GLOBAL INDEXES
clause may be used with DROP
PARTITION
, TRUNCATE
PARTITION
, and EXCHANGE
PARTITION
operations to keep the global indexes on index-organized tables usable. For the remaining operations in the above list, global indexes on index-organized tables remain usable. In addition, local index partitions on index-organized tables remain usable after a MOVE
PARTITION
operation.
This section describes how to add new partitions to a partitioned table and explains why partitions cannot be specifically added to most partitioned indexes.
Use the ALTER
TABLE
... ADD
PARTITION
statement to add a new partition to the "high" end (the point after the last existing partition). To add a partition at the beginning or in the middle of a table, use the SPLIT
PARTITION
clause.
For example, consider the table, sales
, which contains data for the current month in addition to the previous 12 months. On January 1, 1999, you add a partition for January, which is stored in tablespace tsx
.
ALTER TABLE sales ADD PARTITION jan96 VALUES LESS THAN ( '01-FEB-1999' ) TABLESPACE tsx;
Local and global indexes associated with the range-partitioned table remain usable.
When you add a partition to a hash-partitioned table, the database populates the new partition with rows rehashed from an existing partition (selected by the database) as determined by the hash function.
The following statements show two ways of adding a hash partition to table scubagear
. Choosing the first statement adds a new hash partition whose partition name is system generated, and which is placed in the table default tablespace. The second statement also adds a new hash partition, but that partition is explicitly named p_named
and is created in tablespace gear5
.
ALTER TABLE scubagear ADD PARTITION; ALTER TABLE scubagear ADD PARTITION p_named TABLESPACE gear5;
Indexes may be marked UNUSABLE
as explained in the following table:
Table Type | Index Behavior |
---|---|
Regular (Heap) | Unless you specify UPDATE INDEXES as part of the ALTER TABLE statement:
|
Index-organized |
|
The following statement illustrates adding a new partition to a list-partitioned table. In this example physical attributes and NOLOGGING
are specified for the partition being added.
ALTER TABLE q1_sales_by_region ADD PARTITION q1_nonmainland VALUES ('HI', 'PR') STORAGE (INITIAL 20K NEXT 20K) TABLESPACE tbs_3 NOLOGGING;
Any value in the set of literal values that describe the partition being added must not exist in any of the other partitions of the table.
You cannot add a partition to a list-partitioned table that has a default partition, but you can split the default partition. By doing so, you effectively create a new partition defined by the values that you specify, and a second partition that remains the default partition.
Local and global indexes associated with the list-partitioned table remain usable.
Partitions can be added at both the range partition level and the hash subpartition level.
Adding a new range partition to a range-hash partitioned table is as described previously in "Adding a Partition to a Range-Partitioned Table". However, you can specify a SUBPARTITIONS
clause that lets you add a specified number of subpartitions, or a SUBPARTITION
clause for naming specific subpartitions. If no SUBPARTITIONS
or SUBPARTITION
clause is specified, the partition inherits table level defaults for subpartitions.
This example adds a range partition q1_2000
to table sales
, which will be populated with data for the first quarter of the year 2000. There are eight subpartitions stored in tablespace tbs5
. The subpartitions cannot be set explicitly to use table compression. Subpartitions inherit the compression attribute from the partition level and are stored in a compressed form in this example:
ALTER TABLE sales ADD PARTITION q1_2000 VALUES LESS THAN (2000, 04, 01) COMPRESS SUBPARTITIONS 8 STORE IN tbs5;
You use the MODIFY
PARTITION
... ADD
SUBPARTITION
clause of the ALTER
TABLE
statement to add a hash subpartition to a range-hash partitioned table. The newly added subpartition is populated with rows rehashed from other subpartitions of the same partition as determined by the hash function.
In the following example, a new hash subpartition us_loc5
, stored in tablespace us1
, is added to range partition locations_us
in table diving
.
ALTER TABLE diving MODIFY PARTITION locations_us ADD SUBPARTITION us_locs5 TABLESPACE us1;
Index subpartitions corresponding to the added and rehashed subpartitions must be rebuilt unless you specify UPDATE
INDEXES
.
Partitions can be added at both the range partition level and the list subpartition level.
Adding a new range partition to a range-list partitioned table is as described previously in "Adding a Partition to a Range-Partitioned Table". However, you can specify SUBPARTITION
clauses for naming and providing value lists for the subpartitions. If no SUBPARTITION
clauses are specified, then the partition inherits the subpartition template. If there is no subpartition template, then a single default subpartition is created.
This following statement statements adds a new partition to the quarterly_regional_sales
table that is partitioned by the range-list method. Some new physical attributes are specified for this new partition while table-level defaults are inherited for those that are not specified.
ALTER TABLE quarterly_regional_sales ADD PARTITION q1_2000 VALUES LESS THAN (TO_DATE('1-APR-2000','DD-MON-YYYY')) STORAGE (INITIAL 20K NEXT 20K) TABLESPACE ts3 NOLOGGING ( SUBPARTITION q1_2000_northwest VALUES ('OR', 'WA'), SUBPARTITION q1_2000_southwest VALUES ('AZ', 'UT', 'NM'), SUBPARTITION q1_2000_northeast VALUES ('NY', 'VM', 'NJ'), SUBPARTITION q1_2000_southeast VALUES ('FL', 'GA'), SUBPARTITION q1_2000_northcentral VALUES ('SD', 'WI'), SUBPARTITION q1_2000_southcentral VALUES ('OK', 'TX') );
You use the MODIFY
PARTITION
... ADD
SUBPARTITION
clause of the ALTER
TABLE
statement to add a list subpartition to a range-list partitioned table.
The following statement adds a new subpartition to the existing set of subpartitions in range-list partitioned table quarterly_regional_sales
. The new subpartition is created in tablespace ts2
.
ALTER TABLE quarterly_regional_sales MODIFY PARTITION q1_1999 ADD SUBPARTITION q1_1999_south VALUES ('AR','MS','AL') tablespace ts2;
You cannot explicitly add a partition to a local index. Instead, a new partition is added to a local index only when you add a partition to the underlying table. Specifically, when there is a local index defined on a table and you issue the ALTER
TABLE
statement to add a partition, a matching partition is also added to the local index. The database assigns names and default physical storage attributes to the new index partitions, but you can rename or alter them after the ADD
PARTITION
operation is complete.
You can effectively specify a new tablespace for an index partition in an ADD
PARTITION
operation by first modifying the default attributes for the index. For example, assume that a local index, q1_sales_by_region_locix
, was created for list partitioned table q1_sales_by_region
. If before adding the new partition q1_nonmainland
, as shown in "Adding a Partition to a List-Partitioned Table", you had issued the following statement, then the corresponding index partition would be created in tablespace tbs_4
.
ALTER INDEX q1_sales_by_region_locix MODIFY DEFAULT ATTRIBUTES TABLESPACE tbs_4;
Otherwise, it would be necessary for you to use the following statement to move the index partition to tbs_4
after adding it:
ALTER INDEX q1_sales_by_region_locix REBUILD PARTITION q1_nonmainland TABLESPACE tbs_4;
You can add a partition to a hash-partitioned global index using the ADD
PARTITION
syntax of ALTER
INDEX
. The database adds hash partitions and populates them with index entries rehashed from an existing hash partition of the index, as determined by the hash function. The following statement adds a partition to the index hgidx
shown in "Creating a Hash-Partitioned Global Index":
ALTER INDEX hgidx ADD PARTITION p5;
You cannot add a partition to a range-partitioned global index, because the highest partition always has a partition bound of MAXVALUE
. If you want to add a new highest partition, use the ALTER
INDEX
... SPLIT
PARTITION
statement.
Coalescing partitions is a way of reducing the number of partitions in a hash-partitioned table or index, or the number of subpartitions in a range-hash partitioned table. When a hash partition is coalesced, its contents are redistributed into one or more remaining partitions determined by the hash function. The specific partition that is coalesced is selected by the database, and is dropped after its contents have been redistributed.
Index partitions may be marked UNUSABLE
as explained in the following table:
Table Type | Index Behavior |
---|---|
Regular (Heap) | Unless you specify UPDATE INDEXES as part of the ALTER TABLE statement:
|
Index-organized |
|
The ALTER
TABLE
... COALESCE
PARTITION
statement is used to coalesce a partition in a hash-partitioned table. The following statement reduces by one the number of partitions in a table by coalescing a partition.
ALTER TABLE ouu1 COALESCE PARTITION;
The following statement distributes the contents of a subpartition of partition us_locations
into one or more remaining subpartitions (determined by the hash function) of the same partition. Basically, this operation is the inverse of the MODIFY
PARTITION
... ADD
SUBPARTITION
clause discussed in "Adding a Subpartition to a Range-Hash Partitioned Table".
ALTER TABLE diving MODIFY PARTITION us_locations COALESCE SUBPARTITION;
You can instruct the database to reduce by one the number of index partitions in a hash-partitioned global index using the COALESCE
PARTITION
clause of ALTER
INDEX
. The database selects the partition to coalesce based on the requirements of the hash partition. The following statement reduces by one the number of partitions in the hgidx
index, created in "Creating a Hash-Partitioned Global Index":
ALTER INDEX hgidx COALESCE PARTITION;
You can drop partitions from range, list, or composite range-list partitioned tables. For hash-partitioned tables, or hash subpartitions of range-hash partitioned tables, you must perform a coalesce operation instead.
Use one of the following statements to drop a table partition or subpartition:
ALTER
TABLE
... DROP
SUBPARTITION
to drop a subpartition of a range-list partitioned table
If you want to preserve the data in the partition, use the MERGE
PARTITION
statement instead of the DROP
PARTITION
statement.
If local indexes are defined for the table, this statement also drops the matching partition or subpartitions from the local index. All global indexes, or all partitions of partitioned global indexes, are marked UNUSABLE
unless either of the following are true:
You specify UPDATE
INDEXES
(Cannot be specified for index-organized tables. Use UPDATE
GLOBAL
INDEXES
instead.)
The partition being dropped or its subpartitions are empty
Note:
You cannot drop the only partition in a table. Instead, you must drop the table.The following sections contain some scenarios for dropping table partitions.
If the partition contains data and one or more global indexes are defined on the table, use one of the following methods to drop the table partition.
Method 1
Leave the global indexes in place during the ALTER
TABLE
... DROP
PARTITION
statement. Afterward, you must rebuild any global indexes (whether partitioned or not) because the index (or index partitions) will have been marked UNUSABLE
. The following statements provide an example of dropping partition dec98 from the sales table, then rebuilding its global non-partitioned index.
ALTER TABLE sales DROP PARTITION dec98; ALTER INDEX sales_area_ix REBUILD;
If index sales_area_ix
were a range-partitioned global index, then all partitions of the index would require rebuilding. Further, it is not possible to rebuild all partitions of an index in one statement. You must write a separate REBUILD
statement for each partition in the index. The following statements rebuild the index partitions jan99_ix
, feb99_ix
, mar99_ix
, ..., dec99_ix
.
ALTER INDEX sales_area_ix REBUILD PARTITION jan99_ix; ALTER INDEX sales_area_ix REBUILD PARTITION feb99_ix; ALTER INDEX sales_area_ix REBUILD PARTITION mar99_ix; ... ALTER INDEX sales_area_ix REBUILD PARTITION dec99_ix;
This method is most appropriate for large tables where the partition being dropped contains a significant percentage of the total data in the table.
Method 2
Issue the DELETE
statement to delete all rows from the partition before you issue the ALTER
TABLE
... DROP
PARTITION
statement. The DELETE
statement updates the global indexes, and also fires triggers and generates redo and undo logs.
For example, to drop the first partition, which has a partition bound of 10000, issue the following statements:
DELETE FROM sales WHERE TRANSID < 10000; ALTER TABLE sales DROP PARTITION dec98;
This method is most appropriate for small tables, or for large tables when the partition being dropped contains a small percentage of the total data in the table.
Method 3
Specify UPDATE
INDEXES
in the ALTER
TABLE
statement. Doing so causes the global index to be updated at the time the partition is dropped.
ALTER TABLE sales DROP PARTITION dec98 UPDATE INDEXES;
If a partition contains data and the table has referential integrity constraints, choose either of the following methods to drop the table partition. This table has a local index only, so it is not necessary to rebuild any indexes.
Method 1
Disable the integrity constraints, issue the ALTER
TABLE
... DROP
PARTITION
statement, then enable the integrity constraints:
ALTER TABLE sales DISABLE CONSTRAINT dname_sales1; ALTER TABLE sales DROP PARTITTION dec98; ALTER TABLE sales ENABLE CONSTRAINT dname_sales1;
This method is most appropriate for large tables where the partition being dropped contains a significant percentage of the total data in the table.
Method 2
Issue the DELETE
statement to delete all rows from the partition before you issue the ALTER
TABLE
... DROP
PARTITION
statement. The DELETE
statement enforces referential integrity constraints, and also fires triggers and generates redo and undo log.
DELETE FROM sales WHERE TRANSID < 10000; ALTER TABLE sales DROP PARTITION dec94;
This method is most appropriate for small tables or for large tables when the partition being dropped contains a small percentage of the total data in the table.
You cannot explicitly drop a partition of a local index. Instead, local index partitions are dropped only when you drop a partition from the underlying table.
If a global index partition is empty, you can explicitly drop it by issuing the ALTER
INDEX
... DROP
PARTITION
statement. But, if a global index partition contains data, dropping the partition causes the next highest partition to be marked UNUSABLE
. For example, you would like to drop the index partition P1, and P2 is the next highest partition. You must issue the following statements:
ALTER INDEX npr DROP PARTITION P1; ALTER INDEX npr REBUILD PARTITION P2;
Note:
You cannot drop the highest partition in a global index.You can convert a partition (or subpartition) into a non-partitioned table, and a non-partitioned table into a partition (or subpartition) of a partitioned table by exchanging their data segments. You can also convert a hash-partitioned table into a partition of a range-hash partitioned table, or convert the partition of the range-hash partitioned table into a hash-partitioned table. Similarly, you can convert a list-partitioned table into a partition of a range-list partitioned table, or convert the partition of the range-list partitioned table into a list-partitioned table
Exchanging table partitions is most useful when you have an application using non-partitioned tables that you want to convert to partitions of a partitioned table. For example, in data warehousing environments exchanging partitions facilitates high-speed data loading of new, incremental data into an already existing partitioned table. Generically, OLTP as well as data warehousing environments benefit from exchanging old data partitions out of a partitioned table. The data is purged from the partitioned table without actually being deleted and can be archived separately afterwards.
When you exchange partitions, logging attributes are preserved. You can optionally specify if local indexes are also to be exchanged (INCLUDING
INDEXES
clause), and if rows are to be validated for proper mapping (WITH
VALIDATION
clause).
Note:
When you specifyWITHOUT
VALIDATION
for the exchange partition operation, this is normally a fast operation because it involves only data dictionary updates. However, if the table or partitioned table involved in the exchange operation has a primary key or unique constraint enabled, then the exchange operation will be performed as if WITH
VALIDATION
were specified in order to maintain the integrity of the constraints.
To avoid the overhead of this validation activity, issue the following statement for each constraint before doing the exchange partition operation:
ALTER TABLE table_name DISABLE CONSTRAINT constraint_name KEEP INDEX
Then, enable the constraints after the exchange.
Unless you specify UPDATE
INDEXES
, the database marks UNUSABLE
the global indexes or all global index partitions on the table whose partition is being exchanged. Global indexes or global index partitions on the table being exchanged remain invalidated. (You cannot use UPDATE
INDEXES
for index-organized tables. Use UPDATE
GLOBAL
INDEXES
instead.)
See Also:
"Using Transportable Tablespaces: Scenarios" for information about transportable tablespaces
To exchange a partition of a range, hash, or list-partitioned table with a non-partitioned table, or the reverse, use the ALTER
TABLE
... EXCHANGE
PARTITION
statement. An example of converting a partition into a non-partitioned table follows. In this example, table stocks
can be range, hash, or list partitioned.
ALTER TABLE stocks EXCHANGE PARTITION p3 WITH TABLE stock_table_3;
In this example, you are exchanging a whole hash-partitioned table, with all of its partitions, with the range partition of a range-hash partitioned table and all of its hash subpartitions. This is illustrated in the following example.
First, create a hash-partitioned table:
CREATE TABLE t1 (i NUMBER, j NUMBER) PARTITION BY HASH(i) (PARTITION p1, PARTITION p2);
Populate the table, then create a range-hash partitioned table as shown:
CREATE TABLE t2 (i NUMBER, j NUMBER) PARTITION BY RANGE(j) SUBPARTITION BY HASH(i) (PARTITION p1 VALUES LESS THAN (10) SUBPARTITION t2_pls1 SUBPARTITION t2_pls2, PARTITION p2 VALUES LESS THAN (20) SUBPARTITION t2_p2s1 SUBPARTITION t2_p2s2));
It is important that the partitioning key in table t1
is the same as the subpartitioning key in table t2
.
To migrate the data in t1
to t2
, and validate the rows, use the following statement:
ALTER TABLE t2 EXCHANGE PARTITION p1 WITH TABLE t1 WITH VALIDATION;
Use the ALTER
TABLE
... EXCHANGE
PARTITION
statement to convert a hash subpartition of a range-hash partitioned table into a non-partitioned table, or the reverse. The following example converts the subpartition q3_1999_s1
of table sales
into the non-partitioned table q3_1999
. Local index partitions are exchanged with corresponding indexes on q3_1999
.
ALTER TABLE sales EXCHANGE SUBPARTITION q3_1999_s1 WITH TABLE q3_1999 INCLUDING INDEXES;
The semantics of the ALTER
TABLE
... EXCHANGE
PARTITION
statement are the same as described previously in "Exchanging a Hash-Partitioned Table with a Range-Hash Partition". In the example shown there, the syntax of the CREATE TABLE
statements would only need to be modified to create a list-partitioned table and a range-list partitioned table, respectively. The actions involved remain the same.
The semantics of the ALTER
TABLE
... EXCHANGE
SUBPARTITION
are the same as described previously in "Exchanging a Subpartition of a Range-Hash Partitioned Table".
Use the ALTER
TABLE
... MERGE
PARTITION
statement to merge the contents of two partitions into one partition. The two original partitions are dropped, as are any corresponding local indexes.
You cannot use this statement for a hash-partitioned table or for hash subpartitions of a range-hash partitioned table.
If the involved partitions or subpartitions contain data, indexes may be marked UNUSABLE
as explained in the following table:
Table Type | Index Behavior |
---|---|
Regular (Heap) | Unless you specify UPDATE INDEXES as part of the ALTER TABLE statement:
|
Index-organized |
|
You are allowed to merge the contents of two adjacent range partitions into one partition. Nonadjacent range partitions cannot be merged. The resulting partition inherits the higher upper bound of the two merged partitions.
One reason for merging range partitions is to keep historical data online in larger partitions. For example, you can have daily partitions, with the oldest partition rolled up into weekly partitions, which can then be rolled up into monthly partitions, and so on.
The following scripts create an example of merging range partitions.
First, create a partitioned table and create local indexes.
-- Create a Table with four partitions each on its own tablespace -- Partitioned by range on the data column. -- CREATE TABLE four_seasons ( one DATE, two VARCHAR2(60), three NUMBER ) PARTITION BY RANGE ( one ) ( PARTITION quarter_one VALUES LESS THAN ( TO_DATE('01-apr-1998','dd-mon-yyyy')) TABLESPACE quarter_one, PARTITION quarter_two VALUES LESS THAN ( TO_DATE('01-jul-1998','dd-mon-yyyy')) TABLESPACE quarter_two, PARTITION quarter_three VALUES LESS THAN ( TO_DATE('01-oct-1998','dd-mon-yyyy')) TABLESPACE quarter_three, PARTITION quarter_four VALUES LESS THAN ( TO_DATE('01-jan-1999','dd-mon-yyyy')) TABLESPACE quarter_four ); -- -- Create local PREFIXED index on Four_Seasons -- Prefixed because the leftmost columns of the index match the -- Partition key -- CREATE INDEX i_four_seasons_l ON four_seasons ( one,two ) LOCAL ( PARTITION i_quarter_one TABLESPACE i_quarter_one, PARTITION i_quarter_two TABLESPACE i_quarter_two, PARTITION i_quarter_three TABLESPACE i_quarter_three, PARTITION i_quarter_four TABLESPACE i_quarter_four );
Next, merge partitions.
-- -- Merge the first two partitions -- ALTER TABLE four_seasons MERGE PARTITIONS quarter_one, quarter_two INTO PARTITION quarter_two UPDATE INDEXES;
If you omit the UPDATE
INDEXES
clause from the preceding statement, then you must rebuild the local index for the affected partition.
-- Rebuild index for quarter_two, which has been marked unusable -- because it has not had all of the data from Q1 added to it. -- Rebuilding the index will correct this. -- ALTER TABLE four_seasons MODIFY PARTITION quarter_two REBUILD UNUSABLE LOCAL INDEXES;
When you merge list partitions, the partitions being merged can be any two partitions. They do not need to be adjacent, as for range partitions, because list partitioning does not assume any order for partitions. The resulting partition consists of all of the data from the original two partitions. If you merge a default list partition with any other partition, the resulting partition will be the default partition.
The following statement merges two partitions of a table partitioned using the list method into a partition that inherits all of its attributes from the table-level default attributes. MAXEXTENTS
is specified in the statement.
ALTER TABLE q1_sales_by_region MERGE PARTITIONS q1_northcentral, q1_southcentral INTO PARTITION q1_central STORAGE(MAXEXTENTS 20);
The value lists for the two original partitions were specified as:
PARTITION q1_northcentral VALUES ('SD','WI') PARTITION q1_southcentral VALUES ('OK','TX')
The resulting sales_west
partition value list comprises the set that represents the union of these two partition value lists, or specifically:
('SD','WI','OK','TX')
When you merge range-hash partitions, the subpartitions are rehashed into the number of subpartitions specified by SUBPARTITIONS
n
or the SUBPARTITION
clause. If neither is included, table-level defaults are used.
Note that the inheritance of properties is different when a range-hash partition is split (discussed in "Splitting a Range-Hash Partition"), as opposed to when two range-hash partitions are merged. When a partition is split, the new partitions can inherit properties from the original partition because there is only one parent. However, when partitions are merged, properties must be inherited from table level defaults because there are two parents and the new partition cannot inherit from either at the expense of the other.
The following example merges two range-hash partitions:
ALTER TABLE all_seasons MERGE PARTITIONS quarter_1, quarter_2 INTO PARTITION quarter_2 SUBPARTITIONS 8;
Partitions can be merged at the range partition level and subpartitions can be merged at the list subpartition level.
Merging range partitions in a range-list partitioned table is as described previously in "Merging Range Partitions". However, when you merge two range-list partitions, the resulting new partition inherits the subpartition descriptions from the subpartition template, if one exists. If no subpartition template exists, then a single default subpartition is created for the new partition.
This following statement merges two partitions in the range-list partitioned stripe_regional_sales
table. A subpartition template exists for the table.
ALTER TABLE stripe_regional_sales MERGE PARTITIONS q1_1999, q2_1999 INTO PARTITION q1_q2_1999 STORAGE(MAXEXTENTS 20);
Some new physical attributes are specified for this new partition while table-level defaults are inherited for those that are not specified. The new resulting partition q1_q2_1999
inherits the high-value bound of the partition q2_1999
and the subpartition value-list descriptions from the subpartition template description of the table.
The data in the resulting partitions consists of data from both the partitions. However, there may be cases where the database returns an error. This can occur because data may map out of the new partition when both of the following conditions exist:
Some literal values of the merged subpartitions were not included in the subpartition template
The subpartition template does not contain a default partition definition.
This error condition can be eliminated by always specifying a default partition in the default subpartition template.
You can merge the contents of any two arbitrary list subpartitions belonging to the same range partition. The resulting subpartition value-list descriptor includes all of the literal values in the value lists for the partitions being merged.
The following statement merges two subpartitions of a table partitioned using range-list method into a new subpartition located in tablespace ts4
:
ALTER TABLE quarterly_regional_sales MERGE SUBPARTITIONS q1_1999_northwest, q1_1999_southwest INTO SUBPARTITION q1_1999_west TABLESPACE ts4;
The value lists for the original two partitions were:
Subpartition q1_1999_northwest
was described as ('WA','OR')
Subpartition q1_1999_southwest
was described as ('AZ','NM','UT')
The resulting subpartition value list comprises the set that represents the union of these two subpartition value lists:
Subpartition q1_1999_west
has a value list described as ('WA','OR','AZ','NM','UT')
The tablespace in which the resulting subpartition is located and the subpartition attributes are determined by the partition-level default attributes, except for those specified explicitly. If any of the existing subpartition names are being reused, then the new subpartition inherits the subpartition attributes of the subpartition whose name is being reused.
You can modify the default attributes of a table, or for a partition of a composite partitioned table. When you modify default attributes, the new attributes affect only future partitions, or subpartitions, that are created. The default values can still be specifically overridden when creating a new partition or subpartition.
You can modify the default attributes that will be inherited for range, list, or hash partitions using the MODIFY
DEFAULT
ATTRIBUTES
clause of ALTER
TABLE
.
For hash-partitioned tables, only the TABLESPACE
attribute can be modified.
To modify the default attributes inherited when creating subpartitions, use the ALTER
TABLE
... MODIFY
DEFAULT
ATTRIBUTES
FOR
PARTITION
. The following statement modifies the TABLESPACE
in which future subpartitions of partition p1
in range-hash partitioned table emp
will reside.
ALTER TABLE emp MODIFY DEFAULT ATTRIBUTES FOR PARTITION p1 TABLESPACE ts1;
Because all subpartitions of a range-hash partitioned table must share the same attributes, except TABLESPACE
, it is the only attribute that can be changed.
In similar fashion to table partitions, you can alter the default attributes that will be inherited by partitions of a range-partitioned global index, or local index partitions of partitioned tables. For this you use the ALTER
INDEX
... MODIFY
DEFAULT
ATTRIBUTES
statement. Use the ALTER
INDEX
... MODIFY
DEFAULT
ATTRIBUTES
FOR
PARTITION
statement if you are altering default attributes to be inherited by subpartitions of a composite partitioned table.
It is possible to modify attributes of an existing partition of a table or index.
You cannot change the TABLESPACE
attribute. Use ALTER
TABLESPACE
... MOVE
PARTITION
/SUBPARTITION
to move a partition or subpartition to a new tablespace.
Use the ALTER
TABLE
... MODIFY
PARTITION
statement to modify existing attributes of a range partition or list partition. You can modify segment attributes (except TABLESPACE
), or you can allocate and deallocate extents, mark local index partitions UNUSABLE
, or rebuild local indexes that have been marked UNUSABLE
.
If this is a range partition of a range-hash partitioned table, note the following:
If you allocate or deallocate an extent, this action is performed for every subpartition of the specified partition.
Likewise, changing any other attributes results in corresponding changes to those attributes of all the subpartitions for that partition. The partition level default attributes are changed as well. To avoid changing attributes of existing subpartitions, use the FOR
PARTITION
clause of the MODIFY
DEFAULT
ATTRIBUTES
statement.
The following are some examples of modifying the real attributes of a partition.
This example modifies the MAXEXTENTS
storage attribute for the range partition sales_q1
of table sales
:
ALTER TABLE sales MODIFY PARTITION sales_q1 STORAGE (MAXEXTENTS 10);
All of the local index subpartitions of partition ts1
in range-hash partitioned table scubagear are marked UNUSABLE
in the following example:
ALTER TABLE scubagear MODIFY PARTITION ts1 UNUSABLE LOCAL INDEXES;
You also use the ALTER
TABLE
... MODIFY
PARTITION
statement to modify attributes of a hash partition. However, because the physical attributes of individual hash partitions must all be the same (except for TABLESPACE
), you are restricted to:
Allocating a new extent
Deallocating an unused extent
Rebuilding local index subpartitions that are marked UNUSABLE
The following example rebuilds any unusable local index partitions associated with hash partition P1
of table dept
:
ALTER TABLE dept MODIFY PARTITION p1 REBUILD UNUSABLE LOCAL INDEXES;
With the MODIFY
SUBPARTITION
clause of ALTER
TABLE
you can perform the same actions as listed previously for partitions, but at the specific composite partitioned table subpartition level. For example:
ALTER TABLE emp MODIFY SUBPARTITION p3_s1 REBUILD UNUSABLE LOCAL INDEXES;
The MODIFY
PARTITION
clause of ALTER
INDEX
lets you modify the real attributes of an index partition or its subpartitions. The rules are very similar to those for table partitions, but unlike the MODIFY
PARTITION
clause for ALTER
INDEX
, there is no subclause to rebuild an unusable index partition, but there is a subclause to coalesce an index partition or its subpartitions. In this context, coalesce means to merge index blocks where possible to free them for reuse.
You can also allocate or deallocate storage for a subpartition of a local index, or mark it UNUSABLE
, using the MODIFY
PARTITION
clause.
List partitioning allows you the option of adding literal values from the defining value list.
Use the MODIFY
PARTITION
... ADD
VALUES
clause of the ALTER
TABLE
statement to extend the value list of an existing partition. Literal values being added must not have been included in any other partition value list. The partition value list for any corresponding local index partition is correspondingly extended, and any global index, or global or local index partitions, remain usable.
The following statement adds a new set of state codes ('OK
', 'KS
') to an existing partition list.
ALTER TABLE sales_by_region MODIFY PARTITION region_south ADD VALUES ('OK', 'KS');
The existence of a default partition can have a performance impact when adding values to other partitions. This is because in order to add values to a list partition, the database must check that the values being added do not already exist in the default partition. If any of the values do exist in the default partition, an error is raised.
Note:
The database executes a query to check for the existence of rows in the default partition that correspond to the literal values being added. Therefore, it is advisable to create a local prefixed index on the table. This speeds up the execution of the query and the overall operation.You cannot add values to a default list partition.
This operation is essentially the same as described for "Modifying List Partitions: Adding Values", however, you use a MODIFY
SUBPARTITION
clause instead of the MODIFY
PARTITION
clause. For example, to extend the range of literal values in the value list for subpartition q1_1999_southeast
use the following statement:
ALTER TABLE quarterly_regional_sales MODIFY SUBPARTITION q1_1999_southeast ADD VALUES ('KS');
Literal values being added must not have been included in any other subpartition value list within the owning partition. However, they can be duplicates of literal values in the subpartition value lists of other partitions within the table.
List partitioning allows you the option of dropping literal values from the defining value list.
Use the MODIFY
PARTITION
... DROP
VALUES
clause of the ALTER
TABLE
statement to remove literal values from the value list of an existing partition. The statement is always executed with validation, meaning that it checks to see if any rows exist in the partition that correspond to the set of values being dropped. If any such rows are found then the database returns an error message and the operation fails. When necessary, use a DELETE
statement to delete corresponding rows from the table before attempting to drop values.
Note:
You cannot drop all literal values from the value list describing the partition. You must use theALTER TABLE ... DROP PARTITION
statement instead.The partition value list for any corresponding local index partition reflects the new value list, and any global index, or global or local index partitions, remain usable.
The statement below drops a set of state codes ('OK
' and 'KS
') from an existing partition value list.
ALTER TABLE sales_by_region MODIFY PARTITION region_south DROP VALUES ('OK', 'KS');
Note:
The database executes a query to check for the existence of rows in the partition that correspond to the literal values being dropped. Therefore, it is advisable to create a local prefixed index on the table. This speeds up the execution of the query and the overall operation.You cannot drop values from a default list partition.
This operation is essentially the same as described for "Modifying List Partitions: Dropping Values", however, you use a MODIFY
SUBPARTITION
clause instead of the MODIFY
PARTITION
clause. For example, to remove a set of literal values in the value list for subpartition q1_1999_southeast
use the following statement:
ALTER TABLE quarterly_regional_sales MODIFY SUBPARTITION q1_1999_southeast DROP VALUES ('KS');
You can modify a subpartition template of a composite partitioned table by replacing it with a new subpartition template. Any subsequent operations that use the subpartition template (such as ADD
PARTITION
or MERGE
PARTITIONS
) will now use the new subpartition template. Existing subpartitions remain unchanged.
Use the ALTER
TABLE
... SET
SUBPARTITION
TEMPLATE
statement to specify a new subpartition template. For example:
ALTER TABLE emp_sub_template SET SUBPARTITION TEMPLATE (SUBPARTITION e TABLESPACE ts1, SUBPARTITION f TABLESPACE ts2, SUBPARTITION g TABLESPACE ts3, SUBPARTITION h TABLESPACE ts4 );
You can drop a subpartition template by specifying an empty list:
ALTER TABLE emp_sub_template SET SUBPARTITION TEMPLATE ( );
Use the MOVE
PARTITION
clause of the ALTER
TABLE
statement to:
Re-cluster data and reduce fragmentation
Move a partition to another tablespace
Modify create-time attributes
Store the data in compressed format using table compression
Typically, you can change the physical storage attributes of a partition in a single step using an ALTER
TABLE
/INDEX
... MODIFY
PARTITION
statement. However, there are some physical attributes, such as TABLESPACE
, that you cannot modify using MODIFY
PARTITION
. In these cases, use the MOVE
PARTITION
clause. Modifying some other attributes, such as table compression, affects only future storage, but not existing data.
Note:
ALTER
TABLE
...MOVE
does not permit DML on the partition while the command is executing. If you want to move a partition and leave it available for DML, see "Redefining Partitions Online".If the partition being moved contains any data, indexes may be marked UNUSABLE
according to the following table:
Table Type | Index Behavior |
---|---|
Regular (Heap) | Unless you specify UPDATE INDEXES as part of the ALTER TABLE statement:
|
Index-organized | Any local or global indexes defined for the partition being moved remain usable because they are primary-key based logical rowids. However, the guess information for these rowids becomes incorrect. |
Use the MOVE
PARTITION
clause to move a partition. For example, to move the most active partition to a tablespace that resides on its own disk (in order to balance I/O), not log the action, and compress the data, issue the following statement:
ALTER TABLE parts MOVE PARTITION depot2 TABLESPACE ts094 NOLOGGING COMPRESS;
This statement always drops the old partition segment and creates a new segment, even if you do not specify a new tablespace.
If you are moving a partition of a partitioned index-organized table, you can specify the MAPPING
TABLE
clause as part of the MOVE
PARTITION
clause, and the mapping table partition will be moved to the new location along with the table partition.
The following statement shows how to move data in a subpartition of a table. In this example, a PARALLEL
clause has also been specified.
ALTER TABLE scuba_gear MOVE SUBPARTITION bcd_types TABLESPACE tbs23 PARALLEL (DEGREE 2);
The ALTER
TABLE
... MOVE
PARTITION
statement for regular tables, marks all partitions of a global index UNUSABLE
. You can rebuild the entire index by rebuilding each partition individually using the ALTER
INDEX
... REBUILD
PARTITION
statement. You can perform these rebuilds concurrently.
You can also simply drop the index and re-create it.
Oracle Database provides a mechanism to move a partition or to make other changes to the partition's physical structure without significantly affecting the availability of the partition for DML. The mechanism is called online table redefinition.
For information on redefining a single partition of a table, see "Redefining Tables Online".
Some reasons for rebuilding index partitions include:
To recover space and improve performance
To repair a damaged index partition caused by media failure
To rebuild a local index partition after loading the underlying table partition with SQL*Loader or an import utility
To rebuild index partitions that have been marked UNUSABLE
To enable key compression for B-tree indexes
The following sections discuss your options for rebuilding index partitions and subpartitions.
You can rebuild global index partitions in two ways:
Rebuild each partition by issuing the ALTER
INDEX
... REBUILD
PARTITION
statement (you can run the rebuilds concurrently).
Drop the entire global index and re-create it. This method is more efficient because the table is scanned only once.
For most maintenance operations on partitioned tables with indexes, you can optionally avoid the need to rebuild the index by specifying UPDATE
INDEXES
on your DDL statement.
Rebuild local indexes using either ALTER
INDEX
or ALTER
TABLE
as follows:
ALTER
INDEX
... REBUILD
PARTITION
/SUBPARTITION
This statement rebuilds an index partition or subpartition unconditionally.
ALTER
TABLE
... MODIFY
PARTITION
/SUBPARTITION
... REBUILD
UNUSABLE
LOCAL
INDEXES
This statement finds all of the unusable indexes for the given table partition or subpartition and rebuilds them. It only rebuilds an index partition if it has been marked UNUSABLE
.
The ALTER
INDEX
... REBUILD
PARTITION
statement rebuilds one partition of an index. It cannot be used for composite-partitioned tables. Only real physical segments can be rebuilt with this command. When you re-create the index, you can also choose to move the partition to a new tablespace or change attributes.
For composite-partitioned tables, use ALTER
INDEX
... REBUILD
SUBPARTITION
to rebuild a subpartition of an index. You can move the subpartition to another tablespace or specify a parallel clause. The following statement rebuilds a subpartition of a local index on a table and moves the index subpartition is another tablespace.
ALTER INDEX scuba REBUILD SUBPARTITION bcd_types TABLESPACE tbs23 PARALLEL (DEGREE 2);
The REBUILD
UNUSABLE
LOCAL
INDEXES
clause of ALTER
TABLE
... MODIFY
PARTITION
does not allow you to specify any new attributes for the rebuilt index partition. The following example finds and rebuilds any unusable local index partitions for table scubagear
, partition p1
.
ALTER TABLE scubagear MODIFY PARTITION p1 REBUILD UNUSABLE LOCAL INDEXES;
There is a corresponding ALTER
TABLE
... MODIFY
SUBPARTITION
clause for rebuilding unusable local index subpartitions.
It is possible to rename partitions and subpartitions of both tables and indexes. One reason for renaming a partition might be to assign a meaningful name, as opposed to a default system name that was assigned to the partition in another maintenance operation.
Rename a range, hash, or list partition, using the ALTER
TABLE
... RENAME
PARTITION
statement. For example:
ALTER TABLE scubagear RENAME PARTITION sys_p636 TO tanks;
Likewise, you can assign new names to subpartitions of a table. In this case you would use the ALTER
TABLE
... RENAME
PARTITION
syntax.
The SPLIT
PARTITION
clause of the ALTER
TABLE
or ALTER
INDEX
statement is used to redistribute the contents of a partition into two new partitions. Consider doing this when a partition becomes too large and causes backup, recovery, or maintenance operations to take a long time to complete. You can also use the SPLIT
PARTITION
clause to redistribute the I/O load.
This clause cannot be used for hash partitions or subpartitions.
If the partition you are splitting contains any data, indexes may be marked UNUSABLE
as explained in the following table:
Table Type | Index Behavior |
---|---|
Regular (Heap) | Unless you specify UPDATE INDEXES as part of the ALTER TABLE statement:
|
Index-organized |
|
You split a range partition using the ALTER
TABLE
... SPLIT
PARTITION
statement. You specify a value of the partitioning key column within the range of the partition at which to split the partition. The first of the resulting two new partitions includes all rows in the original partition whose partitioning key column values map lower that the specified value. The second partition contains all rows whose partitioning key column values map greater than or equal to the specified value.
You can optionally specify new attributes for the two partitions resulting from the split. If there are local indexes defined on the table, this statement also splits the matching partition in each local index.
In the following example fee_katy
is a partition in the table vet_cats
, which has a local index, jaf1
. There is also a global index, vet
on the table. vet
contains two partitions, vet_parta
, and vet_partb
.
To split the partition fee_katy
, and rebuild the index partitions, issue the following statements:
ALTER TABLE vet_cats SPLIT PARTITION fee_katy at (100) INTO ( PARTITION fee_katy1 ..., PARTITION fee_katy2 ...); ALTER INDEX JAF1 REBUILD PARTITION fee_katy1; ALTER INDEX JAF1 REBUILD PARTITION fee_katy2; ALTER INDEX VET REBUILD PARTITION vet_parta; ALTER INDEX VET REBUILD PARTITION vet_partb;
Note:
If you do not specify new partition names, the database assigns names of the formSYS_P
n
. You can examine the data dictionary to locate the names assigned to the new local index partitions. You may want to rename them. Any attributes you do not specify are inherited from the original partition.You split a list partition by using the ALTER
TABLE
... SPLIT
PARTITION
statement. The SPLIT
PARTITION
clause enables you to specify a list of literal values that define a partition into which rows with corresponding partitioning key values are inserted. The remaining rows of the original partition are inserted into a second partition whose value list contains the remaining values from the original partition.
You can optionally specify new attributes for the two partitions that result from the split.
The following statement splits the partition region_east
into two partitions:
ALTER TABLE sales_by_region SPLIT PARTITION region_east VALUES ('CT', 'MA', 'MD') INTO ( PARTITION region_east_1 TABLESPACE tbs2, PARTITION region_east_2 STORAGE (NEXT 2M PCTINCREASE 25)) PARALLEL 5;
The literal value list for the original region_east
partition was specified as:
PARTITION region_east VALUES ('MA','NY','CT','NH','ME','MD','VA','PA','NJ')
The two new partitions are:
region_east_1
with a literal value list of ('CT','MA','MD')
region_east_2
inheriting the remaining literal value list of ('NY','NH','ME','VA','PA','NJ')
The individual partitions have new physical attributes specified at the partition level. The operation is executed with parallelism of degree 5.
You can split a default list partition just like you split any other list partition. This is also the only means of adding a partition to list-partitioned table that contains a default partition. When you split the default partition, you create a new partition defined by the values that you specify, and a second partition that remains the default partition.
The following example splits the default partition of sales_by_region
, thereby creating a new partition:
ALTER TABLE sales_by_region SPLIT PARTITION region_unknown VALUES ('MT', 'WY', 'ID') INTO ( PARTITION region_wildwest, PARTITION region_unknown);
This is the opposite of merging range-hash partitions. When you split range-hash partitions, the new subpartitions are rehashed into either the number of subpartitions specified in a SUBPARTITIONS
or SUBPARTITION
clause. Or, if no such clause is included, the new partitions inherit the number of subpartitions (and tablespaces) from the partition being split.
Note that the inheritance of properties is different when a range-hash partition is split, versus when two range-hash partitions are merged. When a partition is split, the new partitions can inherit properties from the original partition because there is only one parent. However, when partitions are merged, properties must be inherited from table level defaults because there are two parents and the new partition cannot inherit from either at the expense of the other.
The following example splits a range-hash partition:
ALTER TABLE all_seasons SPLIT PARTITION quarter_1 AT (TO_DATE('16-dec-1997','dd-mon-yyyy')) INTO (PARTITION q1_1997_1 SUBPARTITIONS 4 STORE IN (ts1,ts3), PARTITION q1_1997_2);
Partitions can be split at both the range partition level and at the list subpartition level.
Splitting a range partition of a range-list partitioned table is similar to what is described in "Splitting a Partition of a Range-Partitioned Table". No subpartition literal value list can be specified for either of the new partitions. The new partitions inherit the subpartition descriptions from the original partition being split.
The following example splits the q1_1999
partition of the quarterly_regional_sales
table:
ALTER TABLE quarterly_regional_sales SPLIT PARTITION q1_1999 AT (to_date('15-Feb-1999','dd-mon-yyyy')) INTO ( PARTITION q1_1999_jan_feb TABLESPACE ts1, PARTITION q1_1999_feb_mar STORAGE (NEXT 2M PCTINCREASE 25) TABLESPACE ts2) PARALLEL 5;
This operation splits the partition q1_1999
into two resulting partitions: q1_1999_jan_feb
and q1_1999_feb_mar
. Both partitions inherit their subpartition descriptions from the original partition. The individual partitions have new physical attributes, including tablespaces, specified at the partition level. These new attributes become the default attributes of the new partitions. This operation is run with parallelism of degree 5.
The ALTER
TABLE
... SPLIT
PARTITION
statement provides no means of specifically naming subpartitions resulting from the split of a partition in a composite partitioned table. However, for those subpartitions in the parent partition with names of the form partition name_subpartition name
, the database generates corresponding names in the newly created subpartitions using the new partition names. All other subpartitions are assigned system generated names of the form SYS_SUBP
n
. System generated names are also assigned for the subpartitions of any partition resulting from the split for which a name is not specified. Unnamed partitions are assigned a system generated partition name of the form SYS_P
n
.
The following query displays the subpartition names resulting from the previous split partition operation on table quarterly_regional_sales
. It also reflects the results of other operations performed on this table in preceding sections of this chapter since its creation in "When to Use Composite Range-List Partitioning".
SELECT PARTITION_NAME, SUBPARTITION_NAME, TABLESPACE_NAME FROM DBA_TAB_SUBPARTITIONS WHERE TABLE_NAME='QUARTERLY_REGIONAL_SALES' ORDER BY PARTITION_NAME; PARTITION_NAME SUBPARTITION_NAME TABLESPACE_NAME -------------------- ------------------------------ --------------- Q1_1999_FEB_MAR Q1_1999_FEB_MAR_WEST TS2 Q1_1999_FEB_MAR Q1_1999_FEB_MAR_NORTHEAST TS2 Q1_1999_FEB_MAR Q1_1999_FEB_MAR_SOUTHEAST TS2 Q1_1999_FEB_MAR Q1_1999_FEB_MAR_NORTHCENTRAL TS2 Q1_1999_FEB_MAR Q1_1999_FEB_MAR_SOUTHCENTRAL TS2 Q1_1999_FEB_MAR Q1_1999_FEB_MAR_SOUTH TS2 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_WEST TS1 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_NORTHEAST TS1 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_SOUTHEAST TS1 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_NORTHCENTRAL TS1 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_SOUTHCENTRAL TS1 Q1_1999_JAN_FEB Q1_1999_JAN_FEB_SOUTH TS1 Q1_2000 Q1_2000_NORTHWEST TS3 Q1_2000 Q1_2000_SOUTHWEST TS3 Q1_2000 Q1_2000_NORTHEAST TS3 Q1_2000 Q1_2000_SOUTHEAST TS3 Q1_2000 Q1_2000_NORTHCENTRAL TS3 Q1_2000 Q1_2000_SOUTHCENTRAL TS3 Q2_1999 Q2_1999_NORTHWEST TS4 Q2_1999 Q2_1999_SOUTHWEST TS4 Q2_1999 Q2_1999_NORTHEAST TS4 Q2_1999 Q2_1999_SOUTHEAST TS4 Q2_1999 Q2_1999_NORTHCENTRAL TS4 Q2_1999 Q2_1999_SOUTHCENTRAL TS4 Q3_1999 Q3_1999_NORTHWEST TS4 Q3_1999 Q3_1999_SOUTHWEST TS4 Q3_1999 Q3_1999_NORTHEAST TS4 Q3_1999 Q3_1999_SOUTHEAST TS4 Q3_1999 Q3_1999_NORTHCENTRAL TS4 Q3_1999 Q3_1999_SOUTHCENTRAL TS4 Q4_1999 Q4_1999_NORTHWEST TS4 Q4_1999 Q4_1999_SOUTHWEST TS4 Q4_1999 Q4_1999_NORTHEAST TS4 Q4_1999 Q4_1999_SOUTHEAST TS4 Q4_1999 Q4_1999_NORTHCENTRAL TS4 Q4_1999 Q4_1999_SOUTHCENTRAL TS4 36 rows selected.
Splitting a list subpartition of a range-list partitioned table is similar to what is described in "Splitting a Partition of a List-Partitioned Table", but the syntax is that of SUBPARTITION
rather than PARTITION
. For example, the following statement splits a subpartition of the quarterly_regional_sales
table:
ALTER TABLE quarterly_regional_sales SPLIT SUBPARTITION q2_1999_southwest VALUES ('UT') INTO ( SUBPARTITION q2_1999_utah TABLESPACE ts2, SUBPARTITION q2_1999_southwest TABLESPACE ts3 ) PARALLEL;
This operation splits the subpartition q2_1999_southwest
into two subpartitions:
q2_1999_utah
with literal value list of ('UT')
q2_1999_southwest
which inherits the remaining literal value list of ('AZ','NM')
The individual subpartitions have new physical attributes that are inherited from the subpartition being split.
You cannot explicitly split a partition in a local index. A local index partition is split only when you split a partition in the underlying table. However, you can split a global index partition as is done in the following example:
ALTER INDEX quon1 SPLIT PARTITION canada AT ( 100 ) INTO PARTITION canada1 ..., PARTITION canada2 ...); ALTER INDEX quon1 REBUILD PARTITION canada1; ALTER INDEX quon1 REBUILD PARTITION canada2;
The index being split can contain index data, and the resulting partitions do not require rebuilding, unless the original partition was previously marked UNUSABLE
.
Oracle Database implements a SPLIT
PARTITION
operation by creating two new partitions and redistributing the rows from the partition being split into the two new partitions. This is an expensive operation because it is necessary to scan all the rows of the partition being split and then insert them one-by-one into the new partitions. Further if you do not use the UPDATE
INDEXES
clause, both local and global indexes also require rebuilding.
Sometimes after a split operation, one of the new partitions contains all of the rows from the partition being split, while the other partition contains no rows. This is often the case when splitting the first partition of a table. The database can detect such situations and can optimize the split operation. This optimization results in a fast split operation that behaves like an add partition operation.
Specifically, the database can optimize and speed up SPLIT
PARTITION
operations if all of the following conditions are met:
One of the two resulting partitions must be empty.
The non-empty resulting partition must have storage characteristics identical to those of the partition being split. Specifically:
If the partition being split is composite, then the storage characteristics of each subpartition in the new non-empty resulting partition must be identical to those of the subpartitions of the partition being split.
If the partition being split contains a LOB
column, then the storage characteristics of each LOB
(sub)partition in the new non-empty resulting partition must be identical to those of the LOB
(sub)partitions of the partition being split.
If a partition of an index-organized table with overflow is being split, then the storage characteristics of each overflow (sub)partition in the new nonempty resulting partition must be identical to those of the overflow (sub)partitions of the partition being split.
If a partition an index-organized table with mapping table is being split, then the storage characteristics of each mapping table (sub)partition in the new nonempty resulting partition must be identical to those of the mapping table (sub)partitions of the partition being split.
If these conditions are met after the split, then all global indexes remain usable, even if you did not specify the UPDATE
INDEXES
clause. Local index (sub)partitions associated with both resulting partitions remain usable if they were usable before the split. Local index (sub)partition(s) corresponding to the non-empty resulting partition will be identical to the local index (sub)partition(s) of the partition that was split.
The same optimization holds for SPLIT
SUBPARTITION
operations.
Use the ALTER
TABLE
... TRUNCATE
PARTITION
statement to remove all rows from a table partition. Truncating a partition is similar to dropping a partition, except that the partition is emptied of its data, but not physically dropped.
You cannot truncate an index partition. However, if local indexes are defined for the table, the ALTER
TABLE
... TRUNCATE
PARTITION
statement truncates the matching partition in each local index. Unless you specify UPDATE
INDEXES
, any global indexes are marked UNUSABLE
and must be rebuilt. (You cannot use UPDATE
INDEXES
for index-organized tables. Use UPDATE
GLOBAL
INDEXES
instead.)
Use the ALTER
TABLE
... TRUNCATE
PARTITION
statement to remove all rows from a table partition, with or without reclaiming space.
If the partition contains data and global indexes, use one of the following methods to truncate the table partition.
Method 1
Leave the global indexes in place during the ALTER
TABLE
... TRUNCATE
PARTITION
statement. In this example, table sales
has a global index sales_area_ix
, which is rebuilt.
ALTER TABLE sales TRUNCATE PARTITION dec98; ALTER INDEX sales_area_ix REBUILD;
This method is most appropriate for large tables where the partition being truncated contains a significant percentage of the total data in the table.
Method 2
Issue the DELETE
statement to delete all rows from the partition before you issue the ALTER
TABLE
... TRUNCATE
PARTITION
statement. The DELETE
statement updates the global indexes, and also fires triggers and generates redo and undo logs.
For example, to truncate the first partition, which has a partition bound of 10000, issue the following statements:
DELETE FROM sales WHERE TRANSID < 10000; ALTER TABLE sales TRUNCATE PARTITION dec98;
This method is most appropriate for small tables, or for large tables when the partition being truncated contains a small percentage of the total data in the table.
Method 3
Specify UPDATE
INDEXES
in the ALTER TABLE
statement. This causes the global index to be truncated at the time the partition is truncated.
ALTER TABLE sales TRUNCATE PARTITION dec98 UPDATE INDEXES;
If a partition contains data and has referential integrity constraints, choose either of the following methods to truncate the table partition.
Method 1
Disable the integrity constraints, issue the ALTER
TABLE
... TRUNCATE
PARTITION
statement, then reenable the integrity constraints:
ALTER TABLE sales DISABLE CONSTRAINT dname_sales1; ALTER TABLE sales TRUNCATE PARTITTION dec94; ALTER TABLE sales ENABLE CONSTRAINT dname_sales1;
This method is most appropriate for large tables where the partition being truncated contains a significant percentage of the total data in the table.
Method 2
Issue the DELETE
statement to delete all rows from the partition before you issue the ALTER
TABLE
... TRUNCATE
PARTITION
statement. The DELETE
statement enforces referential integrity constraints, and also fires triggers and generates redo and undo log.
Note:
You can substantially reduce the amount of logging by setting theNOLOGGING
attribute (using ALTER
TABLE
... TRUNCATE
PARTITION
... NOLOGGING
) for the partition before deleting all of its rows.DELETE FROM sales WHERE TRANSID < 10000; ALTER TABLE sales TRUNCATE PARTITION dec94;
This method is most appropriate for small tables, or for large tables when the partition being truncated contains a small percentage of the total data in the table.
You use the ALTER
TABLE
... TRUNCATE
SUBPARTITION
statement to remove all rows from a subpartition of a composite partitioned table. Corresponding local index subpartitions are also truncated.
The following statement shows how to truncate data in a subpartition of a table. In this example, the space occupied by the deleted rows is made available for use by other schema objects in the tablespace.
ALTER TABLE diving TRUNCATE SUBPARTITION us_locations DROP STORAGE;
Oracle Database processes a DROP
TABLE
command for a partitioned table in the same way that it processes the command for a non-partitioned table. One exception that was introduced in version 10g Release 2 is when you use the PURGE
keyword.
To avoid running into resource constraints, the DROP
TABLE
...PURGE
command for a partitioned table drops the table in multiple transactions, where each transaction drops a subset of the partitions or subpartitions and then commits. The table becomes completely dropped at the conclusion of the final transaction. This behavior comes with some changes to the DROP
TABLE
command that you should be aware of.
First, if the DROP
TABLE
...PURGE
command fails, you can take corrective action, if any, and then restart the command. The command resumes at the point where it failed.
Second, while the DROP
TABLE
...PURGE
statement is in progress, the table is marked as unusable by setting a new STATUS
column to the value "UNUSABLE"
in the following data dictionary views:
USER_TABLES
, ALL_TABLES
, DBA_TABLES
USER_PART_TABLES
, ALL_PART_TABLES
, DBA_PART_TABLES
USER_OBJECT_TABLES
, ALL_OBJECT_TABLES
, DBA_OBJECT_TABLES
You can list all UNUSABLE
partitioned tables by querying the STATUS
column of these views.
Queries against other data dictionary views pertaining to partitioning, such as DBA_TAB_PARTITIONS
and DBA_TAB_SUBPARTITIONS
, exclude rows belonging to an UNUSABLE
table. A complete list of these views is available in "Viewing Information About Partitioned Tables and Indexes".
After a table is marked UNUSABLE
, the only command that can be executed against it is another DROP
TABLE
...PURGE
command, and only if the previous DROP
TABLE
...PURGE
command failed. Any other command against an UNUSABLE
table results in an error. The table remains in the UNUSABLE
state until the drop operation is complete.
See Also:
Oracle Database SQL Reference for the syntax of the DROP
TABLE
command.
Oracle Database Reference for a description of the data dictionary views mentioned in this section.
This section presents an example of moving the time window in a historical table.
A historical table describes the business transactions of an enterprise over intervals of time. Historical tables can be base tables, which contain base information; for example, sales, checks, and orders. Historical tables can also be rollup tables, which contain summary information derived from the base information using operations such as GROUP BY
, AVERAGE
, or COUNT
.
The time interval in a historical table is often a rolling window. DBAs periodically delete sets of rows that describe the oldest transactions, and in turn allocate space for sets of rows that describe the most recent transactions. For example, at the close of business on April 30, 1995, the DBA deletes the rows (and supporting index entries) that describe transactions from April 1994, and allocates space for the April 1995 transactions.
Now consider a specific example. You have a table, order
, which contains 13 months of transactions: a year of historical data in addition to orders for the current month. There is one partition for each month. These monthly partitions are named order_
yymm
, as are the tablespaces in which they reside.
The order
table contains two local indexes, order_ix_onum
, which is a local, prefixed, unique index on the order number, and order_ix_supp
, which is a local, non-prefixed index on the supplier number. The local index partitions are named with suffixes that match the underlying table. There is also a global unique index, order_ix_cust
, for the customer name. order_ix_cust
contains three partitions, one for each third of the alphabet. So on October 31, 1994, change the time window on order
as follows:
Back up the data for the oldest time interval.
ALTER TABLESPACE order_9310 BEGIN BACKUP; ... ALTER TABLESPACE order_9310 END BACKUP;
Drop the partition for the oldest time interval.
ALTER TABLE order DROP PARTITION order_9310;
Add the partition to the most recent time interval.
ALTER TABLE order ADD PARTITION order_9411;
Re-create the global index partitions.
ALTER INDEX order_ix_cust REBUILD PARTITION order_ix_cust_AH; ALTER INDEX order_ix_cust REBUILD PARTITION order_ix_cust_IP; ALTER INDEX order_ix_cust REBUILD PARTITION order_ix_cust_QZ;
Ordinarily, the database acquires sufficient locks to ensure that no operation (DML, DDL, or utility) interferes with an individual DDL statement, such as ALTER
TABLE
... DROP
PARTITION
. However, if the partition maintenance operation requires several steps, it is the database administrator's responsibility to ensure that applications (or other maintenance operations) do not interfere with the multistep operation in progress. Some methods for doing this are:
Bring down all user-level applications during a well-defined batch window.
Ensure that no one is able to access table order
by revoking access privileges from a role that is used in all applications.
The following views display information specific to partitioned tables and indexes:
View | Description |
---|---|
DBA_PART_TABLES
|
DBA view displays partitioning information for all partitioned tables in the database. ALL view displays partitioning information for all partitioned tables accessible to the user. USER view is restricted to partitioning information for partitioned tables owned by the user. |
DBA_TAB_PARTITIONS
|
Display partition-level partitioning information, partition storage parameters, and partition statistics generated by the DBMS_STATS package or the ANALYZE statement. |
DBA_TAB_SUBPARTITIONS
|
Display subpartition-level partitioning information, subpartition storage parameters, and subpartition statistics generated by the DBMS_STATS package or the ANALYZE statement. |
DBA_PART_KEY_COLUMNS
|
Display the partitioning key columns for partitioned tables. |
DBA_SUBPART_KEY_COLUMNS
|
Display the subpartitioning key columns for composite-partitioned tables (and local indexes on composite-partitioned tables). |
DBA_PART_COL_STATISTICS
|
Display column statistics and histogram information for the partitions of tables. |
DBA_SUBPART_COL_STATISTICS
|
Display column statistics and histogram information for subpartitions of tables. |
DBA_PART_HISTOGRAMS
|
Display the histogram data (end-points for each histogram) for histograms on table partitions. |
DBA_SUBPART_HISTOGRAMS
|
Display the histogram data (end-points for each histogram) for histograms on table subpartitions. |
DBA_PART_INDEXES
|
Display partitioning information for partitioned indexes. |
DBA_IND_PARTITIONS
|
Display the following for index partitions: partition-level partitioning information, storage parameters for the partition, statistics collected by the DBMS_STATS package or the ANALYZE statement. |
DBA_IND_SUBPARTITIONS
|
Display the following information for index subpartitions: partition-level partitioning information, storage parameters for the partition, statistics collected by the DBMS_STATS package or the ANALYZE statement. |
DBA_SUBPARTITION_TEMPLATES
|
Display information about existing subpartition templates. |
See Also:
Oracle Database Reference for complete descriptions of these views
Oracle Database Performance Tuning Guide and Oracle Database Performance Tuning Guide for information about histograms and generating statistics for tables