Using paginated full text search for movies, combined actor search and fetch to allow combining search with filters.

This commit is contained in:
DebaucheryLibrarian
2021-08-22 22:25:20 +02:00
parent e0905ab8fc
commit 6a8c9d89cb
21 changed files with 163 additions and 196 deletions

View File

@@ -915,6 +915,12 @@ exports.up = knex => Promise.resolve()
table.unique('movie_id');
}))
.then(() => knex.schema.createTable('movies_search', (table) => {
table.integer('movie_id', 16)
.references('id')
.inTable('movies')
.onDelete('cascade');
}))
.then(() => knex.schema.createTable('chapters', (table) => {
table.increments('id', 16);
@@ -1369,6 +1375,7 @@ exports.up = knex => Promise.resolve()
// allow vim fold
return knex.raw(`
ALTER TABLE releases_search ADD COLUMN document tsvector;
ALTER TABLE movies_search ADD COLUMN document tsvector;
/* allow scenes without dates to be mixed inbetween scenes with dates */
ALTER TABLE releases
@@ -1389,14 +1396,16 @@ exports.up = knex => Promise.resolve()
CREATE UNIQUE INDEX unique_entity_campaigns_affiliate ON campaigns (entity_id, affiliate_id) WHERE banner_id IS NULL AND url IS NULL;
CREATE UNIQUE INDEX releases_search_unique ON releases_search (release_id);
CREATE UNIQUE INDEX movies_search_unique ON movies_search (movie_id);
CREATE INDEX releases_search_index ON releases_search USING GIN (document);
CREATE INDEX movies_search_index ON movies_search USING GIN (document);
`);
})
// FUNCTIONS
.then(() => { // eslint-disable-line arrow-body-style
// allow vim fold
return knex.raw(`
CREATE EXTENSION pg_trgm;
CREATE EXTENSION IF NOT EXISTS pg_trgm;
CREATE FUNCTION current_user_id() RETURNS INTEGER AS $$
/* if the user ID is undefined, the adapter will pass it as a string, which cannot be cast as NULL by ::integer */
@@ -1407,6 +1416,7 @@ exports.up = knex => Promise.resolve()
* Using a table as a proxy for the search results allows us to get both a reference to the releases table, and the ranking.
* A composite type does not seem to be compatible with PostGraphile's @sortable, and a view does not allow for many native constraints */
CREATE TABLE releases_search_results (release_id integer, rank real, FOREIGN KEY (release_id) REFERENCES releases (id));
CREATE TABLE movies_search_results (movie_id integer, rank real, FOREIGN KEY (movie_id) REFERENCES movies (id));
CREATE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$
SELECT releases.id, ranks.rank FROM (
@@ -1420,10 +1430,16 @@ exports.up = knex => Promise.resolve()
ORDER BY ranks.rank DESC;
$$ LANGUAGE SQL STABLE;
CREATE FUNCTION search_movies(query text, min_length smallint DEFAULT 2) RETURNS SETOF movies AS $$
SELECT * FROM movies
WHERE length(query) >= min_length
AND title ILIKE ('%' || TRIM(query) || '%')
CREATE FUNCTION search_movies(query text) RETURNS SETOF movies_search_results AS $$
SELECT movies.id, ranks.rank FROM (
SELECT
movies_search.movie_id,
ts_rank(movies_search.document, to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|'))) AS rank
FROM movies_search
) ranks
LEFT JOIN movies ON movies.id = ranks.movie_id
WHERE ranks.rank > 0
ORDER BY ranks.rank DESC;
$$ LANGUAGE SQL STABLE;
CREATE FUNCTION search_entities(search text) RETURNS SETOF entities AS $$
@@ -1436,13 +1452,14 @@ exports.up = knex => Promise.resolve()
url ILIKE ('%' || search || '%')
$$ LANGUAGE SQL STABLE;
CREATE FUNCTION search_actors(search text, min_length smallint DEFAULT 2) RETURNS SETOF actors AS $$
CREATE FUNCTION search_actors(query text, min_length smallint DEFAULT 2) RETURNS SETOF actors AS $$
SELECT * FROM actors
WHERE length(search) >= min_length
WHERE query IS NULL
OR length(query) >= min_length
AND CASE
WHEN length(search) > 1
THEN name ILIKE ('%' || TRIM(search) || '%')
ELSE name ILIKE (TRIM(search) || '%')
WHEN length(query) > 1 THEN name ILIKE ('%' || TRIM(query) || '%')
WHEN length(query) = 1 THEN name ILIKE (TRIM(query) || '%')
ELSE true
END
$$ LANGUAGE SQL STABLE;
@@ -1750,6 +1767,7 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style
DROP TABLE IF EXISTS releases_teasers CASCADE;
DROP TABLE IF EXISTS releases_tags CASCADE;
DROP TABLE IF EXISTS releases_search CASCADE;
DROP TABLE IF EXISTS movies_search CASCADE;
DROP TABLE IF EXISTS movies_scenes CASCADE;
DROP TABLE IF EXISTS movies_covers CASCADE;
@@ -1848,5 +1866,6 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style
DROP FUNCTION IF EXISTS get_random_campaign;
DROP TABLE IF EXISTS releases_search_results;
DROP TABLE IF EXISTS movies_search_results;
`);
};