1CREATE VIEW(7) PostgreSQL 15.4 Documentation CREATE VIEW(7)
2
3
4
6 CREATE_VIEW - define a new view
7
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
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 relation (table, sequence, index, view, materialized view, or foreign
32 table) in the same schema.
33
35 TEMPORARY or TEMP
36 If specified, the view is created as a temporary view. Temporary
37 views are automatically dropped at the end of the current session.
38 Existing permanent relations with the same name are not visible to
39 the current session while the temporary view exists, unless they
40 are referenced with schema-qualified names.
41
42 If any of the tables referenced by the view are temporary, the view
43 is created as a temporary view (whether TEMPORARY is specified or
44 not).
45
46 RECURSIVE
47 Creates a recursive view. The syntax
48
49 CREATE RECURSIVE VIEW [ schema . ] view_name (column_names) AS SELECT ...;
50
51 is equivalent to
52
53 CREATE VIEW [ schema . ] view_name AS WITH RECURSIVE view_name (column_names) AS (SELECT ...) SELECT column_names FROM view_name;
54
55 A view column name list must be specified for a recursive view.
56
57 name
58 The name (optionally schema-qualified) of a view to be created.
59
60 column_name
61 An optional list of names to be used for columns of the view. If
62 not given, the column names are deduced from the query.
63
64 WITH ( view_option_name [= view_option_value] [, ... ] )
65 This clause specifies optional parameters for a view; the following
66 parameters are supported:
67
68 check_option (enum)
69 This parameter may be either local or cascaded, and is
70 equivalent to specifying WITH [ CASCADED | LOCAL ] CHECK OPTION
71 (see below).
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 security_invoker (boolean)
78 This option causes the underlying base relations to be checked
79 against the privileges of the user of the view rather than the
80 view owner. See the notes below for full details.
81
82 All of the above options can be changed on existing views using
83 ALTER VIEW.
84
85 query
86 A SELECT or VALUES command which will provide the columns and rows
87 of the view.
88
89 WITH [ CASCADED | LOCAL ] CHECK OPTION
90 This option controls the behavior of automatically updatable views.
91 When this option is specified, INSERT and UPDATE commands on the
92 view will be checked to ensure that new rows satisfy the
93 view-defining condition (that is, the new rows are checked to
94 ensure that they are visible through the view). If they are not,
95 the update will be rejected. If the CHECK OPTION is not specified,
96 INSERT and UPDATE commands on the view are allowed to create rows
97 that are not visible through the view. The following check options
98 are supported:
99
100 LOCAL
101 New rows are only checked against the conditions defined
102 directly in the view itself. Any conditions defined on
103 underlying base views are not checked (unless they also specify
104 the CHECK OPTION).
105
106 CASCADED
107 New rows are checked against the conditions of the view and all
108 underlying base views. If the CHECK OPTION is specified, and
109 neither LOCAL nor CASCADED is specified, then CASCADED is
110 assumed.
111
112 The CHECK OPTION may not be used with RECURSIVE views.
113
114 Note that the CHECK OPTION is only supported on views that are
115 automatically updatable, and do not have INSTEAD OF triggers or
116 INSTEAD rules. If an automatically updatable view is defined on top
117 of a base view that has INSTEAD OF triggers, then the LOCAL CHECK
118 OPTION may be used to check the conditions on the automatically
119 updatable view, but the conditions on the base view with INSTEAD OF
120 triggers will not be checked (a cascaded check option will not
121 cascade down to a trigger-updatable view, and any check options
122 defined directly on a trigger-updatable view will be ignored). If
123 the view or any of its base relations has an INSTEAD rule that
124 causes the INSERT or UPDATE command to be rewritten, then all check
125 options will be ignored in the rewritten query, including any
126 checks from automatically updatable views defined on top of the
127 relation with the INSTEAD rule.
128
130 Use the DROP VIEW statement to drop views.
131
132 Be careful that the names and types of the view's columns will be
133 assigned the way you want. For example:
134
135 CREATE VIEW vista AS SELECT 'Hello World';
136
137 is bad form because the column name defaults to ?column?; also, the
138 column data type defaults to text, which might not be what you wanted.
139 Better style for a string literal in a view's result is something like:
140
141 CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
142
143 By default, access to the underlying base relations referenced in the
144 view is determined by the permissions of the view owner. In some cases,
145 this can be used to provide secure but restricted access to the
146 underlying tables. However, not all views are secure against tampering;
147 see Section 41.5 for details.
148
149 If the view has the security_invoker property set to true, access to
150 the underlying base relations is determined by the permissions of the
151 user executing the query, rather than the view owner. Thus, the user of
152 a security invoker view must have the relevant permissions on the view
153 and its underlying base relations.
154
155 If any of the underlying base relations is a security invoker view, it
156 will be treated as if it had been accessed directly from the original
157 query. Thus, a security invoker view will always check its underlying
158 base relations using the permissions of the current user, even if it is
159 accessed from a view without the security_invoker property.
160
161 If any of the underlying base relations has row-level security enabled,
162 then by default, the row-level security policies of the view owner are
163 applied, and access to any additional relations referred to by those
164 policies is determined by the permissions of the view owner. However,
165 if the view has security_invoker set to true, then the policies and
166 permissions of the invoking user are used instead, as if the base
167 relations had been referenced directly from the query using the view.
168
169 Functions called in the view are treated the same as if they had been
170 called directly from the query using the view. Therefore, the user of a
171 view must have permissions to call all functions used by the view.
172 Functions in the view are executed with the privileges of the user
173 executing the query or the function owner, depending on whether the
174 functions are defined as SECURITY INVOKER or SECURITY DEFINER. Thus,
175 for example, calling CURRENT_USER directly in a view will always return
176 the invoking user, not the view owner. This is not affected by the
177 view's security_invoker setting, and so a view with security_invoker
178 set to false is not equivalent to a SECURITY DEFINER function and those
179 concepts should not be confused.
180
181 The user creating or replacing a view must have USAGE privileges on any
182 schemas referred to in the view query, in order to look up the
183 referenced objects in those schemas. Note, however, that this lookup
184 only happens when the view is created or replaced. Therefore, the user
185 of the view only requires the USAGE privilege on the schema containing
186 the view, not on the schemas referred to in the view query, even for a
187 security invoker view.
188
189 When CREATE OR REPLACE VIEW is used on an existing view, only the
190 view's defining SELECT rule, plus any WITH ( ... ) parameters and its
191 CHECK OPTION are changed. Other view properties, including ownership,
192 permissions, and non-SELECT rules, remain unchanged. You must own the
193 view to replace it (this includes being a member of the owning role).
194
195 Updatable Views
196 Simple views are automatically updatable: the system will allow INSERT,
197 UPDATE and DELETE statements to be used on the view in the same way as
198 on a regular table. A view is automatically updatable if it satisfies
199 all of the following conditions:
200
201 • The view must have exactly one entry in its FROM list, which must
202 be a table or another updatable view.
203
204 • The view definition must not contain WITH, DISTINCT, GROUP BY,
205 HAVING, LIMIT, or OFFSET clauses at the top level.
206
207 • The view definition must not contain set operations (UNION,
208 INTERSECT or EXCEPT) at the top level.
209
210 • The view's select list must not contain any aggregates, window
211 functions or set-returning functions.
212
213 An automatically updatable view may contain a mix of updatable and
214 non-updatable columns. A column is updatable if it is a simple
215 reference to an updatable column of the underlying base relation;
216 otherwise the column is read-only, and an error will be raised if an
217 INSERT or UPDATE statement attempts to assign a value to it.
218
219 If the view is automatically updatable the system will convert any
220 INSERT, UPDATE or DELETE statement on the view into the corresponding
221 statement on the underlying base relation. INSERT statements that have
222 an ON CONFLICT UPDATE clause are fully supported.
223
224 If an automatically updatable view contains a WHERE condition, the
225 condition restricts which rows of the base relation are available to be
226 modified by UPDATE and DELETE statements on the view. However, an
227 UPDATE is allowed to change a row so that it no longer satisfies the
228 WHERE condition, and thus is no longer visible through the view.
229 Similarly, an INSERT command can potentially insert base-relation rows
230 that do not satisfy the WHERE condition and thus are not visible
231 through the view (ON CONFLICT UPDATE may similarly affect an existing
232 row not visible through the view). The CHECK OPTION may be used to
233 prevent INSERT and UPDATE commands from creating such rows that are not
234 visible through the view.
235
236 If an automatically updatable view is marked with the security_barrier
237 property then all the view's WHERE conditions (and any conditions using
238 operators which are marked as LEAKPROOF) will always be evaluated
239 before any conditions that a user of the view has added. See
240 Section 41.5 for full details. Note that, due to this, rows which are
241 not ultimately returned (because they do not pass the user's WHERE
242 conditions) may still end up being locked. EXPLAIN can be used to see
243 which conditions are applied at the relation level (and therefore do
244 not lock rows) and which are not.
245
246 A more complex view that does not satisfy all these conditions is
247 read-only by default: the system will not allow an insert, update, or
248 delete on the view. You can get the effect of an updatable view by
249 creating INSTEAD OF triggers on the view, which must convert attempted
250 inserts, etc. on the view into appropriate actions on other tables. For
251 more information see CREATE TRIGGER (CREATE_TRIGGER(7)). Another
252 possibility is to create rules (see CREATE RULE (CREATE_RULE(7))), but
253 in practice triggers are easier to understand and use correctly.
254
255 Note that the user performing the insert, update or delete on the view
256 must have the corresponding insert, update or delete privilege on the
257 view. In addition, by default, the view's owner must have the relevant
258 privileges on the underlying base relations, whereas the user
259 performing the update does not need any permissions on the underlying
260 base relations (see Section 41.5). However, if the view has
261 security_invoker set to true, the user performing the update, rather
262 than the view owner, must have the relevant privileges on the
263 underlying base relations.
264
266 Create a view consisting of all comedy films:
267
268 CREATE VIEW comedies AS
269 SELECT *
270 FROM films
271 WHERE kind = 'Comedy';
272
273 This will create a view containing the columns that are in the film
274 table at the time of view creation. Though * was used to create the
275 view, columns added later to the table will not be part of the view.
276
277 Create a view with LOCAL CHECK OPTION:
278
279 CREATE VIEW universal_comedies AS
280 SELECT *
281 FROM comedies
282 WHERE classification = 'U'
283 WITH LOCAL CHECK OPTION;
284
285 This will create a view based on the comedies view, showing only films
286 with kind = 'Comedy' and classification = 'U'. Any attempt to INSERT or
287 UPDATE a row in the view will be rejected if the new row doesn't have
288 classification = 'U', but the film kind will not be checked.
289
290 Create a view with CASCADED CHECK OPTION:
291
292 CREATE VIEW pg_comedies AS
293 SELECT *
294 FROM comedies
295 WHERE classification = 'PG'
296 WITH CASCADED CHECK OPTION;
297
298 This will create a view that checks both the kind and classification of
299 new rows.
300
301 Create a view with a mix of updatable and non-updatable columns:
302
303 CREATE VIEW comedies AS
304 SELECT f.*,
305 country_code_to_name(f.country_code) AS country,
306 (SELECT avg(r.rating)
307 FROM user_ratings r
308 WHERE r.film_id = f.id) AS avg_rating
309 FROM films f
310 WHERE f.kind = 'Comedy';
311
312 This view will support INSERT, UPDATE and DELETE. All the columns from
313 the films table will be updatable, whereas the computed columns country
314 and avg_rating will be read-only.
315
316 Create a recursive view consisting of the numbers from 1 to 100:
317
318 CREATE RECURSIVE VIEW public.nums_1_100 (n) AS
319 VALUES (1)
320 UNION ALL
321 SELECT n+1 FROM nums_1_100 WHERE n < 100;
322
323 Notice that although the recursive view's name is schema-qualified in
324 this CREATE, its internal self-reference is not schema-qualified. This
325 is because the implicitly-created CTE's name cannot be
326 schema-qualified.
327
329 CREATE OR REPLACE VIEW is a PostgreSQL language extension. So is the
330 concept of a temporary view. The WITH ( ... ) clause is an extension as
331 well, as are security barrier views and security invoker views.
332
334 ALTER VIEW (ALTER_VIEW(7)), DROP VIEW (DROP_VIEW(7)), CREATE
335 MATERIALIZED VIEW (CREATE_MATERIALIZED_VIEW(7))
336
337
338
339PostgreSQL 15.4 2023 CREATE VIEW(7)