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;
104 search_unlisted_place TEXT;
107 -- The place ein question might not have a direct entry in place_addressline.
108 -- Look for the parent of such places then and save if in for_place_id.
110 postcode_isexact := false;
112 -- first query osmline (interpolation lines)
113 IF in_housenumber >= 0 THEN
114 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
115 null, 'place', 'house'
116 FROM location_property_osmline
117 WHERE place_id = in_place_id AND in_housenumber>=startnumber
118 AND in_housenumber <= endnumber
119 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
120 searchpostcode, searchhousename, searchclass, searchtype;
123 --then query tiger data
124 -- %NOTIGERDATA% IF 0 THEN
125 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
126 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
128 FROM location_property_tiger
129 WHERE place_id = in_place_id AND in_housenumber >= startnumber
130 AND in_housenumber <= endnumber
131 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
132 searchpostcode, searchhousename, searchclass, searchtype;
134 -- %NOTIGERDATA% END IF;
136 -- %NOAUXDATA% IF 0 THEN
137 IF for_place_id IS NULL THEN
138 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
139 FROM location_property_aux
140 WHERE place_id = in_place_id
141 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
142 searchpostcode, searchhousename, searchclass, searchtype;
144 -- %NOAUXDATA% END IF;
147 IF for_place_id IS NULL THEN
148 SELECT parent_place_id, country_code, rank_search, postcode, 'place', 'postcode'
149 FROM location_postcode
150 WHERE place_id = in_place_id
151 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
152 searchclass, searchtype;
155 -- POI objects in the placex table
156 IF for_place_id IS NULL THEN
157 SELECT parent_place_id, country_code, housenumber, rank_search,
158 postcode, address is not null and address ? 'postcode',
160 address -> '_unlisted_place' as unlisted_place
162 WHERE place_id = in_place_id and rank_search > 27
163 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
164 searchpostcode, postcode_isexact, searchhousename, searchclass,
165 searchtype, search_unlisted_place;
168 -- If for_place_id is still NULL at this point then the object has its own
169 -- entry in place_address line. However, still check if there is not linked
170 -- place we should be using instead.
171 IF for_place_id IS NULL THEN
172 select coalesce(linked_place_id, place_id), country_code,
173 housenumber, rank_search, postcode,
174 address is not null and address ? 'postcode', null
175 from placex where place_id = in_place_id
176 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, postcode_isexact, searchhousename;
179 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
181 found := 1000; -- the lowest rank_address included
183 -- Return the record for the base entry.
185 SELECT placex.place_id, osm_type, osm_id, name,
186 coalesce(extratags->'linked_place', extratags->'place') as place_type,
187 class, type, admin_level,
188 type not in ('postcode', 'postal_code') as isaddress,
189 CASE WHEN rank_address = 0 THEN 100
190 WHEN rank_address = 11 THEN 5
191 ELSE rank_address END as rank_address,
192 0 as distance, country_code, postcode
194 WHERE place_id = for_place_id
196 --RAISE WARNING '%',location;
197 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
198 searchcountrycode := location.country_code;
200 IF location.rank_address < 4 THEN
201 -- no country locations for ranks higher than country
202 searchcountrycode := NULL;
204 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
205 location.name, location.class, location.type,
207 location.admin_level, true, location.isaddress,
208 location.rank_address, location.distance)::addressline;
209 RETURN NEXT countrylocation;
210 found := location.rank_address;
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 = for_place_id
221 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
222 AND linked_place_id is null
223 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
224 OR placex.country_code = searchcountrycode)
225 ORDER BY rank_address desc, isaddress desc, fromarea desc,
226 distance asc, rank_search desc
228 --RAISE WARNING '%',location;
229 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
230 searchcountrycode := location.country_code;
232 IF location.type in ('postcode', 'postal_code')
233 AND searchpostcode is not null
235 -- If the place had a postcode assigned, take this one only
236 -- into consideration when it is an area and the place does not have
237 -- a postcode itself.
238 IF location.fromarea AND not postcode_isexact AND location.isaddress THEN
239 searchpostcode := null; -- remove the less exact postcode
241 location.isaddress := false;
244 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
245 location.name, location.class, location.type,
247 location.admin_level, location.fromarea,
248 location.isaddress, location.rank_address,
249 location.distance)::addressline;
250 RETURN NEXT countrylocation;
251 found := location.rank_address;
254 -- If no country was included yet, add the name information from country_name.
256 SELECT name FROM country_name
257 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
258 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
259 IF countryname IS NOT NULL THEN
260 location := ROW(null, null, null, countryname, 'place', 'country', NULL,
261 null, true, true, 4, 0)::addressline;
262 RETURN NEXT location;
266 -- Finally add some artificial rows.
267 IF searchcountrycode IS NOT NULL THEN
268 location := ROW(null, null, null, hstore('ref', searchcountrycode),
269 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
270 RETURN NEXT location;
273 IF searchhousename IS NOT NULL THEN
274 location := ROW(in_place_id, null, null, searchhousename, searchclass,
275 searchtype, null, null, true, true, 29, 0)::addressline;
276 RETURN NEXT location;
279 IF searchhousenumber IS NOT NULL THEN
280 location := ROW(null, null, null, hstore('ref', searchhousenumber),
281 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
282 RETURN NEXT location;
285 IF search_unlisted_place is not null THEN
286 RETURN NEXT ROW(null, null, null, hstore('name', search_unlisted_place),
287 'place', 'locality', null, null, true, true, 26, 0)::addressline;
290 IF searchpostcode IS NOT NULL THEN
291 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
292 'postcode', null, null, false, true, 5, 0)::addressline;
293 RETURN NEXT location;
299 LANGUAGE plpgsql STABLE;