Adding full text search to movies

main
Drew Bednar 4 days ago
parent ecca50afd6
commit 9070d4a4c8

@ -46,7 +46,7 @@ start-local:
.PHONY: start-local
db-local:
docker exec -it pulleydb psql postgres://pulley:passwd@localhost:5432/pulley
docker exec -it pulleydb psql postgres://pulley:pulley@localhost:5432/pulley
.PHONY: db-local
stop-local:

@ -15,7 +15,7 @@ curl -i http://0.0.0.0:5002/v1/movies/1
## Creating a movie
```bash
curl -i -X POST -d '{"title":"Moana","year":2016,"runtime":"107 mins", "genres":["animation","adventure"]}' http://0.0.0.0:5002/v1/movies
curl -i -X POST -d '{"title":"Passengers","year":2016,"runtime":"120 mins", "genres":["comedy","adventure"]}' http://0.0.0.0:5002/v1/movies
```
```bash
@ -70,4 +70,36 @@ We can timeout our curl request like so
```bash
curl --max-time 2 localhost:5002/v1/movies/4
```
```
## Migrations
Don't forget that the migrate tool can be used to create the stub of your index files.
```bash
migrate create -seq -ext .sql -dir ./migrations add_movies_indexes
```
To run migrations from the cmdline you need to have the pgx5 installed
```bash
go install -tags 'pgx5' github.com/golang-migrate/migrate/v4/cmd/migrate@latest
```
Then you need to specify a database uri
```bash
migrate -dir ./migrations -database "pgx://pulley:pulley@localhost:5434/pulley" goto 2
```
## Postgres
en.wikipedia.org/wiki/Stemming
We are using the postgres simple type for full text search but we could use some of the more advanced options for this like english. This will perform stemming for us and resulting in common words like "a" or "the" from appearing in the lexemes it generates.
Check out `\dF` for all the available configurations. See the docs for more about full text search. https://www.postgresql.org/docs/current/textsearch.html
### Other Resources
- https://niallburkley.com/blog/index-columns-for-like-in-postgres/

@ -177,10 +177,22 @@ func (m MovieModel) GetAll(ctx context.Context, title string, genres []string, f
// ORDER BY id ASC
// `
// The plainto_tsquery('simple', $1) function takes a search value and turns it
// into a formatted query term that PostgreSQL full-text search can understand.
// It normalizes the search value (again using the simple configuration), strips
// any special characters, and inserts the and operator & between the words.
// As an example, the search value "The Club" would result in the query term
// 'the' & 'club'.
// The @@ operator is the matches operator. In our statement we are using it to
// check whether the generated query term matches the lexemes. To continue the
// example, the query term 'the' & 'club' will match rows which contain both lexemes
// 'the' and 'club'.
query := `
SELECT id, created_at, title, year, runtime, genres, version
FROM movies
WHERE (LOWER(title) = LOWER($1) OR $1 = '')
WHERE (to_tsvector('simple', title) @@ plainto_tsquery('simple', $1) OR $1 = '')
AND (genres @> $2 OR $2 = '{}')
ORDER BY id`

@ -0,0 +1,2 @@
DROP INDEX IF EXISTS movies_title_idx;
DROP INDEX IF EXISTS movies_genres_idx;

@ -0,0 +1,4 @@
DROP INDEX IF EXISTS movies_title_idx;
DROP INDEX IF EXISTS movies_genres_idx;
CREATE INDEX IF NOT EXISTS movies_title_idx ON public.movies USING GIN (to_tsvector('simple', title));
CREATE INDEX IF NOT EXISTS movies_genres_idx ON public.movies USING GIN (genres);
Loading…
Cancel
Save