Privilege requirements
To drop a materialized view, you must have the DROP TABLE privilege. For more information about privileges in OceanBase Database, see Privilege types in Oracle-compatible mode.
Considerations
- When you drop a materialized view, it is not moved to the recycle bin.
- If materialized view logs are created on the base table of the materialized view, you must drop the materialized view logs on the base table before you drop the base table. Otherwise, an error is returned.
Syntax
The syntax for dropping a materialized view is as follows:
DROP MATERIALIZED VIEW [ schema. ] materialized_view;
Parameters
| Parameter | Description |
|---|---|
| schema. | Optional. Specifies the schema where the materialized view is located. If you omit schema., the current schema is used by default. |
| materialized_view | Specifies the name of the materialized view. |
Examples
The following examples show how to create a materialized view, query materialized views, and drop a materialized view.
Create a table named
test_tbl1as the base table of the materialized view.CREATE TABLE test_tbl1 (col1 INT PRIMARY KEY, col2 VARCHAR2(20), col3 INT);Create a materialized view named
mv_test_tbl1based on thetest_tbl1table.CREATE MATERIALIZED VIEW mv_test_tbl1(PRIMARY KEY (col1)) AS SELECT col1, col2 FROM test_tbl1;Create a materialized view log on the
mv_test_tbl1materialized view.CREATE MATERIALIZED VIEW LOG ON mv_test_tbl1 WITH PRIMARY KEY (col2) INCLUDING NEW VALUES;Create a nested materialized view named
mv_mv_test_tbl1based on themv_test_tbl1materialized view.CREATE MATERIALIZED VIEW mv_mv_test_tbl1 AS SELECT col1 FROM mv_test_tbl1;View information about all materialized views.
SELECT owner, mview_name, container_name, query, refresh_mode FROM sys.DBA_MVIEWS WHERE OWNER = 'TEST_USER001';Notice
In Oracle mode, the
OWNERcolumn of the viewsys.DBA_MVIEWSmatches the schema name in uppercase letters.The return result is as follows:
+--------------+-----------------+-----------------+--------------------------------------------------------------------------------------------------------------------------------+--------------+ | OWNER | MVIEW_NAME | CONTAINER_NAME | QUERY | REFRESH_MODE | +--------------+-----------------+-----------------+--------------------------------------------------------------------------------------------------------------------------------+--------------+ | TEST_USER001 | MV_TEST_TBL1 | MV_TEST_TBL1 | select "TEST_USER001"."TEST_TBL1"."COL1" AS "COL1","TEST_USER001"."TEST_TBL1"."COL2" AS "COL2" from "TEST_USER001"."TEST_TBL1" | DEMAND | | TEST_USER001 | MV_MV_TEST_TBL1 | MV_MV_TEST_TBL1 | select "MV_TEST_TBL1"."COL1" AS "COL1" from "TEST_USER001"."MV_TEST_TBL1" "MV_TEST_TBL1" | DEMAND | +--------------+-----------------+-----------------+--------------------------------------------------------------------------------------------------------------------------------+--------------+ 2 rows in setDrop the
mv_mv_test_tbl1materialized view.DROP MATERIALIZED VIEW mv_mv_test_tbl1;The return result is as follows:
Query OK, 0 rows affectedDrop the
mv_test_tbl1materialized view.Notice
If materialized view logs are created on the base table of the materialized view, you must drop the materialized view logs on the base table before you drop the base table. Otherwise, an error is returned.
DROP MATERIALIZED VIEW mv_test_tbl1;The return result is as follows:
OBE-00600: internal error code, arguments: -4007, drop table required by materialized view refresh is not supportedDrop the materialized view logs on the
mv_test_tbl1materialized view.DROP MATERIALIZED VIEW LOG ON mv_test_tbl1;The return result is as follows:
Query OK, 0 rows affectedDrop the
mv_test_tbl1materialized view again.DROP MATERIALIZED VIEW mv_test_tbl1;The return result is as follows:
Query OK, 0 rows affected