Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

ALTER MATERIALIZED VIEW LOG

Purpose

Use the ALTER MATERIALIZED VIEW LOG statement to alter the storage characteristics, refresh mode or time, or type of an existing materialized view log. A materialized view log is a table associated with the master table of a materialized view.


Note:

The keyword SNAPSHOT is supported in place of MATERIALIZED VIEW for backward compatibility.


See Also:

Prerequisites

Only the owner of the master table or a user with the SELECT privilege on the master table and the ALTER privilege on the materialized view log can alter a materialized view log.

See Also:

Oracle9i Advanced Replication for detailed information about the prerequisites for ALTER MATERIALIZED VIEW LOG

Syntax

alter_materialized_view_log::=

Text description of statements_15.gif follows
Text description of alter_materialized_view_log


(physical_attributes_clause::=, alter_table_partitioning -- part of ALTER TABLE syntax, parallel_clause::=, logging_clause::=, allocate_extent_clause::=, new_values_clause::=),

new_values_clause::=

Text description of statements_17.gif follows
Text description of new_values_clause


physical_attributes_clause::=

Text description of statements_19.gif follows
Text description of physical_attributes_clause


(storage_clause::=)

allocate_extent_clause::=

Text description of statements_111.gif follows
Text description of allocate_extent_clause


parallel_clause::=

Text description of statements_169.gif follows
Text description of parallel_clause


Semantics

schema

Specify the schema containing the master table. If you omit schema, Oracle assumes the materialized view log is in your own schema.

table

Specify the name of the master table associated with the materialized view log to be altered.

physical_attributes_clause

The physical_attributes_clause lets you change the value of PCTFREE, PCTUSED, INITRANS, and MAXTRANS parameters and storage characteristics for the table, the partition, the overflow data segment, or the default characteristics of a partitioned table.

Restriction on Materialized View Physical Attributes

You cannot use the storage_clause to modify extent parameters if the materialized view log resides in a locally managed tablespace.

See Also:

CREATE TABLE for a description of these parameters

alter_table_partitioning

The syntax and general functioning of the partitioning clauses is the same as described for the ALTER TABLE statement.

Restrictions on Altering Materialized View Partitions

parallel_clause

The parallel_clause lets you specify whether parallel operations will be supported for the materialized view log.


Note:

The syntax of the parallel_clause supersedes syntax appearing in earlier releases of Oracle. Superseded syntax is still supported for backward compatibility, but may result in slightly different behavior than that documented.


NOPARALLEL

Specify NOPARALLEL for serial execution. This is the default.

PARALLEL

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.

PARALLEL integer

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.

See Also:

"Notes on the parallel_clause" for CREATE TABLE

logging_clause

Specify the logging attribute of the materialized view log.

See Also:

logging_clause for a full description of this clause

allocate_extent_clause

Use the allocate_extent_clause to explicitly allocate a new extent for the materialized view log.

See Also:

allocate_extent_clause for a full description of this clause

CACHE | NOCACHE Clause

For data that will be accessed frequently, CACHE specifies that the blocks retrieved for this log are placed at the most recently used end of the LRU list in the buffer cache when a full table scan is performed. This attribute is useful for small lookup tables. NOCACHE specifies that the blocks are placed at the least recently used end of the LRU list.

See Also:

CREATE TABLE for information about specifying CACHE or NOCACHE

ADD Clause

The ADD clause lets you augment the materialized view log so that it records the primary key values, rowid values, or object ID values when rows in the materialized view master table are changed. This clause can also be used to record additional columns.

To stop recording any of this information, you must first drop the materialized view log and then re-create it. Dropping the materialized view log and then re-creating it forces each of the existing materialized views that depend on the master table to complete refresh on its next refresh.

Restriction on Augmenting Materialized View Logs

You can specify only one PRIMARY KEY, one ROWID, one OBJECT ID and one column list for each materialized view log. Therefore, if any of these three values were specified at create time (either implicitly or explicitly), you cannot specify those values in this ALTER statement.

OBJECT ID

Specify OBJECT ID if you want the appropriate object identifier of all rows that are changed to be recorded in the materialized view log.

Restriction on the OBJECT ID clause

You can specify OBJECT ID only for logs on object tables, and you cannot specify it for storage tables.

PRIMARY KEY

Specify PRIMARY KEY if you want the primary key values of all rows that are changed to be recorded in the materialized view log.

ROWID

Specify ROWID if you want the rowid values of all rows that are changed to be recorded in the materialized view log.

column

Specify the additional columns whose values you want to be recorded in the materialized view log for all rows that are changed. Typically these columns are filter columns (non-primary-key columns referenced by materialized views) and join columns (non-primary-key columns that define a join in the WHERE clause of the subquery).

See Also:

NEW VALUES Clause

The NEW VALUES clause lets you specify whether Oracle saves both old and new values in the materialized view log. The value you set in this clause applies to all columns in the log, not only to primary key, rowid, or columns you may have added in this ALTER MATERIALIZED VIEW LOG statement.

INCLUDING

Specify INCLUDING to save both new and old values in the log. If this log is for a table on which you have a single-table materialized aggregate view, and if you want the materialized view to be eligible for fast refresh, you must specify INCLUDING.

EXCLUDING

Specify EXCLUDING to disable the recording of new values in the log. You can use this clause to avoid the overhead of recording new values.

If you have a fast-refreshable single-table materialized aggregate view defined on this table, do not specify EXCLUDING NEW VALUES unless you first change the refresh mode of the materialized view to something other than FAST.

See Also:

"Materialized View Log EXCLUDING NEW VALUES: Example"

Examples

Rowid Materialized View Log: Example

The following statement alters an existing primary key materialized view log to also record rowid information:

ALTER MATERIALIZED VIEW LOG ON order_items ADD ROWID;
Materialized View Log EXCLUDING NEW VALUES: Example

The following statement alters the materialized view log on hr.employees by adding a filter column and excluding new values. Any materialized aggregate views that use this log will no longer be fast refreshable. However, if fast refresh is no longer needed, this action avoids the overhead of recording new values:

ALTER MATERIALIZED VIEW LOG ON employees
   ADD (commission_pct)
   EXCLUDING NEW VALUES;