exports.up = knex => Promise.resolve() .then(() => knex.raw(` CREATE VIEW releases_document AS SELECT releases.id, releases.site_id, to_tsvector(releases.title) || to_tsvector(sites.name) || to_tsvector(sites.slug) || to_tsvector(replace(CAST(releases.date AS VARCHAR), '-', ' ')) || to_tsvector(string_agg(actors.name, ' ')) || to_tsvector(string_agg(tags.name, ' ')) as document FROM releases JOIN releases_actors AS local_actors ON local_actors.release_id = releases.id JOIN releases_tags AS local_tags ON local_tags.release_id = releases.id JOIN sites ON releases.site_id = sites.id JOIN actors ON local_actors.actor_id = actors.id JOIN tags ON local_tags.tag_id = tags.id GROUP BY releases.id, sites.name, sites.slug; COMMENT ON VIEW releases_document IS E'@foreignKey (id) references releases (id)\n@foreignKey (site_id) references sites (id)'; CREATE FUNCTION search_releases(query text) RETURNS SETOF releases_document AS $$ SELECT * FROM releases_document AS search WHERE search.document @@ plainto_tsquery(replace(query, '.', ' ')) ORDER BY ts_rank(search.document, plainto_tsquery(replace(query, '.', ' '))) DESC; $$ LANGUAGE SQL STABLE; `)); exports.down = knex => Promise.resolve() .then(() => knex.raw(` DROP FUNCTION IF EXISTS search_releases; DROP VIEW IF EXISTS releases_document; `));