aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/alter_table.sgml
blob: e4ef90ed9ddda0585917db1c0c7b8e3fdb75517a (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
<!--
doc/src/sgml/ref/alter_table.sgml
PostgreSQL documentation
-->

<refentry id="SQL-ALTERTABLE">
 <refmeta>
  <refentrytitle>ALTER TABLE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>ALTER TABLE</refname>
  <refpurpose>change the definition of a table</refpurpose>
 </refnamediv>

 <indexterm zone="sql-altertable">
  <primary>ALTER TABLE</primary>
 </indexterm>

 <refsynopsisdiv>
<synopsis>
ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
    <replaceable class="PARAMETER">action</replaceable> [, ... ]
ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
    RENAME [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> TO <replaceable class="PARAMETER">new_column_name</replaceable>
ALTER TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
    RENAME CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> TO <replaceable class="PARAMETER">new_constraint_name</replaceable>
ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
    RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
    SET SCHEMA <replaceable class="PARAMETER">new_schema</replaceable>

<phrase>where <replaceable class="PARAMETER">action</replaceable> is one of:</phrase>

    ADD [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ COLLATE <replaceable class="PARAMETER">collation</replaceable> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
    DROP [ COLUMN ] [ IF EXISTS ] <replaceable class="PARAMETER">column_name</replaceable> [ RESTRICT | CASCADE ]
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> [ SET DATA ] TYPE <replaceable class="PARAMETER">data_type</replaceable> [ COLLATE <replaceable class="PARAMETER">collation</replaceable> ] [ USING <replaceable class="PARAMETER">expression</replaceable> ]
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET DEFAULT <replaceable class="PARAMETER">expression</replaceable>
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> DROP DEFAULT
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> { SET | DROP } NOT NULL
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET ( <replaceable class="PARAMETER">attribute_option</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> RESET ( <replaceable class="PARAMETER">attribute_option</replaceable> [, ... ] )
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
    ADD <replaceable class="PARAMETER">table_constraint</replaceable> [ NOT VALID ]
    ADD <replaceable class="PARAMETER">table_constraint_using_index</replaceable>
    VALIDATE CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable>
    DROP CONSTRAINT [ IF EXISTS ]  <replaceable class="PARAMETER">constraint_name</replaceable> [ RESTRICT | CASCADE ]
    DISABLE TRIGGER [ <replaceable class="PARAMETER">trigger_name</replaceable> | ALL | USER ]
    ENABLE TRIGGER [ <replaceable class="PARAMETER">trigger_name</replaceable> | ALL | USER ]
    ENABLE REPLICA TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable>
    ENABLE ALWAYS TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable>
    DISABLE RULE <replaceable class="PARAMETER">rewrite_rule_name</replaceable>
    ENABLE RULE <replaceable class="PARAMETER">rewrite_rule_name</replaceable>
    ENABLE REPLICA RULE <replaceable class="PARAMETER">rewrite_rule_name</replaceable>
    ENABLE ALWAYS RULE <replaceable class="PARAMETER">rewrite_rule_name</replaceable>
    CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
    SET WITHOUT CLUSTER
    SET WITH OIDS
    SET WITHOUT OIDS
    SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
    RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )
    INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
    NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
    OF <replaceable class="PARAMETER">type_name</replaceable>
    NOT OF
    OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
    SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable>

<phrase>and <replaceable class="PARAMETER">table_constraint_using_index</replaceable> is:</phrase>

    [ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
    { UNIQUE | PRIMARY KEY } USING INDEX <replaceable class="PARAMETER">index_name</replaceable>
    [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>ALTER TABLE</command> changes the definition of an existing table.
   There are several subforms:

  <variablelist>
   <varlistentry>
    <term><literal>ADD COLUMN</literal></term>
    <listitem>
     <para>
      This form adds a new column to the table, using the same syntax as
      <xref linkend="SQL-CREATETABLE">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DROP COLUMN [ IF EXISTS ]</literal></term>
    <listitem>
     <para>
      This form drops a column from a table.  Indexes and
      table constraints involving the column will be automatically
      dropped as well.  You will need to say <literal>CASCADE</> if
      anything outside the table depends on the column, for example,
      foreign key references or views.
      If <literal>IF EXISTS</literal> is specified and the column
      does not exist, no error is thrown. In this case a notice
      is issued instead.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>IF EXISTS</literal></term>
    <listitem>
     <para>
      Do not throw an error if the table does not exist. A notice is issued
      in this case.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET DATA TYPE</literal></term>
    <listitem>
     <para>
      This form changes the type of a column of a table. Indexes and
      simple table constraints involving the column will be automatically
      converted to use the new column type by reparsing the originally
      supplied expression.
      The optional <literal>COLLATE</literal> clause specifies a collation
      for the new column; if omitted, the collation is the default for the
      new column type.
      The optional <literal>USING</literal>
      clause specifies how to compute the new column value from the old;
      if omitted, the default conversion is the same as an assignment
      cast from old data type to new.  A  <literal>USING</literal>
      clause must be provided if there is no implicit or assignment
      cast from old to new type.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET</literal>/<literal>DROP DEFAULT</literal></term>
    <listitem>
     <para>
      These forms set or remove the default value for a column.
      The default values only apply to subsequent <command>INSERT</command>
      commands; they do not cause rows already in the table to change.
      Defaults can also be created for views, in which case they are
      inserted into <command>INSERT</> statements on the view before
      the view's <literal>ON INSERT</literal> rule is applied.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET</literal>/<literal>DROP NOT NULL</literal></term>
    <listitem>
     <para>
      These forms change whether a column is marked to allow null
      values or to reject null values.  You can only use <literal>SET
      NOT NULL</> when the column contains no null values.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET STATISTICS</literal></term>
    <listitem>
     <para>
      This form
      sets the per-column statistics-gathering target for subsequent
      <xref linkend="sql-analyze"> operations.
      The target can be set in the range 0 to 10000; alternatively, set it
      to -1 to revert to using the system default statistics
      target (<xref linkend="guc-default-statistics-target">).
      For more information on the use of statistics by the
      <productname>PostgreSQL</productname> query planner, refer to
      <xref linkend="planner-stats">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET ( <replaceable class="PARAMETER">attribute_option</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )</literal></term>
    <term><literal>RESET ( <replaceable class="PARAMETER">attribute_option</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      This form sets or resets per-attribute options.  Currently, the only
      defined per-attribute options are <literal>n_distinct</> and
      <literal>n_distinct_inherited</>, which override the
      number-of-distinct-values estimates made by subsequent
      <xref linkend="sql-analyze">
      operations.  <literal>n_distinct</> affects the statistics for the table
      itself, while <literal>n_distinct_inherited</> affects the statistics
      gathered for the table plus its inheritance children.  When set to a
      positive value, <command>ANALYZE</> will assume that the column contains
      exactly the specified number of distinct nonnull values.  When set to a
      negative value, which must be greater
      than or equal to -1, <command>ANALYZE</> will assume that the number of
      distinct nonnull values in the column is linear in the size of the
      table; the exact count is to be computed by multiplying the estimated
      table size by the absolute value of the given number.  For example,
      a value of -1 implies that all values in the column are distinct, while
      a value of -0.5 implies that each value appears twice on the average.
      This can be useful when the size of the table changes over time, since
      the multiplication by the number of rows in the table is not performed
      until query planning time.  Specify a value of 0 to revert to estimating
      the number of distinct values normally.  For more information on the use
      of statistics by the <productname>PostgreSQL</productname> query
      planner, refer to <xref linkend="planner-stats">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <indexterm>
     <primary>TOAST</primary>
     <secondary>per-column storage settings</secondary>
    </indexterm>

    <term><literal>SET STORAGE</literal></term>
    <listitem>
     <para>
      This form sets the storage mode for a column. This controls whether this
      column is held inline or in a secondary <acronym>TOAST</> table, and
      whether the data
      should be compressed or not. <literal>PLAIN</literal> must be used
      for fixed-length values such as <type>integer</type> and is
      inline, uncompressed. <literal>MAIN</literal> is for inline,
      compressible data. <literal>EXTERNAL</literal> is for external,
      uncompressed data, and <literal>EXTENDED</literal> is for external,
      compressed data.  <literal>EXTENDED</literal> is the default for most
      data types that support non-<literal>PLAIN</literal> storage.
      Use of <literal>EXTERNAL</literal> will make substring operations on
      very large <type>text</type> and <type>bytea</type> values run faster,
      at the penalty of increased storage space.  Note that
      <literal>SET STORAGE</> doesn't itself change anything in the table,
      it just sets the strategy to be pursued during future table updates.
      See <xref linkend="storage-toast"> for more information.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>ADD <replaceable class="PARAMETER">table_constraint</replaceable> [ NOT VALID ]</literal></term>
    <listitem>
     <para>
      This form adds a new constraint to a table using the same syntax as
      <xref linkend="SQL-CREATETABLE">, plus the option <literal>NOT
      VALID</literal>, which is currently only allowed for foreign key
      and CHECK constraints.
      If the constraint is marked <literal>NOT VALID</literal>, the
      potentially-lengthy initial check to verify that all rows in the table
      satisfy the constraint is skipped.  The constraint will still be
      enforced against subsequent inserts or updates (that is, they'll fail
      unless there is a matching row in the referenced table, in the case
      of foreign keys; and they'll fail unless the new row matches the
      specified check constraints).  But the
      database will not assume that the constraint holds for all rows in
      the table, until it is validated by using the <literal>VALIDATE
      CONSTRAINT</literal> option.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>ADD <replaceable class="PARAMETER">table_constraint_using_index</replaceable></literal></term>
    <listitem>
     <para>
      This form adds a new <literal>PRIMARY KEY</> or <literal>UNIQUE</>
      constraint to a table based on an existing unique index.  All the
      columns of the index will be included in the constraint.
     </para>

     <para>
      The index cannot have expression columns nor be a partial index.
      Also, it must be a b-tree index with default sort ordering.  These
      restrictions ensure that the index is equivalent to one that would be
      built by a regular <literal>ADD PRIMARY KEY</> or <literal>ADD UNIQUE</>
      command.
     </para>

     <para>
      If <literal>PRIMARY KEY</> is specified, and the index's columns are not
      already marked <literal>NOT NULL</>, then this command will attempt to
      do <literal>ALTER COLUMN SET NOT NULL</> against each such column.
      That requires a full table scan to verify the column(s) contain no
      nulls.  In all other cases, this is a fast operation.
     </para>

     <para>
      If a constraint name is provided then the index will be renamed to match
      the constraint name.  Otherwise the constraint will be named the same as
      the index.
     </para>

     <para>
      After this command is executed, the index is <quote>owned</> by the
      constraint, in the same way as if the index had been built by
      a regular <literal>ADD PRIMARY KEY</> or <literal>ADD UNIQUE</>
      command.  In particular, dropping the constraint will make the index
      disappear too.
     </para>

     <note>
      <para>
       Adding a constraint using an existing index can be helpful in
       situations where a new constraint needs to be added without blocking
       table updates for a long time.  To do that, create the index using
       <command>CREATE INDEX CONCURRENTLY</>, and then install it as an
       official constraint using this syntax.  See the example below.
      </para>
     </note>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>VALIDATE CONSTRAINT</literal></term>
    <listitem>
     <para>
      This form validates a foreign key or check constraint that was previously created
      as <literal>NOT VALID</literal>, by scanning the table to ensure there
      are no rows for which the constraint is not satisfied.
      Nothing happens if the constraint is already marked valid.
     </para>
     <para>
      Validation can be a long process on larger tables and currently requires
      an <literal>ACCESS EXCLUSIVE</literal> lock.  The value of separating
      validation from initial creation is that you can defer validation to less
      busy times, or can be used to give additional time to correct pre-existing
      errors while preventing new errors.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DROP CONSTRAINT [ IF EXISTS ]</literal></term>
    <listitem>
     <para>
      This form drops the specified constraint on a table.
      If <literal>IF EXISTS</literal> is specified and the constraint
      does not exist, no error is thrown. In this case a notice is issued instead.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] TRIGGER</literal></term>
    <listitem>
     <para>
      These forms configure the firing of trigger(s) belonging to the table.
      A disabled trigger is still known to the system, but is not executed
      when its triggering event occurs.  For a deferred trigger, the enable
      status is checked when the event occurs, not when the trigger function
      is actually executed.  One can disable or enable a single
      trigger specified by name, or all triggers on the table, or only
      user triggers (this option excludes internally generated constraint
      triggers such as those that are used to implement foreign key
      constraints or deferrable uniqueness and exclusion constraints).
      Disabling or enabling internally generated constraint triggers
      requires superuser privileges; it should be done with caution since
      of course the integrity of the constraint cannot be guaranteed if the
      triggers are not executed.
      The trigger firing mechanism is also affected by the configuration
      variable <xref linkend="guc-session-replication-role">. Simply enabled
      triggers will fire when the replication role is <quote>origin</>
      (the default) or <quote>local</>. Triggers configured as <literal>ENABLE
      REPLICA</literal> will only fire if the session is in <quote>replica</>
      mode, and triggers configured as <literal>ENABLE ALWAYS</literal> will
      fire regardless of the current replication mode.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] RULE</literal></term>
    <listitem>
     <para>
      These forms configure the firing of rewrite rules belonging to the table.
      A disabled rule is still known to the system, but is not applied
      during query rewriting. The semantics are as for disabled/enabled
      triggers. This configuration is ignored for <literal>ON SELECT</literal> rules, which
      are always applied in order to keep views working even if the current
      session is in a non-default replication role.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>CLUSTER ON</literal></term>
    <listitem>
     <para>
      This form selects the default index for future
      <xref linkend="SQL-CLUSTER">
      operations.  It does not actually re-cluster the table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET WITHOUT CLUSTER</literal></term>
    <listitem>
     <para>
      This form removes the most recently used
      <xref linkend="SQL-CLUSTER">
      index specification from the table.  This affects
      future cluster operations that don't specify an index.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET WITH OIDS</literal></term>
    <listitem>
     <para>
      This form adds an <literal>oid</literal> system column to the
      table (see <xref linkend="ddl-system-columns">).
      It does nothing if the table already has OIDs.
     </para>

     <para>
      Note that this is not equivalent to <literal>ADD COLUMN oid oid</>;
      that would add a normal column that happened to be named
      <literal>oid</>, not a system column.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET WITHOUT OIDS</literal></term>
    <listitem>
     <para>
      This form removes the <literal>oid</literal> system column from the
      table.  This is exactly equivalent to
      <literal>DROP COLUMN oid RESTRICT</literal>,
      except that it will not complain if there is already no
      <literal>oid</literal> column.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      This form changes one or more storage parameters for the table.  See
      <xref linkend="SQL-CREATETABLE-storage-parameters"
      endterm="SQL-CREATETABLE-storage-parameters-title">
      for details on the available parameters.  Note that the table contents
      will not be modified immediately by this command; depending on the
      parameter you might need to rewrite the table to get the desired effects.
      That can be done with <link linkend="SQL-VACUUM">VACUUM
      FULL</>, <xref linkend="SQL-CLUSTER"> or one of the forms
      of <command>ALTER TABLE</> that forces a table rewrite.
     </para>

     <note>
      <para>
       While <command>CREATE TABLE</> allows <literal>OIDS</> to be specified
       in the <literal>WITH (<replaceable
       class="PARAMETER">storage_parameter</>)</literal> syntax,
       <command>ALTER TABLE</> does not treat <literal>OIDS</> as a
       storage parameter.  Instead use the <literal>SET WITH OIDS</>
       and <literal>SET WITHOUT OIDS</> forms to change OID status.
      </para>
     </note>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      This form resets one or more storage parameters to their
      defaults.  As with <literal>SET</>, a table rewrite might be
      needed to update the table entirely.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
    <listitem>
     <para>
      This form adds the target table as a new child of the specified parent
      table.  Subsequently, queries against the parent will include records
      of the target table.  To be added as a child, the target table must
      already contain all the same columns as the parent (it could have
      additional columns, too).  The columns must have matching data types,
      and if they have <literal>NOT NULL</literal> constraints in the parent
      then they must also have <literal>NOT NULL</literal> constraints in the
      child.
     </para>

     <para>
      There must also be matching child-table constraints for all
      <literal>CHECK</literal> constraints of the parent, except those
      marked non-inheritable (that is, created with <literal>ALTER TABLE ... ADD CONSTRAINT ... NO INHERIT</literal>)
      in the parent, which are ignored; all child-table constraints matched
      must not be marked non-inheritable.
      Currently
      <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and
      <literal>FOREIGN KEY</literal> constraints are not considered, but
      this might change in the future.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
    <listitem>
     <para>
      This form removes the target table from the list of children of the
      specified parent table.
      Queries against the parent table will no longer include records drawn
      from the target table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>OF <replaceable class="PARAMETER">type_name</replaceable></literal></term>
    <listitem>
     <para>
      This form links the table to a composite type as though <command>CREATE
      TABLE OF</> had formed it.  The table's list of column names and types
      must precisely match that of the composite type; the presence of
      an <literal>oid</> system column is permitted to differ.  The table must
      not inherit from any other table.  These restrictions ensure
      that <command>CREATE TABLE OF</> would permit an equivalent table
      definition.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>NOT OF</literal></term>
    <listitem>
     <para>
      This form dissociates a typed table from its type.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>OWNER</literal></term>
    <listitem>
     <para>
      This form changes the owner of the table, sequence, or view to the
      specified user.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET TABLESPACE</literal></term>
    <listitem>
     <para>
      This form changes the table's tablespace to the specified tablespace and
      moves the data file(s) associated with the table to the new tablespace.
      Indexes on the table, if any, are not moved; but they can be moved
      separately with additional <literal>SET TABLESPACE</literal> commands.
      See also
      <xref linkend="SQL-CREATETABLESPACE">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>RENAME</literal></term>
    <listitem>
     <para>
      The <literal>RENAME</literal> forms change the name of a table
      (or an index, sequence, or view), the name of an individual column in
      a table, or the name of a constraint of the table. There is no effect on the stored data.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET SCHEMA</literal></term>
    <listitem>
     <para>
      This form moves the table into another schema.  Associated indexes,
      constraints, and sequences owned by table columns are moved as well.
     </para>
    </listitem>
   </varlistentry>

  </variablelist>
  </para>

  <para>
   All the actions except <literal>RENAME</literal> and <literal>SET SCHEMA</>
   can be combined into
   a list of multiple alterations to apply in parallel.  For example, it
   is possible to add several columns and/or alter the type of several
   columns in a single command.  This is particularly useful with large
   tables, since only one pass over the table need be made.
  </para>

  <para>
   You must own the table to use <command>ALTER TABLE</>.
   To change the schema of a table, you must also have
   <literal>CREATE</literal> privilege on the new schema.
   To add the table as a new child of a parent table, you must own the
   parent table as well.
   To alter the owner, you must also be a direct or indirect member of the new
   owning role, and that role must have <literal>CREATE</literal> privilege on
   the table's schema.  (These restrictions enforce that altering the owner
   doesn't do anything you couldn't do by dropping and recreating the table.
   However, a superuser can alter ownership of any table anyway.)
   To add a column or alter a column type or use the <literal>OF</literal>
   clause, you must also have <literal>USAGE</literal> privilege on the data
   type.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

    <variablelist>

     <varlistentry>
      <term><replaceable class="PARAMETER">name</replaceable></term>
      <listitem>
       <para>
        The name (optionally schema-qualified) of an existing table to
        alter. If <literal>ONLY</> is specified before the table name, only
        that table is altered. If <literal>ONLY</> is not specified, the table
        and all its descendant tables (if any) are altered.  Optionally,
        <literal>*</> can be specified after the table name to explicitly
        indicate that descendant tables are included.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">column_name</replaceable></term>
      <listitem>
       <para>
        Name of a new or existing column.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_column_name</replaceable></term>
      <listitem>
       <para>
        New name for an existing column.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_name</replaceable></term>
      <listitem>
       <para>
        New name for the table.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">type</replaceable></term>
      <listitem>
       <para>
        Data type of the new column, or new data type for an existing
        column.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">table_constraint</replaceable></term>
      <listitem>
       <para>
        New table constraint for the table.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">constraint_name</replaceable></term>
      <listitem>
       <para>
        Name of an existing constraint to drop.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>CASCADE</literal></term>
      <listitem>
       <para>
        Automatically drop objects that depend on the dropped column
        or constraint (for example, views referencing the column).
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>RESTRICT</literal></term>
      <listitem>
       <para>
        Refuse to drop the column or constraint if there are any dependent
        objects. This is the default behavior.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">trigger_name</replaceable></term>
      <listitem>
       <para>
        Name of a single trigger to disable or enable.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>ALL</literal></term>
      <listitem>
       <para>
        Disable or enable all triggers belonging to the table.
        (This requires superuser privilege if any of the triggers are
        internally generated constraint triggers such as those that are used
        to implement foreign key constraints or deferrable uniqueness and
        exclusion constraints.)
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>USER</literal></term>
      <listitem>
       <para>
        Disable or enable all triggers belonging to the table except for
        internally generated constraint triggers such as those that are used
        to implement foreign key constraints or deferrable uniqueness and
        exclusion constraints.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">index_name</replaceable></term>
      <listitem>
       <para>
        The index name on which the table should be marked for clustering.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">storage_parameter</replaceable></term>
      <listitem>
       <para>
        The name of a table storage parameter.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">value</replaceable></term>
      <listitem>
       <para>
        The new value for a table storage parameter.
        This might be a number or a word depending on the parameter.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">parent_table</replaceable></term>
      <listitem>
       <para>
        A parent table to associate or de-associate with this table.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_owner</replaceable></term>
      <listitem>
       <para>
        The user name of the new owner of the table.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_tablespace</replaceable></term>
      <listitem>
       <para>
        The name of the tablespace to which the table will be moved.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_schema</replaceable></term>
      <listitem>
       <para>
        The name of the schema to which the table will be moved.
       </para>
      </listitem>
     </varlistentry>

    </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

   <para>
    The key word <literal>COLUMN</literal> is noise and can be omitted.
   </para>

   <para>
    When a column is added with <literal>ADD COLUMN</literal>, all existing
    rows in the table are initialized with the column's default value
    (NULL if no <literal>DEFAULT</> clause is specified).
   </para>

   <para>
    Adding a column with a non-null default or changing the type of an
    existing column will require the entire table and indexes to be rewritten.
    As an exception, if the <literal>USING</> clause does not change the column
    contents and the old type is either binary coercible to the new type or
    an unconstrained domain over the new type, a table rewrite is not needed,
    but any indexes on the affected columns must still be rebuilt.  Adding or
    removing a system <literal>oid</> column also requires rewriting the entire
    table.  Table and/or index rebuilds may take a significant amount of time
    for a large table; and will temporarily require as much as double the disk
    space.
   </para>

   <para>
    Adding a <literal>CHECK</> or <literal>NOT NULL</> constraint requires
    scanning the table to verify that existing rows meet the constraint.
   </para>

   <para>
    The main reason for providing the option to specify multiple changes
    in a single <command>ALTER TABLE</> is that multiple table scans or
    rewrites can thereby be combined into a single pass over the table.
   </para>

   <para>
    The <literal>DROP COLUMN</literal> form does not physically remove
    the column, but simply makes it invisible to SQL operations.  Subsequent
    insert and update operations in the table will store a null value for the
    column. Thus, dropping a column is quick but it will not immediately
    reduce the on-disk size of your table, as the space occupied
    by the dropped column is not reclaimed.  The space will be
    reclaimed over time as existing rows are updated.  (These statements do
    not apply when dropping the system <literal>oid</> column; that is done
    with an immediate rewrite.)
   </para>

   <para>
    To force an immediate rewrite of the table, you can use
    <link linkend="SQL-VACUUM">VACUUM FULL</>, <xref linkend="SQL-CLUSTER">
    or one of the forms of ALTER TABLE that forces a rewrite.  This results in
    no semantically-visible change in the table, but gets rid of
    no-longer-useful data.
   </para>

   <para>
    The <literal>USING</literal> option of <literal>SET DATA TYPE</> can actually
    specify any expression involving the old values of the row; that is, it
    can refer to other columns as well as the one being converted.  This allows
    very general conversions to be done with the <literal>SET DATA TYPE</>
    syntax.  Because of this flexibility, the <literal>USING</literal>
    expression is not applied to the column's default value (if any); the
    result might not be a constant expression as required for a default.
    This means that when there is no implicit or assignment cast from old to
    new type, <literal>SET DATA TYPE</> might fail to convert the default even
    though a <literal>USING</literal> clause is supplied.  In such cases,
    drop the default with <literal>DROP DEFAULT</>, perform the <literal>ALTER
    TYPE</>, and then use <literal>SET DEFAULT</> to add a suitable new
    default.  Similar considerations apply to indexes and constraints involving
    the column.
   </para>

   <para>
    If a table has any descendant tables, it is not permitted to add,
    rename, or change the type of a column, or rename an inherited constraint
    in the parent table without doing
    the same to the descendants.  That is, <command>ALTER TABLE ONLY</command>
    will be rejected.  This ensures that the descendants always have
    columns matching the parent.
   </para>

   <para>
    A recursive <literal>DROP COLUMN</literal> operation will remove a
    descendant table's column only if the descendant does not inherit
    that column from any other parents and never had an independent
    definition of the column.  A nonrecursive <literal>DROP
    COLUMN</literal> (i.e., <command>ALTER TABLE ONLY ... DROP
    COLUMN</command>) never removes any descendant columns, but
    instead marks them as independently defined rather than inherited.
   </para>

   <para>
    The <literal>TRIGGER</>, <literal>CLUSTER</>, <literal>OWNER</>,
    and <literal>TABLESPACE</> actions never recurse to descendant tables;
    that is, they always act as though <literal>ONLY</> were specified.
    Adding a constraint recurses only for <literal>CHECK</> constraints
    that are not marked <literal>NO INHERIT</>.
   </para>

   <para>
    Changing any part of a system catalog table is not permitted.
   </para>

   <para>
    Refer to <xref linkend="sql-createtable"> for a further description of valid
    parameters. <xref linkend="ddl"> has further information on
    inheritance.
   </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

  <para>
   To add a column of type <type>varchar</type> to a table:
<programlisting>
ALTER TABLE distributors ADD COLUMN address varchar(30);
</programlisting>
  </para>

  <para>
   To drop a column from a table:
<programlisting>
ALTER TABLE distributors DROP COLUMN address RESTRICT;
</programlisting>
  </para>

  <para>
   To change the types of two existing columns in one operation:
<programlisting>
ALTER TABLE distributors
    ALTER COLUMN address TYPE varchar(80),
    ALTER COLUMN name TYPE varchar(100);
</programlisting>
  </para>

  <para>
   To change an integer column containing UNIX timestamps to <type>timestamp
   with time zone</type> via a <literal>USING</literal> clause:
<programlisting>
ALTER TABLE foo
    ALTER COLUMN foo_timestamp SET DATA TYPE timestamp with time zone
    USING
        timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
</programlisting>
  </para>

  <para>
   The same, when the column has a default expression that won't automatically
   cast to the new data type:
<programlisting>
ALTER TABLE foo
    ALTER COLUMN foo_timestamp DROP DEFAULT,
    ALTER COLUMN foo_timestamp TYPE timestamp with time zone
    USING
        timestamp with time zone 'epoch' + foo_timestamp * interval '1 second',
    ALTER COLUMN foo_timestamp SET DEFAULT now();
</programlisting>
  </para>

  <para>
   To rename an existing column:
<programlisting>
ALTER TABLE distributors RENAME COLUMN address TO city;
</programlisting>
  </para>

  <para>
   To rename an existing table:
<programlisting>
ALTER TABLE distributors RENAME TO suppliers;
</programlisting>
  </para>

  <para>
   To rename an existing constraint:
<programlisting>
ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
</programlisting>
  </para>

  <para>
   To add a not-null constraint to a column:
<programlisting>
ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
</programlisting>
   To remove a not-null constraint from a column:
<programlisting>
ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
</programlisting>
  </para>

  <para>
   To add a check constraint to a table and all its children:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
</programlisting>
  </para>

  <para>
   To add a check constraint only to a table and not to its children:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5) NO INHERIT;
</programlisting>
   (The check constraint will not be inherited by future children, either.)
  </para>

  <para>
   To remove a check constraint from a table and all its children:
<programlisting>
ALTER TABLE distributors DROP CONSTRAINT zipchk;
</programlisting>
  </para>

  <para>
   To remove a check constraint from one table only:
<programlisting>
ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk;
</programlisting>
   (The check constraint remains in place for any child tables.)
  </para>

  <para>
   To add a foreign key constraint to a table:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address);
</programlisting>
  </para>

  <para>
   To add a (multicolumn) unique constraint to a table:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zipcode);
</programlisting>
  </para>

  <para>
   To add an automatically named primary key constraint to a table, noting
   that a table can only ever have one primary key:
<programlisting>
ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
</programlisting>
  </para>

  <para>
   To move a table to a different tablespace:
<programlisting>
ALTER TABLE distributors SET TABLESPACE fasttablespace;
</programlisting>
  </para>

  <para>
   To move a table to a different schema:
<programlisting>
ALTER TABLE myschema.distributors SET SCHEMA yourschema;
</programlisting>
  </para>

  <para>
   To recreate a primary key constraint, without blocking updates while the
   index is rebuilt:
<programlisting>
CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id);
ALTER TABLE distributors DROP CONSTRAINT distributors_pkey,
    ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx;
</programlisting></para>

 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   The forms <literal>ADD</literal> (without <literal>USING INDEX</literal>),
   <literal>DROP</>, <literal>SET DEFAULT</>,
   and <literal>SET DATA TYPE</literal> (without <literal>USING</literal>)
   conform with the SQL standard.  The other forms are
   <productname>PostgreSQL</productname> extensions of the SQL standard.
   Also, the ability to specify more than one manipulation in a single
   <command>ALTER TABLE</> command is an extension.
  </para>

  <para>
   <command>ALTER TABLE DROP COLUMN</> can be used to drop the only
   column of a table, leaving a zero-column table.  This is an
   extension of SQL, which disallows zero-column tables.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-createtable"></member>
  </simplelist>
 </refsect1>
</refentry>