dml.sgml 8.67 KB
Newer Older
1
<!-- $PostgreSQL: pgsql/doc/src/sgml/dml.sgml,v 1.16 2007/02/01 00:28:16 momjian Exp $ -->
2 3 4 5

<chapter id="dml">
 <title>Data Manipulation</title>

6
 <remark>
7
  This chapter is still quite incomplete.
8
 </remark>
9 10 11 12 13 14 15 16 17 18 19 20 21 22

 <para>
  The previous chapter discussed how to create tables and other
  structures to hold your data.  Now it is time to fill the tables
  with data.  This chapter covers how to insert, update, and delete
  table data.  We also introduce ways to effect automatic data changes
  when certain events occur: triggers and rewrite rules.  The chapter
  after this will finally explain how to extract your long-lost data
  back out of the database.
 </para>

 <sect1 id="dml-insert">
  <title>Inserting Data</title>

Peter Eisentraut's avatar
Peter Eisentraut committed
23 24 25 26 27 28 29 30
  <indexterm zone="dml-insert">
   <primary>inserting</primary>
  </indexterm>

  <indexterm zone="dml-insert">
   <primary>INSERT</primary>
  </indexterm>

31 32 33
  <para>
   When a table is created, it contains no data.  The first thing to
   do before a database can be of much use is to insert data.  Data is
34 35 36 37
   conceptually inserted one row at a time.  Of course you can also
   insert more than one row, but there is no way to insert less than
   one row at a time.  Even if you know only some column values, a
   complete row must be created.
38 39 40
  </para>

  <para>
41
   To create a new row, use the <xref linkend="sql-insert"
Neil Conway's avatar
Neil Conway committed
42
   endterm="sql-insert-title"> command.  The command requires the
43 44
   table name and a value for each of the columns of the table.  For
   example, consider the products table from <xref linkend="ddl">:
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
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric
);
</programlisting>
   An example command to insert a row would be:
<programlisting>
INSERT INTO products VALUES (1, 'Cheese', 9.99);
</programlisting>
   The data values are listed in the order in which the columns appear
   in the table, separated by commas.  Usually, the data values will
   be literals (constants), but scalar expressions are also allowed.
  </para>

  <para>
   The above syntax has the drawback that you need to know the order
   of the columns in the table.  To avoid that you can also list the
   columns explicitly.  For example, both of the following commands
   have the same effect as the one above:
<programlisting>
INSERT INTO products (product_no, name, price) VALUES (1, 'Cheese', 9.99);
INSERT INTO products (name, price, product_no) VALUES ('Cheese', 9.99, 1);
</programlisting>
   Many users consider it good practice to always list the column
   names.
  </para>

  <para>
   If you don't have values for all the columns, you can omit some of
   them.  In that case, the columns will be filled with their default
77
   values.  For example:
78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94
<programlisting>
INSERT INTO products (product_no, name) VALUES (1, 'Cheese');
INSERT INTO products VALUES (1, 'Cheese');
</programlisting>
   The second form is a <productname>PostgreSQL</productname>
   extension.  It fills the columns from the left with as many values
   as are given, and the rest will be defaulted.
  </para>

  <para>
   For clarity, you can also request default values explicitly, for
   individual columns or for the entire row:
<programlisting>
INSERT INTO products (product_no, name, price) VALUES (1, 'Cheese', DEFAULT);
INSERT INTO products DEFAULT VALUES;
</programlisting>
  </para>
95

96 97 98 99 100 101 102 103 104 105
  <para>
   You can insert multiple rows in a single command:
<programlisting>
INSERT INTO products (product_no, name, price) VALUES
    (1, 'Cheese', 9.99),
    (2, 'Bread', 1.99),
    (3, 'Milk', 2.99);
</programlisting>
  </para>

106 107
  <tip>
   <para>
Neil Conway's avatar
Neil Conway committed
108 109 110 111 112 113
    When inserting a lot of data at the same time, considering using
    the <xref linkend="sql-copy" endterm="sql-copy-title"> command.
    It is not as flexible as the <xref linkend="sql-insert"
    endterm="sql-insert-title"> command, but is more efficient. Refer
    to <xref linkend="populate"> for more information on improving
    bulk loading performance.
114 115
   </para>
  </tip>
116 117 118 119 120
 </sect1>

 <sect1 id="dml-update">
  <title>Updating Data</title>

Peter Eisentraut's avatar
Peter Eisentraut committed
121 122 123 124 125 126 127 128
  <indexterm zone="dml-update">
   <primary>updating</primary>
  </indexterm>

  <indexterm zone="dml-update">
   <primary>UPDATE</primary>
  </indexterm>

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
  <para>
   The modification of data that is already in the database is
   referred to as updating.  You can update individual rows, all the
   rows in a table, or a subset of all rows.  Each column can be
   updated separately; the other columns are not affected.
  </para>

  <para>
   To perform an update, you need three pieces of information:
   <orderedlist spacing=compact>
    <listitem>
     <para>The name of the table and column to update,</para>
    </listitem>

    <listitem>
     <para>The new value of the column,</para>
    </listitem>

    <listitem>
     <para>Which row(s) to update.</para>
    </listitem>
   </orderedlist>
  </para>

  <para>
   Recall from <xref linkend="ddl"> that SQL does not, in general,
   provide a unique identifier for rows.  Therefore it is not
   necessarily possible to directly specify which row to update.
   Instead, you specify which conditions a row must meet in order to
   be updated.  Only if you have a primary key in the table (no matter
159 160
   whether you declared it or not) can you reliably address individual rows,
   by choosing a condition that matches the primary key.
161 162 163 164 165 166 167 168 169 170
   Graphical database access tools rely on this fact to allow you to
   update rows individually.
  </para>

  <para>
   For example, this command updates all products that have a price of
   5 to have a price of 10:
<programlisting>
UPDATE products SET price = 10 WHERE price = 5;
</programlisting>
171
    This might cause zero, one, or many rows to be updated.  It is not
172 173 174 175
    an error to attempt an update that does not match any rows.
  </para>

  <para>
176
   Let's look at that command in detail. First is the key word
177
   <literal>UPDATE</literal> followed by the table name.  As usual,
178
   the table name can be schema-qualified, otherwise it is looked up
179 180 181 182 183 184 185 186
   in the path.  Next is the key word <literal>SET</literal> followed
   by the column name, an equals sign and the new column value.  The
   new column value can be any scalar expression, not just a constant.
   For example, if you want to raise the price of all products by 10%
   you could use:
<programlisting>
UPDATE products SET price = price * 1.10;
</programlisting>
187 188
   As you see, the expression for the new value can refer to the existing
   value(s) in the row.  We also left out the <literal>WHERE</literal> clause.
189
   If it is omitted, it means that all rows in the table are updated.
190 191
   If it is present, only those rows that match the
   <literal>WHERE</literal> condition are updated.  Note that the equals
192 193
   sign in the <literal>SET</literal> clause is an assignment while
   the one in the <literal>WHERE</literal> clause is a comparison, but
194 195
   this does not create any ambiguity.  Of course, the
   <literal>WHERE</literal> condition does
196 197 198 199 200 201
   not have to be an equality test.  Many other operators are
   available (see <xref linkend="functions">).  But the expression
   needs to evaluate to a Boolean result.
  </para>

  <para>
202
   You can update more than one column in an
203
   <command>UPDATE</command> command by listing more than one
204 205
   assignment in the <literal>SET</literal> clause.  For example:
<programlisting>
206
UPDATE mytable SET a = 5, b = 3, c = 1 WHERE a &gt; 0;
207 208 209 210 211 212 213
</programlisting>
  </para>
 </sect1>

 <sect1 id="dml-delete">
  <title>Deleting Data</title>

Peter Eisentraut's avatar
Peter Eisentraut committed
214 215 216 217 218 219 220 221
  <indexterm zone="dml-delete">
   <primary>deleting</primary>
  </indexterm>

  <indexterm zone="dml-delete">
   <primary>DELETE</primary>
  </indexterm>

222 223 224 225 226
  <para>
   So far we have explained how to add data to tables and how to
   change data.  What remains is to discuss how to remove data that is
   no longer needed.  Just as adding data is only possible in whole
   rows, you can only remove entire rows from a table.  In the
227
   previous section we explained that SQL does not provide a way to
228 229 230 231 232 233 234 235 236
   directly address individual rows.  Therefore, removing rows can
   only be done by specifying conditions that the rows to be removed
   have to match.  If you have a primary key in the table then you can
   specify the exact row.  But you can also remove groups of rows
   matching a condition, or you can remove all rows in the table at
   once.
  </para>

  <para>
Neil Conway's avatar
Neil Conway committed
237 238 239
   You use the <xref linkend="sql-delete" endterm="sql-delete-title">
   command to remove rows; the syntax is very similar to the
   <command>UPDATE</command> command.  For instance, to remove all
240
   rows from the products table that have a price of 10, use:
241 242 243 244
<programlisting>
DELETE FROM products WHERE price = 10;
</programlisting>
  </para>
245 246

  <para>
247
   If you simply write:
248 249 250 251 252
<programlisting>
DELETE FROM products;
</programlisting>
   then all rows in the table will be deleted!  Caveat programmer.
  </para>
253 254
 </sect1>
</chapter>