diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 84e7eca0ae85..8a7f957d697e 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -1121,6 +1121,71 @@ public function orWhereRaw($sql, $bindings = []) return $this->whereRaw($sql, $bindings, 'or'); } + /** + * Add a "where like" clause to the query. + * + * @param string $column + * @param string $value + * @param bool $caseSensitive + * @param string $boolean + * @param bool $not + * @return $this + */ + public function whereLike($column, $value, $caseSensitive = false, $boolean = 'and', $not = false) + { + $type = 'Like'; + + $this->wheres[] = compact('type', 'column', 'value', 'caseSensitive', 'boolean', 'not'); + + if (method_exists($this->grammar, 'prepareWhereLikeBinding')) { + $value = $this->grammar->prepareWhereLikeBinding($value, $caseSensitive); + } + + $this->addBinding($value); + + return $this; + } + + /** + * Add an "or where like" clause to the query. + * + * @param string $column + * @param string $value + * @param bool $caseSensitive + * @return $this + */ + public function orWhereLike($column, $value, $caseSensitive = false) + { + return $this->whereLike($column, $value, $caseSensitive, 'or', false); + } + + /** + * Add a "where not like" clause to the query. + * + * @param string $column + * @param string $value + * @param bool $caseSensitive + * @param string $boolean + * @return $this + */ + public function whereNotLike($column, $value, $caseSensitive = false, $boolean = 'and') + { + return $this->whereLike($column, $value, $caseSensitive, $boolean, true); + } + + /** + * Add an "or where not like" clause to the query. + * + * @param string $columns + * @param string $value + * @param bool $caseSensitive + * @return $this + */ + public function orWhereNotLike($column, $value, $caseSensitive = false) + { + return $this->whereNotLike($column, $value, $caseSensitive, 'or'); + } + /** * Add a "where in" clause to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index 42c9102b4c62..63e624bcaf17 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -308,6 +308,24 @@ protected function whereBitwise(Builder $query, $where) return $this->whereBasic($query, $where); } + /** + * Compile a "where like" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereLike(Builder $query, $where) + { + if ($where['caseSensitive']) { + throw new RuntimeException('This database engine does not support case sensitive like operations.'); + } + + $where['operator'] = $where['not'] ? 'not like' : 'like'; + + return $this->whereBasic($query, $where); + } + /** * Compile a "where in" clause. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 8c1521f60d31..397dbe54e24b 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -15,6 +15,22 @@ class MySqlGrammar extends Grammar */ protected $operators = ['sounds like']; + /** + * Compile a "where like" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereLike(Builder $query, $where) + { + $where['operator'] = $where['not'] ? 'not ' : ''; + + $where['operator'] .= $where['caseSensitive'] ? 'like binary' : 'like'; + + return $this->whereBasic($query, $where); + } + /** * Add a "where null" clause to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index c22720a05c7c..bbb11284e72b 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -68,6 +68,22 @@ protected function whereBitwise(Builder $query, $where) return '('.$this->wrap($where['column']).' '.$operator.' '.$value.')::bool'; } + /** + * Compile a "where like" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereLike(Builder $query, $where) + { + $where['operator'] = $where['not'] ? 'not ' : ''; + + $where['operator'] .= $where['caseSensitive'] ? 'like' : 'ilike'; + + return $this->whereBasic($query, $where); + } + /** * Compile a "where date" clause. * diff --git a/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php b/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php index 5a754ebdb852..5b9e9761f381 100755 --- a/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php @@ -42,6 +42,39 @@ protected function wrapUnion($sql) return 'select * from ('.$sql.')'; } + /** + * Compile a "where like" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereLike(Builder $query, $where) + { + if ($where['caseSensitive'] == false) { + return parent::whereLike($query, $where); + } + $where['operator'] = $where['not'] ? 'not glob' : 'glob'; + + return $this->whereBasic($query, $where); + } + + /** + * Convert a LIKE pattern to a GLOB pattern using simple string replacement. + * + * @param string $value + * @param bool $caseSensitive + * @return string + */ + public function prepareWhereLikeBinding($value, $caseSensitive) + { + return $caseSensitive === false ? $value : str_replace( + ['*', '?', '%', '_'], + ['[*]', '[?]', '*', '?'], + $value + ); + } + /** * Compile a "where date" clause. * diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index a045f41548c6..c345ffcfb5c8 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -656,6 +656,128 @@ public function testWhereLikePostgres() $this->assertEquals([0 => '1'], $builder->getBindings()); } + public function testWhereLikeClausePostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1'); + $this->assertSame('select * from "users" where "id"::text ilike ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1', false); + $this->assertSame('select * from "users" where "id"::text ilike ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1', true); + $this->assertSame('select * from "users" where "id"::text like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1'); + $this->assertSame('select * from "users" where "id"::text not ilike ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1', false); + $this->assertSame('select * from "users" where "id"::text not ilike ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1', true); + $this->assertSame('select * from "users" where "id"::text not like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + } + + public function testWhereLikeClauseMysql() + { + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1'); + $this->assertSame('select * from `users` where `id` like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1', false); + $this->assertSame('select * from `users` where `id` like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1', true); + $this->assertSame('select * from `users` where `id` like binary ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1'); + $this->assertSame('select * from `users` where `id` not like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1', false); + $this->assertSame('select * from `users` where `id` not like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1', true); + $this->assertSame('select * from `users` where `id` not like binary ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + } + + public function testWhereLikeClauseSqlite() + { + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1'); + $this->assertSame('select * from "users" where "id" like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1', true); + $this->assertSame('select * from "users" where "id" glob ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereLike('description', 'Hell* _orld?%', true); + $this->assertSame('select * from "users" where "description" glob ?', $builder->toSql()); + $this->assertEquals([0 => 'Hell[*] ?orld[?]*'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1'); + $this->assertSame('select * from "users" where "id" not like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereNotLike('description', 'Hell* _orld?%', true); + $this->assertSame('select * from "users" where "description" not glob ?', $builder->toSql()); + $this->assertEquals([0 => 'Hell[*] ?orld[?]*'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereLike('name', 'John%', true)->whereNotLike('name', '%Doe%', true); + $this->assertSame('select * from "users" where "name" glob ? and "name" not glob ?', $builder->toSql()); + $this->assertEquals([0 => 'John*', 1 => '*Doe*'], $builder->getBindings()); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereLike('name', 'John%')->orWhereLike('name', 'Jane%', true); + $this->assertSame('select * from "users" where "name" like ? or "name" glob ?', $builder->toSql()); + $this->assertEquals([0 => 'John%', 1 => 'Jane*'], $builder->getBindings()); + } + + public function testWhereLikeClauseSqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1'); + $this->assertSame('select * from [users] where [id] like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereLike('id', '1')->orWhereLike('id', '2'); + $this->assertSame('select * from [users] where [id] like ? or [id] like ?', $builder->toSql()); + $this->assertEquals([0 => '1', 1 => '2'], $builder->getBindings()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereNotLike('id', '1'); + $this->assertSame('select * from [users] where [id] not like ?', $builder->toSql()); + $this->assertEquals([0 => '1'], $builder->getBindings()); + } + public function testWhereDateSqlite() { $builder = $this->getSQLiteBuilder(); diff --git a/tests/Integration/Database/QueryBuilderWhereLikeTest.php b/tests/Integration/Database/QueryBuilderWhereLikeTest.php new file mode 100644 index 000000000000..f2bf96663d60 --- /dev/null +++ b/tests/Integration/Database/QueryBuilderWhereLikeTest.php @@ -0,0 +1,110 @@ +id('id'); + $table->string('name', 200); + $table->text('email'); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('users'); + } + + protected function setUp(): void + { + parent::setUp(); + + DB::table('users')->insert([ + ['name' => 'John Doe', 'email' => 'John.Doe@example.com'], + ['name' => 'Jane Doe', 'email' => 'janedoe@example.com'], + ['name' => 'Dale doe', 'email' => 'Dale.Doe@example.com'], + ['name' => 'Earl Smith', 'email' => 'Earl.Smith@example.com'], + ['name' => 'tim smith', 'email' => 'tim.smith@example.com'], + ]); + } + + public function testWhereLike() + { + $users = DB::table('users')->whereLike('email', 'john.doe@example.com')->get(); + $this->assertCount(1, $users); + $this->assertSame('John.Doe@example.com', $users[0]->email); + + $this->assertSame(4, DB::table('users')->whereNotLike('email', 'john.doe@example.com')->count()); + } + + public function testWhereLikeWithPercentWildcard() + { + $this->assertSame(5, DB::table('users')->whereLike('email', '%@example.com')->count()); + $this->assertSame(2, DB::table('users')->whereNotLike('email', '%Doe%')->count()); + + $users = DB::table('users')->whereLike('email', 'john%')->get(); + $this->assertCount(1, $users); + $this->assertSame('John.Doe@example.com', $users[0]->email); + } + + public function testWhereLikeWithUnderscoreWildcard() + { + $users = DB::table('users')->whereLike('email', '_a_e_%@example.com')->get(); + $this->assertCount(2, $users); + $this->assertSame('janedoe@example.com', $users[0]->email); + $this->assertSame('Dale.Doe@example.com', $users[1]->email); + } + + public function testWhereLikeCaseSensitive() + { + if ($this->driver === 'sqlsrv') { + $this->markTestSkipped('The case-sensitive whereLike clause is not supported on MSSQL.'); + } + + $users = DB::table('users')->whereLike('email', 'john.doe@example.com', true)->get(); + $this->assertCount(0, $users); + + $users = DB::table('users')->whereLike('email', 'tim.smith@example.com', true)->get(); + $this->assertCount(1, $users); + $this->assertSame('tim.smith@example.com', $users[0]->email); + $this->assertSame(5, DB::table('users')->whereNotLike('email', 'john.doe@example.com', true)->count()); + } + + public function testWhereLikeWithPercentWildcardCaseSensitive() + { + if ($this->driver === 'sqlsrv') { + $this->markTestSkipped('The case-sensitive whereLike clause is not supported on MSSQL.'); + } + + $this->assertSame(2, DB::table('users')->whereLike('email', '%Doe@example.com', true)->count()); + $this->assertSame(4, DB::table('users')->whereNotLike('email', '%smith%', true)->count()); + + $users = DB::table('users')->whereLike('email', '%Doe@example.com', true)->get(); + $this->assertCount(2, $users); + $this->assertSame('John.Doe@example.com', $users[0]->email); + $this->assertSame('Dale.Doe@example.com', $users[1]->email); + } + + public function testWhereLikeWithUnderscoreWildcardCaseSensitive() + { + if ($this->driver === 'sqlsrv') { + $this->markTestSkipped('The case-sensitive whereLike clause is not supported on MSSQL.'); + } + + $users = DB::table('users')->whereLike('email', 'j__edoe@example.com', true)->get(); + $this->assertCount(1, $users); + $this->assertSame('janedoe@example.com', $users[0]->email); + + $users = DB::table('users')->whereNotLike('email', '%_oe@example.com', true)->get(); + $this->assertCount(2, $users); + $this->assertSame('Earl.Smith@example.com', $users[0]->email); + $this->assertSame('tim.smith@example.com', $users[1]->email); + } +}