1CREATE TABLE AS(7)       PostgreSQL 15.4 Documentation      CREATE TABLE AS(7)
2
3
4

NAME

6       CREATE_TABLE_AS - define a new table from the results of a query
7

SYNOPSIS

9       CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name
10           [ (column_name [, ...] ) ]
11           [ USING method ]
12           [ WITH ( storage_parameter [= value] [, ... ] ) | WITHOUT OIDS ]
13           [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
14           [ TABLESPACE tablespace_name ]
15           AS query
16           [ WITH [ NO ] DATA ]
17

DESCRIPTION

19       CREATE TABLE AS creates a table and fills it with data computed by a
20       SELECT command. The table columns have the names and data types
21       associated with the output columns of the SELECT (except that you can
22       override the column names by giving an explicit list of new column
23       names).
24
25       CREATE TABLE AS bears some resemblance to creating a view, but it is
26       really quite different: it creates a new table and evaluates the query
27       just once to fill the new table initially. The new table will not track
28       subsequent changes to the source tables of the query. In contrast, a
29       view re-evaluates its defining SELECT statement whenever it is queried.
30
31       CREATE TABLE AS requires CREATE privilege on the schema used for the
32       table.
33

PARAMETERS

35       GLOBAL or LOCAL
36           Ignored for compatibility. Use of these keywords is deprecated;
37           refer to CREATE TABLE (CREATE_TABLE(7)) for details.
38
39       TEMPORARY or TEMP
40           If specified, the table is created as a temporary table. Refer to
41           CREATE TABLE (CREATE_TABLE(7)) for details.
42
43       UNLOGGED
44           If specified, the table is created as an unlogged table. Refer to
45           CREATE TABLE (CREATE_TABLE(7)) for details.
46
47       IF NOT EXISTS
48           Do not throw an error if a relation with the same name already
49           exists; simply issue a notice and leave the table unmodified.
50
51       table_name
52           The name (optionally schema-qualified) of the table to be created.
53
54       column_name
55           The name of a column in the new table. If column names are not
56           provided, they are taken from the output column names of the query.
57
58       USING method
59           This optional clause specifies the table access method to use to
60           store the contents for the new table; the method needs be an access
61           method of type TABLE. See Chapter 63 for more information. If this
62           option is not specified, the default table access method is chosen
63           for the new table. See default_table_access_method for more
64           information.
65
66       WITH ( storage_parameter [= value] [, ... ] )
67           This clause specifies optional storage parameters for the new
68           table; see Storage Parameters in the CREATE TABLE (CREATE_TABLE(7))
69           documentation for more information. For backward-compatibility the
70           WITH clause for a table can also include OIDS=FALSE to specify that
71           rows of the new table should contain no OIDs (object identifiers),
72           OIDS=TRUE is not supported anymore.
73
74       WITHOUT OIDS
75           This is backward-compatible syntax for declaring a table WITHOUT
76           OIDS, creating a table WITH OIDS is not supported anymore.
77
78       ON COMMIT
79           The behavior of temporary tables at the end of a transaction block
80           can be controlled using ON COMMIT. The three options are:
81
82           PRESERVE ROWS
83               No special action is taken at the ends of transactions. This is
84               the default behavior.
85
86           DELETE ROWS
87               All rows in the temporary table will be deleted at the end of
88               each transaction block. Essentially, an automatic TRUNCATE is
89               done at each commit.
90
91           DROP
92               The temporary table will be dropped at the end of the current
93               transaction block.
94
95       TABLESPACE tablespace_name
96           The tablespace_name is the name of the tablespace in which the new
97           table is to be created. If not specified, default_tablespace is
98           consulted, or temp_tablespaces if the table is temporary.
99
100       query
101           A SELECT, TABLE, or VALUES command, or an EXECUTE command that runs
102           a prepared SELECT, TABLE, or VALUES query.
103
104       WITH [ NO ] DATA
105           This clause specifies whether or not the data produced by the query
106           should be copied into the new table. If not, only the table
107           structure is copied. The default is to copy the data.
108

NOTES

110       This command is functionally similar to SELECT INTO (SELECT_INTO(7)),
111       but it is preferred since it is less likely to be confused with other
112       uses of the SELECT INTO syntax. Furthermore, CREATE TABLE AS offers a
113       superset of the functionality offered by SELECT INTO.
114

EXAMPLES

116       Create a new table films_recent consisting of only recent entries from
117       the table films:
118
119           CREATE TABLE films_recent AS
120             SELECT * FROM films WHERE date_prod >= '2002-01-01';
121
122       To copy a table completely, the short form using the TABLE command can
123       also be used:
124
125           CREATE TABLE films2 AS
126             TABLE films;
127
128       Create a new temporary table films_recent, consisting of only recent
129       entries from the table films, using a prepared statement. The new table
130       will be dropped at commit:
131
132           PREPARE recentfilms(date) AS
133             SELECT * FROM films WHERE date_prod > $1;
134           CREATE TEMP TABLE films_recent ON COMMIT DROP AS
135             EXECUTE recentfilms('2002-01-01');
136

COMPATIBILITY

138       CREATE TABLE AS conforms to the SQL standard. The following are
139       nonstandard extensions:
140
141       •   The standard requires parentheses around the subquery clause; in
142           PostgreSQL, these parentheses are optional.
143
144       •   In the standard, the WITH [ NO ] DATA clause is required; in
145           PostgreSQL it is optional.
146
147       •   PostgreSQL handles temporary tables in a way rather different from
148           the standard; see CREATE TABLE (CREATE_TABLE(7)) for details.
149
150       •   The WITH clause is a PostgreSQL extension; storage parameters are
151           not in the standard.
152
153       •   The PostgreSQL concept of tablespaces is not part of the standard.
154           Hence, the clause TABLESPACE is an extension.
155

SEE ALSO

157       CREATE MATERIALIZED VIEW (CREATE_MATERIALIZED_VIEW(7)), CREATE TABLE
158       (CREATE_TABLE(7)), EXECUTE(7), SELECT(7), SELECT INTO (SELECT_INTO(7)),
159       VALUES(7)
160
161
162
163PostgreSQL 15.4                      2023                   CREATE TABLE AS(7)
Impressum