1 -- Functions for returning address information for a place.
3 DROP TYPE IF EXISTS addressline CASCADE;
4 CREATE TYPE addressline as (
20 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[])
30 FOR j IN 1..array_upper(languagepref,1) LOOP
31 IF name ? languagepref[j] THEN
32 result := trim(name->languagepref[j]);
39 -- anything will do as a fallback - just take the first name type thing there is
40 RETURN trim((avals(name))[1]);
43 LANGUAGE plpgsql IMMUTABLE;
46 --housenumber only needed for tiger data
47 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT,
64 CASE WHEN place_id = for_place_id THEN 99 ELSE rank_address END as rank_address
65 FROM get_addressdata(for_place_id, housenumber)
66 WHERE isaddress order by rank_address desc
68 currresult := trim(get_name_by_language(location.name, languagepref));
69 IF currresult != prevresult AND currresult IS NOT NULL
70 AND result[(100 - location.rank_address)] IS NULL
72 result[(100 - location.rank_address)] := currresult;
73 prevresult := currresult;
77 RETURN array_to_string(result,', ');
80 LANGUAGE plpgsql STABLE;
82 DROP TYPE IF EXISTS addressdata_place;
83 CREATE TYPE addressdata_place AS (
85 country_code VARCHAR(2),
95 -- Compute the list of address parts for the given place.
97 -- If in_housenumber is greator or equal 0, look for an interpolation.
98 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER)
99 RETURNS setof addressline
102 place addressdata_place;
104 current_rank_address INTEGER;
105 location_isaddress BOOLEAN;
107 -- The place in question might not have a direct entry in place_addressline.
108 -- Look for the parent of such places then and save it in place.
110 -- first query osmline (interpolation lines)
111 IF in_housenumber >= 0 THEN
112 SELECT parent_place_id as place_id, country_code,
113 in_housenumber as housenumber, postcode,
114 'place' as class, 'house' as type,
115 null as name, null as address,
116 ST_Centroid(linegeo) as centroid
118 FROM location_property_osmline
119 WHERE place_id = in_place_id
120 AND in_housenumber between startnumber and endnumber;
123 --then query tiger data
124 {% if config.get_bool('USE_US_TIGER_DATA') %}
125 IF place IS NULL AND in_housenumber >= 0 THEN
126 SELECT parent_place_id as place_id, 'us' as country_code,
127 in_housenumber as housenumber, postcode,
128 'place' as class, 'house' as type,
129 null as name, null as address,
130 ST_Centroid(linegeo) as centroid
132 FROM location_property_tiger
133 WHERE place_id = in_place_id
134 AND in_housenumber between startnumber and endnumber;
139 IF place IS NULL THEN
140 SELECT parent_place_id as place_id, country_code,
141 null::text as housenumber, postcode,
142 'place' as class, 'postcode' as type,
143 null as name, null as address,
146 FROM location_postcode
147 WHERE place_id = in_place_id;
150 -- POI objects in the placex table
151 IF place IS NULL THEN
152 SELECT parent_place_id as place_id, country_code,
153 coalesce(address->'housenumber',
154 address->'streetnumber',
155 address->'conscriptionnumber')::text as housenumber,
162 WHERE place_id = in_place_id and rank_search > 27;
165 -- If place is still NULL at this point then the object has its own
166 -- entry in place_address line. However, still check if there is not linked
167 -- place we should be using instead.
168 IF place IS NULL THEN
169 select coalesce(linked_place_id, place_id) as place_id, country_code,
170 null::text as housenumber, postcode,
172 null as name, address,
175 FROM placex where place_id = in_place_id;
178 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
180 -- --- Return the record for the base entry.
183 SELECT placex.place_id, osm_type, osm_id, name,
184 coalesce(extratags->'linked_place', extratags->'place') as place_type,
185 class, type, admin_level,
186 CASE WHEN rank_address = 0 THEN 100
187 WHEN rank_address = 11 THEN 5
188 ELSE rank_address END as rank_address,
191 WHERE place_id = place.place_id
193 --RAISE WARNING '%',location;
194 IF location.rank_address < 4 THEN
195 -- no country locations for ranks higher than country
196 place.country_code := NULL::varchar(2);
197 ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
198 place.country_code := location.country_code;
201 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
202 location.name, location.class, location.type,
204 location.admin_level, true,
205 location.type not in ('postcode', 'postal_code'),
206 location.rank_address, 0)::addressline;
208 current_rank_address := location.rank_address;
211 -- --- Return records for address parts.
214 SELECT placex.place_id, osm_type, osm_id, name, class, type,
215 coalesce(extratags->'linked_place', extratags->'place') as place_type,
216 admin_level, fromarea, isaddress,
217 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
218 distance, country_code, postcode
219 FROM place_addressline join placex on (address_place_id = placex.place_id)
220 WHERE place_addressline.place_id IN (place.place_id, in_place_id)
221 AND linked_place_id is null
222 AND (placex.country_code IS NULL OR place.country_code IS NULL
223 OR placex.country_code = place.country_code)
224 ORDER BY rank_address desc,
225 (place_addressline.place_id = in_place_id) desc,
226 (fromarea and place.centroid is not null and not isaddress
227 and (place.address is null or avals(name) && avals(place.address))
228 and ST_Contains(geometry, place.centroid)) desc,
229 isaddress desc, fromarea desc,
230 distance asc, rank_search desc
232 -- RAISE WARNING '%',location;
233 location_isaddress := location.rank_address != current_rank_address;
235 IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
236 place.country_code := location.country_code;
238 IF location.type in ('postcode', 'postal_code')
239 AND place.postcode is not null
241 -- If the place had a postcode assigned, take this one only
242 -- into consideration when it is an area and the place does not have
243 -- a postcode itself.
244 IF location.fromarea AND location.isaddress
245 AND (place.address is null or not place.address ? 'postcode')
247 place.postcode := null; -- remove the less exact postcode
249 location_isaddress := false;
252 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
253 location.name, location.class, location.type,
255 location.admin_level, location.fromarea,
257 location.rank_address,
258 location.distance)::addressline;
260 current_rank_address := location.rank_address;
263 -- If no country was included yet, add the name information from country_name.
264 IF current_rank_address > 4 THEN
266 SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
268 --RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
269 RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
270 null, true, true, 4, 0)::addressline;
274 -- Finally add some artificial rows.
275 IF place.country_code IS NOT NULL THEN
276 location := ROW(null, null, null, hstore('ref', place.country_code),
277 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
278 RETURN NEXT location;
281 IF place.name IS NOT NULL THEN
282 location := ROW(in_place_id, null, null, place.name, place.class,
283 place.type, null, null, true, true, 29, 0)::addressline;
284 RETURN NEXT location;
287 IF place.housenumber IS NOT NULL THEN
288 location := ROW(null, null, null, hstore('ref', place.housenumber),
289 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
290 RETURN NEXT location;
293 IF place.address is not null and place.address ? '_unlisted_place' THEN
294 RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
295 'place', 'locality', null, null, true, true, 25, 0)::addressline;
298 IF place.postcode is not null THEN
299 location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
300 'postcode', null, null, false, true, 5, 0)::addressline;
301 RETURN NEXT location;
307 LANGUAGE plpgsql STABLE;