INSERT
Applies to: Databricks SQL Databricks Runtime
Inserts new rows into a table and optionally truncates the table or partitions. You specify the inserted rows by value expressions or the result of a query.
Databricks does not support INSERT
for Hive Avro tables if the timestamp-millis
type is present in the table schema.
Syntax
INSERT { OVERWRITE | INTO } [ TABLE ] table_name
[ PARTITION clause ]
[ ( column_name [, ...] ) | BY NAME ]
query
INSERT INTO [ TABLE ] table_name
REPLACE WHERE predicate
query
Note
When you INSERT INTO
a Delta table, schema enforcement and evolution is supported.
If a column’s data type cannot be safely cast to a Delta table’s data type, a runtime exception is thrown.
If schema evolution is enabled, new columns can exist as the last columns of your schema (or nested columns) for the schema to evolve.
Parameters
INTO
orOVERWRITE
If you specify
OVERWRITE
the following applies:Without a
partition_spec
the table is truncated before inserting the first row.Otherwise, all partitions matching the
partition_spec
are truncated before inserting the first row.
If you specify
INTO
all rows inserted are additive to the existing rows.-
Identifies the table to be inserted to. The name must not include a temporal specification. If the table cannot be found Databricks raises a TABLE_OR_VIEW_NOT_FOUND error.
table_name
must not be a foreign table.Applies to: Databricks SQL Databricks Runtime 16.0 and later
table_name
may include an options specification. -
An optional parameter that specifies a target partition for the insert. You may also only partially specify the partition.
When specifying a static partition (
column = value
), this column must not be repeated in the insert column list.When specifying a dynamic partition for
INSERT OVERWRITE
, thetable_name
must be a Delta Lake table. ( column_name [, …] )
An optional list of columns in the table. The insert command may specify any particular column from the table at most once.
Applies to: Databricks SQL Databricks Runtime 12.2 LTS and above
If this command omits a column, Databricks SQL assigns the corresponding default value instead.
If the target table schema does not define any default value for the inserted column, Databricks SQL assigns
NULL
if the column is nullable. Otherwise, Databricks SQL raises an error.
Providing no column list is equivalent to specifying all columns, except for those with assigned values in the
PARTITION
clause, in the order defined in the table.BY NAME
Applies to: Databricks SQL Databricks Runtime 13.3 LTS and above
When this clause is used instead of an explicit column list, the command uses the exposed column names of
query
to produce the column list in the order ofquery
. As with an explicit column list, each column must exist in the target table, and must not be duplicated. If a column present intable_name
is not part of the implied column list theDEFAULT
value is used instead.BY NAME
also matches attributes of structs by name.No column in
query
may match a column specified in thePARTITION
clause or any column that is generated.REPLACE WHERE boolean_expression
Applies to: Databricks SQL Databricks Runtime 12.2 LTS and above
If
table_name
is a Delta Lake table, delete rows matchingboolean_expression
before inserting any rows matchingboolean-expression
specified inquery
. Rows inquery
which do not matchboolean_expression
are ignored.boolean_expression
can be any expression that evaluates to a result typeBOOLEAN
.-
A query that produces the rows to be inserted.
You must match the number of columns returned by the query with the specified or implied insert column list.
If a data type cannot be safely cast to the matching column data type, a runtime exception is thrown.
Applies to: Databricks SQL Databricks Runtime 11.3 LTS and above
If
query
consists of a VALUES clause theexpression
can beDEFAULT
.If
query
consists of a SELECT clause thenamed_expression
can beDEFAULT
.DEFAULT
will insert the explicitly definedDEFAULT
expression of the corresponding column intable_name
, orNULL
if none is defined.
If schema evolution is enabled, new columns can exist as the last columns of your schema (or nested columns) for the schema to evolve.
Examples
In this section:
INSERT INTO
INSERT using VALUES
> CREATE TABLE students (name VARCHAR(64), address VARCHAR(64) DEFAULT 'unknown', student_id INT)
PARTITIONED BY (student_id);
-- Single row insert using a `VALUES` clause specifying all columns.
> INSERT INTO students VALUES
('Amy Smith', '123 Park Ave, San Jose', 111111);
-- Single row insert using an implicit default for address
> INSERT INTO students(name, student_id) VALUES('Grayson Miller', 222222);
-- Single row insert using an explicit DEFAULT keyword for address
> INSERT INTO students VALUES('Youna Kim', DEFAULT, 333333);
-- Multi-row insert using a `VALUES` clause
> INSERT INTO students VALUES
('Bob Brown', '456 Taylor St, Cupertino', 444444),
('Cathy Johnson', '789 Race Ave, Palo Alto', 555555);
-- Multi-row insert using a mix of DEFAULT and literals
> INSERT INTO students VALUES
('Gwyneth Zhao', '120 Main St, Rockport', 666666),
('Jackson Peterson', DEFAULT, 777777);
> SELECT * FROM students;
name address student_id
---------------- ------------------------ ----------
Amy Smith 123 Park Ave, San Jose 111111
Grayson Miller unknown 222222
Youna Kim unknown 333333
Bob Brown 456 Taylor St, Cupertino 444444
Cathy Johnson 789 Race Ave, Palo Alto 555555
Gwyneth Zhao 120 Main St, Rockport 666666
Jackson Peterson unknown 777777
Insert using a subquery
-- Assuming the persons table has already been created and populated.
> SELECT * FROM persons;
name address ssn
------------- ------------------------- ---------
Dora Williams 134 Forest Ave, Melo Park 123456789
Eddie Davis 245 Market St, Milpitas 345678901
> INSERT INTO students PARTITION (student_id = 444444)
SELECT name, address FROM persons WHERE name = "Dora Williams";
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Amy Smith 123 Park Ave, San Jose 111111
Bob Brown 456 Taylor St, Cupertino 222222
Cathy Johnson 789 Race Ave, Palo Alto 333333
Dora Williams 134 Forest Ave, Melo Park 444444
-- Use an option specification to influence the write behavior
INSERT INTO t WITH ('write.split-size' = 10) SELECT * FROM s;
Insert using a TABLE
clause
-- Assuming the visiting_students table has already been created and populated.
> SELECT * FROM visiting_students;
name address student_id
------------- --------------------- ----------
Fleur Laurent 345 Copper St, London 777777
Gordon Martin 779 Lake Ave, Oxford 888888
> INSERT INTO students TABLE visiting_students;
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Amy Smith 123 Park Ave,San Jose 111111
Bob Brown 456 Taylor St, Cupertino 222222
Cathy Johnson 789 Race Ave, Palo Alto 333333
Dora Williams 134 Forest Ave, Melo Park 444444
Fleur Laurent 345 Copper St, London 777777
Gordon Martin 779 Lake Ave, Oxford 888888
Insert into a directory
> CREATE TABLE students (name VARCHAR(64), address VARCHAR(64), student_id INT)
PARTITIONED BY (student_id)
LOCATION "/path/to/students_table";
> INSERT INTO delta.`/path/to/students_table` VALUES
('Amy Smith', '123 Park Ave, San Jose', 111111);
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Amy Smith 123 Park Ave, San Jose 111111
Insert with a column list
> INSERT INTO students (address, name, student_id) VALUES
('Hangzhou, China', 'Kent Yao', 11215016);
> SELECT * FROM students WHERE name = 'Kent Yao';
name address student_id
--------- ---------------------- ----------
Kent Yao Hangzhou, China 11215016
Insert with both a partition spec and a column list
> INSERT INTO students PARTITION (student_id = 11215017) (address, name) VALUES
('Hangzhou, China', 'Kent Yao Jr.');
> SELECT * FROM students WHERE student_id = 11215017;
name address student_id
------------ ---------------------- ----------
Kent Yao Jr. Hangzhou, China 11215017
INSERT using the BY NAME clause
> CREATE TABLE target(n INT, text STRING, s STRUCT<a INT, b INT>);
> INSERT INTO target BY NAME SELECT named_struct('b', 2, 'a', 1) AS s, 0 AS n, 'data' AS text;
> SELECT * FROM target;
0 data {"a":1,"b":2}
> CREATE OR REPLACE TABLE target(n INT, arr ARRAY<STRUCT<a INT, b INT>>);
> INSERT INTO target BY NAME SELECT array(named_struct('b', 2, 'a', 1)) AS arr, 0 AS n;
> INSERT INTO target BY NAME SELECT array(named_struct('b', 2, 'a', 1)) AS arr;
> SELECT * FROM target;
0 [{"a":1,"b":2}]
NULL [{"a":1,"b":2}]
> INSERT INTO target BY NAME SELECT array(named_struct('b', 2, 'a', 1)) AS arr, 0 AS badname;
Error
> INSERT INTO target BY NAME SELECT array(named_struct('b', 2, 'a', 1)) AS arr, 0 AS n, 1 AS n;
Error: INSERT_COLUMN_ARITY_MISMATCH.TOO_MANY_DATA_COLUMNS
REPLACE WHERE
> CREATE TABLE sales(tx_date DATE, amount INTEGER);
> INSERT INTO sales VALUES
(DATE'2022-10-01', 1234),
(DATE'2022-10-02', 2345),
(DATE'2022-10-03', 3456),
(DATE'2022-11-01', 3214);
-- Replace any rows with a transaction date in October 2022.
> INSERT INTO sales REPLACE WHERE tx_date BETWEEN '2022-10-01' AND '2022-10-31'
VALUES (DATE'2022-10-01', 1237),
(DATE'2022-10-02', 2378),
(DATE'2022-10-04', 2456),
(DATE'2022-10-05', 6328);
> SELECT * FROM sales ORDER BY tx_date;
tx_date amount
---------- ------
2022-10-01 1237
2022-10-02 2378
2022-10-04 2456
2022-10-05 6328
2022-11-01 3214
INSERT OVERWRITE
Insert using a VALUES
clause
-- Assuming the students table has already been created and populated.
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Amy Smith 123 Park Ave, San Jose 111111
Bob Brown 456 Taylor St, Cupertino 222222
Cathy Johnson 789 Race Ave, Palo Alto 333333
Dora Williams 134 Forest Ave, Melo Park 444444
Fleur Laurent 345 Copper St, London 777777
Gordon Martin 779 Lake Ave, Oxford 888888
Helen Davis 469 Mission St, San Diego 999999
Jason Wang 908 Bird St, Saratoga 121212
> INSERT OVERWRITE students VALUES
('Ashua Hill', '456 Erica Ct, Cupertino', 111111),
('Brian Reed', '723 Kern Ave, Palo Alto', 222222);
> SELECT * FROM students;
name address student_id
---------- ----------------------- ----------
Ashua Hill 456 Erica Ct, Cupertino 111111
Brian Reed 723 Kern Ave, Palo Alto 222222
Insert using a subquery
-- Assuming the persons table has already been created and populated.
> SELECT * FROM persons;
name address ssn
------------- ------------------------- ---------
Dora Williams 134 Forest Ave, Melo Park 123456789
Eddie Davis 245 Market St,Milpitas 345678901
> INSERT OVERWRITE students PARTITION (student_id = 222222)
SELECT name, address FROM persons WHERE name = "Dora Williams";
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Ashua Hill 456 Erica Ct, Cupertino 111111
Dora Williams 134 Forest Ave, Melo Park 222222
Insert using a TABLE
clause
-- Assuming the visiting_students table has already been created and populated.
> SELECT * FROM visiting_students;
name address student_id
------------- --------------------- ----------
Fleur Laurent 345 Copper St, London 777777
Gordon Martin 779 Lake Ave, Oxford 888888
> INSERT OVERWRITE students TABLE visiting_students;
> SELECT * FROM students;
name address student_id
------------- --------------------- ----------
Fleur Laurent 345 Copper St, London 777777
Gordon Martin 779 Lake Ave, Oxford 888888
Insert overwrite a directory
> CREATE TABLE students (name VARCHAR(64), address VARCHAR(64), student_id INT)
PARTITIONED BY (student_id)
LOCATION "/path/to/students_table";
> INSERT OVERWRITE delta.`/path/to/students_table` VALUES
('Amy Smith', '123 Park Ave, San Jose', 111111);
> SELECT * FROM students;
name address student_id
------------- ------------------------- ----------
Amy Smith 123 Park Ave, San Jose 111111