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 -- Functions for returning address information for a place.
10 DROP TYPE IF EXISTS addressline CASCADE;
11 CREATE TYPE addressline as (
27 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[])
37 FOR j IN 1..array_upper(languagepref,1) LOOP
38 IF name ? languagepref[j] THEN
39 result := trim(name->languagepref[j]);
46 -- anything will do as a fallback - just take the first name type thing there is
47 RETURN trim((avals(name))[1]);
50 LANGUAGE plpgsql IMMUTABLE;
53 --housenumber only needed for tiger data
54 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT,
71 CASE WHEN place_id = for_place_id THEN 99 ELSE rank_address END as rank_address
72 FROM get_addressdata(for_place_id, housenumber)
73 WHERE isaddress order by rank_address desc
75 currresult := trim(get_name_by_language(location.name, languagepref));
76 IF currresult != prevresult AND currresult IS NOT NULL
77 AND result[(100 - location.rank_address)] IS NULL
79 result[(100 - location.rank_address)] := currresult;
80 prevresult := currresult;
84 RETURN array_to_string(result,', ');
87 LANGUAGE plpgsql STABLE;
89 DROP TYPE IF EXISTS addressdata_place;
90 CREATE TYPE addressdata_place AS (
92 country_code VARCHAR(2),
102 -- Compute the list of address parts for the given place.
104 -- If in_housenumber is greator or equal 0, look for an interpolation.
105 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER)
106 RETURNS setof addressline
109 place addressdata_place;
111 current_rank_address INTEGER;
112 location_isaddress BOOLEAN;
114 -- The place in question might not have a direct entry in place_addressline.
115 -- Look for the parent of such places then and save it in place.
117 -- first query osmline (interpolation lines)
118 IF in_housenumber >= 0 THEN
119 SELECT parent_place_id as place_id, country_code,
120 in_housenumber as housenumber, postcode,
121 'place' as class, 'house' as type,
122 null as name, null as address,
123 ST_Centroid(linegeo) as centroid
125 FROM location_property_osmline
126 WHERE place_id = in_place_id
127 AND in_housenumber between startnumber and endnumber;
130 --then query tiger data
131 {% if config.get_bool('USE_US_TIGER_DATA') %}
132 IF place IS NULL AND in_housenumber >= 0 THEN
133 SELECT parent_place_id as place_id, 'us' as country_code,
134 in_housenumber as housenumber, postcode,
135 'place' as class, 'house' as type,
136 null as name, null as address,
137 ST_Centroid(linegeo) as centroid
139 FROM location_property_tiger
140 WHERE place_id = in_place_id
141 AND in_housenumber between startnumber and endnumber;
146 IF place IS NULL THEN
147 SELECT parent_place_id as place_id, country_code,
148 null::text as housenumber, postcode,
149 'place' as class, 'postcode' as type,
150 null as name, null as address,
153 FROM location_postcode
154 WHERE place_id = in_place_id;
157 -- POI objects in the placex table
158 IF place IS NULL THEN
159 SELECT parent_place_id as place_id, country_code,
160 coalesce(address->'housenumber',
161 address->'streetnumber',
162 address->'conscriptionnumber')::text as housenumber,
169 WHERE place_id = in_place_id and rank_search > 27;
172 -- If place is still NULL at this point then the object has its own
173 -- entry in place_address line. However, still check if there is not linked
174 -- place we should be using instead.
175 IF place IS NULL THEN
176 select coalesce(linked_place_id, place_id) as place_id, country_code,
177 null::text as housenumber, postcode,
179 null as name, address,
182 FROM placex where place_id = in_place_id;
185 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
187 -- --- Return the record for the base entry.
190 SELECT placex.place_id, osm_type, osm_id, name,
191 coalesce(extratags->'linked_place', extratags->'place') as place_type,
192 class, type, admin_level,
193 CASE WHEN rank_address = 0 THEN 100
194 WHEN rank_address = 11 THEN 5
195 ELSE rank_address END as rank_address,
198 WHERE place_id = place.place_id
200 --RAISE WARNING '%',location;
201 IF location.rank_address < 4 THEN
202 -- no country locations for ranks higher than country
203 place.country_code := NULL::varchar(2);
204 ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
205 place.country_code := location.country_code;
208 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
209 location.name, location.class, location.type,
211 location.admin_level, true,
212 location.type not in ('postcode', 'postal_code'),
213 location.rank_address, 0)::addressline;
215 current_rank_address := location.rank_address;
218 -- --- Return records for address parts.
221 SELECT placex.place_id, osm_type, osm_id, name, class, type,
222 coalesce(extratags->'linked_place', extratags->'place') as place_type,
223 admin_level, fromarea, isaddress,
224 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
225 distance, country_code, postcode
226 FROM place_addressline join placex on (address_place_id = placex.place_id)
227 WHERE place_addressline.place_id IN (place.place_id, in_place_id)
228 AND linked_place_id is null
229 AND (placex.country_code IS NULL OR place.country_code IS NULL
230 OR placex.country_code = place.country_code)
231 ORDER BY rank_address desc,
232 (place_addressline.place_id = in_place_id) desc,
233 (CASE WHEN coalesce((avals(name) && avals(place.address)), False) THEN 2
234 WHEN isaddress THEN 0
236 and place.centroid is not null
237 and ST_Contains(geometry, place.centroid) THEN 1
239 fromarea desc, distance asc, rank_search desc
241 -- RAISE WARNING '%',location;
242 location_isaddress := location.rank_address != current_rank_address;
244 IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
245 place.country_code := location.country_code;
247 IF location.type in ('postcode', 'postal_code')
248 AND place.postcode is not null
250 -- If the place had a postcode assigned, take this one only
251 -- into consideration when it is an area and the place does not have
252 -- a postcode itself.
253 IF location.fromarea AND location.isaddress
254 AND (place.address is null or not place.address ? 'postcode')
256 place.postcode := null; -- remove the less exact postcode
258 location_isaddress := false;
261 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
262 location.name, location.class, location.type,
264 location.admin_level, location.fromarea,
266 location.rank_address,
267 location.distance)::addressline;
269 current_rank_address := location.rank_address;
272 -- If no country was included yet, add the name information from country_name.
273 IF current_rank_address > 4 THEN
275 SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
277 --RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
278 RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
279 null, true, true, 4, 0)::addressline;
283 -- Finally add some artificial rows.
284 IF place.country_code IS NOT NULL THEN
285 location := ROW(null, null, null, hstore('ref', place.country_code),
286 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
287 RETURN NEXT location;
290 IF place.name IS NOT NULL THEN
291 location := ROW(in_place_id, null, null, place.name, place.class,
292 place.type, null, null, true, true, 29, 0)::addressline;
293 RETURN NEXT location;
296 IF place.housenumber IS NOT NULL THEN
297 location := ROW(null, null, null, hstore('ref', place.housenumber),
298 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
299 RETURN NEXT location;
302 IF place.address is not null and place.address ? '_unlisted_place' THEN
303 RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
304 'place', 'locality', null, null, true, true, 25, 0)::addressline;
307 IF place.postcode is not null THEN
308 location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
309 'postcode', null, null, false, true, 5, 0)::addressline;
310 RETURN NEXT location;
316 LANGUAGE plpgsql STABLE;