Skip to content

Commit

Permalink
Add support for LIKE BINARY
Browse files Browse the repository at this point in the history
  • Loading branch information
JanJakes committed Jan 10, 2025
1 parent f5a52ca commit 174916a
Show file tree
Hide file tree
Showing 3 changed files with 250 additions and 78 deletions.
119 changes: 80 additions & 39 deletions tests/WP_SQLite_Driver_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -3033,13 +3033,13 @@ public function testTranslatesUtf8SELECT() {
$this->assertQuery( 'DELETE FROM _options' );
}

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

// Insert data into the table
Expand All @@ -3052,70 +3052,111 @@ public function testTranslateLikeBinaryAndGlob() {
$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');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('aste*risk');" );
$this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('question?mark');" );

// Test case-sensitive LIKE BINARY
// Test exact string
$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 %
// Test exact string with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'third'" );
$this->assertCount( 0, $result );

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

// Test % 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 _
// Test % wildcard with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'x%'" );
$this->assertCount( 0, $result );

// Test "%" character (not a wildcard)
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\%chars'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'special%chars', $result[0]->name );

// Test _ 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'" );
// Test _ wildcard with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'x_yz'" );
$this->assertCount( 0, $result );

// Test GLOB equivalent for case-sensitive matching with wildcard
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f*'" );
// Test "_" character (not a wildcard)
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\_chars'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );
$this->assertEquals( 'special_chars', $result[0]->name );

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

// Test GLOB with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'S*'" );
// Test escaping of "*" with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f*'" );
$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'
// Test escaping of "?"
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'question?mark'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'question?mark', $result[0]->name );

$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'FIRST';" );
$this->assertCount( 1, $result ); // Should only match 'FIRST'
// Test escaping of "?" with no matches
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f?rst'" );
$this->assertCount( 0, $result );

// 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 );
// Test escaping of character class
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '[f]irst'" );
$this->assertCount( 0, $result );

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

// Test pattern with special characters using LIKE BINARY
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '%special%';" );
$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 );
$this->assertEquals( 'special\chars', $result[3]->name );

// Test escaping - "\t" is a tab character
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'firs\\t'" );
$this->assertCount( 0, $result );

// Test escaping - "\\t" is "t" (input resolves to "\t", which LIKE resolves to "t")
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'firs\\\\t'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'first', $result[0]->name );

// Test escaping - "\%" is a "%" literal
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\%chars'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'special%chars', $result[0]->name );

// Test escaping - "\\%" is also a "%" literal
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\\\%chars'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'special%chars', $result[0]->name );

// Test escaping - "\\\%" is "\" and a wildcard
$result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\\\\\%chars'" );
$this->assertCount( 1, $result );
$this->assertEquals( 'special\\chars', $result[0]->name );

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

public function testOnConflictReplace() {
Expand Down
46 changes: 46 additions & 0 deletions wp-includes/sqlite-ast/class-wp-sqlite-driver.php
Original file line number Diff line number Diff line change
Expand Up @@ -1313,6 +1313,12 @@ private function translate( $ast ) {
throw $this->not_supported_exception(
sprintf( 'data type: %s', $child->value )
);
case 'predicateOperations':
$token = $ast->get_child_token();
if ( WP_MySQL_Lexer::LIKE_SYMBOL === $token->id ) {
return $this->translate_like( $ast );
}
return $this->translate_sequence( $ast->get_children() );
case 'systemVariable':
// @TODO: Emulate some system variables, or use reasonable defaults.
// See: https://dev.mysql.com/doc/refman/8.4/en/server-system-variable-reference.html
Expand Down Expand Up @@ -1346,6 +1352,13 @@ private function translate_token( WP_MySQL_Token $token ) {
return '"' . trim( $token->value, '`"' ) . '"';
case WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL:
return 'AUTOINCREMENT';
case WP_MySQL_Lexer::BINARY_SYMBOL:
/*
* There is no "BINARY expr" equivalent in SQLite. We can look for
* the BINARY keyword in particular cases (with REGEXP, LIKE, etc.)
* and then remove it from the translated output here.
*/
return null;
default:
return $token->value;
}
Expand All @@ -1370,6 +1383,39 @@ private function translate_sequence( array $nodes, string $separator = ' ' ): ?s
return implode( $separator, $parts );
}

private function translate_like( WP_Parser_Node $node ): string {
$tokens = $node->get_descendant_tokens();
$is_binary = isset( $tokens[1] ) && WP_MySQL_Lexer::BINARY_SYMBOL === $tokens[1]->id;

if ( true === $is_binary ) {
$children = $node->get_children();
return sprintf(
'GLOB _helper_like_to_glob_pattern(%s)',
$this->translate( $children[1] )
);
}

/*
* @TODO: Implement the ESCAPE '...' clause.
*/

/*
* @TODO: Implement more correct LIKE behavior.
*
* While SQLite supports the LIKE operator, it seems to differ from the
* MySQL behavior in some ways:
*
* 1. In SQLite, LIKE is case-insensitive only for ASCII characters
* ('a' LIKE 'A' is TRUE but 'æ' LIKE 'Æ' is FALSE)
* 2. In MySQL, LIKE interprets some escape sequences. See the contents
* of the "_helper_like_to_glob_pattern" function.
*
* We'll probably need to overload the like() function:
* https://www.sqlite.org/lang_corefunc.html#like
*/
return $this->translate_sequence( $node->get_children() );
}

private function get_sqlite_create_table_statement( string $table_name, ?string $new_table_name = null ): array {
// 1. Get table info.
$table_info = $this->execute_sqlite_query(
Expand Down
Loading

0 comments on commit 174916a

Please sign in to comment.