table of contents
CREATE FOREIGN TABLE(7) | PostgreSQL 17.1 Documentation | CREATE FOREIGN TABLE(7) |
NAME¶
CREATE_FOREIGN_TABLE - define a new foreign table
SYNOPSIS¶
CREATE FOREIGN TABLE [ IF NOT EXISTS ] table_name ( [
{ column_name data_type [ OPTIONS ( option 'value' [, ... ] ) ] [ COLLATE collation ] [ column_constraint [ ... ] ]
| table_constraint }
[, ... ] ] ) [ INHERITS ( parent_table [, ... ] ) ]
SERVER server_name [ OPTIONS ( option 'value' [, ... ] ) ] CREATE FOREIGN TABLE [ IF NOT EXISTS ] table_name
PARTITION OF parent_table [ (
{ column_name [ WITH OPTIONS ] [ column_constraint [ ... ] ]
| table_constraint }
[, ... ] ) ] { FOR VALUES partition_bound_spec | DEFAULT }
SERVER server_name [ OPTIONS ( option 'value' [, ... ] ) ] where column_constraint is: [ CONSTRAINT constraint_name ] { NOT NULL |
NULL |
CHECK ( expression ) [ NO INHERIT ] |
DEFAULT default_expr |
GENERATED ALWAYS AS ( generation_expr ) STORED } and table_constraint is: [ CONSTRAINT constraint_name ] CHECK ( expression ) [ NO INHERIT ] and partition_bound_spec is: IN ( partition_bound_expr [, ...] ) | FROM ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] )
TO ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] ) | WITH ( MODULUS numeric_literal, REMAINDER numeric_literal )
DESCRIPTION¶
CREATE FOREIGN TABLE creates a new foreign table in the current database. The table will be owned by the user issuing the command.
If a schema name is given (for example, CREATE FOREIGN TABLE myschema.mytable ...) then the table is created in the specified schema. Otherwise it is created in the current schema. The name of the foreign table must be distinct from the name of any other relation (table, sequence, index, view, materialized view, or foreign table) in the same schema.
CREATE FOREIGN TABLE also automatically creates a data type that represents the composite type corresponding to one row of the foreign table. Therefore, foreign tables cannot have the same name as any existing data type in the same schema.
If PARTITION OF clause is specified then the table is created as a partition of parent_table with specified bounds.
To be able to create a foreign table, you must have USAGE privilege on the foreign server, as well as USAGE privilege on all column types used in the table.
PARAMETERS¶
IF NOT EXISTS
table_name
column_name
data_type
COLLATE collation
INHERITS ( parent_table [, ... ] )
PARTITION OF parent_table { FOR VALUES partition_bound_spec | DEFAULT }
CONSTRAINT constraint_name
NOT NULL
NULL
This clause is only provided for compatibility with non-standard SQL databases. Its use is discouraged in new applications.
CHECK ( expression ) [ NO INHERIT ]
Currently, CHECK expressions cannot contain subqueries nor refer to variables other than columns of the current row. The system column tableoid may be referenced, but not any other system column.
A constraint marked with NO INHERIT will not propagate to child tables.
DEFAULT default_expr
The default expression will be used in any insert operation that does not specify a value for the column. If there is no default for a column, then the default is null.
GENERATED ALWAYS AS ( generation_expr ) STORED
The keyword STORED is required to signify that the column will be computed on write. (The computed value will be presented to the foreign-data wrapper for storage and must be returned on reading.)
The generation expression can refer to other columns in the table, but not other generated columns. Any functions and operators used must be immutable. References to other tables are not allowed.
server_name
OPTIONS ( option 'value' [, ...] )
NOTES¶
Constraints on foreign tables (such as CHECK or NOT NULL clauses) are not enforced by the core PostgreSQL system, and most foreign data wrappers do not attempt to enforce them either; that is, the constraint is simply assumed to hold true. There would be little point in such enforcement since it would only apply to rows inserted or updated via the foreign table, and not to rows modified by other means, such as directly on the remote server. Instead, a constraint attached to a foreign table should represent a constraint that is being enforced by the remote server.
Some special-purpose foreign data wrappers might be the only access mechanism for the data they access, and in that case it might be appropriate for the foreign data wrapper itself to perform constraint enforcement. But you should not assume that a wrapper does that unless its documentation says so.
Although PostgreSQL does not attempt to enforce constraints on foreign tables, it does assume that they are correct for purposes of query optimization. If there are rows visible in the foreign table that do not satisfy a declared constraint, queries on the table might produce errors or incorrect answers. It is the user's responsibility to ensure that the constraint definition matches reality.
Caution
When a foreign table is used as a partition of a partitioned table, there is an implicit constraint that its contents must satisfy the partitioning rule. Again, it is the user's responsibility to ensure that that is true, which is best done by installing a matching constraint on the remote server.
Within a partitioned table containing foreign-table partitions, an UPDATE that changes the partition key value can cause a row to be moved from a local partition to a foreign-table partition, provided the foreign data wrapper supports tuple routing. However, it is not currently possible to move a row from a foreign-table partition to another partition. An UPDATE that would require doing that will fail due to the partitioning constraint, assuming that that is properly enforced by the remote server.
Similar considerations apply to generated columns. Stored generated columns are computed on insert or update on the local PostgreSQL server and handed to the foreign-data wrapper for writing out to the foreign data store, but it is not enforced that a query of the foreign table returns values for stored generated columns that are consistent with the generation expression. Again, this might result in incorrect query results.
EXAMPLES¶
Create foreign table films, which will be accessed through the server film_server:
CREATE FOREIGN TABLE films (
code char(5) NOT NULL,
title varchar(40) NOT NULL,
did integer NOT NULL,
date_prod date,
kind varchar(10),
len interval hour to minute ) SERVER film_server;
Create foreign table measurement_y2016m07, which will be accessed through the server server_07, as a partition of the range partitioned table measurement:
CREATE FOREIGN TABLE measurement_y2016m07
PARTITION OF measurement FOR VALUES FROM ('2016-07-01') TO ('2016-08-01')
SERVER server_07;
COMPATIBILITY¶
The CREATE FOREIGN TABLE command largely conforms to the SQL standard; however, much as with CREATE TABLE, NULL constraints and zero-column foreign tables are permitted. The ability to specify column default values is also a PostgreSQL extension. Table inheritance, in the form defined by PostgreSQL, is nonstandard.
SEE ALSO¶
ALTER FOREIGN TABLE (ALTER_FOREIGN_TABLE(7)), DROP FOREIGN TABLE (DROP_FOREIGN_TABLE(7)), CREATE TABLE (CREATE_TABLE(7)), CREATE SERVER (CREATE_SERVER(7)), IMPORT FOREIGN SCHEMA (IMPORT_FOREIGN_SCHEMA(7))
2024 | PostgreSQL 17.1 |