@@ -1529,17 +1529,39 @@ private function execute_insert_or_replace_statement( WP_Parser_Node $node ): vo
15291529
15301530 $ parts = array ();
15311531 foreach ( $ node ->get_children () as $ child ) {
1532- if ( $ child instanceof WP_MySQL_Token && WP_MySQL_Lexer::IGNORE_SYMBOL === $ child ->id ) {
1532+ $ is_token = $ child instanceof WP_MySQL_Token;
1533+ $ is_node = $ child instanceof WP_Parser_Node;
1534+
1535+ // Skip the SET keyword in "INSERT INTO ... SET ..." syntax.
1536+ if ( $ is_token && WP_MySQL_Lexer::SET_SYMBOL === $ child ->id ) {
1537+ continue ;
1538+ }
1539+
1540+ if ( $ is_token && WP_MySQL_Lexer::IGNORE_SYMBOL === $ child ->id ) {
15331541 // Translate "UPDATE IGNORE" to "UPDATE OR IGNORE".
15341542 $ parts [] = 'OR IGNORE ' ;
15351543 } elseif (
15361544 $ is_non_strict_mode
1537- && $ child instanceof WP_Parser_Node
1538- && ( 'insertFromConstructor ' === $ child ->rule_name || 'insertQueryExpression ' === $ child ->rule_name )
1545+ && $ is_node
1546+ && (
1547+ 'insertFromConstructor ' === $ child ->rule_name
1548+ || 'insertQueryExpression ' === $ child ->rule_name
1549+ || 'updateList ' === $ child ->rule_name
1550+ )
15391551 ) {
15401552 $ table_ref = $ node ->get_first_child_node ( 'tableRef ' );
15411553 $ table_name = $ this ->unquote_sqlite_identifier ( $ this ->translate ( $ table_ref ) );
15421554 $ parts [] = $ this ->translate_insert_or_replace_body_in_non_strict_mode ( $ table_name , $ child );
1555+ } elseif ( $ is_node && 'updateList ' === $ child ->rule_name ) {
1556+ // Convert "SET c1 = v1, c2 = v2, ... to "(c1, c2, ...) VALUES (v1, v2, ...)".
1557+ $ columns = array ();
1558+ $ values = array ();
1559+ foreach ( $ child ->get_child_nodes ( 'updateElement ' ) as $ update_element ) {
1560+ $ column_ref = $ update_element ->get_first_child_node ( 'columnRef ' );
1561+ $ columns [] = $ this ->translate ( $ column_ref );
1562+ $ values [] = $ this ->translate ( $ update_element ->get_first_child_node ( 'expr ' ) );
1563+ }
1564+ $ parts [] = '( ' . implode ( ', ' , $ columns ) . ') VALUES ( ' . implode ( ', ' , $ values ) . ') ' ;
15431565 } else {
15441566 $ parts [] = $ this ->translate ( $ child );
15451567 }
@@ -4305,6 +4327,12 @@ private function translate_insert_or_replace_body_in_non_strict_mode(
43054327 foreach ( $ fields_node ->get_child_nodes () as $ field ) {
43064328 $ insert_list [] = $ this ->unquote_sqlite_identifier ( $ this ->translate ( $ field ) );
43074329 }
4330+ } elseif ( 'updateList ' === $ node ->rule_name ) {
4331+ // This is the "INSERT INTO ... SET c1 = v1, c2 = v2, ... " syntax.
4332+ foreach ( $ node ->get_child_nodes ( 'updateElement ' ) as $ update_element ) {
4333+ $ column_ref = $ update_element ->get_first_child_node ( 'columnRef ' );
4334+ $ insert_list [] = $ this ->unquote_sqlite_identifier ( $ this ->translate ( $ column_ref ) );
4335+ }
43084336 } else {
43094337 // When no explicit field list is provided, all columns are required.
43104338 foreach ( array_column ( $ columns , 'COLUMN_NAME ' ) as $ column_name ) {
@@ -4385,10 +4413,25 @@ function ( $column ) use ( $insert_list ) {
43854413 }
43864414 }
43874415
4388- // 6. Wrap the original insert VALUES or SELECT expression in a FROM clause.
4389- $ values = 'insertFromConstructor ' === $ node ->rule_name
4390- ? $ node ->get_first_child_node ( 'insertValues ' )
4391- : $ node ->get_first_child_node ( 'queryExpressionOrParens ' );
4416+ // 6. Wrap the original insert VALUES, SELECT, or SET list in a FROM clause.
4417+ if ( 'insertFromConstructor ' === $ node ->rule_name ) {
4418+ // VALUES (...)
4419+ $ from = $ this ->translate (
4420+ $ node ->get_first_child_node ( 'insertValues ' )
4421+ );
4422+ } elseif ( 'insertQueryExpression ' === $ node ->rule_name ) {
4423+ // SELECT ...
4424+ $ from = $ this ->translate (
4425+ $ node ->get_first_child_node ( 'queryExpressionOrParens ' )
4426+ );
4427+ } else {
4428+ // SET c1 = v1, c2 = v2, ...
4429+ $ values = array ();
4430+ foreach ( $ node ->get_child_nodes ( 'updateElement ' ) as $ update_element ) {
4431+ $ values [] = $ this ->translate ( $ update_element ->get_first_child_node ( 'expr ' ) );
4432+ }
4433+ $ from = 'VALUES ( ' . implode ( ', ' , $ values ) . ') ' ;
4434+ }
43924435
43934436 /*
43944437 * The "WHERE true" suffix is used to avoid parsing ambiguity in SQLite.
@@ -4397,7 +4440,7 @@ function ( $column ) use ( $insert_list ) {
43974440 *
43984441 * See: https://www.sqlite.org/lang_insert.html
43994442 */
4400- $ fragment .= ' FROM ( ' . $ this -> translate ( $ values ) . ') WHERE true ' ;
4443+ $ fragment .= ' FROM ( ' . $ from . ') WHERE true ' ;
44014444
44024445 return $ fragment ;
44034446 }
0 commit comments