diff --git a/server/api/documents.js b/server/api/documents.js index 47bcd3af3..091276431 100644 --- a/server/api/documents.js +++ b/server/api/documents.js @@ -1,5 +1,8 @@ import Router from 'koa-router'; import httpErrors from 'http-errors'; +import { + sequelize, +} from '../sequelize'; import auth from './authentication'; import pagination from './middlewares/pagination'; @@ -40,6 +43,42 @@ router.post('documents.info', auth({ require: false }), async (ctx) => { if (!document) throw httpErrors.NotFound(); }); +router.post('documents.search', auth(), async (ctx) => { + let { query } = ctx.request.body; + ctx.assertPresent(query, 'query is required'); + + const user = await ctx.state.user; + + const sql = ` + SELECT * FROM documents + WHERE "searchVector" @@ to_tsquery('english', :query) AND + "teamId" = '${user.teamId}'::uuid + ORDER BY ts_rank(documents."searchVector", to_tsquery('english', :query)) + DESC; + `; + + const documents = await sequelize + .query( + sql, + { + replacements: { + query: query, + }, + model: Document, + } + ); + + let data = []; + await Promise.all(documents.map(async (document) => { + data.push(await presentDocument(document)); + })); + + ctx.body = { + pagination: ctx.state.pagination, + data: data, + }; +}); + router.post('documents.create', auth(), async (ctx) => { let { diff --git a/server/migrations/20160711071958-search-index.js b/server/migrations/20160711071958-search-index.js new file mode 100644 index 000000000..5a73c0ec5 --- /dev/null +++ b/server/migrations/20160711071958-search-index.js @@ -0,0 +1,46 @@ +'use strict'; + +module.exports = { + up: function (queryInterface, Sequelize) { + const searchDocument = ` +ALTER TABLE documents ADD COLUMN "searchVector" tsvector; +CREATE INDEX documents_tsv_idx ON documents USING gin("searchVector"); + +CREATE FUNCTION documents_search_trigger() RETURNS trigger AS $$ +begin + new."searchVector" := + setweight(to_tsvector('english', coalesce(new.title, '')),'A') || + setweight(to_tsvector('english', coalesce(new.text, '')), 'C'); + return new; +end +$$ LANGUAGE plpgsql; + +CREATE TRIGGER documents_tsvectorupdate BEFORE INSERT OR UPDATE +ON documents FOR EACH ROW EXECUTE PROCEDURE documents_search_trigger(); + `; + + const searchAtlas = ` +ALTER TABLE atlases ADD COLUMN "searchVector" tsvector; +CREATE INDEX atlases_tsv_idx ON atlases USING gin("searchVector"); + +CREATE FUNCTION atlases_search_trigger() RETURNS trigger AS $$ +begin + new."searchVector" := + setweight(to_tsvector('english', coalesce(new.name, '')),'A') || + setweight(to_tsvector('english', coalesce(new.description, '')), 'C'); + return new; +end +$$ LANGUAGE plpgsql; + +CREATE TRIGGER atlases_tsvectorupdate BEFORE INSERT OR UPDATE +ON atlases FOR EACH ROW EXECUTE PROCEDURE atlases_search_trigger(); + `; + + queryInterface.sequelize.query(searchDocument); + queryInterface.sequelize.query(searchAtlas); + }, + + down: function (queryInterface, Sequelize) { + // TODO? + } +};