Defines a new materialized view.

Synopsis

  1. CREATE MATERIALIZED VIEW <table_name>
  2. [ (<column_name> [, ...] ) ]
  3. [ WITH ( <storage_parameter> [= <value>] [, ... ] ) ]
  4. [ TABLESPACE <tablespace_name> ]
  5. AS <query>
  6. [ WITH [ NO ] DATA ]
  7. [DISTRIBUTED {| BY <column> [<opclass>], [ ... ] | RANDOMLY | REPLICATED }]

Description

CREATE MATERIALIZED VIEW defines a materialized view of a query. The query is run and used to populate the view at the time the command is issued (unless WITH NO DATA is used) and can be refreshed using REFRESH MATERIALIZED VIEW.

CREATE MATERIALIZED VIEW is similar to CREATE TABLE AS, except that it also remembers the query used to initialize the view, so that it can be refreshed later upon demand. To refresh materialized view data, use the REFRESH MATERIALIZED VIEW command. A materialized view has many of the same properties as a table, but there is no support for temporary materialized views or automatic generation of OIDs.

Parameters

table_name

The name (optionally schema-qualified) of the materialized view to be created.

column_name

The name of a column in the materialized view. The column names are assigned based on position. The first column name is assigned to the first column of the query result, and so on. If a column name is not provided, it is taken from the output column names of the query.

WITH ( storage_parameter [= value] [, … ] )

This clause specifies optional storage parameters for the materialized view. All parameters supported for CREATE TABLE are also supported for CREATE MATERIALIZED VIEW with the exception of OIDS. See CREATE TABLE for more information.

TABLESPACE tablespace_name

The tablespace_name is the name of the tablespace in which the new materialized view is to be created. If not specified, server configuration parameter default_tablespace is consulted.

query

A SELECT or VALUES command. This query will run within a security-restricted operation; in particular, calls to functions that themselves create temporary tables will fail.

WITH [ NO ] DATA

This clause specifies whether or not the materialized view should be populated with data at creation time. WITH DATA is the default, populate the materialized view. For WITH NO DATA, the materialized view is not populated with data, is flagged as unscannable, and cannot be queried until REFRESH MATERIALIZED VIEW is used to populate the materialized view. An error is returned if a query attempts to access an unscannable materialized view.

DISTRIBUTED BY (column [opclass], [ … ] )

DISTRIBUTED RANDOMLY

DISTRIBUTED REPLICATED

Used to declare the Greenplum Database distribution policy for the materialized view data. For information about a table distribution policy, see CREATE TABLE.

Notes

Materialized views are read only. The system will not allow an INSERT, UPDATE, or DELETE on a materialized view. Use REFRESH MATERIALIZED VIEW to update the materialized view data.

If you want the data to be ordered upon generation, you must use an ORDER BY clause in the materialized view query. However, if a materialized view query contains an ORDER BY or SORT clause, the data is not guaranteed to be ordered or sorted if SELECT is performed on the materialized view.

Examples

Create a view consisting of all comedy films:

  1. CREATE MATERIALIZED VIEW comedies AS SELECT * FROM films
  2. WHERE kind = 'comedy';

This will create a view containing the columns that are in the film table at the time of view creation. Though * was used to create the materialized view, columns added later to the table will not be part of the view.

Create a view that gets the top ten ranked baby names:

  1. CREATE MATERIALIZED VIEW topten AS SELECT name, rank, gender, year FROM
  2. names, rank WHERE rank < '11' AND names.id=rank.id;

Compatibility

CREATE MATERIALIZED VIEW is a Greenplum Database extension of the SQL standard.

See Also

SELECT, VALUES, CREATE VIEW, ALTER MATERIALIZED VIEW, DROP MATERIALIZED VIEW, REFRESH MATERIALIZED VIEW

Parent topic: SQL Commands