alter_foreign_table.sgml 14.2 KB
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416
<!--
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 ] <replaceable class="PARAMETER">name</replaceable>
    <replaceable class="PARAMETER">action</replaceable> [, ... ]
ALTER FOREIGN TABLE [ IF EXISTS ] <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>
    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> OPTIONS ( [ ADD | SET | DROP ] <replaceable class="PARAMETER">option</replaceable> ['<replaceable class="PARAMETER">value</replaceable>'] [, ... ])
    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>
    OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
    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
      <xref linkend="SQL-CREATEFOREIGNTABLE">.
      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</> 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>IF EXISTS</literal></term>
    <listitem>
     <para>
      Do not throw an error if the foreign table does not exist. A notice is
      issued in this case.
     </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.
     </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</> 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
      <xref linkend="sql-analyze"> operations.
      See the similar form of <xref linkend="sql-altertable">
      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 <xref linkend="sql-altertable">
      for more details.
     </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 <xref linkend="sql-altertable"> for more
      details.
     </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>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>

   <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>SET</>, and <literal>DROP</>
      specify the action to be performed.  <literal>ADD</> 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>

  </variablelist>
  </para>

  <para>
   All the actions except <literal>RENAME</literal> and <literal>SET SCHEMA</>
   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>
   You must own the table to use <command>ALTER FOREIGN TABLE</>.
   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 also be a direct or indirect member of 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.
       </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><literal>CASCADE</literal></term>
      <listitem>
       <para>
        Automatically drop objects that depend on the dropped column
        (for example, views referencing the column).
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>RESTRICT</literal></term>
      <listitem>
       <para>
        Refuse to drop the column 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">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</> constraint is
    added, or a column type is changed with <literal>SET DATA TYPE</>.  It is
    the user's responsibility to ensure that the table definition matches the
    remote side.
   </para>

   <para>
    Refer to <xref linkend="sql-createforeigntable"> 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 'value3');
</programlisting></para>

 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   The forms <literal>ADD</literal>, <literal>DROP</>,
   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 is an extension.
  </para>

  <para>
   <command>ALTER FOREIGN TABLE DROP COLUMN</> 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>
</refentry>