6.2 INSERT
Used forInserting rows of data into a table
Available inDSQL, ESQL, PSQL
Syntax
INSERT INTO target
{ DEFAULT VALUES
| [(<column_list>)] [<override_opt>] <value_source> }
[RETURNING <returning_list> [INTO <variables>]]
<column_list> ::= col_name [, col_name ...]
<override_opt> ::=
OVERRIDING {USER | SYSTEM} VALUE
<value_source> ::= VALUES (<value_list>) | <select_stmt>
<value_list> ::= <ins_value> [, <ins_value> ...]
<ins_value> :: = <value_expression> | DEFAULT
<returning_list> ::= * | <output_column> [, <output_column]
<output_column> ::=
target.*
| <return_expression> [COLLATE collation] [[AS] alias]
<return_expression> ::=
<value_expression>
| [target.]col_name
<value_expression> ::=
<literal>
| <context-variable>
| any other expression returning a single
value of a Firebird data type or NULL
<variables> ::= [:]varname [, [:]varname ...]
Table 6.2.1 Arguments for the INSERT
Statement Parameters
Argument | Description |
---|---|
target | The name of the table or view to which a new row, or batch of rows, should be added |
col_name | Name of a table or view column |
value_expression | An expression whose value is used for inserting into the table or for returning |
return_expression | The expression to be returned in the |
literal | A literal |
context-variable | Context variable |
varname | Name of a PSQL local variable |
The INSERT
statement is used to add rows to a table or to one or more tables underlying a view:
If the column values are supplied in a
VALUES
clause, exactly one row is insertedThe values may be provided instead by a
SELECT
expression, in which case zero to many rows may be insertedWith the
DEFAULT VALUES
clause, no values are provided at all and exactly one row is inserted.
Restrictions
Columns returned to the
NEW.*column_name*
context variables in triggers should not have a colon (:
) prefixed to their namesNo column may appear more than once in the column list.
ALERT : BEFORE INSERT
Triggers
Regardless of the method used for inserting rows, be mindful of any columns in the target table or view that are populated by BEFORE INSERT
triggers, such as primary keys and case-insensitive search columns. Those columns should be excluded from both the column_list and the VALUES
list if, as they should, the triggers test the NEW.*column_name*
for NULL
.
6.2.1 INSERT … VALUES
The VALUES
list must provide a value for every column in the column list, in the same order and of the correct type. The column list need not specify every column in the target but, if the column list is absent, the engine requires a value for every column in the table or view (computed columns excluded).
The value DEFAULT
allows a column to be specified in the column list, but instructs Firebird to use the default value (either NULL
or the value specified in the DEFAULT
clause of the column definition). For identity columns, specifying DEFAULT
will generate the identity value. It is possible to include calculated columns in the column list and specifying DEFAULT
as the column value.
Note
Introducer syntax provides a way to identify the character set of a value that is a string constant (literal). Introducer syntax works only with literal strings: it cannot be applied to string variables, parameters, column references or values that are expressions.
Examples
INSERT INTO cars (make, model, year)
VALUES ('Ford', 'T', 1908);
INSERT INTO cars
VALUES ('Ford', 'T', 1908, 'USA', 850);
-- notice the '_' prefix (introducer syntax)
INSERT INTO People
VALUES (_ISO8859_1 'Hans-Jörg Schäfer');
6.2.2 INSERT … SELECT
For this method of inserting, the output columns of the SELECT
statement must provide a value for every target column in the column list, in the same order and of the correct type.
Literal values, context variables or expressions of compatible type can be substituted for any column in the source row. In this case, a source column list and a corresponding VALUES
list are required.
If the column list is absent — as it is when SELECT *
is used for the source expression — the column_list must contain the names of every column in the target table or view (computed columns excluded).
Examples
INSERT INTO cars (make, model, year)
SELECT make, model, year
FROM new_cars;
INSERT INTO cars
SELECT * FROM new_cars;
INSERT INTO Members (number, name)
SELECT number, name FROM NewMembers
WHERE Accepted = 1
UNION ALL
SELECT number, name FROM SuspendedMembers
WHERE Vindicated = 1
INSERT INTO numbers(num)
WITH RECURSIVE r(n) as (
SELECT 1 FROM rdb$database
UNION ALL
SELECT n+1 FROM r WHERE n < 100
)
SELECT n FROM r
Of course, the column names in the source table need not be the same as those in the target table. Any type of SELECT
statement is permitted, as long as its output columns exactly match the insert columns in number, order and type. Types need not be exactly the same, but they must be assignment-compatible.
Important
When using and INSERT … SELECT
with a RETURNING
clause, the SELECT
has to produce at most one row, as RETURNING
currently only works for statements affecting at most one row.
This behaviour may change in future Firebird versions.
6.2.3 INSERT … DEFAULT VALUES
The DEFAULT VALUES
clause allows insertion of a record without providing any values at all, either directly or from a SELECT
statement. This is only possible if every NOT NULL
or CHECK
ed column in the table either has a valid default declared or gets such a value from a BEFORE INSERT
trigger. Furthermore, triggers providing required field values must not depend on the presence of input values.
Specifying DEFAULT VALUES
is equivalent to specifying a values list with value DEFAULT
for all columns.
Example
INSERT INTO journal
DEFAULT VALUES
RETURNING entry_id;
6.2.4 OVERRIDING
The OVERRIDING
clause controls the behaviour of an identity column for this statement only.
OVERRIDING SYSTEM VALUE
The user-provided value for the identity column is used, and no value is generated using the identity. In other words, for this insert, the identity will behave as if it is GENERATED BY DEFAULT
. This option can only be specified for tables with a GENERATED ALWAYS AS IDENTITY
column.
This can be useful when merging or importing data from another source. After such an insert, it may be necessary to change the next value of the identity sequence using ALTER TABLE to prevent subsequent inserts from generating colliding identity values.
OVERRIDING USER VALUE
The user-provided value for the identity column is ignored, and the column value is generated using the identity. In other words, for this insert, the identity will behave as if it is GENERATED ALWAYS
, while allowing the identity column in the column-list. This option can only be specified for tables with a GENERATED BY DEFAULT AS IDENTITY
column.
It is usually simpler to leave out the identity column to achieve the same effect.
Examples of OVERRIDING
-- for GENERATED ALWAYS AS IDENTITY
-- value 11 is used anyway
insert into objects_always (id, name)
OVERRIDING SYSTEM VALUE values (11, 'Laptop');
-- for GENERATED BY DEFAULT AS IDENTITY
-- value 12 is not used
insert into objects_default (id, name)
OVERRIDING USER VALUE values (12, 'Laptop');
6.2.5 The RETURNING
Clause
An INSERT
statement adding at most one row may optionally include a RETURNING
clause in order to return values from the inserted row. The clause, if present, need not contain all of the insert columns and may also contain other columns or expressions. The returned values reflect any changes that may have been made in BEFORE INSERT
triggers.
The user executing the statement needs to have SELECT
privileges on the columns specified in the RETURNING
clause.
The syntax of the returning_list is similar to the column list of a SELECT
clause. It is possible to reference all columns using *
or *table_name*.*
.
The optional INTO
sub-clause is only valid in PSQL.
Multiple INSERT
s
In DSQL, a statement with RETURNING
always returns only one row. If the RETURNING
clause is specified and more than one row is inserted by the INSERT
statement, the statement fails and an error message is returned. This behaviour may change in future Firebird versions.
Examples
INSERT INTO Scholars (firstname, lastname, address,
phone, email)
VALUES ('Henry', 'Higgins', '27A Wimpole Street',
'3231212', NULL)
RETURNING lastname, fullname, id;
INSERT INTO Scholars (firstname, lastname, address,
phone, email)
VALUES (
'Henry', 'Higgins', '27A Wimpole Street',
'3231212', NULL)
RETURNING *;
INSERT INTO Dumbbells (firstname, lastname, iq)
SELECT fname, lname, iq
FROM Friends
ORDER BY iq ROWS 1
RETURNING id, firstname, iq
INTO :id, :fname, :iq;
Note
RETURNING
is supported forVALUES
andDEFAULT VALUES
inserts, and singletonSELECT
inserts.In DSQL, a statement with a
RETURNING
clause always returns exactly one row. If no record was actually inserted, the fields in this row are allNULL
. This behaviour may change in a later version of Firebird. In PSQL, if no row was inserted, nothing is returned, and the target variables keep their existing values.
6.2.6 Inserting into BLOB
columns
Inserting into BLOB
columns is only possible under the following circumstances:
The client application has made special provisions for such inserts, using the Firebird API. In this case, the modus operandi is application-specific and outside the scope of this manual.
The value inserted is a string literal of no more than 65,533 bytes (64KB - 3).
Note
A limit, in characters, is calculated at run-time for strings that are in multi-byte character sets, to avoid overrunning the bytes limit. For example, for a UTF8 string (max. 4 bytes/character), the run-time limit is likely to be about (floor(65533/4)) = 16383 characters.
You are using the
INSERT … SELECT
form and one or more columns in the result set areBLOB
s.