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
95 countrylocation RECORD;
96 searchcountrycode varchar(2);
97 searchhousenumber TEXT;
98 searchhousename HSTORE;
99 searchrankaddress INTEGER;
101 postcode_isexact BOOL;
106 -- The place ein question might not have a direct entry in place_addressline.
107 -- Look for the parent of such places then and save if in for_place_id.
109 postcode_isexact := false;
111 -- first query osmline (interpolation lines)
112 IF in_housenumber >= 0 THEN
113 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
114 null, 'place', 'house'
115 FROM location_property_osmline
116 WHERE place_id = in_place_id AND in_housenumber>=startnumber
117 AND in_housenumber <= endnumber
118 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
119 searchpostcode, searchhousename, searchclass, searchtype;
122 --then query tiger data
123 -- %NOTIGERDATA% IF 0 THEN
124 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
125 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
127 FROM location_property_tiger
128 WHERE place_id = in_place_id AND in_housenumber >= startnumber
129 AND in_housenumber <= endnumber
130 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
131 searchpostcode, searchhousename, searchclass, searchtype;
133 -- %NOTIGERDATA% END IF;
135 -- %NOAUXDATA% IF 0 THEN
136 IF for_place_id IS NULL THEN
137 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
138 FROM location_property_aux
139 WHERE place_id = in_place_id
140 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
141 searchpostcode, searchhousename, searchclass, searchtype;
143 -- %NOAUXDATA% END IF;
146 IF for_place_id IS NULL THEN
147 SELECT parent_place_id, country_code, rank_search, postcode, 'place', 'postcode'
148 FROM location_postcode
149 WHERE place_id = in_place_id
150 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
151 searchclass, searchtype;
154 -- POI objects in the placex table
155 IF for_place_id IS NULL THEN
156 SELECT parent_place_id, country_code, housenumber, rank_search,
157 postcode, address is not null and address ? 'postcode',
160 WHERE place_id = in_place_id and rank_search > 27
161 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
162 searchpostcode, postcode_isexact, searchhousename, searchclass, searchtype;
165 -- If for_place_id 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 for_place_id IS NULL THEN
169 select coalesce(linked_place_id, place_id), country_code,
170 housenumber, rank_search, postcode,
171 address is not null and address ? 'postcode', null
172 from placex where place_id = in_place_id
173 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, postcode_isexact, searchhousename;
176 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
178 found := 1000; -- the lowest rank_address included
180 -- Return the record for the base entry.
182 SELECT placex.place_id, osm_type, osm_id, name,
183 class, type, admin_level,
184 type not in ('postcode', 'postal_code') as isaddress,
185 CASE WHEN rank_address = 0 THEN 100
186 WHEN rank_address = 11 THEN 5
187 ELSE rank_address END as rank_address,
188 0 as distance, country_code, postcode
190 WHERE place_id = for_place_id
192 --RAISE WARNING '%',location;
193 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
194 searchcountrycode := location.country_code;
196 IF location.rank_address < 4 THEN
197 -- no country locations for ranks higher than country
198 searchcountrycode := NULL;
200 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
201 location.name, location.class, location.type, NULL,
202 location.admin_level, true, location.isaddress,
203 location.rank_address, location.distance)::addressline;
204 RETURN NEXT countrylocation;
205 found := location.rank_address;
209 SELECT placex.place_id, osm_type, osm_id, name, class, type,
210 coalesce(extratags->'linked_place', extratags->'place') as place_type,
211 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
212 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
213 distance, country_code, postcode
214 FROM place_addressline join placex on (address_place_id = placex.place_id)
215 WHERE place_addressline.place_id = for_place_id
216 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
217 AND linked_place_id is null
218 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
219 OR placex.country_code = searchcountrycode)
220 ORDER BY rank_address desc, isaddress desc, fromarea desc,
221 distance asc, rank_search desc
223 --RAISE WARNING '%',location;
224 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
225 searchcountrycode := location.country_code;
227 IF location.type in ('postcode', 'postal_code')
228 AND searchpostcode is not null
230 -- If the place had a postcode assigned, take this one only
231 -- into consideration when it is an area and the place does not have
232 -- a postcode itself.
233 IF location.fromarea AND not postcode_isexact AND location.isaddress THEN
234 searchpostcode := null; -- remove the less exact postcode
236 location.isaddress := false;
239 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
240 location.name, location.class, location.type,
242 location.admin_level, location.fromarea,
243 location.isaddress, location.rank_address,
244 location.distance)::addressline;
245 RETURN NEXT countrylocation;
246 found := location.rank_address;
249 -- If no country was included yet, add the name information from country_name.
251 SELECT name FROM country_name
252 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
253 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
254 IF countryname IS NOT NULL THEN
255 location := ROW(null, null, null, countryname, 'place', 'country', NULL,
256 null, true, true, 4, 0)::addressline;
257 RETURN NEXT location;
261 -- Finally add some artificial rows.
262 IF searchcountrycode IS NOT NULL THEN
263 location := ROW(null, null, null, hstore('ref', searchcountrycode),
264 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
265 RETURN NEXT location;
268 IF searchhousename IS NOT NULL THEN
269 location := ROW(in_place_id, null, null, searchhousename, searchclass,
270 searchtype, null, null, true, true, 29, 0)::addressline;
271 RETURN NEXT location;
274 IF searchhousenumber IS NOT NULL THEN
275 location := ROW(null, null, null, hstore('ref', searchhousenumber),
276 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
277 RETURN NEXT location;
280 IF searchpostcode IS NOT NULL THEN
281 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
282 'postcode', null, null, false, true, 5, 0)::addressline;
283 RETURN NEXT location;
289 LANGUAGE plpgsql STABLE;