This page in other versions: 9.0 / 9.1 / 9.2 / 9.3 / 9.4  |  Development versions: devel  |  Unsupported versions: 7.1 / 7.2 / 7.3 / 7.4 / 8.0 / 8.1 / 8.2 / 8.3 / 8.4

INSERT

Name

INSERT -- create new rows in a table

Synopsis

INSERT INTO table [ ( column [, ...] ) ]
    { DEFAULT VALUES | VALUES ( { expression | DEFAULT } [, ...] ) | query }

Description

INSERT inserts new rows into a table. One can insert a single row specified by value expressions, or several rows as a result of a query.

The target column names may be listed in any order. If no list of column names is given at all, the default is all the columns of the table in their declared order; or the first N column names, if there are only N columns supplied by the VALUES clause or query. The values supplied by the VALUES clause or query are associated with the explicit or implicit column list left-to-right.

Each column not present in the explicit or implicit column list will be filled with a default value, either its declared default value or null if there is none.

If the expression for any column is not of the correct data type, automatic type conversion will be attempted.

You must have INSERT privilege to a table in order to insert into it. If you use the query clause to insert rows from a query, you also need to have SELECT privilege on any table used in the query.

Parameters

table

The name (optionally schema-qualified) of an existing table.

column

The name of a column in table. The column name can be qualified with a subfield name or array subscript, if needed. (Inserting into only some fields of a composite column leaves the other fields null.)

DEFAULT VALUES

All columns will be filled with their default values.

expression

An expression or value to assign to the corresponding column.

DEFAULT

The corresponding column will be filled with its default value.

query

A query (SELECT statement) that supplies the rows to be inserted. Refer to the SELECT statement for a description of the syntax.

Outputs

On successful completion, an INSERT command returns a command tag of the form

INSERT oid count

The count is the number of rows inserted. If count is exactly one, and the target table has OIDs, then oid is the OID assigned to the inserted row. Otherwise oid is zero.

Examples

Insert a single row into table films:

INSERT INTO films VALUES
    ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes');

In this example, the len column is omitted and therefore it will have the default value:

INSERT INTO films (code, title, did, date_prod, kind)
    VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');

This example uses the DEFAULT clause for the date columns rather than specifying a value:

INSERT INTO films VALUES
    ('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes');
INSERT INTO films (code, title, did, date_prod, kind)
    VALUES ('T_601', 'Yojimbo', 106, DEFAULT, 'Drama');

To insert a row consisting entirely of default values:

INSERT INTO films DEFAULT VALUES;

This example inserts some rows into table films from a table tmp_films with the same column layout as films:

INSERT INTO films SELECT * FROM tmp_films WHERE date_prod < '2004-05-07';

This example inserts into array columns:

-- Create an empty 3x3 gameboard for noughts-and-crosses
-- (these commands create the same board)
INSERT INTO tictactoe (game, board[1:3][1:3])
    VALUES (1,'{{"","",""},{"","",""},{"","",""}}');
INSERT INTO tictactoe (game, board)
    VALUES (2,'{{,,},{,,},{,,}}');

Compatibility

INSERT conforms to the SQL standard. The case in which a column name list is omitted, but not all the columns are filled from the VALUES clause or query, is disallowed by the standard.

Possible limitations of the query clause are documented under SELECT.

Comments


Dec. 6, 2005, 10:24 p.m.

It seems that the order of execution for an INSERT statement is as the columns are listed in the table, rather than as they are listed in the INSERT statement. Here's an example:

test=# CREATE SEQUENCE s;
CREATE SEQUENCE
test=# CREATE TABLE a (a0 int, a1 int, a2 int, a3 int);
CREATE TABLE
test=# INSERT INTO a (a3, a2, a0, a1) VALUES (nextval('s'), nextval('s'), nextval('s'), nextval('s'));
INSERT 0 1
test=# SELECT * FROM a;
a0 | a1 | a2 | a3
----+----+----+----
1 | 2 | 3 | 4
(1 row)


Jan. 10, 2006, 10:54 p.m.

Prior comment is incorrect. The evaluation of the VALUES did not proceed left-to-right as the poster expected. If instead he had tried:

insert into a (a3,a2,a0,a1) values (1,2,3,4);

He would have seen the result he expected.


March 15, 2006, 1:01 a.m.

I'm pretty sure David was trying to state that the expressions in the VALUES list are evaluated in the order the columns appear in the table and not in the order they appear in your INSERT statement.

In his example he expected to have the following results:
a0 | a1 | a2 | a3
---+----+----+----
3 | 4 | 2 | 1

But instead he got
a0 | a1 | a2 | a3
---+----+----+----
1 | 2 | 3 | 4


April 25, 2006, 2:08 p.m.

Useful tip for faster INSERTs:
You can use the INSERT INTO tbl &lt;query&gt; syntax to accelerate the speed of inserts by batching them together. For example...

INSERT INTO my_table SELECT 1, 'a' UNION SELECT 2, 'b' UNION SELECT 3, 'c' UNION ...

If you batch up many sets of values per INSERT statement and batch up multiple INSERT statements per transaction, you can achieve significantly faster insertion performance. I managed to achieve almost 8x faster inserts on a PostgreSQL 8.1 / Win2K installation by batching up 100 (small) using this technique.

If anyone knows a faster/more elegant way to construct the row set than using SELECT..UNION then please let me know!

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group