1<!--
2doc/src/sgml/ref/create_foreign_table.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-createforeigntable">
7 <indexterm zone="sql-createforeigntable">
8  <primary>CREATE FOREIGN TABLE</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>CREATE FOREIGN TABLE</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>CREATE FOREIGN TABLE</refname>
19  <refpurpose>define a new foreign table</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable> ( [
25  { <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">data_type</replaceable> [ OPTIONS ( <replaceable class="parameter">option</replaceable> '<replaceable class="parameter">value</replaceable>' [, ... ] ) ] [ COLLATE <replaceable>collation</replaceable> ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
26    | <replaceable>table_constraint</replaceable> }
27    [, ... ]
28] )
29[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
30  SERVER <replaceable class="parameter">server_name</replaceable>
31[ OPTIONS ( <replaceable class="parameter">option</replaceable> '<replaceable class="parameter">value</replaceable>' [, ... ] ) ]
32
33CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable>
34  PARTITION OF <replaceable class="parameter">parent_table</replaceable> [ (
35  { <replaceable class="parameter">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
36    | <replaceable>table_constraint</replaceable> }
37    [, ... ]
38) ] <replaceable class="parameter">partition_bound_spec</replaceable>
39  SERVER <replaceable class="parameter">server_name</replaceable>
40[ OPTIONS ( <replaceable class="parameter">option</replaceable> '<replaceable class="parameter">value</replaceable>' [, ... ] ) ]
41
42<phrase>where <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
43
44[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
45{ NOT NULL |
46  NULL |
47  CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
48  DEFAULT <replaceable>default_expr</replaceable> |
49  GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED }
50
51<phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
52
53[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
54CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ]
55</synopsis>
56 </refsynopsisdiv>
57
58 <refsect1 id="sql-createforeigntable-description">
59  <title>Description</title>
60
61  <para>
62   <command>CREATE FOREIGN TABLE</command> creates a new foreign table
63   in the current database. The table will be owned by the user issuing the
64   command.
65  </para>
66
67  <para>
68   If a schema name is given (for example, <literal>CREATE FOREIGN TABLE
69   myschema.mytable ...</literal>) then the table is created in the specified
70   schema.  Otherwise it is created in the current schema.
71   The name of the foreign table must be
72   distinct from the name of any other foreign table, table, sequence, index,
73   view, or materialized view in the same schema.
74  </para>
75
76  <para>
77   <command>CREATE FOREIGN TABLE</command> also automatically creates a data
78   type that represents the composite type corresponding to one row of
79   the foreign table.  Therefore, foreign tables cannot have the same
80   name as any existing data type in the same schema.
81  </para>
82
83  <para>
84   If <literal>PARTITION OF</literal> clause is specified then the table is
85   created as a partition of <literal>parent_table</literal> with specified
86   bounds.
87  </para>
88
89  <para>
90   To be able to create a foreign table, you must have <literal>USAGE</literal>
91   privilege on the foreign server, as well as <literal>USAGE</literal>
92   privilege on all column types used in the table.
93  </para>
94 </refsect1>
95
96 <refsect1>
97  <title>Parameters</title>
98
99  <variablelist>
100
101   <varlistentry>
102    <term><literal>IF NOT EXISTS</literal></term>
103    <listitem>
104     <para>
105      Do not throw an error if a relation with the same name already exists.
106      A notice is issued in this case.  Note that there is no guarantee that
107      the existing relation is anything like the one that would have been
108      created.
109     </para>
110    </listitem>
111   </varlistentry>
112
113   <varlistentry>
114    <term><replaceable class="parameter">table_name</replaceable></term>
115    <listitem>
116     <para>
117      The name (optionally schema-qualified) of the table to be created.
118     </para>
119    </listitem>
120   </varlistentry>
121
122   <varlistentry>
123    <term><replaceable class="parameter">column_name</replaceable></term>
124    <listitem>
125     <para>
126      The name of a column to be created in the new table.
127     </para>
128    </listitem>
129   </varlistentry>
130
131   <varlistentry>
132    <term><replaceable class="parameter">data_type</replaceable></term>
133    <listitem>
134     <para>
135      The data type of the column. This can include array
136      specifiers. For more information on the data types supported by
137      <productname>PostgreSQL</productname>, refer to <xref
138      linkend="datatype"/>.
139     </para>
140    </listitem>
141   </varlistentry>
142
143   <varlistentry>
144    <term><literal>COLLATE <replaceable>collation</replaceable></literal></term>
145    <listitem>
146     <para>
147      The <literal>COLLATE</literal> clause assigns a collation to
148      the column (which must be of a collatable data type).
149      If not specified, the column data type's default collation is used.
150     </para>
151    </listitem>
152   </varlistentry>
153
154   <varlistentry>
155    <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
156    <listitem>
157     <para>
158      The optional <literal>INHERITS</literal> clause specifies a list of
159      tables from which the new foreign table automatically inherits
160      all columns.  Parent tables can be plain tables or foreign tables.
161      See the similar form of
162      <xref linkend="sql-createtable"/> for more details.
163     </para>
164    </listitem>
165   </varlistentry>
166
167   <varlistentry>
168    <term><literal>PARTITION OF <replaceable>parent_table</replaceable> FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable></literal></term>
169    <listitem>
170     <para>
171      This form can be used to create the foreign table as partition of
172      the given parent table with specified partition bound values.
173      See the similar form of
174      <xref linkend="sql-createtable"/> for more details.
175      Note that it is currently not allowed to create the foreign table as a
176      partition of the parent table if there are <literal>UNIQUE</literal>
177      indexes on the parent table.  (See also
178      <link linkend="sql-altertable"><command>ALTER TABLE ATTACH PARTITION</command></link>.)
179     </para>
180    </listitem>
181   </varlistentry>
182
183   <varlistentry>
184    <term><literal>CONSTRAINT <replaceable class="parameter">constraint_name</replaceable></literal></term>
185    <listitem>
186     <para>
187      An optional name for a column or table constraint.  If the
188      constraint is violated, the constraint name is present in error messages,
189      so constraint names like <literal>col must be positive</literal> can be used
190      to communicate helpful constraint information to client applications.
191      (Double-quotes are needed to specify constraint names that contain spaces.)
192      If a constraint name is not specified, the system generates a name.
193     </para>
194    </listitem>
195   </varlistentry>
196
197   <varlistentry>
198    <term><literal>NOT NULL</literal></term>
199    <listitem>
200     <para>
201      The column is not allowed to contain null values.
202     </para>
203    </listitem>
204   </varlistentry>
205
206   <varlistentry>
207    <term><literal>NULL</literal></term>
208    <listitem>
209     <para>
210      The column is allowed to contain null values. This is the default.
211     </para>
212
213     <para>
214      This clause is only provided for compatibility with
215      non-standard SQL databases.  Its use is discouraged in new
216      applications.
217     </para>
218    </listitem>
219   </varlistentry>
220
221   <varlistentry>
222    <term><literal>CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] </literal></term>
223    <listitem>
224     <para>
225      The <literal>CHECK</literal> clause specifies an expression producing a
226      Boolean result which each row in the foreign table is expected
227      to satisfy; that is, the expression should produce TRUE or UNKNOWN,
228      never FALSE, for all rows in the foreign table.
229      A check constraint specified as a column constraint should
230      reference that column's value only, while an expression
231      appearing in a table constraint can reference multiple columns.
232     </para>
233
234     <para>
235      Currently, <literal>CHECK</literal> expressions cannot contain
236      subqueries nor refer to variables other than columns of the
237      current row.  The system column <literal>tableoid</literal>
238      may be referenced, but not any other system column.
239     </para>
240
241     <para>
242      A constraint marked with <literal>NO INHERIT</literal> will not propagate to
243      child tables.
244     </para>
245    </listitem>
246   </varlistentry>
247
248   <varlistentry>
249    <term><literal>DEFAULT
250    <replaceable>default_expr</replaceable></literal></term>
251    <listitem>
252     <para>
253      The <literal>DEFAULT</literal> clause assigns a default data value for
254      the column whose column definition it appears within.  The value
255      is any variable-free expression (subqueries and cross-references
256      to other columns in the current table are not allowed).  The
257      data type of the default expression must match the data type of the
258      column.
259     </para>
260
261     <para>
262      The default expression will be used in any insert operation that
263      does not specify a value for the column.  If there is no default
264      for a column, then the default is null.
265     </para>
266    </listitem>
267   </varlistentry>
268
269   <varlistentry>
270    <term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
271    <listitem>
272     <para>
273      This clause creates the column as a <firstterm>generated
274      column</firstterm>.  The column cannot be written to, and when read the
275      result of the specified expression will be returned.
276     </para>
277
278     <para>
279      The keyword <literal>STORED</literal> is required to signify that the
280      column will be computed on write.  (The computed value will be presented
281      to the foreign-data wrapper for storage and must be returned on
282      reading.)
283     </para>
284
285     <para>
286      The generation expression can refer to other columns in the table, but
287      not other generated columns.  Any functions and operators used must be
288      immutable.  References to other tables are not allowed.
289     </para>
290    </listitem>
291   </varlistentry>
292
293   <varlistentry>
294    <term><replaceable class="parameter">server_name</replaceable></term>
295    <listitem>
296     <para>
297      The name of an existing foreign server to use for the foreign table.
298      For details on defining a server, see <xref
299      linkend="sql-createserver"/>.
300     </para>
301    </listitem>
302   </varlistentry>
303
304   <varlistentry>
305    <term><literal>OPTIONS ( <replaceable class="parameter">option</replaceable> '<replaceable class="parameter">value</replaceable>' [, ...] )</literal></term>
306    <listitem>
307     <para>
308      Options to be associated with the new foreign table or one of its
309      columns.
310      The allowed option names and values are specific to each foreign
311      data wrapper and are validated using the foreign-data wrapper's
312      validator function.  Duplicate option names are not allowed (although
313      it's OK for a table option and a column option to have the same name).
314     </para>
315    </listitem>
316   </varlistentry>
317
318  </variablelist>
319
320 </refsect1>
321
322 <refsect1>
323  <title>Notes</title>
324
325   <para>
326    Constraints on foreign tables (such as <literal>CHECK</literal>
327    or <literal>NOT NULL</literal> clauses) are not enforced by the
328    core <productname>PostgreSQL</productname> system, and most foreign data wrappers
329    do not attempt to enforce them either; that is, the constraint is
330    simply assumed to hold true.  There would be little point in such
331    enforcement since it would only apply to rows inserted or updated via
332    the foreign table, and not to rows modified by other means, such as
333    directly on the remote server.  Instead, a constraint attached to a
334    foreign table should represent a constraint that is being enforced by
335    the remote server.
336   </para>
337
338   <para>
339    Some special-purpose foreign data wrappers might be the only access
340    mechanism for the data they access, and in that case it might be
341    appropriate for the foreign data wrapper itself to perform constraint
342    enforcement.  But you should not assume that a wrapper does that
343    unless its documentation says so.
344   </para>
345
346   <para>
347    Although <productname>PostgreSQL</productname> does not attempt to enforce
348    constraints on foreign tables, it does assume that they are correct
349    for purposes of query optimization.  If there are rows visible in the
350    foreign table that do not satisfy a declared constraint, queries on
351    the table might produce incorrect answers.  It is the user's
352    responsibility to ensure that the constraint definition matches
353    reality.
354   </para>
355
356   <para>
357    Similar considerations apply to generated columns.  Stored generated
358    columns are computed on insert or update on the local
359    <productname>PostgreSQL</productname> server and handed to the
360    foreign-data wrapper for writing out to the foreign data store, but it is
361    not enforced that a query of the foreign table returns values for stored
362    generated columns that are consistent with the generation expression.
363    Again, this might result in incorrect query results.
364   </para>
365
366   <para>
367    While rows can be moved from local partitions to a foreign-table partition
368    (provided the foreign data wrapper supports tuple routing), they cannot be
369    moved from a foreign-table partition to another partition.
370   </para>
371 </refsect1>
372
373 <refsect1 id="sql-createforeigntable-examples">
374  <title>Examples</title>
375
376  <para>
377   Create foreign table <structname>films</structname>, which will be accessed through
378   the server <structname>film_server</structname>:
379
380<programlisting>
381CREATE FOREIGN TABLE films (
382    code        char(5) NOT NULL,
383    title       varchar(40) NOT NULL,
384    did         integer NOT NULL,
385    date_prod   date,
386    kind        varchar(10),
387    len         interval hour to minute
388)
389SERVER film_server;
390</programlisting></para>
391
392  <para>
393   Create foreign table <structname>measurement_y2016m07</structname>, which will be
394   accessed through the server <structname>server_07</structname>, as a partition
395   of the range partitioned table <structname>measurement</structname>:
396
397<programlisting>
398CREATE FOREIGN TABLE measurement_y2016m07
399    PARTITION OF measurement FOR VALUES FROM ('2016-07-01') TO ('2016-08-01')
400    SERVER server_07;
401</programlisting></para>
402
403 </refsect1>
404
405 <refsect1 id="sql-createforeigntable-compatibility">
406  <title>Compatibility</title>
407
408  <para>
409   The <command>CREATE FOREIGN TABLE</command> command largely conforms to the
410   <acronym>SQL</acronym> standard; however, much as with
411   <link linkend="sql-createtable"><command>CREATE TABLE</command></link>,
412   <literal>NULL</literal> constraints and zero-column foreign tables are permitted.
413   The ability to specify column default values is also
414   a <productname>PostgreSQL</productname> extension.  Table inheritance, in the form
415   defined by <productname>PostgreSQL</productname>, is nonstandard.
416  </para>
417
418 </refsect1>
419
420 <refsect1>
421  <title>See Also</title>
422
423  <simplelist type="inline">
424   <member><xref linkend="sql-alterforeigntable"/></member>
425   <member><xref linkend="sql-dropforeigntable"/></member>
426   <member><xref linkend="sql-createtable"/></member>
427   <member><xref linkend="sql-createserver"/></member>
428   <member><xref linkend="sql-importforeignschema"/></member>
429  </simplelist>
430 </refsect1>
431</refentry>
432