1CREATE VIEW(7)           PostgreSQL 11.3 Documentation          CREATE VIEW(7)
2
3
4

NAME

6       CREATE_VIEW - define a new view
7

SYNOPSIS

9       CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW name [ ( column_name [, ...] ) ]
10           [ WITH ( view_option_name [= view_option_value] [, ... ] ) ]
11           AS query
12           [ WITH [ CASCADED | LOCAL ] CHECK OPTION ]
13

DESCRIPTION

15       CREATE VIEW defines a view of a query. The view is not physically
16       materialized. Instead, the query is run every time the view is
17       referenced in a query.
18
19       CREATE OR REPLACE VIEW is similar, but if a view of the same name
20       already exists, it is replaced. The new query must generate the same
21       columns that were generated by the existing view query (that is, the
22       same column names in the same order and with the same data types), but
23       it may add additional columns to the end of the list. The calculations
24       giving rise to the output columns may be completely different.
25
26       If a schema name is given (for example, CREATE VIEW myschema.myview
27       ...) then the view is created in the specified schema. Otherwise it is
28       created in the current schema. Temporary views exist in a special
29       schema, so a schema name cannot be given when creating a temporary
30       view. The name of the view must be distinct from the name of any other
31       view, table, sequence, index or foreign table in the same schema.
32

PARAMETERS

34       TEMPORARY or TEMP
35           If specified, the view is created as a temporary view. Temporary
36           views are automatically dropped at the end of the current session.
37           Existing permanent relations with the same name are not visible to
38           the current session while the temporary view exists, unless they
39           are referenced with schema-qualified names.
40
41           If any of the tables referenced by the view are temporary, the view
42           is created as a temporary view (whether TEMPORARY is specified or
43           not).
44
45       RECURSIVE
46           Creates a recursive view. The syntax
47
48               CREATE RECURSIVE VIEW [ schema . ] view_name (column_names) AS SELECT ...;
49
50           is equivalent to
51
52               CREATE VIEW [ schema . ] view_name AS WITH RECURSIVE view_name (column_names) AS (SELECT ...) SELECT column_names FROM view_name;
53
54           A view column name list must be specified for a recursive view.
55
56       name
57           The name (optionally schema-qualified) of a view to be created.
58
59       column_name
60           An optional list of names to be used for columns of the view. If
61           not given, the column names are deduced from the query.
62
63       WITH ( view_option_name [= view_option_value] [, ... ] )
64           This clause specifies optional parameters for a view; the following
65           parameters are supported:
66
67           check_option (string)
68               This parameter may be either local or cascaded, and is
69               equivalent to specifying WITH [ CASCADED | LOCAL ] CHECK OPTION
70               (see below). This option can be changed on existing views using
71               ALTER VIEW (ALTER_VIEW(7)).
72
73           security_barrier (boolean)
74               This should be used if the view is intended to provide
75               row-level security. See Section 41.5 for full details.
76
77
78       query
79           A SELECT(7) or VALUES(7) command which will provide the columns and
80           rows of the view.
81
82       WITH [ CASCADED | LOCAL ] CHECK OPTION
83           This option controls the behavior of automatically updatable views.
84           When this option is specified, INSERT and UPDATE commands on the
85           view will be checked to ensure that new rows satisfy the
86           view-defining condition (that is, the new rows are checked to
87           ensure that they are visible through the view). If they are not,
88           the update will be rejected. If the CHECK OPTION is not specified,
89           INSERT and UPDATE commands on the view are allowed to create rows
90           that are not visible through the view. The following check options
91           are supported:
92
93           LOCAL
94               New rows are only checked against the conditions defined
95               directly in the view itself. Any conditions defined on
96               underlying base views are not checked (unless they also specify
97               the CHECK OPTION).
98
99           CASCADED
100               New rows are checked against the conditions of the view and all
101               underlying base views. If the CHECK OPTION is specified, and
102               neither LOCAL nor CASCADED is specified, then CASCADED is
103               assumed.
104
105           The CHECK OPTION may not be used with RECURSIVE views.
106
107           Note that the CHECK OPTION is only supported on views that are
108           automatically updatable, and do not have INSTEAD OF triggers or
109           INSTEAD rules. If an automatically updatable view is defined on top
110           of a base view that has INSTEAD OF triggers, then the LOCAL CHECK
111           OPTION may be used to check the conditions on the automatically
112           updatable view, but the conditions on the base view with INSTEAD OF
113           triggers will not be checked (a cascaded check option will not
114           cascade down to a trigger-updatable view, and any check options
115           defined directly on a trigger-updatable view will be ignored). If
116           the view or any of its base relations has an INSTEAD rule that
117           causes the INSERT or UPDATE command to be rewritten, then all check
118           options will be ignored in the rewritten query, including any
119           checks from automatically updatable views defined on top of the
120           relation with the INSTEAD rule.
121

NOTES

123       Use the DROP VIEW (DROP_VIEW(7)) statement to drop views.
124
125       Be careful that the names and types of the view's columns will be
126       assigned the way you want. For example:
127
128           CREATE VIEW vista AS SELECT 'Hello World';
129
130       is bad form because the column name defaults to ?column?; also, the
131       column data type defaults to text, which might not be what you wanted.
132       Better style for a string literal in a view's result is something like:
133
134           CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
135
136       Access to tables referenced in the view is determined by permissions of
137       the view owner. In some cases, this can be used to provide secure but
138       restricted access to the underlying tables. However, not all views are
139       secure against tampering; see Section 41.5 for details. Functions
140       called in the view are treated the same as if they had been called
141       directly from the query using the view. Therefore the user of a view
142       must have permissions to call all functions used by the view.
143
144       When CREATE OR REPLACE VIEW is used on an existing view, only the
145       view's defining SELECT rule is changed. Other view properties,
146       including ownership, permissions, and non-SELECT rules, remain
147       unchanged. You must own the view to replace it (this includes being a
148       member of the owning role).
149
150   Updatable Views
151       Simple views are automatically updatable: the system will allow INSERT,
152       UPDATE and DELETE statements to be used on the view in the same way as
153       on a regular table. A view is automatically updatable if it satisfies
154       all of the following conditions:
155
156       ·   The view must have exactly one entry in its FROM list, which must
157           be a table or another updatable view.
158
159       ·   The view definition must not contain WITH, DISTINCT, GROUP BY,
160           HAVING, LIMIT, or OFFSET clauses at the top level.
161
162       ·   The view definition must not contain set operations (UNION,
163           INTERSECT or EXCEPT) at the top level.
164
165       ·   The view's select list must not contain any aggregates, window
166           functions or set-returning functions.
167
168       An automatically updatable view may contain a mix of updatable and
169       non-updatable columns. A column is updatable if it is a simple
170       reference to an updatable column of the underlying base relation;
171       otherwise the column is read-only, and an error will be raised if an
172       INSERT or UPDATE statement attempts to assign a value to it.
173
174       If the view is automatically updatable the system will convert any
175       INSERT, UPDATE or DELETE statement on the view into the corresponding
176       statement on the underlying base relation.  INSERT statements that have
177       an ON CONFLICT UPDATE clause are fully supported.
178
179       If an automatically updatable view contains a WHERE condition, the
180       condition restricts which rows of the base relation are available to be
181       modified by UPDATE and DELETE statements on the view. However, an
182       UPDATE is allowed to change a row so that it no longer satisfies the
183       WHERE condition, and thus is no longer visible through the view.
184       Similarly, an INSERT command can potentially insert base-relation rows
185       that do not satisfy the WHERE condition and thus are not visible
186       through the view (ON CONFLICT UPDATE may similarly affect an existing
187       row not visible through the view). The CHECK OPTION may be used to
188       prevent INSERT and UPDATE commands from creating such rows that are not
189       visible through the view.
190
191       If an automatically updatable view is marked with the security_barrier
192       property then all the view's WHERE conditions (and any conditions using
193       operators which are marked as LEAKPROOF) will always be evaluated
194       before any conditions that a user of the view has added. See
195       Section 41.5 for full details. Note that, due to this, rows which are
196       not ultimately returned (because they do not pass the user's WHERE
197       conditions) may still end up being locked.  EXPLAIN can be used to see
198       which conditions are applied at the relation level (and therefore do
199       not lock rows) and which are not.
200
201       A more complex view that does not satisfy all these conditions is
202       read-only by default: the system will not allow an insert, update, or
203       delete on the view. You can get the effect of an updatable view by
204       creating INSTEAD OF triggers on the view, which must convert attempted
205       inserts, etc. on the view into appropriate actions on other tables. For
206       more information see CREATE TRIGGER (CREATE_TRIGGER(7)). Another
207       possibility is to create rules (see CREATE RULE (CREATE_RULE(7))), but
208       in practice triggers are easier to understand and use correctly.
209
210       Note that the user performing the insert, update or delete on the view
211       must have the corresponding insert, update or delete privilege on the
212       view. In addition the view's owner must have the relevant privileges on
213       the underlying base relations, but the user performing the update does
214       not need any permissions on the underlying base relations (see
215       Section 41.5).
216

EXAMPLES

218       Create a view consisting of all comedy films:
219
220           CREATE VIEW comedies AS
221               SELECT *
222               FROM films
223               WHERE kind = 'Comedy';
224
225       This will create a view containing the columns that are in the film
226       table at the time of view creation. Though * was used to create the
227       view, columns added later to the table will not be part of the view.
228
229       Create a view with LOCAL CHECK OPTION:
230
231           CREATE VIEW universal_comedies AS
232               SELECT *
233               FROM comedies
234               WHERE classification = 'U'
235               WITH LOCAL CHECK OPTION;
236
237       This will create a view based on the comedies view, showing only films
238       with kind = 'Comedy' and classification = 'U'. Any attempt to INSERT or
239       UPDATE a row in the view will be rejected if the new row doesn't have
240       classification = 'U', but the film kind will not be checked.
241
242       Create a view with CASCADED CHECK OPTION:
243
244           CREATE VIEW pg_comedies AS
245               SELECT *
246               FROM comedies
247               WHERE classification = 'PG'
248               WITH CASCADED CHECK OPTION;
249
250       This will create a view that checks both the kind and classification of
251       new rows.
252
253       Create a view with a mix of updatable and non-updatable columns:
254
255           CREATE VIEW comedies AS
256               SELECT f.*,
257                      country_code_to_name(f.country_code) AS country,
258                      (SELECT avg(r.rating)
259                       FROM user_ratings r
260                       WHERE r.film_id = f.id) AS avg_rating
261               FROM films f
262               WHERE f.kind = 'Comedy';
263
264       This view will support INSERT, UPDATE and DELETE. All the columns from
265       the films table will be updatable, whereas the computed columns country
266       and avg_rating will be read-only.
267
268       Create a recursive view consisting of the numbers from 1 to 100:
269
270           CREATE RECURSIVE VIEW public.nums_1_100 (n) AS
271               VALUES (1)
272           UNION ALL
273               SELECT n+1 FROM nums_1_100 WHERE n < 100;
274
275       Notice that although the recursive view's name is schema-qualified in
276       this CREATE, its internal self-reference is not schema-qualified. This
277       is because the implicitly-created CTE's name cannot be
278       schema-qualified.
279

COMPATIBILITY

281       CREATE OR REPLACE VIEW is a PostgreSQL language extension. So is the
282       concept of a temporary view. The WITH ( ... ) clause is an extension as
283       well.
284

SEE ALSO

286       ALTER VIEW (ALTER_VIEW(7)), DROP VIEW (DROP_VIEW(7)), CREATE
287       MATERIALIZED VIEW (CREATE_MATERIALIZED_VIEW(7))
288
289
290
291PostgreSQL 11.3                      2019                       CREATE VIEW(7)
Impressum