postgresql/doc/src/sgml/ref/alter_foreign_table.sgml

557 lines
20 KiB
Plaintext

<!--
doc/src/sgml/rel/alter_foreign_table.sgml
PostgreSQL documentation
-->
<refentry id="sql-alterforeigntable">
<indexterm zone="sql-alterforeigntable">
<primary>ALTER FOREIGN TABLE</primary>
</indexterm>
<refmeta>
<refentrytitle>ALTER FOREIGN TABLE</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>ALTER FOREIGN TABLE</refname>
<refpurpose>change the definition of a foreign table</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
ALTER FOREIGN TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="parameter">name</replaceable> [ * ]
<replaceable class="parameter">action</replaceable> [, ... ]
ALTER FOREIGN TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="parameter">name</replaceable> [ * ]
RENAME [ COLUMN ] <replaceable class="parameter">column_name</replaceable> TO <replaceable class="parameter">new_column_name</replaceable>
ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
RENAME TO <replaceable class="parameter">new_name</replaceable>
ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
ADD [ COLUMN ] <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">data_type</replaceable> [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
DROP [ COLUMN ] [ IF EXISTS ] <replaceable class="parameter">column_name</replaceable> [ RESTRICT | CASCADE ]
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> [ SET DATA ] TYPE <replaceable class="parameter">data_type</replaceable> [ COLLATE <replaceable class="parameter">collation</replaceable> ]
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET DEFAULT <replaceable class="parameter">expression</replaceable>
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> DROP DEFAULT
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> { SET | DROP } NOT NULL
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET STATISTICS <replaceable class="parameter">integer</replaceable>
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET ( <replaceable class="parameter">attribute_option</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] )
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> RESET ( <replaceable class="parameter">attribute_option</replaceable> [, ... ] )
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }
ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> OPTIONS ( [ ADD | SET | DROP ] <replaceable class="parameter">option</replaceable> ['<replaceable class="parameter">value</replaceable>'] [, ... ])
ADD <replaceable class="parameter">table_constraint</replaceable> [ NOT VALID ]
VALIDATE CONSTRAINT <replaceable class="parameter">constraint_name</replaceable>
DROP CONSTRAINT [ IF EXISTS ] <replaceable class="parameter">constraint_name</replaceable> [ RESTRICT | CASCADE ]
DISABLE TRIGGER [ <replaceable class="parameter">trigger_name</replaceable> | ALL | USER ]
ENABLE TRIGGER [ <replaceable class="parameter">trigger_name</replaceable> | ALL | USER ]
ENABLE REPLICA TRIGGER <replaceable class="parameter">trigger_name</replaceable>
ENABLE ALWAYS TRIGGER <replaceable class="parameter">trigger_name</replaceable>
SET WITHOUT OIDS
INHERIT <replaceable class="parameter">parent_table</replaceable>
NO INHERIT <replaceable class="parameter">parent_table</replaceable>
OWNER TO { <replaceable class="parameter">new_owner</replaceable> | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
OPTIONS ( [ ADD | SET | DROP ] <replaceable class="parameter">option</replaceable> ['<replaceable class="parameter">value</replaceable>'] [, ... ])
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>ALTER FOREIGN TABLE</command> changes the definition of an
existing foreign table. There are several subforms:
<variablelist>
<varlistentry>
<term><literal>ADD COLUMN</literal></term>
<listitem>
<para>
This form adds a new column to the foreign table, using the same syntax as
<link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link>.
Unlike the case when adding a column to a regular table, nothing happens
to the underlying storage: this action simply declares that
some new column is now accessible through the foreign table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DROP COLUMN [ IF EXISTS ]</literal></term>
<listitem>
<para>
This form drops a column from a foreign table.
You will need to say <literal>CASCADE</literal> if
anything outside the table depends on the column; for example,
views.
If <literal>IF EXISTS</literal> is specified and the column
does not exist, no error is thrown. In this case a notice
is issued instead.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET DATA TYPE</literal></term>
<listitem>
<para>
This form changes the type of a column of a foreign table.
Again, this has no effect on any underlying storage: this action simply
changes the type that <productname>PostgreSQL</productname> believes the column to
have.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET</literal>/<literal>DROP DEFAULT</literal></term>
<listitem>
<para>
These forms set or remove the default value for a column.
Default values only apply in subsequent <command>INSERT</command>
or <command>UPDATE</command> commands; they do not cause rows already in the
table to change.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET</literal>/<literal>DROP NOT NULL</literal></term>
<listitem>
<para>
Mark a column as allowing, or not allowing, null values.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET STATISTICS</literal></term>
<listitem>
<para>
This form
sets the per-column statistics-gathering target for subsequent
<link linkend="sql-analyze"><command>ANALYZE</command></link> operations.
See the similar form of <link linkend="sql-altertable"><command>ALTER TABLE</command></link>
for more details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET ( <replaceable class="parameter">attribute_option</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] )</literal></term>
<term><literal>RESET ( <replaceable class="parameter">attribute_option</replaceable> [, ... ] )</literal></term>
<listitem>
<para>
This form sets or resets per-attribute options.
See the similar form of <link linkend="sql-altertable"><command>ALTER TABLE</command></link>
for more details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<literal>SET STORAGE</literal>
</term>
<listitem>
<para>
This form sets the storage mode for a column.
See the similar form of <link linkend="sql-altertable"><command>ALTER TABLE</command></link>
for more details.
Note that the storage mode has no effect unless the table's
foreign-data wrapper chooses to pay attention to it.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ADD <replaceable class="parameter">table_constraint</replaceable> [ NOT VALID ]</literal></term>
<listitem>
<para>
This form adds a new constraint to a foreign table, using the same
syntax as <link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link>.
Currently only <literal>CHECK</literal> constraints are supported.
</para>
<para>
Unlike the case when adding a constraint to a regular table, nothing is
done to verify the constraint is correct; rather, this action simply
declares that some new condition should be assumed to hold for all rows
in the foreign table. (See the discussion
in <link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link>.)
If the constraint is marked <literal>NOT VALID</literal>, then it isn't
assumed to hold, but is only recorded for possible future use.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>VALIDATE CONSTRAINT</literal></term>
<listitem>
<para>
This form marks as valid a constraint that was previously marked
as <literal>NOT VALID</literal>. No action is taken to verify the
constraint, but future queries will assume that it holds.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DROP CONSTRAINT [ IF EXISTS ]</literal></term>
<listitem>
<para>
This form drops the specified constraint on a foreign table.
If <literal>IF EXISTS</literal> is specified and the constraint
does not exist, no error is thrown.
In this case a notice is issued instead.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] TRIGGER</literal></term>
<listitem>
<para>
These forms configure the firing of trigger(s) belonging to the foreign
table. See the similar form of <link linkend="sql-altertable"><command>ALTER TABLE</command></link> for more
details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET WITHOUT OIDS</literal></term>
<listitem>
<para>
Backward compatibility syntax for removing the <literal>oid</literal>
system column. As <literal>oid</literal> system columns cannot be added
anymore, this never has an effect.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>INHERIT <replaceable class="parameter">parent_table</replaceable></literal></term>
<listitem>
<para>
This form adds the target foreign table as a new child of the specified
parent table.
See the similar form of <link linkend="sql-altertable"><command>ALTER TABLE</command></link>
for more details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>NO INHERIT <replaceable class="parameter">parent_table</replaceable></literal></term>
<listitem>
<para>
This form removes the target foreign table from the list of children of
the specified parent table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>OWNER</literal></term>
<listitem>
<para>
This form changes the owner of the foreign table to the
specified user.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>OPTIONS ( [ ADD | SET | DROP ] <replaceable class="parameter">option</replaceable> ['<replaceable class="parameter">value</replaceable>'] [, ... ] )</literal></term>
<listitem>
<para>
Change options for the foreign table or one of its columns.
<literal>ADD</literal>, <literal>SET</literal>, and <literal>DROP</literal>
specify the action to be performed. <literal>ADD</literal> is assumed
if no operation is explicitly specified. Duplicate option names are not
allowed (although it's OK for a table option and a column option to have
the same name). Option names and values are also validated using the
foreign data wrapper library.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RENAME</literal></term>
<listitem>
<para>
The <literal>RENAME</literal> forms change the name of a foreign table
or the name of an individual column in a foreign table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET SCHEMA</literal></term>
<listitem>
<para>
This form moves the foreign table into another schema.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
All the actions except <literal>RENAME</literal> and <literal>SET SCHEMA</literal>
can be combined into
a list of multiple alterations to apply in parallel. For example, it
is possible to add several columns and/or alter the type of several
columns in a single command.
</para>
<para>
If the command is written as <literal>ALTER FOREIGN TABLE IF EXISTS ...</literal>
and the foreign table does not exist, no error is thrown. A notice is
issued in this case.
</para>
<para>
You must own the table to use <command>ALTER FOREIGN TABLE</command>.
To change the schema of a foreign table, you must also have
<literal>CREATE</literal> privilege on the new schema.
To alter the owner, you must be able to <literal>SET ROLE</literal> to the
new owning role, and that role must have <literal>CREATE</literal> privilege
on the table's schema. (These restrictions enforce that altering the owner
doesn't do anything you couldn't do by dropping and recreating the table.
However, a superuser can alter ownership of any table anyway.)
To add a column or alter a column type, you must also
have <literal>USAGE</literal> privilege on the data type.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of an existing foreign table to
alter. If <literal>ONLY</literal> is specified before the table name, only
that table is altered. If <literal>ONLY</literal> is not specified, the table
and all its descendant tables (if any) are altered. Optionally,
<literal>*</literal> can be specified after the table name to explicitly
indicate that descendant tables are included.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">column_name</replaceable></term>
<listitem>
<para>
Name of a new or existing column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_column_name</replaceable></term>
<listitem>
<para>
New name for an existing column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_name</replaceable></term>
<listitem>
<para>
New name for the table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">data_type</replaceable></term>
<listitem>
<para>
Data type of the new column, or new data type for an existing
column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">table_constraint</replaceable></term>
<listitem>
<para>
New table constraint for the foreign table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">constraint_name</replaceable></term>
<listitem>
<para>
Name of an existing constraint to drop.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CASCADE</literal></term>
<listitem>
<para>
Automatically drop objects that depend on the dropped column
or constraint (for example, views referencing the column),
and in turn all objects that depend on those objects
(see <xref linkend="ddl-depend"/>).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RESTRICT</literal></term>
<listitem>
<para>
Refuse to drop the column or constraint if there are any dependent
objects. This is the default behavior.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">trigger_name</replaceable></term>
<listitem>
<para>
Name of a single trigger to disable or enable.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ALL</literal></term>
<listitem>
<para>
Disable or enable all triggers belonging to the foreign table. (This
requires superuser privilege if any of the triggers are internally
generated triggers. The core system does not add such triggers to
foreign tables, but add-on code could do so.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>USER</literal></term>
<listitem>
<para>
Disable or enable all triggers belonging to the foreign table except
for internally generated triggers.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">parent_table</replaceable></term>
<listitem>
<para>
A parent table to associate or de-associate with this foreign table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_owner</replaceable></term>
<listitem>
<para>
The user name of the new owner of the table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_schema</replaceable></term>
<listitem>
<para>
The name of the schema to which the table will be moved.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
The key word <literal>COLUMN</literal> is noise and can be omitted.
</para>
<para>
Consistency with the foreign server is not checked when a column is added
or removed with <literal>ADD COLUMN</literal> or
<literal>DROP COLUMN</literal>, a <literal>NOT NULL</literal>
or <literal>CHECK</literal> constraint is added, or a column type is changed
with <literal>SET DATA TYPE</literal>. It is the user's responsibility to ensure
that the table definition matches the remote side.
</para>
<para>
Refer to <link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link> for a further description of valid
parameters.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
To mark a column as not-null:
<programlisting>
ALTER FOREIGN TABLE distributors ALTER COLUMN street SET NOT NULL;
</programlisting>
</para>
<para>
To change options of a foreign table:
<programlisting>
ALTER FOREIGN TABLE myschema.distributors OPTIONS (ADD opt1 'value', SET opt2 'value2', DROP opt3);
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
The forms <literal>ADD</literal>, <literal>DROP</literal>,
and <literal>SET DATA TYPE</literal>
conform with the SQL standard. The other forms are
<productname>PostgreSQL</productname> extensions of the SQL standard.
Also, the ability to specify more than one manipulation in a single
<command>ALTER FOREIGN TABLE</command> command is an extension.
</para>
<para>
<command>ALTER FOREIGN TABLE DROP COLUMN</command> can be used to drop the only
column of a foreign table, leaving a zero-column table. This is an
extension of SQL, which disallows zero-column foreign tables.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-createforeigntable"/></member>
<member><xref linkend="sql-dropforeigntable"/></member>
</simplelist>
</refsect1>
</refentry>