Skip to content

Commit

Permalink
[8.x] Implement Full-Text Search for MySQL & PostgreSQL (#40129)
Browse files Browse the repository at this point in the history
* Implement Full-Text Searches for MySQL

* Refactor to use generic whereFulltext

* Simplify value argument

* postgresql whereFulltext support (#40229)

* wip

* Update PostgresGrammar.php

* add orWhereFulltext

* Fix bindings

* wip

* formatting

* Apply fixes from StyleCI

* formatting and capitalization in backwards compatible way

Co-authored-by: Tobias Petry <tp@webstrategy.de>
Co-authored-by: Taylor Otwell <taylor@laravel.com>
Co-authored-by: StyleCI Bot <bot@styleci.io>
  • Loading branch information
4 people committed Jan 6, 2022
1 parent e70c996 commit 26bfb14
Show file tree
Hide file tree
Showing 13 changed files with 392 additions and 18 deletions.
33 changes: 33 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
12 changes: 12 additions & 0 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
24 changes: 24 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
65 changes: 65 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
8 changes: 4 additions & 4 deletions src/Illuminate/Database/Schema/Blueprint.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
Expand Down Expand Up @@ -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);
}

/**
Expand Down Expand Up @@ -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);
}
Expand Down
2 changes: 1 addition & 1 deletion src/Illuminate/Database/Schema/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.');
}
Expand Down
4 changes: 2 additions & 2 deletions src/Illuminate/Database/Schema/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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');
}
Expand Down Expand Up @@ -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);
}
Expand Down
14 changes: 6 additions & 8 deletions src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,6 @@

use Illuminate\Database\Schema\Blueprint;
use Illuminate\Support\Fluent;
use RuntimeException;

class PostgresGrammar extends Grammar
{
Expand Down Expand Up @@ -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)
);
}

Expand Down Expand Up @@ -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);
}
Expand Down
16 changes: 13 additions & 3 deletions tests/Database/DatabasePostgresSchemaGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -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()
Expand All @@ -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()
Expand All @@ -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()
Expand Down
75 changes: 75 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down Expand Up @@ -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();
Expand Down Expand Up @@ -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
*/
Expand Down

0 comments on commit 26bfb14

Please sign in to comment.