Search the Reference Library pages:  

Oracle Materialized Views
Version 11.1
 
General

Data Dictionary Objects
col$ snap$ tab$
 
Special DBA_, ALL_ and USER_
dba_mview_log_filter_cols dba_base_table_mviews dba_mview_joins
all_refresh_dependencies dba_mviews dba_mview_keys
dba_registered_mview_groups dba_mview_aggregates dba_mview_logs
dba_registered_snapshot_groups dba_mview_analysis dba_mview_refresh_times
dba_tune_mview dba_mview_comments dba_registered_mviews
dba_tune_mview dba_mview_detail_relations  
Related Packages
dbms_offline_snapshot dbms_snapshot_lib
dbms_snapshot dbms_snapshot_util

System Privileges

create materialized view

delete any table

under any table
create any materialized view insert any table update any table
drop any materialized view lock any table create table
  select any table create view
 
Definitions
Complex Materialized View Each row in the materialized view can not be mapped back to a single row in a source table.

Materialized View
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 objects are called master tables (a replication term) or detail tables (a data warehousing term). This reference uses "master tables" for consistency. The databases containing the master tables are called the master databases.

When you create a materialized view, Oracle Database creates one internal table and at least one index, and may create one view, all in the schema of the materialized view. Oracle Database uses these objects to maintain the materialized view data. You must have the privileges necessary to create these objects.

Materialized View Log
When DML changes are made to master table data, Oracle Database stores rows describing those changes in the materialized view log and then uses the materialized view log to refresh materialized views based on the master table. This process is called incremental or fast refresh. Without a materialized view log, Oracle Database must re-execute the materialized view query to refresh the materialized view. This process is called a complete refresh. Usually, a fast refresh takes less time than a complete refresh.

A materialized view log is located in the master database in the same schema as the master table. A master table can have only one materialized view log defined on it. Oracle Database can use this materialized view log to perform fast refreshes for all fast-refreshable materialized views based on the master table.

To fast refresh a materialized join view, you must create a materialized view log for each of the tables referenced by the materialized view.

Build
Specifies when to populate the materialized view. Specify IMMEDIATE to indicate that the materialized view is to be populated immediately: The default. Specify DEFERRED to indicate that the materialized view is to be populated by the next REFRESH operation. The first (deferred) refresh must always be a complete refresh. Until then, the materialized view has a staleness value of UNUSABLE, so it cannot be used for query rewrite.

Syntax:
BUILD <IMMEDIATE | DEFERRED>
WITH REDUCED PRECISION Authorizes the loss of precision that will result if the precision of the table or materialized view columns do not exactly match the precision returned by subquery.

WITHOUT REDUCED PRECISION

Requires that the precision of the table or materialized view columns match exactly the precision returned by the subquery, or the create operation will fail. This is the default

Caching
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 least recently used (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.

Syntax:
<CACHE | NOCACHE>
Cluster Creates materialized views as part of a cluster. A cluster materialized view uses the space allocation of the cluster. Partitioning is not allowed when an MV is built on a cluster.

Compression
Use the table_compression clause to instruct the database whether to compress data segments to reduce disk and memory use. The COMPRESS keyword enables table compression. The NOCOMPRESS keyword disables table compression.

Syntax:
<COMPRESS | NOCOMPRESS>

Organization Index
Create an index-organized materialized view. IOT can be specified for the following:
  • Read-only and updatable object materialized views.
  • Read-only and updatable primary key materialized views.
  • Read-only rowid materialized views.

The keywords and parameters of the index_org_table_clause have the same semantics as described in CREATE TABLE, with the restrictions that follow.

Parallel The parallel_clause indicates whether parallel operations will be supported for the materialized view and sets the default degree of parallelism for queries and DML on the materialized view after creation.

Syntax:
PARALLEL (DEGREE <INTEGER>)
Partitioning T

Prebuilt Tables
The ON PREBUILT TABLE clause lets you register an existing table as a preinitialized materialized view. This clause is particularly useful for registering large materialized views in a data warehousing environment. The table must have the same name and be in the same schema as the resulting materialized view.

If the materialized view is dropped, then the preexisting table reverts to its identity as a table.

Query Rewrite
If the schema owner does not own the master tables, then the schema owner must have the GLOBAL QUERY REWRITE privilege or the QUERY REWRITE object privilege on each table outside the schema.

If you are defining the materialized view on a pre-built container (ON PRE-BUILT TABLE clause), then you must have the SELECT privilege WITH GRANT OPTION on the container table.
Refresh Group A grouping of materialized views so that they can be refreshed as a single transaction for consistency

Refresh Log
When DML changes are made to master table data, Oracle Database stores rows describing those changes in the materialized view log and then uses the materialized view log to refresh materialized views based on the master table. This process is called incremental or fast refresh. Without a materialized view log, Oracle Database must re-execute the materialized view query to refresh the materialized view. This process is called a complete refresh. Usually, a fast refresh takes less time than a complete refresh
Refresh Types COMPLETE REFRESH
FAST REFRESH
Simple Materialized View Each row in the materialized view can be mapped back to a single row in a source table
Snapshot The keyword SNAPSHOT is supported in place of MATERIALIZED VIEW for backward compatibility

Using Index
The USING INDEX clause allow establishing values for INITRANS and STORAGE parameters for the default index used to maintain the materialized view. If USING INDEX is not specified, then default tablespace values are used. The default index is used to speed up incremental (FAST) refresh of the materialized view.

Specify USING NO INDEX to suppress the creation of the default index. You can create an alternative index explicitly by using the CREATE INDEX statement. You should create such an index if you specify USING NO INDEX and you are creating the materialized view with the incremental refresh method (REFRESH FAST).

Syntax: <
USING INDEX | USING NO INDEX>
 
Create Materialized View

Fast Refresh

Note: Jonathan Lewis has indicated that REFRESH ON COMMIT with a single row update can cause 45 statement executions. Also be wary of possible read consistency violations prior to the commit.

CREATE MATERIALIZED VIEW <schema.name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
BUILD IMMEDIATE
REFRESH <FAST | FORCE> ON <COMMIT | DEMAND>
<USING INDEX | USING NO INDEX>
INITRANS <integer>
STORAGE CLAUSE

AS (<SQL statement>);
CREATE MATERIALIZED VIEW mv_simple
TABLESPACE uwdata
BUILD IMMEDIATE
REFRESH FAST ON COMMIT AS

SELECT * FROM servers;

-- create refresh log then repeat (see page bottom)

CREATE MATERIALIZED VIEW mv_simple
TABLESPACE uwdata
BUILD IMMEDIATE
REFRESH FAST ON COMMIT AS

SELECT * FROM servers;

desc user_snapshots

SELECT name, table_name, updatable, refresh_method, refresh_mode
FROM user_snapshots;

set long 100000

SELECT name, query
FROM user_snapshots;

SELECT name, last_refresh
FROM user_mview_refresh_times;

SELECT table_name
FROM user_tables;

SELECT constraint_name, table_name, constraint_type
FROM user_constraints;

CREATE OR REPLACE VIEW servers_view AS
SELECT * FROM servers;

desc servers
desc servers_view
desc mv_simple

SELECT DISTINCT network_id
FROM servers;

SELECT DISTINCT network_id
FROM servers_view;

SELECT DISTINCT network_id
FROM mv_simple;

UPDATE servers
SET network_id = 10
WHERE network_id = 6;

SELECT DISTINCT network_id
FROM servers;

SELECT DISTINCT network_id
FROM servers_view;

SELECT DISTINCT network_id
FROM mv_simple;

COMMIT;

SELECT DISTINCT network_id
FROM servers;

SELECT DISTINCT network_id
FROM servers_view;

SELECT DISTINCT network_id
FROM mv_simple;

Force Refresh
CREATE MATERIALIZED VIEW <schema.name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
BUILD IMMEDIATE
REFRESH <FAST | FORCE> ON <COMMIT | DEMAND> 
AS (<SQL statement>);
CREATE MATERIALIZED VIEW mv_force
TABLESPACE uwdata
NOCACHE
LOGGING
NOCOMPRESS
NOPARALLEL
BUILD IMMEDIATE
REFRESH FORCE ON DEMAND
WITH ROWID AS

SELECT * FROM servers;

desc mv_force

SELECT name, table_name, updatable, refresh_method,
refresh_mode
FROM user_snapshots;

set long 10000

SELECT name, query
FROM user_snapshots;

Complete Refresh
CREATE MATERIALIZED VIEW <schema.name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
REFRESH <COMPLETE | FORCE>
START WITH <date>
NEXT <date_calculation>
[FOR UPDATE]
AS (<SQL statement>);
CREATE MATERIALIZED VIEW mv_complete
TABLESPACE uwdata
REFRESH COMPLETE
START WITH
SYSDATE
NEXT SYSDATE + 1 AS
SELECT s.srvr_id, i.installstatus, COUNT(*)
FROM servers s, serv_inst i
WHERE s.srvr_id = i.srvr_id
GROUP BY s.srvr_id, i.installstatus;
Note: To create a materialized view that refreshes at 3:00am in the morning:

SQL> SELECT to_char(sysdate, 'MM/DD/YYYY HH:MI:SS')
2 FROM DUAL;

TO_CHAR(SYSDATE,'MM/DD/YYYYHH
-----------------------------------------------------------------
12/03/2006 01:25:30

SQL> SELECT TO_CHAR(TRUNC(SYSDATE) + 3/24, 'MM/DD/YYYY HH:MI:SS')
2 FROM DUAL;


TO_CHAR(TRUNC(SYSDATE)+3/24,'M
-----------------------------------------------------------------
12/03/2006 03:00:00

SELECT name, table_name, updatable, refresh_method
FROM user_snapshots;

SELECT name, table_name, 
refresh_method
FROM user_snapshots;

col next format a30

SELECT name, type, next, start_with, refresh_group
FROM user_snapshots;

col query format a50

SELECT name, query, status
FROM user_snapshots;

SELECT *
FROM mv_complete


Complete Refresh Using Index
CREATE MATERIALIZED VIEW <schema.name>
[LOGGING] [CACHE]
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
USING INDEX
REFRESH <COMPLETE | FORCE>
START WITH <date>
NEXT <date_calculation>
[FOR UPDATE]
AS (<SQL statement>);
CREATE SNAPSHOT mv_w_index
LOGGING CACHE
PCTFREE 0 PCTUSED 99
TABLESPACE uwdata
USING INDEX
REFRESH COMPLETE

AS SELECT s.srvr_id, COUNT(*)
FROM servers s, serv_inst i
WHERE s.srvr_id = i.srvr_id
GROUP BY s.srvr_id;

desc mv_w_index

SELECT name, table_name, updatable, refresh_method
FROM user_snapshots;

SELECT * FROM mv_w_index;

SELECT index_name, index_type
FROM user_indexes;

SELECT column_expression
FROM user_ind_expressions
WHERE table_name = 'MV_W_INDEX';

Prebuilt Table
CREATE MATERIALIZED VIEW <schema.name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
REFRESH <COMPLETE | FORCE>
START WITH <date>
NEXT <date_calculation>
[FOR UPDATE]
AS (<SQL statement>);
conn sh/sh

CREATE TABLE mv_prebuilt (
month VARCHAR2(8),
state VARCHAR2(40),
sales NUMBER(10,2));

CREATE MATERIALIZED VIEW mv_prebuilt
ON PREBUILT TABLE WITH REDUCED PRECISION
AS SELECT t.calendar_month_desc AS month,
c.cust_state_province AS state,
SUM(s.amount_sold) AS sales
FROM times t, customers c, sales s
WHERE s.time_id = t.time_id AND s.cust_id = c.cust_id
GROUP BY t.calendar_month_desc, c.cust_state_province;

SELECT name, table_name, refresh_method, refresh_mode, prebuilt
FROM user_snapshots;

Enable Query Rewrite
CREATE MATERIALIZED VIEW <schema.name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
REFRESH <COMPLETE | FORCE>
START WITH <date>
NEXT <date_calculation>
[FOR UPDATE]
AS (<SQL statement>);
set linesize 121
col name format a30
col value format a30

SELECT name, value
FROM gv$parameter
WHERE name LIKE '%rewrite%';

EXPLAIN PLAN FOR
SELECT s.srvr_id, i.installstatus, COUNT(*)
FROM servers s, serv_inst i
WHERE s.srvr_id = i.srvr_id
AND s.srvr_id = 502
GROUP BY s.srvr_id, i.installstatus;

SELECT * FROM TABLE(dbms_xplan.display);

CREATE MATERIALIZED VIEW mv_rewrite
TABLESPACE uwdata
REFRESH ON DEMAND
ENABLE QUERY REWRITE
AS SELECT s.srvr_id, i.installstatus, COUNT(*)
FROM servers s, serv_inst i
WHERE s.srvr_id = i.srvr_id
GROUP BY s.srvr_id, i.installstatus;

EXPLAIN PLAN FOR
SELECT s.srvr_id, i.installstatus, COUNT(*)
FROM servers s, serv_inst i
WHERE s.srvr_id = i.srvr_id
AND s.srvr_id = 502
GROUP BY s.srvr_id, i.installstatus;

SELECT * FROM TABLE(dbms_xplan.display);

-- if the base table may be updated then
ALTER SESSION SET query_rewrite_integrity = STALE_TOLERATED;
 
Alter Materialized View
Allocate Extent ALTER MATERIALIZED VIEW <schema.materialized_view>
ALLOCATE EXTENT (SIZE <size_clause> DATAFILE <'file_name'>)
INSTANCE <integer>;
ALTER MATERIALIZED VIEW mv_simple ALLOCATE EXTENT (SIZE 8K);
Caching ALTER MATERIALIZED VIEW <schema.materialized_view>
<CACHE | NOCACHE>;
ALTER MATERIALIZED VIEW mv_simple NOCACHE;
Compile ALTER MATERIALIZED VIEW <schema.materialized_view> COMPILE;
ALTER MATERIALIZED VIEW mv_simple COMPILE;
Consider Fresh ALTER MATERIALIZED VIEW <schema.materialized_view>
CONSIDER FRESH;
ALTER MATERIALIZED VIEW mv_complete CONSIDER FRESH;
Deallocate Unused ALTER MATERIALIZED VIEW <schema.materialized_view>
DEALLOCATE UNUSED;
ALTER MATERIALIZED VIEW mv_complete DEALLOCATE UNUSED;
Index Organized Table ALTER MATERIALIZED VIEW <schema.materialized_view>
<index_organized_table_clause>
<alter_overflow_clause>
<alter_mapping_table_clause>
COALESCE; 
See IOT Page;
LOB Storage ALTER MATERIALIZED VIEW <schema.materialized_view>
LOB (lob_item) STORE AS (lob_storage_parameters);
TBD
Logging ALTER MATERIALIZED VIEW <schema.materialized_view>
<LOGGING | NOLOGGING>;
ALTER MATERIALIZED VIEW mv_simple LOGGING;
Modify LOB Storage ALTER MATERIALIZED VIEW <schema.materialized_view>
MODIFY LOB (<lob_item>) (new_lob_parameter);
TBD
Parallel Access ALTER MATERIALIZED VIEW <schema.materialized_view> 
<PARALLEL | NO_PARALLEL>;
ALTER MATERIALIZED VIEW mv_simple PARALLEL;
Physical Attributes ALTER MATERIALIZED VIEW <schema.materialized_view> (
PCT_FREE <integer>
PCT_USED <integer>
INITRANS <integer>
TABLESPACE <tablespace_name>;
ALTER MATERIALIZED VIEW mv_simple PCTFREE 1;
Query Rewrite ALTER MATERIALIZED VIEW <schema.materialized_view> 
<ENABLE | DISABLE> QUERY REWRITE;
ALTER MATERIALIZED VIEW mv_simple ENABLE QUERY REWRITE;

Refresh
ALTER MATERIALIZED VIEW <schema.materialized_view> 
REFRESH <FAST | COMPLETE | FORCE>
ON <DEMAND | COMMIT>
START WITH <date_time>
NEXT <date_time>
WITH PRIMARY KEY
USING DEFAULT MASTER ROLLBACK SEGMENT
USING <ENFORCED | TRUSTED> CONSTRAINTS;
ALTER MATERIALIZED VIEW mv_complete REFRESH COMPLETE;

Shrink
ALTER MATERIALIZED VIEW <schema.materialized_view> SHRINK SPACE <COMPACT | CASCADE>;
ALTER MATERIALIZED VIEW mv_simple ENABLE ROW MOVEMENT;

ALTER MATERIALIZED VIEW mv_simple SHRINK SPACE CASCADE;
Table Compression ALTER MATERIALIZED VIEW <schema.materialized_view> 
<COMPRESS | NOCOMPRESS>;
ALTER MATERIALIZED VIEW mv_simple COMPRESS;
Table Partitioning ALTER MATERIALIZED VIEW <schema.materialized_view> ....
See Partitioning Page;
 
Drop

Drop Materialized View
DROP MATERIALIZED VIEW <schema.materialized_view>;
SELECT table_name
FROM user_tables;

DROP MATERIALIZED VIEW mv_simple;

SELECT table_name
FROM user_tables;

Drop Snapshot
DROP MATERIALIZED VIEW <schema.materialized_view>;
SELECT table_name
FROM user_tables;

DROP SNAPSHOT mv_complex;

SELECT table_name
FROM user_tables;

Drop Materialized View Preserve Table
DROP MATERIALIZED VIEW <schema.materialized_view>
PRESERVE TABLE;
SELECT table_name
FROM user_tables;

DROP MATERIALIZED VIEW mv_simple PRESERVE TABLE;

SELECT table_name
FROM user_tables;

DROP TABLE mv_serers;

SELECT table_name
FROM user_tables;
 
Create Refresh Log

Create Log Tables
CREATE MATERIALIZED VIEW LOG ON <schema.table_name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>
<LOGGING | NOLOGGING>
<CACHE | NOCACHE>
<NOPARALLEL | PARALLEL <integer>>
<table_partitioning_clause>
WITH <OBJECT | PRIMARY KEY | ROWID | SEQUENCE | (column_list)>
[<INCLUDING | EXCLUDING> NEW VALUES];
CREATE MATERIALIZED VIEW LOG ON servers
PCTFREE 0
PCTUSED 99
TABLESPACE uwdata
WITH PRIMARY KEY, ROWID;

desc user_snapshot_logs

SELECT master, log_table, rowids, primary_key
FROM user_snapshot_logs;

SELECT table_name
FROM user_tables;

desc mlog$_servers

desc rupd$_servers
 
Alter Refresh Log

Alter Physical Attributes
ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
PCTFREE <integer>
PCTUSED <integer>
TABLESPACE <tablespace_name>;
SELECT table_name, pct_free, pct_used
FROM user_tables;

ALTER MATERIALIZED VIEW LOG ON servers PCTFREE 20;

SELECT table_name, pct_free, pct_used
FROM user_tables;

Alter Parallelism
ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
<NOPARALLEL | PARALLEL <integer>>;
SELECT table_name, degree
FROM user_tables;

ALTER MATERIALIZED VIEW LOG ON servers PARALLEL 8;

SELECT table_name, degree
FROM user_tables;
Alter Logging ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
<LOGGING | NOLOGGING>;
ALTER MATERIALIZED VIEW LOG ON servers LOGGING;
Alter Allocate Extent by Size ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
ALLOCATE EXTENT (SIZE <integer> <M | G | T>);
ALTER MATERIALIZED VIEW LOG ON servers
ALLOCATE EXTENT (SIZE 512K);
Alter Allocate Extent by Datafile ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
ALLOCATE EXTENT (DATAFILE <file_name>);
ALTER MATERIALIZED VIEW LOG ON servers
ALLOCATE EXTENT (DATAFILE 'c: emp\users01.dbf');
Alter Allocate Extent by Instance ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
ALLOCATE EXTENT SIZE (INSTANCE <integer>);
ALTER MATERIALIZED VIEW LOG ON servers
ALLOCATE EXTENT (INSTANCE 1);

Shrink Log
ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
[COMPACT] [CASCADE];
ALTER MATERIALIZED VIEW LOG ON servers
SHRINK SPACE COMPACT CASCADE;

ALTER TABLE mlog$_servers ENABLE ROW MOVEMENT;

ALTER MATERIALIZED VIEW LOG ON servers
SHRINK SPACE COMPACT CASCADE;
Log Caching ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
<CACHE | NOCACHE>;
ALTER MATERIALIZED VIEW LOG ON servers CACHE;
Add Clause ALTER MATERIALIZED VIEW LOG [FORCE] ON <schema.table_name>
ADD <OBJECT | PRIMARY KEY | ROWID | SEQUENCE | (column_list)>
[<INCLUDING | EXCLUDING> NEW VALUES];
ALTER MATERIALIZED VIEW LOG ON servers ADD SEQUENCE;
 
Drop Refresh Log
Drop Log DROP MATERIALIZED VIEW LOG ON <table_name>;
DROP MATERIALIZED VIEW LOG ON servers;
 
Notes
Indexing [with respect to MV's on 10gR2 Jonathan Lewis wrote ] ... you are allowed to create indexes on the tables that sit under materialized views - just don't make them unique indexes
 
Related Topics
DBMS_ADVISOR
DBMS_MVIEW
DBMS_REFRESH
Tables
   Home |    Search |    Code Library |    Sponsors |    Privacy |    Terms of Use |    Contact Us    © 2003 - 2024 psoug.org
-----