1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>CREATE VIEW</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-createusermapping.html" title="CREATE USER MAPPING" /><link rel="next" href="sql-deallocate.html" title="DEALLOCATE" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">CREATE VIEW</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-createusermapping.html" title="CREATE USER MAPPING">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-deallocate.html" title="DEALLOCATE">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-CREATEVIEW"><div class="titlepage"></div><a id="id-1.9.3.97.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">CREATE VIEW</span></h2><p>CREATE VIEW — define a new view</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW <em class="replaceable"><code>name</code></em> [ ( <em class="replaceable"><code>column_name</code></em> [, ...] ) ]
4 [ WITH ( <em class="replaceable"><code>view_option_name</code></em> [= <em class="replaceable"><code>view_option_value</code></em>] [, ... ] ) ]
5 AS <em class="replaceable"><code>query</code></em>
6 [ WITH [ CASCADED | LOCAL ] CHECK OPTION ]
7 </pre></div><div class="refsect1" id="id-1.9.3.97.5"><h2>Description</h2><p>
8 <code class="command">CREATE VIEW</code> defines a view of a query. The view
9 is not physically materialized. Instead, the query is run every time
10 the view is referenced in a query.
12 <code class="command">CREATE OR REPLACE VIEW</code> is similar, but if a view
13 of the same name already exists, it is replaced. The new query must
14 generate the same columns that were generated by the existing view query
15 (that is, the same column names in the same order and with the same data
16 types), but it may add additional columns to the end of the list. The
17 calculations giving rise to the output columns may be completely different.
19 If a schema name is given (for example, <code class="literal">CREATE VIEW
20 myschema.myview ...</code>) then the view is created in the specified
21 schema. Otherwise it is created in the current schema. Temporary
22 views exist in a special schema, so a schema name cannot be given
23 when creating a temporary view. The name of the view must be
24 distinct from the name of any other relation (table, sequence, index, view,
25 materialized view, or foreign table) in the same schema.
26 </p></div><div class="refsect1" id="id-1.9.3.97.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">TEMPORARY</code> or <code class="literal">TEMP</code></span></dt><dd><p>
27 If specified, the view is created as a temporary view.
28 Temporary views are automatically dropped at the end of the
29 current session. Existing
30 permanent relations with the same name are not visible to the
31 current session while the temporary view exists, unless they are
32 referenced with schema-qualified names.
34 If any of the tables referenced by the view are temporary,
35 the view is created as a temporary view (whether
36 <code class="literal">TEMPORARY</code> is specified or not).
37 </p></dd><dt><span class="term"><code class="literal">RECURSIVE</code>
38 <a id="id-1.9.3.97.6.2.2.1.2" class="indexterm"></a>
40 Creates a recursive view. The syntax
41 </p><pre class="synopsis">
42 CREATE RECURSIVE VIEW [ <em class="replaceable"><code>schema</code></em> . ] <em class="replaceable"><code>view_name</code></em> (<em class="replaceable"><code>column_names</code></em>) AS SELECT <em class="replaceable"><code>...</code></em>;
45 </p><pre class="synopsis">
46 CREATE VIEW [ <em class="replaceable"><code>schema</code></em> . ] <em class="replaceable"><code>view_name</code></em> AS WITH RECURSIVE <em class="replaceable"><code>view_name</code></em> (<em class="replaceable"><code>column_names</code></em>) AS (SELECT <em class="replaceable"><code>...</code></em>) SELECT <em class="replaceable"><code>column_names</code></em> FROM <em class="replaceable"><code>view_name</code></em>;
48 A view column name list must be specified for a recursive view.
49 </p></dd><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
50 The name (optionally schema-qualified) of a view to be created.
51 </p></dd><dt><span class="term"><em class="replaceable"><code>column_name</code></em></span></dt><dd><p>
52 An optional list of names to be used for columns of the view.
53 If not given, the column names are deduced from the query.
54 </p></dd><dt><span class="term"><code class="literal">WITH ( <em class="replaceable"><code>view_option_name</code></em> [= <em class="replaceable"><code>view_option_value</code></em>] [, ... ] )</code></span></dt><dd><p>
55 This clause specifies optional parameters for a view; the following
56 parameters are supported:
58 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">check_option</code> (<code class="type">enum</code>)</span></dt><dd><p>
59 This parameter may be either <code class="literal">local</code> or
60 <code class="literal">cascaded</code>, and is equivalent to specifying
61 <code class="literal">WITH [ CASCADED | LOCAL ] CHECK OPTION</code> (see below).
62 </p></dd><dt><span class="term"><code class="literal">security_barrier</code> (<code class="type">boolean</code>)</span></dt><dd><p>
63 This should be used if the view is intended to provide row-level
64 security. See <a class="xref" href="rules-privileges.html" title="39.5. Rules and Privileges">Section 39.5</a> for full details.
65 </p></dd><dt><span class="term"><code class="literal">security_invoker</code> (<code class="type">boolean</code>)</span></dt><dd><p>
66 This option causes the underlying base relations to be checked
67 against the privileges of the user of the view rather than the view
68 owner. See the notes below for full details.
69 </p></dd></dl></div><p>
71 All of the above options can be changed on existing views using <a class="link" href="sql-alterview.html" title="ALTER VIEW"><code class="command">ALTER VIEW</code></a>.
72 </p></dd><dt><span class="term"><em class="replaceable"><code>query</code></em></span></dt><dd><p>
73 A <a class="link" href="sql-select.html" title="SELECT"><code class="command">SELECT</code></a> or
74 <a class="link" href="sql-values.html" title="VALUES"><code class="command">VALUES</code></a> command
75 which will provide the columns and rows of the view.
76 </p></dd><dt><span class="term"><code class="literal">WITH [ CASCADED | LOCAL ] CHECK OPTION</code>
77 <a id="id-1.9.3.97.6.2.7.1.2" class="indexterm"></a>
78 <a id="id-1.9.3.97.6.2.7.1.3" class="indexterm"></a>
80 This option controls the behavior of automatically updatable views. When
81 this option is specified, <code class="command">INSERT</code>,
82 <code class="command">UPDATE</code>, and <code class="command">MERGE</code>
83 commands on the view will be checked to ensure that new rows satisfy the
84 view-defining condition (that is, the new rows are checked to ensure that
85 they are visible through the view). If they are not, the update will be
86 rejected. If the <code class="literal">CHECK OPTION</code> is not specified,
87 <code class="command">INSERT</code>, <code class="command">UPDATE</code>, and
88 <code class="command">MERGE</code> commands on the view are
89 allowed to create rows that are not visible through the view. The
90 following check options are supported:
92 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">LOCAL</code></span></dt><dd><p>
93 New rows are only checked against the conditions defined directly in
94 the view itself. Any conditions defined on underlying base views are
95 not checked (unless they also specify the <code class="literal">CHECK OPTION</code>).
96 </p></dd><dt><span class="term"><code class="literal">CASCADED</code></span></dt><dd><p>
97 New rows are checked against the conditions of the view and all
98 underlying base views. If the <code class="literal">CHECK OPTION</code> is specified,
99 and neither <code class="literal">LOCAL</code> nor <code class="literal">CASCADED</code> is specified,
100 then <code class="literal">CASCADED</code> is assumed.
101 </p></dd></dl></div><p>
103 The <code class="literal">CHECK OPTION</code> may not be used with <code class="literal">RECURSIVE</code>
106 Note that the <code class="literal">CHECK OPTION</code> is only supported on views that
107 are automatically updatable, and do not have <code class="literal">INSTEAD OF</code>
108 triggers or <code class="literal">INSTEAD</code> rules. If an automatically updatable
109 view is defined on top of a base view that has <code class="literal">INSTEAD OF</code>
110 triggers, then the <code class="literal">LOCAL CHECK OPTION</code> may be used to check
111 the conditions on the automatically updatable view, but the conditions
112 on the base view with <code class="literal">INSTEAD OF</code> triggers will not be
113 checked (a cascaded check option will not cascade down to a
114 trigger-updatable view, and any check options defined directly on a
115 trigger-updatable view will be ignored). If the view or any of its base
116 relations has an <code class="literal">INSTEAD</code> rule that causes the
117 <code class="command">INSERT</code> or <code class="command">UPDATE</code> command to be rewritten, then
118 all check options will be ignored in the rewritten query, including any
119 checks from automatically updatable views defined on top of the relation
120 with the <code class="literal">INSTEAD</code> rule. <code class="command">MERGE</code> is not
121 supported if the view or any of its base relations have rules.
122 </p></dd></dl></div></div><div class="refsect1" id="id-1.9.3.97.7"><h2>Notes</h2><p>
123 Use the <a class="link" href="sql-dropview.html" title="DROP VIEW"><code class="command">DROP VIEW</code></a>
124 statement to drop views.
126 Be careful that the names and types of the view's columns will be
127 assigned the way you want. For example:
128 </p><pre class="programlisting">
129 CREATE VIEW vista AS SELECT 'Hello World';
131 is bad form because the column name defaults to <code class="literal">?column?</code>;
132 also, the column data type defaults to <code class="type">text</code>, which might not
133 be what you wanted. Better style for a string literal in a view's
134 result is something like:
135 </p><pre class="programlisting">
136 CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
139 By default, access to the underlying base relations referenced in the view
140 is determined by the permissions of the view owner. In some cases, this
141 can be used to provide secure but restricted access to the underlying
142 tables. However, not all views are secure against tampering; see <a class="xref" href="rules-privileges.html" title="39.5. Rules and Privileges">Section 39.5</a> for details.
144 If the view has the <code class="literal">security_invoker</code> property set to
145 <code class="literal">true</code>, access to the underlying base relations is
146 determined by the permissions of the user executing the query, rather than
147 the view owner. Thus, the user of a security invoker view must have the
148 relevant permissions on the view and its underlying base relations.
150 If any of the underlying base relations is a security invoker view, it
151 will be treated as if it had been accessed directly from the original
152 query. Thus, a security invoker view will always check its underlying
153 base relations using the permissions of the current user, even if it is
154 accessed from a view without the <code class="literal">security_invoker</code>
157 If any of the underlying base relations has
158 <a class="link" href="ddl-rowsecurity.html" title="5.9. Row Security Policies">row-level security</a> enabled, then
159 by default, the row-level security policies of the view owner are applied,
160 and access to any additional relations referred to by those policies is
161 determined by the permissions of the view owner. However, if the view has
162 <code class="literal">security_invoker</code> set to <code class="literal">true</code>, then
163 the policies and permissions of the invoking user are used instead, as if
164 the base relations had been referenced directly from the query using the
167 Functions called in the view are treated the same as if they had been
168 called directly from the query using the view. Therefore, the user of
169 a view must have permissions to call all functions used by the view.
170 Functions in the view are executed with the privileges of the user
171 executing the query or the function owner, depending on whether the
172 functions are defined as <code class="literal">SECURITY INVOKER</code> or
173 <code class="literal">SECURITY DEFINER</code>. Thus, for example, calling
174 <code class="literal">CURRENT_USER</code> directly in a view will always return the
175 invoking user, not the view owner. This is not affected by the view's
176 <code class="literal">security_invoker</code> setting, and so a view with
177 <code class="literal">security_invoker</code> set to <code class="literal">false</code> is
178 <span class="emphasis"><em>not</em></span> equivalent to a
179 <code class="literal">SECURITY DEFINER</code> function and those concepts should not
182 The user creating or replacing a view must have <code class="literal">USAGE</code>
183 privileges on any schemas referred to in the view query, in order to look
184 up the referenced objects in those schemas. Note, however, that this
185 lookup only happens when the view is created or replaced. Therefore, the
186 user of the view only requires the <code class="literal">USAGE</code> privilege on
187 the schema containing the view, not on the schemas referred to in the view
188 query, even for a security invoker view.
190 When <code class="command">CREATE OR REPLACE VIEW</code> is used on an existing
191 view, only the view's defining SELECT rule, plus any
192 <code class="literal">WITH ( ... )</code> parameters and its
193 <code class="literal">CHECK OPTION</code> are changed.
194 Other view properties, including ownership, permissions, and non-SELECT
195 rules, remain unchanged. You must own the view
196 to replace it (this includes being a member of the owning role).
197 </p><div class="refsect2" id="SQL-CREATEVIEW-UPDATABLE-VIEWS"><h3>Updatable Views</h3><a id="id-1.9.3.97.7.11.2" class="indexterm"></a><p>
198 Simple views are automatically updatable: the system will allow
199 <code class="command">INSERT</code>, <code class="command">UPDATE</code>,
200 <code class="command">DELETE</code>, and <code class="command">MERGE</code> statements
201 to be used on the view in the same way as on a regular table. A view is
202 automatically updatable if it satisfies all of the following conditions:
204 </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
205 The view must have exactly one entry in its <code class="literal">FROM</code> list,
206 which must be a table or another updatable view.
207 </p></li><li class="listitem"><p>
208 The view definition must not contain <code class="literal">WITH</code>,
209 <code class="literal">DISTINCT</code>, <code class="literal">GROUP BY</code>, <code class="literal">HAVING</code>,
210 <code class="literal">LIMIT</code>, or <code class="literal">OFFSET</code> clauses at the top level.
211 </p></li><li class="listitem"><p>
212 The view definition must not contain set operations (<code class="literal">UNION</code>,
213 <code class="literal">INTERSECT</code> or <code class="literal">EXCEPT</code>) at the top level.
214 </p></li><li class="listitem"><p>
215 The view's select list must not contain any aggregates, window functions
216 or set-returning functions.
217 </p></li></ul></div><p>
219 An automatically updatable view may contain a mix of updatable and
220 non-updatable columns. A column is updatable if it is a simple reference
221 to an updatable column of the underlying base relation; otherwise the
222 column is read-only, and an error will be raised if an
223 <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or
224 <code class="command">MERGE</code> statement attempts to assign a value to it.
226 If the view is automatically updatable the system will convert any
227 <code class="command">INSERT</code>, <code class="command">UPDATE</code>,
228 <code class="command">DELETE</code>, or <code class="command">MERGE</code> statement
229 on the view into the corresponding statement on the underlying base
230 relation. <code class="command">INSERT</code> statements that have an <code class="literal">ON
231 CONFLICT UPDATE</code> clause are fully supported.
233 If an automatically updatable view contains a <code class="literal">WHERE</code>
234 condition, the condition restricts which rows of the base relation are
235 available to be modified by <code class="command">UPDATE</code>,
236 <code class="command">DELETE</code>, and <code class="command">MERGE</code>
237 statements on the view. However, an <code class="command">UPDATE</code> or
238 <code class="command">MERGE</code> is allowed to
239 change a row so that it no longer satisfies the <code class="literal">WHERE</code>
240 condition, and thus is no longer visible through the view. Similarly,
241 an <code class="command">INSERT</code> or <code class="command">MERGE</code> command can
242 potentially insert base-relation rows
243 that do not satisfy the <code class="literal">WHERE</code> condition and thus are not
244 visible through the view (<code class="literal">ON CONFLICT UPDATE</code> may
245 similarly affect an existing row not visible through the view).
246 The <code class="literal">CHECK OPTION</code> may be used to prevent
247 <code class="command">INSERT</code>, <code class="command">UPDATE</code>, and
248 <code class="command">MERGE</code> commands from creating such rows that are not
249 visible through the view.
251 If an automatically updatable view is marked with the
252 <code class="literal">security_barrier</code> property then all the view's <code class="literal">WHERE</code>
253 conditions (and any conditions using operators which are marked as <code class="literal">LEAKPROOF</code>)
254 will always be evaluated before any conditions that a user of the view has
255 added. See <a class="xref" href="rules-privileges.html" title="39.5. Rules and Privileges">Section 39.5</a> for full details. Note that,
256 due to this, rows which are not ultimately returned (because they do not
257 pass the user's <code class="literal">WHERE</code> conditions) may still end up being locked.
258 <code class="command">EXPLAIN</code> can be used to see which conditions are
259 applied at the relation level (and therefore do not lock rows) and which are
262 A more complex view that does not satisfy all these conditions is
263 read-only by default: the system will not allow an <code class="command">INSERT</code>,
264 <code class="command">UPDATE</code>, <code class="command">DELETE</code>, or <code class="command">MERGE</code>
265 on the view. You can get the effect of an updatable view by
266 creating <code class="literal">INSTEAD OF</code> triggers on the view, which must
267 convert attempted inserts, etc. on the view into appropriate actions
268 on other tables. For more information see <a class="xref" href="sql-createtrigger.html" title="CREATE TRIGGER"><span class="refentrytitle">CREATE TRIGGER</span></a>. Another possibility is to create rules
269 (see <a class="xref" href="sql-createrule.html" title="CREATE RULE"><span class="refentrytitle">CREATE RULE</span></a>), but in practice triggers are
270 easier to understand and use correctly. Also note that <code class="command">MERGE</code>
271 is not supported on relations with rules.
273 Note that the user performing the insert, update or delete on the view
274 must have the corresponding insert, update or delete privilege on the
275 view. In addition, by default, the view's owner must have the relevant
276 privileges on the underlying base relations, whereas the user performing
277 the update does not need any permissions on the underlying base relations
278 (see <a class="xref" href="rules-privileges.html" title="39.5. Rules and Privileges">Section 39.5</a>). However, if the view has
279 <code class="literal">security_invoker</code> set to <code class="literal">true</code>, the
280 user performing the update, rather than the view owner, must have the
281 relevant privileges on the underlying base relations.
282 </p></div></div><div class="refsect1" id="id-1.9.3.97.8"><h2>Examples</h2><p>
283 Create a view consisting of all comedy films:
285 </p><pre class="programlisting">
286 CREATE VIEW comedies AS
289 WHERE kind = 'Comedy';
291 This will create a view containing the columns that are in the
292 <code class="literal">film</code> table at the time of view creation. Though
293 <code class="literal">*</code> was used to create the view, columns added later to
294 the table will not be part of the view.
296 Create a view with <code class="literal">LOCAL CHECK OPTION</code>:
298 </p><pre class="programlisting">
299 CREATE VIEW universal_comedies AS
302 WHERE classification = 'U'
303 WITH LOCAL CHECK OPTION;
305 This will create a view based on the <code class="literal">comedies</code> view, showing
306 only films with <code class="literal">kind = 'Comedy'</code> and
307 <code class="literal">classification = 'U'</code>. Any attempt to <code class="command">INSERT</code> or
308 <code class="command">UPDATE</code> a row in the view will be rejected if the new row
309 doesn't have <code class="literal">classification = 'U'</code>, but the film
310 <code class="literal">kind</code> will not be checked.
312 Create a view with <code class="literal">CASCADED CHECK OPTION</code>:
314 </p><pre class="programlisting">
315 CREATE VIEW pg_comedies AS
318 WHERE classification = 'PG'
319 WITH CASCADED CHECK OPTION;
321 This will create a view that checks both the <code class="literal">kind</code> and
322 <code class="literal">classification</code> of new rows.
324 Create a view with a mix of updatable and non-updatable columns:
326 </p><pre class="programlisting">
327 CREATE VIEW comedies AS
329 country_code_to_name(f.country_code) AS country,
330 (SELECT avg(r.rating)
332 WHERE r.film_id = f.id) AS avg_rating
334 WHERE f.kind = 'Comedy';
336 This view will support <code class="command">INSERT</code>, <code class="command">UPDATE</code> and
337 <code class="command">DELETE</code>. All the columns from the <code class="literal">films</code> table will
338 be updatable, whereas the computed columns <code class="literal">country</code> and
339 <code class="literal">avg_rating</code> will be read-only.
341 Create a recursive view consisting of the numbers from 1 to 100:
342 </p><pre class="programlisting">
343 CREATE RECURSIVE VIEW public.nums_1_100 (n) AS
346 SELECT n+1 FROM nums_1_100 WHERE n < 100;
348 Notice that although the recursive view's name is schema-qualified in this
349 <code class="command">CREATE</code>, its internal self-reference is not schema-qualified.
350 This is because the implicitly-created CTE's name cannot be
352 </p></div><div class="refsect1" id="id-1.9.3.97.9"><h2>Compatibility</h2><p>
353 <code class="command">CREATE OR REPLACE VIEW</code> is a
354 <span class="productname">PostgreSQL</span> language extension.
355 So is the concept of a temporary view.
356 The <code class="literal">WITH ( ... )</code> clause is an extension as well, as are
357 security barrier views and security invoker views.
358 </p></div><div class="refsect1" id="id-1.9.3.97.10"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-alterview.html" title="ALTER VIEW"><span class="refentrytitle">ALTER VIEW</span></a>, <a class="xref" href="sql-dropview.html" title="DROP VIEW"><span class="refentrytitle">DROP VIEW</span></a>, <a class="xref" href="sql-creatematerializedview.html" title="CREATE MATERIALIZED VIEW"><span class="refentrytitle">CREATE MATERIALIZED VIEW</span></a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-createusermapping.html" title="CREATE USER MAPPING">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-deallocate.html" title="DEALLOCATE">Next</a></td></tr><tr><td width="40%" align="left" valign="top">CREATE USER MAPPING </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> DEALLOCATE</td></tr></table></div></body></html>