1 -- Get tokens used for searching the given place.
3 -- These are the tokens that will be saved in the search_name table.
4 CREATE OR REPLACE FUNCTION token_get_name_search_tokens(info JSONB)
7 SELECT (info->>'names')::INTEGER[]
8 $$ LANGUAGE SQL IMMUTABLE STRICT;
11 -- Get tokens for matching the place name against others.
13 -- This should usually be restricted to full name tokens.
14 CREATE OR REPLACE FUNCTION token_get_name_match_tokens(info JSONB)
17 SELECT (info->>'names')::INTEGER[]
18 $$ LANGUAGE SQL IMMUTABLE STRICT;
21 -- Return the housenumber tokens applicable for the place.
22 CREATE OR REPLACE FUNCTION token_get_housenumber_search_tokens(info JSONB)
25 SELECT (info->>'hnr_tokens')::INTEGER[]
26 $$ LANGUAGE SQL IMMUTABLE STRICT;
29 -- Return the housenumber in the form that it can be matched during search.
30 CREATE OR REPLACE FUNCTION token_normalized_housenumber(info JSONB)
34 $$ LANGUAGE SQL IMMUTABLE STRICT;
37 CREATE OR REPLACE FUNCTION token_normalized_postcode(postcode TEXT)
40 SELECT CASE WHEN postcode SIMILAR TO '%(,|;)%' THEN NULL ELSE upper(trim(postcode))END;
41 $$ LANGUAGE SQL IMMUTABLE STRICT;
44 -- Return token info that should be saved permanently in the database.
45 CREATE OR REPLACE FUNCTION token_strip_info(info JSONB)
49 $$ LANGUAGE SQL IMMUTABLE STRICT;
51 --------------- private functions ----------------------------------------------
53 -- Functions for term normalisation and access to the 'word' table.
55 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
56 AS '{{ modulepath }}/nominatim.so', 'transliteration'
57 LANGUAGE c IMMUTABLE STRICT;
60 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
61 AS '{{ modulepath }}/nominatim.so', 'gettokenstring'
62 LANGUAGE c IMMUTABLE STRICT;
65 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
70 o := public.gettokenstring(public.transliteration(name));
71 RETURN trim(substr(o,1,length(o)));
74 LANGUAGE plpgsql IMMUTABLE;
76 -- returns NULL if the word is too common
77 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
82 return_word_id INTEGER;
85 lookup_token := trim(lookup_word);
86 SELECT min(word_id), max(search_name_count) FROM word
87 WHERE word_token = lookup_token and class is null and type is null
88 INTO return_word_id, count;
89 IF return_word_id IS NULL THEN
90 return_word_id := nextval('seq_word');
91 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
93 IF count > {{ max_word_freq }} THEN
94 return_word_id := NULL;
97 RETURN return_word_id;
103 -- Create housenumber tokens from an OSM addr:housenumber.
104 -- The housnumber is split at comma and semicolon as necessary.
105 -- The function returns the normalized form of the housenumber suitable
107 CREATE OR REPLACE FUNCTION create_housenumbers(housenumbers TEXT[],
112 SELECT array_to_string(array_agg(trans), ';'), array_agg(tid)::TEXT
113 INTO normtext, tokens
114 FROM (SELECT lookup_word as trans, getorcreate_housenumber_id(lookup_word) as tid
115 FROM (SELECT make_standard_name(h) as lookup_word
116 FROM unnest(housenumbers) h) x) y;
118 $$ LANGUAGE plpgsql STABLE STRICT;
121 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
126 return_word_id INTEGER;
128 lookup_token := ' ' || trim(lookup_word);
129 SELECT min(word_id) FROM word
130 WHERE word_token = lookup_token and class='place' and type='house'
132 IF return_word_id IS NULL THEN
133 return_word_id := nextval('seq_word');
134 INSERT INTO word VALUES (return_word_id, lookup_token, null,
135 'place', 'house', null, 0);
137 RETURN return_word_id;
143 CREATE OR REPLACE FUNCTION create_postcode_id(postcode TEXT)
149 return_word_id INTEGER;
151 lookup_token := ' ' || make_standard_name(postcode);
153 SELECT word_id FROM word
154 WHERE word_token = lookup_token and word = postcode
155 and class='place' and type='postcode'
160 INSERT INTO word VALUES (nextval('seq_word'), lookup_token, postcode,
161 'place', 'postcode', null, 0);
168 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT,
169 lookup_country_code varchar(2))
174 return_word_id INTEGER;
176 lookup_token := ' '||trim(lookup_word);
177 SELECT min(word_id) FROM word
178 WHERE word_token = lookup_token and country_code=lookup_country_code
180 IF return_word_id IS NULL THEN
181 return_word_id := nextval('seq_word');
182 INSERT INTO word VALUES (return_word_id, lookup_token, null,
183 null, null, lookup_country_code, 0);
185 RETURN return_word_id;
191 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT,
192 lookup_class text, lookup_type text)
197 return_word_id INTEGER;
199 lookup_token := ' '||trim(lookup_word);
200 SELECT min(word_id) FROM word
201 WHERE word_token = lookup_token and word = normalized_word
202 and class = lookup_class and type = lookup_type
204 IF return_word_id IS NULL THEN
205 return_word_id := nextval('seq_word');
206 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
207 lookup_class, lookup_type, null, 0);
209 RETURN return_word_id;
215 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT,
216 normalized_word TEXT,
224 return_word_id INTEGER;
226 lookup_token := ' '||trim(lookup_word);
227 SELECT min(word_id) FROM word
228 WHERE word_token = lookup_token and word = normalized_word
229 and class = lookup_class and type = lookup_type and operator = op
231 IF return_word_id IS NULL THEN
232 return_word_id := nextval('seq_word');
233 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
234 lookup_class, lookup_type, null, 0, op);
236 RETURN return_word_id;
242 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
247 nospace_lookup_token TEXT;
248 return_word_id INTEGER;
250 lookup_token := ' '||trim(lookup_word);
251 SELECT min(word_id) FROM word
252 WHERE word_token = lookup_token and class is null and type is null
254 IF return_word_id IS NULL THEN
255 return_word_id := nextval('seq_word');
256 INSERT INTO word VALUES (return_word_id, lookup_token, src_word,
257 null, null, null, 0);
259 RETURN return_word_id;
265 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
270 RETURN getorcreate_name_id(lookup_word, '');
275 -- Normalize a string and lookup its word ids (partial words).
276 CREATE OR REPLACE FUNCTION addr_ids_from_name(lookup_word TEXT)
282 return_word_id INTEGER[];
286 words := string_to_array(make_standard_name(lookup_word), ' ');
287 IF array_upper(words, 1) IS NOT NULL THEN
288 FOR j IN 1..array_upper(words, 1) LOOP
289 IF (words[j] != '') THEN
290 SELECT array_agg(word_id) INTO word_ids
292 WHERE word_token = words[j] and class is null and type is null;
294 IF word_ids IS NULL THEN
295 id := nextval('seq_word');
296 INSERT INTO word VALUES (id, words[j], null, null, null, null, 0);
297 return_word_id := return_word_id || id;
299 return_word_id := array_merge(return_word_id, word_ids);
305 RETURN return_word_id;
311 -- Normalize a string and look up its name ids (full words).
312 CREATE OR REPLACE FUNCTION word_ids_from_name(lookup_word TEXT)
317 return_word_ids INTEGER[];
319 lookup_token := ' '|| make_standard_name(lookup_word);
320 SELECT array_agg(word_id) FROM word
321 WHERE word_token = lookup_token and class is null and type is null
322 INTO return_word_ids;
323 RETURN return_word_ids;
326 LANGUAGE plpgsql STABLE STRICT;
329 CREATE OR REPLACE FUNCTION create_country(src HSTORE, country_code varchar(2))
339 FOR item IN SELECT (each(src)).* LOOP
341 s := make_standard_name(item.value);
342 w := getorcreate_country(s, country_code);
344 words := regexp_split_to_array(item.value, E'[,;()]');
345 IF array_upper(words, 1) != 1 THEN
346 FOR j IN 1..array_upper(words, 1) LOOP
347 s := make_standard_name(words[j]);
349 w := getorcreate_country(s, country_code);
359 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE)
370 result := '{}'::INTEGER[];
372 FOR item IN SELECT (each(src)).* LOOP
374 s := make_standard_name(item.value);
375 w := getorcreate_name_id(s, item.value);
377 IF not(ARRAY[w] <@ result) THEN
378 result := result || w;
381 w := getorcreate_word_id(s);
383 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
384 result := result || w;
387 words := string_to_array(s, ' ');
388 IF array_upper(words, 1) IS NOT NULL THEN
389 FOR j IN 1..array_upper(words, 1) LOOP
390 IF (words[j] != '') THEN
391 w = getorcreate_word_id(words[j]);
392 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
393 result := result || w;
399 words := regexp_split_to_array(item.value, E'[,;()]');
400 IF array_upper(words, 1) != 1 THEN
401 FOR j IN 1..array_upper(words, 1) LOOP
402 s := make_standard_name(words[j]);
404 w := getorcreate_word_id(s);
405 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
406 result := result || w;
412 s := regexp_replace(item.value, '市$', '');
413 IF s != item.value THEN
414 s := make_standard_name(s);
416 w := getorcreate_name_id(s, item.value);
417 IF NOT (ARRAY[w] <@ result) THEN
418 result := result || w;
431 CREATE OR REPLACE FUNCTION precompute_words(src TEXT)
441 s := make_standard_name(src);
442 w := getorcreate_name_id(s, src);
444 w := getorcreate_word_id(s);
446 words := string_to_array(s, ' ');
447 IF array_upper(words, 1) IS NOT NULL THEN
448 FOR j IN 1..array_upper(words, 1) LOOP
449 IF (words[j] != '') THEN
450 w := getorcreate_word_id(words[j]);
455 words := regexp_split_to_array(src, E'[,;()]');
456 IF array_upper(words, 1) != 1 THEN
457 FOR j IN 1..array_upper(words, 1) LOOP
458 s := make_standard_name(words[j]);
460 w := getorcreate_word_id(s);
465 s := regexp_replace(src, '市$', '');
467 s := make_standard_name(s);
469 w := getorcreate_name_id(s, src);