exports.up = async (knex) => { await knex.raw(` CREATE OR REPLACE FUNCTION curate_search_query(query text) RETURNS tsquery AS $$ SELECT to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|')); $$ LANGUAGE SQL STABLE; CREATE OR REPLACE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$ SELECT results.release_id, ts_rank(results.document::tsvector, curate_search_query(query)) as rank FROM ( SELECT releases_search.release_id, document FROM releases_search WHERE document::tsvector @@ curate_search_query(query) ) AS results ORDER BY rank DESC; $$ LANGUAGE SQL STABLE; COMMENT ON FUNCTION search_releases IS E'@sortable'; `); }; exports.down = async (knex) => { await knex.raw(` CREATE OR REPLACE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$ SELECT releases.id, ranks.rank FROM ( SELECT releases_search.release_id, ts_rank(releases_search.document, to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|'))) AS rank FROM releases_search ) ranks LEFT JOIN releases ON releases.id = ranks.release_id WHERE ranks.rank > 0 ORDER BY ranks.rank DESC; $$ LANGUAGE SQL STABLE; DROP FUNCTION curate_search_query; COMMENT ON FUNCTION search_releases IS E'@sortable'; `); };