Skip to content

Commit

Permalink
Sqlite: Fix LIKE BINARY queries (#149)
Browse files Browse the repository at this point in the history
This PR modifies the SQLite database integration plugin ensuring LIKE
BINARY queries are supported.

The translator has been updated to utilize the `GLOB` SQLite function to
support the `LIKE BINARY` clause in Sqlite, ensuring it respects case
sensitivity.

### Example query
**MySQL**
```sql
SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f%'
```

**SQLite**
```sql
SELECT * FROM _tmp_table WHERE name GLOB 'f*'
```

---------

Co-authored-by: Ari Stathopoulos <[email protected]>
Co-authored-by: Jeroen P <[email protected]>
Co-authored-by: Rostislav Wolný <[email protected]>
  • Loading branch information
4 people authored Aug 14, 2024
1 parent dd6bd6b commit 46528e8
Show file tree
Hide file tree
Showing 2 changed files with 137 additions and 0 deletions.
85 changes: 85 additions & 0 deletions tests/WP_SQLite_Translator_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -2895,6 +2895,91 @@ public function testTranslatesUtf8SELECT() {
$this->assertQuery( 'DELETE FROM _options' );
}

public function testTranslateLikeBinaryAndGlob() {
// Create a temporary table for testing
$this->assertQuery(
"CREATE TABLE _tmp_table (
ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
name varchar(20) NOT NULL default ''
);"
);

// Insert data into the table
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('first');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('FIRST');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('second');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('%special%');" );
$this->assertQuery( 'INSERT INTO _tmp_table (name) VALUES (NULL);' );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special%chars');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special_chars');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special\\chars');" );

// Test case-sensitive LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test case-sensitive LIKE BINARY with wildcard %
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f%'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test case-sensitive LIKE BINARY with wildcard _
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f_rst'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test case-insensitive LIKE
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE 'FIRST'" );
$this->assertCount( 2, $result ); // Should match both 'first' and 'FIRST'

// Test mixed case with LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'First'" );
$this->assertCount( 0, $result );

// Test no matches with LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'third'" );
$this->assertCount( 0, $result );

// Test GLOB equivalent for case-sensitive matching with wildcard
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f*'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test GLOB with single character wildcard
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f?rst'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test GLOB with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'S*'" );
$this->assertCount( 0, $result );

// Test GLOB case sensitivity with LIKE and GLOB
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'first';" );
$this->assertCount( 1, $result ); // Should only match 'first'

$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'FIRST';" );
$this->assertCount( 1, $result ); // Should only match 'FIRST'

// Test NULL comparison with LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first';" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

$result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE name LIKE BINARY NULL;' );
$this->assertCount( 0, $result ); // NULL comparison should return no results

// Test pattern with special characters using LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '%special%';" );
$this->assertCount( 4, $result );
$this->assertEquals( '%special%', $result[0]->name );
$this->assertEquals( 'special%chars', $result[1]->name );
$this->assertEquals( 'special_chars', $result[2]->name );
$this->assertEquals( 'specialchars', $result[3]->name );
}

public function testOnConflictReplace() {
$this->assertQuery(
"CREATE TABLE _tmp_table (
Expand Down
52 changes: 52 additions & 0 deletions wp-includes/sqlite/class-wp-sqlite-translator.php
Original file line number Diff line number Diff line change
Expand Up @@ -2068,6 +2068,7 @@ private function translate_expression( $token ) {
|| $this->translate_regexp_functions( $token )
|| $this->capture_group_by( $token )
|| $this->translate_ungrouped_having( $token )
|| $this->translate_like_binary( $token )
|| $this->translate_like_escape( $token )
|| $this->translate_left_function( $token )
);
Expand Down Expand Up @@ -2592,6 +2593,57 @@ private function translate_regexp_functions( $token ) {
}
return true;
}
/**
* Translate LIKE BINARY to SQLite equivalent using GLOB.
*
* @param WP_SQLite_Token $token The token to translate.
*
* @return bool
*/
private function translate_like_binary( $token ): bool {
if ( ! $token->matches( WP_SQLite_Token::TYPE_KEYWORD, null, array( 'LIKE' ) ) ) {
return false;
}

$next = $this->rewriter->peek_nth( 2 );
if ( ! $next || ! $next->matches( WP_SQLite_Token::TYPE_KEYWORD, null, array( 'BINARY' ) ) ) {
return false;
}

$this->rewriter->skip(); // Skip 'LIKE'
$this->rewriter->skip(); // Skip 'BINARY'

$pattern_token = $this->rewriter->peek();
$this->rewriter->skip(); // Skip the pattern token

$this->rewriter->add( new WP_SQLite_Token( 'GLOB', WP_SQLite_Token::TYPE_KEYWORD ) );
$this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ) );

$escaped_pattern = $this->escape_like_to_glob( $pattern_token->value );
$this->rewriter->add( new WP_SQLite_Token( $escaped_pattern, WP_SQLite_Token::TYPE_STRING ) );
$this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ) );

return true;
}

/**
* Escape LIKE pattern to GLOB pattern.
*
* @param string $pattern The LIKE pattern.
* @return string The escaped GLOB pattern.
*/
private function escape_like_to_glob( $pattern ) {
// Remove surrounding quotes
$pattern = trim( $pattern, "'\"" );

$pattern = str_replace( '%', '*', $pattern );
$pattern = str_replace( '_', '?', $pattern );

// No need to escape special characters in this case
// because GLOB doesn't require escaping in the same way LIKE does
// Return the pattern wrapped in single quotes
return "'" . $pattern . "'";
}

/**
* Detect GROUP BY.
Expand Down

0 comments on commit 46528e8

Please sign in to comment.