From b7cbb5d55f51ba3ee35cf1e13afadf2dd90d7431 Mon Sep 17 00:00:00 2001 From: Tom Russell Date: Tue, 22 Jan 2019 22:38:00 +0000 Subject: [PATCH] Draft search box db table --- migrations/008.search.up.sql | 31 +++++++++++++++++++++++++++++++ 1 file changed, 31 insertions(+) create mode 100644 migrations/008.search.up.sql diff --git a/migrations/008.search.up.sql b/migrations/008.search.up.sql new file mode 100644 index 00000000..c780c6d0 --- /dev/null +++ b/migrations/008.search.up.sql @@ -0,0 +1,31 @@ +-- +-- Set up search table for text search over locations +-- +-- uses extension: CREATE EXTENSION pg_trgm; +-- + +CREATE TABLE IF NOT EXISTS search_locations ( + -- internal unique id + search_id serial PRIMARY KEY, + -- string to match against in search (E1 0AB / Hackney / Commercial Road...) + search_str text, + -- search class for hint (postcode / borough / road name...) + search_class text, + -- geometry as EPSG:4326 (lat-long) to be used in front end directly + center geometry(POINT, 4326), + -- zoom level + zoom int +); + +-- Index for fuzzy match +-- see https://www.postgresql.org/docs/current/pgtrgm.html +-- and https://www.postgresql.org/docs/current/textsearch-indexes.html +-- +-- Should support (I)LIKE or similarity searches: +-- - SELECT * FROM search_locations WHERE search_str ILIKE 'e1%' +-- - SELECT *, search_str <-> 'searchterm' AS dist FROM search_locations ORDER BY dist LIMIT 5; +-- - SELECT *, similarity(search_str, 'searchterm') AS dist FROM search_locations +-- WHERE t % 'searchterm' ORDER BY dist DESC, t LIMIT 5; +-- Docs suggest the second query will perform better than the third, when only a small number +-- of closest matches are desired, if combined with a GIST index (not GIN as below), +CREATE INDEX trgm_idx_search_str ON search_locations USING GIN (search_str gin_trgm_ops);