1 -- Functions for term normalisation and access to the 'word' table.
3 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
4 AS '{modulepath}/nominatim.so', 'transliteration'
5 LANGUAGE c IMMUTABLE STRICT;
8 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
9 AS '{modulepath}/nominatim.so', 'gettokenstring'
10 LANGUAGE c IMMUTABLE STRICT;
13 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
18 o := public.gettokenstring(public.transliteration(name));
19 RETURN trim(substr(o,1,length(o)));
22 LANGUAGE plpgsql IMMUTABLE;
24 -- returns NULL if the word is too common
25 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
30 return_word_id INTEGER;
33 lookup_token := trim(lookup_word);
34 SELECT min(word_id), max(search_name_count) FROM word
35 WHERE word_token = lookup_token and class is null and type is null
36 INTO return_word_id, count;
37 IF return_word_id IS NULL THEN
38 return_word_id := nextval('seq_word');
39 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
41 IF count > get_maxwordfreq() THEN
42 return_word_id := NULL;
45 RETURN return_word_id;
51 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
56 return_word_id INTEGER;
58 lookup_token := ' ' || trim(lookup_word);
59 SELECT min(word_id) FROM word
60 WHERE word_token = lookup_token and class='place' and type='house'
62 IF return_word_id IS NULL THEN
63 return_word_id := nextval('seq_word');
64 INSERT INTO word VALUES (return_word_id, lookup_token, null,
65 'place', 'house', null, 0);
67 RETURN return_word_id;
73 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
79 return_word_id INTEGER;
81 lookup_word := upper(trim(postcode));
82 lookup_token := ' ' || make_standard_name(lookup_word);
83 SELECT min(word_id) FROM word
84 WHERE word_token = lookup_token and class='place' and type='postcode'
86 IF return_word_id IS NULL THEN
87 return_word_id := nextval('seq_word');
88 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word,
89 'place', 'postcode', null, 0);
91 RETURN return_word_id;
97 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT,
98 lookup_country_code varchar(2))
103 return_word_id INTEGER;
105 lookup_token := ' '||trim(lookup_word);
106 SELECT min(word_id) FROM word
107 WHERE word_token = lookup_token and country_code=lookup_country_code
109 IF return_word_id IS NULL THEN
110 return_word_id := nextval('seq_word');
111 INSERT INTO word VALUES (return_word_id, lookup_token, null,
112 null, null, lookup_country_code, 0);
114 RETURN return_word_id;
120 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT,
121 lookup_class text, lookup_type 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 word = normalized_word
131 and class = lookup_class and type = lookup_type
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
136 lookup_class, lookup_type, null, 0);
138 RETURN return_word_id;
144 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT,
145 normalized_word TEXT,
153 return_word_id INTEGER;
155 lookup_token := ' '||trim(lookup_word);
156 SELECT min(word_id) FROM word
157 WHERE word_token = lookup_token and word = normalized_word
158 and class = lookup_class and type = lookup_type and operator = op
160 IF return_word_id IS NULL THEN
161 return_word_id := nextval('seq_word');
162 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
163 lookup_class, lookup_type, null, 0, op);
165 RETURN return_word_id;
171 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
176 nospace_lookup_token TEXT;
177 return_word_id INTEGER;
179 lookup_token := ' '||trim(lookup_word);
180 SELECT min(word_id) FROM word
181 WHERE word_token = lookup_token and class is null and type is null
183 IF return_word_id IS NULL THEN
184 return_word_id := nextval('seq_word');
185 INSERT INTO word VALUES (return_word_id, lookup_token, src_word,
186 null, null, null, 0);
188 RETURN return_word_id;
194 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
199 RETURN getorcreate_name_id(lookup_word, '');
205 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
210 return_word_id INTEGER;
212 lookup_token := trim(lookup_word);
213 SELECT min(word_id) FROM word
214 WHERE word_token = lookup_token and class is null and type is null
216 RETURN return_word_id;
219 LANGUAGE plpgsql STABLE;
222 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
227 return_word_id INTEGER;
229 lookup_token := ' '||trim(lookup_word);
230 SELECT min(word_id) FROM word
231 WHERE word_token = lookup_token and class is null and type is null
233 RETURN return_word_id;
236 LANGUAGE plpgsql STABLE;
239 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
244 return_word_ids INTEGER[];
246 lookup_token := ' '||trim(lookup_word);
247 SELECT array_agg(word_id) FROM word
248 WHERE word_token = lookup_token and class is null and type is null
249 INTO return_word_ids;
250 RETURN return_word_ids;
253 LANGUAGE plpgsql STABLE;
256 CREATE OR REPLACE FUNCTION create_country(src HSTORE, country_code varchar(2))
266 FOR item IN SELECT (each(src)).* LOOP
268 s := make_standard_name(item.value);
269 w := getorcreate_country(s, country_code);
271 words := regexp_split_to_array(item.value, E'[,;()]');
272 IF array_upper(words, 1) != 1 THEN
273 FOR j IN 1..array_upper(words, 1) LOOP
274 s := make_standard_name(words[j]);
276 w := getorcreate_country(s, country_code);
286 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE)
297 result := '{}'::INTEGER[];
299 FOR item IN SELECT (each(src)).* LOOP
301 s := make_standard_name(item.value);
302 w := getorcreate_name_id(s, item.value);
304 IF not(ARRAY[w] <@ result) THEN
305 result := result || w;
308 w := getorcreate_word_id(s);
310 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
311 result := result || w;
314 words := string_to_array(s, ' ');
315 IF array_upper(words, 1) IS NOT NULL THEN
316 FOR j IN 1..array_upper(words, 1) LOOP
317 IF (words[j] != '') THEN
318 w = getorcreate_word_id(words[j]);
319 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
320 result := result || w;
326 words := regexp_split_to_array(item.value, E'[,;()]');
327 IF array_upper(words, 1) != 1 THEN
328 FOR j IN 1..array_upper(words, 1) LOOP
329 s := make_standard_name(words[j]);
331 w := getorcreate_word_id(s);
332 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
333 result := result || w;
339 s := regexp_replace(item.value, '市$', '');
340 IF s != item.value THEN
341 s := make_standard_name(s);
343 w := getorcreate_name_id(s, item.value);
344 IF NOT (ARRAY[w] <@ result) THEN
345 result := result || w;
358 CREATE OR REPLACE FUNCTION make_keywords(src TEXT)
369 result := '{}'::INTEGER[];
371 s := make_standard_name(src);
372 w := getorcreate_name_id(s, src);
374 IF NOT (ARRAY[w] <@ result) THEN
375 result := result || w;
378 w := getorcreate_word_id(s);
380 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
381 result := result || w;
384 words := string_to_array(s, ' ');
385 IF array_upper(words, 1) IS NOT NULL THEN
386 FOR j IN 1..array_upper(words, 1) LOOP
387 IF (words[j] != '') THEN
388 w = getorcreate_word_id(words[j]);
389 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
390 result := result || w;
396 words := regexp_split_to_array(src, E'[,;()]');
397 IF array_upper(words, 1) != 1 THEN
398 FOR j IN 1..array_upper(words, 1) LOOP
399 s := make_standard_name(words[j]);
401 w := getorcreate_word_id(s);
402 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
403 result := result || w;
409 s := regexp_replace(src, '市$', '');
411 s := make_standard_name(s);
413 w := getorcreate_name_id(s, src);
414 IF NOT (ARRAY[w] <@ result) THEN
415 result := result || w;