doc: ALTER DEFAULT PRIVILEGES does not affect inherited roles
[pgsql.git] / doc / src / sgml / ref / alter_table.sgml
blob2c4138e4e9f5c0e9541e8649d5e67fb094fa3813
1 <!--
2 doc/src/sgml/ref/alter_table.sgml
3 PostgreSQL documentation
4 -->
6 <refentry id="sql-altertable">
7 <indexterm zone="sql-altertable">
8 <primary>ALTER TABLE</primary>
9 </indexterm>
11 <refmeta>
12 <refentrytitle>ALTER TABLE</refentrytitle>
13 <manvolnum>7</manvolnum>
14 <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
17 <refnamediv>
18 <refname>ALTER TABLE</refname>
19 <refpurpose>change the definition of a table</refpurpose>
20 </refnamediv>
22 <refsynopsisdiv>
23 <synopsis>
24 ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="parameter">name</replaceable> [ * ]
25 <replaceable class="parameter">action</replaceable> [, ... ]
26 ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="parameter">name</replaceable> [ * ]
27 RENAME [ COLUMN ] <replaceable class="parameter">column_name</replaceable> TO <replaceable class="parameter">new_column_name</replaceable>
28 ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="parameter">name</replaceable> [ * ]
29 RENAME CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> TO <replaceable class="parameter">new_constraint_name</replaceable>
30 ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
31 RENAME TO <replaceable class="parameter">new_name</replaceable>
32 ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
33 SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
34 ALTER TABLE ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="parameter">role_name</replaceable> [, ... ] ]
35 SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable> [ NOWAIT ]
36 ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
37 ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
38 ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
39 DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
41 <phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
43 ADD [ COLUMN ] [ IF NOT EXISTS ] <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">data_type</replaceable> [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
44 DROP [ COLUMN ] [ IF EXISTS ] <replaceable class="parameter">column_name</replaceable> [ RESTRICT | CASCADE ]
45 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> [ SET DATA ] TYPE <replaceable class="parameter">data_type</replaceable> [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ USING <replaceable class="parameter">expression</replaceable> ]
46 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET DEFAULT <replaceable class="parameter">expression</replaceable>
47 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> DROP DEFAULT
48 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> { SET | DROP } NOT NULL
49 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> DROP EXPRESSION [ IF EXISTS ]
50 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ]
51 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> { SET GENERATED { ALWAYS | BY DEFAULT } | SET <replaceable>sequence_option</replaceable> | RESTART [ [ WITH ] <replaceable class="parameter">restart</replaceable> ] } [...]
52 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> DROP IDENTITY [ IF EXISTS ]
53 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET STATISTICS <replaceable class="parameter">integer</replaceable>
54 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET ( <replaceable class="parameter">attribute_option</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] )
55 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> RESET ( <replaceable class="parameter">attribute_option</replaceable> [, ... ] )
56 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }
57 ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET COMPRESSION <replaceable class="parameter">compression_method</replaceable>
58 ADD <replaceable class="parameter">table_constraint</replaceable> [ NOT VALID ]
59 ADD <replaceable class="parameter">table_constraint_using_index</replaceable>
60 ALTER CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
61 VALIDATE CONSTRAINT <replaceable class="parameter">constraint_name</replaceable>
62 DROP CONSTRAINT [ IF EXISTS ] <replaceable class="parameter">constraint_name</replaceable> [ RESTRICT | CASCADE ]
63 DISABLE TRIGGER [ <replaceable class="parameter">trigger_name</replaceable> | ALL | USER ]
64 ENABLE TRIGGER [ <replaceable class="parameter">trigger_name</replaceable> | ALL | USER ]
65 ENABLE REPLICA TRIGGER <replaceable class="parameter">trigger_name</replaceable>
66 ENABLE ALWAYS TRIGGER <replaceable class="parameter">trigger_name</replaceable>
67 DISABLE RULE <replaceable class="parameter">rewrite_rule_name</replaceable>
68 ENABLE RULE <replaceable class="parameter">rewrite_rule_name</replaceable>
69 ENABLE REPLICA RULE <replaceable class="parameter">rewrite_rule_name</replaceable>
70 ENABLE ALWAYS RULE <replaceable class="parameter">rewrite_rule_name</replaceable>
71 DISABLE ROW LEVEL SECURITY
72 ENABLE ROW LEVEL SECURITY
73 FORCE ROW LEVEL SECURITY
74 NO FORCE ROW LEVEL SECURITY
75 CLUSTER ON <replaceable class="parameter">index_name</replaceable>
76 SET WITHOUT CLUSTER
77 SET WITHOUT OIDS
78 SET ACCESS METHOD <replaceable class="parameter">new_access_method</replaceable>
79 SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable>
80 SET { LOGGED | UNLOGGED }
81 SET ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )
82 RESET ( <replaceable class="parameter">storage_parameter</replaceable> [, ... ] )
83 INHERIT <replaceable class="parameter">parent_table</replaceable>
84 NO INHERIT <replaceable class="parameter">parent_table</replaceable>
85 OF <replaceable class="parameter">type_name</replaceable>
86 NOT OF
87 OWNER TO { <replaceable class="parameter">new_owner</replaceable> | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
88 REPLICA IDENTITY { DEFAULT | USING INDEX <replaceable class="parameter">index_name</replaceable> | FULL | NOTHING }
90 <phrase>and <replaceable class="parameter">partition_bound_spec</replaceable> is:</phrase>
92 IN ( <replaceable class="parameter">partition_bound_expr</replaceable> [, ...] ) |
93 FROM ( { <replaceable class="parameter">partition_bound_expr</replaceable> | MINVALUE | MAXVALUE } [, ...] )
94 TO ( { <replaceable class="parameter">partition_bound_expr</replaceable> | MINVALUE | MAXVALUE } [, ...] ) |
95 WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REMAINDER <replaceable class="parameter">numeric_literal</replaceable> )
97 <phrase>and <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
99 [ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
100 { NOT NULL |
101 NULL |
102 CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
103 DEFAULT <replaceable>default_expr</replaceable> |
104 GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
105 GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
106 UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
107 PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
108 REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
109 [ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
110 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
112 <phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
114 [ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
115 { CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
116 NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
117 UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
118 PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
119 EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ] |
120 FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
121 [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
122 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
124 <phrase>and <replaceable class="parameter">table_constraint_using_index</replaceable> is:</phrase>
126 [ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
127 { UNIQUE | PRIMARY KEY } USING INDEX <replaceable class="parameter">index_name</replaceable>
128 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
130 <phrase><replaceable class="parameter">index_parameters</replaceable> in <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and <literal>EXCLUDE</literal> constraints are:</phrase>
132 [ INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ]
133 [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
134 [ USING INDEX TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
136 <phrase><replaceable class="parameter">exclude_element</replaceable> in an <literal>EXCLUDE</literal> constraint is:</phrase>
138 { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ <replaceable class="parameter">opclass</replaceable> ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
140 <phrase><replaceable class="parameter">referential_action</replaceable> in a <literal>FOREIGN KEY</literal>/<literal>REFERENCES</literal> constraint is:</phrase>
142 { NO ACTION | RESTRICT | CASCADE | SET NULL [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] | SET DEFAULT [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] }
143 </synopsis>
144 </refsynopsisdiv>
146 <refsect1>
147 <title>Description</title>
149 <para>
150 <command>ALTER TABLE</command> changes the definition of an existing table.
151 There are several subforms described below. Note that the lock level required
152 may differ for each subform. An <literal>ACCESS EXCLUSIVE</literal> lock is
153 acquired unless explicitly noted. When multiple subcommands are given, the
154 lock acquired will be the strictest one required by any subcommand.
156 <variablelist>
157 <varlistentry id="sql-altertable-desc-add-column">
158 <term><literal>ADD COLUMN [ IF NOT EXISTS ]</literal></term>
159 <listitem>
160 <para>
161 This form adds a new column to the table, using the same syntax as
162 <link linkend="sql-createtable"><command>CREATE TABLE</command></link>. If <literal>IF NOT EXISTS</literal>
163 is specified and a column already exists with this name,
164 no error is thrown.
165 </para>
166 </listitem>
167 </varlistentry>
169 <varlistentry id="sql-altertable-desc-drop-column">
170 <term><literal>DROP COLUMN [ IF EXISTS ]</literal></term>
171 <listitem>
172 <para>
173 This form drops a column from a table. Indexes and
174 table constraints involving the column will be automatically
175 dropped as well.
176 Multivariate statistics referencing the dropped column will also be
177 removed if the removal of the column would cause the statistics to
178 contain data for only a single column.
179 You will need to say <literal>CASCADE</literal> if anything outside the table
180 depends on the column, for example, foreign key references or views.
181 If <literal>IF EXISTS</literal> is specified and the column
182 does not exist, no error is thrown. In this case a notice
183 is issued instead.
184 </para>
185 </listitem>
186 </varlistentry>
188 <varlistentry id="sql-altertable-desc-set-data-type">
189 <term><literal>SET DATA TYPE</literal></term>
190 <listitem>
191 <para>
192 This form changes the type of a column of a table. Indexes and
193 simple table constraints involving the column will be automatically
194 converted to use the new column type by reparsing the originally
195 supplied expression.
196 The optional <literal>COLLATE</literal> clause specifies a collation
197 for the new column; if omitted, the collation is the default for the
198 new column type.
199 The optional <literal>USING</literal>
200 clause specifies how to compute the new column value from the old;
201 if omitted, the default conversion is the same as an assignment
202 cast from old data type to new. A <literal>USING</literal>
203 clause must be provided if there is no implicit or assignment
204 cast from old to new type.
205 </para>
207 <para>
208 When this form is used, the column's statistics are removed,
209 so running <link linkend="sql-analyze"><command>ANALYZE</command></link>
210 on the table afterwards is recommended.
211 </para>
212 </listitem>
213 </varlistentry>
215 <varlistentry id="sql-altertable-desc-set-drop-default">
216 <term><literal>SET</literal>/<literal>DROP DEFAULT</literal></term>
217 <listitem>
218 <para>
219 These forms set or remove the default value for a column (where
220 removal is equivalent to setting the default value to NULL). The new
221 default value will only apply in subsequent <command>INSERT</command>
222 or <command>UPDATE</command> commands; it does not cause rows already
223 in the table to change.
224 </para>
225 </listitem>
226 </varlistentry>
228 <varlistentry id="sql-altertable-desc-set-drop-not-null">
229 <term><literal>SET</literal>/<literal>DROP NOT NULL</literal></term>
230 <listitem>
231 <para>
232 These forms change whether a column is marked to allow null
233 values or to reject null values.
234 </para>
236 <para>
237 <literal>SET NOT NULL</literal> may only be applied to a column
238 provided none of the records in the table contain a
239 <literal>NULL</literal> value for the column. Ordinarily this is
240 checked during the <literal>ALTER TABLE</literal> by scanning the
241 entire table; however, if a valid <literal>CHECK</literal> constraint is
242 found which proves no <literal>NULL</literal> can exist, then the
243 table scan is skipped.
244 </para>
246 <para>
247 If this table is a partition, one cannot perform <literal>DROP NOT NULL</literal>
248 on a column if it is marked <literal>NOT NULL</literal> in the parent
249 table. To drop the <literal>NOT NULL</literal> constraint from all the
250 partitions, perform <literal>DROP NOT NULL</literal> on the parent
251 table. Even if there is no <literal>NOT NULL</literal> constraint on the
252 parent, such a constraint can still be added to individual partitions,
253 if desired; that is, the children can disallow nulls even if the parent
254 allows them, but not the other way around.
255 </para>
256 </listitem>
257 </varlistentry>
259 <varlistentry id="sql-altertable-desc-drop-expression">
260 <term><literal>DROP EXPRESSION [ IF EXISTS ]</literal></term>
261 <listitem>
262 <para>
263 This form turns a stored generated column into a normal base column.
264 Existing data in the columns is retained, but future changes will no
265 longer apply the generation expression.
266 </para>
268 <para>
269 If <literal>DROP EXPRESSION IF EXISTS</literal> is specified and the
270 column is not a stored generated column, no error is thrown. In this
271 case a notice is issued instead.
272 </para>
273 </listitem>
274 </varlistentry>
276 <varlistentry id="sql-altertable-desc-generated-identity">
277 <term><literal>ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY</literal></term>
278 <term><literal>SET GENERATED { ALWAYS | BY DEFAULT }</literal></term>
279 <term><literal>DROP IDENTITY [ IF EXISTS ]</literal></term>
280 <listitem>
281 <para>
282 These forms change whether a column is an identity column or change the
283 generation attribute of an existing identity column.
284 See <link linkend="sql-createtable"><command>CREATE TABLE</command></link> for details.
285 Like <literal>SET DEFAULT</literal>, these forms only affect the
286 behavior of subsequent <command>INSERT</command>
287 and <command>UPDATE</command> commands; they do not cause rows
288 already in the table to change.
289 </para>
291 <para>
292 If <literal>DROP IDENTITY IF EXISTS</literal> is specified and the
293 column is not an identity column, no error is thrown. In this case a
294 notice is issued instead.
295 </para>
296 </listitem>
297 </varlistentry>
299 <varlistentry id="sql-altertable-desc-set-sequence-option">
300 <term><literal>SET <replaceable>sequence_option</replaceable></literal></term>
301 <term><literal>RESTART</literal></term>
302 <listitem>
303 <para>
304 These forms alter the sequence that underlies an existing identity
305 column. <replaceable>sequence_option</replaceable> is an option
306 supported by <link linkend="sql-altersequence"><command>ALTER SEQUENCE</command></link> such
307 as <literal>INCREMENT BY</literal>.
308 </para>
309 </listitem>
310 </varlistentry>
312 <varlistentry id="sql-altertable-desc-set-statistics">
313 <term><literal>SET STATISTICS</literal></term>
314 <listitem>
315 <para>
316 This form
317 sets the per-column statistics-gathering target for subsequent
318 <link linkend="sql-analyze"><command>ANALYZE</command></link> operations.
319 The target can be set in the range 0 to 10000; alternatively, set it
320 to -1 to revert to using the system default statistics
321 target (<xref linkend="guc-default-statistics-target"/>).
322 For more information on the use of statistics by the
323 <productname>PostgreSQL</productname> query planner, refer to
324 <xref linkend="planner-stats"/>.
325 </para>
326 <para>
327 <literal>SET STATISTICS</literal> acquires a
328 <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
329 </para>
330 </listitem>
331 </varlistentry>
333 <varlistentry id="sql-altertable-desc-set-attribute-option">
334 <term><literal>SET ( <replaceable class="parameter">attribute_option</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] )</literal></term>
335 <term><literal>RESET ( <replaceable class="parameter">attribute_option</replaceable> [, ... ] )</literal></term>
336 <listitem>
337 <para>
338 This form sets or resets per-attribute options. Currently, the only
339 defined per-attribute options are <literal>n_distinct</literal> and
340 <literal>n_distinct_inherited</literal>, which override the
341 number-of-distinct-values estimates made by subsequent
342 <link linkend="sql-analyze"><command>ANALYZE</command></link>
343 operations. <literal>n_distinct</literal> affects the statistics for the table
344 itself, while <literal>n_distinct_inherited</literal> affects the statistics
345 gathered for the table plus its inheritance children. When set to a
346 positive value, <command>ANALYZE</command> will assume that the column contains
347 exactly the specified number of distinct nonnull values. When set to a
348 negative value, which must be greater
349 than or equal to -1, <command>ANALYZE</command> will assume that the number of
350 distinct nonnull values in the column is linear in the size of the
351 table; the exact count is to be computed by multiplying the estimated
352 table size by the absolute value of the given number. For example,
353 a value of -1 implies that all values in the column are distinct, while
354 a value of -0.5 implies that each value appears twice on the average.
355 This can be useful when the size of the table changes over time, since
356 the multiplication by the number of rows in the table is not performed
357 until query planning time. Specify a value of 0 to revert to estimating
358 the number of distinct values normally. For more information on the use
359 of statistics by the <productname>PostgreSQL</productname> query
360 planner, refer to <xref linkend="planner-stats"/>.
361 </para>
362 <para>
363 Changing per-attribute options acquires a
364 <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
365 </para>
366 </listitem>
367 </varlistentry>
369 <varlistentry id="sql-altertable-desc-set-storage">
370 <term>
371 <literal>SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }</literal>
372 <indexterm>
373 <primary>TOAST</primary>
374 <secondary>per-column storage settings</secondary>
375 </indexterm>
376 </term>
377 <listitem>
378 <para>
379 This form sets the storage mode for a column. This controls whether this
380 column is held inline or in a secondary <acronym>TOAST</acronym> table,
381 and whether the data
382 should be compressed or not. <literal>PLAIN</literal> must be used
383 for fixed-length values such as <type>integer</type> and is
384 inline, uncompressed. <literal>MAIN</literal> is for inline,
385 compressible data. <literal>EXTERNAL</literal> is for external,
386 uncompressed data, and <literal>EXTENDED</literal> is for external,
387 compressed data.
388 Writing <literal>DEFAULT</literal> sets the storage mode to the default
389 mode for the column's data type. <literal>EXTENDED</literal> is the
390 default for most data types that support non-<literal>PLAIN</literal>
391 storage.
392 Use of <literal>EXTERNAL</literal> will make substring operations on
393 very large <type>text</type> and <type>bytea</type> values run faster,
394 at the penalty of increased storage space.
395 Note that <literal>ALTER TABLE ... SET STORAGE</literal> doesn't itself
396 change anything in the table; it just sets the strategy to be pursued
397 during future table updates.
398 See <xref linkend="storage-toast"/> for more information.
399 </para>
400 </listitem>
401 </varlistentry>
403 <varlistentry id="sql-altertable-desc-set-compression">
404 <term>
405 <literal>SET COMPRESSION <replaceable class="parameter">compression_method</replaceable></literal>
406 </term>
407 <listitem>
408 <para>
409 This form sets the compression method for a column, determining how
410 values inserted in future will be compressed (if the storage mode
411 permits compression at all).
412 This does not cause the table to be rewritten, so existing data may still
413 be compressed with other compression methods. If the table is restored
414 with <application>pg_restore</application>, then all values are rewritten
415 with the configured compression method.
416 However, when data is inserted from another relation (for example,
417 by <command>INSERT ... SELECT</command>), values from the source table are
418 not necessarily detoasted, so any previously compressed data may retain
419 its existing compression method, rather than being recompressed with the
420 compression method of the target column.
421 The supported compression
422 methods are <literal>pglz</literal> and <literal>lz4</literal>.
423 (<literal>lz4</literal> is available only if <option>--with-lz4</option>
424 was used when building <productname>PostgreSQL</productname>.) In
425 addition, <replaceable class="parameter">compression_method</replaceable>
426 can be <literal>default</literal>, which selects the default behavior of
427 consulting the <xref linkend="guc-default-toast-compression"/> setting
428 at the time of data insertion to determine the method to use.
429 </para>
430 </listitem>
431 </varlistentry>
433 <varlistentry id="sql-altertable-desc-add-table-constraint">
434 <term><literal>ADD <replaceable class="parameter">table_constraint</replaceable> [ NOT VALID ]</literal></term>
435 <listitem>
436 <para>
437 This form adds a new constraint to a table using the same constraint
438 syntax as <link linkend="sql-createtable"><command>CREATE TABLE</command></link>, plus the option <literal>NOT
439 VALID</literal>, which is currently only allowed for foreign key
440 and CHECK constraints.
441 </para>
443 <para>
444 Normally, this form will cause a scan of the table to verify that all
445 existing rows in the table satisfy the new constraint. But if
446 the <literal>NOT VALID</literal> option is used, this
447 potentially-lengthy scan is skipped. The constraint will still be
448 enforced against subsequent inserts or updates (that is, they'll fail
449 unless there is a matching row in the referenced table, in the case
450 of foreign keys, or they'll fail unless the new row matches the
451 specified check condition). But the
452 database will not assume that the constraint holds for all rows in
453 the table, until it is validated by using the <literal>VALIDATE
454 CONSTRAINT</literal> option.
455 See <xref linkend="sql-altertable-notes"/> below for more information
456 about using the <literal>NOT VALID</literal> option.
457 </para>
459 <para>
460 Although most forms of <literal>ADD
461 <replaceable class="parameter">table_constraint</replaceable></literal>
462 require an <literal>ACCESS EXCLUSIVE</literal> lock, <literal>ADD
463 FOREIGN KEY</literal> requires only a <literal>SHARE ROW
464 EXCLUSIVE</literal> lock. Note that <literal>ADD FOREIGN KEY</literal>
465 also acquires a <literal>SHARE ROW EXCLUSIVE</literal> lock on the
466 referenced table, in addition to the lock on the table on which the
467 constraint is declared.
468 </para>
470 <para>
471 Additional restrictions apply when unique or primary key constraints
472 are added to partitioned tables; see <link linkend="sql-createtable"><command>CREATE TABLE</command></link>.
473 Also, foreign key constraints on partitioned
474 tables may not be declared <literal>NOT VALID</literal> at present.
475 </para>
477 </listitem>
478 </varlistentry>
480 <varlistentry id="sql-altertable-desc-add-table-constraint-using-index">
481 <term><literal>ADD <replaceable class="parameter">table_constraint_using_index</replaceable></literal></term>
482 <listitem>
483 <para>
484 This form adds a new <literal>PRIMARY KEY</literal> or <literal>UNIQUE</literal>
485 constraint to a table based on an existing unique index. All the
486 columns of the index will be included in the constraint.
487 </para>
489 <para>
490 The index cannot have expression columns nor be a partial index.
491 Also, it must be a b-tree index with default sort ordering. These
492 restrictions ensure that the index is equivalent to one that would be
493 built by a regular <literal>ADD PRIMARY KEY</literal> or <literal>ADD UNIQUE</literal>
494 command.
495 </para>
497 <para>
498 If <literal>PRIMARY KEY</literal> is specified, and the index's columns are not
499 already marked <literal>NOT NULL</literal>, then this command will attempt to
500 do <literal>ALTER COLUMN SET NOT NULL</literal> against each such column.
501 That requires a full table scan to verify the column(s) contain no
502 nulls. In all other cases, this is a fast operation.
503 </para>
505 <para>
506 If a constraint name is provided then the index will be renamed to match
507 the constraint name. Otherwise the constraint will be named the same as
508 the index.
509 </para>
511 <para>
512 After this command is executed, the index is <quote>owned</quote> by the
513 constraint, in the same way as if the index had been built by
514 a regular <literal>ADD PRIMARY KEY</literal> or <literal>ADD UNIQUE</literal>
515 command. In particular, dropping the constraint will make the index
516 disappear too.
517 </para>
519 <para>
520 This form is not currently supported on partitioned tables.
521 </para>
523 <note>
524 <para>
525 Adding a constraint using an existing index can be helpful in
526 situations where a new constraint needs to be added without blocking
527 table updates for a long time. To do that, create the index using
528 <command>CREATE INDEX CONCURRENTLY</command>, and then install it as an
529 official constraint using this syntax. See the example below.
530 </para>
531 </note>
532 </listitem>
533 </varlistentry>
535 <varlistentry id="sql-altertable-desc-alter-constraint">
536 <term><literal>ALTER CONSTRAINT</literal></term>
537 <listitem>
538 <para>
539 This form alters the attributes of a constraint that was previously
540 created. Currently only foreign key constraints may be altered.
541 </para>
542 </listitem>
543 </varlistentry>
545 <varlistentry id="sql-altertable-desc-validate-constraint">
546 <term><literal>VALIDATE CONSTRAINT</literal></term>
547 <listitem>
548 <para>
549 This form validates a foreign key or check constraint that was
550 previously created as <literal>NOT VALID</literal>, by scanning the
551 table to ensure there are no rows for which the constraint is not
552 satisfied. Nothing happens if the constraint is already marked valid.
553 (See <xref linkend="sql-altertable-notes"/> below for an explanation
554 of the usefulness of this command.)
555 </para>
556 <para>
557 This command acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
558 </para>
559 </listitem>
560 </varlistentry>
562 <varlistentry id="sql-altertable-desc-drop-constraint">
563 <term><literal>DROP CONSTRAINT [ IF EXISTS ]</literal></term>
564 <listitem>
565 <para>
566 This form drops the specified constraint on a table, along with
567 any index underlying the constraint.
568 If <literal>IF EXISTS</literal> is specified and the constraint
569 does not exist, no error is thrown. In this case a notice is issued instead.
570 </para>
571 </listitem>
572 </varlistentry>
574 <varlistentry id="sql-altertable-desc-disable-enable-trigger">
575 <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] TRIGGER</literal></term>
576 <listitem>
577 <para>
578 These forms configure the firing of trigger(s) belonging to the table.
579 A disabled trigger is still known to the system, but is not executed
580 when its triggering event occurs. (For a deferred trigger, the enable
581 status is checked when the event occurs, not when the trigger function
582 is actually executed.) One can disable or enable a single
583 trigger specified by name, or all triggers on the table, or only
584 user triggers (this option excludes internally generated constraint
585 triggers, such as those that are used to implement foreign key
586 constraints or deferrable uniqueness and exclusion constraints).
587 Disabling or enabling internally generated constraint triggers
588 requires superuser privileges; it should be done with caution since
589 of course the integrity of the constraint cannot be guaranteed if the
590 triggers are not executed.
591 </para>
593 <para>
594 The trigger firing mechanism is also affected by the configuration
595 variable <xref linkend="guc-session-replication-role"/>. Simply enabled
596 triggers (the default) will fire when the replication role is <quote>origin</quote>
597 (the default) or <quote>local</quote>. Triggers configured as <literal>ENABLE
598 REPLICA</literal> will only fire if the session is in <quote>replica</quote>
599 mode, and triggers configured as <literal>ENABLE ALWAYS</literal> will
600 fire regardless of the current replication role.
601 </para>
603 <para>
604 The effect of this mechanism is that in the default configuration,
605 triggers do not fire on replicas. This is useful because if a trigger
606 is used on the origin to propagate data between tables, then the
607 replication system will also replicate the propagated data; so the
608 trigger should not fire a second time on the replica, because that would
609 lead to duplication. However, if a trigger is used for another purpose
610 such as creating external alerts, then it might be appropriate to set it
611 to <literal>ENABLE ALWAYS</literal> so that it is also fired on
612 replicas.
613 </para>
615 <para>
616 When this command is applied to a partitioned table, the states of
617 corresponding clone triggers in the partitions are updated too,
618 unless <literal>ONLY</literal> is specified.
619 </para>
621 <para>
622 This command acquires a <literal>SHARE ROW EXCLUSIVE</literal> lock.
623 </para>
624 </listitem>
625 </varlistentry>
627 <varlistentry id="sql-altertable-desc-disable-enable-rule">
628 <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] RULE</literal></term>
629 <listitem>
630 <para>
631 These forms configure the firing of rewrite rules belonging to the table.
632 A disabled rule is still known to the system, but is not applied
633 during query rewriting. The semantics are as for disabled/enabled
634 triggers. This configuration is ignored for <literal>ON SELECT</literal> rules, which
635 are always applied in order to keep views working even if the current
636 session is in a non-default replication role.
637 </para>
639 <para>
640 The rule firing mechanism is also affected by the configuration variable
641 <xref linkend="guc-session-replication-role"/>, analogous to triggers as
642 described above.
643 </para>
644 </listitem>
645 </varlistentry>
647 <varlistentry id="sql-altertable-desc-disable-enable-row-level-security">
648 <term><literal>DISABLE</literal>/<literal>ENABLE ROW LEVEL SECURITY</literal></term>
649 <listitem>
650 <para>
651 These forms control the application of row security policies belonging
652 to the table. If enabled and no policies exist for the table, then a
653 default-deny policy is applied. Note that policies can exist for a table
654 even if row-level security is disabled. In this case, the policies will
655 <emphasis>not</emphasis> be applied and the policies will be ignored.
656 See also
657 <link linkend="sql-createpolicy"><command>CREATE POLICY</command></link>.
658 </para>
659 </listitem>
660 </varlistentry>
662 <varlistentry id="sql-altertable-desc-force-row-level-security">
663 <term><literal>NO FORCE</literal>/<literal>FORCE ROW LEVEL SECURITY</literal></term>
664 <listitem>
665 <para>
666 These forms control the application of row security policies belonging
667 to the table when the user is the table owner. If enabled, row-level
668 security policies will be applied when the user is the table owner. If
669 disabled (the default) then row-level security will not be applied when
670 the user is the table owner.
671 See also
672 <link linkend="sql-createpolicy"><command>CREATE POLICY</command></link>.
673 </para>
674 </listitem>
675 </varlistentry>
677 <varlistentry id="sql-altertable-desc-cluster-on">
678 <term><literal>CLUSTER ON</literal></term>
679 <listitem>
680 <para>
681 This form selects the default index for future
682 <link linkend="sql-cluster"><command>CLUSTER</command></link>
683 operations. It does not actually re-cluster the table.
684 </para>
685 <para>
686 Changing cluster options acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
687 </para>
688 </listitem>
689 </varlistentry>
691 <varlistentry id="sql-altertable-desc-set-without-cluster">
692 <term><literal>SET WITHOUT CLUSTER</literal></term>
693 <listitem>
694 <para>
695 This form removes the most recently used
696 <link linkend="sql-cluster"><command>CLUSTER</command></link>
697 index specification from the table. This affects
698 future cluster operations that don't specify an index.
699 </para>
700 <para>
701 Changing cluster options acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
702 </para>
703 </listitem>
704 </varlistentry>
706 <varlistentry id="sql-altertable-desc-set-without-oids">
707 <term><literal>SET WITHOUT OIDS</literal></term>
708 <listitem>
709 <para>
710 Backward-compatible syntax for removing the <literal>oid</literal>
711 system column. As <literal>oid</literal> system columns cannot be
712 added anymore, this never has an effect.
713 </para>
714 </listitem>
715 </varlistentry>
717 <varlistentry id="sql-altertable-desc-set-access-method">
718 <term><literal>SET ACCESS METHOD</literal></term>
719 <listitem>
720 <para>
721 This form changes the access method of the table by rewriting it. See
722 <xref linkend="tableam"/> for more information.
723 </para>
724 </listitem>
725 </varlistentry>
727 <varlistentry id="sql-altertable-desc-set-tablespace">
728 <term><literal>SET TABLESPACE</literal></term>
729 <listitem>
730 <para>
731 This form changes the table's tablespace to the specified tablespace and
732 moves the data file(s) associated with the table to the new tablespace.
733 Indexes on the table, if any, are not moved; but they can be moved
734 separately with additional <literal>SET TABLESPACE</literal> commands.
735 When applied to a partitioned table, nothing is moved, but any
736 partitions created afterwards with
737 <command>CREATE TABLE PARTITION OF</command> will use that tablespace,
738 unless overridden by a <literal>TABLESPACE</literal> clause.
739 </para>
741 <para>
742 All tables in the current database in a tablespace can be moved by using
743 the <literal>ALL IN TABLESPACE</literal> form, which will lock all tables
744 to be moved first and then move each one. This form also supports
745 <literal>OWNED BY</literal>, which will only move tables owned by the
746 roles specified. If the <literal>NOWAIT</literal> option is specified
747 then the command will fail if it is unable to acquire all of the locks
748 required immediately. Note that system catalogs are not moved by this
749 command; use <command>ALTER DATABASE</command> or explicit
750 <command>ALTER TABLE</command> invocations instead if desired. The
751 <literal>information_schema</literal> relations are not considered part
752 of the system catalogs and will be moved.
753 See also
754 <link linkend="sql-createtablespace"><command>CREATE TABLESPACE</command></link>.
755 </para>
756 </listitem>
757 </varlistentry>
759 <varlistentry id="sql-altertable-desc-set-logged-unlogged">
760 <term><literal>SET { LOGGED | UNLOGGED }</literal></term>
761 <listitem>
762 <para>
763 This form changes the table from unlogged to logged or vice-versa
764 (see <xref linkend="sql-createtable-unlogged"/>). It cannot be applied
765 to a temporary table.
766 </para>
768 <para>
769 This also changes the persistence of any sequences linked to the table
770 (for identity or serial columns). However, it is also possible to
771 change the persistence of such sequences separately.
772 </para>
773 </listitem>
774 </varlistentry>
776 <varlistentry id="sql-altertable-desc-set-storage-parameter">
777 <term><literal>SET ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
778 <listitem>
779 <para>
780 This form changes one or more storage parameters for the table. See
781 <xref linkend="sql-createtable-storage-parameters"/> in the
782 <link linkend="sql-createtable"><command>CREATE TABLE</command></link> documentation
783 for details on the available parameters. Note that the table contents
784 will not be modified immediately by this command; depending on the
785 parameter you might need to rewrite the table to get the desired effects.
786 That can be done with <link linkend="sql-vacuum"><command>VACUUM
787 FULL</command></link>, <link linkend="sql-cluster"><command>CLUSTER</command></link> or one of the forms
788 of <command>ALTER TABLE</command> that forces a table rewrite.
789 For planner related parameters, changes will take effect from the next
790 time the table is locked so currently executing queries will not be
791 affected.
792 </para>
794 <para>
795 <literal>SHARE UPDATE EXCLUSIVE</literal> lock will be taken for
796 fillfactor, toast and autovacuum storage parameters, as well as the
797 planner parameter <varname>parallel_workers</varname>.
798 </para>
799 </listitem>
800 </varlistentry>
802 <varlistentry id="sql-altertable-desc-reset-storage-parameter">
803 <term><literal>RESET ( <replaceable class="parameter">storage_parameter</replaceable> [, ... ] )</literal></term>
804 <listitem>
805 <para>
806 This form resets one or more storage parameters to their
807 defaults. As with <literal>SET</literal>, a table rewrite might be
808 needed to update the table entirely.
809 </para>
810 </listitem>
811 </varlistentry>
813 <varlistentry id="sql-altertable-desc-inherit">
814 <term><literal>INHERIT <replaceable class="parameter">parent_table</replaceable></literal></term>
815 <listitem>
816 <para>
817 This form adds the target table as a new child of the specified parent
818 table. Subsequently, queries against the parent will include records
819 of the target table. To be added as a child, the target table must
820 already contain all the same columns as the parent (it could have
821 additional columns, too). The columns must have matching data types,
822 and if they have <literal>NOT NULL</literal> constraints in the parent
823 then they must also have <literal>NOT NULL</literal> constraints in the
824 child.
825 </para>
827 <para>
828 There must also be matching child-table constraints for all
829 <literal>CHECK</literal> constraints of the parent, except those
830 marked non-inheritable (that is, created with <literal>ALTER TABLE ... ADD CONSTRAINT ... NO INHERIT</literal>)
831 in the parent, which are ignored; all child-table constraints matched
832 must not be marked non-inheritable.
833 Currently
834 <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and
835 <literal>FOREIGN KEY</literal> constraints are not considered, but
836 this might change in the future.
837 </para>
838 </listitem>
839 </varlistentry>
841 <varlistentry id="sql-altertable-desc-no-inherit">
842 <term><literal>NO INHERIT <replaceable class="parameter">parent_table</replaceable></literal></term>
843 <listitem>
844 <para>
845 This form removes the target table from the list of children of the
846 specified parent table.
847 Queries against the parent table will no longer include records drawn
848 from the target table.
849 </para>
850 </listitem>
851 </varlistentry>
853 <varlistentry id="sql-altertable-desc-of">
854 <term><literal>OF <replaceable class="parameter">type_name</replaceable></literal></term>
855 <listitem>
856 <para>
857 This form links the table to a composite type as though <command>CREATE
858 TABLE OF</command> had formed it. The table's list of column names and types
859 must precisely match that of the composite type. The table must
860 not inherit from any other table. These restrictions ensure
861 that <command>CREATE TABLE OF</command> would permit an equivalent table
862 definition.
863 </para>
864 </listitem>
865 </varlistentry>
867 <varlistentry id="sql-altertable-desc-not-of">
868 <term><literal>NOT OF</literal></term>
869 <listitem>
870 <para>
871 This form dissociates a typed table from its type.
872 </para>
873 </listitem>
874 </varlistentry>
876 <varlistentry id="sql-altertable-desc-owner-to">
877 <term><literal>OWNER TO</literal></term>
878 <listitem>
879 <para>
880 This form changes the owner of the table, sequence, view, materialized view,
881 or foreign table to the specified user.
882 </para>
883 </listitem>
884 </varlistentry>
886 <varlistentry id="sql-altertable-replica-identity">
887 <term><literal>REPLICA IDENTITY</literal></term>
888 <listitem>
889 <para>
890 This form changes the information which is written to the write-ahead log
891 to identify rows which are updated or deleted.
892 In most cases, the old value of each column is only logged if it differs
893 from the new value; however, if the old value is stored externally, it is
894 always logged regardless of whether it changed.
895 This option has no effect except when logical replication is in use.
896 <variablelist>
897 <varlistentry id="sql-altertable-replica-identity-default">
898 <term><literal>DEFAULT</literal></term>
899 <listitem>
900 <para>
901 Records the old values of the columns of the primary key, if any.
902 This is the default for non-system tables.
903 </para>
904 </listitem>
905 </varlistentry>
907 <varlistentry id="sql-altertable-replica-identity-using-index">
908 <term><literal>USING INDEX <replaceable class="parameter">index_name</replaceable></literal></term>
909 <listitem>
910 <para>
911 Records the old values of the columns covered by the named index,
912 that must be unique, not partial, not deferrable, and include only
913 columns marked <literal>NOT NULL</literal>. If this index is
914 dropped, the behavior is the same as <literal>NOTHING</literal>.
915 </para>
916 </listitem>
917 </varlistentry>
919 <varlistentry id="sql-altertable-replica-identity-full">
920 <term><literal>FULL</literal></term>
921 <listitem>
922 <para>
923 Records the old values of all columns in the row.
924 </para>
925 </listitem>
926 </varlistentry>
928 <varlistentry id="sql-altertable-replica-identity-nothing">
929 <term><literal>NOTHING</literal></term>
930 <listitem>
931 <para>
932 Records no information about the old row. This is the default for
933 system tables.
934 </para>
935 </listitem>
936 </varlistentry>
937 </variablelist></para>
938 </listitem>
939 </varlistentry>
941 <varlistentry id="sql-altertable-desc-rename">
942 <term><literal>RENAME</literal></term>
943 <listitem>
944 <para>
945 The <literal>RENAME</literal> forms change the name of a table
946 (or an index, sequence, view, materialized view, or foreign table), the
947 name of an individual column in a table, or the name of a constraint of
948 the table. When renaming a constraint that has an underlying index,
949 the index is renamed as well.
950 There is no effect on the stored data.
951 </para>
952 </listitem>
953 </varlistentry>
955 <varlistentry id="sql-altertable-desc-set-schema">
956 <term><literal>SET SCHEMA</literal></term>
957 <listitem>
958 <para>
959 This form moves the table into another schema. Associated indexes,
960 constraints, and sequences owned by table columns are moved as well.
961 </para>
962 </listitem>
963 </varlistentry>
965 <varlistentry id="sql-altertable-attach-partition">
966 <term><literal>ATTACH PARTITION <replaceable class="parameter">partition_name</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }</literal></term>
967 <listitem>
968 <para>
969 This form attaches an existing table (which might itself be partitioned)
970 as a partition of the target table. The table can be attached
971 as a partition for specific values using <literal>FOR VALUES</literal>
972 or as a default partition by using <literal>DEFAULT</literal>.
973 For each index in the target table, a corresponding
974 one will be created in the attached table; or, if an equivalent
975 index already exists, it will be attached to the target table's index,
976 as if <command>ALTER INDEX ATTACH PARTITION</command> had been executed.
977 Note that if the existing table is a foreign table, it is currently not
978 allowed to attach the table as a partition of the target table if there
979 are <literal>UNIQUE</literal> indexes on the target table. (See also
980 <xref linkend="sql-createforeigntable"/>.) For each user-defined
981 row-level trigger that exists in the target table, a corresponding one
982 is created in the attached table.
983 </para>
985 <para>
986 A partition using <literal>FOR VALUES</literal> uses same syntax for
987 <replaceable class="parameter">partition_bound_spec</replaceable> as
988 <link linkend="sql-createtable"><command>CREATE TABLE</command></link>. The partition bound specification
989 must correspond to the partitioning strategy and partition key of the
990 target table. The table to be attached must have all the same columns
991 as the target table and no more; moreover, the column types must also
992 match. Also, it must have all the <literal>NOT NULL</literal> and
993 <literal>CHECK</literal> constraints of the target table. Currently
994 <literal>FOREIGN KEY</literal> constraints are not considered.
995 <literal>UNIQUE</literal> and <literal>PRIMARY KEY</literal> constraints
996 from the parent table will be created in the partition, if they don't
997 already exist.
998 If any of the <literal>CHECK</literal> constraints of the table being
999 attached are marked <literal>NO INHERIT</literal>, the command will fail;
1000 such constraints must be recreated without the
1001 <literal>NO INHERIT</literal> clause.
1002 </para>
1004 <para>
1005 If the new partition is a regular table, a full table scan is performed
1006 to check that existing rows in the table do not violate the partition
1007 constraint. It is possible to avoid this scan by adding a valid
1008 <literal>CHECK</literal> constraint to the table that allows only
1009 rows satisfying the desired partition constraint before running this
1010 command. The <literal>CHECK</literal> constraint will be used to
1011 determine that the table need not be scanned to validate the partition
1012 constraint. This does not work, however, if any of the partition keys
1013 is an expression and the partition does not accept
1014 <literal>NULL</literal> values. If attaching a list partition that will
1015 not accept <literal>NULL</literal> values, also add a
1016 <literal>NOT NULL</literal> constraint to the partition key column,
1017 unless it's an expression.
1018 </para>
1020 <para>
1021 If the new partition is a foreign table, nothing is done to verify
1022 that all the rows in the foreign table obey the partition constraint.
1023 (See the discussion in <xref linkend="sql-createforeigntable"/> about
1024 constraints on the foreign table.)
1025 </para>
1027 <para>
1028 When a table has a default partition, defining a new partition changes
1029 the partition constraint for the default partition. The default
1030 partition can't contain any rows that would need to be moved to the new
1031 partition, and will be scanned to verify that none are present. This
1032 scan, like the scan of the new partition, can be avoided if an
1033 appropriate <literal>CHECK</literal> constraint is present. Also like
1034 the scan of the new partition, it is always skipped when the default
1035 partition is a foreign table.
1036 </para>
1038 <para>
1039 Attaching a partition acquires a
1040 <literal>SHARE UPDATE EXCLUSIVE</literal> lock on the parent table,
1041 in addition to the <literal>ACCESS EXCLUSIVE</literal> locks on the table
1042 being attached and on the default partition (if any).
1043 </para>
1045 <para>
1046 Further locks must also be held on all sub-partitions if the table being
1047 attached is itself a partitioned table. Likewise if the default
1048 partition is itself a partitioned table. The locking of the
1049 sub-partitions can be avoided by adding a <literal>CHECK</literal>
1050 constraint as described in
1051 <xref linkend="ddl-partitioning-declarative-maintenance"/>.
1052 </para>
1053 </listitem>
1054 </varlistentry>
1056 <varlistentry id="sql-altertable-detach-partition">
1057 <term><literal>DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]</literal></term>
1059 <listitem>
1060 <para>
1061 This form detaches the specified partition of the target table. The detached
1062 partition continues to exist as a standalone table, but no longer has any
1063 ties to the table from which it was detached. Any indexes that were
1064 attached to the target table's indexes are detached. Any triggers that
1065 were created as clones of those in the target table are removed.
1066 <literal>SHARE</literal> lock is obtained on any tables that reference
1067 this partitioned table in foreign key constraints.
1068 </para>
1069 <para>
1070 If <literal>CONCURRENTLY</literal> is specified, it runs using a reduced
1071 lock level to avoid blocking other sessions that might be accessing the
1072 partitioned table. In this mode, two transactions are used internally.
1073 During the first transaction, a <literal>SHARE UPDATE EXCLUSIVE</literal>
1074 lock is taken on both parent table and partition, and the partition is
1075 marked as undergoing detach; at that point, the transaction is committed
1076 and all other transactions using the partitioned table are waited for.
1077 Once all those transactions have completed, the second transaction
1078 acquires <literal>SHARE UPDATE EXCLUSIVE</literal> on the partitioned
1079 table and <literal>ACCESS EXCLUSIVE</literal> on the partition,
1080 and the detach process completes. A <literal>CHECK</literal> constraint
1081 that duplicates the partition constraint is added to the partition.
1082 <literal>CONCURRENTLY</literal> cannot be run in a transaction block and
1083 is not allowed if the partitioned table contains a default partition.
1084 </para>
1085 <para>
1086 If <literal>FINALIZE</literal> is specified, a previous
1087 <literal>DETACH CONCURRENTLY</literal> invocation that was canceled or
1088 interrupted is completed.
1089 At most one partition in a partitioned table can be pending detach at
1090 a time.
1091 </para>
1092 </listitem>
1093 </varlistentry>
1095 </variablelist>
1096 </para>
1098 <para>
1099 All the forms of ALTER TABLE that act on a single table, except
1100 <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
1101 <literal>ATTACH PARTITION</literal>, and
1102 <literal>DETACH PARTITION</literal> can be combined into
1103 a list of multiple alterations to be applied together. For example, it
1104 is possible to add several columns and/or alter the type of several
1105 columns in a single command. This is particularly useful with large
1106 tables, since only one pass over the table need be made.
1107 </para>
1109 <para>
1110 You must own the table to use <command>ALTER TABLE</command>.
1111 To change the schema or tablespace of a table, you must also have
1112 <literal>CREATE</literal> privilege on the new schema or tablespace.
1113 To add the table as a new child of a parent table, you must own the parent
1114 table as well. Also, to attach a table as a new partition of the table,
1115 you must own the table being attached.
1116 To alter the owner, you must be able to <literal>SET ROLE</literal> to the
1117 new owning role, and that role must have <literal>CREATE</literal>
1118 privilege on the table's schema.
1119 (These restrictions enforce that altering the owner
1120 doesn't do anything you couldn't do by dropping and recreating the table.
1121 However, a superuser can alter ownership of any table anyway.)
1122 To add a column or alter a column type or use the <literal>OF</literal>
1123 clause, you must also have <literal>USAGE</literal> privilege on the data
1124 type.
1125 </para>
1126 </refsect1>
1128 <refsect1>
1129 <title>Parameters</title>
1131 <variablelist>
1133 <varlistentry id="sql-altertable-parms-if-exists">
1134 <term><literal>IF EXISTS</literal></term>
1135 <listitem>
1136 <para>
1137 Do not throw an error if the table does not exist. A notice is issued
1138 in this case.
1139 </para>
1140 </listitem>
1141 </varlistentry>
1143 <varlistentry id="sql-altertable-parms-name">
1144 <term><replaceable class="parameter">name</replaceable></term>
1145 <listitem>
1146 <para>
1147 The name (optionally schema-qualified) of an existing table to
1148 alter. If <literal>ONLY</literal> is specified before the table name, only
1149 that table is altered. If <literal>ONLY</literal> is not specified, the table
1150 and all its descendant tables (if any) are altered. Optionally,
1151 <literal>*</literal> can be specified after the table name to explicitly
1152 indicate that descendant tables are included.
1153 </para>
1154 </listitem>
1155 </varlistentry>
1157 <varlistentry id="sql-altertable-parms-column-name">
1158 <term><replaceable class="parameter">column_name</replaceable></term>
1159 <listitem>
1160 <para>
1161 Name of a new or existing column.
1162 </para>
1163 </listitem>
1164 </varlistentry>
1166 <varlistentry id="sql-altertable-parms-new-column-name">
1167 <term><replaceable class="parameter">new_column_name</replaceable></term>
1168 <listitem>
1169 <para>
1170 New name for an existing column.
1171 </para>
1172 </listitem>
1173 </varlistentry>
1175 <varlistentry id="sql-altertable-parms-new-name">
1176 <term><replaceable class="parameter">new_name</replaceable></term>
1177 <listitem>
1178 <para>
1179 New name for the table.
1180 </para>
1181 </listitem>
1182 </varlistentry>
1184 <varlistentry id="sql-altertable-parms-data-type">
1185 <term><replaceable class="parameter">data_type</replaceable></term>
1186 <listitem>
1187 <para>
1188 Data type of the new column, or new data type for an existing
1189 column.
1190 </para>
1191 </listitem>
1192 </varlistentry>
1194 <varlistentry id="sql-altertable-parms-table-constraint">
1195 <term><replaceable class="parameter">table_constraint</replaceable></term>
1196 <listitem>
1197 <para>
1198 New table constraint for the table.
1199 </para>
1200 </listitem>
1201 </varlistentry>
1203 <varlistentry id="sql-altertable-parms-constraint-name">
1204 <term><replaceable class="parameter">constraint_name</replaceable></term>
1205 <listitem>
1206 <para>
1207 Name of a new or existing constraint.
1208 </para>
1209 </listitem>
1210 </varlistentry>
1212 <varlistentry id="sql-altertable-parms-cascade">
1213 <term><literal>CASCADE</literal></term>
1214 <listitem>
1215 <para>
1216 Automatically drop objects that depend on the dropped column
1217 or constraint (for example, views referencing the column),
1218 and in turn all objects that depend on those objects
1219 (see <xref linkend="ddl-depend"/>).
1220 </para>
1221 </listitem>
1222 </varlistentry>
1224 <varlistentry id="sql-altertable-parms-restrict">
1225 <term><literal>RESTRICT</literal></term>
1226 <listitem>
1227 <para>
1228 Refuse to drop the column or constraint if there are any dependent
1229 objects. This is the default behavior.
1230 </para>
1231 </listitem>
1232 </varlistentry>
1234 <varlistentry id="sql-altertable-parms-trigger-name">
1235 <term><replaceable class="parameter">trigger_name</replaceable></term>
1236 <listitem>
1237 <para>
1238 Name of a single trigger to disable or enable.
1239 </para>
1240 </listitem>
1241 </varlistentry>
1243 <varlistentry id="sql-altertable-parms-all">
1244 <term><literal>ALL</literal></term>
1245 <listitem>
1246 <para>
1247 Disable or enable all triggers belonging to the table.
1248 (This requires superuser privilege if any of the triggers are
1249 internally generated constraint triggers, such as those that are used
1250 to implement foreign key constraints or deferrable uniqueness and
1251 exclusion constraints.)
1252 </para>
1253 </listitem>
1254 </varlistentry>
1256 <varlistentry id="sql-altertable-parms-user">
1257 <term><literal>USER</literal></term>
1258 <listitem>
1259 <para>
1260 Disable or enable all triggers belonging to the table except for
1261 internally generated constraint triggers, such as those that are used
1262 to implement foreign key constraints or deferrable uniqueness and
1263 exclusion constraints.
1264 </para>
1265 </listitem>
1266 </varlistentry>
1268 <varlistentry id="sql-altertable-parms-index-name">
1269 <term><replaceable class="parameter">index_name</replaceable></term>
1270 <listitem>
1271 <para>
1272 The name of an existing index.
1273 </para>
1274 </listitem>
1275 </varlistentry>
1277 <varlistentry id="sql-altertable-parms-storage-parameter">
1278 <term><replaceable class="parameter">storage_parameter</replaceable></term>
1279 <listitem>
1280 <para>
1281 The name of a table storage parameter.
1282 </para>
1283 </listitem>
1284 </varlistentry>
1286 <varlistentry id="sql-altertable-parms-value">
1287 <term><replaceable class="parameter">value</replaceable></term>
1288 <listitem>
1289 <para>
1290 The new value for a table storage parameter.
1291 This might be a number or a word depending on the parameter.
1292 </para>
1293 </listitem>
1294 </varlistentry>
1296 <varlistentry id="sql-altertable-parms-parent-table">
1297 <term><replaceable class="parameter">parent_table</replaceable></term>
1298 <listitem>
1299 <para>
1300 A parent table to associate or de-associate with this table.
1301 </para>
1302 </listitem>
1303 </varlistentry>
1305 <varlistentry id="sql-altertable-parms-new-owner">
1306 <term><replaceable class="parameter">new_owner</replaceable></term>
1307 <listitem>
1308 <para>
1309 The user name of the new owner of the table.
1310 </para>
1311 </listitem>
1312 </varlistentry>
1314 <varlistentry id="sql-altertable-parms-new-access-method">
1315 <term><replaceable class="parameter">new_access_method</replaceable></term>
1316 <listitem>
1317 <para>
1318 The name of the access method to which the table will be converted.
1319 </para>
1320 </listitem>
1321 </varlistentry>
1323 <varlistentry id="sql-altertable-parms-new-tablespace">
1324 <term><replaceable class="parameter">new_tablespace</replaceable></term>
1325 <listitem>
1326 <para>
1327 The name of the tablespace to which the table will be moved.
1328 </para>
1329 </listitem>
1330 </varlistentry>
1332 <varlistentry id="sql-altertable-parms-new-schema">
1333 <term><replaceable class="parameter">new_schema</replaceable></term>
1334 <listitem>
1335 <para>
1336 The name of the schema to which the table will be moved.
1337 </para>
1338 </listitem>
1339 </varlistentry>
1341 <varlistentry id="sql-altertable-parms-partition-name">
1342 <term><replaceable class="parameter">partition_name</replaceable></term>
1343 <listitem>
1344 <para>
1345 The name of the table to attach as a new partition or to detach from this table.
1346 </para>
1347 </listitem>
1348 </varlistentry>
1350 <varlistentry id="sql-altertable-parms-partition-bound-spec">
1351 <term><replaceable class="parameter">partition_bound_spec</replaceable></term>
1352 <listitem>
1353 <para>
1354 The partition bound specification for a new partition. Refer to
1355 <xref linkend="sql-createtable"/> for more details on the syntax of the same.
1356 </para>
1357 </listitem>
1358 </varlistentry>
1360 </variablelist>
1361 </refsect1>
1363 <refsect1 id="sql-altertable-notes" xreflabel="Notes">
1364 <title>Notes</title>
1366 <para>
1367 The key word <literal>COLUMN</literal> is noise and can be omitted.
1368 </para>
1370 <para>
1371 When a column is added with <literal>ADD COLUMN</literal> and a
1372 non-volatile <literal>DEFAULT</literal> is specified, the default is
1373 evaluated at the time of the statement and the result stored in the
1374 table's metadata. That value will be used for the column for all existing
1375 rows. If no <literal>DEFAULT</literal> is specified, NULL is used. In
1376 neither case is a rewrite of the table required.
1377 </para>
1379 <para>
1380 Adding a column with a volatile <literal>DEFAULT</literal> or
1381 changing the type of an existing column will require the entire table and
1382 its indexes to be rewritten. As an exception, when changing the type of an
1383 existing column, if the <literal>USING</literal> clause does not change
1384 the column contents and the old type is either binary coercible to the new
1385 type or an unconstrained domain over the new type, a table rewrite is not
1386 needed. However, indexes must always be rebuilt unless the system can
1387 verify that the new index would be logically equivalent to the existing
1388 one. For example, if the collation for a column has been changed, an index
1389 rebuild is always required because the new sort order might be different.
1390 However, in the absence of a collation change, a column can be changed
1391 from <type>text</type> to <type>varchar</type> (or vice versa) without
1392 rebuilding the indexes because these data types sort identically.
1393 Table and/or index rebuilds may take a
1394 significant amount of time for a large table; and will temporarily require
1395 as much as double the disk space.
1396 </para>
1398 <para>
1399 Adding a <literal>CHECK</literal> or <literal>NOT NULL</literal> constraint requires
1400 scanning the table to verify that existing rows meet the constraint,
1401 but does not require a table rewrite.
1402 </para>
1404 <para>
1405 Similarly, when attaching a new partition it may be scanned to verify that
1406 existing rows meet the partition constraint.
1407 </para>
1409 <para>
1410 The main reason for providing the option to specify multiple changes
1411 in a single <command>ALTER TABLE</command> is that multiple table scans or
1412 rewrites can thereby be combined into a single pass over the table.
1413 </para>
1415 <para>
1416 Scanning a large table to verify a new foreign key or check constraint
1417 can take a long time, and other updates to the table are locked out
1418 until the <command>ALTER TABLE ADD CONSTRAINT</command> command is
1419 committed. The main purpose of the <literal>NOT VALID</literal>
1420 constraint option is to reduce the impact of adding a constraint on
1421 concurrent updates. With <literal>NOT VALID</literal>,
1422 the <command>ADD CONSTRAINT</command> command does not scan the table
1423 and can be committed immediately. After that, a <literal>VALIDATE
1424 CONSTRAINT</literal> command can be issued to verify that existing rows
1425 satisfy the constraint. The validation step does not need to lock out
1426 concurrent updates, since it knows that other transactions will be
1427 enforcing the constraint for rows that they insert or update; only
1428 pre-existing rows need to be checked. Hence, validation acquires only
1429 a <literal>SHARE UPDATE EXCLUSIVE</literal> lock on the table being
1430 altered. (If the constraint is a foreign key then a <literal>ROW
1431 SHARE</literal> lock is also required on the table referenced by the
1432 constraint.) In addition to improving concurrency, it can be useful to
1433 use <literal>NOT VALID</literal> and <literal>VALIDATE
1434 CONSTRAINT</literal> in cases where the table is known to contain
1435 pre-existing violations. Once the constraint is in place, no new
1436 violations can be inserted, and the existing problems can be corrected
1437 at leisure until <literal>VALIDATE CONSTRAINT</literal> finally
1438 succeeds.
1439 </para>
1441 <para>
1442 The <literal>DROP COLUMN</literal> form does not physically remove
1443 the column, but simply makes it invisible to SQL operations. Subsequent
1444 insert and update operations in the table will store a null value for the
1445 column. Thus, dropping a column is quick but it will not immediately
1446 reduce the on-disk size of your table, as the space occupied
1447 by the dropped column is not reclaimed. The space will be
1448 reclaimed over time as existing rows are updated.
1449 </para>
1451 <para>
1452 To force immediate reclamation of space occupied by a dropped column,
1453 you can execute one of the forms of <command>ALTER TABLE</command> that
1454 performs a rewrite of the whole table. This results in reconstructing
1455 each row with the dropped column replaced by a null value.
1456 </para>
1458 <para>
1459 The rewriting forms of <command>ALTER TABLE</command> are not MVCC-safe.
1460 After a table rewrite, the table will appear empty to concurrent
1461 transactions, if they are using a snapshot taken before the rewrite
1462 occurred. See <xref linkend="mvcc-caveats"/> for more details.
1463 </para>
1465 <para>
1466 The <literal>USING</literal> option of <literal>SET DATA TYPE</literal> can actually
1467 specify any expression involving the old values of the row; that is, it
1468 can refer to other columns as well as the one being converted. This allows
1469 very general conversions to be done with the <literal>SET DATA TYPE</literal>
1470 syntax. Because of this flexibility, the <literal>USING</literal>
1471 expression is not applied to the column's default value (if any); the
1472 result might not be a constant expression as required for a default.
1473 This means that when there is no implicit or assignment cast from old to
1474 new type, <literal>SET DATA TYPE</literal> might fail to convert the default even
1475 though a <literal>USING</literal> clause is supplied. In such cases,
1476 drop the default with <literal>DROP DEFAULT</literal>, perform the <literal>ALTER
1477 TYPE</literal>, and then use <literal>SET DEFAULT</literal> to add a suitable new
1478 default. Similar considerations apply to indexes and constraints involving
1479 the column.
1480 </para>
1482 <para>
1483 If a table has any descendant tables, it is not permitted to add,
1484 rename, or change the type of a column in the parent table without doing
1485 the same to the descendants. This ensures that the descendants always
1486 have columns matching the parent. Similarly, a <literal>CHECK</literal>
1487 constraint cannot be renamed in the parent without also renaming it in
1488 all descendants, so that <literal>CHECK</literal> constraints also match
1489 between the parent and its descendants. (That restriction does not apply
1490 to index-based constraints, however.)
1491 Also, because selecting from the parent also selects from its descendants,
1492 a constraint on the parent cannot be marked valid unless it is also marked
1493 valid for those descendants. In all of these cases, <command>ALTER TABLE
1494 ONLY</command> will be rejected.
1495 </para>
1497 <para>
1498 A recursive <literal>DROP COLUMN</literal> operation will remove a
1499 descendant table's column only if the descendant does not inherit
1500 that column from any other parents and never had an independent
1501 definition of the column. A nonrecursive <literal>DROP
1502 COLUMN</literal> (i.e., <command>ALTER TABLE ONLY ... DROP
1503 COLUMN</command>) never removes any descendant columns, but
1504 instead marks them as independently defined rather than inherited.
1505 A nonrecursive <literal>DROP COLUMN</literal> command will fail for a
1506 partitioned table, because all partitions of a table must have the same
1507 columns as the partitioning root.
1508 </para>
1510 <para>
1511 The actions for identity columns (<literal>ADD
1512 GENERATED</literal>, <literal>SET</literal> etc., <literal>DROP
1513 IDENTITY</literal>), as well as the actions
1514 <literal>CLUSTER</literal>, <literal>OWNER</literal>,
1515 and <literal>TABLESPACE</literal> never recurse to descendant tables;
1516 that is, they always act as though <literal>ONLY</literal> were specified.
1517 Actions affecting trigger states recurse to partitions of partitioned
1518 tables (unless <literal>ONLY</literal> is specified), but never to
1519 traditional-inheritance descendants.
1520 Adding a constraint recurses only for <literal>CHECK</literal> constraints
1521 that are not marked <literal>NO INHERIT</literal>.
1522 </para>
1524 <para>
1525 Changing any part of a system catalog table is not permitted.
1526 </para>
1528 <para>
1529 Refer to <xref linkend="sql-createtable"/> for a further description of valid
1530 parameters. <xref linkend="ddl"/> has further information on
1531 inheritance.
1532 </para>
1533 </refsect1>
1535 <refsect1>
1536 <title>Examples</title>
1538 <para>
1539 To add a column of type <type>varchar</type> to a table:
1540 <programlisting>
1541 ALTER TABLE distributors ADD COLUMN address varchar(30);
1542 </programlisting>
1543 That will cause all existing rows in the table to be filled with null
1544 values for the new column.
1545 </para>
1547 <para>
1548 To add a column with a non-null default:
1549 <programlisting>
1550 ALTER TABLE measurements
1551 ADD COLUMN mtime timestamp with time zone DEFAULT now();
1552 </programlisting>
1553 Existing rows will be filled with the current time as the value of the
1554 new column, and then new rows will receive the time of their insertion.
1555 </para>
1557 <para>
1558 To add a column and fill it with a value different from the default to
1559 be used later:
1560 <programlisting>
1561 ALTER TABLE transactions
1562 ADD COLUMN status varchar(30) DEFAULT 'old',
1563 ALTER COLUMN status SET default 'current';
1564 </programlisting>
1565 Existing rows will be filled with <literal>old</literal>, but then
1566 the default for subsequent commands will be <literal>current</literal>.
1567 The effects are the same as if the two sub-commands had been issued
1568 in separate <command>ALTER TABLE</command> commands.
1569 </para>
1571 <para>
1572 To drop a column from a table:
1573 <programlisting>
1574 ALTER TABLE distributors DROP COLUMN address RESTRICT;
1575 </programlisting>
1576 </para>
1578 <para>
1579 To change the types of two existing columns in one operation:
1580 <programlisting>
1581 ALTER TABLE distributors
1582 ALTER COLUMN address TYPE varchar(80),
1583 ALTER COLUMN name TYPE varchar(100);
1584 </programlisting>
1585 </para>
1587 <para>
1588 To change an integer column containing Unix timestamps to <type>timestamp
1589 with time zone</type> via a <literal>USING</literal> clause:
1590 <programlisting>
1591 ALTER TABLE foo
1592 ALTER COLUMN foo_timestamp SET DATA TYPE timestamp with time zone
1593 USING
1594 timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
1595 </programlisting>
1596 </para>
1598 <para>
1599 The same, when the column has a default expression that won't automatically
1600 cast to the new data type:
1601 <programlisting>
1602 ALTER TABLE foo
1603 ALTER COLUMN foo_timestamp DROP DEFAULT,
1604 ALTER COLUMN foo_timestamp TYPE timestamp with time zone
1605 USING
1606 timestamp with time zone 'epoch' + foo_timestamp * interval '1 second',
1607 ALTER COLUMN foo_timestamp SET DEFAULT now();
1608 </programlisting>
1609 </para>
1611 <para>
1612 To rename an existing column:
1613 <programlisting>
1614 ALTER TABLE distributors RENAME COLUMN address TO city;
1615 </programlisting>
1616 </para>
1618 <para>
1619 To rename an existing table:
1620 <programlisting>
1621 ALTER TABLE distributors RENAME TO suppliers;
1622 </programlisting>
1623 </para>
1625 <para>
1626 To rename an existing constraint:
1627 <programlisting>
1628 ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
1629 </programlisting>
1630 </para>
1632 <para>
1633 To add a not-null constraint to a column:
1634 <programlisting>
1635 ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
1636 </programlisting>
1637 To remove a not-null constraint from a column:
1638 <programlisting>
1639 ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
1640 </programlisting>
1641 </para>
1643 <para>
1644 To add a check constraint to a table and all its children:
1645 <programlisting>
1646 ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
1647 </programlisting>
1648 </para>
1650 <para>
1651 To add a check constraint only to a table and not to its children:
1652 <programlisting>
1653 ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5) NO INHERIT;
1654 </programlisting>
1655 (The check constraint will not be inherited by future children, either.)
1656 </para>
1658 <para>
1659 To remove a check constraint from a table and all its children:
1660 <programlisting>
1661 ALTER TABLE distributors DROP CONSTRAINT zipchk;
1662 </programlisting>
1663 </para>
1665 <para>
1666 To remove a check constraint from one table only:
1667 <programlisting>
1668 ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk;
1669 </programlisting>
1670 (The check constraint remains in place for any child tables.)
1671 </para>
1673 <para>
1674 To add a foreign key constraint to a table:
1675 <programlisting>
1676 ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address);
1677 </programlisting>
1678 </para>
1680 <para>
1681 To add a foreign key constraint to a table with the least impact on other work:
1682 <programlisting>
1683 ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) NOT VALID;
1684 ALTER TABLE distributors VALIDATE CONSTRAINT distfk;
1685 </programlisting>
1686 </para>
1688 <para>
1689 To add a (multicolumn) unique constraint to a table:
1690 <programlisting>
1691 ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zipcode);
1692 </programlisting>
1693 </para>
1695 <para>
1696 To add an automatically named primary key constraint to a table, noting
1697 that a table can only ever have one primary key:
1698 <programlisting>
1699 ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
1700 </programlisting>
1701 </para>
1703 <para>
1704 To move a table to a different tablespace:
1705 <programlisting>
1706 ALTER TABLE distributors SET TABLESPACE fasttablespace;
1707 </programlisting>
1708 </para>
1710 <para>
1711 To move a table to a different schema:
1712 <programlisting>
1713 ALTER TABLE myschema.distributors SET SCHEMA yourschema;
1714 </programlisting>
1715 </para>
1717 <para>
1718 To recreate a primary key constraint, without blocking updates while the
1719 index is rebuilt:
1720 <programlisting>
1721 CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id);
1722 ALTER TABLE distributors DROP CONSTRAINT distributors_pkey,
1723 ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx;
1724 </programlisting></para>
1726 <para>
1727 To attach a partition to a range-partitioned table:
1728 <programlisting>
1729 ALTER TABLE measurement
1730 ATTACH PARTITION measurement_y2016m07 FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
1731 </programlisting></para>
1733 <para>
1734 To attach a partition to a list-partitioned table:
1735 <programlisting>
1736 ALTER TABLE cities
1737 ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
1738 </programlisting></para>
1740 <para>
1741 To attach a partition to a hash-partitioned table:
1742 <programlisting>
1743 ALTER TABLE orders
1744 ATTACH PARTITION orders_p4 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
1745 </programlisting></para>
1747 <para>
1748 To attach a default partition to a partitioned table:
1749 <programlisting>
1750 ALTER TABLE cities
1751 ATTACH PARTITION cities_partdef DEFAULT;
1752 </programlisting></para>
1754 <para>
1755 To detach a partition from a partitioned table:
1756 <programlisting>
1757 ALTER TABLE measurement
1758 DETACH PARTITION measurement_y2015m12;
1759 </programlisting></para>
1761 </refsect1>
1763 <refsect1>
1764 <title>Compatibility</title>
1766 <para>
1767 The forms <literal>ADD [COLUMN]</literal>,
1768 <literal>DROP [COLUMN]</literal>, <literal>DROP IDENTITY</literal>, <literal>RESTART</literal>,
1769 <literal>SET DEFAULT</literal>, <literal>SET DATA TYPE</literal> (without <literal>USING</literal>),
1770 <literal>SET GENERATED</literal>, and <literal>SET <replaceable>sequence_option</replaceable></literal>
1771 conform with the SQL standard.
1772 The form <literal>ADD <replaceable>table_constraint</replaceable></literal>
1773 conforms with the SQL standard when the <literal>USING INDEX</literal> and
1774 <literal>NOT VALID</literal> clauses are omitted and the constraint type is
1775 one of <literal>CHECK</literal>, <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>,
1776 or <literal>REFERENCES</literal>.
1777 The other forms are
1778 <productname>PostgreSQL</productname> extensions of the SQL standard.
1779 Also, the ability to specify more than one manipulation in a single
1780 <command>ALTER TABLE</command> command is an extension.
1781 </para>
1783 <para>
1784 <command>ALTER TABLE DROP COLUMN</command> can be used to drop the only
1785 column of a table, leaving a zero-column table. This is an
1786 extension of SQL, which disallows zero-column tables.
1787 </para>
1788 </refsect1>
1790 <refsect1>
1791 <title>See Also</title>
1793 <simplelist type="inline">
1794 <member><xref linkend="sql-createtable"/></member>
1795 </simplelist>
1796 </refsect1>
1797 </refentry>