Skip to content

Commit bff6aad

Browse files
authored
Add support for derived tables in UPDATE with JOIN queries, fix special cases (#241)
The following query from Action Scheduler was still failing: ```sql UPDATE wp_actionscheduler_actions t1 JOIN ( SELECT action_id from wp_actionscheduler_actions WHERE claim_id = 0 AND scheduled_date_gmt <= '2025-09-03 12:23:55' AND status='pending' ORDER BY priority ASC, attempts ASC, scheduled_date_gmt ASC, action_id ASC LIMIT 25 FOR UPDATE ) t2 ON t1.action_id = t2.action_id SET claim_id=37, last_attempt_gmt='2025-09-03 12:23:55', last_attempt_local='2025-09-03 12:23:55 ``` This was due to the derived table subquery in `JOIN` and the `FOR UDPATE` clause. This PR moves the derived subquery to the `FROM` clause, and strips away the locking clauses like `FOR UPDATE`.
1 parent ffd7cd7 commit bff6aad

File tree

3 files changed

+113
-17
lines changed

3 files changed

+113
-17
lines changed

tests/WP_SQLite_Driver_Tests.php

Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6840,4 +6840,37 @@ public function testUpdateWithJoinedTablesInNonStrictMode(): void {
68406840
$result
68416841
);
68426842
}
6843+
6844+
public function testUpdateWithJoinComplexQuery(): void {
6845+
$this->assertQuery( "SET SESSION sql_mode = ''" );
6846+
6847+
$default_date = '0000-00-00 00:00:00';
6848+
$this->assertQuery(
6849+
"CREATE TABLE wp_actionscheduler_actions (
6850+
action_id bigint(20) unsigned NOT NULL auto_increment,
6851+
status varchar(20) NOT NULL,
6852+
scheduled_date_gmt datetime NULL default '{$default_date}',
6853+
scheduled_date_local datetime NULL default '{$default_date}',
6854+
priority tinyint unsigned NOT NULL default '10',
6855+
attempts int(11) NOT NULL default '0',
6856+
last_attempt_gmt datetime NULL default '{$default_date}',
6857+
last_attempt_local datetime NULL default '{$default_date}',
6858+
claim_id bigint(20) unsigned NOT NULL default '0',
6859+
PRIMARY KEY (action_id)
6860+
)"
6861+
);
6862+
6863+
$this->assertQuery(
6864+
"UPDATE wp_actionscheduler_actions t1
6865+
JOIN (
6866+
SELECT action_id
6867+
FROM wp_actionscheduler_actions
6868+
WHERE claim_id = 0 AND scheduled_date_gmt <= '2025-09-03 12:23:55' AND status = 'pending'
6869+
ORDER BY priority ASC, attempts ASC, scheduled_date_gmt ASC, action_id ASC
6870+
LIMIT 25
6871+
FOR UPDATE
6872+
) t2 ON t1.action_id = t2.action_id
6873+
SET claim_id = 37, last_attempt_gmt = '2025-09-03 12:23:55', last_attempt_local = '2025-09-03 12:23:55'"
6874+
);
6875+
}
68436876
}

tests/WP_SQLite_Driver_Translation_Tests.php

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -168,6 +168,17 @@ public function testUpdate(): void {
168168
'UPDATE t SET c = 1 WHERE c = 2'
169169
);
170170

171+
// UPDATE with a table alias.
172+
$this->assertQuery(
173+
'UPDATE `t` AS `a` SET `c` = 1 WHERE `a`.`c` = 2',
174+
'UPDATE t AS a SET c = 1 WHERE a.c = 2'
175+
);
176+
177+
$this->assertQuery(
178+
'UPDATE `t` AS `a` SET `c` = 1 WHERE `a`.`c` = 2',
179+
'UPDATE t AS a SET a.c = 1 WHERE a.c = 2'
180+
);
181+
171182
// UPDATE with LIMIT.
172183
$this->assertQuery(
173184
'UPDATE `t` SET `c` = 1 WHERE rowid IN ( SELECT rowid FROM `t` LIMIT 1 )',
@@ -179,6 +190,24 @@ public function testUpdate(): void {
179190
'UPDATE `t` SET `c` = 1 WHERE rowid IN ( SELECT rowid FROM `t` ORDER BY `c` ASC LIMIT 1 )',
180191
'UPDATE t SET c = 1 ORDER BY c ASC LIMIT 1'
181192
);
193+
194+
// UPDATE with multiple tables.
195+
$this->assertQuery(
196+
'UPDATE `t1` SET `id` = 1 FROM `t2` WHERE `t1`.`c` = `t2`.`c`',
197+
'UPDATE t1, t2 SET t1.id = 1 WHERE t1.c = t2.c'
198+
);
199+
200+
// UPDATE with JOIN.
201+
$this->assertQuery(
202+
'UPDATE `t1` SET `id` = 1 FROM `t2` WHERE `t1`.`c` = 2 AND `t1`.`c` = `t2`.`c`',
203+
'UPDATE t1 JOIN t2 ON t1.c = t2.c SET t1.id = 1 WHERE t1.c = 2'
204+
);
205+
206+
// UPDATE with JOIN using a derived table.
207+
$this->assertQuery(
208+
'UPDATE `t1` SET `id` = 1 FROM ( SELECT * FROM `t2` ) AS `t2` WHERE `t1`.`c` = 2 AND `t1`.`c` = `t2`.`c`',
209+
'UPDATE t1 JOIN ( SELECT * FROM t2 ) AS t2 ON t1.c = t2.c SET t1.id = 1 WHERE t1.c = 2'
210+
);
182211
}
183212

184213
public function testDelete(): void {

wp-includes/sqlite-ast/class-wp-sqlite-driver.php

Lines changed: 51 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -1286,14 +1286,6 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
12861286
* SET_SYMBOL updateList whereClause? orderClause? simpleLimitClause?
12871287
*/
12881288

1289-
// Translate WITH clause.
1290-
$with = $this->translate( $node->get_first_child_node( 'withClause' ) );
1291-
1292-
// Translate "UPDATE IGNORE" to "UPDATE OR IGNORE".
1293-
$or_ignore = $node->has_child_token( WP_MySQL_Lexer::IGNORE_SYMBOL )
1294-
? 'OR IGNORE'
1295-
: null;
1296-
12971289
// Collect all tables used in the UPDATE clause (e.g, UPDATE t1, t2 JOIN t3).
12981290
$table_alias_map = $this->create_table_reference_map(
12991291
$node->get_first_child_node( 'tableReferenceList' )
@@ -1316,7 +1308,7 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
13161308
if ( null === $table_or_alias ) {
13171309
$persistent_table_names = array();
13181310
$temporary_table_names = array();
1319-
foreach ( array_column( $table_alias_map, 'table_name' ) as $table_name ) {
1311+
foreach ( array_filter( array_column( $table_alias_map, 'table_name' ) ) as $table_name ) {
13201312
$is_temporary = $this->information_schema_builder->temporary_table_exists( $table_name );
13211313
$quoted_table_name = $this->connection->quote( $table_name );
13221314
if ( $is_temporary ) {
@@ -1387,18 +1379,42 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
13871379
throw $this->new_not_supported_exception( 'UPDATE statement modifying multiple tables' );
13881380
}
13891381

1382+
// Translate WITH clause.
1383+
$with = $this->translate( $node->get_first_child_node( 'withClause' ) );
1384+
1385+
// Translate "UPDATE IGNORE" to "UPDATE OR IGNORE".
1386+
$or_ignore = $node->has_child_token( WP_MySQL_Lexer::IGNORE_SYMBOL )
1387+
? 'OR IGNORE'
1388+
: null;
1389+
1390+
// Compose the update target clause.
1391+
$update_target_table = $table_alias_map[ $update_target ]['table_name'] ?? $update_target;
1392+
$update_target_clause = $this->quote_sqlite_identifier( $update_target_table );
1393+
if ( $update_target !== $update_target_table ) {
1394+
$update_target_clause .= ' AS ' . $this->quote_sqlite_identifier( $update_target );
1395+
}
1396+
13901397
// Compose the FROM clause using all tables except the one being updated.
13911398
// UPDATE with FROM in SQLite is equivalent to UPDATE with JOIN in MySQL.
13921399
$from_items = array();
13931400
foreach ( $table_alias_map as $alias => $data ) {
1394-
$table_name = $data['table_name'];
13951401
if ( $alias === $update_target ) {
13961402
continue;
13971403
}
13981404

1399-
$from_item = $this->quote_sqlite_identifier( $alias );
1405+
$table_name = $data['table_name'];
1406+
1407+
// Derived table.
1408+
if ( null === $table_name ) {
1409+
$from_item = $data['table_expr'] . ' AS ' . $this->quote_sqlite_identifier( $alias );
1410+
$from_items[] = $from_item;
1411+
continue;
1412+
}
1413+
1414+
// Regular table.
1415+
$from_item = $this->quote_sqlite_identifier( $table_name );
14001416
if ( $alias !== $table_name ) {
1401-
$from_item .= ' AS ' . $this->quote_sqlite_identifier( $table_name );
1417+
$from_item .= ' AS ' . $this->quote_sqlite_identifier( $alias );
14021418
}
14031419
$from_items[] = $from_item;
14041420
}
@@ -1449,7 +1465,7 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
14491465
$with,
14501466
'UPDATE',
14511467
$or_ignore,
1452-
$this->quote_sqlite_identifier( $update_target ),
1468+
$update_target_clause,
14531469
'SET',
14541470
$update_list,
14551471
$from,
@@ -2825,6 +2841,10 @@ private function translate( $node ): ?string {
28252841
case 'indexHint':
28262842
case 'indexHintList':
28272843
return null;
2844+
case 'lockingClause':
2845+
// SQLite doesn't support locking clauses (SELECT ... FOR UPDATE).
2846+
// They are not needed in SQLite due to the database file locking.
2847+
return null;
28282848
default:
28292849
return $this->translate_sequence( $node->get_children() );
28302850
}
@@ -4107,8 +4127,9 @@ private function create_select_item_disambiguation_map( WP_Parser_Node $select_i
41074127
* The returned array maps table aliases to table names and additional data:
41084128
* - key: table alias, or name if no alias is used
41094129
* - value: an array of table data
4110-
* - table_name: the real name of the table
4111-
* - join_expr: the join expression used for the table
4130+
* - table_name: the real name of the table (null for derived tables)
4131+
* - table_expr: the table expression for a derived table (null for regular tables)
4132+
* - join_expr: the join expression used for the table (null when no join is used)
41124133
*
41134134
* MySQL has a non-stand ardsyntax extension where a comma-separated list of
41144135
* table references is allowed as a table reference in itself, for instance:
@@ -4145,11 +4166,24 @@ private function create_table_reference_map( WP_Parser_Node $node ): array {
41454166

41464167
if ( 'singleTable' === $child->rule_name ) {
41474168
// Extract data from the "singleTable" node.
4148-
$name = $this->translate( $child->get_first_child_node( 'tableRef' ) );
4149-
$alias = $this->translate( $child->get_first_child_node( 'tableAlias' ) );
4169+
$name = $this->translate( $child->get_first_child_node( 'tableRef' ) );
4170+
$alias_node = $child->get_first_child_node( 'tableAlias' );
4171+
$alias = $alias_node ? $this->translate( $alias_node->get_first_child_node( 'identifier' ) ) : null;
41504172

41514173
$table_map[ $this->unquote_sqlite_identifier( $alias ?? $name ) ] = array(
41524174
'table_name' => $this->unquote_sqlite_identifier( $name ),
4175+
'table_expr' => null,
4176+
'join_expr' => $this->translate( $join_expr ),
4177+
);
4178+
} elseif ( 'derivedTable' === $child->rule_name ) {
4179+
// Extract data from the "derivedTable" node.
4180+
$subquery = $child->get_first_descendant_node( 'subquery' );
4181+
$alias_node = $child->get_first_child_node( 'tableAlias' );
4182+
$alias = $alias_node ? $this->translate( $alias_node->get_first_child_node( 'identifier' ) ) : null;
4183+
4184+
$table_map[ $this->unquote_sqlite_identifier( $alias ) ] = array(
4185+
'table_name' => null,
4186+
'table_expr' => $this->translate( $subquery ),
41534187
'join_expr' => $this->translate( $join_expr ),
41544188
);
41554189
} elseif ( 'tableReferenceListParens' === $child->rule_name ) {

0 commit comments

Comments
 (0)