INSERT Statement INSERT

INSERT statement Impala supports inserting into tables and partitions that you create with the Impala CREATE TABLE statement, or pre-defined tables and partitions created through Hive.

[with_clause] INSERT { INTO | OVERWRITE } [TABLE] table_name [(column_list)] [ PARTITION (partition_clause)] { [hint_clause] select_statement | VALUES (value [, value ...]) [, (value [, value ...]) ...] } partition_clause ::= col_name [= constant] [, col_name [= constant] ...] hint_clause ::= hint_with_dashes | hint_with_cstyle_delimiters | hint_with_brackets hint_with_dashes ::= -- +SHUFFLE | -- +NOSHUFFLE -- +CLUSTERED hint_with_cstyle_comments ::= /* +SHUFFLE */ | /* +NOSHUFFLE */ | /* +CLUSTERED */ hint_with_brackets ::= [SHUFFLE] | [NOSHUFFLE] (With this hint format, the square brackets are part of the syntax.)

Appending or replacing (INTO and OVERWRITE clauses):

The INSERT INTO syntax appends data to a table. The existing data files are left as-is, and the inserted data is put into one or more new data files.

The INSERT OVERWRITE syntax replaces the data in a table. Currently, the overwritten data files are deleted immediately; they do not go through the HDFS trash mechanism.

The INSERT statement currently does not support writing data files containing complex types (ARRAY, STRUCT, and MAP). To prepare Parquet data for such tables, you generate the data files outside Impala and then use LOAD DATA or CREATE EXTERNAL TABLE to associate those data files with the table. Currently, such tables must use the Parquet file format. See for details about working with complex types.

Kudu tables require a unique primary key for each row. If an INSERT statement attempts to insert a row with the same values for the primary key columns as an existing row, that row is discarded and the insert operation continues. When rows are discarded due to duplicate primary keys, the statement finishes with a warning, not an error. (This is a change from early releases of Kudu where the default was to return in error in such cases, and the syntax INSERT IGNORE was required to make the statement succeed. The IGNORE clause is no longer part of the INSERT syntax.)

For situations where you prefer to replace rows with duplicate primary key values, rather than discarding the new data, you can use the UPSERT statement instead of INSERT. UPSERT inserts rows that are entirely new, and for rows that match an existing primary key in the table, the non-primary-key columns are updated to reflect the values in the upserted data.

If you really want to store new rows, not replace existing ones, but cannot do so because of the primary key uniqueness constraint, consider recreating the table with additional columns included in the primary key.

See for more details about using Impala with Kudu.

Impala currently supports:

  • Insert commands that partition or add files result in changes to Hive metadata. Because Impala uses Hive metadata, such changes may necessitate a metadata refresh. For more information, see the REFRESH function.
  • Currently, Impala can only insert data into tables that use the text and Parquet formats. For other file formats, insert the data using Hive and use Impala to query it.
  • As an alternative to the INSERT statement, if you have existing data files elsewhere in HDFS, the LOAD DATA statement can move those files into a table. This statement works with tables of any file format.

When you insert the results of an expression, particularly of a built-in function call, into a small numeric column such as INT, SMALLINT, TINYINT, or FLOAT, you might need to use a CAST() expression to coerce values into the appropriate type. Impala does not automatically convert from a larger type to a smaller one. For example, to insert cosine values into a FLOAT column, write CAST(COS(angle) AS FLOAT) in the INSERT statement to make the conversion explicit.

Because Impala can read certain file formats that it cannot write, the INSERT statement does not work for all kinds of Impala tables. See for details about what file formats are supported by the INSERT statement.

The following example sets up new tables with the same definition as the TAB1 table from the Tutorial section, using different file formats, and demonstrates inserting data into the tables created with the STORED AS TEXTFILE and STORED AS PARQUET clauses:

CREATE DATABASE IF NOT EXISTS file_formats; USE file_formats; DROP TABLE IF EXISTS text_table; CREATE TABLE text_table ( id INT, col_1 BOOLEAN, col_2 DOUBLE, col_3 TIMESTAMP ) STORED AS TEXTFILE; DROP TABLE IF EXISTS parquet_table; CREATE TABLE parquet_table ( id INT, col_1 BOOLEAN, col_2 DOUBLE, col_3 TIMESTAMP ) STORED AS PARQUET;

With the INSERT INTO TABLE syntax, each new set of inserted rows is appended to any existing data in the table. This is how you would record small amounts of data that arrive continuously, or ingest new batches of data alongside the existing data. For example, after running 2 INSERT INTO TABLE statements with 5 rows each, the table contains 10 rows total:

[localhost:21000] > insert into table text_table select * from default.tab1; Inserted 5 rows in 0.41s [localhost:21000] > insert into table text_table select * from default.tab1; Inserted 5 rows in 0.46s [localhost:21000] > select count(*) from text_table; +----------+ | count(*) | +----------+ | 10 | +----------+ Returned 1 row(s) in 0.26s

With the INSERT OVERWRITE TABLE syntax, each new set of inserted rows replaces any existing data in the table. This is how you load data to query in a data warehousing scenario where you analyze just the data for a particular day, quarter, and so on, discarding the previous data each time. You might keep the entire set of data in one raw table, and transfer and transform certain rows into a more compact and efficient form to perform intensive analysis on that subset.

For example, here we insert 5 rows into a table using the INSERT INTO clause, then replace the data by inserting 3 rows with the INSERT OVERWRITE clause. Afterward, the table only contains the 3 rows from the final INSERT statement.

[localhost:21000] > insert into table parquet_table select * from default.tab1; Inserted 5 rows in 0.35s [localhost:21000] > insert overwrite table parquet_table select * from default.tab1 limit 3; Inserted 3 rows in 0.43s [localhost:21000] > select count(*) from parquet_table; +----------+ | count(*) | +----------+ | 3 | +----------+ Returned 1 row(s) in 0.43s

The VALUES clause lets you insert one or more rows by specifying constant values for all the columns. The number, types, and order of the expressions must match the table definition.

The INSERT ... VALUES technique is not suitable for loading large quantities of data into HDFS-based tables, because the insert operations cannot be parallelized, and each one produces a separate data file. Use it for setting up small dimension tables or tiny amounts of data for experimenting with SQL syntax, or with HBase tables. Do not use it for large ETL jobs or benchmark tests for load operations. Do not run scripts with thousands of INSERT ... VALUES statements that insert a single row each time. If you do run INSERT ... VALUES operations to load data into a staging table as one stage in an ETL pipeline, include multiple row values if possible within each VALUES clause, and use a separate database to make cleanup easier if the operation does produce many tiny files.

The following example shows how to insert one row or multiple rows, with expressions of different types, using literal values, expressions, and function return values:

create table val_test_1 (c1 int, c2 float, c3 string, c4 boolean, c5 timestamp); insert into val_test_1 values (100, 99.9/10, 'abc', true, now()); create table val_test_2 (id int, token string); insert overwrite val_test_2 values (1, 'a'), (2, 'b'), (-1,'xyzzy');

These examples show the type of not implemented error that you see when attempting to insert data into a table with a file format that Impala currently does not write to:

DROP TABLE IF EXISTS sequence_table; CREATE TABLE sequence_table ( id INT, col_1 BOOLEAN, col_2 DOUBLE, col_3 TIMESTAMP ) STORED AS SEQUENCEFILE; DROP TABLE IF EXISTS rc_table; CREATE TABLE rc_table ( id INT, col_1 BOOLEAN, col_2 DOUBLE, col_3 TIMESTAMP ) STORED AS RCFILE; [localhost:21000] > insert into table rc_table select * from default.tab1; Remote error Backend 0:RC_FILE not implemented. [localhost:21000] > insert into table sequence_table select * from default.tab1; Remote error Backend 0:SEQUENCE_FILE not implemented.

Inserting data into partitioned tables requires slightly different syntax that divides the partitioning columns from the others:

create table t1 (i int) partitioned by (x int, y string); -- Select an INT column from another table. -- All inserted rows will have the same x and y values, as specified in the INSERT statement. -- This technique of specifying all the partition key values is known as static partitioning. insert into t1 partition(x=10, y='a') select c1 from some_other_table; -- Select two INT columns from another table. -- All inserted rows will have the same y value, as specified in the INSERT statement. -- Values from c2 go into t1.x. -- Any partitioning columns whose value is not specified are filled in -- from the columns specified last in the SELECT list. -- This technique of omitting some partition key values is known as dynamic partitioning. insert into t1 partition(x, y='b') select c1, c2 from some_other_table; -- Select an INT and a STRING column from another table. -- All inserted rows will have the same x value, as specified in the INSERT statement. -- Values from c3 go into t1.y. insert into t1 partition(x=20, y) select c1, c3 from some_other_table;

The following examples show how you can copy the data in all the columns from one table to another, copy the data from only some columns, or specify the columns in the select list in a different order than they actually appear in the table:

-- Start with 2 identical tables. create table t1 (c1 int, c2 int); create table t2 like t1; -- If there is no () part after the destination table name, -- all columns must be specified, either as * or by name. insert into t2 select * from t1; insert into t2 select c1, c2 from t1; -- With the () notation following the destination table name, -- you can omit columns (all values for that column are NULL -- in the destination table), and/or reorder the values -- selected from the source table. This is the "column permutation" feature. insert into t2 (c1) select c1 from t1; insert into t2 (c2, c1) select c1, c2 from t1; -- The column names can be entirely different in the source and destination tables. -- You can copy any columns, not just the corresponding ones, from the source table. -- But the number and type of selected columns must match the columns mentioned in the () part. alter table t2 replace columns (x int, y int); insert into t2 (y) select c1 from t1; -- For partitioned tables, all the partitioning columns must be mentioned in the () column list -- or a PARTITION clause; these columns cannot be defaulted to NULL. create table pt1 (x int, y int) partitioned by (z int); -- The values from c1 are copied into the column x in the new table, -- all in the same partition based on a constant value for z. -- The values of y in the new table are all NULL. insert into pt1 (x) partition (z=5) select c1 from t1; -- Again we omit the values for column y so they are all NULL. -- The inserted x values can go into different partitions, based on -- the different values inserted into the partitioning column z. insert into pt1 (x,z) select x, z from t2;

SELECT * for a partitioned table requires that all partition key columns in the source table be declared as the last columns in the CREATE TABLE statement. You still include a PARTITION BY clause listing all the partition key columns. These partition columns are automatically mapped to the last columns from the SELECT * list.

create table source (x int, y int, year int, month int, day int); create table destination (x int, y int) partitioned by (year int, month int, day int); ...load some data into the unpartitioned source table... -- Insert a single partition of data. -- The SELECT * means you cannot specify partition (year=2014, month, day). insert overwrite destination partition (year, month, day) select * from source where year=2014; -- Insert the data for all year/month/day combinations. insert overwrite destination partition (year, month, day) select * from source; -- If one of the partition columns is omitted from the source table, -- then you can specify a specific value for that column in the PARTITION clause. -- Here the source table holds only data from 2014, and so does not include a year column. create table source_2014 (x int, y int, month, day); ...load some data into the unpartitioned source_2014 table... insert overwrite destination partition (year=2014, month, day) select * from source_2014;

Concurrency considerations: Each INSERT operation creates new data files with unique names, so you can run multiple INSERT INTO statements simultaneously without filename conflicts. While data is being inserted into an Impala table, the data is staged temporarily in a subdirectory inside the data directory; during this period, you cannot issue queries against that table in Hive. If an INSERT operation fails, the temporary data file and the subdirectory could be left behind in the data directory. If so, remove the relevant subdirectory and any data files it contains manually, by issuing an hdfs dfs -rm -r command, specifying the full path of the work subdirectory, whose name ends in _dir.

VALUES Clause

The VALUES clause is a general-purpose way to specify the columns of one or more rows, typically within an INSERT statement.

The following examples illustrate:

  • How to insert a single row using a VALUES clause.
  • How to insert multiple rows using a VALUES clause.
  • How the row or rows from a VALUES clause can be appended to a table through INSERT INTO, or replace the contents of the table through INSERT OVERWRITE.
  • How the entries in a VALUES clause can be literals, function results, or any other kind of expression. See for the notation to use for literal values, especially for quoting and escaping conventions for strings. See and for other things you can include in expressions with the VALUES clause.
[localhost:21000] > describe val_example; Query: describe val_example Query finished, fetching results ... +-------+---------+---------+ | name | type | comment | +-------+---------+---------+ | id | int | | | col_1 | boolean | | | col_2 | double | | +-------+---------+---------+ [localhost:21000] > insert into val_example values (1,true,100.0); Inserted 1 rows in 0.30s [localhost:21000] > select * from val_example; +----+-------+-------+ | id | col_1 | col_2 | +----+-------+-------+ | 1 | true | 100 | +----+-------+-------+ [localhost:21000] > insert overwrite val_example values (10,false,pow(2,5)), (50,true,10/3); Inserted 2 rows in 0.16s [localhost:21000] > select * from val_example; +----+-------+-------------------+ | id | col_1 | col_2 | +----+-------+-------------------+ | 10 | false | 32 | | 50 | true | 3.333333333333333 | +----+-------+-------------------+

When used in an INSERT statement, the Impala VALUES clause can specify some or all of the columns in the destination table, and the columns can be specified in a different order than they actually appear in the table. To specify a different set or order of columns than in the table, use the syntax:

INSERT INTO destination (col_x, col_y, col_z) VALUES (val_x, val_y, val_z);

Any columns in the table that are not listed in the INSERT statement are set to NULL.

To use a VALUES clause like a table in other statements, wrap it in parentheses and use AS clauses to specify aliases for the entire object and any columns you need to refer to:

[localhost:21000] > select * from (values(4,5,6),(7,8,9)) as t; +---+---+---+ | 4 | 5 | 6 | +---+---+---+ | 4 | 5 | 6 | | 7 | 8 | 9 | +---+---+---+ [localhost:21000] > select * from (values(1 as c1, true as c2, 'abc' as c3),(100,false,'xyz')) as t; +-----+-------+-----+ | c1 | c2 | c3 | +-----+-------+-----+ | 1 | true | abc | | 100 | false | xyz | +-----+-------+-----+

For example, you might use a tiny table constructed like this from constant literals or function return values as part of a longer statement involving joins or UNION ALL.

Impala physically writes all inserted files under the ownership of its default user, typically impala. Therefore, this user must have HDFS write permission in the corresponding table directory.

The permission requirement is independent of the authorization performed by the Sentry framework. (If the connected user is not authorized to insert into a table, Sentry blocks that operation immediately, regardless of the privileges available to the impala user.) Files created by Impala are not owned by and do not inherit permissions from the connected user.

The number of data files produced by an INSERT statement depends on the size of the cluster, the number of data blocks that are processed, the partition key columns in a partitioned table, and the mechanism Impala uses for dividing the work in parallel. Do not assume that an INSERT statement will produce some particular number of output files. In case of performance issues with data written by Impala, check that the output files do not suffer from issues such as many tiny files or many tiny partitions. (In the Hadoop context, even files or partitions of a few tens of megabytes are considered tiny.)

You can use the INSERT statement with HBase tables as follows:

  • You can insert a single row or a small set of rows into an HBase table with the INSERT ... VALUES syntax. This is a good use case for HBase tables with Impala, because HBase tables are not subject to the same kind of fragmentation from many small insert operations as HDFS tables are.

  • You can insert any number of rows at once into an HBase table using the INSERT ... SELECT syntax.

  • If more than one inserted row has the same value for the HBase key column, only the last inserted row with that value is visible to Impala queries. You can take advantage of this fact with INSERT ... VALUES statements to effectively update rows one at a time, by inserting new rows with the same key values as existing rows. Be aware that after an INSERT ... SELECT operation copying from an HDFS table, the HBase table might contain fewer rows than were inserted, if the key column in the source table contained duplicate values.

  • You cannot INSERT OVERWRITE into an HBase table. New rows are always appended.

  • When you create an Impala or Hive table that maps to an HBase table, the column order you specify with the INSERT statement might be different than the order you declare with the CREATE TABLE statement. Behind the scenes, HBase arranges the columns based on how they are divided into column families. This might cause a mismatch during insert operations, especially if you use the syntax INSERT INTO hbase_table SELECT * FROM hdfs_table. Before inserting data, verify the column order by issuing a DESCRIBE statement for the table, and adjust the order of the select list in the INSERT statement.

See for more details about using Impala with HBase.

See for details about reading and writing S3 data with Impala.

See for details about reading and writing ADLS data with Impala.

The user ID that the impalad daemon runs under, typically the impala user, must have read permission for the files in the source directory of an INSERT ... SELECT operation, and write permission for all affected directories in the destination table. (An INSERT operation could write files to multiple different HDFS directories if the destination table is partitioned.) This user must also have write permission to create a temporary work directory in the top-level HDFS directory of the destination table. An INSERT OVERWRITE operation does not require write permission on the original data files in the table, only on the table directories themselves.