diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 6a53c2033751..2d2d96ff76bc 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -1821,6 +1821,39 @@ protected function addDynamic($segment, $connector, $parameters, $index) $this->where(Str::snake($segment), '=', $parameters[$index], $bool); } + /** + * Add a "where fulltext" clause to the query. + * + * @param string|string[] $columns + * @param string $value + * @param string $boolean + * @return $this + */ + public function whereFullText($columns, $value, array $options = [], $boolean = 'and') + { + $type = 'Fulltext'; + + $columns = (array) $columns; + + $this->wheres[] = compact('type', 'columns', 'value', 'options', 'boolean'); + + $this->addBinding($value); + + return $this; + } + + /** + * Add a "or where fulltext" clause to the query. + * + * @param string|string[] $columns + * @param string $value + * @return $this + */ + public function orWhereFullText($columns, $value, array $options = []) + { + return $this->whereFulltext($columns, $value, $options, 'or'); + } + /** * Add a "group by" clause to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index 2f7d0721ae04..ea670a2e9646 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -629,6 +629,18 @@ protected function compileJsonLength($column, $operator, $value) throw new RuntimeException('This database engine does not support JSON length operations.'); } + /** + * Compile a "where fulltext" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + public function whereFullText(Builder $query, $where) + { + throw new RuntimeException('This database engine does not support fulltext search operations.'); + } + /** * Compile the "group by" portions of the query. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 17b1aff01347..404b3d5408b0 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -50,6 +50,30 @@ protected function whereNotNull(Builder $query, $where) return parent::whereNotNull($query, $where); } + /** + * Compile a "where fulltext" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + public function whereFullText(Builder $query, $where) + { + $columns = $this->columnize($where['columns']); + + $value = $this->parameter($where['value']); + + $mode = ($where['options']['mode'] ?? []) === 'boolean' + ? ' in boolean mode' + : ' in natural language mode'; + + $expanded = ($where['options']['expanded'] ?? []) && ($where['options']['mode'] ?? []) !== 'boolean' + ? ' with query expansion' + : ''; + + return "match ({$columns}) against (".$value."{$mode}{$expanded})"; + } + /** * Compile an insert ignore statement into SQL. * diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index d40d163ce850..47f498e54708 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -85,6 +85,71 @@ protected function dateBasedWhere($type, Builder $query, $where) return 'extract('.$type.' from '.$this->wrap($where['column']).') '.$where['operator'].' '.$value; } + /** + * Compile a "where fulltext" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + public function whereFullText(Builder $query, $where) + { + $language = $where['options']['language'] ?? 'english'; + + if (! in_array($language, $this->validFullTextLanguages())) { + $language = 'english'; + } + + $columns = collect($where['columns'])->map(function ($column) use ($language) { + return "to_tsvector('{$language}', {$this->wrap($column)})"; + })->implode(' || '); + + $mode = 'plainto_tsquery'; + + if (($where['options']['mode'] ?? []) === 'phrase') { + $mode = 'phraseto_tsquery'; + } + + if (($where['options']['mode'] ?? []) === 'websearch') { + $mode = 'websearch_to_tsquery'; + } + + return "({$columns}) @@ {$mode}('{$language}', {$this->parameter($where['value'])})"; + } + + /** + * Get an array of valid full text languages. + * + * @return array + */ + protected function validFullTextLanguages() + { + return [ + 'simple', + 'arabic', + 'danish', + 'dutch', + 'english', + 'finnish', + 'french', + 'german', + 'hungarian', + 'indonesian', + 'irish', + 'italian', + 'lithuanian', + 'nepali', + 'norwegian', + 'portuguese', + 'romanian', + 'russian', + 'spanish', + 'swedish', + 'tamil', + 'turkish', + ]; + } + /** * Compile the "select *" portion of the query. * diff --git a/src/Illuminate/Database/Schema/Blueprint.php b/src/Illuminate/Database/Schema/Blueprint.php index 954607f3c2b0..dfe53ee792a8 100755 --- a/src/Illuminate/Database/Schema/Blueprint.php +++ b/src/Illuminate/Database/Schema/Blueprint.php @@ -208,7 +208,7 @@ protected function addImpliedCommands(Grammar $grammar) protected function addFluentIndexes() { foreach ($this->columns as $column) { - foreach (['primary', 'unique', 'index', 'fulltext', 'spatialIndex'] as $index) { + foreach (['primary', 'unique', 'index', 'fulltext', 'fullText', 'spatialIndex'] as $index) { // If the index has been specified on the given column, but is simply equal // to "true" (boolean), no name has been specified for this index so the // index method can be called without a name and it will generate one. @@ -373,9 +373,9 @@ public function dropIndex($index) * @param string|array $index * @return \Illuminate\Support\Fluent */ - public function dropFulltext($index) + public function dropFullText($index) { - return $this->dropIndexCommand('dropFulltext', 'fulltext', $index); + return $this->dropIndexCommand('dropFullText', 'fulltext', $index); } /** @@ -549,7 +549,7 @@ public function index($columns, $name = null, $algorithm = null) * @param string|null $algorithm * @return \Illuminate\Support\Fluent */ - public function fulltext($columns, $name = null, $algorithm = null) + public function fullText($columns, $name = null, $algorithm = null) { return $this->indexCommand('fulltext', $columns, $name, $algorithm); } diff --git a/src/Illuminate/Database/Schema/Grammars/Grammar.php b/src/Illuminate/Database/Schema/Grammars/Grammar.php index 380fcd30da53..7313576b4f18 100755 --- a/src/Illuminate/Database/Schema/Grammars/Grammar.php +++ b/src/Illuminate/Database/Schema/Grammars/Grammar.php @@ -104,7 +104,7 @@ public function compileFulltext(Blueprint $blueprint, Fluent $command) * @param \Illuminate\Support\Fluent $command * @return string */ - public function compileDropFulltext(Blueprint $blueprint, Fluent $command) + public function compileDropFullText(Blueprint $blueprint, Fluent $command) { throw new RuntimeException('This database driver does not support fulltext index creation.'); } diff --git a/src/Illuminate/Database/Schema/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Schema/Grammars/MySqlGrammar.php index 2eaefd1f5156..92c1513527e7 100755 --- a/src/Illuminate/Database/Schema/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Schema/Grammars/MySqlGrammar.php @@ -248,7 +248,7 @@ public function compileIndex(Blueprint $blueprint, Fluent $command) * @param \Illuminate\Support\Fluent $command * @return string */ - public function compileFulltext(Blueprint $blueprint, Fluent $command) + public function compileFullText(Blueprint $blueprint, Fluent $command) { return $this->compileKey($blueprint, $command, 'fulltext'); } @@ -369,7 +369,7 @@ public function compileDropIndex(Blueprint $blueprint, Fluent $command) * @param \Illuminate\Support\Fluent $command * @return string */ - public function compileDropFulltext(Blueprint $blueprint, Fluent $command) + public function compileDropFullText(Blueprint $blueprint, Fluent $command) { return $this->compileDropIndex($blueprint, $command); } diff --git a/src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php index c7023c8ea08e..27490bc44f7f 100755 --- a/src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php @@ -4,7 +4,6 @@ use Illuminate\Database\Schema\Blueprint; use Illuminate\Support\Fluent; -use RuntimeException; class PostgresGrammar extends Grammar { @@ -190,15 +189,14 @@ public function compileFulltext(Blueprint $blueprint, Fluent $command) { $language = $command->language ?: 'english'; - if (count($command->columns) > 1) { - throw new RuntimeException('The PostgreSQL driver does not support fulltext index creation using multiple columns.'); - } + $columns = array_map(function ($column) use ($language) { + return "to_tsvector({$this->quoteString($language)}, {$this->wrap($column)})"; + }, $command->columns); - return sprintf('create index %s on %s using gin (to_tsvector(%s, %s))', + return sprintf('create index %s on %s using gin ((%s))', $this->wrap($command->index), $this->wrapTable($blueprint), - $this->quoteString($language), - $this->wrap($command->columns[0]) + implode(' || ', $columns) ); } @@ -392,7 +390,7 @@ public function compileDropIndex(Blueprint $blueprint, Fluent $command) * @param \Illuminate\Support\Fluent $command * @return string */ - public function compileDropFulltext(Blueprint $blueprint, Fluent $command) + public function compileDropFullText(Blueprint $blueprint, Fluent $command) { return $this->compileDropIndex($blueprint, $command); } diff --git a/tests/Database/DatabasePostgresSchemaGrammarTest.php b/tests/Database/DatabasePostgresSchemaGrammarTest.php index 12601bb8c802..fae92c3eb6ee 100755 --- a/tests/Database/DatabasePostgresSchemaGrammarTest.php +++ b/tests/Database/DatabasePostgresSchemaGrammarTest.php @@ -269,7 +269,17 @@ public function testAddingFulltextIndex() $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); $this->assertCount(1, $statements); - $this->assertSame('create index "users_body_fulltext" on "users" using gin (to_tsvector(\'english\', "body"))', $statements[0]); + $this->assertSame('create index "users_body_fulltext" on "users" using gin ((to_tsvector(\'english\', "body")))', $statements[0]); + } + + public function testAddingFulltextIndexMultipleColumns() + { + $blueprint = new Blueprint('users'); + $blueprint->fulltext(['body', 'title']); + $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); + + $this->assertCount(1, $statements); + $this->assertSame('create index "users_body_title_fulltext" on "users" using gin ((to_tsvector(\'english\', "body") || to_tsvector(\'english\', "title")))', $statements[0]); } public function testAddingFulltextIndexWithLanguage() @@ -279,7 +289,7 @@ public function testAddingFulltextIndexWithLanguage() $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); $this->assertCount(1, $statements); - $this->assertSame('create index "users_body_fulltext" on "users" using gin (to_tsvector(\'spanish\', "body"))', $statements[0]); + $this->assertSame('create index "users_body_fulltext" on "users" using gin ((to_tsvector(\'spanish\', "body")))', $statements[0]); } public function testAddingFulltextIndexWithFluency() @@ -289,7 +299,7 @@ public function testAddingFulltextIndexWithFluency() $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); $this->assertCount(2, $statements); - $this->assertSame('create index "users_body_fulltext" on "users" using gin (to_tsvector(\'english\', "body"))', $statements[1]); + $this->assertSame('create index "users_body_fulltext" on "users" using gin ((to_tsvector(\'english\', "body")))', $statements[1]); } public function testAddingSpatialIndex() diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 4064664fa4b7..d27a38a10276 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -15,6 +15,7 @@ use Illuminate\Database\Query\Grammars\SQLiteGrammar; use Illuminate\Database\Query\Grammars\SqlServerGrammar; use Illuminate\Database\Query\Processors\MySqlProcessor; +use Illuminate\Database\Query\Processors\PostgresProcessor; use Illuminate\Database\Query\Processors\Processor; use Illuminate\Pagination\AbstractPaginator as Paginator; use Illuminate\Pagination\Cursor; @@ -858,6 +859,72 @@ public function testArrayWhereColumn() $this->assertEquals([], $builder->getBindings()); } + public function testWhereFulltextMySql() + { + $builder = $this->getMySqlBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World'); + $this->assertSame('select * from `users` where match (`body`) against (? in natural language mode)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getMySqlBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World', ['expanded' => true]); + $this->assertSame('select * from `users` where match (`body`) against (? in natural language mode with query expansion)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getMySqlBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', '+Hello -World', ['mode' => 'boolean']); + $this->assertSame('select * from `users` where match (`body`) against (? in boolean mode)', $builder->toSql()); + $this->assertEquals(['+Hello -World'], $builder->getBindings()); + + $builder = $this->getMySqlBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', '+Hello -World', ['mode' => 'boolean', 'expanded' => true]); + $this->assertSame('select * from `users` where match (`body`) against (? in boolean mode)', $builder->toSql()); + $this->assertEquals(['+Hello -World'], $builder->getBindings()); + + $builder = $this->getMySqlBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext(['body', 'title'], 'Car,Plane'); + $this->assertSame('select * from `users` where match (`body`, `title`) against (? in natural language mode)', $builder->toSql()); + $this->assertEquals(['Car,Plane'], $builder->getBindings()); + } + + public function testWhereFulltextPostgres() + { + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World'); + $this->assertSame('select * from "users" where (to_tsvector(\'english\', "body")) @@ plainto_tsquery(\'english\', ?)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World', ['language' => 'simple']); + $this->assertSame('select * from "users" where (to_tsvector(\'simple\', "body")) @@ plainto_tsquery(\'simple\', ?)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World', ['mode' => 'plain']); + $this->assertSame('select * from "users" where (to_tsvector(\'english\', "body")) @@ plainto_tsquery(\'english\', ?)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World', ['mode' => 'phrase']); + $this->assertSame('select * from "users" where (to_tsvector(\'english\', "body")) @@ phraseto_tsquery(\'english\', ?)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', '+Hello -World', ['mode' => 'websearch']); + $this->assertSame('select * from "users" where (to_tsvector(\'english\', "body")) @@ websearch_to_tsquery(\'english\', ?)', $builder->toSql()); + $this->assertEquals(['+Hello -World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext('body', 'Hello World', ['language' => 'simple', 'mode' => 'plain']); + $this->assertSame('select * from "users" where (to_tsvector(\'simple\', "body")) @@ plainto_tsquery(\'simple\', ?)', $builder->toSql()); + $this->assertEquals(['Hello World'], $builder->getBindings()); + + $builder = $this->getPostgresBuilderWithProcessor(); + $builder->select('*')->from('users')->whereFulltext(['body', 'title'], 'Car Plane'); + $this->assertSame('select * from "users" where (to_tsvector(\'english\', "body") || to_tsvector(\'english\', "title")) @@ plainto_tsquery(\'english\', ?)', $builder->toSql()); + $this->assertEquals(['Car Plane'], $builder->getBindings()); + } + public function testUnions() { $builder = $this->getBuilder(); @@ -4312,6 +4379,14 @@ protected function getMySqlBuilderWithProcessor() return new Builder(m::mock(ConnectionInterface::class), $grammar, $processor); } + protected function getPostgresBuilderWithProcessor() + { + $grammar = new PostgresGrammar; + $processor = new PostgresProcessor; + + return new Builder(m::mock(ConnectionInterface::class), $grammar, $processor); + } + /** * @return \Mockery\MockInterface|\Illuminate\Database\Query\Builder */ diff --git a/tests/Integration/Database/MySql/FulltextTest.php b/tests/Integration/Database/MySql/FulltextTest.php new file mode 100644 index 000000000000..a98d0c74b48a --- /dev/null +++ b/tests/Integration/Database/MySql/FulltextTest.php @@ -0,0 +1,69 @@ +id('id'); + $table->string('title', 200); + $table->text('body'); + $table->fulltext(['title', 'body']); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('articles'); + } + + protected function setUp(): void + { + parent::setUp(); + + DB::table('articles')->insert([ + ['title' => 'MySQL Tutorial', 'body' => 'DBMS stands for DataBase ...'], + ['title' => 'How To Use MySQL Well', 'body' => 'After you went through a ...'], + ['title' => 'Optimizing MySQL', 'body' => 'In this tutorial, we show ...'], + ['title' => '1001 MySQL Tricks', 'body' => '1. Never run mysqld as root. 2. ...'], + ['title' => 'MySQL vs. YourSQL', 'body' => 'In the following database comparison ...'], + ['title' => 'MySQL Security', 'body' => 'When configured properly, MySQL ...'], + ]); + } + + /** @link https://dev.mysql.com/doc/refman/8.0/en/fulltext-natural-language.html */ + public function testWhereFulltext() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], 'database')->get(); + + $this->assertCount(2, $articles); + $this->assertSame('MySQL Tutorial', $articles[0]->title); + $this->assertSame('MySQL vs. YourSQL', $articles[1]->title); + } + + /** @link https://dev.mysql.com/doc/refman/8.0/en/fulltext-boolean.html */ + public function testWhereFulltextWithBooleanMode() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], '+MySQL -YourSQL', ['mode' => 'boolean'])->get(); + + $this->assertCount(5, $articles); + } + + /** @link https://dev.mysql.com/doc/refman/8.0/en/fulltext-query-expansion.html */ + public function testWhereFulltextWithExpandedQuery() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], 'database', ['expanded' => true])->get(); + + $this->assertCount(6, $articles); + } +} diff --git a/tests/Integration/Database/Postgres/FulltextTest.php b/tests/Integration/Database/Postgres/FulltextTest.php new file mode 100644 index 000000000000..39ddb6837022 --- /dev/null +++ b/tests/Integration/Database/Postgres/FulltextTest.php @@ -0,0 +1,73 @@ +id('id'); + $table->string('title', 200); + $table->text('body'); + $table->fulltext(['title', 'body']); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('articles'); + } + + protected function setUp(): void + { + parent::setUp(); + + DB::table('articles')->insert([ + ['title' => 'PostgreSQL Tutorial', 'body' => 'DBMS stands for DataBase ...'], + ['title' => 'How To Use PostgreSQL Well', 'body' => 'After you went through a ...'], + ['title' => 'Optimizing PostgreSQL', 'body' => 'In this tutorial, we show ...'], + ['title' => '1001 PostgreSQL Tricks', 'body' => '1. Never run mysqld as root. 2. ...'], + ['title' => 'PostgreSQL vs. YourSQL', 'body' => 'In the following database comparison ...'], + ['title' => 'PostgreSQL Security', 'body' => 'When configured properly, PostgreSQL ...'], + ]); + } + + public function testWhereFulltext() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], 'database')->orderBy('id')->get(); + + $this->assertCount(2, $articles); + $this->assertSame('PostgreSQL Tutorial', $articles[0]->title); + $this->assertSame('PostgreSQL vs. YourSQL', $articles[1]->title); + } + + public function testWhereFulltextWithWebsearch() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], '+PostgreSQL -YourSQL', ['mode' => 'websearch'])->get(); + + $this->assertCount(5, $articles); + } + + public function testWhereFulltextWithPlain() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], 'PostgreSQL tutorial', ['mode' => 'plain'])->get(); + + $this->assertCount(2, $articles); + } + + public function testWhereFulltextWithPhrase() + { + $articles = DB::table('articles')->whereFulltext(['title', 'body'], 'PostgreSQL tutorial', ['mode' => 'phrase'])->get(); + + $this->assertCount(1, $articles); + } +} diff --git a/tests/Integration/Database/Postgres/PostgresTestCase.php b/tests/Integration/Database/Postgres/PostgresTestCase.php new file mode 100644 index 000000000000..9b06d1a36e85 --- /dev/null +++ b/tests/Integration/Database/Postgres/PostgresTestCase.php @@ -0,0 +1,15 @@ +driver !== 'pgsql') { + $this->markTestSkipped('Test requires a PostgreSQL connection.'); + } + } +}