| Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-01 |
|
Common SQL DDL Clauses , 8 of 9
The physical_attributes_clause lets you specify the value of the PCTFREE, PCTUSED, INITRANS, and MAXTRANS parameters and the storage characteristics of a table, cluster, index, or materialized view.
You can specify the physical_attributes_clause in the following statements:
CREATE CLUSTER and ALTER CLUSTER: to set or change the physical attributes of the cluster and all tables in the cluster (see CREATE CLUSTER and ALTER CLUSTER).CREATE TABLE: to set the physical attributes of the table, a table partition, the OIDINDEX of an object table, or the overflow segment of an index-organized table (see CREATE TABLE).ALTER TABLE: to change the physical attributes of the table, the default physical attributes of future table partitions, or the physical attributes of existing table partitions (see ALTER TABLE).
CREATE INDEX: to set the physical attributes of an index, or index partition (see CREATE INDEX).ALTER INDEX: to change the physical attributes of the index, the default physical attributes of future partitions, or the physical attributes of existing index partitions (see ALTER INDEX).CREATE MATERIALIZED VIEW: to set the physical attributes of the materialized view, one of its partitions, or the index Oracle generates to maintain the materialized view (see CREATE MATERIALIZED VIEW).ALTER MATERIALIZED VIEW: to change the physical attributes of the materialized view, the default physical attributes of future partitions, the physical attributes of an existing partition, or the index Oracle creates to maintain the materialized view (see ALTER MATERIALIZED VIEW).CREATE MATERIALIZED VIEW LOG and ALTER MATERIALIZED VIEW LOG: to set or change the physical attributes of the materialized view log (see CREATE MATERIALIZED VIEW LOG and ALTER MATERIALIZED VIEW LOG).physical_attributes_clause::=
This section describes the parameters of the physical_attributes_clause. For additional information, refer to the SQL statement in which you set or reset these parameters for a particular database object.
Specify a whole number representing the percentage of space in each data block of the database object reserved for future updates to the object's rows. The value of PCTFREE must be a value from 0 to 99. A value of 0 means that the entire block can be filled by inserts of new rows. The default value is 10. This value reserves 10% of each block for updates to existing rows and allows inserts of new rows to fill a maximum of 90% of each block.
PCTFREE has the same function in the statements that create and alter tables, partitions, clusters, indexes, materialized views, and materialized view logs. The combination of PCTFREE and PCTUSED determines whether new rows will be inserted into existing data blocks or into new blocks.
Restriction on the PCTFREE clause: When altering an index, you can specify this parameter only in the modify_index_default_attrs clause and the split_partition_clause.
Specify a whole number representing the minimum percentage of used space that Oracle maintains for each data block of the database object. A block becomes a candidate for row insertion when its used space falls below PCTUSED. PCTUSED is specified as a positive integer from 0 to 99 and defaults to 40.
PCTUSED has the same function in the statements that create and alter tables, partitions, clusters, materialized views, and materialized view logs.
PCTUSED is not a valid table storage characteristic for an index-organized table (ORGANIZATION INDEX).
The sum of PCTFREE and PCTUSED must be equal to or less than 100. You can use PCTFREE and PCTUSED together to utilize space within a table more efficiently.
Restrictions on the PCTUSED clause: You cannot specify this parameter for an index or for the index segment of an index-organized table.
| See Also:
Oracle9i Database Performance Tuning Guide and Reference for information on the performance effects of different values |
Specify the initial number of concurrent transaction entries allocated within each data block allocated to the database object. This value can range from 1 to 255 and defaults to 1, with the following exceptions:
INITRANS value for a cluster or index is 2 or the default INITRANS value of the cluster's tablespace, whichever is greater.In general, you should not change the INITRANS value from its default.
Each transaction that updates a block requires a transaction entry in the block. The size of a transaction entry depends on your operating system.
This parameter ensures that a minimum number of concurrent transactions can update the block and helps avoid the overhead of dynamically allocating a transaction entry.
The INITRANS parameter serves the same purpose in the statements that create and alter tables, partitions, clusters, indexes, materialized views, and materialized view logs.
Specify the maximum number of concurrent transactions that can update a data block allocated to the database object. This limit does not apply to queries. This value can range from 1 to 255 and the default is a function of the data block size. You should not change the MAXTRANS value from its default.
If the number of concurrent transactions updating a block exceeds the INITRANS value, then Oracle dynamically allocates transaction entries in the block until either the MAXTRANS value is exceeded or the block has no more free space.
The MAXTRANS parameter serves the same purpose in the PARTITION description, clusters, materialized views, and materialized view logs as in tables.
The storage_clause lets you specify storage characteristics for the table, object table OID index, partition, LOB data segment, LOB index segment, or index-organized table overflow data segment. This clause has performance ramifications for large tables. Storage should be allocated to minimize dynamic allocation of additional space.
|
![]() Copyright © 1996, 2002 Oracle Corporation. All Rights Reserved. |
|