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
|
<!--
doc/src/sgml/ref/create_table_as.sgml
PostgreSQL documentation
-->
<refentry id="sql-createtableas">
<indexterm zone="sql-createtableas">
<primary>CREATE TABLE AS</primary>
</indexterm>
<refmeta>
<refentrytitle>CREATE TABLE AS</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE TABLE AS</refname>
<refpurpose>define a new table from the results of a query</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
AS <replaceable>query</replaceable>
[ WITH [ NO ] DATA ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>CREATE TABLE AS</command> creates a table and fills it
with data computed by a <command>SELECT</command> command.
The table columns have the
names and data types associated with the output columns of the
<command>SELECT</command> (except that you can override the column
names by giving an explicit list of new column names).
</para>
<para>
<command>CREATE TABLE AS</command> bears some resemblance to
creating a view, but it is really quite different: it creates a new
table and evaluates the query just once to fill the new table
initially. The new table will not track subsequent changes to the
source tables of the query. In contrast, a view re-evaluates its
defining <command>SELECT</command> statement whenever it is
queried.
</para>
<para>
<command>CREATE TABLE AS</command> requires <literal>CREATE</literal>
privilege on the schema used for the table.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>GLOBAL</literal> or <literal>LOCAL</literal></term>
<listitem>
<para>
Ignored for compatibility. Use of these keywords is deprecated;
refer to <xref linkend="sql-createtable"/> for details.
</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<varlistentry>
<term><literal>TEMPORARY</literal> or <literal>TEMP</literal></term>
<listitem>
<para>
If specified, the table is created as a temporary table.
Refer to <xref linkend="sql-createtable"/> for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>UNLOGGED</literal></term>
<listitem>
<para>
If specified, the table is created as an unlogged table.
Refer to <xref linkend="sql-createtable"/> for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
<para>
Do not throw an error if a relation with the same name already
exists; simply issue a notice and leave the table unmodified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>table_name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of the table to be created.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>column_name</replaceable></term>
<listitem>
<para>
The name of a column in the new table. If column names are not
provided, they are taken from the output column names of the query.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>USING <replaceable class="parameter">method</replaceable></literal></term>
<listitem>
<para>
This optional clause specifies the table access method to use to store
the contents for the new table; the method needs be an access method of
type <literal>TABLE</literal>. See <xref linkend="tableam"/> for more
information. If this option is not specified, the default table access
method is chosen for the new table. See <xref
linkend="guc-default-table-access-method"/> for more information.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
<listitem>
<para>
This clause specifies optional storage parameters for the new table;
see <xref linkend="sql-createtable-storage-parameters"/> in the
<xref linkend="sql-createtable"/> documentation for more
information. For backward-compatibility the <literal>WITH</literal>
clause for a table can also include <literal>OIDS=FALSE</literal> to
specify that rows of the new table should contain no OIDs (object
identifiers), <literal>OIDS=TRUE</literal> is not supported anymore.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>WITHOUT OIDS</literal></term>
<listitem>
<para>
This is backward-compatible syntax for declaring a table
<literal>WITHOUT OIDS</literal>, creating a table <literal>WITH
OIDS</literal> is not supported anymore.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ON COMMIT</literal></term>
<listitem>
<para>
The behavior of temporary tables at the end of a transaction
block can be controlled using <literal>ON COMMIT</literal>.
The three options are:
<variablelist>
<varlistentry>
<term><literal>PRESERVE ROWS</literal></term>
<listitem>
<para>
No special action is taken at the ends of transactions.
This is the default behavior.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DELETE ROWS</literal></term>
<listitem>
<para>
All rows in the temporary table will be deleted at the end
of each transaction block. Essentially, an automatic <link
linkend="sql-truncate"><command>TRUNCATE</command></link> is done
at each commit.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DROP</literal></term>
<listitem>
<para>
The temporary table will be dropped at the end of the current
transaction block.
</para>
</listitem>
</varlistentry>
</variablelist></para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TABLESPACE <replaceable class="parameter">tablespace_name</replaceable></literal></term>
<listitem>
<para>
The <replaceable class="parameter">tablespace_name</replaceable> is the name
of the tablespace in which the new table is to be created.
If not specified,
<xref linkend="guc-default-tablespace"/> is consulted, or
<xref linkend="guc-temp-tablespaces"/> if the table is temporary.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>query</replaceable></term>
<listitem>
<para>
A <link linkend="sql-select"><command>SELECT</command></link>, <link
linkend="sql-table"><command>TABLE</command></link>, or <link linkend="sql-values"><command>VALUES</command></link>
command, or an <link linkend="sql-execute"><command>EXECUTE</command></link> command that runs a
prepared <command>SELECT</command>, <command>TABLE</command>, or
<command>VALUES</command> query.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>WITH [ NO ] DATA</literal></term>
<listitem>
<para>
This clause specifies whether or not the data produced by the query
should be copied into the new table. If not, only the table structure
is copied. The default is to copy the data.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
This command is functionally similar to <xref
linkend="sql-selectinto"/>, but it is
preferred since it is less likely to be confused with other uses of
the <command>SELECT INTO</command> syntax. Furthermore, <command>CREATE
TABLE AS</command> offers a superset of the functionality offered
by <command>SELECT INTO</command>.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Create a new table <literal>films_recent</literal> consisting of only
recent entries from the table <literal>films</literal>:
<programlisting>
CREATE TABLE films_recent AS
SELECT * FROM films WHERE date_prod >= '2002-01-01';
</programlisting>
</para>
<para>
To copy a table completely, the short form using
the <literal>TABLE</literal> command can also be used:
<programlisting>
CREATE TABLE films2 AS
TABLE films;
</programlisting>
</para>
<para>
Create a new temporary table <literal>films_recent</literal>, consisting of
only recent entries from the table <literal>films</literal>, using a
prepared statement. The new table will be dropped at commit:
<programlisting>
PREPARE recentfilms(date) AS
SELECT * FROM films WHERE date_prod > $1;
CREATE TEMP TABLE films_recent ON COMMIT DROP AS
EXECUTE recentfilms('2002-01-01');
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
<command>CREATE TABLE AS</command> conforms to the <acronym>SQL</acronym>
standard. The following are nonstandard extensions:
<itemizedlist spacing="compact">
<listitem>
<para>
The standard requires parentheses around the subquery clause; in
<productname>PostgreSQL</productname>, these parentheses are
optional.
</para>
</listitem>
<listitem>
<para>
In the standard, the <literal>WITH [ NO ] DATA</literal> clause
is required; in PostgreSQL it is optional.
</para>
</listitem>
<listitem>
<para><productname>PostgreSQL</productname> handles temporary tables in a way
rather different from the standard; see
<xref linkend="sql-createtable"/>
for details.
</para>
</listitem>
<listitem>
<para>
The <literal>WITH</literal> clause is a <productname>PostgreSQL</productname>
extension; storage parameters are not in the standard.
</para>
</listitem>
<listitem>
<para>
The <productname>PostgreSQL</productname> concept of tablespaces is not
part of the standard. Hence, the clause <literal>TABLESPACE</literal>
is an extension.
</para>
</listitem>
</itemizedlist></para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-creatematerializedview"/></member>
<member><xref linkend="sql-createtable"/></member>
<member><xref linkend="sql-execute"/></member>
<member><xref linkend="sql-select"/></member>
<member><xref linkend="sql-selectinto"/></member>
<member><xref linkend="sql-values"/></member>
</simplelist>
</refsect1>
</refentry>
|