Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
A materialized view is a database object that contains the results of a query. The FROM
clause of the query can name tables, views, and other materialized views. Collectively these are called master tables (a replication term) or detail tables (a data warehouse term). This reference uses "master tables" for consistency. The databases containing the master tables are called the master databases.
Use the ALTER
MATERIALIZED
VIEW
statement to modify an existing materialized view in one or more of the following ways:
See Also:
|
The privileges required to alter a materialized view should be granted directly, as follows:
The materialized view must be in your own schema, or you must have the ALTER
ANY
MATERIALIZED
VIEW
system privilege.
To enable a materialized view for query rewrite:
QUERY
REWRITE
privilege.GLOBAL
QUERY
REWRITE
privilege.QUERY
REWRITE
privilege, as described in the preceding two items. In addition, the owner of the materialized view must have SELECT
access to any master tables that the materialized view owner does not own.
See Also:
Oracle9i Advanced Replication and Oracle9i Data Warehousing Guide |
alter_materialized_view::=
physical_attributes_clause::=
, data_segment_compression::=
, LOB_storage_clause::=
, modify_LOB_storage_clause::=
, alter_table_partitioning
-- part of ALTER
TABLE
syntax, parallel_clause::=
, logging_clause::=
, allocate_extent_clause::=
)LOB_parameters::=
modify_LOB_parameters::=
logging_clause::=
deallocate_unused_clause::=
index_org_table_clause::=
, alter_overflow_clause::=
, alter_mapping_table_clauses
: not supported with materialized views)index_org_table_clause::=
mapping_table_clause
: not supported with materialized views, key_compression
: not supported with materialized views, index_org_overflow_clause::=
)index_org_overflow_clause::=
alter_overflow_clause::=
add_overflow_clause::=
scoped_table_ref_constraint::=
Specify the schema containing the materialized view. If you omit schema
, Oracle assumes the materialized view is in your own schema.
Specify the name of the materialized view to be altered.
Specify new values for the PCTFREE
, PCTUSED
, INITRANS
, and MAXTRANS
parameters (or, when used in the USING
INDEX
clause, for the INITRANS
and MAXTRANS
parameters only) and the storage characteristics for the materialized view.
See Also:
|
Use the data_segment_compression
clause to instruct Oracle whether to compress data segments to reduce disk and memory use. The COMPRESS
keyword enables data segment compression. The NOCOMPRESS
keyword disables data segment compression.
See Also:
|
The LOB_storage_clause
lets you specify the storage characteristics of a new LOB. LOB storage behaves for materialized views exactly as it does for tables.
See Also:
the |
The modify_LOB_storage_clause
lets you modify the physical attributes of the LOB attribute lob_item
or LOB object attribute. Modification of LOB storage behaves for materialized views exactly as it does for tables.
See Also:
|
The syntax and general functioning of the partitioning clauses for materialized views is the same as for partitioned tables.
LOB_storage_clause
or modify_LOB_storage_clause
within any of the partitioning_clauses
.Use this clause to mark UNUSABLE
all the local index partitions associated with partition
.
Use this clause to rebuild the unusable local index partitions associated with partition
.
The parallel_clause
lets you change the default degree of parallelism for the materialized view.
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
.
See Also:
"Notes on the parallel_clause" for |
Specify or change the logging characteristics of the materialized view.
See Also:
|
The allocate_extent_clause
lets you explicitly allocate a new extent for the materialized view.
See Also:
|
For data that will be accessed frequently, CACHE
specifies that the blocks retrieved for this table 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:
ALTER TABLE for information about specifying |
Use the alter_iot_clauses
to change the characteristics of an index-organized materialized view. The keywords and parameters of the components of the alter_iot_clauses
have the same semantics as in ALTER
TABLE
, with the restrictions that follow.
You cannot specify the mapping_table_clause
or the key_compression
clause of the index_org_table_clause
.
See Also:
|
Use this clause to change the value of INITRANS
, MAXTRANS
, and STORAGE
parameters for the index Oracle uses to maintain the materialized view's data.
You cannot specify the PCTUSED
or PCTFREE
parameters in this clause.
Use the MODIFY
scoped_table_ref_constraint
clause to rescope a REF
column or attribute to a new table.
You can rescope only one REF
column or attribute in each ALTER
MATERIALIZED
VIEW
statement, and this must be the only clause in this statement.
Specify REBUILD
to regenerate refresh operations if a type that is referenced in materialized_view
has evolved.
You cannot specify any other clause in the same ALTER
MATERIALIZED
VIEW
statement.
Use the alter_mv_refresh
to change the default method and mode and the default times for automatic refreshes. If the contents of a materialized view's master tables are modified, the data in the materialized view must be updated to make the materialized view accurately reflect the data currently in its master table(s). This clause lets you schedule the times and specify the method and mode for Oracle to refresh the materialized view.
Note: This clause only sets the default refresh options. For instructions on actually implementing the refresh, refer to Oracle9i Advanced Replication and Oracle9i Data Warehousing Guide. |
Specify FAST
for incremental refresh method, which performs the refresh according to the changes that have occurred to the master tables. The changes are stored either in the materialized view log associated with the master table (for conventional DML changes) or in the direct loader log (for direct-path INSERT
operations).
For both conventional DML changes and for direct-path INSERT
s, other conditions may restrict the eligibility of a materialized view for fast refresh.
See Also:
|
FAST
refresh at create time, Oracle verifies that the materialized view you are creating is eligible for fast refresh. When you change the refresh method to FAST
in an ALTER
MATERIALIZED
VIEW
statement, Oracle does not perform this verification. If the materialized view is not eligible for fast refresh, Oracle will return an error when you attempt to refresh this view.Specify COMPLETE
for the complete refresh method, which is implemented by executing the materialized view's defining query. If you request a complete refresh, Oracle performs a complete refresh even if a fast refresh is possible.
Specify FORCE
if, when a refresh occurs, you want Oracle to perform a fast refresh if one is possible or a complete refresh otherwise.
Specify ON
COMMIT
if you want a fast refresh to occur whenever Oracle commits a transaction that operates on a master table of the materialized view.
This clause is supported only for materialized join views and single-table materialized aggregate views.
See Also:
Oracle9i Advanced Replication and Oracle9i Data Warehousing Guide |
Specify ON
DEMAND
if you want the materialized view to be refreshed on demand by calling one of the three DBMS_MVIEW
refresh procedures. If you omit both ON
COMMIT
and ON
DEMAND
, ON
DEMAND
is the default.
See Also:
|
Specify START
WITH
date
to indicate a date for the first automatic refresh time.
Specify NEXT
to indicate a date expression for calculating the interval between automatic refreshes.
Both the START
WITH
and NEXT
values must evaluate to a time in the future. If you omit the START
WITH
value, Oracle determines the first automatic refresh time by evaluating the NEXT
expression with respect to the creation time of the materialized view. If you specify a START
WITH
value but omit the NEXT
value, Oracle refreshes the materialized view only once. If you omit both the START
WITH
and NEXT
values, or if you omit the alter_mv_refresh
entirely, Oracle does not automatically refresh the materialized view.
Specify WITH
PRIMARY
KEY
to change a rowid materialized view to a primary key materialized view. Primary key materialized views allow materialized view master tables to be reorganized without affecting the materialized view's ability to continue to fast refresh.
For you to specify this clause, the master table must contain an enabled primary key constraint and must have defined on it a materialized view log that logs primary key information.
See Also:
|
Specify USING
ROLLBACK
SEGMENT
to change the remote rollback segment to be used during materialized view refresh, where rollback_segment
is the name of the rollback segment to be used.
See Also:
Oracle9i Advanced Replication for information on changing the local materialized view rollback segment using the |
Specify DEFAULT
if you want Oracle to choose the rollback segment to use. If you specify DEFAULT
, you cannot specify rollback_segment.
Specify the remote rollback segment to be used at the remote master for the individual materialized view. (To change the local materialized view rollback segment, use the DBMS_REFRESH
package, described in Oracle9i Advanced Replication.)
One master rollback segment is stored for each materialized view and is validated during materialized view creation and refresh. If the materialized view is complex, the master rollback segment, if specified, is ignored.
Use this clause to determine whether the materialized view is eligible to be used for query rewrite.
Specify ENABLE
to enable the materialized view for query rewrite.
ENABLE
mode.DETERMINISTIC
.
CURRENT_TIME
or USER
.
See Also:
Oracle9i Data Warehousing Guide for more information on query rewrite |
Specify DISABLE
if you do not want the materialized view to be eligible for use by query rewrite. (If a materialized view is in the invalid state, it is not eligible for use by query rewrite, whether or not it is disabled.) However, a disabled materialized view can be refreshed.
Specify COMPILE
to explicitly revalidate a materialized view. If an object upon which the materialized view depends is dropped or altered, the materialized view remains accessible, but it is invalid for query rewrite. You can use this clause to explicitly revalidate the materialized view to make it eligible for query rewrite.
If the materialized view fails to revalidate, it cannot be refreshed or used for query rewrite.
This clause lets you manage the staleness state of a materialized after changes have been made to its master tables. CONSIDER
FRESH
directs Oracle to consider the materialized view fresh and therefore eligible for query rewrite in the TRUSTED
or STALE_TOLERATED
modes. Because Oracle cannot guarantee the freshness of the materialized view, query rewrite in ENFORCED
mode is not supported. This clause also sets the staleness state of the materialized view to UNKNOWN
. The staleness state is displayed in the STALENESS
column of the ALL_MVIEWS
, DBA_MVIEWS
, and USER_MVIEWS
data dictionary views.
See Also:
Oracle9i Data Warehousing Guide for more information on query rewrite and the implications of performing partition maintenance operations on master tables, and "CONSIDER FRESH: Example" |
The following statement changes the default refresh method for the sales_by_month_by_state
materialized view (created in "Creating Materialized Aggregate Views: Example") to FAST
:
ALTER MATERIALIZED VIEW sales_by_month_by_state
REFRESH FAST;
The next automatic refresh of the materialized view will be a fast refresh provided it is a simple materialized view and its master table has a materialized view log that was created before the materialized view was created or last refreshed.
Because the REFRESH
clause does not specify START
WITH
or NEXT
values, Oracle will use the refresh intervals established by the REFRESH
clause when the sales_by_month_by_state
materialized view was created or last altered.
The following statement stores a new interval between automatic refreshes for the sales_by_month_by_state
materialized view:
ALTER MATERIALIZED VIEW sales_by_month_by_state REFRESH NEXT SYSDATE+7;
Because the REFRESH
clause does not specify a START
WITH
value, the next automatic refresh occurs at the time established by the START
WITH
and NEXT
values specified when the sales_by_month_by_state
materialized view was created or last altered.
At the time of the next automatic refresh, Oracle refreshes the materialized view, evaluates the NEXT
expression SYSDATE
+7 to determine the next automatic refresh time, and continues to refresh the materialized view automatically once a week. Because the REFRESH
clause does not explicitly specify a refresh method, Oracle continues to use the refresh method specified by the REFRESH
clause of the CREATE
MATERIALIZED
VIEW
or most recent ALTER
MATERIALIZED
VIEW
statement.
The following statement instructs Oracle that materialized view sales_by_month_by_state
should be considered fresh. This statement allows sales_by_month_by_state
to be eligible for query rewrite in TRUSTED
mode even after you have performed partition maintenance operations on the master tables of sales_by_month_by_state
:
ALTER MATERIALIZED VIEW sales_by_month_by_state CONSIDER FRESH;
See Also:
Splitting Table Partitions: Examples for a partitioning maintenance example that would require this |
The following statement specifies a new refresh method, a new NEXT
refresh time, and a new interval between automatic refreshes of the emp_data
materialized view (created in "Periodic Refresh of Materialized Views: Example"):
ALTER MATERIALIZED VIEW emp_data REFRESH COMPLETE START WITH TRUNC(SYSDATE+1) + 9/24 NEXT SYSDATE+7;
The START
WITH
value establishes the next automatic refresh for the materialized view to be 9:00 a.m. tomorrow. At that point, Oracle performs a complete refresh of the materialized view, evaluates the NEXT
expression, and subsequently refreshes the materialized view every week.
The following statement enables query rewrite on the materialized view mv1
and implicitly revalidates it:
ALTER MATERIALIZED VIEW emp_data ENABLE QUERY REWRITE;
The following statement changes the remote master rollback segment used during materialized view refresh to rbs_two
:
ALTER MATERIALIZED VIEW new_employees REFRESH USING MASTER ROLLBACK SEGMENT rbs_two;
The following statement changes the remote master rollback segment used during materialized view refresh to one chosen by Oracle:
ALTER MATERIALIZED VIEW new_employees REFRESH USING DEFAULT MASTER ROLLBACK SEGMENT;
The following statement changes the rowid materialized view order_data
(created in "Creating Rowid Materialized Views: Example") to a primary key materialized view. This example requires that you have already defined a materialized view log with a primary key on order_data
.
ALTER MATERIALIZED VIEW order_data REFRESH WITH PRIMARY KEY;
The following statement revalidates the materialized view store_mv
:
ALTER MATERIALIZED VIEW order_data COMPILE;