This topic describes how to create a materialized view by using SQL statements.
Note
OceanBase Database does not support directly modifying the properties of a materialized view, such as the update time and refresh strategy. In this case, you can delete and recreate the materialized view to modify its properties.
Privilege requirements
To create a materialized view, you must have the CREATE TABLE privilege. For more information about the privileges of OceanBase Database, see Privilege types in Oracle mode.
Syntax
The syntax for creating a materialized view is as follows:
CREATE MATERIALIZED VIEW view_name [([column_list] [PRIMARY KEY(column_list)])]
[table_option_list]
[partition_option]
[mv_column_group_option]
[refresh_clause [query_rewrite_clause] [on_query_computation_clause]]
AS view_select_stmt;
Parameters:
view_name: specifies the name of the materialized view to be created.column_list: an optional parameter that specifies the list of columns in the materialized view. If you want to specify explicit names for the view columns, you can use thecolumn_listclause and separate the column names with commas.PRIMARY KEY(column_list): an optional parameter that specifies the primary key of the materialized view.table_option_list: an optional parameter that specifies the table options for the materialized view.partition_option: an optional parameter that specifies the partitioning options for the materialized view.mv_column_group_option: an optional parameter that specifies the storage format of the materialized view. If not specified, the default is to create a row-based materialized view.refresh_clause [query_rewrite_clause] [on_query_computation_clause]: an optional parameter that specifies the following options:refresh_clause: specifies the refresh method for the materialized view.query_rewrite_clause: an optional parameter that specifies whether to enable automatic query rewriting for the materialized view.on_query_computation_clause: an optional parameter that specifies whether the materialized view is a regular materialized view or a real-time materialized view.
AS view_select_stmt: specifies the query (SELECT) statement used to define the data of the materialized view. This statement retrieves data from the base table and stores the results in the materialized view.Note
For OceanBase Database V4.3.5:
- Starting from V4.3.5 BP2, you can create a full-refresh materialized view with a standard view or an external table as the base table.
- Starting from V4.3.5 BP4, you can add the
AS OF PROCTIME()clause to the base table when creating a materialized view. If you useAS OF PROCTIME()outside the base table of the materialized view, an error will be returned.AS OF PROCTIME()is used to specify that the incremental refresh should skip this table, and a table withAS OF PROCTIME()does not need to create an mlog. - Starting from V4.3.5 BP5, when a standard view is declared as a dimension table (
AS OF PROCTIME()), it can serve as the base table for an incremental-refresh materialized view.
For more information about the syntax for creating a materialized view, see CREATE MATERIALIZED VIEW.
Create a materialized view
Create a regular materialized view
To create a regular materialized view, omit or specify the DISABLE ON QUERY COMPUTATION clause.
Notice
In OceanBase Database in Oracle mode, when you create a materialized view and specify the DISABLE ON QUERY COMPUTATION clause (on_query_computation_clause), you must also specify the refresh method (refresh_clause).
Here is an example:
Create a table named
tbl1as the base table for the materialized view. The following example creates thetbl1table:CREATE TABLE tbl1 (col1 NUMBER PRIMARY KEY, col2 VARCHAR2(20), col3 NUMBER);Create a materialized view named
mv_tbl1based on thetbl1table. The following example creates themv_tbl1materialized view:CREATE MATERIALIZED VIEW mv_tbl1 AS SELECT col1, col2 FROM tbl1 WHERE col3 >= 20;or
CREATE MATERIALIZED VIEW mv_tbl1 REFRESH FORCE DISABLE ON QUERY COMPUTATION AS SELECT col1, col2 FROM tbl1 WHERE col3 >= 20;
Create a nested materialized view
A nested materialized view is a materialized view that is built on an existing materialized view. For example, in the following figure, the mv1 materialized view is built based on the tbl1 and tbl2 tables, which is a typical materialized view. The mv2 materialized view is built based on the mv1 materialized view and the tbl3 table, which is a nested materialized view. Similarly, the mv3 materialized view is built based on the mv1 and mv2 materialized views, which is also a nested materialized view. The following figure shows this.
In OceanBase Database V4.3.5, starting from V4.3.5 BP3, you can specify the refresh strategy for a nested materialized view. Valid values are as follows:
INDIVIDUAL: the default value, indicating independent refresh.INCONSISTENT: indicating cascading inconsistent refresh.CONSISTENT: indicating cascading consistent refresh.
Note
For non-nested materialized views, cascading refresh is not supported. Therefore, specifying any refresh strategy is meaningless and the default value of INDIVIDUAL is used. The three specified refresh strategies only take effect in background tasks. When you manually use the PL package (DBMS_MVIEW.REFRESH) to schedule a refresh, the refresh is performed based on the specified PL parameters.
Limitations on nested materialized views
- To support incremental refresh for nested materialized views, you must create mlogs on the materialized view (base table).
- If a materialized view is fully refreshed, the dependent materialized view (nested materialized view) must be fully refreshed before incremental refresh is performed. Otherwise, an error is returned.
- If a materialized view (nested materialized view) is a real-time materialized view, you must perform incremental refresh on the underlying materialized view to update the mlog. The query results of a real-time materialized view are obtained by simulating the mlog to merge the results of the underlying materialized view and itself. Therefore, you must perform incremental refresh on the underlying materialized view to update the mlog to ensure that the data of the real-time materialized view is up-to-date.
Here is an example:
Create a table named
tbl3as the base table for the materialized view. The following example creates thetbl3table:CREATE TABLE tbl3(id INT, name VARCHAR2(30), PRIMARY KEY(id));Create a table named
tbl4as the base table for the materialized view. The following example creates thetbl4table:CREATE TABLE tbl4(id INT, age INT, PRIMARY KEY(id));Create a materialized view named
mv1_tbl3_tbl4based on thetbl3andtbl4tables. The following example creates themv1_tbl3_tbl4materialized view:CREATE MATERIALIZED VIEW mv1_tbl3_tbl4 (PRIMARY KEY (id1, id2)) REFRESH COMPLETE AS SELECT tbl3.id id1, tbl4.id id2, tbl3.name, tbl4.age FROM tbl3, tbl4 WHERE tbl3.id = tbl4.id;Create a materialized view named
mv_mv1_tbl3_tbl4based on themv1_tbl3_tbl4materialized view. The following example creates themv_mv1_tbl3_tbl4materialized view:CREATE MATERIALIZED VIEW mv_mv1_tbl3_tbl4 REFRESH COMPLETE AS SELECT SUM(AGE) age_sum FROM mv1_tbl3_tbl4;Create a materialized view named
mv1_mv1_tbl3_tbl4based on themv1_tbl3_tbl4materialized view. The refresh strategy is set toINCONSISTENT. The following example creates themv1_mv1_tbl3_tbl4materialized view:CREATE MATERIALIZED VIEW mv1_mv1_tbl3_tbl4 REFRESH COMPLETE INCONSISTENT AS SELECT SUM(AGE) age_sum FROM mv1_tbl3_tbl4;
Create a real-time materialized view
To create a real-time materialized view, specify the ENABLE ON QUERY COMPUTATION clause.
Notice
In OceanBase Database in Oracle mode, when you create a real-time materialized view, you must also specify the refresh method (refresh_clause).
Considerations
Before you create a real-time materialized view, you must create a materialized view log for each base table that is referenced by the materialized view.
Note
For OceanBase Database V4.3.5, the automatic management of materialized view logs is supported starting from V4.3.5 BP4. If you enable automatic management of materialized view logs, you do not need to create materialized view logs for base tables before you create a real-time materialized view. OceanBase Database automatically creates materialized view logs or updates the definitions of existing materialized view logs to include the columns required by the new real-time materialized view. For more information, see Automatic management of materialized view logs.
Only specific types of materialized views can be specified as real-time materialized views. If you specify a materialized view that does not meet the requirements as a real-time materialized view, an error is returned. The requirements for a real-time materialized view are the same as those for an incrementally refreshed materialized view. For more information, see the Basic requirements for incremental refresh section in Refresh a materialized view.
If a materialized view (nested materialized view) is a real-time materialized view, you must incrementally refresh the lower-level materialized view to update the materialized view log (mlog). The query results of a real-time materialized view are obtained by simulating the mlog and merging the query results of the lower-level materialized view and itself. Therefore, you must incrementally refresh the lower-level materialized view to update the mlog, so that the data of the real-time materialized view is the latest.
Here is an example:
Create a table named
tbl2as the base table of the materialized view.CREATE TABLE tbl2(col1 INT, col2 INT, col3 INT);Create a materialized view log on the
tbl2table.CREATE MATERIALIZED VIEW LOG ON tbl2 WITH PRIMARY KEY, ROWID, SEQUENCE (col1, col2, col3) INCLUDING NEW VALUES;Create a real-time materialized view named
mv_tbl2based on thetbl2table.CREATE MATERIALIZED VIEW mv_tbl2 REFRESH COMPLETE ON DEMAND ENABLE ON QUERY COMPUTATION AS SELECT col1, count(*) AS cnt FROM tbl2 GROUP BY col1;After you create the real-time materialized view, you can view the materialized view in the DBA_MVIEWS view to check whether it is a real-time materialized view.
SELECT MVIEW_NAME, ON_QUERY_COMPUTATION FROM sys.DBA_MVIEWS WHERE MVIEW_NAME = 'MV_TBL2';Notice
In Oracle mode, when the value of the
MVIEW_NAMEfield in thesys.DBA_MVIEWSview matches the name of a table, the table name must be in uppercase.The returned result is as follows:
+------------+----------------------+ | MVIEW_NAME | ON_QUERY_COMPUTATION | +------------+----------------------+ | MV_TBL2 | Y | +------------+----------------------+ 1 row in setView the execution plan of the real-time materialized view.
EXPLAIN BASIC SELECT * FROM mv_tbl2;From the following execution plan, you can see that data is read from the materialized view and the mlog of the base table referenced by the view during execution. The two parts of data are calculated and integrated to obtain the real-time data of the materialized view.
The returned result is as follows:
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Query Plan | +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | ============================================== | | |ID|OPERATOR |NAME | | | ---------------------------------------------- | | |0 |HASH GROUP BY | | | | |1 |└─SUBPLAN SCAN |INNER_RT_MV$$| | | |2 | └─UNION ALL | | | | |3 | ├─TABLE FULL SCAN |MV_TBL2 | | | |4 | └─HASH GROUP BY | | | | |5 | └─SUBPLAN SCAN |DLT_T$$ | | | |6 | └─WINDOW FUNCTION | | | | |7 | └─TABLE FULL SCAN|MLOG$_TBL2 | | | ============================================== | | Outputs & filters: | | ------------------------------------- | | 0 - output([INNER_RT_MV$$.COL1], [cast(T_FUN_SUM(INNER_RT_MV$$.CNT), NUMBER(38, 0))]), filter([T_FUN_SUM(INNER_RT_MV$$.CNT) > cast(0, NUMBER(-1, -85))]), rowset=16 | | group([INNER_RT_MV$$.COL1]), agg_func([T_FUN_SUM(INNER_RT_MV$$.CNT)]) | | 1 - output([INNER_RT_MV$$.COL1], [INNER_RT_MV$$.CNT]), filter(nil), rowset=16 | | access([INNER_RT_MV$$.COL1], [INNER_RT_MV$$.CNT]) | | 2 - output([UNION([1])], [UNION([2])]), filter(nil), rowset=16 | | 3 - output([MV_TBL2.COL1], [MV_TBL2.CNT]), filter(nil), rowset=16 | | access([MV_TBL2.COL1], [MV_TBL2.CNT]), partitions(p0) | | is_index_back=false, is_global_index=false, | | range_key([MV_TBL2.__pk_increment]), range(MIN ; MAX)always true | | 4 - output([DLT_T$$.COL1], [T_FUN_SUM(CASE WHEN DLT_T$$.OLD_NEW$$ = cast('N', VARCHAR2(1048576 )) THEN cast(1, NUMBER(-1, -85)) ELSE (T_OP_NEG, cast(1, | | NUMBER(-1, -85))) END)]), filter(nil), rowset=16 | | group([DLT_T$$.COL1]), agg_func([T_FUN_SUM(CASE WHEN DLT_T$$.OLD_NEW$$ = cast('N', VARCHAR2(1048576 )) THEN cast(1, NUMBER(-1, -85)) ELSE (T_OP_NEG, | | cast(1, NUMBER(-1, -85))) END)]) | | 5 - output([DLT_T$$.OLD_NEW$$], [DLT_T$$.COL1]), filter([DLT_T$$.OLD_NEW$$ = cast('N', VARCHAR2(1048576 )) AND DLT_T$$.SEQUENCE$$ = DLT_T$$.MAXSEQ$$ OR | | DLT_T$$.OLD_NEW$$ = cast('O', VARCHAR2(1048576 )) AND DLT_T$$.SEQUENCE$$ = DLT_T$$.MINSEQ$$]), rowset=16 | | access([DLT_T$$.OLD_NEW$$], [DLT_T$$.SEQUENCE$$], [DLT_T$$.MAXSEQ$$], [DLT_T$$.MINSEQ$$], [DLT_T$$.COL1]) | | 6 - output([MLOG$_TBL2.OLD_NEW$$], [MLOG$_TBL2.SEQUENCE$$], [T_FUN_MAX(MLOG$_TBL2.SEQUENCE$$)], [T_FUN_MIN(MLOG$_TBL2.SEQUENCE$$)], [MLOG$_TBL2.COL1]), filter(nil), rowset=16 | | win_expr(T_FUN_MAX(MLOG$_TBL2.SEQUENCE$$)), partition_by([MLOG$_TBL2.M_ROW$$]), order_by(nil), window_type(RANGE), upper(UNBOUNDED PRECEDING), lower(UNBOUNDED | | FOLLOWING) | | win_expr(T_FUN_MIN(MLOG$_TBL2.SEQUENCE$$)), partition_by([MLOG$_TBL2.M_ROW$$]), order_by(nil), window_type(RANGE), upper(UNBOUNDED PRECEDING), lower(UNBOUNDED | | FOLLOWING) | | 7 - output([MLOG$_TBL2.M_ROW$$], [MLOG$_TBL2.SEQUENCE$$], [MLOG$_TBL2.OLD_NEW$$], [MLOG$_TBL2.COL1], [ORA_ROWSCN]), filter([cast(ORA_ROWSCN, NUMBER(-1, | | -1)) > last_refresh_scn(500155)]), rowset=16 | | access([MLOG$_TBL2.M_ROW$$], [MLOG$_TBL2.SEQUENCE$$], [MLOG$_TBL2.OLD_NEW$$], [MLOG$_TBL2.COL1], [ORA_ROWSCN]), partitions(p0) | | is_index_back=false, is_global_index=false, filter_before_indexback[false], | | range_key([MLOG$_TBL2.M_ROW$$], [MLOG$_TBL2.SEQUENCE$$]), range(MIN,MIN ; MAX,MAX)always true | +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ 40 rows in set
Create a materialized view that enables query rewrite
When you create a materialized view, you can specify the ENABLE QUERY REWRITE clause to enable automatic query rewrite for the materialized view. For more information about query rewrite and rewrite control, see Query rewrite of materialized views.
Notice
Specifying the ENABLE QUERY REWRITE clause for a materialized view does not guarantee that the query will be rewritten. If the query rewrite conditions are not met, the query will not be rewritten, and no error will be returned. By default, the system variable query_rewrite_enabled is set to false, so materialized views defined with the ENABLE QUERY REWRITE clause will not be used for query rewrite.
Here is an example:
Create a materialized view named
mv_spj_tbl1based on thetbl1table and enable automatic query rewrite for the materialized view.CREATE MATERIALIZED VIEW mv_spj_tbl1 NEVER REFRESH ENABLE QUERY REWRITE AS SELECT * FROM tbl1;After the materialized view is created, you can query the DBA_MVIEWS view to check whether automatic query rewrite is enabled for the materialized view.
SELECT MVIEW_NAME, REWRITE_ENABLED FROM sys.DBA_MVIEWS WHERE MVIEW_NAME = 'MV_SPJ_TBL1';Notice
In Oracle mode, when the
sys.DBA_MVIEWSview'sMVIEW_NAMEfield matches the table name, the table name must be in uppercase.The return result is as follows:
+-------------+-----------------+ | MVIEW_NAME | REWRITE_ENABLED | +-------------+-----------------+ | MV_SPJ_TBL1 | Y | +-------------+-----------------+ 1 row in set
Create a columnstore materialized view
OceanBase Database supports materialized views in rowstore, columnstore, and rowstore-columnstore redundant formats. You can specify the mv_column_group_option option to explicitly create a columnstore or rowstore-columnstore redundant materialized view. If a materialized view is a wide table formed by joining multiple tables, creating a columnstore materialized view can improve the performance of some queries. You can specify WITH COLUMN GROUP(each column) to create a columnstore materialized view.
Note
If you do not specify the mv_column_group_option option, a rowstore materialized view is created by default.
Here is an example:
Create a columnstore materialized view named mv_ec_tbl1 based on the tbl1 table.
CREATE MATERIALIZED VIEW mv_ec_tbl1
WITH COLUMN GROUP(each column)
AS SELECT *
FROM tbl1;
Add a primary key when you create a materialized view
Notice
If you specify a primary key for a materialized view, the view maintenance fails if the data does not meet the primary key constraints.
Here is an example:
Create a materialized view named mv_pk_tbl1 based on the tbl1 table and specify a primary key for the view.
CREATE MATERIALIZED VIEW mv_pk_tbl1(v_id, v_name, PRIMARY KEY(v_id))
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;
Add table options and partitioning options when you create a materialized view
When you create a materialized view, you can set table options and design and configure suitable partitioning options based on the data characteristics and access patterns to improve query performance and management efficiency.
For more information about the table options and partitioning options, see CREATE TABLE.
Here is an example:
Create a materialized view named mv_pp_tbl1 based on the tbl1 table. Set the parallelism of the materialized view to 5, and hash partition the materialized view by the col1 column into 8 partitions. Query the records in the tbl1 table that satisfy the condition col3 >= 20 as the base table, and use the query results as the data of the materialized view.
CREATE MATERIALIZED VIEW mv_pp_tbl1
PARALLEL 5
PARTITION BY HASH(col1) PARTITIONS 8
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;
Add an index to a materialized view
You cannot directly create an index in the statement for creating a materialized view. You can use the CREATE INDEX statement to create an index for a materialized view.
Here is an example:
Create an index named idx_mv_tbl1 on the col1 column of the materialized view mv_tbl1.
CREATE INDEX idx_mv_tbl1 ON mv_tbl1(col1);
Refresh a materialized view
OceanBase Database supports the following refresh strategies for materialized views: full refresh, incremental refresh, hybrid refresh, and no refresh.
- Full refresh: Recomputes all data in the materialized view to ensure that the data in the view is consistent with the source table.
- Incremental refresh: Refreshes only the data that is affected by changes in the source table, without recomputing the entire view.
- Hybrid refresh: The default option. First, it attempts an incremental refresh. If the incremental refresh fails, it performs a full refresh.
- No refresh: The materialized view is refreshed only when it is created and cannot be refreshed again after creation.
For more information about how to refresh a materialized view, see Refresh a materialized view.
Create a materialized view with a complete refresh strategy
When you create a materialized view, you can use the REFRESH COMPLETE clause to set the refresh strategy to complete refresh.
Notice
If a materialized view is completely refreshed, the dependent materialized views (nested materialized views) must also be completely refreshed before they can be incrementally refreshed. Otherwise, an error will be reported.
Here is an example:
Create a materialized view named mv_rc_tbl1 based on table tbl1, set the refresh strategy to complete refresh (REFRESH COMPLETE), and specify col1 and col2 as the data source of the materialized view, which are selected from tbl1 where col3 is greater than or equal to 20.
CREATE MATERIALIZED VIEW mv_rc_tbl1
REFRESH COMPLETE
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;
Create a materialized view with a complete refresh strategy based on an external table
OceanBase Database V4.3.5 BP2 and later allow you to create a materialized view with a complete refresh strategy based on an external table.
For more information about external tables, see About external tables.
Here is an example:
Notice
The IP address in the example has been desensitized. When you verify, replace it with the actual IP address of your machine.
The following example shows how to create an external table in the local file system and in the Oracle mode of OceanBase Database. The steps are as follows:
Prepare an external file.
Execute the following command to create a file named
ext_tbl1.csvin the/home/admin/external_csvdirectory on the server where the OBServer node is located.[admin@xxx /home/admin/external_csv]# vi ext_tbl1.csvThe content of the file is as follows:
1,'A1' 2,'A2' 3,'A3'Set the import file path.
Notice
Due to security reasons, you can only modify the
secure_file_privsystem variable by executing an SQL statement through a local Unix socket. For more information, see secure_file_priv.Execute the following command to log in to the server where the OBServer node is located.
ssh admin@10.10.10.1Execute the following command to connect to the
oracle001tenant through a local Unix socket.obclient -S /home/admin/oceanbase/run/sql.sock -usys@oracle001 -p******Execute the following SQL statement to set the import path to
/home/admin/external_csv.SET GLOBAL secure_file_priv = "/home/admin/external_csv";
Reconnect to the
oracle001tenant.Here is an example:
obclient -h10.10.10.1 -P2881 -usys@oracle001 -p****** -ACreate an external table named
ext_tbl1.CREATE EXTERNAL TABLE ext_tbl1 ( id INT, name VARCHAR2(50) ) LOCATION = '/home/admin/external_csv' FORMAT = ( TYPE = 'CSV' FIELD_DELIMITER = ',' FIELD_OPTIONALLY_ENCLOSED_BY ='''' ) PATTERN = 'ext_tbl1.csv';Create a materialized view named
mv_ext_tbl1with a complete refresh strategy based on the external tableext_tbl1.CREATE MATERIALIZED VIEW mv_ext_tbl1 REFRESH COMPLETE AS SELECT * FROM ext_tbl1;Query the data in the materialized view
mv_ext_tbl1.SELECT * FROM mv_ext_tbl1;The return result is as follows:
+------+------+ | ID | NAME | +------+------+ | 2 | A2 | | 1 | A1 | | 3 | A3 | +------+------+ 3 rows in set
Create a materialized view with incremental refresh
When you create a materialized view, you can use the REFRESH FAST clause to set the refresh strategy to incremental refresh.
Considerations
At present, incremental refresh is supported for materialized views that are created based on the following SQL statements: non-aggregated single-table statements, aggregated single-table statements, multi-table join statements, aggregated multi-table join statements, and
UNION ALLstatements. For SQL statements that do not fall into these five categories, incremental refresh is not supported. For more information about the requirements for incremental refresh, see the Incremental refresh section in Refresh a materialized view.Note
For OceanBase Database V4.3.5, incremental refresh for single-table non-aggregated and `UNION ALL` statements is supported starting from V4.3.5 BP3.
The
REFRESH FASTmethod uses the records in the materialized view log to determine what needs to be incrementally refreshed. Therefore, when you use incremental refresh to refresh a materialized view, you must create the materialized view log for the base table before you create the materialized view. For more information, see Materialized view log.Note
For V4.3.5, the automatic management of materialized view logs is supported starting from V4.3.5 BP4. If automatic management of materialized view logs is enabled, you do not need to create the materialized view log for the base table before you create an incremental refresh materialized view. OceanBase Database automatically creates the corresponding materialized view log or updates the existing materialized view log table definition to include the columns required by the new materialized view. For more information, see Automatic management of materialized view logs.
When you create a materialized view, you can add the
AS OF PROCTIME()clause to the base table. If you useAS OF PROCTIME()in a location other than the base table, an error is returned.The
AS OF PROCTIME()clause specifies to skip the refresh of the table during incremental refresh, thereby accelerating the incremental refresh of the materialized view. You do not need to create a materialized view log for the table specified byAS OF PROCTIME(). If you want to use an alias for the table, you must specify the alias after theAS OF PROCTIME()clause.Note
For OceanBase Database V4.3.5, you can add the
AS OF PROCTIME()clause to the base table when you create a materialized view starting from V4.3.5 BP4.When you use a standard view declared as a dimension table (
AS OF PROCTIME()) as the base table of an incremental refresh materialized view, the following limitations apply:- Not all tables in the materialized view can be dimension tables, just like the base table.
Note
For OceanBase Database V4.3.5, you can use a standard view declared as a dimension table (
AS OF PROCTIME()) as the base table of an incremental refresh materialized view starting from V4.3.5 BP5.
Here is an example:
Create a table named
tbl5as the base table of the materialized view.CREATE TABLE tbl5 (col1 INT PRIMARY KEY, col2 INT, col3 INT);Create a materialized view log on the
tbl5table. Specify theSEQUENCEoption for the materialized view log, which indicates that the changes are identified by sequence numbers. Specify thecol2andcol3columns to be recorded.CREATE MATERIALIZED VIEW LOG ON tbl5 WITH SEQUENCE (col2, col3) INCLUDING NEW VALUES;Create a materialized view named
mv_tbl5based on thetbl5table. Specify the incremental refresh strategy (REFRESH FAST) for the materialized view. In the query part, specify to group the records by thecol2column and calculate the number of records in each group (cnt), the number of non-null records in thecol3column (cnt_col3), and the sum of thecol3column (sum_col3) as the result of the materialized view.CREATE MATERIALIZED VIEW mv_tbl5 REFRESH FAST AS SELECT col2, COUNT(*) cnt, COUNT(col3) cnt_col3, SUM(col3) sum_col3 FROM tbl5 GROUP BY col2;Create a materialized view named
mv2_tbl5_tbl1based on thetbl5andtbl1tables. Specify the incremental refresh strategy for the materialized view. Join the tables by using thecol1field. UseAS OF PROCTIME()to specify that thetbl1table is skipped during the incremental refresh of the materialized view.CREATE MATERIALIZED VIEW mv2_tbl5_tbl1 REFRESH FAST ON DEMAND AS SELECT t5.col1 tbl5_c1, t1.col1 tbl1_c1, t5.col2 tbl5_c2, t1.col2 tbl1_c2 FROM tbl5 t5 INNER JOIN tbl1 AS OF PROCTIME() t1 ON t5.col1 = t1.col1 WHERE t5.col2 = 3;Create an incremental refresh materialized view based on a standard view that is declared as a dimension table (
AS OF PROCTIME()).Create a view named
v1_tbl5based on thetbl5table.obclient> CREATE VIEW v1_tbl5 AS SELECT * FROM tbl5;Create a materialized view named
mv3_tbl5_v_tbl5based on thetbl5andv1_tbl5tables. Specify the incremental refresh strategy for the materialized view. Join the tables by using thecol1field. UseAS OF PROCTIME()to specify that thev1_tbl5view is a dimension table.obclient> CREATE MATERIALIZED VIEW mv3_tbl5_v_tbl5 AS SELECT a.col1 a_c1, b.col1 b_c1 FROM tbl5 a JOIN v1_tbl5 AS OF PROCTIME() b ON a.col1 = b.col1;
Create a materialized view with a mixed refresh strategy (default)
When you create a materialized view, you can omit or specify the REFRESH FORCE clause to set the refresh strategy to mixed refresh.
Here is an example:
Create a materialized view named mv_rf_tbl1 based on table tbl1, set the refresh strategy to mixed refresh (REFRESH FORCE), and specify that the data source of the materialized view consists of the col1 and col2 columns of the rows in tbl1 where col3 is greater than or equal to 20.
CREATE MATERIALIZED VIEW mv_rf_tbl1
REFRESH FORCE
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;
Create a materialized view that never refreshes
When you create a materialized view, you can use the NEVER REFRESH clause to set the refresh strategy to never refresh. This means that the materialized view is only refreshed when it is created and cannot be refreshed again after creation.
Here is an example:
Create a materialized view named mv_nr_tbl1 based on table tbl1, set the refresh strategy to never refresh (NEVER REFRESH), and specify that the data source of the materialized view consists of the col1 and col2 columns of the rows in tbl1 where col3 is greater than or equal to 20.
CREATE MATERIALIZED VIEW mv_nr_tbl1
NEVER REFRESH
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;
Create a materialized view with an automatic refresh schedule
When you create a materialized view, you can specify the START WITH datetime_expr and NEXT datetime_expr clauses to create a background automatic refresh task for the materialized view.
Notice
If you use the NEXT clause, the time expression in the refresh schedule must be set to a future date or time, otherwise an error will be returned.
Here is an example:
Create a materialized view named mv_rc_swn_tbl1 based on the tbl1 table. Set the refresh strategy of the materialized view to complete refresh. Set the initial refresh time to the current date and time, and set the refresh interval to 1 hour.
CREATE MATERIALIZED VIEW mv_rc_swn_tbl1
REFRESH COMPLETE
START WITH current_date NEXT current_date + INTERVAL '1' HOUR
AS SELECT col1, col2
FROM tbl1
WHERE col3 >= 20;