1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>5.7. Modifying Tables</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="ddl-system-columns.html" title="5.6. System Columns" /><link rel="next" href="ddl-priv.html" title="5.8. Privileges" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">5.7. Modifying Tables</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ddl-system-columns.html" title="5.6. System Columns">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><th width="60%" align="center">Chapter 5. Data Definition</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ddl-priv.html" title="5.8. Privileges">Next</a></td></tr></table><hr /></div><div class="sect1" id="DDL-ALTER"><div class="titlepage"><div><div><h2 class="title" style="clear: both">5.7. Modifying Tables <a href="#DDL-ALTER" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-ADDING-A-COLUMN">5.7.1. Adding a Column</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-REMOVING-A-COLUMN">5.7.2. Removing a Column</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-ADDING-A-CONSTRAINT">5.7.3. Adding a Constraint</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-REMOVING-A-CONSTRAINT">5.7.4. Removing a Constraint</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-COLUMN-DEFAULT">5.7.5. Changing a Column's Default Value</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-COLUMN-TYPE">5.7.6. Changing a Column's Data Type</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-RENAMING-COLUMN">5.7.7. Renaming a Column</a></span></dt><dt><span class="sect2"><a href="ddl-alter.html#DDL-ALTER-RENAMING-TABLE">5.7.8. Renaming a Table</a></span></dt></dl></div><a id="id-1.5.4.9.2" class="indexterm"></a><p>
3 When you create a table and you realize that you made a mistake, or
4 the requirements of the application change, you can drop the
5 table and create it again. But this is not a convenient option if
6 the table is already filled with data, or if the table is
7 referenced by other database objects (for instance a foreign key
8 constraint). Therefore <span class="productname">PostgreSQL</span>
9 provides a family of commands to make modifications to existing
10 tables. Note that this is conceptually distinct from altering
11 the data contained in the table: here we are interested in altering
12 the definition, or structure, of the table.
15 </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>Add columns</p></li><li class="listitem"><p>Remove columns</p></li><li class="listitem"><p>Add constraints</p></li><li class="listitem"><p>Remove constraints</p></li><li class="listitem"><p>Change default values</p></li><li class="listitem"><p>Change column data types</p></li><li class="listitem"><p>Rename columns</p></li><li class="listitem"><p>Rename tables</p></li></ul></div><p>
17 All these actions are performed using the
18 <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a>
19 command, whose reference page contains details beyond those given
21 </p><div class="sect2" id="DDL-ALTER-ADDING-A-COLUMN"><div class="titlepage"><div><div><h3 class="title">5.7.1. Adding a Column <a href="#DDL-ALTER-ADDING-A-COLUMN" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.5.2" class="indexterm"></a><p>
22 To add a column, use a command like:
23 </p><pre class="programlisting">
24 ALTER TABLE products ADD COLUMN description text;
26 The new column is initially filled with whatever default
27 value is given (null if you don't specify a <code class="literal">DEFAULT</code> clause).
28 </p><div class="tip"><h3 class="title">Tip</h3><p>
29 Adding a column with a constant default value does not require each row of
30 the table to be updated when the <code class="command">ALTER TABLE</code> statement
31 is executed. Instead, the default value will be returned the next time
32 the row is accessed, and applied when the table is rewritten, making
33 the <code class="command">ALTER TABLE</code> very fast even on large tables.
35 If the default value is volatile (e.g., <code class="function">clock_timestamp()</code>)
36 each row will need to be updated with the value calculated at the time
37 <code class="command">ALTER TABLE</code> is executed. To avoid a potentially
38 lengthy update operation, particularly if you intend to fill the column
39 with mostly nondefault values anyway, it may be preferable to add the
40 column with no default, insert the correct values using
41 <code class="command">UPDATE</code>, and then add any desired default as described
44 You can also define constraints on the column at the same time,
45 using the usual syntax:
46 </p><pre class="programlisting">
47 ALTER TABLE products ADD COLUMN description text CHECK (description <> '');
49 In fact all the options that can be applied to a column description
50 in <code class="command">CREATE TABLE</code> can be used here. Keep in mind however
51 that the default value must satisfy the given constraints, or the
52 <code class="literal">ADD</code> will fail. Alternatively, you can add
53 constraints later (see below) after you've filled in the new column
55 </p></div><div class="sect2" id="DDL-ALTER-REMOVING-A-COLUMN"><div class="titlepage"><div><div><h3 class="title">5.7.2. Removing a Column <a href="#DDL-ALTER-REMOVING-A-COLUMN" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.6.2" class="indexterm"></a><p>
56 To remove a column, use a command like:
57 </p><pre class="programlisting">
58 ALTER TABLE products DROP COLUMN description;
60 Whatever data was in the column disappears. Table constraints involving
61 the column are dropped, too. However, if the column is referenced by a
62 foreign key constraint of another table,
63 <span class="productname">PostgreSQL</span> will not silently drop that
64 constraint. You can authorize dropping everything that depends on
65 the column by adding <code class="literal">CASCADE</code>:
66 </p><pre class="programlisting">
67 ALTER TABLE products DROP COLUMN description CASCADE;
69 See <a class="xref" href="ddl-depend.html" title="5.15. Dependency Tracking">Section 5.15</a> for a description of the general
70 mechanism behind this.
71 </p></div><div class="sect2" id="DDL-ALTER-ADDING-A-CONSTRAINT"><div class="titlepage"><div><div><h3 class="title">5.7.3. Adding a Constraint <a href="#DDL-ALTER-ADDING-A-CONSTRAINT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.7.2" class="indexterm"></a><p>
72 To add a constraint, the table constraint syntax is used. For example:
73 </p><pre class="programlisting">
74 ALTER TABLE products ADD CHECK (name <> '');
75 ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no);
76 ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups;
79 To add a not-null constraint, which is normally not written as a table
80 constraint, this special syntax is available:
81 </p><pre class="programlisting">
82 ALTER TABLE products ALTER COLUMN product_no SET NOT NULL;
84 This command silently does nothing if the column already has a
87 The constraint will be checked immediately, so the table data must
88 satisfy the constraint before it can be added.
89 </p></div><div class="sect2" id="DDL-ALTER-REMOVING-A-CONSTRAINT"><div class="titlepage"><div><div><h3 class="title">5.7.4. Removing a Constraint <a href="#DDL-ALTER-REMOVING-A-CONSTRAINT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.8.2" class="indexterm"></a><p>
90 To remove a constraint you need to know its name. If you gave it
91 a name then that's easy. Otherwise the system assigned a
92 generated name, which you need to find out. The
93 <span class="application">psql</span> command <code class="literal">\d
94 <em class="replaceable"><code>tablename</code></em></code> can be helpful
95 here; other interfaces might also provide a way to inspect table
96 details. Then the command is:
97 </p><pre class="programlisting">
98 ALTER TABLE products DROP CONSTRAINT some_name;
101 As with dropping a column, you need to add <code class="literal">CASCADE</code> if you
102 want to drop a constraint that something else depends on. An example
103 is that a foreign key constraint depends on a unique or primary key
104 constraint on the referenced column(s).
106 Simplified syntax is available to drop a not-null constraint:
107 </p><pre class="programlisting">
108 ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL;
110 This mirrors the <code class="literal">SET NOT NULL</code> syntax for adding a
111 not-null constraint. This command will silently do nothing if the column
112 does not have a not-null constraint. (Recall that a column can have at
113 most one not-null constraint, so it is never ambiguous which constraint
114 this command acts on.)
115 </p></div><div class="sect2" id="DDL-ALTER-COLUMN-DEFAULT"><div class="titlepage"><div><div><h3 class="title">5.7.5. Changing a Column's Default Value <a href="#DDL-ALTER-COLUMN-DEFAULT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.9.2" class="indexterm"></a><p>
116 To set a new default for a column, use a command like:
117 </p><pre class="programlisting">
118 ALTER TABLE products ALTER COLUMN price SET DEFAULT 7.77;
120 Note that this doesn't affect any existing rows in the table, it
121 just changes the default for future <code class="command">INSERT</code> commands.
123 To remove any default value, use:
124 </p><pre class="programlisting">
125 ALTER TABLE products ALTER COLUMN price DROP DEFAULT;
127 This is effectively the same as setting the default to null.
128 As a consequence, it is not an error
129 to drop a default where one hadn't been defined, because the
130 default is implicitly the null value.
131 </p></div><div class="sect2" id="DDL-ALTER-COLUMN-TYPE"><div class="titlepage"><div><div><h3 class="title">5.7.6. Changing a Column's Data Type <a href="#DDL-ALTER-COLUMN-TYPE" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.10.2" class="indexterm"></a><p>
132 To convert a column to a different data type, use a command like:
133 </p><pre class="programlisting">
134 ALTER TABLE products ALTER COLUMN price TYPE numeric(10,2);
136 This will succeed only if each existing entry in the column can be
137 converted to the new type by an implicit cast. If a more complex
138 conversion is needed, you can add a <code class="literal">USING</code> clause that
139 specifies how to compute the new values from the old.
141 <span class="productname">PostgreSQL</span> will attempt to convert the column's
142 default value (if any) to the new type, as well as any constraints
143 that involve the column. But these conversions might fail, or might
144 produce surprising results. It's often best to drop any constraints
145 on the column before altering its type, and then add back suitably
146 modified constraints afterwards.
147 </p></div><div class="sect2" id="DDL-ALTER-RENAMING-COLUMN"><div class="titlepage"><div><div><h3 class="title">5.7.7. Renaming a Column <a href="#DDL-ALTER-RENAMING-COLUMN" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.11.2" class="indexterm"></a><p>
149 </p><pre class="programlisting">
150 ALTER TABLE products RENAME COLUMN product_no TO product_number;
152 </p></div><div class="sect2" id="DDL-ALTER-RENAMING-TABLE"><div class="titlepage"><div><div><h3 class="title">5.7.8. Renaming a Table <a href="#DDL-ALTER-RENAMING-TABLE" class="id_link">#</a></h3></div></div></div><a id="id-1.5.4.9.12.2" class="indexterm"></a><p>
154 </p><pre class="programlisting">
155 ALTER TABLE products RENAME TO items;
157 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ddl-system-columns.html" title="5.6. System Columns">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ddl-priv.html" title="5.8. Privileges">Next</a></td></tr><tr><td width="40%" align="left" valign="top">5.6. System Columns </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 5.8. Privileges</td></tr></table></div></body></html>