-
Notifications
You must be signed in to change notification settings - Fork 29k
[SPARK-28786][DOC][SQL]Document INSERT statement in SQL Reference #25525
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Closed
Closed
Changes from all commits
Commits
Show all changes
8 commits
Select commit
Hold shift + click to select a range
37b2685
[SPARK-28786][DOC][SQL]Document INSERT statement in SQL Reference
huaxingao a5733a2
fix a few problems
huaxingao 6fda06a
remove dynamic-partition-insert and fix a few issues
huaxingao 0b3fa02
fix a few issues
huaxingao e57c1a5
address comments
huaxingao 71778b7
address comments
huaxingao caacd58
make the paramters the same format as the ones in Document ALTER DATA…
huaxingao 43de251
change column names to lower case
huaxingao File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,209 @@ | ||
| --- | ||
| layout: global | ||
| title: INSERT INTO | ||
| displayTitle: INSERT INTO | ||
| license: | | ||
| Licensed to the Apache Software Foundation (ASF) under one or more | ||
| contributor license agreements. See the NOTICE file distributed with | ||
| this work for additional information regarding copyright ownership. | ||
| The ASF licenses this file to You under the Apache License, Version 2.0 | ||
| (the "License"); you may not use this file except in compliance with | ||
| the License. You may obtain a copy of the License at | ||
|
|
||
| http://www.apache.org/licenses/LICENSE-2.0 | ||
|
|
||
| Unless required by applicable law or agreed to in writing, software | ||
| distributed under the License is distributed on an "AS IS" BASIS, | ||
| WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
| See the License for the specific language governing permissions and | ||
| limitations under the License. | ||
| --- | ||
|
|
||
| ### Description | ||
|
|
||
| The `INSERT INTO` statement inserts new rows into a table. The inserted rows can be specified by value expressions or result from a query. | ||
|
|
||
| ### Syntax | ||
| {% highlight sql %} | ||
| INSERT INTO [ TABLE ] table_name | ||
| [ PARTITION ( partition_col_name [ = partition_col_val ] [ , ... ] ) ] | ||
| { { VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ] } | query } | ||
| {% endhighlight %} | ||
|
|
||
| ### Parameters | ||
| <dl> | ||
| <dt><code><em>table_name</em></code></dt> | ||
| <dd>The name of an existing table.</dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>PARTITION ( partition_col_name [ = partition_col_val ] [ , ... ] )</em></code></dt> | ||
| <dd>Specifies one or more partition column and value pairs. The partition value is optional.</dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ]</em></code></dt> | ||
| <dd>Specifies the values to be inserted. Either an explicitly specified value or a NULL can be inserted. A comma must be used to seperate each value in the clause. More than one set of values can be specified to insert multiple rows.</dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>query</em></code></dt> | ||
| <dd>A query that produces the rows to be inserted. It can be in one of following formats: | ||
| <ul> | ||
| <li>a <code>SELECT</code> statement</li> | ||
| <li>a <code>TABLE</code> statement</li> | ||
| <li>a <code>FROM</code> statement</li> | ||
| </ul> | ||
| </dd> | ||
| </dl> | ||
|
|
||
| ### Examples | ||
| #### Single Row Insert Using a VALUES Clause | ||
| {% highlight sql %} | ||
| CREATE TABLE students (name VARCHAR(64), address VARCHAR(64), student_id INT) | ||
| USING PARQUET PARTITIONED BY (student_id); | ||
|
|
||
| INSERT INTO students | ||
| VALUES ('Amy Smith', '123 Park Ave, San Jose', 111111); | ||
|
|
||
| SELECT * FROM students; | ||
|
|
||
| + -------------- + ------------------------------ + -------------- + | ||
| | name | address | student_id | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| | Amy Smith | 123 Park Ave, San Jose | 111111 | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| {% endhighlight %} | ||
|
|
||
| #### Multi-Row Insert Using a VALUES Clause | ||
| {% highlight sql %} | ||
| INSERT INTO students | ||
| VALUES ('Bob Brown', '456 Taylor St, Cupertino', 222222), | ||
| ('Cathy Johnson', '789 Race Ave, Palo Alto', 333333); | ||
|
|
||
| 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 | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| {% endhighlight %} | ||
|
|
||
| #### Insert Using a SELECT Statement | ||
| Assuming the `persons` table has already been created and populated. | ||
|
|
||
| {% highlight sql %} | ||
| 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 | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| {% endhighlight %} | ||
|
|
||
| #### Insert Using a TABLE Statement | ||
| Assuming the `visiting_students` table has already been created and populated. | ||
|
|
||
| {% highlight sql %} | ||
| 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 | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| {% endhighlight %} | ||
|
|
||
| #### Insert Using a FROM Statement | ||
| Assuming the `applicants` table has already been created and populated. | ||
|
|
||
| {% highlight sql %} | ||
| SELECT * FROM applicants; | ||
|
|
||
| + -------------- + ------------------------------ + -------------- + -------------- + | ||
| | name | address | student_id | qualified | | ||
| + -------------- + ------------------------------ + -------------- + -------------- + | ||
| | Helen Davis | 469 Mission St, San Diego | 999999 | true | | ||
| + -------------- + ------------------------------ + -------------- + -------------- + | ||
| | Ivy King | 367 Leigh Ave, Santa Clara | 101010 | false | | ||
| + -------------- + ------------------------------ + -------------- + -------------- + | ||
| | Jason Wang | 908 Bird St, Saratoga | 121212 | true | | ||
| + -------------- + ------------------------------ + -------------- + -------------- + | ||
|
|
||
| INSERT INTO students | ||
| FROM applicants SELECT name, address, id applicants WHERE qualified = true; | ||
|
|
||
| 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 | | ||
| + -------------- + ------------------------------ + -------------- + | ||
| {% endhighlight %} | ||
|
|
||
| Related Statements: | ||
| * [INSERT OVERWRITE statement](sql-ref-syntax-dml-insert-overwrite-table.html) | ||
| * [INSERT OVERWRITE DIRECTORY statement](sql-ref-syntax-dml-insert-overwrite-directory.html) | ||
| * [INSERT OVERWRITE DIRECTORY with Hive format statement](sql-ref-syntax-dml-insert-overwrite-directory-hive.html) | ||
87 changes: 87 additions & 0 deletions
87
docs/sql-ref-syntax-dml-insert-overwrite-directory-hive.md
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,87 @@ | ||
| --- | ||
| layout: global | ||
| title: INSERT OVERWRITE DIRECTORY with Hive format | ||
| displayTitle: INSERT OVERWRITE DIRECTORY with Hive format | ||
| license: | | ||
| Licensed to the Apache Software Foundation (ASF) under one or more | ||
| contributor license agreements. See the NOTICE file distributed with | ||
| this work for additional information regarding copyright ownership. | ||
| The ASF licenses this file to You under the Apache License, Version 2.0 | ||
| (the "License"); you may not use this file except in compliance with | ||
| the License. You may obtain a copy of the License at | ||
|
|
||
| http://www.apache.org/licenses/LICENSE-2.0 | ||
|
|
||
| Unless required by applicable law or agreed to in writing, software | ||
| distributed under the License is distributed on an "AS IS" BASIS, | ||
| WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
| See the License for the specific language governing permissions and | ||
| limitations under the License. | ||
| --- | ||
|
|
||
| ### Description | ||
| The `INSERT OVERWRITE DIRECTORY` with Hive format overwrites the existing data in the directory with the new values using Hive `SerDe`. | ||
| Hive support must be enabled to use this command. The inserted rows can be specified by value expressions or result from a query. | ||
|
|
||
| ### Syntax | ||
| {% highlight sql %} | ||
| INSERT OVERWRITE [ LOCAL ] DIRECTORY directory_path | ||
| [ ROW FORMAT row_format ] [ STORED AS file_format ] | ||
| { { VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ] } | query } | ||
| {% endhighlight %} | ||
|
|
||
| ### Parameters | ||
| <dl> | ||
| <dt><code><em>directory_path</em></code></dt> | ||
| <dd> | ||
| Specifies the destination directory. The <code>LOCAL</code> keyword is used to specify that the directory is on the local file system. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>row_format</em></code></dt> | ||
| <dd> | ||
| Specifies the row format for this insert. Valid options are <code>SERDE</code> clause and <code>DELIMITED</code> clause. <code>SERDE</code> clause can be used to specify a custom <code>SerDe</code> for this insert. Alternatively, <code>DELIMITED</code> clause can be used to specify the native <code>SerDe</code> and state the delimiter, escape character, null character, and so on. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>file_format</em></code></dt> | ||
| <dd> | ||
| Specifies the file format for this insert. Valid options are <code>TEXTFILE</code>, <code>SEQUENCEFILE</code>, <code>RCFILE</code>, <code>ORC</code>, <code>PARQUET</code>, and <code>AVRO</code>. You can also specify your own input and output format using <code>INPUTFORMAT</code> and <code>OUTPUTFORMAT</code>. <code>ROW FORMAT SERDE</code> can only be used with <code>TEXTFILE</code>, <code>SEQUENCEFILE</code>, or <code>RCFILE</code>, while <code>ROW FORMAT DELIMITED</code> can only be used with <code>TEXTFILE</code>. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ]</em></code></dt> | ||
| <dd> | ||
| Specifies the values to be inserted. Either an explicitly specified value or a NULL can be inserted. A comma must be used to seperate each value in the clause. More than one set of values can be specified to insert multiple rows. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>query</em></code></dt> | ||
| <dd>A query that produces the rows to be inserted. It can be in one of following formats: | ||
| <ul> | ||
| <li>a <code>SELECT</code> statement</li> | ||
| <li>a <code>TABLE</code> statement</li> | ||
| <li>a <code>FROM</code> statement</li> | ||
| </ul> | ||
| </dd> | ||
| </dl> | ||
|
|
||
| ### Examples | ||
| {% highlight sql %} | ||
| INSERT OVERWRITE LOCAL DIRECTORY '/tmp/destination' | ||
| STORED AS orc | ||
| SELECT * FROM test_table; | ||
|
|
||
| INSERT OVERWRITE LOCAL DIRECTORY '/tmp/destination' | ||
| ROW FORMAT DELIMITED FIELDS TERMINATED BY ',' | ||
| SELECT * FROM test_table; | ||
| {% endhighlight %} | ||
|
|
||
| Related Statements: | ||
| * [INSERT INTO statement](sql-ref-syntax-dml-insert-into.html) | ||
| * [INSERT OVERWRITE statement](sql-ref-syntax-dml-insert-overwrite-table.html) | ||
| * [INSERT OVERWRITE DIRECTORY statement](sql-ref-syntax-dml-insert-overwrite-directory.html) |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,85 @@ | ||
| --- | ||
| layout: global | ||
| title: INSERT OVERWRITE DIRECTORY | ||
| displayTitle: INSERT OVERWRITE DIRECTORY | ||
| license: | | ||
| Licensed to the Apache Software Foundation (ASF) under one or more | ||
| contributor license agreements. See the NOTICE file distributed with | ||
| this work for additional information regarding copyright ownership. | ||
| The ASF licenses this file to You under the Apache License, Version 2.0 | ||
| (the "License"); you may not use this file except in compliance with | ||
| the License. You may obtain a copy of the License at | ||
|
|
||
| http://www.apache.org/licenses/LICENSE-2.0 | ||
|
|
||
| Unless required by applicable law or agreed to in writing, software | ||
| distributed under the License is distributed on an "AS IS" BASIS, | ||
| WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
| See the License for the specific language governing permissions and | ||
| limitations under the License. | ||
| --- | ||
| ### Description | ||
| The `INSERT OVERWRITE DIRECTORY` statement overwrites the existing data in the directory with the new values using Spark native format. The inserted rows can be specified by value expressions or result from a query. | ||
|
|
||
| ### Syntax | ||
| {% highlight sql %} | ||
| INSERT OVERWRITE [ LOCAL ] DIRECTORY [ directory_path ] | ||
| USING file_format [ OPTIONS ( key = val [ , ... ] ) ] | ||
| { { VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ] } | query } | ||
| {% endhighlight %} | ||
|
|
||
| ### Parameters | ||
| <dl> | ||
| <dt><code><em>directory_path</em></code></dt> | ||
| <dd> | ||
| Specifies the destination directory. It can also be specified in <code>OPTIONS</code> using <code>path</code>. The <code>LOCAL</code> keyword is used to specify that the directory is on the local file system. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>file_format</em></code></dt> | ||
| <dd> | ||
| Specifies the file format to use for the insert. Valid options are <code>TEXT</code>, <code>CSV</code>, <code>JSON</code>, <code>JDBC</code>, <code>PARQUET</code>, <code>ORC</code>, <code>HIVE</code>, <code>DELTA</code>, <code>LIBSVM</code>, or a fully qualified class name of a custom implementation of <code>org.apache.spark.sql.sources.DataSourceRegister</code>. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>OPTIONS ( key = val [ , ... ] )</em></code></dt> | ||
| <dd>Specifies one or more table property key and value pairs.</dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ]</em></code></dt> | ||
| <dd> | ||
| Specifies the values to be inserted. Either an explicitly specified value or a NULL can be inserted. A comma must be used to seperate each value in the clause. More than one set of values can be specified to insert multiple rows. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| <dl> | ||
| <dt><code><em>query</em></code></dt> | ||
| <dd>A query that produces the rows to be inserted. It can be in one of following formats: | ||
| <ul> | ||
| <li>a <code>SELECT</code> statement</li> | ||
| <li>a <code>TABLE</code> statement</li> | ||
| <li>a <code>FROM</code> statement</li> | ||
| </ul> | ||
| </dd> | ||
| </dl> | ||
|
|
||
| ### Examples | ||
| {% highlight sql %} | ||
| INSERT OVERWRITE DIRECTORY '/tmp/destination' | ||
| USING parquet | ||
| OPTIONS (col1 1, col2 2, col3 'test') | ||
| SELECT * FROM test_table; | ||
|
|
||
| INSERT OVERWRITE DIRECTORY | ||
| USING parquet | ||
| OPTIONS ('path' '/tmp/destination', col1 1, col2 2, col3 'test') | ||
| SELECT * FROM test_table; | ||
| {% endhighlight %} | ||
|
|
||
| Related Statements: | ||
| * [INSERT INTO statement](sql-ref-syntax-dml-insert-into.html) | ||
| * [INSERT OVERWRITE statement](sql-ref-syntax-dml-insert-overwrite-table.html) | ||
| * [INSERT OVERWRITE DIRECTORY with Hive format statement](sql-ref-syntax-dml-insert-overwrite-directory-hive.html) |
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@huaxingao If we determine that we allow more syntax flavors .. could we please add one test for each ?