Oracle® Database Data Warehousing Guide 11g Release 2 (11.2) Part Number E16579-02 |
|
|
PDF · Mobi · ePub |
This chapter discusses advanced topics in using materialized views. It contains the following topics:
Because of the large volume of data held in a data warehouse, partitioning is an extremely useful option when designing a database. Partitioning the fact tables improves scalability, simplifies system administration, and makes it possible to define local indexes that can be efficiently rebuilt. Partitioning the fact tables also improves the opportunity of fast refreshing the materialized view because this may enable Partition Change Tracking (PCT) refresh on the materialized view. Partitioning a materialized view also has benefits for refresh, because the refresh procedure can then use parallel DML in more scenarios and PCT-based refresh can use truncate partition to efficiently maintain the materialized view. See Oracle Database VLDB and Partitioning Guide for further details about partitioning.
It is possible and advantageous to track freshness to a finer grain than the entire materialized view. The ability to identify which rows in a materialized view are affected by a certain detail table partition, is known as Partition Change Tracking. When one or more of the detail tables are partitioned, it may be possible to identify the specific rows in the materialized view that correspond to a modified detail partition(s); those rows become stale when a partition is modified while all other rows remain fresh.
You can use PCT to identify which materialized view rows correspond to a particular partition. PCT is also used to support fast refresh after partition maintenance operations on detail tables. For instance, if a detail table partition is truncated or dropped, the affected rows in the materialized view are identified and deleted.
Identifying which materialized view rows are fresh or stale, rather than considering the entire materialized view as stale, allows query rewrite to use those rows that are fresh while in QUERY_REWRITE_INTEGRITY
= ENFORCED
or TRUSTED
modes. Several views, such as DBA_MVIEW_DETAIL_PARTITION
, detail which partitions are stale or fresh. Oracle does not rewrite against partial stale materialized views if partition change tracking on the changed table is enabled by the presence of join dependent expression in the materialized view. See "Join Dependent Expression" for more information.
To support PCT, a materialized view must satisfy the following requirements:
At least one of the detail tables referenced by the materialized view must be partitioned.
Partitioned tables must use either range, list or composite partitioning.
The top level partition key must consist of only a single column.
The materialized view must contain either the partition key column or a partition marker or ROWID
or join dependent expression of the detail table. See Oracle Database PL/SQL Packages and Types Reference for details regarding the DBMS_MVIEW.PMARKER
function.
If you use a GROUP
BY
clause, the partition key column or the partition marker or ROWID
or join dependent expression must be present in the GROUP
BY
clause.
If you use an analytic window function or the MODEL
clause, the partition key column or the partition marker or ROWID
or join dependent expression must be present in their respective PARTITION
BY
subclauses.
Data modifications can only occur on the partitioned table. If PCT refresh is being done for a table which has join dependent expression in the materialized view, then data modifications should not have occurred in any of the join dependent tables.
The COMPATIBILITY
initialization parameter must be a minimum of 9.0.0.0.0.
PCT is not supported for a materialized view that refers to views, remote tables, or outer joins.
Partition change tracking requires sufficient information in the materialized view to be able to correlate a detail row in the source partitioned detail table to the corresponding materialized view row. This can be accomplished by including the detail table partition key columns in the SELECT
list and, if GROUP
BY
is used, in the GROUP
BY
list.
Consider an example of a materialized view storing daily customer sales. The following example uses the sh
sample schema and the three detail tables sales
, products
, and times
to create the materialized view. sales
table is partitioned by time_id
column and products
is partitioned by the prod_id
column. times
is not a partitioned table.
The following is an example:
CREATE MATERIALIZED VIEW LOG ON SALES WITH ROWID (prod_id, time_id, quantity_sold, amount_sold) INCLUDING NEW VALUES; CREATE MATERIALIZED VIEW LOG ON PRODUCTS WITH ROWID (prod_id, prod_name, prod_desc) INCLUDING NEW VALUES; CREATE MATERIALIZED VIEW LOG ON TIMES WITH ROWID (time_id, calendar_month_name, calendar_year) INCLUDING NEW VALUES; CREATE MATERIALIZED VIEW cust_dly_sales_mv BUILD DEFERRED REFRESH FAST ON DEMAND ENABLE QUERY REWRITE AS SELECT s.time_id, p.prod_id, p.prod_name, COUNT(*), SUM(s.quantity_sold), SUM(s.amount_sold), COUNT(s.quantity_sold), COUNT(s.amount_sold) FROM sales s, products p, times t WHERE s.time_id = t.time_id AND s.prod_id = p.prod_id GROUP BY s.time_id, p.prod_id, p.prod_name;
For cust_dly_sales_mv
, PCT is enabled on both the sales
table and products
table because their respective partitioning key columns time_id
and prod_id
are in the materialized view.
An expression consisting of columns from tables directly or indirectly joined through equijoins to the partitioned detail table on the partitioning key and which is either a dimensional attribute or a dimension hierarchical parent of the joining key is called a join dependent expression. The set of tables in the path to detail table are called join dependent tables. Consider the following:
SELECT s.time_id, t.calendar_month_name FROM sales s, times t WHERE s.time_id = t.time_id;
In this query, times
table is a join dependent table since it is joined to sales
table on the partitioning key column time_id
. Moreover, calendar_month_name
is a dimension hierarchical attribute of times.time_id
, because calendar_month_name
is an attribute of times.mon_id
and times.mon_id
is a dimension hierarchical parent of times.time_id
. Hence, the expression calendar_month_name
from times
tables is a join dependent expression. Let's consider another example:
SELECT s.time_id, y.calendar_year_name FROM sales s, times_d d, times_m m, times_y y WHERE s.time_id = d.time_id AND d.day_id = m.day_id AND m.mon_id = y.mon_id;
Here, times
table is denormalized into times_d
, times_m
and times_y
tables. The expression calendar_year_name
from times_y
table is a join dependent expression and the tables times_d
, times_m
and times_y
are join dependent tables. This is because times_y
table is joined indirectly through times_m
and times_d
tables to sales table on its partitioning key column time_id
.
This lets users create materialized views containing aggregates on some level higher than the partitioning key of the detail table. Consider the following example of materialized view storing monthly customer sales.
Example 10-2 Join Dependent Expression
Assuming the presence of materialized view logs defined earlier, the materialized view can be created using the following DDL:
CREATE MATERIALIZED VIEW cust_mth_sales_mv BUILD DEFERRED REFRESH FAST ON DEMAND ENABLE QUERY REWRITE AS SELECT t.calendar_month_name, p.prod_id, p.prod_name, COUNT(*), SUM(s.quantity_sold), SUM(s.amount_sold), COUNT(s.quantity_sold), COUNT(s.amount_sold) FROM sales s, products p, times t WHERE s.time_id = t.time_id AND s.prod_id = p.prod_id GROUP BY t.calendar_month_name, p.prod_id, p.prod_name;
Here, you can correlate a detail table row to its corresponding materialized view row using the join dependent table times
and the relationship that times.calendar_month_name
is a dimensional attribute determined by times.time_id
. This enables partition change tracking on sales
table. In addition to this, PCT is enabled on products table because of presence of its partitioning key column prod_id
in the materialized view.
The DBMS_MVIEW.PMARKER
function is designed to significantly reduce the cardinality of the materialized view (see Example 10-3 for an example). The function returns a partition identifier that uniquely identifies the partition for a specified row within a specified partition table. Therefore, the DBMS_MVIEW.PMARKER
function is used instead of the partition key column in the SELECT
and GROUP
BY
clauses.
Unlike the general case of a PL/SQL function in a materialized view, use of the DBMS_MVIEW.PMARKER
does not prevent rewrite with that materialized view even when the rewrite mode is QUERY_REWRITE_INTEGRITY = ENFORCED
.
As an example of using the PMARKER
function, consider calculating a typical number, such as revenue generated by a product category during a given year. If there were 1000 different products sold each month, it would result in 12,000 rows in the materialized view.
Consider an example of a materialized view storing the yearly sales revenue for each product category. With approximately hundreds of different products in each product category, including the partitioning key column prod_id
of the products
table in the materialized view would substantially increase the cardinality. Instead, this materialized view uses the DBMS_MVIEW.PMARKER
function, which increases the cardinality of materialized view by a factor of the number of partitions in the products
table.
CREATE MATERIALIZED VIEW prod_yr_sales_mv BUILD DEFERRED REFRESH FAST ON DEMAND ENABLE QUERY REWRITE AS SELECT DBMS_MVIEW.PMARKER(p.rowid), p.prod_category, t.calendar_year, COUNT(*), SUM(s.amount_sold), SUM(s.quantity_sold), COUNT(s.amount_sold), COUNT(s.quantity_sold) FROM sales s, products p, times t WHERE s.time_id = t.time_id AND s.prod_id = p.prod_id GROUP BY DBMS_MVIEW.PMARKER (p.rowid), p.prod_category, t.calendar_year;
prod_yr_sales_mv
includes the DBMS_MVIEW.PMARKER
function on the products
table in its SELECT
list. This enables partition change tracking on products
table with significantly less cardinality impact than grouping by the partition key column prod_id
. In this example, the desired level of aggregation for the prod_yr_sales_mv
is to group by products.prod_category
. Using the DBMS_MVIEW.PMARKER
function, the materialized view cardinality is increased only by a factor of the number of partitions in the products
table. This would generally be significantly less than the cardinality impact of including the partition key columns.
Note that partition change tracking is enabled on sales
table because of presence of join dependent expression calendar_year
in the SELECT
list.
A subsequent INSERT
statement adds a new row to the sales_part3
partition of table sales
. At this point, because cust_dly_sales_mv
has PCT available on table sales
using a partition key, Oracle can identify the stale rows in the materialized view cust_dly_sales_mv
corresponding to sales_part3
partition (The other rows are unchanged in their freshness state). Query rewrite cannot identify the fresh portion of materialized views cust_mth_sales_mv
and prod_yr_sales_mv
because PCT is available on table sales using join dependent expressions. Query rewrite can determine the fresh portion of a materialized view on changes to a detail table only if PCT is available on the detail table using a partition key or partition marker.
Partitioning a materialized view involves defining the materialized view with the standard Oracle partitioning clauses, as illustrated in the following example. This statement creates a materialized view called part_sales_mv
, which uses three partitions, can be fast refreshed, and is eligible for query rewrite:
CREATE MATERIALIZED VIEW part_sales_mv PARALLEL PARTITION BY RANGE (time_id) (PARTITION month1 VALUES LESS THAN (TO_DATE('31-12-1998', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf1, PARTITION month2 VALUES LESS THAN (TO_DATE('31-12-1999', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf2, PARTITION month3 VALUES LESS THAN (TO_DATE('31-12-2000', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf3) BUILD DEFERRED REFRESH FAST ENABLE QUERY REWRITE AS SELECT s.cust_id, s.time_id, SUM(s.amount_sold) AS sum_dol_sales, SUM(s.quantity_sold) AS sum_unit_sales FROM sales s GROUP BY s.time_id, s.cust_id;
Alternatively, a materialized view can be registered to a partitioned prebuilt table as illustrated in the following example:
CREATE TABLE part_sales_tab_mv(time_id, cust_id, sum_dollar_sales, sum_unit_sale) PARALLEL PARTITION BY RANGE (time_id) (PARTITION month1 VALUES LESS THAN (TO_DATE('31-12-1998', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf1, PARTITION month2 VALUES LESS THAN (TO_DATE('31-12-1999', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf2, PARTITION month3 VALUES LESS THAN (TO_DATE('31-12-2000', 'DD-MM-YYYY')) PCTFREE 0 STORAGE (INITIAL 8M) TABLESPACE sf3) AS SELECT s.time_id, s.cust_id, SUM(s.amount_sold) AS sum_dollar_sales, SUM(s.quantity_sold) AS sum_unit_sales FROM sales s GROUP BY s.time_id, s.cust_id; CREATE MATERIALIZED VIEW part_sales_tab_mv ON PREBUILT TABLE ENABLE QUERY REWRITE AS SELECT s.time_id, s.cust_id, SUM(s.amount_sold) AS sum_dollar_sales, SUM(s.quantity_sold) AS sum_unit_sales FROM sales s GROUP BY s.time_id, s.cust_id;
In this example, the table part_sales_tab_mv
has been partitioned over three months and then the materialized view was registered to use the prebuilt table. This materialized view is eligible for query rewrite because the ENABLE
QUERY
REWRITE
clause has been included.
When a materialized view is partitioned on the partitioning key column or join dependent expressions of the detail table, it is more efficient to use a TRUNCATE
PARTITION
statement to remove one or more partitions of the materialized view during refresh and then repopulate the partition with new data. Oracle Database uses this variant of fast refresh (called PCT refresh) with partition truncation if the following conditions are satisfied in addition to other conditions described in "Partition Change Tracking".
The materialized view is partitioned on the partitioning key column or join dependent expressions of the detail table.
If PCT is enabled using either the partitioning key column or join expressions, the materialized view should be range or list partitioned.
PCT refresh is nonatomic.
When a data warehouse or data mart contains a time dimension, it is often desirable to archive the oldest information and then reuse the storage for new information. This is called the rolling window scenario. If the fact tables or materialized views include a time dimension and are horizontally partitioned by the time attribute, then management of rolling materialized views can be reduced to a few fast partition maintenance operations provided the unit of data that is rolled out equals, or is at least aligned with, the range partitions.
If you plan to have rolling materialized views in your data warehouse, you should determine how frequently you plan to perform partition maintenance operations, and you should plan to partition fact tables and materialized views to reduce the amount of system administration overhead required when old data is aged out. An additional consideration is that you might want to use data compression on your infrequently updated partitions.
You are not restricted to using range partitions. For example, a composite partition using both a time value and a key value could result in a good partition solution for your data.
See Chapter 16, "Maintaining the Data Warehouse" for further details regarding CONSIDER
FRESH
and for details regarding compression.
This section discusses the concepts used by analytic SQL and how relational databases can handle these types of queries. It also illustrates the best approach for creating materialized views using a common scenario.
While data warehouse environments typically view data in the form of a star schema, for analytical SQL queries, data is held in the form of a hierarchical cube. A hierarchical cube includes the data aggregated along the rollup hierarchy of each of its dimensions and these aggregations are combined across dimensions. It includes the typical set of aggregations needed for business intelligence queries.
Example 10-4 Hierarchical Cube
Consider a sales data set with two dimensions, each of which has a 4-level hierarchy:
Time, which contains (all times), year, quarter, and month.
Product, which contains (all products), division, brand, and item.
This means there are 16 aggregate groups in the hierarchical cube. This is because the four levels of time are multiplied by four levels of product to produce the cube. Table 10-1 shows the four levels of each dimension.
Table 10-1 ROLLUP By Time and Product
ROLLUP By Time | ROLLUP By Product |
---|---|
year, quarter, month |
division, brand, item |
year, quarter |
division, brand |
year |
division |
all times |
all products |
Note that as you increase the number of dimensions and levels, the number of groups to calculate increases dramatically. This example involves 16 groups, but if you were to add just two more dimensions with the same number of levels, you would have 4 x 4 x 4 x 4 = 256 different groups. Also, consider that a similar increase in groups occurs if you have multiple hierarchies in your dimensions. For example, the time dimension might have an additional hierarchy of fiscal month rolling up to fiscal quarter and then fiscal year. Handling the explosion of groups has historically been the major challenge in data storage for online analytical processing systems.
Typical online analytical queries slice and dice different parts of the cube comparing aggregations from one level to aggregation from another level. For instance, a query might find sales of the grocery division for the month of January, 2002 and compare them with total sales of the grocery division for all of 2001.
Materialized views with multiple aggregate groups give their best performance for refresh and query rewrite when partitioned appropriately.
PCT refresh in a rolling window scenario requires partitioning at the top level on some level from the time dimension. And, partition pruning for queries rewritten against this materialized view requires partitioning on GROUPING_ID
column. Hence, the most effective partitioning scheme for these materialized views is to use composite partitioning (range-list on (time
, GROUPING_ID
) columns). By partitioning the materialized views this way, you enable:
PCT refresh, thereby improving refresh performance.
Partition pruning: only relevant aggregate groups are accessed, thereby greatly reducing the query processing cost.
If you do not want to use PCT refresh, you can just partition by list on GROUPING_ID
column.
You should consider data compression when using highly redundant data, such as tables with many foreign keys. In particular, materialized views created with the ROLLUP
clause are likely candidates. See Oracle Database SQL Language Reference for data compression syntax and restrictions and "Storage And Table Compression" for details regarding compression.
Oracle Database provides support for materialized views whose defining query involves set operators. Materialized views with set operators can now be created enabled for query rewrite. You can refresh the materialized view using either ON
COMMIT
or ON
DEMAND
refresh.
Fast refresh is supported if the defining query has the UNION
ALL
operator at the top level and each query block in the UNION
ALL
, meets the requirements of a materialized view with aggregates or materialized view with joins only. Further, the materialized view must include a constant column (known as a UNION
ALL
marker) that has a distinct value in each query block, which, in the following example, is columns 1 marker
and 2 marker
.
See "Restrictions on Fast Refresh on Materialized Views with UNION ALL" for detailed restrictions on fast refresh for materialized views with UNION
ALL
.
The following examples illustrate creation of fast refreshable materialized views involving UNION
ALL
.
Example 10-5 Materialized View Using UNION ALL with Two Join Views
To create a UNION
ALL
materialized view with two join views, the materialized view logs must have the rowid column and, in the following example, the UNION
ALL
marker is the columns, 1 marker
and 2 marker
.
CREATE MATERIALIZED VIEW LOG ON sales WITH ROWID; CREATE MATERIALIZED VIEW LOG ON customers WITH ROWID; CREATE MATERIALIZED VIEW unionall_sales_cust_joins_mv REFRESH FAST ON COMMIT ENABLE QUERY REWRITE AS (SELECT c.rowid crid, s.rowid srid, c.cust_id, s.amount_sold, 1 marker FROM sales s, customers c WHERE s.cust_id = c.cust_id AND c.cust_last_name = 'Smith') UNION ALL (SELECT c.rowid crid, s.rowid srid, c.cust_id, s.amount_sold, 2 marker FROM sales s, customers c WHERE s.cust_id = c.cust_id AND c.cust_last_name = 'Brown');
Example 10-6 Materialized View Using UNION ALL with Joins and Aggregates
The following example shows a UNION
ALL
of a materialized view with joins and a materialized view with aggregates. A couple of things can be noted in this example. Nulls or constants can be used to ensure that the data types of the corresponding SELECT
list columns match. Also, the UNION
ALL
marker column can be a string literal, which is 'Year' umarker
, 'Quarter' umarker
, or 'Daily' umarker
in the following example:
CREATE MATERIALIZED VIEW LOG ON sales WITH ROWID, SEQUENCE (amount_sold, time_id) INCLUDING NEW VALUES; CREATE MATERIALIZED VIEW LOG ON times WITH ROWID, SEQUENCE (time_id, fiscal_year, fiscal_quarter_number, day_number_in_week) INCLUDING NEW VALUES; CREATE MATERIALIZED VIEW unionall_sales_mix_mv REFRESH FAST ON DEMAND AS (SELECT 'Year' umarker, NULL, NULL, t.fiscal_year, SUM(s.amount_sold) amt, COUNT(s.amount_sold), COUNT(*) FROM sales s, times t WHERE s.time_id = t.time_id GROUP BY t.fiscal_year) UNION ALL (SELECT 'Quarter' umarker, NULL, NULL, t.fiscal_quarter_number, SUM(s.amount_sold) amt, COUNT(s.amount_sold), COUNT(*) FROM sales s, times t WHERE s.time_id = t.time_id and t.fiscal_year = 2001 GROUP BY t.fiscal_quarter_number) UNION ALL (SELECT 'Daily' umarker, s.rowid rid, t.rowid rid2, t.day_number_in_week, s.amount_sold amt, 1, 1 FROM sales s, times t WHERE s.time_id = t.time_id AND t.time_id between '01-Jan-01' AND '01-Dec-31');
Models, which provide array-based computations in SQL, can be used in materialized views. Because the MODEL
clause calculations can be expensive, you may want to use two separate materialized views: one for the model calculations and one for the SELECT
... GROUP
BY
query. For example, instead of using one, long materialized view, you could create the following materialized views:
CREATE MATERIALIZED VIEW my_groupby_mv REFRESH FAST ENABLE QUERY REWRITE AS SELECT country_name country, prod_name prod, calendar_year year, SUM(amount_sold) sale, COUNT(amount_sold) cnt, COUNT(*) cntstr FROM sales, times, customers, countries, products WHERE sales.time_id = times.time_id AND sales.prod_id = products.prod_id AND sales.cust_id = customers.cust_id AND customers.country_id = countries.country_id GROUP BY country_name, prod_name, calendar_year; CREATE MATERIALIZED VIEW my_model_mv ENABLE QUERY REWRITE AS SELECT country, prod, year, sale, cnt FROM my_groupby_mv MODEL PARTITION BY(country) DIMENSION BY(prod, year) MEASURES(sale s) IGNORE NAV (s['Shorts', 2000] = 0.2 * AVG(s)[CV(), year BETWEEN 1996 AND 1999], s['Kids Pajama', 2000] = 0.5 * AVG(s)[CV(), year BETWEEN 1995 AND 1999], s['Boys Pajama', 2000] = 0.6 * AVG(s)[CV(), year BETWEEN 1994 AND 1999], ... <hundreds of other update rules>);
By using two materialized views, you can incrementally maintain the materialized view my_groupby_mv
. The materialized view my_model_mv
is on a much smaller data set because it is built on my_groupby_mv
and can be maintained by a complete refresh.
Materialized views with models can use complete refresh or PCT refresh only, and are available for partial text query rewrite only.
See Also:
Chapter 23, "SQL for Modeling" for further details about model calculationsDependencies related to materialized views are automatically maintained to ensure correct operation. When a materialized view is created, the materialized view depends on the detail tables referenced in its definition. Any DML operation, such as an INSERT
, or DELETE
, UPDATE
, or DDL operation on any dependency in the materialized view will cause it to become invalid. To revalidate a materialized view, use the ALTER
MATERIALIZED
VIEW
COMPILE
statement.
A materialized view is automatically revalidated when it is referenced. In many cases, the materialized view will be successfully and transparently revalidated. However, if a column has been dropped in a table referenced by a materialized view or the owner of the materialized view did not have one of the query rewrite privileges and that privilege has now been granted to the owner, you should use the following statement to revalidate the materialized view:
ALTER MATERIALIZED VIEW mview_name COMPILE;
The state of a materialized view can be checked by querying the data dictionary views USER_MVIEWS
or ALL_MVIEWS
. The column STALENESS
will show one of the values FRESH
, STALE
, UNUSABLE
, UNKNOWN
, UNDEFINED
, or NEEDS_COMPILE
to indicate whether the materialized view can be used. The state is maintained automatically. However, if the staleness of a materialized view is marked as NEEDS_COMPILE
, you could issue an ALTER
MATERIALIZED
VIEW
... COMPILE
statement to validate the materialized view and get the correct staleness state. If the state of a materialized view is UNUSABLE
, you must perform a complete refresh to bring the materialized view back to the FRESH
state. If the materialized view is based on a prebuilt table that you never refresh, you must drop and re-create the materialized view. The staleness of remote materialized views is not tracked. Thus, if you use remote materialized views for rewrite, they are considered to be trusted.
To create a materialized view in your own schema, you must have the CREATE
MATERIALIZED
VIEW
privilege and the SELECT
privilege to any tables referenced that are in another schema. To create a materialized view in another schema, you must have the CREATE
ANY
MATERIALIZED
VIEW
privilege and the owner of the materialized view needs SELECT
privileges to the tables referenced if they are from another schema. Moreover, if you enable query rewrite on a materialized view that references tables outside your schema, you must have the GLOBAL
QUERY
REWRITE
privilege or the QUERY
REWRITE
object privilege on each table outside your schema.
If the materialized view is on a prebuilt container, the creator, if different from the owner, must have SELECT
WITH
GRANT
privilege on the container table.
If you continue to get a privilege error while trying to create a materialized view and you believe that all the required privileges have been granted, then the problem is most likely due to a privilege not being granted explicitly and trying to inherit the privilege from a role instead. The owner of the materialized view must have explicitly been granted SELECT
access to the referenced tables if the tables are in a different schema.
If the materialized view is being created with ON
COMMIT
REFRESH
specified, then the owner of the materialized view requires an additional privilege if any of the tables in the defining query are outside the owner's schema. In that case, the owner requires the ON
COMMIT
REFRESH
system privilege or the ON
COMMIT
REFRESH
object privilege on each table outside the owner's schema.
For all security concerns, a materialized view serves as a view that happens to be materialized when you are directly querying the materialized view. When creating a view or materialized view, the owner must have the necessary permissions to access the underlying base relations of the view or materialized view that they are creating. With these permissions, the owner can publish a view or materialized view that other users can access, assuming they have been granted access to the view or materialized view.
Using materialized views with Virtual Private Database is similar. When you create a materialized view, there must not be any VPD policies in effect against the base relations of the materialized view for the owner of the materialized view. However, the owner of the materialized view may establish a VPD policy on the new materialized view. Users who access the materialized view are subject to the VPD policy on the materialized view. However, they are not additionally subject to the VPD policies of the underlying base relations of the materialized view, since security processing of the underlying base relations is performed against the owner of the materialized view.
When you access a materialized view using query rewrite, the materialized view serves as an access structure much like an index. As such, the security implications for materialized views accessed in this way are much the same as for indexes: all security checks are performed against the relations specified in the request query. The index or materialized view is used to speed the performance of accessing the data, not provide any additional security checks. Thus, the presence of the index or materialized view presents no additional security checking.
This holds true when you are accessing a materialized view using query rewrite in the presence of VPD. The request query is subject to any VPD policies that are present against the relations specified in the query. Query rewrite may rewrite the query to use a materialize view instead of accessing the detail relations, but only if it can guarantee to deliver exactly the same rows as if the rewrite had not occurred. Specifically, query rewrite must retain and respect any VPD policies against the relations specified in the request query. However, any VPD policies against the materialized view itself do not have effect when the materialized view is accessed using query rewrite. This is because the data is already protected by the VPD policies against the relations in the request query.
Query rewrite does not use its full and partial text match modes with request queries that include relations with active VPD policies, but it does use general rewrite methods. This is because VPD transparently transforms the request query to affect the VPD policy. If query rewrite were to perform a text match transformation against a request query with a VPD policy, the effect would be to negate the VPD policy.
In addition, when you create or refresh a materialized view, the owner of the materialized view must not have any active VPD policies in effect against the base relations of the materialized view, or an error is returned. The materialized view owner must either have no such VPD policies, or any such policy must return NULL
. This is because VPD would transparently modify the defining query of the materialized view such that the set of rows contained by the materialized view would not match the set of rows indicated by the materialized view definition.
One way to work around this restriction yet still create a materialized view containing the desired VPD-specified subset of rows is to create the materialized view in a user account that has no active VPD policies against the detail relations of the materialized view. In addition, you can include a predicate in the WHERE
clause of the materialized view that embodies the effect of the VPD policy. When query rewrite attempts to rewrite a request query that has that VPD policy, it matches up the VPD-generated predicate on the request query with the predicate you directly specify when you create the materialized view.
Six modifications can be made to a materialized view. You can:
Change its refresh option (FAST/FORCE/COMPLETE/NEVER
).
Change its refresh mode (ON
COMMIT/ON
DEMAND
).
Recompile it.
Enable or disable its use for query rewrite.
Consider it fresh.
Partition maintenance operations.
All other changes are achieved by dropping and then re-creating the materialized view.
The COMPILE
clause of the ALTER
MATERIALIZED
VIEW
statement can be used when the materialized view has been invalidated. This compile process is quick, and allows the materialized view to be used by query rewrite again.
See Also:
Oracle Database SQL Language Reference for further information about the ALTER
MATERIALIZED
VIEW
statement