1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2022 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- Get tokens used for searching the given place.
10 -- These are the tokens that will be saved in the search_name table.
11 CREATE OR REPLACE FUNCTION token_get_name_search_tokens(info JSONB)
14 SELECT (info->>'names')::INTEGER[]
15 $$ LANGUAGE SQL IMMUTABLE STRICT;
18 -- Get tokens for matching the place name against others.
20 -- This should usually be restricted to full name tokens.
21 CREATE OR REPLACE FUNCTION token_get_name_match_tokens(info JSONB)
24 SELECT (info->>'names')::INTEGER[]
25 $$ LANGUAGE SQL IMMUTABLE STRICT;
28 -- Return the housenumber tokens applicable for the place.
29 CREATE OR REPLACE FUNCTION token_get_housenumber_search_tokens(info JSONB)
32 SELECT (info->>'hnr_tokens')::INTEGER[]
33 $$ LANGUAGE SQL IMMUTABLE STRICT;
36 -- Return the housenumber in the form that it can be matched during search.
37 CREATE OR REPLACE FUNCTION token_normalized_housenumber(info JSONB)
41 $$ LANGUAGE SQL IMMUTABLE STRICT;
44 CREATE OR REPLACE FUNCTION token_is_street_address(info JSONB)
47 SELECT info->>'street' is not null or info->>'place' is null;
48 $$ LANGUAGE SQL IMMUTABLE;
51 CREATE OR REPLACE FUNCTION token_has_addr_street(info JSONB)
54 SELECT info->>'street' is not null;
55 $$ LANGUAGE SQL IMMUTABLE;
58 CREATE OR REPLACE FUNCTION token_has_addr_place(info JSONB)
61 SELECT info->>'place_match' is not null;
62 $$ LANGUAGE SQL IMMUTABLE;
65 CREATE OR REPLACE FUNCTION token_matches_street(info JSONB, street_tokens INTEGER[])
68 SELECT (info->>'street')::INTEGER[] && street_tokens
69 $$ LANGUAGE SQL IMMUTABLE STRICT;
72 CREATE OR REPLACE FUNCTION token_matches_place(info JSONB, place_tokens INTEGER[])
75 SELECT (info->>'place_match')::INTEGER[] && place_tokens
76 $$ LANGUAGE SQL IMMUTABLE STRICT;
79 CREATE OR REPLACE FUNCTION token_addr_place_search_tokens(info JSONB)
82 SELECT (info->>'place_search')::INTEGER[]
83 $$ LANGUAGE SQL IMMUTABLE STRICT;
86 CREATE OR REPLACE FUNCTION token_get_address_keys(info JSONB)
89 SELECT * FROM jsonb_object_keys(info->'addr');
90 $$ LANGUAGE SQL IMMUTABLE STRICT;
93 CREATE OR REPLACE FUNCTION token_get_address_search_tokens(info JSONB, key TEXT)
96 SELECT (info->'addr'->key->>0)::INTEGER[];
97 $$ LANGUAGE SQL IMMUTABLE STRICT;
100 CREATE OR REPLACE FUNCTION token_matches_address(info JSONB, key TEXT, tokens INTEGER[])
103 SELECT (info->'addr'->key->>1)::INTEGER[] && tokens;
104 $$ LANGUAGE SQL IMMUTABLE STRICT;
107 CREATE OR REPLACE FUNCTION token_get_postcode(info JSONB)
110 SELECT info->>'postcode';
111 $$ LANGUAGE SQL IMMUTABLE STRICT;
114 -- Return token info that should be saved permanently in the database.
115 CREATE OR REPLACE FUNCTION token_strip_info(info JSONB)
119 $$ LANGUAGE SQL IMMUTABLE STRICT;
121 --------------- private functions ----------------------------------------------
123 -- Functions for term normalisation and access to the 'word' table.
125 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
126 AS '{{ modulepath }}/nominatim.so', 'transliteration'
127 LANGUAGE c IMMUTABLE STRICT;
130 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
131 AS '{{ modulepath }}/nominatim.so', 'gettokenstring'
132 LANGUAGE c IMMUTABLE STRICT;
135 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
140 o := public.gettokenstring(public.transliteration(name));
141 RETURN trim(substr(o,1,length(o)));
144 LANGUAGE plpgsql IMMUTABLE;
146 -- returns NULL if the word is too common
147 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
152 return_word_id INTEGER;
155 lookup_token := trim(lookup_word);
156 SELECT min(word_id), max(search_name_count) FROM word
157 WHERE word_token = lookup_token and class is null and type is null
158 INTO return_word_id, count;
159 IF return_word_id IS NULL THEN
160 return_word_id := nextval('seq_word');
161 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
163 IF count > {{ max_word_freq }} THEN
164 return_word_id := NULL;
167 RETURN return_word_id;
173 -- Create housenumber tokens from an OSM addr:housenumber.
174 -- The housnumber is split at comma and semicolon as necessary.
175 -- The function returns the normalized form of the housenumber suitable
177 CREATE OR REPLACE FUNCTION create_housenumbers(housenumbers TEXT[],
182 SELECT array_to_string(array_agg(trans), ';'), array_agg(tid)::TEXT
183 INTO normtext, tokens
184 FROM (SELECT lookup_word as trans, getorcreate_housenumber_id(lookup_word) as tid
185 FROM (SELECT make_standard_name(h) as lookup_word
186 FROM unnest(housenumbers) h) x) y;
188 $$ LANGUAGE plpgsql STABLE STRICT;
191 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
196 return_word_id INTEGER;
198 lookup_token := ' ' || trim(lookup_word);
199 SELECT min(word_id) FROM word
200 WHERE word_token = lookup_token and class='place' and type='house'
202 IF return_word_id IS NULL THEN
203 return_word_id := nextval('seq_word');
204 INSERT INTO word VALUES (return_word_id, lookup_token, null,
205 'place', 'house', null, 0);
207 RETURN return_word_id;
213 CREATE OR REPLACE FUNCTION create_postcode_id(postcode TEXT)
219 return_word_id INTEGER;
221 lookup_token := ' ' || make_standard_name(postcode);
223 SELECT word_id FROM word
224 WHERE word_token = lookup_token and word = postcode
225 and class='place' and type='postcode'
230 INSERT INTO word VALUES (nextval('seq_word'), lookup_token, postcode,
231 'place', 'postcode', null, 0);
238 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
243 nospace_lookup_token TEXT;
244 return_word_id INTEGER;
246 lookup_token := ' '||trim(lookup_word);
247 SELECT min(word_id) FROM word
248 WHERE word_token = lookup_token and class is null and type is null
250 IF return_word_id IS NULL THEN
251 return_word_id := nextval('seq_word');
252 INSERT INTO word VALUES (return_word_id, lookup_token, src_word,
253 null, null, null, 0);
255 RETURN return_word_id;
261 -- Normalize a string and lookup its word ids (partial words).
262 CREATE OR REPLACE FUNCTION addr_ids_from_name(lookup_word TEXT)
268 return_word_id INTEGER[];
272 words := string_to_array(make_standard_name(lookup_word), ' ');
273 IF array_upper(words, 1) IS NOT NULL THEN
274 FOR j IN 1..array_upper(words, 1) LOOP
275 IF (words[j] != '') THEN
276 SELECT array_agg(word_id) INTO word_ids
278 WHERE word_token = words[j] and class is null and type is null;
280 IF word_ids IS NULL THEN
281 id := nextval('seq_word');
282 INSERT INTO word VALUES (id, words[j], null, null, null, null, 0);
283 return_word_id := return_word_id || id;
285 return_word_id := array_merge(return_word_id, word_ids);
291 RETURN return_word_id;
297 -- Normalize a string and look up its name ids (full words).
298 CREATE OR REPLACE FUNCTION word_ids_from_name(lookup_word TEXT)
303 return_word_ids INTEGER[];
305 lookup_token := ' '|| make_standard_name(lookup_word);
306 SELECT array_agg(word_id) FROM word
307 WHERE word_token = lookup_token and class is null and type is null
308 INTO return_word_ids;
309 RETURN return_word_ids;
312 LANGUAGE plpgsql STABLE STRICT;
315 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE)
326 result := '{}'::INTEGER[];
328 FOR value IN SELECT unnest(regexp_split_to_array(svals(src), E'[,;]')) LOOP
330 s := make_standard_name(value);
331 w := getorcreate_name_id(s, value);
333 IF not(ARRAY[w] <@ result) THEN
334 result := result || w;
337 -- partial single-word terms
338 words := string_to_array(s, ' ');
339 IF array_upper(words, 1) IS NOT NULL THEN
340 FOR j IN 1..array_upper(words, 1) LOOP
341 IF (words[j] != '') THEN
342 w = getorcreate_word_id(words[j]);
343 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
344 result := result || w;
350 -- consider parts before an opening braket a full word as well
351 words := regexp_split_to_array(value, E'[(]');
352 IF array_upper(words, 1) > 1 THEN
353 s := make_standard_name(words[1]);
355 w := getorcreate_name_id(s, words[1]);
356 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
357 result := result || w;
362 s := regexp_replace(value, '市$', '');
364 s := make_standard_name(s);
366 w := getorcreate_name_id(s, value);
367 IF NOT (ARRAY[w] <@ result) THEN
368 result := result || w;
381 CREATE OR REPLACE FUNCTION precompute_words(src TEXT)
391 s := make_standard_name(src);
392 w := getorcreate_name_id(s, src);
394 w := getorcreate_word_id(s);
396 words := string_to_array(s, ' ');
397 IF array_upper(words, 1) IS NOT NULL THEN
398 FOR j IN 1..array_upper(words, 1) LOOP
399 IF (words[j] != '') THEN
400 w := getorcreate_word_id(words[j]);
405 words := regexp_split_to_array(src, E'[,;()]');
406 IF array_upper(words, 1) != 1 THEN
407 FOR j IN 1..array_upper(words, 1) LOOP
408 s := make_standard_name(words[j]);
410 w := getorcreate_word_id(s);
415 s := regexp_replace(src, '市$', '');
417 s := make_standard_name(s);
419 w := getorcreate_name_id(s, src);