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 TABLE AS</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-createtable.html" title="CREATE TABLE" /><link rel="next" href="sql-createtablespace.html" title="CREATE TABLESPACE" /></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 TABLE AS</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-createtable.html" title="CREATE TABLE">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-createtablespace.html" title="CREATE TABLESPACE">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-CREATETABLEAS"><div class="titlepage"></div><a id="id-1.9.3.86.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">CREATE TABLE AS</span></h2><p>CREATE TABLE AS — define a new table from the results of a query</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <em class="replaceable"><code>table_name</code></em>
4 [ (<em class="replaceable"><code>column_name</code></em> [, ...] ) ]
5 [ USING <em class="replaceable"><code>method</code></em> ]
6 [ WITH ( <em class="replaceable"><code>storage_parameter</code></em> [= <em class="replaceable"><code>value</code></em>] [, ... ] ) | WITHOUT OIDS ]
7 [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
8 [ TABLESPACE <em class="replaceable"><code>tablespace_name</code></em> ]
9 AS <em class="replaceable"><code>query</code></em>
11 </pre></div><div class="refsect1" id="id-1.9.3.86.5"><h2>Description</h2><p>
12 <code class="command">CREATE TABLE AS</code> creates a table and fills it
13 with data computed by a <code class="command">SELECT</code> command.
14 The table columns have the
15 names and data types associated with the output columns of the
16 <code class="command">SELECT</code> (except that you can override the column
17 names by giving an explicit list of new column names).
19 <code class="command">CREATE TABLE AS</code> bears some resemblance to
20 creating a view, but it is really quite different: it creates a new
21 table and evaluates the query just once to fill the new table
22 initially. The new table will not track subsequent changes to the
23 source tables of the query. In contrast, a view re-evaluates its
24 defining <code class="command">SELECT</code> statement whenever it is
27 <code class="command">CREATE TABLE AS</code> requires <code class="literal">CREATE</code>
28 privilege on the schema used for the table.
29 </p></div><div class="refsect1" id="id-1.9.3.86.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">GLOBAL</code> or <code class="literal">LOCAL</code></span></dt><dd><p>
30 Ignored for compatibility. Use of these keywords is deprecated;
31 refer to <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a> for details.
32 </p></dd></dl></div><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>
33 If specified, the table is created as a temporary table.
34 Refer to <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a> for details.
35 </p></dd><dt><span class="term"><code class="literal">UNLOGGED</code></span></dt><dd><p>
36 If specified, the table is created as an unlogged table.
37 Refer to <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a> for details.
38 </p></dd><dt><span class="term"><code class="literal">IF NOT EXISTS</code></span></dt><dd><p>
39 Do not throw an error if a relation with the same name already
40 exists; simply issue a notice and leave the table unmodified.
41 </p></dd><dt><span class="term"><em class="replaceable"><code>table_name</code></em></span></dt><dd><p>
42 The name (optionally schema-qualified) of the table to be created.
43 </p></dd><dt><span class="term"><em class="replaceable"><code>column_name</code></em></span></dt><dd><p>
44 The name of a column in the new table. If column names are not
45 provided, they are taken from the output column names of the query.
46 </p></dd><dt><span class="term"><code class="literal">USING <em class="replaceable"><code>method</code></em></code></span></dt><dd><p>
47 This optional clause specifies the table access method to use to store
48 the contents for the new table; the method needs be an access method of
49 type <code class="literal">TABLE</code>. See <a class="xref" href="tableam.html" title="Chapter 62. Table Access Method Interface Definition">Chapter 62</a> for more
50 information. If this option is not specified, the default table access
51 method is chosen for the new table. See <a class="xref" href="runtime-config-client.html#GUC-DEFAULT-TABLE-ACCESS-METHOD">default_table_access_method</a> for more information.
52 </p></dd><dt><span class="term"><code class="literal">WITH ( <em class="replaceable"><code>storage_parameter</code></em> [= <em class="replaceable"><code>value</code></em>] [, ... ] )</code></span></dt><dd><p>
53 This clause specifies optional storage parameters for the new table;
54 see <a class="xref" href="sql-createtable.html#SQL-CREATETABLE-STORAGE-PARAMETERS" title="Storage Parameters">Storage Parameters</a> in the
55 <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a> documentation for more
56 information. For backward-compatibility the <code class="literal">WITH</code>
57 clause for a table can also include <code class="literal">OIDS=FALSE</code> to
58 specify that rows of the new table should contain no OIDs (object
59 identifiers), <code class="literal">OIDS=TRUE</code> is not supported anymore.
60 </p></dd><dt><span class="term"><code class="literal">WITHOUT OIDS</code></span></dt><dd><p>
61 This is backward-compatible syntax for declaring a table
62 <code class="literal">WITHOUT OIDS</code>, creating a table <code class="literal">WITH
63 OIDS</code> is not supported anymore.
64 </p></dd><dt><span class="term"><code class="literal">ON COMMIT</code></span></dt><dd><p>
65 The behavior of temporary tables at the end of a transaction
66 block can be controlled using <code class="literal">ON COMMIT</code>.
67 The three options are:
69 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">PRESERVE ROWS</code></span></dt><dd><p>
70 No special action is taken at the ends of transactions.
71 This is the default behavior.
72 </p></dd><dt><span class="term"><code class="literal">DELETE ROWS</code></span></dt><dd><p>
73 All rows in the temporary table will be deleted at the end
74 of each transaction block. Essentially, an automatic <a class="link" href="sql-truncate.html" title="TRUNCATE"><code class="command">TRUNCATE</code></a> is done
76 </p></dd><dt><span class="term"><code class="literal">DROP</code></span></dt><dd><p>
77 The temporary table will be dropped at the end of the current
79 </p></dd></dl></div></dd><dt><span class="term"><code class="literal">TABLESPACE <em class="replaceable"><code>tablespace_name</code></em></code></span></dt><dd><p>
80 The <em class="replaceable"><code>tablespace_name</code></em> is the name
81 of the tablespace in which the new table is to be created.
83 <a class="xref" href="runtime-config-client.html#GUC-DEFAULT-TABLESPACE">default_tablespace</a> is consulted, or
84 <a class="xref" href="runtime-config-client.html#GUC-TEMP-TABLESPACES">temp_tablespaces</a> if the table is temporary.
85 </p></dd><dt><span class="term"><em class="replaceable"><code>query</code></em></span></dt><dd><p>
86 A <a class="link" href="sql-select.html" title="SELECT"><code class="command">SELECT</code></a>, <a class="link" href="sql-select.html#SQL-TABLE" title="TABLE Command"><code class="command">TABLE</code></a>, or <a class="link" href="sql-values.html" title="VALUES"><code class="command">VALUES</code></a>
87 command, or an <a class="link" href="sql-execute.html" title="EXECUTE"><code class="command">EXECUTE</code></a> command that runs a
88 prepared <code class="command">SELECT</code>, <code class="command">TABLE</code>, or
89 <code class="command">VALUES</code> query.
90 </p></dd><dt><span class="term"><code class="literal">WITH [ NO ] DATA</code></span></dt><dd><p>
91 This clause specifies whether or not the data produced by the query
92 should be copied into the new table. If not, only the table structure
93 is copied. The default is to copy the data.
94 </p></dd></dl></div></div><div class="refsect1" id="id-1.9.3.86.7"><h2>Notes</h2><p>
95 This command is functionally similar to <a class="xref" href="sql-selectinto.html" title="SELECT INTO"><span class="refentrytitle">SELECT INTO</span></a>, but it is
96 preferred since it is less likely to be confused with other uses of
97 the <code class="command">SELECT INTO</code> syntax. Furthermore, <code class="command">CREATE
98 TABLE AS</code> offers a superset of the functionality offered
99 by <code class="command">SELECT INTO</code>.
100 </p></div><div class="refsect1" id="id-1.9.3.86.8"><h2>Examples</h2><p>
101 Create a new table <code class="literal">films_recent</code> consisting of only
102 recent entries from the table <code class="literal">films</code>:
104 </p><pre class="programlisting">
105 CREATE TABLE films_recent AS
106 SELECT * FROM films WHERE date_prod >= '2002-01-01';
109 To copy a table completely, the short form using
110 the <code class="literal">TABLE</code> command can also be used:
112 </p><pre class="programlisting">
113 CREATE TABLE films2 AS
117 Create a new temporary table <code class="literal">films_recent</code>, consisting of
118 only recent entries from the table <code class="literal">films</code>, using a
119 prepared statement. The new table will be dropped at commit:
121 </p><pre class="programlisting">
122 PREPARE recentfilms(date) AS
123 SELECT * FROM films WHERE date_prod > $1;
124 CREATE TEMP TABLE films_recent ON COMMIT DROP AS
125 EXECUTE recentfilms('2002-01-01');
126 </pre></div><div class="refsect1" id="id-1.9.3.86.9"><h2>Compatibility</h2><p>
127 <code class="command">CREATE TABLE AS</code> conforms to the <acronym class="acronym">SQL</acronym>
128 standard. The following are nonstandard extensions:
130 </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>
131 The standard requires parentheses around the subquery clause; in
132 <span class="productname">PostgreSQL</span>, these parentheses are
134 </p></li><li class="listitem"><p>
135 In the standard, the <code class="literal">WITH [ NO ] DATA</code> clause
136 is required; in PostgreSQL it is optional.
137 </p></li><li class="listitem"><p><span class="productname">PostgreSQL</span> handles temporary tables in a way
138 rather different from the standard; see
139 <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a>
141 </p></li><li class="listitem"><p>
142 The <code class="literal">WITH</code> clause is a <span class="productname">PostgreSQL</span>
143 extension; storage parameters are not in the standard.
144 </p></li><li class="listitem"><p>
145 The <span class="productname">PostgreSQL</span> concept of tablespaces is not
146 part of the standard. Hence, the clause <code class="literal">TABLESPACE</code>
148 </p></li></ul></div></div><div class="refsect1" id="id-1.9.3.86.10"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-creatematerializedview.html" title="CREATE MATERIALIZED VIEW"><span class="refentrytitle">CREATE MATERIALIZED VIEW</span></a>, <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a>, <a class="xref" href="sql-execute.html" title="EXECUTE"><span class="refentrytitle">EXECUTE</span></a>, <a class="xref" href="sql-select.html" title="SELECT"><span class="refentrytitle">SELECT</span></a>, <a class="xref" href="sql-selectinto.html" title="SELECT INTO"><span class="refentrytitle">SELECT INTO</span></a>, <a class="xref" href="sql-values.html" title="VALUES"><span class="refentrytitle">VALUES</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-createtable.html" title="CREATE TABLE">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-createtablespace.html" title="CREATE TABLESPACE">Next</a></td></tr><tr><td width="40%" align="left" valign="top">CREATE TABLE </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"> CREATE TABLESPACE</td></tr></table></div></body></html>