Fix xslt_process() to ensure that it inserts a NULL terminator after the
[PostgreSQL.git] / doc / src / sgml / dml.sgml
blobf67e6a77a944f536271d9198794e8bfe79e00e37
1 <!-- $PostgreSQL$ -->
3 <chapter id="dml">
4 <title>Data Manipulation</title>
6 <remark>
7 This chapter is still quite incomplete.
8 </remark>
10 <para>
11 The previous chapter discussed how to create tables and other
12 structures to hold your data. Now it is time to fill the tables
13 with data. This chapter covers how to insert, update, and delete
14 table data. We also introduce ways to effect automatic data changes
15 when certain events occur: triggers and rewrite rules. The chapter
16 after this will finally explain how to extract your long-lost data
17 from the database.
18 </para>
20 <sect1 id="dml-insert">
21 <title>Inserting Data</title>
23 <indexterm zone="dml-insert">
24 <primary>inserting</primary>
25 </indexterm>
27 <indexterm zone="dml-insert">
28 <primary>INSERT</primary>
29 </indexterm>
31 <para>
32 When a table is created, it contains no data. The first thing to
33 do before a database can be of much use is to insert data. Data is
34 conceptually inserted one row at a time. Of course you can also
35 insert more than one row, but there is no way to insert less than
36 one row. Even if you know only some column values, a
37 complete row must be created.
38 </para>
40 <para>
41 To create a new row, use the <xref linkend="sql-insert"
42 endterm="sql-insert-title"> command. The command requires the
43 table name and column values. For
44 example, consider the products table from <xref linkend="ddl">:
45 <programlisting>
46 CREATE TABLE products (
47 product_no integer,
48 name text,
49 price numeric
51 </programlisting>
52 An example command to insert a row would be:
53 <programlisting>
54 INSERT INTO products VALUES (1, 'Cheese', 9.99);
55 </programlisting>
56 The data values are listed in the order in which the columns appear
57 in the table, separated by commas. Usually, the data values will
58 be literals (constants), but scalar expressions are also allowed.
59 </para>
61 <para>
62 The above syntax has the drawback that you need to know the order
63 of the columns in the table. To avoid this you can also list the
64 columns explicitly. For example, both of the following commands
65 have the same effect as the one above:
66 <programlisting>
67 INSERT INTO products (product_no, name, price) VALUES (1, 'Cheese', 9.99);
68 INSERT INTO products (name, price, product_no) VALUES ('Cheese', 9.99, 1);
69 </programlisting>
70 Many users consider it good practice to always list the column
71 names.
72 </para>
74 <para>
75 If you don't have values for all the columns, you can omit some of
76 them. In that case, the columns will be filled with their default
77 values. For example:
78 <programlisting>
79 INSERT INTO products (product_no, name) VALUES (1, 'Cheese');
80 INSERT INTO products VALUES (1, 'Cheese');
81 </programlisting>
82 The second form is a <productname>PostgreSQL</productname>
83 extension. It fills the columns from the left with as many values
84 as are given, and the rest will be defaulted.
85 </para>
87 <para>
88 For clarity, you can also request default values explicitly, for
89 individual columns or for the entire row:
90 <programlisting>
91 INSERT INTO products (product_no, name, price) VALUES (1, 'Cheese', DEFAULT);
92 INSERT INTO products DEFAULT VALUES;
93 </programlisting>
94 </para>
96 <para>
97 You can insert multiple rows in a single command:
98 <programlisting>
99 INSERT INTO products (product_no, name, price) VALUES
100 (1, 'Cheese', 9.99),
101 (2, 'Bread', 1.99),
102 (3, 'Milk', 2.99);
103 </programlisting>
104 </para>
106 <tip>
107 <para>
108 When inserting a lot of data at the same time, considering using
109 the <xref linkend="sql-copy" endterm="sql-copy-title"> command.
110 It is not as flexible as the <xref linkend="sql-insert"
111 endterm="sql-insert-title"> command, but is more efficient. Refer
112 to <xref linkend="populate"> for more information on improving
113 bulk loading performance.
114 </para>
115 </tip>
116 </sect1>
118 <sect1 id="dml-update">
119 <title>Updating Data</title>
121 <indexterm zone="dml-update">
122 <primary>updating</primary>
123 </indexterm>
125 <indexterm zone="dml-update">
126 <primary>UPDATE</primary>
127 </indexterm>
129 <para>
130 The modification of data that is already in the database is
131 referred to as updating. You can update individual rows, all the
132 rows in a table, or a subset of all rows. Each column can be
133 updated separately; the other columns are not affected.
134 </para>
136 <para>
137 To update existing rows, use the <xref linkend="sql-update"
138 endterm="sql-update-title"> command. This requires
139 three pieces of information:
140 <orderedlist spacing="compact">
141 <listitem>
142 <para>The name of the table and column to update</para>
143 </listitem>
145 <listitem>
146 <para>The new value of the column</para>
147 </listitem>
149 <listitem>
150 <para>Which row(s) to update</para>
151 </listitem>
152 </orderedlist>
153 </para>
155 <para>
156 Recall from <xref linkend="ddl"> that SQL does not, in general,
157 provide a unique identifier for rows. Therefore it is not
158 always possible to directly specify which row to update.
159 Instead, you specify which conditions a row must meet in order to
160 be updated. Only if you have a primary key in the table (independent of
161 whether you declared it or not) can you reliably address individual rows
162 by choosing a condition that matches the primary key.
163 Graphical database access tools rely on this fact to allow you to
164 update rows individually.
165 </para>
167 <para>
168 For example, this command updates all products that have a price of
169 5 to have a price of 10:
170 <programlisting>
171 UPDATE products SET price = 10 WHERE price = 5;
172 </programlisting>
173 This might cause zero, one, or many rows to be updated. It is not
174 an error to attempt an update that does not match any rows.
175 </para>
177 <para>
178 Let's look at that command in detail. First is the key word
179 <literal>UPDATE</literal> followed by the table name. As usual,
180 the table name can be schema-qualified, otherwise it is looked up
181 in the path. Next is the key word <literal>SET</literal> followed
182 by the column name, an equal sign, and the new column value. The
183 new column value can be any scalar expression, not just a constant.
184 For example, if you want to raise the price of all products by 10%
185 you could use:
186 <programlisting>
187 UPDATE products SET price = price * 1.10;
188 </programlisting>
189 As you see, the expression for the new value can refer to the existing
190 value(s) in the row. We also left out the <literal>WHERE</literal> clause.
191 If it is omitted, it means that all rows in the table are updated.
192 If it is present, only those rows that match the
193 <literal>WHERE</literal> condition are updated. Note that the equals
194 sign in the <literal>SET</literal> clause is an assignment while
195 the one in the <literal>WHERE</literal> clause is a comparison, but
196 this does not create any ambiguity. Of course, the
197 <literal>WHERE</literal> condition does
198 not have to be an equality test. Many other operators are
199 available (see <xref linkend="functions">). But the expression
200 needs to evaluate to a Boolean result.
201 </para>
203 <para>
204 You can update more than one column in an
205 <command>UPDATE</command> command by listing more than one
206 assignment in the <literal>SET</literal> clause. For example:
207 <programlisting>
208 UPDATE mytable SET a = 5, b = 3, c = 1 WHERE a &gt; 0;
209 </programlisting>
210 </para>
211 </sect1>
213 <sect1 id="dml-delete">
214 <title>Deleting Data</title>
216 <indexterm zone="dml-delete">
217 <primary>deleting</primary>
218 </indexterm>
220 <indexterm zone="dml-delete">
221 <primary>DELETE</primary>
222 </indexterm>
224 <para>
225 So far we have explained how to add data to tables and how to
226 change data. What remains is to discuss how to remove data that is
227 no longer needed. Just as adding data is only possible in whole
228 rows, you can only remove entire rows from a table. In the
229 previous section we explained that SQL does not provide a way to
230 directly address individual rows. Therefore, removing rows can
231 only be done by specifying conditions that the rows to be removed
232 have to match. If you have a primary key in the table then you can
233 specify the exact row. But you can also remove groups of rows
234 matching a condition, or you can remove all rows in the table at
235 once.
236 </para>
238 <para>
239 You use the <xref linkend="sql-delete" endterm="sql-delete-title">
240 command to remove rows; the syntax is very similar to the
241 <command>UPDATE</command> command. For instance, to remove all
242 rows from the products table that have a price of 10, use:
243 <programlisting>
244 DELETE FROM products WHERE price = 10;
245 </programlisting>
246 </para>
248 <para>
249 If you simply write:
250 <programlisting>
251 DELETE FROM products;
252 </programlisting>
253 then all rows in the table will be deleted! Caveat programmer.
254 </para>
255 </sect1>
256 </chapter>