Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
Use the CREATE
CLUSTER
statement to create a cluster. A cluster is a schema object that contains data from one or more tables, all of which have one or more columns in common. Oracle stores together all the rows (from all the tables) that share the same cluster key.
For information on existing clusters, query the USER_CLUSTERS
, ALL_CLUSTERS
, and DBA_CLUSTERS
data dictionary views.
See Also:
|
To create a cluster in your own schema, you must have CREATE
CLUSTER
system privilege. To create a cluster in another user's schema, you must have CREATE
ANY
CLUSTER
system privilege. Also, the owner of the schema to contain the cluster must have either space quota on the tablespace containing the cluster or the UNLIMITED
TABLESPACE
system privilege.
Oracle does not automatically create an index for a cluster when the cluster is initially created. Data manipulation language (DML) statements cannot be issued against clustered tables until you create a cluster index.
create_cluster::=
Specify the schema to contain the cluster. If you omit schema
, Oracle creates the cluster in your current schema.
Specify is the name of the cluster to be created.
After you create a cluster, you add tables to it. A cluster can contain a maximum of 32 tables. After you create a cluster and add tables to it, the cluster is transparent. You can access clustered tables with SQL statements just as you can access nonclustered tables.
See Also:
CREATE TABLE for information on adding tables to a cluster, Creating a Cluster: Example, and "Adding Tables to a Cluster: Example" |
Specify one or more names of columns in the cluster key. You can specify up to 16 cluster key columns. These columns must correspond in both datatype and size to columns in each of the clustered tables, although they need not correspond in name.
You cannot specify integrity constraints as part of the definition of a cluster key column. Instead, you can associate integrity constraints with the tables that belong to the cluster.
Specify the datatype of each cluster key column.
LONG
, LONG
RAW
, REF
, nested table, varray, BLOB
, CLOB
, BFILE
, or user-defined object type.HASH
IS
clause if any column datatype is not INTEGER
or NUMBER
with scale 0.ROWID
, but Oracle does not guarantee that the values in such columns are valid rowids.
See Also:
"Datatypes" for information on datatypes |
The physical_attributes_clause
lets you specify the storage characteristics of the cluster. Each table in the cluster uses these storage characteristics as well. If you do not specify values for these parameters, Oracle uses the following defaults:
PCTFREE
: 10PCTUSED
: 40INITRANS
: 2 or the default value of the cluster's tablespace, whichever is greaterMAXTRANS
: the default value for the cluster's tablespace
See Also:
|
Specify the amount of space in bytes reserved to store all rows with the same cluster key value or the same hash value. Use K
or M
to specify this space in kilobytes or megabytes. This space determines the maximum number of cluster or hash values stored in a data block. If SIZE
is not a divisor of the data block size, Oracle uses the next largest divisor. If SIZE
is larger than the data block size, Oracle uses the operating system block size, reserving at least one data block for each cluster or hash value.
Oracle also considers the length of the cluster key when determining how much space to reserve for the rows having a cluster key value. Larger cluster keys require larger sizes. To see the actual size, query the KEY_SIZE
column of the USER_CLUSTERS
data dictionary view. (This does not apply to hash clusters, because hash values are not actually stored in the cluster.)
If you omit this parameter, Oracle reserves one data block for each cluster key value or hash value.
Specify the tablespace in which the cluster is created.
Specify INDEX
to create an indexed cluster. In an indexed cluster, Oracle stores together rows having the same cluster key value. Each distinct cluster key value is stored only once in each data block, regardless of the number of tables and rows in which it occurs.
After you create an indexed cluster, you must create an index on the cluster key before you can issue any data manipulation language (DML) statements against a table in the cluster. This index is called the cluster index.
See Also:
CREATE INDEX for information on creating a cluster index and Oracle9i Database Concepts for general information in indexed clusters |
Specify the HASHKEYS
clause to create a hash cluster and specify the number of hash values for a hash cluster. In a hash cluster, Oracle stores together rows that have the same hash key value. The hash value for a row is the value returned by the cluster's hash function.
Oracle rounds up the HASHKEYS
value to the nearest prime number to obtain the actual number of hash values. The minimum value for this parameter is 2. If you omit both the INDEX
clause and the HASHKEYS
parameter, Oracle creates an indexed cluster by default.
When you create a hash cluster, Oracle immediately allocates space for the cluster based on the values of the SIZE
and HASHKEYS
parameters.
See Also:
Oracle9i Database Concepts for more information on how Oracle allocates space for clusters and "Hash Clusters: Examples" |
SINGLE
TABLE
indicates that the cluster is a type of hash cluster containing only one table. This clause can provide faster access to rows than would result if the table were not part of a cluster.
Only one table can be present in the cluster at a time. However, you can drop the table and create a different table in the same cluster.
Specify an expression to be used as the hash function for the hash cluster. The expression:
NUM_COLUMN
* length(VARCHAR2_COLUMN
)LEVEL
or ROWNUM
USERENV
, UID
, or USER
or the datetime functions CURRENT_DATE
, CURRENT_TIMESTAMP
, DBTIMEZONE
, EXTRACT
(datetime), FROM_TZ
, LOCALTIMESTAMP
, NUMTODSINTERVAL
, NUMTOYMINTERVAL
, SESSIONTIMEZONE
, SYSDATE
, SYSTIMESTAMP
, TO_DSINTERVAL
, TO_TIMESTAMP
, TO_DATE
, TO_TIMESTAMP_TZ
, TO_YMINTERVAL
, and TZ_OFFSET
.If you omit the HASH
IS
clause, Oracle uses an internal hash function for the hash cluster.
For information on existing hash functions, query the USER_
, ALL_
, and DBA_CLUSTER_HASH_EXPRESSIONS
data dictionary tables.
The cluster key of a hash column can have one or more columns of any datatype. Hash clusters with composite cluster keys or cluster keys made up of noninteger columns must use the internal hash function.
See Also:
Oracle9i Database Reference for information on the data dictionary views |
The parallel_clause
lets you parallelize the creation of the cluster.
Specify NOPARALLEL
for serial execution. This is the default.
Specify PARALLEL
if you want Oracle to select a degree of parallelism equal to the number of CPUs available on all participating instances times the value of the PARALLEL_THREADS_PER_CPU
initialization parameter.
Specification of integer
indicates the degree of parallelism, which is the number of parallel threads used in the parallel operation. Each parallel thread may use one or two parallel execution servers. Normally Oracle calculates the optimum degree of parallelism, so it is not necessary for you to specify integer
.
If the tables in cluster
contain any columns of LOB or user-defined object type, this statement as well as subsequent INSERT
, UPDATE
, or DELETE
operations on cluster
are executed serially without notification.
See Also:
"Notes on the parallel_clause" for |
This clause lets you specify whether cluster
will use row-level dependency tracking. With this feature, each row in the tables that make up the cluster has a system change number (SCN) that represents a time greater than or equal to the commit time of the last transaction that modified the row. You cannot change this setting after cluster
is created.
Specify ROWDEPENDENCIES
if you want to enable row-level dependency tracking. This setting is useful primarily to allow for parallel propagation in replication environments. It increases the size of each row by 6 bytes.
Specify NOROWDEPENDENCIES
if you do not want to use the row level dependency tracking feature. This is the default.
See Also:
Oracle9i Advanced Replication for information about the use of row-level dependency tracking in replication environments |
Specify CACHE
if you want the blocks retrieved for this cluster to be placed at the most recently used end of the least recently used (LRU) list in the buffer cache when a full table scan is performed. This clause is useful for small lookup tables.
Specify NOCACHE
if you want the blocks retrieved for this cluster to be placed at the least recently used end of the LRU list in the buffer cache when a full table scan is performed. This is the default behavior.
The following statement creates a cluster named personnel
with the cluster key column department
, a cluster size of 512 bytes, and storage parameter values:
CREATE CLUSTER personnel (department NUMBER(4)) SIZE 512 STORAGE (initial 100K next 50K);
The following statement creates the cluster index on the cluster key of personnel
:
CREATE INDEX idx_personnel ON CLUSTER personnel;
After creating the cluster index, you can add tables to the index and perform DML operations on those tables.
The following statements create some departmental tables from the sample hr.employees
table and add them to the personnel cluster created in the earlier example:
CREATE TABLE dept_10 CLUSTER personnel (department_id) AS SELECT * FROM employees WHERE department_id = 10; CREATE TABLE dept_20 CLUSTER personnel (department_id) AS SELECT * FROM employees WHERE department_id = 20;
The following statement creates a hash cluster named language
with the cluster key column cust_language
, a maximum of 10 hash key values, each of which is allocated 512 bytes, and storage parameter values:
CREATE CLUSTER language (cust_language VARCHAR2(3)) SIZE 512 HASHKEYS 10 STORAGE (INITIAL 100k next 50k);
Because the preceding statement omits the HASH
IS
clause, Oracle uses the internal hash function for the cluster.
The following statement creates a hash cluster named address
with the cluster key made up of the columns postal_code
and country_id
, and uses a SQL expression containing these columns for the hash function:
CREATE CLUSTER address (postal_code NUMBER, country_id CHAR(2)) HASHKEYS 20 HASH IS MOD(postal_code + country_id, 101);
The following statement creates a single-table hash cluster named cust_orders
with the cluster key customer_id
and a maximum of 100 hash key values, each of which is allocated 512 bytes:
CREATE CLUSTER cust_orders (customer_id NUMBER(6)) SIZE 512 SINGLE TABLE HASHKEYS 100;