CREATE MATERIALIZED VIEW
CREATE MATERIALIZED VIEW creates a complete-refresh materialized view, and you can use REFRESH MATERIALIZED VIEW (full refresh) to refresh the data in the materialized view.
CREATE MATERIALIZED VIEW is similar to CREATE TABLE AS, but it remembers the query used to initialize the view, so it can refresh data later. A materialized view has many attributes that are the same as those of a table, but does not support temporary materialized views.
Precautions
- Complete-refresh materialized views cannot be created in temporary tables or global temporary tables.
- Complete-refresh materialized views do not support NodeGroups.
- After a complete-refresh materialized view is created, most DDL operations in the base table are no longer supported.
- IUD operations cannot be performed on complete-refresh materialized views.
- After a complete-refresh materialized view is created, if the base table data changes, you need to run the refresh command to synchronize the materialized view with the base table.
- The Ustore does not support the creation and use of materialized views.
- The segment-page does not support the creation and use of materialized views.
Syntax
CREATE MATERIALIZED VIEW mv_name [ (column_name [, ...] ) ] [ WITH ( {storage_parameter = value} [, ... ] ) ] [ TABLESPACE tablespace_name ] AS query [ WITH [ NO ] DATA ];
Parameters
- mv_name
Name (optionally schema-qualified) of the materialized view to be created.
Value range: a string. It must comply with the naming convention.
- column_name
Specifies a column name in the new materialized view. The materialized view supports specified columns. The number of specified columns must be the same as that of columns in the result of the subsequent query statement. If no column name is provided, the column name is obtained from the output column name of the query.
Value range: a string. It must comply with the naming convention.
- WITH ( storage_parameter [= value] [, ... ] )
Specifies an optional storage parameter for a table or an index. For details, see CREATE TABLE.
- TABLESPACE tablespace_name
Tablespace to which the new materialized view belongs. If the tablespace is not specified, the default tablespace is used.
- AS query
A SELECT, TABLE, or VALUES command. This query will be run in a security-constrained operation.
Examples
-- Change the default table type. gaussdb=# set enable_default_ustore_table=off; -- Create a tablespace. gaussdb=# CREATE TABLESPACE tbs_data1 RELATIVE LOCATION 'tablespace1/tbs_data1'; -- Create an ordinary table. gaussdb=# CREATE TABLE my_table (c1 int, c2 int); -- Create a complete-refresh materialized view. gaussdb=# CREATE MATERIALIZED VIEW my_mv TABLESPACE tbs_data1 AS SELECT * FROM my_table; -- Write data to the base table. gaussdb=# INSERT INTO my_table VALUES(1,1),(2,2); -- Query the complete-refresh materialized view. gaussdb=# SELECT * FROM my_mv; c1 | c2 ----+---- (0 rows) -- Completely refresh the complete-refresh materialized view my_mv. gaussdb=# REFRESH MATERIALIZED VIEW my_mv; -- Query the complete-refresh materialized view. gaussdb=# SELECT * FROM my_mv; c1 | c2 ----+---- 1 | 1 2 | 2 (2 rows) -- Delete the complete-refresh materialized view. gaussdb=# DROP MATERIALIZED VIEW my_mv; -- Delete the ordinary table my_table. gaussdb=# DROP TABLE my_table; -- Delete the tablespace. gaussdb=# DROP TABLESPACE tbs_data1;
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot