1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
|
<!--
doc/src/sgml/ref/create_view.sgml
PostgreSQL documentation
-->
<refentry id="SQL-CREATEVIEW">
<refmeta>
<refentrytitle>CREATE VIEW</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE VIEW</refname>
<refpurpose>define a new view</refpurpose>
</refnamediv>
<indexterm zone="sql-createview">
<primary>CREATE VIEW</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW <replaceable class="PARAMETER">name</replaceable> [ ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] ) ]
[ WITH ( <replaceable class="PARAMETER">view_option_name</replaceable> [= <replaceable class="PARAMETER">view_option_value</replaceable>] [, ... ] ) ]
AS <replaceable class="PARAMETER">query</replaceable>
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>CREATE VIEW</command> 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.
</para>
<para>
<command>CREATE OR REPLACE VIEW</command> 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.
</para>
<para>
If a schema name is given (for example, <literal>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.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>TEMPORARY</> or <literal>TEMP</></term>
<listitem>
<para>
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.
</para>
<para>
If any of the tables referenced by the view are temporary,
the view is created as a temporary view (whether
<literal>TEMPORARY</literal> is specified or not).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RECURSIVE</></term>
<listitem>
<para>
Creates a recursive view. The syntax
<synopsis>
CREATE RECURSIVE VIEW [ <replaceable>schema</> . ] <replaceable>view_name</> (<replaceable>column_names</>) AS SELECT <replaceable>...</>;
</synopsis>
is equivalent to
<synopsis>
CREATE VIEW [ <replaceable>schema</> . ] <replaceable>view_name</> AS WITH RECURSIVE <replaceable>view_name</> (<replaceable>column_names</>) AS (SELECT <replaceable>...</>) SELECT <replaceable>column_names</> FROM <replaceable>view_name</>;
</synopsis>
A view column name list must be specified for a recursive view.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of a view to be created.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">column_name</replaceable></term>
<listitem>
<para>
An optional list of names to be used for columns of the view.
If not given, the column names are deduced from the query.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>WITH ( <replaceable class="PARAMETER">view_option_name</replaceable> [= <replaceable class="PARAMETER">view_option_value</replaceable>] [, ... ] )</literal></term>
<listitem>
<para>
This clause specifies optional parameters for a view; currently, the
only supported parameter name is <literal>security_barrier</literal>,
which should be enabled when a view is intended to provide row-level
security. See <xref linkend="rules-privileges"> for full details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">query</replaceable></term>
<listitem>
<para>
A <xref linkend="sql-select"> or
<xref linkend="sql-values"> command
which will provide the columns and rows of the view.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Use the <xref linkend="sql-dropview">
statement to drop views.
</para>
<para>
Be careful that the names and types of the view's columns will be
assigned the way you want. For example:
<programlisting>
CREATE VIEW vista AS SELECT 'Hello World';
</programlisting>
is bad form in two ways: the column name defaults to <literal>?column?</>,
and the column data type defaults to <type>unknown</>. If you want a
string literal in a view's result, use something like:
<programlisting>
CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
</programlisting>
</para>
<para>
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 <xref linkend="rules-privileges"> 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.
</para>
<para>
When <command>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).
</para>
<refsect2 id="SQL-CREATEVIEW-updatable-views">
<title id="SQL-CREATEVIEW-updatable-views-title">Updatable Views</title>
<indexterm zone="sql-createview-updatable-views">
<primary>updatable views</primary>
</indexterm>
<para>
Simple views are automatically updatable: the system will allow
<command>INSERT</>, <command>UPDATE</> and <command>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:
<itemizedlist>
<listitem>
<para>
The view must have exactly one entry in its <literal>FROM</> list,
which must be a table or another updatable view.
</para>
</listitem>
<listitem>
<para>
The view definition must not contain <literal>WITH</>,
<literal>DISTINCT</>, <literal>GROUP BY</>, <literal>HAVING</>,
<literal>LIMIT</>, or <literal>OFFSET</> clauses at the top level.
</para>
</listitem>
<listitem>
<para>
The view definition must not contain set operations (<literal>UNION</>,
<literal>INTERSECT</> or <literal>EXCEPT</>) at the top level.
</para>
</listitem>
<listitem>
<para>
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.
</para>
</listitem>
<listitem>
<para>
No column of the underlying relation can appear more than once in
the view's select list.
</para>
</listitem>
<listitem>
<para>
The view must not have the <literal>security_barrier</> property.
</para>
</listitem>
</itemizedlist>
</para>
<para>
If the view is automatically updatable the system will convert any
<command>INSERT</>, <command>UPDATE</> or <command>DELETE</> statement
on the view into the corresponding statement on the underlying base
relation.
</para>
<para>
If an automatically updatable view contains a <literal>WHERE</>
condition, the condition restricts which rows of the base relation are
available to be modified by <command>UPDATE</> and <command>DELETE</>
statements on the view. However, an <command>UPDATE</> is allowed to
change a row so that it no longer satisfies the <literal>WHERE</>
condition, and thus is no longer visible through the view. Similarly,
an <command>INSERT</> command can potentially insert base-relation rows
that do not satisfy the <literal>WHERE</> condition and thus are not
visible through the view.
</para>
<para>
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 <literal>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 <xref
linkend="sql-createtrigger">. Another possibility is to create rules
(see <xref linkend="sql-createrule">), but in practice triggers are
easier to understand and use correctly.
</para>
<para>
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
<xref linkend="rules-privileges">).
</para>
</refsect2>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Create a view consisting of all comedy films:
<programlisting>
CREATE VIEW comedies AS
SELECT *
FROM films
WHERE kind = 'Comedy';
</programlisting>
This will create a view containing the columns that are in the
<literal>film</> table at the time of view creation. Though
<literal>*</> was used to create the view, columns added later to
the table will not be part of the view.
</para>
<para>
Create a recursive view consisting of the numbers from 1 to 100:
<programlisting>
CREATE RECURSIVE VIEW public.nums_1_100 (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums_1_100 WHERE n < 100;
</programlisting>
Notice that although the recursive view's name is schema-qualified in this
<command>CREATE</>, its internal self-reference is not schema-qualified.
This is because the implicitly-created CTE's name cannot be
schema-qualified.
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
The SQL standard specifies some additional capabilities for the
<command>CREATE VIEW</command> statement:
<synopsis>
CREATE VIEW <replaceable class="parameter">name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
AS <replaceable class="PARAMETER">query</replaceable>
[ WITH [ CASCADED | LOCAL ] CHECK OPTION ]
</synopsis>
</para>
<para>
The optional clauses for the full SQL command are:
<variablelist>
<varlistentry>
<term><literal>CHECK OPTION</literal></term>
<listitem>
<para>
This option controls the behavior of automatically updatable views.
When given, <command>INSERT</> and <command>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 <literal>CHECK OPTION</literal>, <command>INSERT</> and
<command>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 <productname>PostgreSQL</>.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>LOCAL</literal></term>
<listitem>
<para>
Check for integrity on this view.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CASCADED</literal></term>
<listitem>
<para>
Check for integrity on this view and on any dependent
view. <literal>CASCADED</> is assumed if neither
<literal>CASCADED</> nor <literal>LOCAL</> is specified.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
<command>CREATE OR REPLACE VIEW</command> is a
<productname>PostgreSQL</productname> language extension.
So is the concept of a temporary view.
The <literal>WITH</> clause is an extension as well.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-alterview"></member>
<member><xref linkend="sql-dropview"></member>
<member><xref linkend="sql-creatematerializedview"></member>
</simplelist>
</refsect1>
</refentry>
|