aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/alter_table.sgml
blob: f73e5640b31c886d76351745016207e977469ea9 (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
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.81.2.1 2005/12/08 21:35:41 momjian Exp $
PostgreSQL documentation
-->

<refentry id="SQL-ALTERTABLE">
 <refmeta>
  <refentrytitle id="sql-altertable-title">ALTER TABLE</refentrytitle>
  <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 [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
    <replaceable class="PARAMETER">action</replaceable> [, ... ]
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
    RENAME [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> TO <replaceable class="PARAMETER">new_column</replaceable>
ALTER TABLE <replaceable class="PARAMETER">name</replaceable>
    RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ALTER TABLE <replaceable class="PARAMETER">name</replaceable>
    SET SCHEMA <replaceable class="PARAMETER">new_schema</replaceable>

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

    ADD [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> <replaceable class="PARAMETER">type</replaceable> [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
    DROP [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> [ RESTRICT | CASCADE ]
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> TYPE <replaceable class="PARAMETER">type</replaceable> [ USING <replaceable class="PARAMETER">expression</replaceable> ]
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET DEFAULT <replaceable class="PARAMETER">expression</replaceable>
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> DROP DEFAULT
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET | DROP } NOT NULL
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
    ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
    ADD <replaceable class="PARAMETER">table_constraint</replaceable>
    DROP CONSTRAINT <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 ]
    CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
    SET WITHOUT CLUSTER
    SET WITHOUT OIDS
    OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
    SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable>
</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" endterm="SQL-CREATETABLE-TITLE">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DROP COLUMN</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.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>ALTER COLUMN 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>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 may 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" endterm="sql-analyze-title"> operations.
      The target can be set in the range 0 to 1000; 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>
    <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 supplementary 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 <type>text</type> and <type>bytea</type>
      columns 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></literal></term>
    <listitem>
     <para>
      This form adds a new constraint to a table using the same syntax as
      <xref linkend="SQL-CREATETABLE" endterm="SQL-CREATETABLE-TITLE">. 
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DROP CONSTRAINT</literal></term>
    <listitem>
     <para>
      This form drops the specified constraint on a table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DISABLE</literal>/<literal>ENABLE TRIGGER</literal></term>
    <listitem>
     <para>
      These forms disable or enable 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 may disable or enable a single
      trigger specified by name, or all triggers on the table, or only
      user triggers (this option excludes triggers that are used to implement
      foreign key constraints).  Disabling or enabling 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.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>CLUSTER</literal></term>
    <listitem>
     <para>
      This form selects the default index for future 
      <xref linkend="SQL-CLUSTER" endterm="sql-cluster-title">
      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" endterm="sql-cluster-title">
      index specification from the table.  This affects
      future cluster operations that don't specify an index.
     </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>

     <para>
      Note that there is no variant of <command>ALTER TABLE</command>
      that allows OIDs to be restored to a table once they have been
      removed.
     </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" endterm="sql-createtablespace-title">.
     </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) or the name of an individual column in
      a 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 SERIAL-column sequences 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 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.)
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

    <variablelist>

     <varlistentry>
      <term><replaceable class="PARAMETER">name</replaceable></term>
      <listitem>
       <para>
        The name (possibly schema-qualified) of an existing table to
        alter. If <literal>ONLY</> is specified, only that table is
        altered. If <literal>ONLY</> is not specified, the table and all
        its descendant tables (if any) are updated. <literal>*</> can be
        appended to the table name to indicate that descendant tables are
        to be altered, but in the current version, this is the default
        behavior.  (In releases before 7.1, <literal>ONLY</> was the
        default behavior.  The default can be altered by changing the
        configuration parameter <xref linkend="guc-sql-inheritance">.)
       </para>
      </listitem>
     </varlistentry>

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

     <varlistentry>
      <term><replaceable class="PARAMETER">new_column</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 for
        foreign key constraints.)
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>USER</literal></term>
      <listitem>
       <para>
        Disable or enable all triggers belonging to the table except for
        foreign key constraint triggers.
       </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">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 to be rewritten.  This
    may take a significant amount of time for a large table; and it will
    temporarily require 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.
   </para>

   <para>
    The fact that <literal>ALTER TYPE</> requires rewriting the whole table
    is sometimes an advantage, because the rewriting process eliminates
    any dead space in the table.  For example, to reclaim the space occupied
    by a dropped column immediately, the fastest way is
<programlisting>
ALTER TABLE table ALTER COLUMN anycol TYPE anytype;
</programlisting>
    where <literal>anycol</> is any remaining table column and
    <literal>anytype</> is the same type that column already has.
    This results in no semantically-visible change in the table,
    but the command forces rewriting, which gets rid of no-longer-useful
    data.
   </para>

   <para>
    The <literal>USING</literal> option of <literal>ALTER 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>ALTER 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>ALTER TYPE</> may 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 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 can recurse only for <literal>CHECK</> constraints.
   </para>

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

   <para>
    Refer to <xref linkend="sql-createtable"
    endterm="sql-createtable-title"> 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 TYPE timestamp with time zone
    USING
        timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
</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 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:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
</programlisting>
  </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 add a foreign key constraint to a table:
<programlisting>
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) MATCH FULL;
</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>

 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   The <literal>ADD</literal>, <literal>DROP</>, and <literal>SET DEFAULT</>
   forms 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>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->