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;
83 -- Compute the list of address parts for the given place.
85 -- If in_housenumber is greator or equal 0, look for an interpolation.
86 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER)
87 RETURNS setof addressline
92 current_rank_address INTEGER;
93 location_isaddress BOOLEAN;
95 -- The place in question might not have a direct entry in place_addressline.
96 -- Look for the parent of such places then and save it in place.
98 -- first query osmline (interpolation lines)
99 IF in_housenumber >= 0 THEN
100 SELECT parent_place_id as place_id, country_code,
101 in_housenumber::text as housenumber, postcode,
102 'place' as class, 'house' as type,
103 null::hstore as name, null::hstore as address,
104 ST_Centroid(linegeo) as centroid
106 FROM location_property_osmline
107 WHERE place_id = in_place_id
108 AND in_housenumber between startnumber and endnumber;
111 --then query tiger data
112 -- %NOTIGERDATA% IF 0 THEN
113 IF place IS NULL AND in_housenumber >= 0 THEN
114 SELECT parent_place_id as place_id, 'us'::varchar(2) as country_code,
115 in_housenumber::text as housenumber, postcode,
116 'place' as class, 'house' as type,
117 null::hstore as name, null::hstore as address,
118 ST_Centroid(linegeo) as centroid
120 FROM location_property_tiger
121 WHERE place_id = in_place_id
122 AND in_housenumber between startnumber and endnumber;
124 -- %NOTIGERDATA% END IF;
126 -- %NOAUXDATA% IF 0 THEN
127 IF place IS NULL THEN
128 SELECT parent_place_id as place_id, 'us'::varchar(2) as country_code,
129 housenumber, postcode,
130 'place' as class, 'house' as type,
131 null::hstore as name, null::hstore as address,
134 FROM location_property_aux
135 WHERE place_id = in_place_id;
137 -- %NOAUXDATA% END IF;
140 IF place IS NULL THEN
141 SELECT parent_place_id as place_id, country_code,
142 null::text as housenumber, postcode,
143 'place' as class, 'postcode' as type,
144 null::hstore as name, null::hstore as address,
145 null::geometry as centroid
147 FROM location_postcode
148 WHERE place_id = in_place_id;
151 -- POI objects in the placex table
152 IF place IS NULL THEN
153 SELECT parent_place_id as place_id, country_code,
154 housenumber, postcode,
160 WHERE place_id = in_place_id and rank_search > 27;
163 -- If place is still NULL at this point then the object has its own
164 -- entry in place_address line. However, still check if there is not linked
165 -- place we should be using instead.
166 IF place IS NULL THEN
167 select coalesce(linked_place_id, place_id) as place_id, country_code,
168 housenumber, postcode,
170 null::hstore as name, address,
171 null::geometry as centroid
173 FROM placex where place_id = in_place_id;
176 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
178 -- --- Return the record for the base entry.
181 SELECT placex.place_id, osm_type, osm_id, name,
182 coalesce(extratags->'linked_place', extratags->'place') as place_type,
183 class, type, admin_level,
184 CASE WHEN rank_address = 0 THEN 100
185 WHEN rank_address = 11 THEN 5
186 ELSE rank_address END as rank_address,
189 WHERE place_id = place.place_id
191 --RAISE WARNING '%',location;
192 IF location.rank_address < 4 THEN
193 -- no country locations for ranks higher than country
194 place.country_code := NULL::varchar(2);
195 ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
196 place.country_code := location.country_code;
199 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
200 location.name, location.class, location.type,
202 location.admin_level, true,
203 location.type not in ('postcode', 'postal_code'),
204 location.rank_address, 0)::addressline;
206 current_rank_address := location.rank_address;
209 -- --- Return records for address parts.
212 SELECT placex.place_id, osm_type, osm_id, name, class, type,
213 coalesce(extratags->'linked_place', extratags->'place') as place_type,
214 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
215 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
216 distance, country_code, postcode
217 FROM place_addressline join placex on (address_place_id = placex.place_id)
218 WHERE place_addressline.place_id IN (place.place_id, in_place_id)
219 AND linked_place_id is null
220 AND (placex.country_code IS NULL OR place.country_code IS NULL
221 OR placex.country_code = place.country_code)
222 ORDER BY rank_address desc,
223 (place_addressline.place_id = in_place_id) desc,
224 (fromarea and place.centroid is not null and not isaddress
225 and (place.address is null or avals(name) && avals(place.address))
226 and ST_Contains(geometry, place.centroid)) desc,
227 isaddress desc, fromarea desc,
228 distance asc, rank_search desc
230 -- RAISE WARNING '%',location;
231 location_isaddress := location.rank_address != current_rank_address;
233 IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
234 place.country_code := location.country_code;
236 IF location.type in ('postcode', 'postal_code')
237 AND place.postcode is not null
239 -- If the place had a postcode assigned, take this one only
240 -- into consideration when it is an area and the place does not have
241 -- a postcode itself.
242 IF location.fromarea AND location.isaddress
243 AND (place.address is null or not place.address ? 'postcode')
245 place.postcode := null; -- remove the less exact postcode
247 location_isaddress := false;
250 RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
251 location.name, location.class, location.type,
253 location.admin_level, location.fromarea,
255 location.rank_address,
256 location.distance)::addressline;
258 current_rank_address := location.rank_address;
261 -- If no country was included yet, add the name information from country_name.
262 IF current_rank_address > 4 THEN
264 SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
266 --RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
267 RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
268 null, true, true, 4, 0)::addressline;
272 -- Finally add some artificial rows.
273 IF place.country_code IS NOT NULL THEN
274 location := ROW(null, null, null, hstore('ref', place.country_code),
275 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
276 RETURN NEXT location;
279 IF place.name IS NOT NULL THEN
280 location := ROW(in_place_id, null, null, place.name, place.class,
281 place.type, null, null, true, true, 29, 0)::addressline;
282 RETURN NEXT location;
285 IF place.housenumber IS NOT NULL THEN
286 location := ROW(null, null, null, hstore('ref', place.housenumber),
287 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
288 RETURN NEXT location;
291 IF place.address is not null and place.address ? '_unlisted_place' THEN
292 RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
293 'place', 'locality', null, null, true, true, 25, 0)::addressline;
296 IF place.postcode is not null THEN
297 location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
298 'postcode', null, null, false, true, 5, 0)::addressline;
299 RETURN NEXT location;
305 LANGUAGE plpgsql STABLE;