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 PARALLEL SAFE;
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 PARALLEL SAFE;
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 PARALLEL SAFE;
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 PARALLEL SAFE;
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 PARALLEL SAFE;
51 CREATE OR REPLACE FUNCTION token_has_addr_street(info JSONB)
54 SELECT info->>'street' is not null and info->>'street' != '{}';
55 $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
58 CREATE OR REPLACE FUNCTION token_has_addr_place(info JSONB)
61 SELECT info->>'place' is not null;
62 $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
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 PARALLEL SAFE;
72 CREATE OR REPLACE FUNCTION token_matches_place(info JSONB, place_tokens INTEGER[])
75 SELECT (info->>'place')::INTEGER[] <@ place_tokens
76 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
79 CREATE OR REPLACE FUNCTION token_addr_place_search_tokens(info JSONB)
82 SELECT (info->>'place')::INTEGER[]
83 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
86 CREATE OR REPLACE FUNCTION token_get_address_keys(info JSONB)
89 SELECT * FROM jsonb_object_keys(info->'addr');
90 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
93 CREATE OR REPLACE FUNCTION token_get_address_search_tokens(info JSONB, key TEXT)
96 SELECT (info->'addr'->>key)::INTEGER[];
97 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
100 CREATE OR REPLACE FUNCTION token_matches_address(info JSONB, key TEXT, tokens INTEGER[])
103 SELECT (info->'addr'->>key)::INTEGER[] <@ tokens;
104 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
107 CREATE OR REPLACE FUNCTION token_get_postcode(info JSONB)
110 SELECT info->>'postcode';
111 $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
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 PARALLEL SAFE;
121 --------------- private functions ----------------------------------------------
123 CREATE OR REPLACE FUNCTION getorcreate_full_word(norm_term TEXT, lookup_terms TEXT[],
125 OUT partial_tokens INT[])
128 partial_terms TEXT[] = '{}'::TEXT[];
132 SELECT min(word_id) INTO full_token
133 FROM word WHERE word = norm_term and type = 'W';
135 IF full_token IS NULL THEN
136 full_token := nextval('seq_word');
137 INSERT INTO word (word_id, word_token, type, word)
138 SELECT full_token, lookup_term, 'W', norm_term
139 FROM unnest(lookup_terms) as lookup_term;
142 FOR term IN SELECT unnest(string_to_array(unnest(lookup_terms), ' ')) LOOP
144 IF NOT (ARRAY[term] <@ partial_terms) THEN
145 partial_terms := partial_terms || term;
149 partial_tokens := '{}'::INT[];
150 FOR term IN SELECT unnest(partial_terms) LOOP
151 SELECT min(word_id) INTO term_id
152 FROM word WHERE word_token = term and type = 'w';
154 IF term_id IS NULL THEN
155 term_id := nextval('seq_word');
156 INSERT INTO word (word_id, word_token, type)
157 VALUES (term_id, term, 'w');
160 partial_tokens := array_merge(partial_tokens, ARRAY[term_id]);
167 CREATE OR REPLACE FUNCTION getorcreate_full_word(norm_term TEXT,
169 lookup_norm_terms TEXT[],
171 OUT partial_tokens INT[])
174 partial_terms TEXT[] = '{}'::TEXT[];
178 SELECT min(word_id) INTO full_token
179 FROM word WHERE word = norm_term and type = 'W';
181 IF full_token IS NULL THEN
182 full_token := nextval('seq_word');
183 IF lookup_norm_terms IS NULL THEN
184 INSERT INTO word (word_id, word_token, type, word)
185 SELECT full_token, lookup_term, 'W', norm_term
186 FROM unnest(lookup_terms) as lookup_term;
188 INSERT INTO word (word_id, word_token, type, word, info)
189 SELECT full_token, t.lookup, 'W', norm_term,
190 CASE WHEN norm_term = t.norm THEN null
191 ELSE json_build_object('lookup', t.norm) END
192 FROM unnest(lookup_terms, lookup_norm_terms) as t(lookup, norm);
196 FOR term IN SELECT unnest(string_to_array(unnest(lookup_terms), ' ')) LOOP
198 IF NOT (ARRAY[term] <@ partial_terms) THEN
199 partial_terms := partial_terms || term;
203 partial_tokens := '{}'::INT[];
204 FOR term IN SELECT unnest(partial_terms) LOOP
205 SELECT min(word_id) INTO term_id
206 FROM word WHERE word_token = term and type = 'w';
208 IF term_id IS NULL THEN
209 term_id := nextval('seq_word');
210 INSERT INTO word (word_id, word_token, type)
211 VALUES (term_id, term, 'w');
214 partial_tokens := array_merge(partial_tokens, ARRAY[term_id]);
221 CREATE OR REPLACE FUNCTION getorcreate_partial_word(partial TEXT)
227 SELECT min(word_id) INTO token
228 FROM word WHERE word_token = partial and type = 'w';
230 IF token IS NULL THEN
231 token := nextval('seq_word');
232 INSERT INTO word (word_id, word_token, type, info)
233 VALUES (token, partial, 'w', json_build_object('count', 0));
242 CREATE OR REPLACE FUNCTION getorcreate_hnr_id(lookup_term TEXT)
248 SELECT min(word_id) INTO return_id FROM word
249 WHERE word_token = lookup_term and type = 'H';
251 IF return_id IS NULL THEN
252 return_id := nextval('seq_word');
253 INSERT INTO word (word_id, word_token, type)
254 VALUES (return_id, lookup_term, 'H');
263 CREATE OR REPLACE FUNCTION create_analyzed_hnr_id(norm_term TEXT, lookup_terms TEXT[])
269 SELECT min(word_id) INTO return_id
270 FROM word WHERE word = norm_term and type = 'H';
272 IF return_id IS NULL THEN
273 return_id := nextval('seq_word');
274 INSERT INTO word (word_id, word_token, type, word, info)
275 SELECT return_id, lookup_term, 'H', norm_term,
276 json_build_object('lookup', lookup_terms[1])
277 FROM unnest(lookup_terms) as lookup_term;
285 CREATE OR REPLACE FUNCTION create_postcode_word(postcode TEXT, lookup_terms TEXT[])
291 SELECT count(*) INTO existing
292 FROM word WHERE word = postcode and type = 'P';
298 -- postcodes don't need word ids
299 INSERT INTO word (word_token, type, word)
300 SELECT lookup_term, 'P', postcode FROM unnest(lookup_terms) as lookup_term;