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_has_addr_street(info JSONB)
47 SELECT info->>'street' is not null;
48 $$ LANGUAGE SQL IMMUTABLE;
51 CREATE OR REPLACE FUNCTION token_has_addr_place(info JSONB)
54 SELECT info->>'place' is not null;
55 $$ LANGUAGE SQL IMMUTABLE;
58 CREATE OR REPLACE FUNCTION token_matches_street(info JSONB, street_tokens INTEGER[])
61 SELECT (info->>'street')::INTEGER[] && street_tokens
62 $$ LANGUAGE SQL IMMUTABLE STRICT;
65 CREATE OR REPLACE FUNCTION token_matches_place(info JSONB, place_tokens INTEGER[])
68 SELECT (info->>'place')::INTEGER[] <@ place_tokens
69 $$ LANGUAGE SQL IMMUTABLE STRICT;
72 CREATE OR REPLACE FUNCTION token_addr_place_search_tokens(info JSONB)
75 SELECT (info->>'place')::INTEGER[]
76 $$ LANGUAGE SQL IMMUTABLE STRICT;
79 CREATE OR REPLACE FUNCTION token_get_address_keys(info JSONB)
82 SELECT * FROM jsonb_object_keys(info->'addr');
83 $$ LANGUAGE SQL IMMUTABLE STRICT;
86 CREATE OR REPLACE FUNCTION token_get_address_search_tokens(info JSONB, key TEXT)
89 SELECT (info->'addr'->>key)::INTEGER[];
90 $$ LANGUAGE SQL IMMUTABLE STRICT;
93 CREATE OR REPLACE FUNCTION token_matches_address(info JSONB, key TEXT, tokens INTEGER[])
96 SELECT (info->'addr'->>key)::INTEGER[] <@ tokens;
97 $$ LANGUAGE SQL IMMUTABLE STRICT;
100 CREATE OR REPLACE FUNCTION token_normalized_postcode(postcode TEXT)
103 SELECT CASE WHEN postcode SIMILAR TO '%(,|;)%' THEN NULL ELSE upper(trim(postcode))END;
104 $$ LANGUAGE SQL IMMUTABLE STRICT;
107 -- Return token info that should be saved permanently in the database.
108 CREATE OR REPLACE FUNCTION token_strip_info(info JSONB)
112 $$ LANGUAGE SQL IMMUTABLE STRICT;
114 --------------- private functions ----------------------------------------------
116 CREATE OR REPLACE FUNCTION getorcreate_full_word(norm_term TEXT, lookup_terms TEXT[],
118 OUT partial_tokens INT[])
121 partial_terms TEXT[] = '{}'::TEXT[];
126 SELECT min(word_id) INTO full_token
127 FROM word WHERE word = norm_term and type = 'W';
129 IF full_token IS NULL THEN
130 full_token := nextval('seq_word');
131 INSERT INTO word (word_id, word_token, type, word, info)
132 SELECT full_token, lookup_term, 'W', norm_term,
133 json_build_object('count', 0)
134 FROM unnest(lookup_terms) as lookup_term;
137 FOR term IN SELECT unnest(string_to_array(unnest(lookup_terms), ' ')) LOOP
139 IF NOT (ARRAY[term] <@ partial_terms) THEN
140 partial_terms := partial_terms || term;
144 partial_tokens := '{}'::INT[];
145 FOR term IN SELECT unnest(partial_terms) LOOP
146 SELECT min(word_id), max(info->>'count') INTO term_id, term_count
147 FROM word WHERE word_token = term and type = 'w';
149 IF term_id IS NULL THEN
150 term_id := nextval('seq_word');
152 INSERT INTO word (word_id, word_token, type, info)
153 VALUES (term_id, term, 'w', json_build_object('count', term_count));
156 partial_tokens := array_merge(partial_tokens, ARRAY[term_id]);
163 CREATE OR REPLACE FUNCTION getorcreate_partial_word(partial TEXT)
169 SELECT min(word_id) INTO token
170 FROM word WHERE word_token = partial and type = 'w';
172 IF token IS NULL THEN
173 token := nextval('seq_word');
174 INSERT INTO word (word_id, word_token, type, info)
175 VALUES (token, partial, 'w', json_build_object('count', 0));
184 CREATE OR REPLACE FUNCTION getorcreate_hnr_id(lookup_term TEXT)
190 SELECT min(word_id) INTO return_id FROM word
191 WHERE word_token = lookup_term and type = 'H';
193 IF return_id IS NULL THEN
194 return_id := nextval('seq_word');
195 INSERT INTO word (word_id, word_token, type)
196 VALUES (return_id, lookup_term, 'H');
205 CREATE OR REPLACE FUNCTION create_analyzed_hnr_id(norm_term TEXT, lookup_terms TEXT[])
211 SELECT min(word_id) INTO return_id
212 FROM word WHERE word = norm_term and type = 'H';
214 IF return_id IS NULL THEN
215 return_id := nextval('seq_word');
216 INSERT INTO word (word_id, word_token, type, word, info)
217 SELECT return_id, lookup_term, 'H', norm_term,
218 json_build_object('lookup', lookup_terms[1])
219 FROM unnest(lookup_terms) as lookup_term;
227 CREATE OR REPLACE FUNCTION create_postcode_word(postcode TEXT, lookup_terms TEXT[])
233 SELECT count(*) INTO existing
234 FROM word WHERE word = postcode and type = 'P';
240 -- postcodes don't need word ids
241 INSERT INTO word (word_token, type, word)
242 SELECT lookup_term, 'P', postcode FROM unnest(lookup_terms) as lookup_term;