1CREATE VIEW(7)           PostgreSQL 14.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 (enum)
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.
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       query
78           A SELECT or VALUES command which will provide the columns and rows
79           of the view.
80
81       WITH [ CASCADED | LOCAL ] CHECK OPTION
82           This option controls the behavior of automatically updatable views.
83           When this option is specified, INSERT and UPDATE commands on the
84           view will be checked to ensure that new rows satisfy the
85           view-defining condition (that is, the new rows are checked to
86           ensure that they are visible through the view). If they are not,
87           the update will be rejected. If the CHECK OPTION is not specified,
88           INSERT and UPDATE commands on the view are allowed to create rows
89           that are not visible through the view. The following check options
90           are supported:
91
92           LOCAL
93               New rows are only checked against the conditions defined
94               directly in the view itself. Any conditions defined on
95               underlying base views are not checked (unless they also specify
96               the CHECK OPTION).
97
98           CASCADED
99               New rows are checked against the conditions of the view and all
100               underlying base views. If the CHECK OPTION is specified, and
101               neither LOCAL nor CASCADED is specified, then CASCADED is
102               assumed.
103
104           The CHECK OPTION may not be used with RECURSIVE views.
105
106           Note that the CHECK OPTION is only supported on views that are
107           automatically updatable, and do not have INSTEAD OF triggers or
108           INSTEAD rules. If an automatically updatable view is defined on top
109           of a base view that has INSTEAD OF triggers, then the LOCAL CHECK
110           OPTION may be used to check the conditions on the automatically
111           updatable view, but the conditions on the base view with INSTEAD OF
112           triggers will not be checked (a cascaded check option will not
113           cascade down to a trigger-updatable view, and any check options
114           defined directly on a trigger-updatable view will be ignored). If
115           the view or any of its base relations has an INSTEAD rule that
116           causes the INSERT or UPDATE command to be rewritten, then all check
117           options will be ignored in the rewritten query, including any
118           checks from automatically updatable views defined on top of the
119           relation with the INSTEAD rule.
120

NOTES

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

EXAMPLES

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

COMPATIBILITY

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

SEE ALSO

285       ALTER VIEW (ALTER_VIEW(7)), DROP VIEW (DROP_VIEW(7)), CREATE
286       MATERIALIZED VIEW (CREATE_MATERIALIZED_VIEW(7))
287
288
289
290PostgreSQL 14.3                      2022                       CREATE VIEW(7)
Impressum