Provided by: postgresql-client-9.3_9.3.24-0ubuntu0.14.04_amd64 bug

NAME

       CREATE_VIEW - define a new view

SYNOPSIS

       CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW name [ ( column_name [, ...] ) ]
           [ WITH ( view_option_name [= view_option_value] [, ... ] ) ]
           AS query

DESCRIPTION

       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 (for example, CREATE VIEW myschema.myview ...) 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 cannot 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.

PARAMETERS

       TEMPORARY or TEMP
           If specified, the view is created as a temporary view. Temporary views are
           automatically dropped at the end of the current session. Existing permanent relations
           with the same name are not visible to the current session while the temporary view
           exists, unless they are referenced with schema-qualified names.

           If any of the tables referenced by the view are temporary, the view is created as a
           temporary view (whether TEMPORARY is specified or not).

       RECURSIVE
           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.

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

       column_name
           An optional list of names to be used for columns of the view. If not given, the column
           names are deduced from the query.

       WITH ( view_option_name [= view_option_value] [, ... ] )
           This clause specifies optional parameters for a view; currently, the only supported
           parameter name is security_barrier, which should be enabled when a view is intended to
           provide row-level security. See Section 38.5, “Rules and Privileges”, in the
           documentation for full details.

       query
           A SELECT(7) or VALUES(7) command which will provide the columns and rows of the view.

NOTES

       Use the DROP VIEW (DROP_VIEW(7)) statement to drop views.

       Be careful that the names and 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. In
       some cases, this can be used to provide secure but restricted access to the underlying
       tables. However, not all views are secure against tampering; see Section 38.5, “Rules and
       Privileges”, in the documentation for details. 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 all functions used by 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).

   Updatable Views
       Simple views are automatically updatable: the system will allow INSERT, UPDATE and DELETE
       statements to be used on the view in the same way as on a regular table. A view is
       automatically updatable if it satisfies all of the following conditions:

       •   The view must have exactly one entry in its FROM list, which must be a table or
           another updatable view.

       •   The view definition must not contain WITH, DISTINCT, GROUP BY, HAVING, LIMIT, or
           OFFSET clauses at the top level.

       •   The view definition must not contain set operations (UNION, INTERSECT or EXCEPT) at
           the top level.

       •   All columns in the view's select list must be simple references to columns of the
           underlying relation. They cannot be expressions, literals or functions. System columns
           cannot be referenced, either.

       •   No column of the underlying relation can appear more than once in the view's select
           list.

       •   The view must not have the security_barrier property.

       If the view is automatically updatable the system will convert any INSERT, UPDATE or
       DELETE statement on the view into the corresponding statement on the underlying base
       relation.

       If an automatically updatable view contains a WHERE condition, the condition restricts
       which rows of the base relation are available to be modified by UPDATE and DELETE
       statements on the view. However, an UPDATE is allowed to change a row so that it no longer
       satisfies the WHERE condition, and thus is no longer visible through the view. Similarly,
       an INSERT command can potentially insert base-relation rows that do not satisfy the WHERE
       condition and thus are not visible through the view.

       A more complex view that does not satisfy all these conditions is read-only by default:
       the system will not allow an insert, update, or delete on the view. You can get the effect
       of an updatable view by creating INSTEAD OF triggers on the view, which must convert
       attempted inserts, etc. on the view into appropriate actions on other tables. For more
       information see CREATE TRIGGER (CREATE_TRIGGER(7)). Another possibility is to create rules
       (see CREATE RULE (CREATE_RULE(7))), but in practice triggers are easier to understand and
       use correctly.

       Note that the user performing the insert, update or delete on the view must have the
       corresponding insert, update or delete privilege on the view. In addition the view's owner
       must have the relevant privileges on the underlying base relations, but the user
       performing the update does not need any permissions on the underlying base relations (see
       Section 38.5, “Rules and Privileges”, in the documentation).

EXAMPLES

       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 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, its
       internal self-reference is not schema-qualified. This is because the implicitly-created
       CTE's name cannot be schema-qualified.

COMPATIBILITY

       The SQL standard specifies some additional capabilities for the CREATE VIEW statement:

           CREATE VIEW name [ ( column_name [, ...] ) ]
               AS query
               [ WITH [ CASCADED | LOCAL ] CHECK OPTION ]

       The optional clauses for the full SQL command are:

       CHECK OPTION
           This option controls the behavior of automatically updatable views. When given, INSERT
           and UPDATE commands on the view will be checked to ensure new rows satisfy the
           view-defining condition (that is, the new rows would be visible through the view). If
           they do not, the update will be rejected. Without CHECK OPTION, INSERT and UPDATE
           commands on the view are allowed to create rows that are not visible through the view.
           (The latter behavior is the only one currently provided by PostgreSQL.)

       LOCAL
           Check for integrity on this view.

       CASCADED
           Check for integrity on this view and on any dependent view.  CASCADED is assumed if
           neither CASCADED nor LOCAL is specified.

       CREATE OR REPLACE VIEW is a PostgreSQL language extension. So is the concept of a
       temporary view. The WITH clause is an extension as well.

SEE ALSO

       ALTER VIEW (ALTER_VIEW(7)), DROP VIEW (DROP_VIEW(7)), CREATE MATERIALIZED VIEW
       (CREATE_MATERIALIZED_VIEW(7))