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