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 -- %NOTIGERDATA% IF 0 THEN
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;
136 -- %NOTIGERDATA% END IF;
138 -- %NOAUXDATA% IF 0 THEN
139 IF place IS NULL THEN
140 SELECT parent_place_id as place_id, 'us' as country_code,
141 housenumber, postcode,
142 'place' as class, 'house' as type,
143 null as name, null as address,
146 FROM location_property_aux
147 WHERE place_id = in_place_id;
149 -- %NOAUXDATA% END IF;
152 IF place IS NULL THEN
153 SELECT parent_place_id as place_id, country_code,
154 null::text as housenumber, postcode,
155 'place' as class, 'postcode' as type,
156 null as name, null as address,
159 FROM location_postcode
160 WHERE place_id = in_place_id;
163 -- POI objects in the placex table
164 IF place IS NULL THEN
165 SELECT parent_place_id as place_id, country_code,
166 housenumber, postcode,
172 WHERE place_id = in_place_id and rank_search > 27;
175 -- If place is still NULL at this point then the object has its own
176 -- entry in place_address line. However, still check if there is not linked
177 -- place we should be using instead.
178 IF place IS NULL THEN
179 select coalesce(linked_place_id, place_id) as place_id, country_code,
180 housenumber, postcode,
182 null as name, address,
185 FROM placex where place_id = in_place_id;
188 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
190 -- --- Return the record for the base entry.
193 SELECT placex.place_id, osm_type, osm_id, name,
194 coalesce(extratags->'linked_place', extratags->'place') as place_type,
195 class, type, admin_level,
196 CASE WHEN rank_address = 0 THEN 100
197 WHEN rank_address = 11 THEN 5
198 ELSE rank_address END as rank_address,
201 WHERE place_id = place.place_id
203 --RAISE WARNING '%',location;
204 IF location.rank_address < 4 THEN
205 -- no country locations for ranks higher than country
206 place.country_code := NULL::varchar(2);
207 ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
208 place.country_code := location.country_code;
211 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
212 location.name, location.class, location.type,
214 location.admin_level, true,
215 location.type not in ('postcode', 'postal_code'),
216 location.rank_address, 0)::addressline;
218 current_rank_address := location.rank_address;
221 -- --- Return records for address parts.
224 SELECT placex.place_id, osm_type, osm_id, name, class, type,
225 coalesce(extratags->'linked_place', extratags->'place') as place_type,
226 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
227 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
228 distance, country_code, postcode
229 FROM place_addressline join placex on (address_place_id = placex.place_id)
230 WHERE place_addressline.place_id IN (place.place_id, in_place_id)
231 AND linked_place_id is null
232 AND (placex.country_code IS NULL OR place.country_code IS NULL
233 OR placex.country_code = place.country_code)
234 ORDER BY rank_address desc,
235 (place_addressline.place_id = in_place_id) desc,
236 (fromarea and place.centroid is not null and not isaddress
237 and (place.address is null or avals(name) && avals(place.address))
238 and ST_Contains(geometry, place.centroid)) desc,
239 isaddress desc, fromarea desc,
240 distance asc, rank_search desc
242 -- RAISE WARNING '%',location;
243 location_isaddress := location.rank_address != current_rank_address;
245 IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
246 place.country_code := location.country_code;
248 IF location.type in ('postcode', 'postal_code')
249 AND place.postcode is not null
251 -- If the place had a postcode assigned, take this one only
252 -- into consideration when it is an area and the place does not have
253 -- a postcode itself.
254 IF location.fromarea AND location.isaddress
255 AND (place.address is null or not place.address ? 'postcode')
257 place.postcode := null; -- remove the less exact postcode
259 location_isaddress := false;
262 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
263 location.name, location.class, location.type,
265 location.admin_level, location.fromarea,
267 location.rank_address,
268 location.distance)::addressline;
270 current_rank_address := location.rank_address;
273 -- If no country was included yet, add the name information from country_name.
274 IF current_rank_address > 4 THEN
276 SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
278 --RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
279 RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
280 null, true, true, 4, 0)::addressline;
284 -- Finally add some artificial rows.
285 IF place.country_code IS NOT NULL THEN
286 location := ROW(null, null, null, hstore('ref', place.country_code),
287 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
288 RETURN NEXT location;
291 IF place.name IS NOT NULL THEN
292 location := ROW(in_place_id, null, null, place.name, place.class,
293 place.type, null, null, true, true, 29, 0)::addressline;
294 RETURN NEXT location;
297 IF place.housenumber IS NOT NULL THEN
298 location := ROW(null, null, null, hstore('ref', place.housenumber),
299 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
300 RETURN NEXT location;
303 IF place.address is not null and place.address ? '_unlisted_place' THEN
304 RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
305 'place', 'locality', null, null, true, true, 25, 0)::addressline;
308 IF place.postcode is not null THEN
309 location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
310 'postcode', null, null, false, true, 5, 0)::addressline;
311 RETURN NEXT location;
317 LANGUAGE plpgsql STABLE;