Files
supabase/apps/docs/content/guides/database/extensions/pgroonga.mdx
Charis 47705a8968 chore: replace all supabase urls with relative urls (#38537)
* fix: rewrite relative URLs when syncing to GitHub discussion

Relative URLs back to supabse.com won't work in GitHub discussions, so
rewrite them back to absolute URLs starting with https://supabase.com

* fix: replace all supabase urls with relative urls

* chore: add linting for relative urls

* chore: bump linter version

* Prettier

---------

Co-authored-by: Chris Chinchilla <chris.ward@supabase.io>
2025-09-09 12:54:33 +00:00

183 lines
5.0 KiB
Plaintext

---
id: 'pgroonga'
title: 'PGroonga: Multilingual Full Text Search'
description: 'Full Text Search for multiple languages in PostgreSQL'
tocVideo: 'Mmmv9g_MiBA'
---
`PGroonga` is a Postgres extension adding a full text search indexing method based on [Groonga](https://groonga.org). While native Postgres supports full text indexing, it is limited to alphabet and digit based languages. `PGroonga` offers a wider range of character support making it viable for a superset of languages supported by Postgres including Japanese, Chinese, etc.
## Enable the extension
<Tabs
scrollable
size="small"
type="underlined"
defaultActiveId="dashboard"
queryGroup="database-method"
>
<TabPanel id="dashboard" label="Dashboard">
1. Go to the [Database](/dashboard/project/_/database/tables) page in the Dashboard.
2. Click on **Extensions** in the sidebar.
3. Search for `pgroonga` and enable the extension.
</TabPanel>
<TabPanel id="sql" label="SQL">
{/* prettier-ignore */}
```sql
-- Enable the "pgroonga" extension
create extension pgroonga with schema extensions;
-- Disable the "pgroonga" extension
drop extension if exists pgroonga;
```
Even though the SQL code is `create extension`, this is the equivalent of enabling the extension.
To disable an extension you can call `drop extension`.
</TabPanel>
</Tabs>
## Creating a full text search index
Given a table with a `text` column:
{/* prettier-ignore */}
```sql
create table memos (
id serial primary key,
content text
);
```
We can index the column for full text search with a `pgroonga` index:
{/* prettier-ignore */}
```sql
create index ix_memos_content ON memos USING pgroonga(content);
```
To test the full text index, we'll add some data.
{/* prettier-ignore */}
```sql
insert into memos(content)
values
('PostgreSQL is a relational database management system.'),
('Groonga is a fast full text search engine that supports all languages.'),
('PGroonga is a PostgreSQL extension that uses Groonga as index.'),
('There is groonga command.');
```
The Postgres query planner is smart enough to know that, for extremely small tables, it's faster to scan the whole table rather than loading an index. To force the index to be used, we can disable sequential scans:
{/* prettier-ignore */}
```sql
-- For testing only. Don't do this in production
set enable_seqscan = off;
```
Now if we run an explain plan on a query filtering on `memos.content`:
{/* prettier-ignore */}
```sql
explain select * from memos where content like '%engine%';
QUERY PLAN
-----------------------------------------------------------------------------
Index Scan using ix_memos_content on memos (cost=0.00..1.11 rows=1 width=36)
Index Cond: (content ~~ '%engine%'::text)
(2 rows)
```
The `pgroonga` index is used to retrieve the result set:
```markdown
| id | content |
| --- | ------------------------------------------------------------------------ |
| 2 | 'Groonga is a fast full text search engine that supports all languages.' |
```
## Full text search
The `&@~` operator performs full text search. It returns any matching results. Unlike `LIKE` operator, `pgroonga` can search any text that contains the keyword case insensitive.
Take the following example:
{/* prettier-ignore */}
```sql
select * from memos where content &@~ 'groonga';
```
And the result:
```markdown
id | content
----+------------------------------------------------------------------------
2 | Groonga is a fast full text search engine that supports all languages.
3 | PGroonga is a PostgreSQL extension that uses Groonga as index.
4 | There is groonga command.
(3 rows)
```
### Match all search words
To find all memos where content contains BOTH of the words `postgres` and `pgroonga`, we can just use space to separate each words:
{/* prettier-ignore */}
```sql
select * from memos where content &@~ 'postgres pgroonga';
```
And the result:
```markdown
id | content
----+----------------------------------------------------------------
3 | PGroonga is a PostgreSQL extension that uses Groonga as index.
(1 row)
```
### Match any search words
To find all memos where content contain ANY of the words `postgres` or `pgroonga`, use the upper case `OR`:
{/* prettier-ignore */}
```sql
select * from memos where content &@~ 'postgres OR pgroonga';
```
And the result:
```markdown
id | content
----+----------------------------------------------------------------
1 | PostgreSQL is a relational database management system.
3 | PGroonga is a PostgreSQL extension that uses Groonga as index.
(2 rows)
```
### Search that matches words with negation
To find all memos where content contain the word `postgres` but not `pgroonga`, use `-` symbol:
{/* prettier-ignore */}
```sql
select * from memos where content &@~ 'postgres -pgroonga';
```
And the result:
```markdown
id | content
----+--------------------------------------------------------
1 | PostgreSQL is a relational database management system.
(1 row)
```
## Resources
- Official [PGroonga documentation](https://pgroonga.github.io/tutorial/)