4 ALTER TABLE — change the definition of a table
8 ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
10 ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
11 RENAME [ COLUMN ] column_name TO new_column_name
12 ALTER TABLE [ IF EXISTS ] [ ONLY ] name [ * ]
13 RENAME CONSTRAINT constraint_name TO new_constraint_name
14 ALTER TABLE [ IF EXISTS ] name
16 ALTER TABLE [ IF EXISTS ] name
18 ALTER TABLE ALL IN TABLESPACE name [ OWNED BY role_name [, ... ] ]
19 SET TABLESPACE new_tablespace [ NOWAIT ]
20 ALTER TABLE [ IF EXISTS ] name
21 ATTACH PARTITION partition_name { FOR VALUES partition_bound_spec | DEFAULT
23 ALTER TABLE [ IF EXISTS ] name
24 DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ]
26 where action is one of:
28 ADD [ COLUMN ] [ IF NOT EXISTS ] column_name data_type [ COLLATE collation ]
29 [ column_constraint [ ... ] ]
30 DROP [ COLUMN ] [ IF EXISTS ] column_name [ RESTRICT | CASCADE ]
31 ALTER [ COLUMN ] column_name [ SET DATA ] TYPE data_type [ COLLATE collation
32 ] [ USING expression ]
33 ALTER [ COLUMN ] column_name SET DEFAULT expression
34 ALTER [ COLUMN ] column_name DROP DEFAULT
35 ALTER [ COLUMN ] column_name { SET | DROP } NOT NULL
36 ALTER [ COLUMN ] column_name SET EXPRESSION AS ( expression )
37 ALTER [ COLUMN ] column_name DROP EXPRESSION [ IF EXISTS ]
38 ALTER [ COLUMN ] column_name ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTI
39 TY [ ( sequence_options ) ]
40 ALTER [ COLUMN ] column_name { SET GENERATED { ALWAYS | BY DEFAULT } | SET s
41 equence_option | RESTART [ [ WITH ] restart ] } [...]
42 ALTER [ COLUMN ] column_name DROP IDENTITY [ IF EXISTS ]
43 ALTER [ COLUMN ] column_name SET STATISTICS { integer | DEFAULT }
44 ALTER [ COLUMN ] column_name SET ( attribute_option = value [, ... ] )
45 ALTER [ COLUMN ] column_name RESET ( attribute_option [, ... ] )
46 ALTER [ COLUMN ] column_name SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAI
48 ALTER [ COLUMN ] column_name SET COMPRESSION compression_method
49 ADD table_constraint [ NOT VALID ]
50 ADD table_constraint_using_index
51 ALTER CONSTRAINT constraint_name [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY
52 DEFERRED | INITIALLY IMMEDIATE ] [ ENFORCED | NOT ENFORCED ]
53 ALTER CONSTRAINT constraint_name [ INHERIT | NO INHERIT ]
54 VALIDATE CONSTRAINT constraint_name
55 DROP CONSTRAINT [ IF EXISTS ] constraint_name [ RESTRICT | CASCADE ]
56 DISABLE TRIGGER [ trigger_name | ALL | USER ]
57 ENABLE TRIGGER [ trigger_name | ALL | USER ]
58 ENABLE REPLICA TRIGGER trigger_name
59 ENABLE ALWAYS TRIGGER trigger_name
60 DISABLE RULE rewrite_rule_name
61 ENABLE RULE rewrite_rule_name
62 ENABLE REPLICA RULE rewrite_rule_name
63 ENABLE ALWAYS RULE rewrite_rule_name
64 DISABLE ROW LEVEL SECURITY
65 ENABLE ROW LEVEL SECURITY
66 FORCE ROW LEVEL SECURITY
67 NO FORCE ROW LEVEL SECURITY
71 SET ACCESS METHOD { new_access_method | DEFAULT }
72 SET TABLESPACE new_tablespace
73 SET { LOGGED | UNLOGGED }
74 SET ( storage_parameter [= value] [, ... ] )
75 RESET ( storage_parameter [, ... ] )
77 NO INHERIT parent_table
80 OWNER TO { new_owner | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
81 REPLICA IDENTITY { DEFAULT | USING INDEX index_name | FULL | NOTHING }
83 and partition_bound_spec is:
85 IN ( partition_bound_expr [, ...] ) |
86 FROM ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] )
87 TO ( { partition_bound_expr | MINVALUE | MAXVALUE } [, ...] ) |
88 WITH ( MODULUS numeric_literal, REMAINDER numeric_literal )
90 and column_constraint is:
92 [ CONSTRAINT constraint_name ]
93 { NOT NULL [ NO INHERIT ] |
95 CHECK ( expression ) [ NO INHERIT ] |
96 DEFAULT default_expr |
97 GENERATED ALWAYS AS ( generation_expr ) [ STORED | VIRTUAL ] |
98 GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( sequence_options ) ] |
99 UNIQUE [ NULLS [ NOT ] DISTINCT ] index_parameters |
100 PRIMARY KEY index_parameters |
101 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIM
103 [ ON DELETE referential_action ] [ ON UPDATE referential_action ] }
104 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] [ E
105 NFORCED | NOT ENFORCED ]
107 and table_constraint is:
109 [ CONSTRAINT constraint_name ]
110 { CHECK ( expression ) [ NO INHERIT ] |
111 NOT NULL column_name [ NO INHERIT ] |
112 UNIQUE [ NULLS [ NOT ] DISTINCT ] ( column_name [, ... ] [, column_name WITHOU
113 T OVERLAPS ] ) index_parameters |
114 PRIMARY KEY ( column_name [, ... ] [, column_name WITHOUT OVERLAPS ] ) index_p
116 EXCLUDE [ USING index_method ] ( exclude_element WITH operator [, ... ] ) inde
117 x_parameters [ WHERE ( predicate ) ] |
118 FOREIGN KEY ( column_name [, ... ] [, PERIOD column_name ] ) REFERENCES reftab
119 le [ ( refcolumn [, ... ] [, PERIOD refcolumn ] ) ]
120 [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE referential_action
121 ] [ ON UPDATE referential_action ] }
122 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] [ E
123 NFORCED | NOT ENFORCED ]
125 and table_constraint_using_index is:
127 [ CONSTRAINT constraint_name ]
128 { UNIQUE | PRIMARY KEY } USING INDEX index_name
129 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
131 index_parameters in UNIQUE, PRIMARY KEY, and EXCLUDE constraints are:
133 [ INCLUDE ( column_name [, ... ] ) ]
134 [ WITH ( storage_parameter [= value] [, ... ] ) ]
135 [ USING INDEX TABLESPACE tablespace_name ]
137 exclude_element in an EXCLUDE constraint is:
139 { column_name | ( expression ) } [ COLLATE collation ] [ opclass [ ( opclass_par
140 ameter = value [, ... ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
142 referential_action in a FOREIGN KEY/REFERENCES constraint is:
144 { NO ACTION | RESTRICT | CASCADE | SET NULL [ ( column_name [, ... ] ) ] | SET D
145 EFAULT [ ( column_name [, ... ] ) ] }
149 ALTER TABLE changes the definition of an existing table. There are
150 several subforms described below. Note that the lock level required may
151 differ for each subform. An ACCESS EXCLUSIVE lock is acquired unless
152 explicitly noted. When multiple subcommands are given, the lock
153 acquired will be the strictest one required by any subcommand.
155 ADD COLUMN [ IF NOT EXISTS ] #
156 This form adds a new column to the table, using the same syntax
157 as CREATE TABLE. If IF NOT EXISTS is specified and a column
158 already exists with this name, no error is thrown.
160 DROP COLUMN [ IF EXISTS ] #
161 This form drops a column from a table. Indexes and table
162 constraints involving the column will be automatically dropped
163 as well. Multivariate statistics referencing the dropped column
164 will also be removed if the removal of the column would cause
165 the statistics to contain data for only a single column. You
166 will need to say CASCADE if anything outside the table depends
167 on the column, for example, foreign key references or views. If
168 IF EXISTS is specified and the column does not exist, no error
169 is thrown. In this case a notice is issued instead.
172 This form changes the type of a column of a table. Indexes and
173 simple table constraints involving the column will be
174 automatically converted to use the new column type by reparsing
175 the originally supplied expression. The optional COLLATE clause
176 specifies a collation for the new column; if omitted, the
177 collation is the default for the new column type. The optional
178 USING clause specifies how to compute the new column value from
179 the old; if omitted, the default conversion is the same as an
180 assignment cast from old data type to new. A USING clause must
181 be provided if there is no implicit or assignment cast from old
184 When this form is used, the column's statistics are removed, so
185 running ANALYZE on the table afterwards is recommended. For a
186 virtual generated column, ANALYZE is not necessary because such
187 columns never have statistics.
190 These forms set or remove the default value for a column (where
191 removal is equivalent to setting the default value to NULL). The
192 new default value will only apply in subsequent INSERT or UPDATE
193 commands; it does not cause rows already in the table to change.
196 These forms change whether a column is marked to allow null
197 values or to reject null values.
199 SET NOT NULL may only be applied to a column provided none of
200 the records in the table contain a NULL value for the column.
201 Ordinarily this is checked during the ALTER TABLE by scanning
202 the entire table, unless NOT VALID is specified; however, if a
203 valid CHECK constraint exists (and is not dropped in the same
204 command) which proves no NULL can exist, then the table scan is
205 skipped. If a column has an invalid not-null constraint, SET NOT
208 If this table is a partition, one cannot perform DROP NOT NULL
209 on a column if it is marked NOT NULL in the parent table. To
210 drop the NOT NULL constraint from all the partitions, perform
211 DROP NOT NULL on the parent table. Even if there is no NOT NULL
212 constraint on the parent, such a constraint can still be added
213 to individual partitions, if desired; that is, the children can
214 disallow nulls even if the parent allows them, but not the other
215 way around. It is also possible to drop the NOT NULL constraint
216 from ONLY the parent table, which does not remove it from the
220 This form replaces the expression of a generated column.
221 Existing data in a stored generated column is rewritten and all
222 the future changes will apply the new generation expression.
224 When this form is used on a stored generated column, its
225 statistics are removed, so running ANALYZE on the table
226 afterwards is recommended. For a virtual generated column,
227 ANALYZE is not necessary because such columns never have
230 DROP EXPRESSION [ IF EXISTS ] #
231 This form turns a stored generated column into a normal base
232 column. Existing data in the columns is retained, but future
233 changes will no longer apply the generation expression.
235 This form is currently only supported for stored generated
236 columns (not virtual ones).
238 If DROP EXPRESSION IF EXISTS is specified and the column is not
239 a generated column, no error is thrown. In this case a notice is
242 ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY
243 SET GENERATED { ALWAYS | BY DEFAULT }
244 DROP IDENTITY [ IF EXISTS ] #
245 These forms change whether a column is an identity column or
246 change the generation attribute of an existing identity column.
247 See CREATE TABLE for details. Like SET DEFAULT, these forms only
248 affect the behavior of subsequent INSERT and UPDATE commands;
249 they do not cause rows already in the table to change.
251 If DROP IDENTITY IF EXISTS is specified and the column is not an
252 identity column, no error is thrown. In this case a notice is
257 These forms alter the sequence that underlies an existing
258 identity column. sequence_option is an option supported by ALTER
259 SEQUENCE such as INCREMENT BY.
262 This form sets the per-column statistics-gathering target for
263 subsequent ANALYZE operations. The target can be set in the
264 range 0 to 10000. Set it to DEFAULT to revert to using the
265 system default statistics target (default_statistics_target).
266 (Setting to a value of -1 is an obsolete way spelling to get the
267 same outcome.) For more information on the use of statistics by
268 the PostgreSQL query planner, refer to Section 14.2.
270 SET STATISTICS acquires a SHARE UPDATE EXCLUSIVE lock.
272 SET ( attribute_option = value [, ... ] )
273 RESET ( attribute_option [, ... ] ) #
274 This form sets or resets per-attribute options. Currently, the
275 only defined per-attribute options are n_distinct and
276 n_distinct_inherited, which override the
277 number-of-distinct-values estimates made by subsequent ANALYZE
278 operations. n_distinct affects the statistics for the table
279 itself, while n_distinct_inherited affects the statistics
280 gathered for the table plus its inheritance children. When set
281 to a positive value, ANALYZE will assume that the column
282 contains exactly the specified number of distinct nonnull
283 values. When set to a negative value, which must be greater than
284 or equal to -1, ANALYZE will assume that the number of distinct
285 nonnull values in the column is linear in the size of the table;
286 the exact count is to be computed by multiplying the estimated
287 table size by the absolute value of the given number. For
288 example, a value of -1 implies that all values in the column are
289 distinct, while a value of -0.5 implies that each value appears
290 twice on the average. This can be useful when the size of the
291 table changes over time, since the multiplication by the number
292 of rows in the table is not performed until query planning time.
293 Specify a value of 0 to revert to estimating the number of
294 distinct values normally. For more information on the use of
295 statistics by the PostgreSQL query planner, refer to
298 Changing per-attribute options acquires a SHARE UPDATE EXCLUSIVE
301 SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT } #
302 This form sets the storage mode for a column. This controls
303 whether this column is held inline or in a secondary TOAST
304 table, and whether the data should be compressed or not. PLAIN
305 must be used for fixed-length values such as integer and is
306 inline, uncompressed. MAIN is for inline, compressible data.
307 EXTERNAL is for external, uncompressed data, and EXTENDED is for
308 external, compressed data. Writing DEFAULT sets the storage mode
309 to the default mode for the column's data type. EXTENDED is the
310 default for most data types that support non-PLAIN storage. Use
311 of EXTERNAL will make substring operations on very large text
312 and bytea values run faster, at the penalty of increased storage
313 space. Note that ALTER TABLE ... SET STORAGE doesn't itself
314 change anything in the table; it just sets the strategy to be
315 pursued during future table updates. See Section 66.2 for more
318 SET COMPRESSION compression_method #
319 This form sets the compression method for a column, determining
320 how values inserted in future will be compressed (if the storage
321 mode permits compression at all). This does not cause the table
322 to be rewritten, so existing data may still be compressed with
323 other compression methods. If the table is restored with
324 pg_restore, then all values are rewritten with the configured
325 compression method. However, when data is inserted from another
326 relation (for example, by INSERT ... SELECT), values from the
327 source table are not necessarily detoasted, so any previously
328 compressed data may retain its existing compression method,
329 rather than being recompressed with the compression method of
330 the target column. The supported compression methods are pglz
331 and lz4. (lz4 is available only if --with-lz4 was used when
332 building PostgreSQL.) In addition, compression_method can be
333 default, which selects the default behavior of consulting the
334 default_toast_compression setting at the time of data insertion
335 to determine the method to use.
337 ADD table_constraint [ NOT VALID ] #
338 This form adds a new constraint to a table using the same
339 constraint syntax as CREATE TABLE, plus the option NOT VALID,
340 which is currently only allowed for foreign-key, CHECK, and
341 not-null constraints.
343 Normally, this form will cause a scan of the table to verify
344 that all existing rows in the table satisfy the new constraint.
345 But if the NOT VALID option is used, this potentially-lengthy
346 scan is skipped. The constraint will still be applied against
347 subsequent inserts or updates (that is, they'll fail unless
348 there is a matching row in the referenced table, in the case of
349 foreign keys, or they'll fail unless the new row matches the
350 specified check condition). But the database will not assume
351 that the constraint holds for all rows in the table, until it is
352 validated by using the VALIDATE CONSTRAINT option. See Notes
353 below for more information about using the NOT VALID option.
355 Although most forms of ADD table_constraint require an ACCESS
356 EXCLUSIVE lock, ADD FOREIGN KEY requires only a SHARE ROW
357 EXCLUSIVE lock. Note that ADD FOREIGN KEY also acquires a SHARE
358 ROW EXCLUSIVE lock on the referenced table, in addition to the
359 lock on the table on which the constraint is declared.
361 Additional restrictions apply when unique or primary key
362 constraints are added to partitioned tables; see CREATE TABLE.
364 ADD table_constraint_using_index #
365 This form adds a new PRIMARY KEY or UNIQUE constraint to a table
366 based on an existing unique index. All the columns of the index
367 will be included in the constraint.
369 The index cannot have expression columns nor be a partial index.
370 Also, it must be a b-tree index with default sort ordering.
371 These restrictions ensure that the index is equivalent to one
372 that would be built by a regular ADD PRIMARY KEY or ADD UNIQUE
375 If PRIMARY KEY is specified, and the index's columns are not
376 already marked NOT NULL, then this command will attempt to do
377 ALTER COLUMN SET NOT NULL against each such column. That
378 requires a full table scan to verify the column(s) contain no
379 nulls. In all other cases, this is a fast operation.
381 If a constraint name is provided then the index will be renamed
382 to match the constraint name. Otherwise the constraint will be
383 named the same as the index.
385 After this command is executed, the index is “owned” by the
386 constraint, in the same way as if the index had been built by a
387 regular ADD PRIMARY KEY or ADD UNIQUE command. In particular,
388 dropping the constraint will make the index disappear too.
390 This form is not currently supported on partitioned tables.
394 Adding a constraint using an existing index can be helpful in
395 situations where a new constraint needs to be added without
396 blocking table updates for a long time. To do that, create the
397 index using CREATE UNIQUE INDEX CONCURRENTLY, and then convert
398 it to a constraint using this syntax. See the example below.
401 This form alters the attributes of a constraint that was
402 previously created. Currently only foreign key constraints may
403 be altered in this fashion, but see below.
405 ALTER CONSTRAINT ... INHERIT
406 ALTER CONSTRAINT ... NO INHERIT #
407 These forms modify a inheritable constraint so that it becomes
408 not inheritable, or vice-versa. Only not-null constraints may be
409 altered in this fashion at present. In addition to changing the
410 inheritability status of the constraint, in the case where a
411 non-inheritable constraint is being marked inheritable, if the
412 table has children, an equivalent constraint will be added to
413 them. If marking an inheritable constraint as non-inheritable on
414 a table with children, then the corresponding constraint on
415 children will be marked as no longer inherited, but not removed.
417 VALIDATE CONSTRAINT #
418 This form validates a foreign key, check, or not-null constraint
419 that was previously created as NOT VALID, by scanning the table
420 to ensure there are no rows for which the constraint is not
421 satisfied. If the constraint was set to NOT ENFORCED, an error
422 is thrown. Nothing happens if the constraint is already marked
423 valid. (See Notes below for an explanation of the usefulness of
426 This command acquires a SHARE UPDATE EXCLUSIVE lock.
428 DROP CONSTRAINT [ IF EXISTS ] #
429 This form drops the specified constraint on a table, along with
430 any index underlying the constraint. If IF EXISTS is specified
431 and the constraint does not exist, no error is thrown. In this
432 case a notice is issued instead.
434 DISABLE/ENABLE [ REPLICA | ALWAYS ] TRIGGER #
435 These forms configure the firing of trigger(s) belonging to the
436 table. A disabled trigger is still known to the system, but is
437 not executed when its triggering event occurs. (For a deferred
438 trigger, the enable status is checked when the event occurs, not
439 when the trigger function is actually executed.) One can disable
440 or enable a single trigger specified by name, or all triggers on
441 the table, or only user triggers (this option excludes
442 internally generated constraint triggers, such as those that are
443 used to implement foreign key constraints or deferrable
444 uniqueness and exclusion constraints). Disabling or enabling
445 internally generated constraint triggers requires superuser
446 privileges; it should be done with caution since of course the
447 integrity of the constraint cannot be guaranteed if the triggers
450 The trigger firing mechanism is also affected by the
451 configuration variable session_replication_role. Simply enabled
452 triggers (the default) will fire when the replication role is
453 “origin” (the default) or “local”. Triggers configured as ENABLE
454 REPLICA will only fire if the session is in “replica” mode, and
455 triggers configured as ENABLE ALWAYS will fire regardless of the
456 current replication role.
458 The effect of this mechanism is that in the default
459 configuration, triggers do not fire on replicas. This is useful
460 because if a trigger is used on the origin to propagate data
461 between tables, then the replication system will also replicate
462 the propagated data; so the trigger should not fire a second
463 time on the replica, because that would lead to duplication.
464 However, if a trigger is used for another purpose such as
465 creating external alerts, then it might be appropriate to set it
466 to ENABLE ALWAYS so that it is also fired on replicas.
468 When this command is applied to a partitioned table, the states
469 of corresponding clone triggers in the partitions are updated
470 too, unless ONLY is specified.
472 This command acquires a SHARE ROW EXCLUSIVE lock.
474 DISABLE/ENABLE [ REPLICA | ALWAYS ] RULE #
475 These forms configure the firing of rewrite rules belonging to
476 the table. A disabled rule is still known to the system, but is
477 not applied during query rewriting. The semantics are as for
478 disabled/enabled triggers. This configuration is ignored for ON
479 SELECT rules, which are always applied in order to keep views
480 working even if the current session is in a non-default
483 The rule firing mechanism is also affected by the configuration
484 variable session_replication_role, analogous to triggers as
487 DISABLE/ENABLE ROW LEVEL SECURITY #
488 These forms control the application of row security policies
489 belonging to the table. If enabled and no policies exist for the
490 table, then a default-deny policy is applied. Note that policies
491 can exist for a table even if row-level security is disabled. In
492 this case, the policies will not be applied and the policies
493 will be ignored. See also CREATE POLICY.
495 NO FORCE/FORCE ROW LEVEL SECURITY #
496 These forms control the application of row security policies
497 belonging to the table when the user is the table owner. If
498 enabled, row-level security policies will be applied when the
499 user is the table owner. If disabled (the default) then
500 row-level security will not be applied when the user is the
501 table owner. See also CREATE POLICY.
504 This form selects the default index for future CLUSTER
505 operations. It does not actually re-cluster the table.
507 Changing cluster options acquires a SHARE UPDATE EXCLUSIVE lock.
509 SET WITHOUT CLUSTER #
510 This form removes the most recently used CLUSTER index
511 specification from the table. This affects future cluster
512 operations that don't specify an index.
514 Changing cluster options acquires a SHARE UPDATE EXCLUSIVE lock.
517 Backward-compatible syntax for removing the oid system column.
518 As oid system columns cannot be added anymore, this never has an
522 This form changes the access method of the table by rewriting it
523 using the indicated access method; specifying DEFAULT selects
524 the access method set as the default_table_access_method
525 configuration parameter. See Chapter 62 for more information.
527 When applied to a partitioned table, there is no data to
528 rewrite, but partitions created afterwards will default to the
529 given access method unless overridden by a USING clause.
530 Specifying DEFAULT removes a previous value, causing future
531 partitions to default to default_table_access_method.
534 This form changes the table's tablespace to the specified
535 tablespace and moves the data file(s) associated with the table
536 to the new tablespace. Indexes on the table, if any, are not
537 moved; but they can be moved separately with additional SET
538 TABLESPACE commands. When applied to a partitioned table,
539 nothing is moved, but any partitions created afterwards with
540 CREATE TABLE PARTITION OF will use that tablespace, unless
541 overridden by a TABLESPACE clause.
543 All tables in the current database in a tablespace can be moved
544 by using the ALL IN TABLESPACE form, which will lock all tables
545 to be moved first and then move each one. This form also
546 supports OWNED BY, which will only move tables owned by the
547 roles specified. If the NOWAIT option is specified then the
548 command will fail if it is unable to acquire all of the locks
549 required immediately. Note that system catalogs are not moved by
550 this command; use ALTER DATABASE or explicit ALTER TABLE
551 invocations instead if desired. The information_schema relations
552 are not considered part of the system catalogs and will be
553 moved. See also CREATE TABLESPACE.
555 SET { LOGGED | UNLOGGED } #
556 This form changes the table from unlogged to logged or
557 vice-versa (see UNLOGGED). It cannot be applied to a temporary
560 This also changes the persistence of any sequences linked to the
561 table (for identity or serial columns). However, it is also
562 possible to change the persistence of such sequences separately.
564 This form is not supported for partitioned tables.
566 SET ( storage_parameter [= value] [, ... ] ) #
567 This form changes one or more storage parameters for the table.
568 See Storage Parameters in the CREATE TABLE documentation for
569 details on the available parameters. Note that the table
570 contents will not be modified immediately by this command;
571 depending on the parameter you might need to rewrite the table
572 to get the desired effects. That can be done with VACUUM FULL,
573 CLUSTER or one of the forms of ALTER TABLE that forces a table
574 rewrite. For planner related parameters, changes will take
575 effect from the next time the table is locked so currently
576 executing queries will not be affected.
578 SHARE UPDATE EXCLUSIVE lock will be taken for fillfactor, toast
579 and autovacuum storage parameters, as well as the planner
580 parameter parallel_workers.
582 RESET ( storage_parameter [, ... ] ) #
583 This form resets one or more storage parameters to their
584 defaults. As with SET, a table rewrite might be needed to update
587 INHERIT parent_table #
588 This form adds the target table as a new child of the specified
589 parent table. Subsequently, queries against the parent will
590 include records of the target table. To be added as a child, the
591 target table must already contain all the same columns as the
592 parent (it could have additional columns, too). The columns must
593 have matching data types.
595 In addition, all CHECK and NOT NULL constraints on the parent
596 must also exist on the child, except those marked
597 non-inheritable (that is, created with ALTER TABLE ... ADD
598 CONSTRAINT ... NO INHERIT), which are ignored. All child-table
599 constraints matched must not be marked non-inheritable.
600 Currently UNIQUE, PRIMARY KEY, and FOREIGN KEY constraints are
601 not considered, but this might change in the future.
603 NO INHERIT parent_table #
604 This form removes the target table from the list of children of
605 the specified parent table. Queries against the parent table
606 will no longer include records drawn from the target table.
609 This form links the table to a composite type as though CREATE
610 TABLE OF had formed it. The table's list of column names and
611 types must precisely match that of the composite type. The table
612 must not inherit from any other table. These restrictions ensure
613 that CREATE TABLE OF would permit an equivalent table
617 This form dissociates a typed table from its type.
620 This form changes the owner of the table, sequence, view,
621 materialized view, or foreign table to the specified user.
624 This form changes the information which is written to the
625 write-ahead log to identify rows which are updated or deleted.
626 In most cases, the old value of each column is only logged if it
627 differs from the new value; however, if the old value is stored
628 externally, it is always logged regardless of whether it
629 changed. This option has no effect except when logical
630 replication is in use.
633 Records the old values of the columns of the primary key.
634 This is the default for non-system tables. When there is
635 no primary key, the behavior is the same as NOTHING.
637 USING INDEX index_name #
638 Records the old values of the columns covered by the named
639 index, that must be unique, not partial, not deferrable,
640 and include only columns marked NOT NULL. If this index is
641 dropped, the behavior is the same as NOTHING.
644 Records the old values of all columns in the row.
647 Records no information about the old row. This is the
648 default for system tables.
651 The RENAME forms change the name of a table (or an index,
652 sequence, view, materialized view, or foreign table), the name
653 of an individual column in a table, or the name of a constraint
654 of the table. When renaming a constraint that has an underlying
655 index, the index is renamed as well. There is no effect on the
659 This form moves the table into another schema. Associated
660 indexes, constraints, and sequences owned by table columns are
663 ATTACH PARTITION partition_name { FOR VALUES partition_bound_spec |
665 This form attaches an existing table (which might itself be
666 partitioned) as a partition of the target table. The table can
667 be attached as a partition for specific values using FOR VALUES
668 or as a default partition by using DEFAULT. For each index in
669 the target table, a corresponding one will be created in the
670 attached table; or, if an equivalent index already exists, it
671 will be attached to the target table's index, as if ALTER INDEX
672 ATTACH PARTITION had been executed. Note that if the existing
673 table is a foreign table, it is currently not allowed to attach
674 the table as a partition of the target table if there are UNIQUE
675 indexes on the target table. (See also CREATE FOREIGN TABLE.)
676 For each user-defined row-level trigger that exists in the
677 target table, a corresponding one is created in the attached
680 A partition using FOR VALUES uses same syntax for
681 partition_bound_spec as CREATE TABLE. The partition bound
682 specification must correspond to the partitioning strategy and
683 partition key of the target table. The table to be attached must
684 have all the same columns as the target table and no more;
685 moreover, the column types must also match. Also, it must have
686 all the NOT NULL and CHECK constraints of the target table, not
687 marked NO INHERIT. Currently FOREIGN KEY constraints are not
688 considered. UNIQUE and PRIMARY KEY constraints from the parent
689 table will be created in the partition, if they don't already
692 If the new partition is a regular table, a full table scan is
693 performed to check that existing rows in the table do not
694 violate the partition constraint. It is possible to avoid this
695 scan by adding a valid CHECK constraint to the table that allows
696 only rows satisfying the desired partition constraint before
697 running this command. The CHECK constraint will be used to
698 determine that the table need not be scanned to validate the
699 partition constraint. This does not work, however, if any of the
700 partition keys is an expression and the partition does not
701 accept NULL values. If attaching a list partition that will not
702 accept NULL values, also add a NOT NULL constraint to the
703 partition key column, unless it's an expression.
705 If the new partition is a foreign table, nothing is done to
706 verify that all the rows in the foreign table obey the partition
707 constraint. (See the discussion in CREATE FOREIGN TABLE about
708 constraints on the foreign table.)
710 When a table has a default partition, defining a new partition
711 changes the partition constraint for the default partition. The
712 default partition can't contain any rows that would need to be
713 moved to the new partition, and will be scanned to verify that
714 none are present. This scan, like the scan of the new partition,
715 can be avoided if an appropriate CHECK constraint is present.
716 Also like the scan of the new partition, it is always skipped
717 when the default partition is a foreign table.
719 Attaching a partition acquires a SHARE UPDATE EXCLUSIVE lock on
720 the parent table, in addition to the ACCESS EXCLUSIVE locks on
721 the table being attached and on the default partition (if any).
723 Further locks must also be held on all sub-partitions if the
724 table being attached is itself a partitioned table. Likewise if
725 the default partition is itself a partitioned table. The locking
726 of the sub-partitions can be avoided by adding a CHECK
727 constraint as described in Section 5.12.2.2.
729 DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ] #
730 This form detaches the specified partition of the target table.
731 The detached partition continues to exist as a standalone table,
732 but no longer has any ties to the table from which it was
733 detached. Any indexes that were attached to the target table's
734 indexes are detached. Any triggers that were created as clones
735 of those in the target table are removed. SHARE lock is obtained
736 on any tables that reference this partitioned table in foreign
739 If CONCURRENTLY is specified, it runs using a reduced lock level
740 to avoid blocking other sessions that might be accessing the
741 partitioned table. In this mode, two transactions are used
742 internally. During the first transaction, a SHARE UPDATE
743 EXCLUSIVE lock is taken on both parent table and partition, and
744 the partition is marked as undergoing detach; at that point, the
745 transaction is committed and all other transactions using the
746 partitioned table are waited for. Once all those transactions
747 have completed, the second transaction acquires SHARE UPDATE
748 EXCLUSIVE on the partitioned table and ACCESS EXCLUSIVE on the
749 partition, and the detach process completes. A CHECK constraint
750 that duplicates the partition constraint is added to the
751 partition. CONCURRENTLY cannot be run in a transaction block and
752 is not allowed if the partitioned table contains a default
755 If FINALIZE is specified, a previous DETACH CONCURRENTLY
756 invocation that was canceled or interrupted is completed. At
757 most one partition in a partitioned table can be pending detach
760 All the forms of ALTER TABLE that act on a single table, except RENAME,
761 SET SCHEMA, ATTACH PARTITION, and DETACH PARTITION can be combined into
762 a list of multiple alterations to be applied together. For example, it
763 is possible to add several columns and/or alter the type of several
764 columns in a single command. This is particularly useful with large
765 tables, since only one pass over the table need be made.
767 You must own the table to use ALTER TABLE. To change the schema or
768 tablespace of a table, you must also have CREATE privilege on the new
769 schema or tablespace. To add the table as a new child of a parent
770 table, you must own the parent table as well. Also, to attach a table
771 as a new partition of the table, you must own the table being attached.
772 To alter the owner, you must be able to SET ROLE to the new owning
773 role, and that role must have CREATE privilege on the table's schema.
774 (These restrictions enforce that altering the owner doesn't do anything
775 you couldn't do by dropping and recreating the table. However, a
776 superuser can alter ownership of any table anyway.) To add a column or
777 alter a column type or use the OF clause, you must also have USAGE
778 privilege on the data type.
783 Do not throw an error if the table does not exist. A notice is
787 The name (optionally schema-qualified) of an existing table to
788 alter. If ONLY is specified before the table name, only that
789 table is altered. If ONLY is not specified, the table and all
790 its descendant tables (if any) are altered. Optionally, * can be
791 specified after the table name to explicitly indicate that
792 descendant tables are included.
795 Name of a new or existing column.
798 New name for an existing column.
801 New name for the table.
804 Data type of the new column, or new data type for an existing
808 New table constraint for the table.
811 Name of a new or existing constraint.
814 Automatically drop objects that depend on the dropped column or
815 constraint (for example, views referencing the column), and in
816 turn all objects that depend on those objects (see
820 Refuse to drop the column or constraint if there are any
821 dependent objects. This is the default behavior.
824 Name of a single trigger to disable or enable.
827 Disable or enable all triggers belonging to the table. (This
828 requires superuser privilege if any of the triggers are
829 internally generated constraint triggers, such as those that are
830 used to implement foreign key constraints or deferrable
831 uniqueness and exclusion constraints.)
834 Disable or enable all triggers belonging to the table except for
835 internally generated constraint triggers, such as those that are
836 used to implement foreign key constraints or deferrable
837 uniqueness and exclusion constraints.
840 The name of an existing index.
843 The name of a table storage parameter.
846 The new value for a table storage parameter. This might be a
847 number or a word depending on the parameter.
850 A parent table to associate or de-associate with this table.
853 The user name of the new owner of the table.
856 The name of the access method to which the table will be
860 The name of the tablespace to which the table will be moved.
863 The name of the schema to which the table will be moved.
866 The name of the table to attach as a new partition or to detach
869 partition_bound_spec #
870 The partition bound specification for a new partition. Refer to
871 CREATE TABLE for more details on the syntax of the same.
875 The key word COLUMN is noise and can be omitted.
877 When a column is added with ADD COLUMN and a non-volatile DEFAULT is
878 specified, the default value is evaluated at the time of the statement
879 and the result stored in the table's metadata, where it will be
880 returned when any existing rows are accessed. The value will be only
881 applied when the table is rewritten, making the ALTER TABLE very fast
882 even on large tables. If no column constraints are specified, NULL is
883 used as the DEFAULT. In neither case is a rewrite of the table
886 Adding a column with a volatile DEFAULT (e.g., clock_timestamp()), a
887 stored generated column, an identity column, or a column with a domain
888 data type that has constraints will cause the entire table and its
889 indexes to be rewritten. Adding a virtual generated column never
892 Changing the type of an existing column will normally cause the entire
893 table and its indexes to be rewritten. As an exception, when changing
894 the type of an existing column, if the USING clause does not change the
895 column contents and the old type is either binary coercible to the new
896 type or an unconstrained domain over the new type, a table rewrite is
897 not needed. However, indexes will still be rebuilt unless the system
898 can verify that the new index would be logically equivalent to the
899 existing one. For example, if the collation for a column has been
900 changed, an index rebuild is required because the new sort order might
901 be different. However, in the absence of a collation change, a column
902 can be changed from text to varchar (or vice versa) without rebuilding
903 the indexes because these data types sort identically.
905 Table and/or index rebuilds may take a significant amount of time for a
906 large table, and will temporarily require as much as double the disk
909 Adding a CHECK or NOT NULL constraint requires scanning the table to
910 verify that existing rows meet the constraint, but does not require a
911 table rewrite. If a CHECK constraint is added as NOT ENFORCED, no
912 verification will be performed.
914 Similarly, when attaching a new partition it may be scanned to verify
915 that existing rows meet the partition constraint.
917 The main reason for providing the option to specify multiple changes in
918 a single ALTER TABLE is that multiple table scans or rewrites can
919 thereby be combined into a single pass over the table.
921 Scanning a large table to verify new foreign-key, check, or not-null
922 constraints can take a long time, and other updates to the table are
923 locked out until the ALTER TABLE ADD CONSTRAINT command is committed.
924 The main purpose of the NOT VALID constraint option is to reduce the
925 impact of adding a constraint on concurrent updates. With NOT VALID,
926 the ADD CONSTRAINT command does not scan the table and can be committed
927 immediately. After that, a VALIDATE CONSTRAINT command can be issued to
928 verify that existing rows satisfy the constraint. The validation step
929 does not need to lock out concurrent updates, since it knows that other
930 transactions will be enforcing the constraint for rows that they insert
931 or update; only pre-existing rows need to be checked. Hence, validation
932 acquires only a SHARE UPDATE EXCLUSIVE lock on the table being altered.
933 (If the constraint is a foreign key then a ROW SHARE lock is also
934 required on the table referenced by the constraint.) In addition to
935 improving concurrency, it can be useful to use NOT VALID and VALIDATE
936 CONSTRAINT in cases where the table is known to contain pre-existing
937 violations. Once the constraint is in place, no new violations can be
938 inserted, and the existing problems can be corrected at leisure until
939 VALIDATE CONSTRAINT finally succeeds.
941 The DROP COLUMN form does not physically remove the column, but simply
942 makes it invisible to SQL operations. Subsequent insert and update
943 operations in the table will store a null value for the column. Thus,
944 dropping a column is quick but it will not immediately reduce the
945 on-disk size of your table, as the space occupied by the dropped column
946 is not reclaimed. The space will be reclaimed over time as existing
949 To force immediate reclamation of space occupied by a dropped column,
950 you can execute one of the forms of ALTER TABLE that performs a rewrite
951 of the whole table. This results in reconstructing each row with the
952 dropped column replaced by a null value.
954 The rewriting forms of ALTER TABLE are not MVCC-safe. After a table
955 rewrite, the table will appear empty to concurrent transactions, if
956 they are using a snapshot taken before the rewrite occurred. See
957 Section 13.6 for more details.
959 The USING option of SET DATA TYPE can actually specify any expression
960 involving the old values of the row; that is, it can refer to other
961 columns as well as the one being converted. This allows very general
962 conversions to be done with the SET DATA TYPE syntax. Because of this
963 flexibility, the USING expression is not applied to the column's
964 default value (if any); the result might not be a constant expression
965 as required for a default. This means that when there is no implicit or
966 assignment cast from old to new type, SET DATA TYPE might fail to
967 convert the default even though a USING clause is supplied. In such
968 cases, drop the default with DROP DEFAULT, perform the ALTER TYPE, and
969 then use SET DEFAULT to add a suitable new default. Similar
970 considerations apply to indexes and constraints involving the column.
972 If a table has any descendant tables, it is not permitted to add,
973 rename, or change the type of a column in the parent table without
974 doing the same to the descendants. This ensures that the descendants
975 always have columns matching the parent. Similarly, a CHECK constraint
976 cannot be renamed in the parent without also renaming it in all
977 descendants, so that CHECK constraints also match between the parent
978 and its descendants. (That restriction does not apply to index-based
979 constraints, however.) Also, because selecting from the parent also
980 selects from its descendants, a constraint on the parent cannot be
981 marked valid unless it is also marked valid for those descendants. In
982 all of these cases, ALTER TABLE ONLY will be rejected.
984 A recursive DROP COLUMN operation will remove a descendant table's
985 column only if the descendant does not inherit that column from any
986 other parents and never had an independent definition of the column. A
987 nonrecursive DROP COLUMN (i.e., ALTER TABLE ONLY ... DROP COLUMN) never
988 removes any descendant columns, but instead marks them as independently
989 defined rather than inherited. A nonrecursive DROP COLUMN command will
990 fail for a partitioned table, because all partitions of a table must
991 have the same columns as the partitioning root.
993 The actions for identity columns (ADD GENERATED, SET etc., DROP
994 IDENTITY), as well as the actions CLUSTER, OWNER, and TABLESPACE never
995 recurse to descendant tables; that is, they always act as though ONLY
996 were specified. Actions affecting trigger states recurse to partitions
997 of partitioned tables (unless ONLY is specified), but never to
998 traditional-inheritance descendants. Adding a constraint recurses only
999 for CHECK constraints that are not marked NO INHERIT.
1001 Changing any part of a system catalog table is not permitted.
1003 Refer to CREATE TABLE for a further description of valid parameters.
1004 Chapter 5 has further information on inheritance.
1008 To add a column of type varchar to a table:
1009 ALTER TABLE distributors ADD COLUMN address varchar(30);
1011 That will cause all existing rows in the table to be filled with null
1012 values for the new column.
1014 To add a column with a non-null default:
1015 ALTER TABLE measurements
1016 ADD COLUMN mtime timestamp with time zone DEFAULT now();
1018 Existing rows will be filled with the current time as the value of the
1019 new column, and then new rows will receive the time of their insertion.
1021 To add a column and fill it with a value different from the default to
1023 ALTER TABLE transactions
1024 ADD COLUMN status varchar(30) DEFAULT 'old',
1025 ALTER COLUMN status SET default 'current';
1027 Existing rows will be filled with old, but then the default for
1028 subsequent commands will be current. The effects are the same as if the
1029 two sub-commands had been issued in separate ALTER TABLE commands.
1031 To drop a column from a table:
1032 ALTER TABLE distributors DROP COLUMN address RESTRICT;
1034 To change the types of two existing columns in one operation:
1035 ALTER TABLE distributors
1036 ALTER COLUMN address TYPE varchar(80),
1037 ALTER COLUMN name TYPE varchar(100);
1039 To change an integer column containing Unix timestamps to timestamp
1040 with time zone via a USING clause:
1042 ALTER COLUMN foo_timestamp SET DATA TYPE timestamp with time zone
1044 timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
1046 The same, when the column has a default expression that won't
1047 automatically cast to the new data type:
1049 ALTER COLUMN foo_timestamp DROP DEFAULT,
1050 ALTER COLUMN foo_timestamp TYPE timestamp with time zone
1052 timestamp with time zone 'epoch' + foo_timestamp * interval '1 second',
1053 ALTER COLUMN foo_timestamp SET DEFAULT now();
1055 To rename an existing column:
1056 ALTER TABLE distributors RENAME COLUMN address TO city;
1058 To rename an existing table:
1059 ALTER TABLE distributors RENAME TO suppliers;
1061 To rename an existing constraint:
1062 ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
1064 To add a not-null constraint to a column:
1065 ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
1067 To remove a not-null constraint from a column:
1068 ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
1070 To add a check constraint to a table and all its children:
1071 ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
1073 To add a check constraint only to a table and not to its children:
1074 ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5)
1077 (The check constraint will not be inherited by future children,
1080 To remove a check constraint from a table and all its children:
1081 ALTER TABLE distributors DROP CONSTRAINT zipchk;
1083 To remove a check constraint from one table only:
1084 ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk;
1086 (The check constraint remains in place for any child tables.)
1088 To add a foreign key constraint to a table:
1089 ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES
1090 addresses (address);
1092 To add a foreign key constraint to a table with the least impact on
1094 ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES
1095 addresses (address) NOT VALID;
1096 ALTER TABLE distributors VALIDATE CONSTRAINT distfk;
1098 To add a (multicolumn) unique constraint to a table:
1099 ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zip
1102 To add an automatically named primary key constraint to a table, noting
1103 that a table can only ever have one primary key:
1104 ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
1106 To move a table to a different tablespace:
1107 ALTER TABLE distributors SET TABLESPACE fasttablespace;
1109 To move a table to a different schema:
1110 ALTER TABLE myschema.distributors SET SCHEMA yourschema;
1112 To recreate a primary key constraint, without blocking updates while
1113 the index is rebuilt:
1114 CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id);
1115 ALTER TABLE distributors DROP CONSTRAINT distributors_pkey,
1116 ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx;
1118 To attach a partition to a range-partitioned table:
1119 ALTER TABLE measurement
1120 ATTACH PARTITION measurement_y2016m07 FOR VALUES FROM ('2016-07-01') TO ('20
1123 To attach a partition to a list-partitioned table:
1125 ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
1127 To attach a partition to a hash-partitioned table:
1129 ATTACH PARTITION orders_p4 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
1131 To attach a default partition to a partitioned table:
1133 ATTACH PARTITION cities_partdef DEFAULT;
1135 To detach a partition from a partitioned table:
1136 ALTER TABLE measurement
1137 DETACH PARTITION measurement_y2015m12;
1141 The forms ADD [COLUMN], DROP [COLUMN], DROP IDENTITY, RESTART, SET
1142 DEFAULT, SET DATA TYPE (without USING), SET GENERATED, and SET
1143 sequence_option conform with the SQL standard. The form ADD
1144 table_constraint conforms with the SQL standard when the USING INDEX
1145 and NOT VALID clauses are omitted and the constraint type is one of
1146 CHECK, UNIQUE, PRIMARY KEY, or REFERENCES. The other forms are
1147 PostgreSQL extensions of the SQL standard. Also, the ability to specify
1148 more than one manipulation in a single ALTER TABLE command is an
1151 ALTER TABLE DROP COLUMN can be used to drop the only column of a table,
1152 leaving a zero-column table. This is an extension of SQL, which
1153 disallows zero-column tables.