Home Explore Blog CI



postgresql

1st chunk of `doc/src/sgml/dml.sgml`
21ee815158eb050a74773b31dcc64334a2d991c1004c2e0f0000000100000fa0
<!-- doc/src/sgml/dml.sgml -->

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

 <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.  The chapter
  after this will finally explain how to extract your long-lost data
  from 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
   inserted one row at a time.  You can also insert more than one row
   in a single command, but it is not possible to insert something that
   is not a complete row.  Even if you know only some column values, a
   complete row must be created.
  </para>

  <para>
   To create a new row, use the <xref linkend="sql-insert"/>
   command.  The command requires the
   table name and column values.  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 this 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>

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

  <para>
   It is also possible to insert the result of a query (which might be no
   rows, one row, or many rows):
<programlisting>
INSERT INTO products (product_no, name, price)
  SELECT product_no, name, price FROM new_products
    WHERE release_date = 'today';
</programlisting>
   This provides the full power of the SQL query mechanism (<xref
   linkend="queries"/>) for computing the rows to be inserted.
  </para>

  <tip>
   <para>
    When inserting a lot of data at the same time, consider using
    the <xref linkend="sql-copy"/> command.
    It is not as flexible as the <xref linkend="sql-insert"/>
    command, but is more efficient. Refer
    to <xref linkend="populate"/> for more information on improving

Title: Inserting Data into Tables
Summary
This chapter covers how to insert data into tables in a database, including the basic INSERT command, listing columns explicitly, omitting column values, using default values, inserting multiple rows, and inserting the result of a query.