1ALTER TABLE(7)           PostgreSQL 16.1 Documentation          ALTER TABLE(7)
2
3
4

NAME

6       ALTER_TABLE - change the definition of a table
7

SYNOPSIS

9       ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
10           action [, ... ]
11       ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
12           RENAME [ COLUMN ] column_name TO new_column_name
13       ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
14           RENAME CONSTRAINT constraint_name TO new_constraint_name
15       ALTER TABLE [ IF EXISTS ] name
16           RENAME TO new_name
17       ALTER TABLE [ IF EXISTS ] name
18           SET SCHEMA new_schema
19       ALTER TABLE ALL IN TABLESPACE name [ OWNED BY role_name [, ... ] ]
20           SET TABLESPACE new_tablespace [ NOWAIT ]
21       ALTER TABLE [ IF EXISTS ] name
22           ATTACH PARTITION partition_name { FOR VALUES partition_bound_spec | DEFAULT }
23       ALTER TABLE [ IF EXISTS ] name
24           DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ]
25
26       where action is one of:
27
28           ADD [ COLUMN ] [ IF NOT EXISTS ] column_name data_type [ COLLATE collation ] [ column_constraint [ ... ] ]
29           DROP [ COLUMN ] [ IF EXISTS ] column_name [ RESTRICT | CASCADE ]
30           ALTER [ COLUMN ] column_name [ SET DATA ] TYPE data_type [ COLLATE collation ] [ USING expression ]
31           ALTER [ COLUMN ] column_name SET DEFAULT expression
32           ALTER [ COLUMN ] column_name DROP DEFAULT
33           ALTER [ COLUMN ] column_name { SET | DROP } NOT NULL
34           ALTER [ COLUMN ] column_name DROP EXPRESSION [ IF EXISTS ]
35           ALTER [ COLUMN ] column_name ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( sequence_options ) ]
36           ALTER [ COLUMN ] column_name { SET GENERATED { ALWAYS | BY DEFAULT } | SET sequence_option | RESTART [ [ WITH ] restart ] } [...]
37           ALTER [ COLUMN ] column_name DROP IDENTITY [ IF EXISTS ]
38           ALTER [ COLUMN ] column_name SET STATISTICS integer
39           ALTER [ COLUMN ] column_name SET ( attribute_option = value [, ... ] )
40           ALTER [ COLUMN ] column_name RESET ( attribute_option [, ... ] )
41           ALTER [ COLUMN ] column_name SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }
42           ALTER [ COLUMN ] column_name SET COMPRESSION compression_method
43           ADD table_constraint [ NOT VALID ]
44           ADD table_constraint_using_index
45           ALTER CONSTRAINT constraint_name [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
46           VALIDATE CONSTRAINT constraint_name
47           DROP CONSTRAINT [ IF EXISTS ]  constraint_name [ RESTRICT | CASCADE ]
48           DISABLE TRIGGER [ trigger_name | ALL | USER ]
49           ENABLE TRIGGER [ trigger_name | ALL | USER ]
50           ENABLE REPLICA TRIGGER trigger_name
51           ENABLE ALWAYS TRIGGER trigger_name
52           DISABLE RULE rewrite_rule_name
53           ENABLE RULE rewrite_rule_name
54           ENABLE REPLICA RULE rewrite_rule_name
55           ENABLE ALWAYS RULE rewrite_rule_name
56           DISABLE ROW LEVEL SECURITY
57           ENABLE ROW LEVEL SECURITY
58           FORCE ROW LEVEL SECURITY
59           NO FORCE ROW LEVEL SECURITY
60           CLUSTER ON index_name
61           SET WITHOUT CLUSTER
62           SET WITHOUT OIDS
63           SET ACCESS METHOD new_access_method
64           SET TABLESPACE new_tablespace
65           SET { LOGGED | UNLOGGED }
66           SET ( storage_parameter [= value] [, ... ] )
67           RESET ( storage_parameter [, ... ] )
68           INHERIT parent_table
69           NO INHERIT parent_table
70           OF type_name
71           NOT OF
72           OWNER TO { new_owner | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
73           REPLICA IDENTITY { DEFAULT | USING INDEX index_name | FULL | NOTHING }
74
75       and partition_bound_spec is:
76
77       IN ( partition_bound_expr [, ...] ) |
78       FROM ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] )
79         TO ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] ) |
80       WITH ( MODULUS numeric_literal, REMAINDER numeric_literal )
81
82       and column_constraint is:
83
84       [ CONSTRAINT constraint_name ]
85       { NOT NULL |
86         NULL |
87         CHECK ( expression ) [ NO INHERIT ] |
88         DEFAULT default_expr |
89         GENERATED ALWAYS AS ( generation_expr ) STORED |
90         GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( sequence_options ) ] |
91         UNIQUE [ NULLS [ NOT ] DISTINCT ] index_parameters |
92         PRIMARY KEY index_parameters |
93         REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
94           [ ON DELETE referential_action ] [ ON UPDATE referential_action ] }
95       [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
96
97       and table_constraint is:
98
99       [ CONSTRAINT constraint_name ]
100       { CHECK ( expression ) [ NO INHERIT ] |
101         UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] ) index_parameters |
102         PRIMARY KEY ( column_name [, ... ] ) index_parameters |
103         EXCLUDE [ USING index_method ] ( exclude_element WITH operator [, ... ] ) index_parameters [ WHERE ( predicate ) ] |
104         FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ]
105           [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE referential_action ] [ ON UPDATE referential_action ] }
106       [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
107
108       and table_constraint_using_index is:
109
110           [ CONSTRAINT constraint_name ]
111           { UNIQUE | PRIMARY KEY } USING INDEX index_name
112           [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
113
114       index_parameters in UNIQUE, PRIMARY KEY, and EXCLUDE constraints are:
115
116       [ INCLUDE ( column_name [, ... ] ) ]
117       [ WITH ( storage_parameter [= value] [, ... ] ) ]
118       [ USING INDEX TABLESPACE tablespace_name ]
119
120       exclude_element in an EXCLUDE constraint is:
121
122       { column_name | ( expression ) } [ opclass ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
123
124       referential_action in a FOREIGN KEY/REFERENCES constraint is:
125
126       { NO ACTION | RESTRICT | CASCADE | SET NULL [ ( column_name [, ... ] ) ] | SET DEFAULT [ ( column_name [, ... ] ) ] }
127

DESCRIPTION

129       ALTER TABLE changes the definition of an existing table. There are
130       several subforms described below. Note that the lock level required may
131       differ for each subform. An ACCESS EXCLUSIVE lock is acquired unless
132       explicitly noted. When multiple subcommands are given, the lock
133       acquired will be the strictest one required by any subcommand.
134
135       ADD COLUMN [ IF NOT EXISTS ]
136           This form adds a new column to the table, using the same syntax as
137           CREATE TABLE. If IF NOT EXISTS is specified and a column already
138           exists with this name, no error is thrown.
139
140       DROP COLUMN [ IF EXISTS ]
141           This form drops a column from a table. Indexes and table
142           constraints involving the column will be automatically dropped as
143           well. Multivariate statistics referencing the dropped column will
144           also be removed if the removal of the column would cause the
145           statistics to contain data for only a single column. You will need
146           to say CASCADE if anything outside the table depends on the column,
147           for example, foreign key references or views. If IF EXISTS is
148           specified and the column does not exist, no error is thrown. In
149           this case a notice is issued instead.
150
151       SET DATA TYPE
152           This form changes the type of a column of a table. Indexes and
153           simple table constraints involving the column will be automatically
154           converted to use the new column type by reparsing the originally
155           supplied expression. The optional COLLATE clause specifies a
156           collation for the new column; if omitted, the collation is the
157           default for the new column type. The optional USING clause
158           specifies how to compute the new column value from the old; if
159           omitted, the default conversion is the same as an assignment cast
160           from old data type to new. A USING clause must be provided if there
161           is no implicit or assignment cast from old to new type.
162
163           When this form is used, the column's statistics are removed, so
164           running ANALYZE on the table afterwards is recommended.
165
166       SET/DROP DEFAULT
167           These forms set or remove the default value for a column (where
168           removal is equivalent to setting the default value to NULL). The
169           new default value will only apply in subsequent INSERT or UPDATE
170           commands; it does not cause rows already in the table to change.
171
172       SET/DROP NOT NULL
173           These forms change whether a column is marked to allow null values
174           or to reject null values.
175
176           SET NOT NULL may only be applied to a column provided none of the
177           records in the table contain a NULL value for the column.
178           Ordinarily this is checked during the ALTER TABLE by scanning the
179           entire table; however, if a valid CHECK constraint is found which
180           proves no NULL can exist, then the table scan is skipped.
181
182           If this table is a partition, one cannot perform DROP NOT NULL on a
183           column if it is marked NOT NULL in the parent table. To drop the
184           NOT NULL constraint from all the partitions, perform DROP NOT NULL
185           on the parent table. Even if there is no NOT NULL constraint on the
186           parent, such a constraint can still be added to individual
187           partitions, if desired; that is, the children can disallow nulls
188           even if the parent allows them, but not the other way around.
189
190       DROP EXPRESSION [ IF EXISTS ]
191           This form turns a stored generated column into a normal base
192           column. Existing data in the columns is retained, but future
193           changes will no longer apply the generation expression.
194
195           If DROP EXPRESSION IF EXISTS is specified and the column is not a
196           stored generated column, no error is thrown. In this case a notice
197           is issued instead.
198
199       ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY
200       SET GENERATED { ALWAYS | BY DEFAULT }
201       DROP IDENTITY [ IF EXISTS ]
202           These forms change whether a column is an identity column or change
203           the generation attribute of an existing identity column. See CREATE
204           TABLE for details. Like SET DEFAULT, these forms only affect the
205           behavior of subsequent INSERT and UPDATE commands; they do not
206           cause rows already in the table to change.
207
208           If DROP IDENTITY IF EXISTS is specified and the column is not an
209           identity column, no error is thrown. In this case a notice is
210           issued instead.
211
212       SET sequence_option
213       RESTART
214           These forms alter the sequence that underlies an existing identity
215           column.  sequence_option is an option supported by ALTER SEQUENCE
216           such as INCREMENT BY.
217
218       SET STATISTICS
219           This form sets the per-column statistics-gathering target for
220           subsequent ANALYZE operations. The target can be set in the range 0
221           to 10000; alternatively, set it to -1 to revert to using the system
222           default statistics target (default_statistics_target). For more
223           information on the use of statistics by the PostgreSQL query
224           planner, refer to Section 14.2.
225
226           SET STATISTICS acquires a SHARE UPDATE EXCLUSIVE lock.
227
228       SET ( attribute_option = value [, ... ] )
229       RESET ( attribute_option [, ... ] )
230           This form sets or resets per-attribute options. Currently, the only
231           defined per-attribute options are n_distinct and
232           n_distinct_inherited, which override the number-of-distinct-values
233           estimates made by subsequent ANALYZE operations.  n_distinct
234           affects the statistics for the table itself, while
235           n_distinct_inherited affects the statistics gathered for the table
236           plus its inheritance children. When set to a positive value,
237           ANALYZE will assume that the column contains exactly the specified
238           number of distinct nonnull values. When set to a negative value,
239           which must be greater than or equal to -1, ANALYZE will assume that
240           the number of distinct nonnull values in the column is linear in
241           the size of the table; the exact count is to be computed by
242           multiplying the estimated table size by the absolute value of the
243           given number. For example, a value of -1 implies that all values in
244           the column are distinct, while a value of -0.5 implies that each
245           value appears twice on the average. This can be useful when the
246           size of the table changes over time, since the multiplication by
247           the number of rows in the table is not performed until query
248           planning time. Specify a value of 0 to revert to estimating the
249           number of distinct values normally. For more information on the use
250           of statistics by the PostgreSQL query planner, refer to
251           Section 14.2.
252
253           Changing per-attribute options acquires a SHARE UPDATE EXCLUSIVE
254           lock.
255
256       SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }
257           This form sets the storage mode for a column. This controls whether
258           this column is held inline or in a secondary TOAST table, and
259           whether the data should be compressed or not.  PLAIN must be used
260           for fixed-length values such as integer and is inline,
261           uncompressed.  MAIN is for inline, compressible data.  EXTERNAL is
262           for external, uncompressed data, and EXTENDED is for external,
263           compressed data. Writing DEFAULT sets the storage mode to the
264           default mode for the column's data type.  EXTENDED is the default
265           for most data types that support non-PLAIN storage. Use of EXTERNAL
266           will make substring operations on very large text and bytea values
267           run faster, at the penalty of increased storage space. Note that
268           ALTER TABLE ... SET STORAGE doesn't itself change anything in the
269           table; it just sets the strategy to be pursued during future table
270           updates. See Section 73.2 for more information.
271
272       SET COMPRESSION compression_method
273           This form sets the compression method for a column, determining how
274           values inserted in future will be compressed (if the storage mode
275           permits compression at all). This does not cause the table to be
276           rewritten, so existing data may still be compressed with other
277           compression methods. If the table is restored with pg_restore, then
278           all values are rewritten with the configured compression method.
279           However, when data is inserted from another relation (for example,
280           by INSERT ... SELECT), values from the source table are not
281           necessarily detoasted, so any previously compressed data may retain
282           its existing compression method, rather than being recompressed
283           with the compression method of the target column. The supported
284           compression methods are pglz and lz4. (lz4 is available only if
285           --with-lz4 was used when building PostgreSQL.) In addition,
286           compression_method can be default, which selects the default
287           behavior of consulting the default_toast_compression setting at the
288           time of data insertion to determine the method to use.
289
290       ADD table_constraint [ NOT VALID ]
291           This form adds a new constraint to a table using the same
292           constraint syntax as CREATE TABLE, plus the option NOT VALID, which
293           is currently only allowed for foreign key and CHECK constraints.
294
295           Normally, this form will cause a scan of the table to verify that
296           all existing rows in the table satisfy the new constraint. But if
297           the NOT VALID option is used, this potentially-lengthy scan is
298           skipped. The constraint will still be enforced against subsequent
299           inserts or updates (that is, they'll fail unless there is a
300           matching row in the referenced table, in the case of foreign keys,
301           or they'll fail unless the new row matches the specified check
302           condition). But the database will not assume that the constraint
303           holds for all rows in the table, until it is validated by using the
304           VALIDATE CONSTRAINT option. See Notes below for more information
305           about using the NOT VALID option.
306
307           Although most forms of ADD table_constraint require an ACCESS
308           EXCLUSIVE lock, ADD FOREIGN KEY requires only a SHARE ROW EXCLUSIVE
309           lock. Note that ADD FOREIGN KEY also acquires a SHARE ROW EXCLUSIVE
310           lock on the referenced table, in addition to the lock on the table
311           on which the constraint is declared.
312
313           Additional restrictions apply when unique or primary key
314           constraints are added to partitioned tables; see CREATE TABLE.
315           Also, foreign key constraints on partitioned tables may not be
316           declared NOT VALID at present.
317
318       ADD table_constraint_using_index
319           This form adds a new PRIMARY KEY or UNIQUE constraint to a table
320           based on an existing unique index. All the columns of the index
321           will be included in the constraint.
322
323           The index cannot have expression columns nor be a partial index.
324           Also, it must be a b-tree index with default sort ordering. These
325           restrictions ensure that the index is equivalent to one that would
326           be built by a regular ADD PRIMARY KEY or ADD UNIQUE command.
327
328           If PRIMARY KEY is specified, and the index's columns are not
329           already marked NOT NULL, then this command will attempt to do ALTER
330           COLUMN SET NOT NULL against each such column. That requires a full
331           table scan to verify the column(s) contain no nulls. In all other
332           cases, this is a fast operation.
333
334           If a constraint name is provided then the index will be renamed to
335           match the constraint name. Otherwise the constraint will be named
336           the same as the index.
337
338           After this command is executed, the index is “owned” by the
339           constraint, in the same way as if the index had been built by a
340           regular ADD PRIMARY KEY or ADD UNIQUE command. In particular,
341           dropping the constraint will make the index disappear too.
342
343           This form is not currently supported on partitioned tables.
344
345               Note
346               Adding a constraint using an existing index can be helpful in
347               situations where a new constraint needs to be added without
348               blocking table updates for a long time. To do that, create the
349               index using CREATE INDEX CONCURRENTLY, and then install it as
350               an official constraint using this syntax. See the example
351               below.
352
353       ALTER CONSTRAINT
354           This form alters the attributes of a constraint that was previously
355           created. Currently only foreign key constraints may be altered.
356
357       VALIDATE CONSTRAINT
358           This form validates a foreign key or check constraint that was
359           previously created as NOT VALID, by scanning the table to ensure
360           there are no rows for which the constraint is not satisfied.
361           Nothing happens if the constraint is already marked valid. (See
362           Notes below for an explanation of the usefulness of this command.)
363
364           This command acquires a SHARE UPDATE EXCLUSIVE lock.
365
366       DROP CONSTRAINT [ IF EXISTS ]
367           This form drops the specified constraint on a table, along with any
368           index underlying the constraint. If IF EXISTS is specified and the
369           constraint does not exist, no error is thrown. In this case a
370           notice is issued instead.
371
372       DISABLE/ENABLE [ REPLICA | ALWAYS ] TRIGGER
373           These forms configure the firing of trigger(s) belonging to the
374           table. A disabled trigger is still known to the system, but is not
375           executed when its triggering event occurs. (For a deferred trigger,
376           the enable status is checked when the event occurs, not when the
377           trigger function is actually executed.) One can disable or enable a
378           single trigger specified by name, or all triggers on the table, or
379           only user triggers (this option excludes internally generated
380           constraint triggers, such as those that are used to implement
381           foreign key constraints or deferrable uniqueness and exclusion
382           constraints). Disabling or enabling internally generated constraint
383           triggers requires superuser privileges; it should be done with
384           caution since of course the integrity of the constraint cannot be
385           guaranteed if the triggers are not executed.
386
387           The trigger firing mechanism is also affected by the configuration
388           variable session_replication_role. Simply enabled triggers (the
389           default) will fire when the replication role is “origin” (the
390           default) or “local”. Triggers configured as ENABLE REPLICA will
391           only fire if the session is in “replica” mode, and triggers
392           configured as ENABLE ALWAYS will fire regardless of the current
393           replication role.
394
395           The effect of this mechanism is that in the default configuration,
396           triggers do not fire on replicas. This is useful because if a
397           trigger is used on the origin to propagate data between tables,
398           then the replication system will also replicate the propagated
399           data; so the trigger should not fire a second time on the replica,
400           because that would lead to duplication. However, if a trigger is
401           used for another purpose such as creating external alerts, then it
402           might be appropriate to set it to ENABLE ALWAYS so that it is also
403           fired on replicas.
404
405           When this command is applied to a partitioned table, the states of
406           corresponding clone triggers in the partitions are updated too,
407           unless ONLY is specified.
408
409           This command acquires a SHARE ROW EXCLUSIVE lock.
410
411       DISABLE/ENABLE [ REPLICA | ALWAYS ] RULE
412           These forms configure the firing of rewrite rules belonging to the
413           table. A disabled rule is still known to the system, but is not
414           applied during query rewriting. The semantics are as for
415           disabled/enabled triggers. This configuration is ignored for ON
416           SELECT rules, which are always applied in order to keep views
417           working even if the current session is in a non-default replication
418           role.
419
420           The rule firing mechanism is also affected by the configuration
421           variable session_replication_role, analogous to triggers as
422           described above.
423
424       DISABLE/ENABLE ROW LEVEL SECURITY
425           These forms control the application of row security policies
426           belonging to the table. If enabled and no policies exist for the
427           table, then a default-deny policy is applied. Note that policies
428           can exist for a table even if row-level security is disabled. In
429           this case, the policies will not be applied and the policies will
430           be ignored. See also CREATE POLICY.
431
432       NO FORCE/FORCE ROW LEVEL SECURITY
433           These forms control the application of row security policies
434           belonging to the table when the user is the table owner. If
435           enabled, row-level security policies will be applied when the user
436           is the table owner. If disabled (the default) then row-level
437           security will not be applied when the user is the table owner. See
438           also CREATE POLICY.
439
440       CLUSTER ON
441           This form selects the default index for future CLUSTER operations.
442           It does not actually re-cluster the table.
443
444           Changing cluster options acquires a SHARE UPDATE EXCLUSIVE lock.
445
446       SET WITHOUT CLUSTER
447           This form removes the most recently used CLUSTER index
448           specification from the table. This affects future cluster
449           operations that don't specify an index.
450
451           Changing cluster options acquires a SHARE UPDATE EXCLUSIVE lock.
452
453       SET WITHOUT OIDS
454           Backward-compatible syntax for removing the oid system column. As
455           oid system columns cannot be added anymore, this never has an
456           effect.
457
458       SET ACCESS METHOD
459           This form changes the access method of the table by rewriting it.
460           See Chapter 63 for more information.
461
462       SET TABLESPACE
463           This form changes the table's tablespace to the specified
464           tablespace and moves the data file(s) associated with the table to
465           the new tablespace. Indexes on the table, if any, are not moved;
466           but they can be moved separately with additional SET TABLESPACE
467           commands. When applied to a partitioned table, nothing is moved,
468           but any partitions created afterwards with CREATE TABLE PARTITION
469           OF will use that tablespace, unless overridden by a TABLESPACE
470           clause.
471
472           All tables in the current database in a tablespace can be moved by
473           using the ALL IN TABLESPACE form, which will lock all tables to be
474           moved first and then move each one. This form also supports OWNED
475           BY, which will only move tables owned by the roles specified. If
476           the NOWAIT option is specified then the command will fail if it is
477           unable to acquire all of the locks required immediately. Note that
478           system catalogs are not moved by this command; use ALTER DATABASE
479           or explicit ALTER TABLE invocations instead if desired. The
480           information_schema relations are not considered part of the system
481           catalogs and will be moved. See also CREATE TABLESPACE.
482
483       SET { LOGGED | UNLOGGED }
484           This form changes the table from unlogged to logged or vice-versa
485           (see UNLOGGED). It cannot be applied to a temporary table.
486
487           This also changes the persistence of any sequences linked to the
488           table (for identity or serial columns). However, it is also
489           possible to change the persistence of such sequences separately.
490
491       SET ( storage_parameter [= value] [, ... ] )
492           This form changes one or more storage parameters for the table. See
493           Storage Parameters in the CREATE TABLE documentation for details on
494           the available parameters. Note that the table contents will not be
495           modified immediately by this command; depending on the parameter
496           you might need to rewrite the table to get the desired effects.
497           That can be done with VACUUM FULL, CLUSTER or one of the forms of
498           ALTER TABLE that forces a table rewrite. For planner related
499           parameters, changes will take effect from the next time the table
500           is locked so currently executing queries will not be affected.
501
502           SHARE UPDATE EXCLUSIVE lock will be taken for fillfactor, toast and
503           autovacuum storage parameters, as well as the planner parameter
504           parallel_workers.
505
506       RESET ( storage_parameter [, ... ] )
507           This form resets one or more storage parameters to their defaults.
508           As with SET, a table rewrite might be needed to update the table
509           entirely.
510
511       INHERIT parent_table
512           This form adds the target table as a new child of the specified
513           parent table. Subsequently, queries against the parent will include
514           records of the target table. To be added as a child, the target
515           table must already contain all the same columns as the parent (it
516           could have additional columns, too). The columns must have matching
517           data types, and if they have NOT NULL constraints in the parent
518           then they must also have NOT NULL constraints in the child.
519
520           There must also be matching child-table constraints for all CHECK
521           constraints of the parent, except those marked non-inheritable
522           (that is, created with ALTER TABLE ... ADD CONSTRAINT ... NO
523           INHERIT) in the parent, which are ignored; all child-table
524           constraints matched must not be marked non-inheritable. Currently
525           UNIQUE, PRIMARY KEY, and FOREIGN KEY constraints are not
526           considered, but this might change in the future.
527
528       NO INHERIT parent_table
529           This form removes the target table from the list of children of the
530           specified parent table. Queries against the parent table will no
531           longer include records drawn from the target table.
532
533       OF type_name
534           This form links the table to a composite type as though CREATE
535           TABLE OF had formed it. The table's list of column names and types
536           must precisely match that of the composite type. The table must not
537           inherit from any other table. These restrictions ensure that CREATE
538           TABLE OF would permit an equivalent table definition.
539
540       NOT OF
541           This form dissociates a typed table from its type.
542
543       OWNER TO
544           This form changes the owner of the table, sequence, view,
545           materialized view, or foreign table to the specified user.
546
547       REPLICA IDENTITY
548           This form changes the information which is written to the
549           write-ahead log to identify rows which are updated or deleted. In
550           most cases, the old value of each column is only logged if it
551           differs from the new value; however, if the old value is stored
552           externally, it is always logged regardless of whether it changed.
553           This option has no effect except when logical replication is in
554           use.
555
556           DEFAULT
557               Records the old values of the columns of the primary key, if
558               any. This is the default for non-system tables.
559
560           USING INDEX index_name
561               Records the old values of the columns covered by the named
562               index, that must be unique, not partial, not deferrable, and
563               include only columns marked NOT NULL. If this index is dropped,
564               the behavior is the same as NOTHING.
565
566           FULL
567               Records the old values of all columns in the row.
568
569           NOTHING
570               Records no information about the old row. This is the default
571               for system tables.
572
573       RENAME
574           The RENAME forms change the name of a table (or an index, sequence,
575           view, materialized view, or foreign table), the name of an
576           individual column in a table, or the name of a constraint of the
577           table. When renaming a constraint that has an underlying index, the
578           index is renamed as well. There is no effect on the stored data.
579
580       SET SCHEMA
581           This form moves the table into another schema. Associated indexes,
582           constraints, and sequences owned by table columns are moved as
583           well.
584
585       ATTACH PARTITION partition_name { FOR VALUES partition_bound_spec |
586       DEFAULT }
587           This form attaches an existing table (which might itself be
588           partitioned) as a partition of the target table. The table can be
589           attached as a partition for specific values using FOR VALUES or as
590           a default partition by using DEFAULT. For each index in the target
591           table, a corresponding one will be created in the attached table;
592           or, if an equivalent index already exists, it will be attached to
593           the target table's index, as if ALTER INDEX ATTACH PARTITION had
594           been executed. Note that if the existing table is a foreign table,
595           it is currently not allowed to attach the table as a partition of
596           the target table if there are UNIQUE indexes on the target table.
597           (See also CREATE FOREIGN TABLE (CREATE_FOREIGN_TABLE(7)).) For each
598           user-defined row-level trigger that exists in the target table, a
599           corresponding one is created in the attached table.
600
601           A partition using FOR VALUES uses same syntax for
602           partition_bound_spec as CREATE TABLE. The partition bound
603           specification must correspond to the partitioning strategy and
604           partition key of the target table. The table to be attached must
605           have all the same columns as the target table and no more;
606           moreover, the column types must also match. Also, it must have all
607           the NOT NULL and CHECK constraints of the target table. Currently
608           FOREIGN KEY constraints are not considered.  UNIQUE and PRIMARY KEY
609           constraints from the parent table will be created in the partition,
610           if they don't already exist. If any of the CHECK constraints of the
611           table being attached are marked NO INHERIT, the command will fail;
612           such constraints must be recreated without the NO INHERIT clause.
613
614           If the new partition is a regular table, a full table scan is
615           performed to check that existing rows in the table do not violate
616           the partition constraint. It is possible to avoid this scan by
617           adding a valid CHECK constraint to the table that allows only rows
618           satisfying the desired partition constraint before running this
619           command. The CHECK constraint will be used to determine that the
620           table need not be scanned to validate the partition constraint.
621           This does not work, however, if any of the partition keys is an
622           expression and the partition does not accept NULL values. If
623           attaching a list partition that will not accept NULL values, also
624           add a NOT NULL constraint to the partition key column, unless it's
625           an expression.
626
627           If the new partition is a foreign table, nothing is done to verify
628           that all the rows in the foreign table obey the partition
629           constraint. (See the discussion in CREATE FOREIGN TABLE
630           (CREATE_FOREIGN_TABLE(7)) about constraints on the foreign table.)
631
632           When a table has a default partition, defining a new partition
633           changes the partition constraint for the default partition. The
634           default partition can't contain any rows that would need to be
635           moved to the new partition, and will be scanned to verify that none
636           are present. This scan, like the scan of the new partition, can be
637           avoided if an appropriate CHECK constraint is present. Also like
638           the scan of the new partition, it is always skipped when the
639           default partition is a foreign table.
640
641           Attaching a partition acquires a SHARE UPDATE EXCLUSIVE lock on the
642           parent table, in addition to the ACCESS EXCLUSIVE locks on the
643           table being attached and on the default partition (if any).
644
645           Further locks must also be held on all sub-partitions if the table
646           being attached is itself a partitioned table. Likewise if the
647           default partition is itself a partitioned table. The locking of the
648           sub-partitions can be avoided by adding a CHECK constraint as
649           described in Section 5.11.2.2.
650
651       DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ]
652           This form detaches the specified partition of the target table. The
653           detached partition continues to exist as a standalone table, but no
654           longer has any ties to the table from which it was detached. Any
655           indexes that were attached to the target table's indexes are
656           detached. Any triggers that were created as clones of those in the
657           target table are removed.  SHARE lock is obtained on any tables
658           that reference this partitioned table in foreign key constraints.
659
660           If CONCURRENTLY is specified, it runs using a reduced lock level to
661           avoid blocking other sessions that might be accessing the
662           partitioned table. In this mode, two transactions are used
663           internally. During the first transaction, a SHARE UPDATE EXCLUSIVE
664           lock is taken on both parent table and partition, and the partition
665           is marked as undergoing detach; at that point, the transaction is
666           committed and all other transactions using the partitioned table
667           are waited for. Once all those transactions have completed, the
668           second transaction acquires SHARE UPDATE EXCLUSIVE on the
669           partitioned table and ACCESS EXCLUSIVE on the partition, and the
670           detach process completes. A CHECK constraint that duplicates the
671           partition constraint is added to the partition.  CONCURRENTLY
672           cannot be run in a transaction block and is not allowed if the
673           partitioned table contains a default partition.
674
675           If FINALIZE is specified, a previous DETACH CONCURRENTLY invocation
676           that was canceled or interrupted is completed. At most one
677           partition in a partitioned table can be pending detach at a time.
678
679       All the forms of ALTER TABLE that act on a single table, except RENAME,
680       SET SCHEMA, ATTACH PARTITION, and DETACH PARTITION can be combined into
681       a list of multiple alterations to be applied together. For example, it
682       is possible to add several columns and/or alter the type of several
683       columns in a single command. This is particularly useful with large
684       tables, since only one pass over the table need be made.
685
686       You must own the table to use ALTER TABLE. To change the schema or
687       tablespace of a table, you must also have CREATE privilege on the new
688       schema or tablespace. To add the table as a new child of a parent
689       table, you must own the parent table as well. Also, to attach a table
690       as a new partition of the table, you must own the table being attached.
691       To alter the owner, you must be able to SET ROLE to the new owning
692       role, and that role must have CREATE privilege on the table's schema.
693       (These restrictions enforce that altering the owner doesn't do anything
694       you couldn't do by dropping and recreating the table. However, a
695       superuser can alter ownership of any table anyway.) To add a column or
696       alter a column type or use the OF clause, you must also have USAGE
697       privilege on the data type.
698

PARAMETERS

700       IF EXISTS
701           Do not throw an error if the table does not exist. A notice is
702           issued in this case.
703
704       name
705           The name (optionally schema-qualified) of an existing table to
706           alter. If ONLY is specified before the table name, only that table
707           is altered. If ONLY is not specified, the table and all its
708           descendant tables (if any) are altered. Optionally, * can be
709           specified after the table name to explicitly indicate that
710           descendant tables are included.
711
712       column_name
713           Name of a new or existing column.
714
715       new_column_name
716           New name for an existing column.
717
718       new_name
719           New name for the table.
720
721       data_type
722           Data type of the new column, or new data type for an existing
723           column.
724
725       table_constraint
726           New table constraint for the table.
727
728       constraint_name
729           Name of a new or existing constraint.
730
731       CASCADE
732           Automatically drop objects that depend on the dropped column or
733           constraint (for example, views referencing the column), and in turn
734           all objects that depend on those objects (see Section 5.14).
735
736       RESTRICT
737           Refuse to drop the column or constraint if there are any dependent
738           objects. This is the default behavior.
739
740       trigger_name
741           Name of a single trigger to disable or enable.
742
743       ALL
744           Disable or enable all triggers belonging to the table. (This
745           requires superuser privilege if any of the triggers are internally
746           generated constraint triggers, such as those that are used to
747           implement foreign key constraints or deferrable uniqueness and
748           exclusion constraints.)
749
750       USER
751           Disable or enable all triggers belonging to the table except for
752           internally generated constraint triggers, such as those that are
753           used to implement foreign key constraints or deferrable uniqueness
754           and exclusion constraints.
755
756       index_name
757           The name of an existing index.
758
759       storage_parameter
760           The name of a table storage parameter.
761
762       value
763           The new value for a table storage parameter. This might be a number
764           or a word depending on the parameter.
765
766       parent_table
767           A parent table to associate or de-associate with this table.
768
769       new_owner
770           The user name of the new owner of the table.
771
772       new_access_method
773           The name of the access method to which the table will be converted.
774
775       new_tablespace
776           The name of the tablespace to which the table will be moved.
777
778       new_schema
779           The name of the schema to which the table will be moved.
780
781       partition_name
782           The name of the table to attach as a new partition or to detach
783           from this table.
784
785       partition_bound_spec
786           The partition bound specification for a new partition. Refer to
787           CREATE TABLE (CREATE_TABLE(7)) for more details on the syntax of
788           the same.
789

NOTES

791       The key word COLUMN is noise and can be omitted.
792
793       When a column is added with ADD COLUMN and a non-volatile DEFAULT is
794       specified, the default is evaluated at the time of the statement and
795       the result stored in the table's metadata. That value will be used for
796       the column for all existing rows. If no DEFAULT is specified, NULL is
797       used. In neither case is a rewrite of the table required.
798
799       Adding a column with a volatile DEFAULT or changing the type of an
800       existing column will require the entire table and its indexes to be
801       rewritten. As an exception, when changing the type of an existing
802       column, if the USING clause does not change the column contents and the
803       old type is either binary coercible to the new type or an unconstrained
804       domain over the new type, a table rewrite is not needed. However,
805       indexes must always be rebuilt unless the system can verify that the
806       new index would be logically equivalent to the existing one. For
807       example, if the collation for a column has been changed, an index
808       rebuild is always required because the new sort order might be
809       different. However, in the absence of a collation change, a column can
810       be changed from text to varchar (or vice versa) without rebuilding the
811       indexes because these data types sort identically. Table and/or index
812       rebuilds may take a significant amount of time for a large table; and
813       will temporarily require as much as double the disk space.
814
815       Adding a CHECK or NOT NULL constraint requires scanning the table to
816       verify that existing rows meet the constraint, but does not require a
817       table rewrite.
818
819       Similarly, when attaching a new partition it may be scanned to verify
820       that existing rows meet the partition constraint.
821
822       The main reason for providing the option to specify multiple changes in
823       a single ALTER TABLE is that multiple table scans or rewrites can
824       thereby be combined into a single pass over the table.
825
826       Scanning a large table to verify a new foreign key or check constraint
827       can take a long time, and other updates to the table are locked out
828       until the ALTER TABLE ADD CONSTRAINT command is committed. The main
829       purpose of the NOT VALID constraint option is to reduce the impact of
830       adding a constraint on concurrent updates. With NOT VALID, the ADD
831       CONSTRAINT command does not scan the table and can be committed
832       immediately. After that, a VALIDATE CONSTRAINT command can be issued to
833       verify that existing rows satisfy the constraint. The validation step
834       does not need to lock out concurrent updates, since it knows that other
835       transactions will be enforcing the constraint for rows that they insert
836       or update; only pre-existing rows need to be checked. Hence, validation
837       acquires only a SHARE UPDATE EXCLUSIVE lock on the table being altered.
838       (If the constraint is a foreign key then a ROW SHARE lock is also
839       required on the table referenced by the constraint.) In addition to
840       improving concurrency, it can be useful to use NOT VALID and VALIDATE
841       CONSTRAINT in cases where the table is known to contain pre-existing
842       violations. Once the constraint is in place, no new violations can be
843       inserted, and the existing problems can be corrected at leisure until
844       VALIDATE CONSTRAINT finally succeeds.
845
846       The DROP COLUMN form does not physically remove the column, but simply
847       makes it invisible to SQL operations. Subsequent insert and update
848       operations in the table will store a null value for the column. Thus,
849       dropping a column is quick but it will not immediately reduce the
850       on-disk size of your table, as the space occupied by the dropped column
851       is not reclaimed. The space will be reclaimed over time as existing
852       rows are updated.
853
854       To force immediate reclamation of space occupied by a dropped column,
855       you can execute one of the forms of ALTER TABLE that performs a rewrite
856       of the whole table. This results in reconstructing each row with the
857       dropped column replaced by a null value.
858
859       The rewriting forms of ALTER TABLE are not MVCC-safe. After a table
860       rewrite, the table will appear empty to concurrent transactions, if
861       they are using a snapshot taken before the rewrite occurred. See
862       Section 13.6 for more details.
863
864       The USING option of SET DATA TYPE can actually specify any expression
865       involving the old values of the row; that is, it can refer to other
866       columns as well as the one being converted. This allows very general
867       conversions to be done with the SET DATA TYPE syntax. Because of this
868       flexibility, the USING expression is not applied to the column's
869       default value (if any); the result might not be a constant expression
870       as required for a default. This means that when there is no implicit or
871       assignment cast from old to new type, SET DATA TYPE might fail to
872       convert the default even though a USING clause is supplied. In such
873       cases, drop the default with DROP DEFAULT, perform the ALTER TYPE, and
874       then use SET DEFAULT to add a suitable new default. Similar
875       considerations apply to indexes and constraints involving the column.
876
877       If a table has any descendant tables, it is not permitted to add,
878       rename, or change the type of a column in the parent table without
879       doing the same to the descendants. This ensures that the descendants
880       always have columns matching the parent. Similarly, a CHECK constraint
881       cannot be renamed in the parent without also renaming it in all
882       descendants, so that CHECK constraints also match between the parent
883       and its descendants. (That restriction does not apply to index-based
884       constraints, however.) Also, because selecting from the parent also
885       selects from its descendants, a constraint on the parent cannot be
886       marked valid unless it is also marked valid for those descendants. In
887       all of these cases, ALTER TABLE ONLY will be rejected.
888
889       A recursive DROP COLUMN operation will remove a descendant table's
890       column only if the descendant does not inherit that column from any
891       other parents and never had an independent definition of the column. A
892       nonrecursive DROP COLUMN (i.e., ALTER TABLE ONLY ... DROP COLUMN) never
893       removes any descendant columns, but instead marks them as independently
894       defined rather than inherited. A nonrecursive DROP COLUMN command will
895       fail for a partitioned table, because all partitions of a table must
896       have the same columns as the partitioning root.
897
898       The actions for identity columns (ADD GENERATED, SET etc., DROP
899       IDENTITY), as well as the actions CLUSTER, OWNER, and TABLESPACE never
900       recurse to descendant tables; that is, they always act as though ONLY
901       were specified. Actions affecting trigger states recurse to partitions
902       of partitioned tables (unless ONLY is specified), but never to
903       traditional-inheritance descendants. Adding a constraint recurses only
904       for CHECK constraints that are not marked NO INHERIT.
905
906       Changing any part of a system catalog table is not permitted.
907
908       Refer to CREATE TABLE (CREATE_TABLE(7)) for a further description of
909       valid parameters.  Chapter 5 has further information on inheritance.
910

EXAMPLES

912       To add a column of type varchar to a table:
913
914           ALTER TABLE distributors ADD COLUMN address varchar(30);
915
916       That will cause all existing rows in the table to be filled with null
917       values for the new column.
918
919       To add a column with a non-null default:
920
921           ALTER TABLE measurements
922             ADD COLUMN mtime timestamp with time zone DEFAULT now();
923
924       Existing rows will be filled with the current time as the value of the
925       new column, and then new rows will receive the time of their insertion.
926
927       To add a column and fill it with a value different from the default to
928       be used later:
929
930           ALTER TABLE transactions
931             ADD COLUMN status varchar(30) DEFAULT 'old',
932             ALTER COLUMN status SET default 'current';
933
934       Existing rows will be filled with old, but then the default for
935       subsequent commands will be current. The effects are the same as if the
936       two sub-commands had been issued in separate ALTER TABLE commands.
937
938       To drop a column from a table:
939
940           ALTER TABLE distributors DROP COLUMN address RESTRICT;
941
942       To change the types of two existing columns in one operation:
943
944           ALTER TABLE distributors
945               ALTER COLUMN address TYPE varchar(80),
946               ALTER COLUMN name TYPE varchar(100);
947
948       To change an integer column containing Unix timestamps to timestamp
949       with time zone via a USING clause:
950
951           ALTER TABLE foo
952               ALTER COLUMN foo_timestamp SET DATA TYPE timestamp with time zone
953               USING
954                   timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
955
956       The same, when the column has a default expression that won't
957       automatically cast to the new data type:
958
959           ALTER TABLE foo
960               ALTER COLUMN foo_timestamp DROP DEFAULT,
961               ALTER COLUMN foo_timestamp TYPE timestamp with time zone
962               USING
963                   timestamp with time zone 'epoch' + foo_timestamp * interval '1 second',
964               ALTER COLUMN foo_timestamp SET DEFAULT now();
965
966       To rename an existing column:
967
968           ALTER TABLE distributors RENAME COLUMN address TO city;
969
970       To rename an existing table:
971
972           ALTER TABLE distributors RENAME TO suppliers;
973
974       To rename an existing constraint:
975
976           ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
977
978       To add a not-null constraint to a column:
979
980           ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
981
982       To remove a not-null constraint from a column:
983
984           ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
985
986       To add a check constraint to a table and all its children:
987
988           ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
989
990       To add a check constraint only to a table and not to its children:
991
992           ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5) NO INHERIT;
993
994       (The check constraint will not be inherited by future children,
995       either.)
996
997       To remove a check constraint from a table and all its children:
998
999           ALTER TABLE distributors DROP CONSTRAINT zipchk;
1000
1001       To remove a check constraint from one table only:
1002
1003           ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk;
1004
1005       (The check constraint remains in place for any child tables.)
1006
1007       To add a foreign key constraint to a table:
1008
1009           ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address);
1010
1011       To add a foreign key constraint to a table with the least impact on
1012       other work:
1013
1014           ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) NOT VALID;
1015           ALTER TABLE distributors VALIDATE CONSTRAINT distfk;
1016
1017       To add a (multicolumn) unique constraint to a table:
1018
1019           ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zipcode);
1020
1021       To add an automatically named primary key constraint to a table, noting
1022       that a table can only ever have one primary key:
1023
1024           ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
1025
1026       To move a table to a different tablespace:
1027
1028           ALTER TABLE distributors SET TABLESPACE fasttablespace;
1029
1030       To move a table to a different schema:
1031
1032           ALTER TABLE myschema.distributors SET SCHEMA yourschema;
1033
1034       To recreate a primary key constraint, without blocking updates while
1035       the index is rebuilt:
1036
1037           CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id);
1038           ALTER TABLE distributors DROP CONSTRAINT distributors_pkey,
1039               ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx;
1040
1041       To attach a partition to a range-partitioned table:
1042
1043           ALTER TABLE measurement
1044               ATTACH PARTITION measurement_y2016m07 FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
1045
1046       To attach a partition to a list-partitioned table:
1047
1048           ALTER TABLE cities
1049               ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
1050
1051       To attach a partition to a hash-partitioned table:
1052
1053           ALTER TABLE orders
1054               ATTACH PARTITION orders_p4 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
1055
1056       To attach a default partition to a partitioned table:
1057
1058           ALTER TABLE cities
1059               ATTACH PARTITION cities_partdef DEFAULT;
1060
1061       To detach a partition from a partitioned table:
1062
1063           ALTER TABLE measurement
1064               DETACH PARTITION measurement_y2015m12;
1065

COMPATIBILITY

1067       The forms ADD (without USING INDEX), DROP [COLUMN], DROP IDENTITY,
1068       RESTART, SET DEFAULT, SET DATA TYPE (without USING), SET GENERATED, and
1069       SET sequence_option conform with the SQL standard. The other forms are
1070       PostgreSQL extensions of the SQL standard. Also, the ability to specify
1071       more than one manipulation in a single ALTER TABLE command is an
1072       extension.
1073
1074       ALTER TABLE DROP COLUMN can be used to drop the only column of a table,
1075       leaving a zero-column table. This is an extension of SQL, which
1076       disallows zero-column tables.
1077

SEE ALSO

1079       CREATE TABLE (CREATE_TABLE(7))
1080
1081
1082
1083PostgreSQL 16.1                      2023                       ALTER TABLE(7)
Impressum