Skip to content

Commit

Permalink
postgresql whereFulltext support
Browse files Browse the repository at this point in the history
  • Loading branch information
tpetry committed Jan 2, 2022
1 parent ecf2c82 commit 7f8da8b
Show file tree
Hide file tree
Showing 8 changed files with 200 additions and 12 deletions.
2 changes: 0 additions & 2 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -1837,8 +1837,6 @@ public function whereFulltext($columns, $value, array $options = [], $boolean =

$this->wheres[] = compact('type', 'columns', 'value', 'options', 'boolean');

$this->addBinding($value);

return $this;
}

Expand Down
1 change: 1 addition & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -61,6 +61,7 @@ public function whereFulltext(Builder $query, $where)
{
$columns = $this->columnize($where['columns']);

$query->addBinding($where['value']);
$value = $this->parameter($where['value']);

$mode = ($where['options']['mode'] ?? []) === 'boolean'
Expand Down
45 changes: 45 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -70,6 +70,33 @@ protected function whereTime(Builder $query, $where)
return $this->wrap($where['column']).'::time '.$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';

$columns = array_map(function ($column) use($language, $query) {
return "to_tsvector({$this->bindParameter($query, $language)}, {$this->wrap($column)})";
}, $where['columns']);
$columns = implode(' || ', $columns);

$mode = 'plainto_tsquery';
if (($where['options']['mode'] ?? []) === 'phrase') {
$mode = 'phraseto_tsquery';
}
if (($where['options']['mode'] ?? []) === 'websearch') {
$mode = 'websearch_to_tsquery';
}

return "({$columns}) @@ {$mode}({$this->bindParameter($query, $language)}, {$this->bindParameter($query, $where['value'])})";
}

/**
* Compile a date based where clause.
*
Expand Down Expand Up @@ -517,4 +544,22 @@ protected function wrapJsonPathAttributes($path)
: "'$attribute'";
}, $path);
}

/**
* Binds parameter to query.
*
* @param Builder $query
* @param mixed $value
* @return mixed
*/
protected function bindParameter(Builder $query, $value)
{
if ($this->isExpression($value)) {
return $this->getValue($value);
}

$query->addBinding($value);

return '?';
}
}
11 changes: 5 additions & 6 deletions src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -190,15 +190,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
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
49 changes: 48 additions & 1 deletion 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,7 +859,7 @@ public function testArrayWhereColumn()
$this->assertEquals([], $builder->getBindings());
}

public function testWhereFulltext()
public function testWhereFulltextMySql()
{
$builder = $this->getMySqlBuilderWithProcessor();
$builder->select('*')->from('users')->whereFulltext('body', 'Hello World');
Expand Down Expand Up @@ -886,6 +887,44 @@ public function testWhereFulltext()
$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(?, "body")) @@ plainto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['english', 'english', '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(?, "body")) @@ plainto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['simple', 'simple', '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(?, "body")) @@ plainto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['english', 'english', '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(?, "body")) @@ phraseto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['english', 'english', '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(?, "body")) @@ websearch_to_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['english', 'english', '+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(?, "body")) @@ plainto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['simple', 'simple', 'Hello World'], $builder->getBindings());

$builder = $this->getPostgresBuilderWithProcessor();
$builder->select('*')->from('users')->whereFulltext(['body', 'title'], 'Car Plane');
$this->assertSame('select * from "users" where (to_tsvector(?, "body") || to_tsvector(?, "title")) @@ plainto_tsquery(?, ?)', $builder->toSql());
$this->assertEquals(['english', 'english', 'english', 'Car Plane'], $builder->getBindings());
}

public function testUnions()
{
$builder = $this->getBuilder();
Expand Down Expand Up @@ -4340,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
73 changes: 73 additions & 0 deletions tests/Integration/Database/Postgres/FulltextTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
<?php

namespace Illuminate\Tests\Integration\Database\Postgres;

use Illuminate\Database\Schema\Blueprint;
use Illuminate\Support\Facades\DB;
use Illuminate\Support\Facades\Schema;

/**
* @requires extension pdo_pgsql
* @requires OS Linux|Darwin
*/
class FulltextTest extends PostgresTestCase
{
protected function defineDatabaseMigrationsAfterDatabaseRefreshed()
{
Schema::create('articles', function (Blueprint $table) {
$table->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);
}
}
15 changes: 15 additions & 0 deletions tests/Integration/Database/Postgres/PostgresTestCase.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
<?php

namespace Illuminate\Tests\Integration\Database\Postgres;

use Illuminate\Tests\Integration\Database\DatabaseTestCase;

abstract class PostgresTestCase extends DatabaseTestCase
{
protected function defineDatabaseMigrations()
{
if ($this->driver !== 'pgsql') {
$this->markTestSkipped('Test requires a PostgreSQL connection.');
}
}
}

0 comments on commit 7f8da8b

Please sign in to comment.