forked from cockroachdb/cockroach
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
opt, sql: support
UPDATE ... FROM
statements
Addresses cockroachdb#7841. This change adds support for `UPDATE ... FROM` statements. The FROM clause tables are joined together with the target table and is used as input for the update. Furthermore, the RETURNING clause can reference any table in the FROM clause. TODO: - [ ] Prune the passthrough columns in the returning clause. Release note: None
- Loading branch information
Ridwan Sharif
committed
Aug 1, 2019
1 parent
da56c79
commit 4118f61
Showing
20 changed files
with
526 additions
and
94 deletions.
There are no files selected for viewing
This file contains 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
This file contains 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 |
---|---|---|
@@ -1,2 +1,2 @@ | ||
update_stmt ::= | ||
( ( 'WITH' ( ( common_table_expr ) ( ( ',' common_table_expr ) )* ) ) | ) 'UPDATE' ( ( table_name opt_index_flags ) | ( table_name opt_index_flags ) table_alias_name | ( table_name opt_index_flags ) 'AS' table_alias_name ) 'SET' ( ( ( ( column_name '=' a_expr ) | ( '(' ( ( ( column_name ) ) ( ( ',' ( column_name ) ) )* ) ')' '=' ( '(' select_stmt ')' | ( '(' ')' | '(' ( a_expr | a_expr ',' | a_expr ',' ( ( a_expr ) ( ( ',' a_expr ) )* ) ) ')' ) ) ) ) ) ( ( ',' ( ( column_name '=' a_expr ) | ( '(' ( ( ( column_name ) ) ( ( ',' ( column_name ) ) )* ) ')' '=' ( '(' select_stmt ')' | ( '(' ')' | '(' ( a_expr | a_expr ',' | a_expr ',' ( ( a_expr ) ( ( ',' a_expr ) )* ) ) ')' ) ) ) ) ) )* ) ( ( 'WHERE' a_expr ) | ) ( sort_clause | ) ( limit_clause | ) ( 'RETURNING' target_list | 'RETURNING' 'NOTHING' | ) | ||
( ( 'WITH' ( ( common_table_expr ) ( ( ',' common_table_expr ) )* ) ) | ) 'UPDATE' ( ( table_name opt_index_flags ) | ( table_name opt_index_flags ) table_alias_name | ( table_name opt_index_flags ) 'AS' table_alias_name ) 'SET' ( ( ( ( column_name '=' a_expr ) | ( '(' ( ( ( column_name ) ) ( ( ',' ( column_name ) ) )* ) ')' '=' ( '(' select_stmt ')' | ( '(' ')' | '(' ( a_expr | a_expr ',' | a_expr ',' ( ( a_expr ) ( ( ',' a_expr ) )* ) ) ')' ) ) ) ) ) ( ( ',' ( ( column_name '=' a_expr ) | ( '(' ( ( ( column_name ) ) ( ( ',' ( column_name ) ) )* ) ')' '=' ( '(' select_stmt ')' | ( '(' ')' | '(' ( a_expr | a_expr ',' | a_expr ',' ( ( a_expr ) ( ( ',' a_expr ) )* ) ) ')' ) ) ) ) ) )* ) opt_from_list ( ( 'WHERE' a_expr ) | ) ( sort_clause | ) ( limit_clause | ) ( 'RETURNING' target_list | 'RETURNING' 'NOTHING' | ) |
This file contains 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,61 @@ | ||
# LogicTest: local-opt | ||
|
||
statement ok | ||
CREATE TABLE abc (a int primary key, b int, c int) | ||
|
||
statement ok | ||
INSERT INTO abc VALUES (1, 2, 3), (2, 3, 4) | ||
|
||
# Updating using self join. | ||
statement ok | ||
UPDATE abc SET b = other.b + 1, c = other.c + 1 FROM abc AS other WHERE abc.a = other.a | ||
|
||
query III | ||
SELECT * FROM abc | ||
---- | ||
1 3 4 | ||
2 4 5 | ||
|
||
# Update from another table. | ||
statement ok | ||
CREATE TABLE new_abc (a int, b int, c int) | ||
|
||
statement ok | ||
INSERT INTO new_abc VALUES (1, 2, 3), (2, 3, 4) | ||
|
||
statement ok | ||
UPDATE abc SET b = other.b, c = other.c FROM new_abc AS other WHERE abc.a = other.a | ||
|
||
query III | ||
SELECT * FROM abc | ||
---- | ||
1 2 3 | ||
2 3 4 | ||
|
||
# Multiple matching values for a given row. | ||
statement ok | ||
INSERT INTO new_abc VALUES (1, 1, 1) | ||
|
||
statement ok | ||
UPDATE abc SET b = other.b, c = other.c FROM new_abc AS other WHERE abc.a = other.a | ||
|
||
query III | ||
SELECT * FROM abc | ||
---- | ||
1 2 3 | ||
2 3 4 | ||
|
||
# Returning old values. | ||
query IIIII colnames | ||
UPDATE abc SET b = old.b + 1, c = old.c + 2 FROM abc AS old WHERE abc.a = old.a RETURNING abc.a, abc.b AS new_b, old.b as old_b, abc.c as new_c, old.c as old_c | ||
---- | ||
a new_b old_b new_c old_c | ||
1 3 2 5 3 | ||
2 4 3 6 4 | ||
|
||
# Check if RETURNING * returns everything | ||
query IIIIII | ||
UPDATE abc SET b = old.b + 1, c = old.c + 2 FROM abc AS old WHERE abc.a = old.a RETURNING * | ||
---- | ||
1 4 7 1 3 5 | ||
2 5 8 2 4 6 |
This file contains 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
This file contains 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
This file contains 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
This file contains 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
This file contains 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
This file contains 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
Oops, something went wrong.