| Oracle8i SQL Reference Release 3 (8.1.7) Part Number A85397-01 |
|
SQL Statements:
ALTER CLUSTER to ALTER SYSTEM, 8 of 19
A materialized view is a database object that contains the results of a query of one or more tables. Use the ALTER MATERIALIZED VIEW statement to modify an existing materialized view in one or more of the following ways:
The tables in the query 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.
|
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.
LOB_storage_clause: See ALTER TABLE.
modify_LOB_storage_clause: See ALTER TABLE.
partitioning_clauses: See ALTER TABLE.
storage_clause: See the storage_clause.
schema
Specify the schema containing the materialized view. If you omit schema, Oracle assumes the materialized view is in your own schema.
materialized_view
Specify the name of the materialized view to be altered.
physical_attributes_clause
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:
|
LOB_storage_clause
The LOB_storage_clause lets you specify the LOB storage characteristics.
modify_LOB_storage_clause
The modify_LOB_storage_clause lets you modify the physical attributes of the LOB attribute lob_item or LOB object attribute.
partitioning_clauses
The syntax and general functioning of the partitioning clauses for materialized views is the same as for partitioned tables.
Restrictions:
LOB_storage_clause or modify_LOB_storage_clause when modifying a materialized view.
parallel_clause
The parallel_clause lets you change the default degree of parallelism for the materialized view.
LOGGING | NOLOGGING
Specify or change the logging characteristics of the materialized view.
allocate_extent_clause
The allocate_extent_clause lets you explicitly allocate a new extent for the materialized view.
CACHE | NOCACHE
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.
USING INDEX
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.
Restriction: You cannot specify the PCTUSED or PCTFREE parameters in this clause.
refresh_clause
Use the refresh_clause 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 Oracle8i Replication and Oracle8i Data Warehousing Guide. |
|
|
Specify |
|
|
|
For both conventional DML changes and for direct-path loads, other conditions may restrict the eligibility of a materialized view for fast refresh.
|
|
|
|
Restrictions:
|
|
|
|
Specify |
|
|
|
Specify |
|
|
|
Specify Restriction: This clause is supported only for materialized join views and single-table materialized aggregate views.
|
|
|
|
Specify
|
|
|
|
||
|
|
Specify |
|
|
|
Specify |
|
|
Both the |
||
|
|
Specify
|
|
|
|
Specify
|
|
|
|
|
Specify |
|
|
|
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 |
|
|
|
The master rollback segment is stored on a per-materialized-view basis and is validated during materialized view creation and refresh. If the materialized view is complex, the master rollback segment, if specified, is ignored. |
QUERY REWRITE
Use this clause to determine whether the materialized view is eligible to be used for query rewrite.
|
|
Specify
|
|
|
|
Restrictions:
|
|
|
|
Specify |
|
COMPILE
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.
CONSIDER FRESH
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.
This clause is useful after performing partition maintenance operations against the master table. Such operations would otherwise render the materialized view ineligible for fast refresh, and eligible for query rewrite only in STALE_TOLERATED mode.
|
See Also: Oracle8i Data Warehousing Guide for more information on query rewrite and the implications of performing partition maintenance operations on master tables |
The following statement changes the default refresh method for the hq_emp materialized view to FAST:
CREATE MATERIALIZED VIEW hq_emp REFRESH COMPLETE START WTIH SYSDATE NEXT SYSDATE +1/4096 AS SELECT * FROM hq_emp; ALTER MATERIALIZED VIEW hq_emp 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, the refresh intervals established by the REFRESH clause when the hq_emp materialized view was created or last altered are still used.
NEXT Example
The following statement stores a new interval between automatic refreshes for the branch_emp materialized view:
ALTER MATERIALIZED VIEW branch_emp 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 branch_emp 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 specifies a new refresh method, a new next refresh time, and a new interval between automatic refreshes of the sf_emp materialized view:
ALTER MATERIALIZED VIEW sf_emp 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 mv1 ENABLE QUERY REWRITE;
The following statement changes the remote master rollback segment used during materialized view refresh to master_seg:
ALTER MATERIALIZED VIEW inventory REFRESH USING MASTER ROLLBACK SEGMENT master_seg;
The following statement changes the remote master rollback segment used during materialized view refresh to one chosen by Oracle:
ALTER MATERIALIZED VIEW sales REFRESH USING DEFAULT MASTER ROLLBACK SEGMENT;
The following statement changes a rowid materialized view to a primary key materialized view:
ALTER MATERIALIZED VIEW emp_rs REFRESH WITH PRIMARY KEY;
COMPILE Example
The following statement revalidates the materialized view store_mv:
ALTER MATERIALIZED VIEW store_mv COMPILE;
The following statement changes the refresh method of materialized view store_mv to FAST;
ALTER MATERIALIZED VIEW store_mv REFRESH FAST;
CONSIDER FRESH Example
The following statement instructs Oracle that materialized view mv1 should be considered fresh. This statement allows mv1 to be eligible for query rewrite in TRUSTED mode even after you have performed partition maintenance operations on the master tables of mv1:
ALTER MATERIALIZED VIEW mv1 CONSIDER FRESH;
|
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|