1INSERT(7)                        SQL Commands                        INSERT(7)
2
3
4

NAME

6       INSERT - create new rows in a table
7
8

SYNOPSIS

10       INSERT INTO table [ ( column [, ...] ) ]
11           { DEFAULT VALUES | VALUES ( { expression | DEFAULT } [, ...] ) [, ...] | query }
12           [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
13
14

DESCRIPTION

16       INSERT  inserts new rows into a table.  One can insert one or more rows
17       specified by value expressions, or zero or more rows resulting  from  a
18       query.
19
20       The  target column names can be listed in any order. If no list of col‐
21       umn names is given at all, the default is all the columns of the  table
22       in their declared order; or the first N column names, if there are only
23       N columns supplied by the VALUES clause or query. The  values  supplied
24       by  the  VALUES  clause  or  query  are associated with the explicit or
25       implicit column list left-to-right.
26
27       Each column not present in the explicit or implicit column list will be
28       filled  with a default value, either its declared default value or null
29       if there is none.
30
31       If the expression for any column is not of the correct data type, auto‐
32       matic type conversion will be attempted.
33
34       The  optional  RETURNING  clause  causes  INSERT  to compute and return
35       value(s) based on each row actually inserted.  This is primarily useful
36       for  obtaining  values that were supplied by defaults, such as a serial
37       sequence number. However, any expression using the table's  columns  is
38       allowed.  The  syntax of the RETURNING list is identical to that of the
39       output list of SELECT.
40
41       You must have INSERT privilege on a table in order to insert  into  it.
42       If  a  column  list is specified, you only need INSERT privilege on the
43       listed columns.  Use of the RETURNING clause requires SELECT  privilege
44       on  all columns mentioned in RETURNING.  If you use the query clause to
45       insert rows from a query, you of course need to have  SELECT  privilege
46       on any table or column used in the query.
47

PARAMETERS

49       table  The name (optionally schema-qualified) of an existing table.
50
51       column The name of a column in table.  The column name can be qualified
52              with a subfield name or array subscript, if  needed.  (Inserting
53              into  only  some  fields  of a composite column leaves the other
54              fields null.)
55
56       DEFAULT VALUES
57              All columns will be filled with their default values.
58
59       expression
60              An expression or value to assign to the corresponding column.
61
62       DEFAULT
63              The corresponding column will be filled with its default value.
64
65       query  A  query  (SELECT  statement)  that  supplies  the  rows  to  be
66              inserted.  Refer  to  the  SELECT  [select(7)]  statement  for a
67              description of the syntax.
68
69       output_expression
70              An expression to be computed and returned by the INSERT  command
71              after  each  row  is inserted. The expression can use any column
72              names of the table.  Write  *  to  return  all  columns  of  the
73              inserted row(s).
74
75       output_name
76              A name to use for a returned column.
77

OUTPUTS

79       On  successful  completion,  an INSERT command returns a command tag of
80       the form
81
82       INSERT oid count
83
84       The count is the number of rows inserted. If count is exactly one,  and
85       the target table has OIDs, then oid is the OID assigned to the inserted
86       row. Otherwise oid is zero.
87
88       If the INSERT command contains a RETURNING clause, the result  will  be
89       similar to that of a SELECT statement containing the columns and values
90       defined in the RETURNING list, computed over the row(s) inserted by the
91       command.
92

EXAMPLES

94       Insert a single row into table films:
95
96       INSERT INTO films VALUES
97           ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes');
98
99
100       In  this  example, the len column is omitted and therefore it will have
101       the default value:
102
103       INSERT INTO films (code, title, did, date_prod, kind)
104           VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');
105
106
107       This example uses the DEFAULT clause for the date columns  rather  than
108       specifying a value:
109
110       INSERT INTO films VALUES
111           ('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes');
112       INSERT INTO films (code, title, did, date_prod, kind)
113           VALUES ('T_601', 'Yojimbo', 106, DEFAULT, 'Drama');
114
115
116       To insert a row consisting entirely of default values:
117
118       INSERT INTO films DEFAULT VALUES;
119
120
121       To insert multiple rows using the multirow VALUES syntax:
122
123       INSERT INTO films (code, title, did, date_prod, kind) VALUES
124           ('B6717', 'Tampopo', 110, '1985-02-10', 'Comedy'),
125           ('HG120', 'The Dinner Game', 140, DEFAULT, 'Comedy');
126
127
128       This  example inserts some rows into table films from a table tmp_films
129       with the same column layout as films:
130
131       INSERT INTO films SELECT * FROM tmp_films WHERE date_prod < '2004-05-07';
132
133
134       This example inserts into array columns:
135
136       -- Create an empty 3x3 gameboard for noughts-and-crosses
137       INSERT INTO tictactoe (game, board[1:3][1:3])
138           VALUES (1, '{{" "," "," "},{" "," "," "},{" "," "," "}}');
139       -- The subscripts in the above example aren't really needed
140       INSERT INTO tictactoe (game, board)
141           VALUES (2, '{{X," "," "},{" ",O," "},{" ",X," "}}');
142
143
144       Insert a single row into table  distributors,  returning  the  sequence
145       number generated by the DEFAULT clause:
146
147       INSERT INTO distributors (did, dname) VALUES (DEFAULT, 'XYZ Widgets')
148          RETURNING did;
149
150

COMPATIBILITY

152       INSERT  conforms  to the SQL standard, except that the RETURNING clause
153       is a PostgreSQL extension. Also, the case in which a column  name  list
154       is  omitted,  but not all the columns are filled from the VALUES clause
155       or query, is disallowed by the standard.
156
157       Possible limitations of the query clause are  documented  under  SELECT
158       [select(7)].
159
160
161
162SQL - Language Statements         2014-02-17                         INSERT(7)
Impressum