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,
63 SELECT * FROM get_addressdata(for_place_id, housenumber)
64 WHERE isaddress order by rank_address desc
66 currresult := trim(get_name_by_language(location.name, languagepref));
67 IF currresult != prevresult AND currresult IS NOT NULL
68 AND result[(100 - location.rank_address)] IS NULL
70 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
71 prevresult := currresult;
75 RETURN array_to_string(result,', ');
78 LANGUAGE plpgsql STABLE;
81 -- Compute the list of address parts for the given place.
83 -- If in_housenumber is greator or equal 0, look for an interpolation.
84 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER)
85 RETURNS setof addressline
93 countrylocation RECORD;
94 searchcountrycode varchar(2);
95 searchhousenumber TEXT;
96 searchhousename HSTORE;
97 searchrankaddress INTEGER;
99 postcode_isaddress BOOL;
104 -- The place ein question might not have a direct entry in place_addressline.
105 -- Look for the parent of such places then and save if in for_place_id.
107 postcode_isaddress := true;
109 -- first query osmline (interpolation lines)
110 IF in_housenumber >= 0 THEN
111 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
112 null, 'place', 'house'
113 FROM location_property_osmline
114 WHERE place_id = in_place_id AND in_housenumber>=startnumber
115 AND in_housenumber <= endnumber
116 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
117 searchpostcode, searchhousename, searchclass, searchtype;
120 --then query tiger data
121 -- %NOTIGERDATA% IF 0 THEN
122 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
123 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
125 FROM location_property_tiger
126 WHERE place_id = in_place_id AND in_housenumber >= startnumber
127 AND in_housenumber <= endnumber
128 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
129 searchpostcode, searchhousename, searchclass, searchtype;
131 -- %NOTIGERDATA% END IF;
133 -- %NOAUXDATA% IF 0 THEN
134 IF for_place_id IS NULL THEN
135 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
136 FROM location_property_aux
137 WHERE place_id = in_place_id
138 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
139 searchpostcode, searchhousename, searchclass, searchtype;
141 -- %NOAUXDATA% END IF;
144 IF for_place_id IS NULL THEN
145 SELECT parent_place_id, country_code, rank_search, postcode, 'place', 'postcode'
146 FROM location_postcode
147 WHERE place_id = in_place_id
148 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
149 searchclass, searchtype;
152 -- POI objects in the placex table
153 IF for_place_id IS NULL THEN
154 SELECT parent_place_id, country_code, housenumber, rank_search, postcode,
157 WHERE place_id = in_place_id and rank_search > 27
158 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
159 searchpostcode, searchhousename, searchclass, searchtype;
162 -- If for_place_id is still NULL at this point then the object has its own
163 -- entry in place_address line. However, still check if there is not linked
164 -- place we should be using instead.
165 IF for_place_id IS NULL THEN
166 select coalesce(linked_place_id, place_id), country_code,
167 housenumber, rank_search, postcode, null
168 from placex where place_id = in_place_id
169 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
172 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
174 found := 1000; -- the lowest rank_address included
176 -- Return the record for the base entry.
178 SELECT placex.place_id, osm_type, osm_id, name,
179 class, type, admin_level,
180 type not in ('postcode', 'postal_code') as isaddress,
181 CASE WHEN rank_address = 0 THEN 100
182 WHEN rank_address = 11 THEN 5
183 ELSE rank_address END as rank_address,
184 0 as distance, country_code, postcode
186 WHERE place_id = for_place_id
188 --RAISE WARNING '%',location;
189 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
190 searchcountrycode := location.country_code;
192 IF location.rank_address < 4 THEN
193 -- no country locations for ranks higher than country
194 searchcountrycode := NULL;
196 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
197 location.name, location.class, location.type, NULL,
198 location.admin_level, true, location.isaddress,
199 location.rank_address, location.distance)::addressline;
200 RETURN NEXT countrylocation;
201 found := location.rank_address;
205 SELECT placex.place_id, osm_type, osm_id, name, class, type,
206 coalesce(extratags->'place', extratags->'linked_place') as place_type,
207 admin_level, fromarea, isaddress,
208 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
209 distance, country_code, postcode
210 FROM place_addressline join placex on (address_place_id = placex.place_id)
211 WHERE place_addressline.place_id = for_place_id
212 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
213 AND linked_place_id is null
214 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
215 OR placex.country_code = searchcountrycode)
216 ORDER BY rank_address desc, isaddress desc, fromarea desc,
217 distance asc, rank_search desc
219 --RAISE WARNING '%',location;
220 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
221 searchcountrycode := location.country_code;
223 IF location.type in ('postcode', 'postal_code') THEN
224 postcode_isaddress := false;
225 IF location.osm_type != 'R' THEN
226 location.isaddress := FALSE;
229 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
230 location.name, location.class, location.type,
232 location.admin_level, location.fromarea,
233 location.isaddress, location.rank_address,
234 location.distance)::addressline;
235 RETURN NEXT countrylocation;
236 found := location.rank_address;
239 -- If no country was included yet, add the name information from country_name.
241 SELECT name FROM country_name
242 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
243 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
244 IF countryname IS NOT NULL THEN
245 location := ROW(null, null, null, countryname, 'place', 'country', NULL,
246 null, true, true, 4, 0)::addressline;
247 RETURN NEXT location;
251 -- Finally add some artificial rows.
252 IF searchcountrycode IS NOT NULL THEN
253 location := ROW(null, null, null, hstore('ref', searchcountrycode),
254 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
255 RETURN NEXT location;
258 IF searchhousename IS NOT NULL THEN
259 location := ROW(in_place_id, null, null, searchhousename, searchclass,
260 searchtype, null, null, true, true, 29, 0)::addressline;
261 RETURN NEXT location;
264 IF searchhousenumber IS NOT NULL THEN
265 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber),
266 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
267 RETURN NEXT location;
270 IF searchpostcode IS NOT NULL THEN
271 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
272 'postcode', null, null, false, postcode_isaddress, 5, 0)::addressline;
273 RETURN NEXT location;
279 LANGUAGE plpgsql STABLE;