Defines a new view.
CREATE [OR REPLACE] [TEMP | TEMPORARY] [RECURSIVE] VIEW <name> [ ( <column_name> [, ...] ) ]
[ WITH ( view_option_name [= view_option_value] [, ... ] ) ]
AS <query>
[ WITH [ CASCADED | LOCAL ] CHECK OPTION ]
CREATE VIEW
defines a view of a query. The view is not physically materialized. Instead, the query is run every time the view is referenced in a query.
CREATE OR REPLACE VIEW
is similar, but if a view of the same name already exists, it is replaced. The new query must generate the same columns that were generated by the existing view query (that is, the same column names in the same order, and with the same data types), but it may add additional columns to the end of the list. The calculations giving rise to the output columns may be completely different.
If a schema name is given then the view is created in the specified schema. Otherwise it is created in the current schema. Temporary views exist in a special schema, so a schema name may not be given when creating a temporary view. The name of the view must be distinct from the name of any other view, table, sequence, index or foreign table in the same schema.
TEMPORARY
is specified or not).
Creates a recursive view. The syntax
CREATE RECURSIVE VIEW [ <schema> . ] <view_name> (<column_names>) AS SELECT <...>;
is equivalent to
CREATE VIEW [ <schema> . ] <view_name> AS WITH RECURSIVE <view_name> (<column_names>) AS (SELECT <...>) SELECT <column_names> FROM <view_name>;
A view column name list must be specified for a recursive view.
view_option_name
[=
view_option_value
] [, ... ] )
This clause specifies optional parameters for a view; the following parameters are supported:
check_option
(string)
local
or
cascaded
, and is equivalent to specifying
WITH [ CASCADED | LOCAL ] CHECK OPTION
(see below). This option can be changed on existing views using
ALTER VIEW.
security_barrier
(boolean)
Views in Greenplum Database are read only. The system will not allow an insert, update, or delete on a view. You can get the effect of an updatable view by creating rewrite rules on the view into appropriate actions on other tables. For more information see CREATE RULE
.
Be careful that the names and data types of the view's columns will be assigned the way you want. For example:
CREATE VIEW vista AS SELECT 'Hello World';
is bad form in two ways: the column name defaults to ?column?
, and the column data type defaults to unknown
. If you want a string literal in a view's result, use something like:
CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
Access to tables referenced in the view is determined by permissions of the view owner not the current user (even if the current user is a superuser). This can be confusing in the case of superusers, since superusers typically have access to all objects. In the case of a view, even superusers must be explicitly granted access to tables referenced in the view if they are not the owner of the view.
However, functions called in the view are treated the same as if they had been called directly from the query using the view. Therefore the user of a view must have permissions to call any functions used by the view.
If you create a view with an ORDER BY
clause, the ORDER BY
clause is ignored when you do a SELECT
from the view.
When CREATE OR REPLACE VIEW
is used on an existing view, only the view's defining SELECT
rule is changed. Other view properties, including ownership, permissions, and non-SELECT
rules, remain unchanged. You must own the view to replace it (this includes being a member of the owning role).
Create a view consisting of all comedy films:
CREATE VIEW comedies AS SELECT * FROM films
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 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:
CREATE VIEW topten AS SELECT name, rank, gender, year FROM
names, rank WHERE rank < '11' AND names.id=rank.id;
Create a recursive view consisting of the numbers from 1 to 100:
CREATE RECURSIVE VIEW public.nums_1_100 (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums_1_100 WHERE n < 100;
Notice that although the recursive view's name is schema-qualified in this CREATE VIEW
command, its internal self-reference is not schema-qualified. This is because the implicitly-created CTE's name cannot be schema-qualified.
The SQL standard specifies some additional capabilities for the CREATE VIEW
statement that are not in Greenplum Database. The optional clauses for the full SQL command in the standard are:
INSERT
and UPDATE
commands on the view will be checked to ensure data satisfy the view-defining condition (that is, the new data would be visible through the view). If they do not, the update will be rejected.CASCADED
is assumed if neither CASCADED
nor LOCAL
is specified.CREATE OR REPLACE VIEW
is a Greenplum Database language extension. So is the concept of a temporary view.
SELECT, DROP VIEW, CREATE MATERIALIZED VIEW
Parent topic: SQL Commands