Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[8.x] Implement Full-Text Search for PostgreSQL #40229

Merged
merged 1 commit into from
Jan 3, 2022

Conversation

tpetry
Copy link
Contributor

@tpetry tpetry commented Jan 2, 2022

I worked with @driesvints on a basic api for the query builder to do fulltext searching (#40129). Based on the agreed api and his implementation for MySQL, I was able to easily add PostgreSQL support:

Schema::create('articles', function (Blueprint $table) {
    $table->id('id');
    $table->string('title', 200);
    $table->text('body');
    $table->fulltext(['title', 'body']);
});

// Search for "databases" in the title and body fulltext index...
$articles = DB::table('articles')
    ->whereFulltext(['title', 'body'], 'database')
    ->get();

// Search for "databases" in the title and body fulltext index with german language...
$articles = DB::table('articles')
    ->whereFulltext(['title', 'body'], 'database', ['language' => 'german'])
    ->get();

// Search for "databases" in the title and body fulltext index with phrase-mode...
$articles = DB::table('articles')
    ->whereFulltext(['title', 'body'], 'database', ['mode' => 'phrase'])
    ->get();

// Search for "databases" in the title and body fulltext index with websearch-mode...
$articles = DB::table('articles')
    ->whereFulltext(['title', 'body'], 'database', ['mode' => 'websearch'])
    ->get();

PostgreSQL has the great functionality that you can fine tune fulltext-search very much. For the moment, I only implemented the different search-term parsers to keep the pull request small. You will have access to the following search-term modes:

  • mode = 'plain': The plainto_tsquery function will transform a search string by and-ing the search terms: plainto_tsquery('english', 'The Fat Rats door') --> must match 'fat' & 'rat' & 'door'
  • mode = 'phraseto': The phraseto_tsquery function will transform a search string by needing the phrases to appear in the exact order one after another: phraseto_tsquery('english', 'The Fat Rats door') --> must match 'fat' <-> 'rat' <-> 'door'
  • mode = 'websearch': The websearch_to_tsquery function is mostly like MySQL's boolean search mode, which allows positive/negative operators in the text. But contrary to MySQL the terms are combined with and instead of or: websearch_to_tsquery('english', 'fat +rat -door') --> must match 'fat' & 'rat' & !'door'

The websearch mode mode = 'websearch' is only available in PostgreSQL 11+ so the standard mode has been set to mode = 'plain'.

In my pull request #39875 I added fulltext index support for PostgreSQL which was released with v8.75.0. I did not implement multiple columns as the there are different ways to build them and querying needs to use the same method as the index. With querying support now added, I also implemented multiple columns support.


This is a stacked Pull Request on #39875, i will rebase it to the 8.x branch as soon as the pull request of @driesvints is merged.

@tpetry tpetry force-pushed the match-against-postgresql branch from 7f8da8b to 4141270 Compare January 2, 2022 15:54
@tpetry tpetry force-pushed the match-against-postgresql branch from 4141270 to 22fca1b Compare January 2, 2022 15:56
@foremtehan
Copy link
Contributor

Can we leverage PostgreSQL GIN index for this or it will be useless ?

@tpetry
Copy link
Contributor Author

tpetry commented Jan 2, 2022

Can we leverage PostgreSQL GIN index for this or it will be useless ?

If you set a fulltext() index on the columns it will be used 😉

@driesvints driesvints marked this pull request as draft January 3, 2022 10:40
@driesvints
Copy link
Member

Converting to draft for now until my own PR is merged. Thanks!

@driesvints
Copy link
Member

Actually, @tpetry can you send this to my own branch instead? Thanks!

@driesvints driesvints changed the base branch from 8.x to match-against January 3, 2022 10:42
@driesvints driesvints marked this pull request as ready for review January 3, 2022 10:42
@driesvints driesvints merged commit f59133c into laravel:match-against Jan 3, 2022
@driesvints
Copy link
Member

Nvm, got it. Thanks @tpetry!

@tpetry tpetry deleted the match-against-postgresql branch January 3, 2022 11:05
taylorotwell added a commit that referenced this pull request Jan 6, 2022
* 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>
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants