summaryrefslogtreecommitdiff
path: root/doc/src/sgml/dml.sgml
blob: 970a75867cf9a7c1a7ef86277bd0faec8678b217 (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
<!-- $PostgreSQL: pgsql/doc/src/sgml/dml.sgml,v 1.8 2003/11/29 19:51:36 pgsql Exp $ -->

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

 <remark>
  This chapter is still quite incomplete.
 </remark>

 <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>

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

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

  <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
   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.
  </para>

  <para>
   To create a new row, use the <literal>INSERT</literal> command.
   The command requires the table name and a value for each of the
   columns of the table.  For example, consider the products table
   from <xref linkend="ddl">:
<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
   values.  For example,
<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>

  <tip>
   <para>
    To do <quote>bulk loads</quote>, that is, inserting a lot of data,
    take a look at the <xref linkend="sql-copy"
    endterm="sql-copy-title"> command.  It is not as flexible as the
    <command>INSERT</command> command, but is more efficient.
   </para>
  </tip>
 </sect1>

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

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

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

  <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
   whether you declared it or not) can you reliably address individual rows,
   by choosing a condition that matches the primary key.
   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>
    This may cause zero, one, or many rows to be updated.  It is not
    an error to attempt an update that does not match any rows.
  </para>

  <para>
   Let's look at that command in detail: First is the key word
   <literal>UPDATE</literal> followed by the table name.  As usual,
   the table name may be schema-qualified, otherwise it is looked up
   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>
   As you see, the expression for the new value can also refer to the
   old value.  We also left out the <literal>WHERE</literal> clause.
   If it is omitted, it means that all rows in the table are updated.
   If it is present, only those rows that match the condition after
   the <literal>WHERE</literal> are updated.  Note that the equals
   sign in the <literal>SET</literal> clause is an assignment while
   the one in the <literal>WHERE</literal> clause is a comparison, but
   this does not create any ambiguity.  Of course, the condition does
   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>
   You can also update more than one column in an
   <literal>UPDATE</literal> command by listing more than one
   assignment in the <literal>SET</literal> clause.  For example:
<programlisting>
UPDATE mytable SET a = 5, b = 3, c = 1 WHERE a > 0;
</programlisting>
  </para>
 </sect1>

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

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

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

  <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
   previous section we discussed that SQL does not provide a way to
   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>
   You use the <literal>DELETE</literal> command to remove rows; the
   syntax is very similar to the <literal>UPDATE</literal> command.
   For instance, to remove all rows from the products table that have a price of 10, use
<programlisting>
DELETE FROM products WHERE price = 10;
</programlisting>
  </para>

  <para>
   If you simply write
<programlisting>
DELETE FROM products;
</programlisting>
   then all rows in the table will be deleted!  Caveat programmer.
  </para>
 </sect1>
</chapter>