Skip to content

Commit

Permalink
Support UPDATE LIMIT (#93)
Browse files Browse the repository at this point in the history
Wraps WHERE clauses in UPDATE queries in `rowid in ( SELECT rowid from ...WHERE...)` to support MySQL's `LIMIT` and `ORDER BY` clauses that are unsupported in SQLite.

Fixes #27

Co-authored-by: Adam Zielinski <[email protected]>
Co-authored-by: Mukesh Panchal <[email protected]>
  • Loading branch information
3 people authored Apr 16, 2024
1 parent 7c95aef commit ef032b2
Show file tree
Hide file tree
Showing 2 changed files with 188 additions and 2 deletions.
106 changes: 106 additions & 0 deletions tests/WP_SQLite_Translator_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -129,6 +129,112 @@ public function testInsertDateNow() {
$this->assertEquals( gmdate( 'Y' ), $results[0]->y );
}

public function testUpdateWithLimit() {
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 00:00:45');"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-28 00:00:45');"
);

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-27 10:08:48' WHERE option_name = 'first' ORDER BY option_name LIMIT 1;"
);

$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first';" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second';" );

$this->assertEquals( '2001-05-27 10:08:48', $result1[0]->option_value );
$this->assertEquals( '2003-05-28 00:00:45', $result2[0]->option_value );

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-27 10:08:49' WHERE option_name = 'first';"
);
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first';" );
$this->assertEquals( '2001-05-27 10:08:49', $result1[0]->option_value );

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-12 10:00:40' WHERE option_name in ( SELECT option_name from _dates );"
);
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first';" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second';" );
$this->assertEquals( '2001-05-12 10:00:40', $result1[0]->option_value );
$this->assertEquals( '2001-05-12 10:00:40', $result2[0]->option_value );
}

public function testUpdateWithLimitNoEndToken() {
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 00:00:45')"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-28 00:00:45')"
);

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-27 10:08:48' WHERE option_name = 'first' ORDER BY option_name LIMIT 1"
);
$results = $this->engine->get_query_results();

$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );

$this->assertEquals( '2001-05-27 10:08:48', $result1[0]->option_value );
$this->assertEquals( '2003-05-28 00:00:45', $result2[0]->option_value );

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-27 10:08:49' WHERE option_name = 'first'"
);
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$this->assertEquals( '2001-05-27 10:08:49', $result1[0]->option_value );

$this->assertQuery(
"UPDATE _dates SET option_value = '2001-05-12 10:00:40' WHERE option_name in ( SELECT option_name from _dates )"
);
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );
$this->assertEquals( '2001-05-12 10:00:40', $result1[0]->option_value );
$this->assertEquals( '2001-05-12 10:00:40', $result2[0]->option_value );
}

public function testUpdateWithoutWhereButWithSubSelect() {
$this->assertQuery(
"INSERT INTO _options (option_name, option_value) VALUES ('User 0000019', 'second');"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-27 10:08:48');"
);
$return = $this->assertQuery(
"UPDATE _dates SET option_value = (SELECT option_value from _options WHERE option_name = 'User 0000019')"
);
$this->assertSame( 2, $return, 'UPDATE query did not return 2 when two row were changed' );

$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );
$this->assertEquals( 'second', $result1[0]->option_value );
$this->assertEquals( 'second', $result2[0]->option_value );
}

public function testUpdateWithoutWhereButWithLimit() {
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-27 10:08:48');"
);
$return = $this->assertQuery(
"UPDATE _dates SET option_value = 'second' LIMIT 1"
);
$this->assertSame( 1, $return, 'UPDATE query did not return 2 when two row were changed' );

$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );
$this->assertEquals( 'second', $result1[0]->option_value );
$this->assertEquals( '2003-05-27 10:08:48', $result2[0]->option_value );
}

public function testCastAsBinary() {
$this->assertQuery(
// Use a confusing alias to make sure it replaces only the correct token
Expand Down
84 changes: 82 additions & 2 deletions wp-includes/sqlite/class-wp-sqlite-translator.php
Original file line number Diff line number Diff line change
Expand Up @@ -1561,17 +1561,58 @@ private function execute_describe() {

/**
* Executes an UPDATE statement.
* Supported syntax:
*
* UPDATE [LOW_PRIORITY] [IGNORE] table_reference
* SET assignment_list
* [WHERE where_condition]
* [ORDER BY ...]
* [LIMIT row_count]
*
* @see https://dev.mysql.com/doc/refman/8.0/en/update.html
*/
private function execute_update() {
$this->rewriter->consume(); // Update.

$this->rewriter->consume(); // Consume the UPDATE keyword.
$has_where = false;
$needs_closing_parenthesis = false;
$params = array();
while ( true ) {
$token = $this->rewriter->peek();
if ( ! $token ) {
break;
}

/*
* If the query contains a WHERE clause,
* we need to rewrite the query to use a nested SELECT statement.
* eg:
* - UPDATE table SET column = value WHERE condition LIMIT 1;
* will be rewritten to:
* - UPDATE table SET column = value WHERE rowid IN (SELECT rowid FROM table WHERE condition LIMIT 1);
*/
if ($this->rewriter->depth === 0) {
if (($token->value === 'LIMIT' || $token->value === 'ORDER') && !$has_where) {
$this->rewriter->add(
new WP_SQLite_Token('WHERE', WP_SQLite_Token::TYPE_KEYWORD),
);
$needs_closing_parenthesis = true;
$this->preface_WHERE_clause_with_a_subquery();
} else if ($token->value === 'WHERE') {
$has_where = true;
$needs_closing_parenthesis = true;
$this->rewriter->consume();
$this->preface_WHERE_clause_with_a_subquery();
$this->rewriter->add(
new WP_SQLite_Token('WHERE', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED)
);
}
}

// Ignore the semicolon in case of rewritten query as it breaks the query.
if ( ';' === $this->rewriter->peek()->value && $this->rewriter->peek()->type === WP_SQLite_Token::TYPE_DELIMITER ) {
break;
}

// Record the table name.
if (
! $this->table_name &&
Expand All @@ -1594,13 +1635,52 @@ private function execute_update() {

$this->rewriter->consume();
}

// Wrap up the WHERE clause with the nested SELECT statement
if ( $needs_closing_parenthesis ) {
$this->rewriter->add( new WP_SQLite_Token( ')', WP_SQLite_Token::TYPE_OPERATOR ) );
}

$this->rewriter->consume_all();

$updated_query = $this->rewriter->get_updated_query();
$this->execute_sqlite_query( $updated_query, $params );
$this->set_result_from_affected_rows();
}

/**
* Injects `rowid IN (SELECT rowid FROM table WHERE ...` into the WHERE clause at the current
* position in the query.
*
* This is necessary to emulate the behavior of MySQL's UPDATE LIMIT and DELETE LIMIT statement
* as SQLite does not support LIMIT in UPDATE and DELETE statements.
*
* The WHERE clause is wrapped in a subquery that selects the rowid of the rows that match the original
* WHERE clause.
*
* @return void
*/
private function preface_WHERE_clause_with_a_subquery() {
$this->rewriter->add_many(
array(
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( 'rowid', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_KEY ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( 'IN', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( '(', WP_SQLite_Token::TYPE_OPERATOR ),
new WP_SQLite_Token( 'SELECT', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( 'rowid', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_KEY ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( 'FROM', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
new WP_SQLite_Token( $this->table_name, WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED ),
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
)
);
}

/**
* Executes a INSERT or REPLACE statement.
*/
Expand Down

0 comments on commit ef032b2

Please sign in to comment.