Merge pull request #2082 from lonvia/compute-address-on-the-fly-II

Compute address for POIs on the fly
This commit is contained in:
Sarah Hoffmann 2020-12-01 16:41:31 +01:00 committed by GitHub
commit a9357b4dce
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
2 changed files with 148 additions and 111 deletions

View File

@ -87,92 +87,90 @@ CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber IN
RETURNS setof addressline RETURNS setof addressline
AS $$ AS $$
DECLARE DECLARE
for_place_id BIGINT; place RECORD;
result TEXT[];
search TEXT[];
current_rank_address INTEGER;
location RECORD; location RECORD;
countrylocation RECORD; current_rank_address INTEGER;
searchcountrycode varchar(2); location_isaddress BOOLEAN;
searchhousenumber TEXT;
searchhousename HSTORE;
searchpostcode TEXT;
postcode_isexact BOOL;
searchclass TEXT;
searchtype TEXT;
search_unlisted_place TEXT;
countryname HSTORE;
BEGIN BEGIN
-- The place in question might not have a direct entry in place_addressline. -- The place in question might not have a direct entry in place_addressline.
-- Look for the parent of such places then and save if in for_place_id. -- Look for the parent of such places then and save it in place.
postcode_isexact := false;
-- first query osmline (interpolation lines) -- first query osmline (interpolation lines)
IF in_housenumber >= 0 THEN IF in_housenumber >= 0 THEN
SELECT parent_place_id, country_code, in_housenumber::text, postcode, SELECT parent_place_id as place_id, country_code,
null, 'place', 'house' in_housenumber::text as housenumber, postcode,
'place' as class, 'house' as type,
null::hstore as name, null::hstore as address,
ST_Centroid(linegeo) as centroid
INTO place
FROM location_property_osmline FROM location_property_osmline
WHERE place_id = in_place_id AND in_housenumber>=startnumber WHERE place_id = in_place_id
AND in_housenumber <= endnumber AND in_housenumber between startnumber and endnumber;
INTO for_place_id, searchcountrycode, searchhousenumber,
searchpostcode, searchhousename, searchclass, searchtype;
END IF; END IF;
--then query tiger data --then query tiger data
-- %NOTIGERDATA% IF 0 THEN -- %NOTIGERDATA% IF 0 THEN
IF for_place_id IS NULL AND in_housenumber >= 0 THEN IF place IS NULL AND in_housenumber >= 0 THEN
SELECT parent_place_id, 'us', in_housenumber::text, postcode, null, SELECT parent_place_id as place_id, 'us' as country_code,
'place', 'house' in_housenumber::text as housenumber, postcode,
'place' as class, 'house' as type,
null::hstore as name, null::hstore as address,
ST_Centroid(linegeo) as centroid
INTO place
FROM location_property_tiger FROM location_property_tiger
WHERE place_id = in_place_id AND in_housenumber >= startnumber WHERE place_id = in_place_id
AND in_housenumber <= endnumber AND in_housenumber between startnumber and endnumber;
INTO for_place_id, searchcountrycode, searchhousenumber,
searchpostcode, searchhousename, searchclass, searchtype;
END IF; END IF;
-- %NOTIGERDATA% END IF; -- %NOTIGERDATA% END IF;
-- %NOAUXDATA% IF 0 THEN -- %NOAUXDATA% IF 0 THEN
IF for_place_id IS NULL THEN IF place IS NULL THEN
SELECT parent_place_id, 'us', housenumber, postcode, null, 'place', 'house' SELECT parent_place_id as place_id, 'us' as country_code,
housenumber, postcode,
'place' as class, 'house' as type,
null::hstore as name, null::hstore as address,
centroid
INTO place
FROM location_property_aux FROM location_property_aux
WHERE place_id = in_place_id WHERE place_id = in_place_id;
INTO for_place_id,searchcountrycode, searchhousenumber,
searchpostcode, searchhousename, searchclass, searchtype;
END IF; END IF;
-- %NOAUXDATA% END IF; -- %NOAUXDATA% END IF;
-- postcode table -- postcode table
IF for_place_id IS NULL THEN IF place IS NULL THEN
SELECT parent_place_id, country_code, postcode, 'place', 'postcode' SELECT parent_place_id as place_id, country_code,
null::text as housenumber, postcode,
'place' as class, 'postcode' as type,
null::hstore as name, null::hstore as address,
null::geometry as centroid
INTO place
FROM location_postcode FROM location_postcode
WHERE place_id = in_place_id WHERE place_id = in_place_id;
INTO for_place_id, searchcountrycode, searchpostcode,
searchclass, searchtype;
END IF; END IF;
-- POI objects in the placex table -- POI objects in the placex table
IF for_place_id IS NULL THEN IF place IS NULL THEN
SELECT parent_place_id, country_code, housenumber, SELECT parent_place_id as place_id, country_code,
postcode, address is not null and address ? 'postcode', housenumber, postcode,
name, class, type, class, type,
address -> '_unlisted_place' as unlisted_place name, address,
centroid
INTO place
FROM placex FROM placex
WHERE place_id = in_place_id and rank_search > 27 WHERE place_id = in_place_id and rank_search > 27;
INTO for_place_id, searchcountrycode, searchhousenumber,
searchpostcode, postcode_isexact, searchhousename, searchclass,
searchtype, search_unlisted_place;
END IF; END IF;
-- If for_place_id is still NULL at this point then the object has its own -- If place is still NULL at this point then the object has its own
-- entry in place_address line. However, still check if there is not linked -- entry in place_address line. However, still check if there is not linked
-- place we should be using instead. -- place we should be using instead.
IF for_place_id IS NULL THEN IF place IS NULL THEN
select coalesce(linked_place_id, place_id), country_code, select coalesce(linked_place_id, place_id) as place_id, country_code,
housenumber, postcode, housenumber, postcode,
address is not null and address ? 'postcode', null class, type,
from placex where place_id = in_place_id null::hstore as name, address,
INTO for_place_id, searchcountrycode, searchhousenumber, searchpostcode, postcode_isexact, searchhousename; null::geometry as centroid
INTO place
FROM placex where place_id = in_place_id;
END IF; END IF;
--RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode; --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
@ -183,28 +181,27 @@ BEGIN
SELECT placex.place_id, osm_type, osm_id, name, SELECT placex.place_id, osm_type, osm_id, name,
coalesce(extratags->'linked_place', extratags->'place') as place_type, coalesce(extratags->'linked_place', extratags->'place') as place_type,
class, type, admin_level, class, type, admin_level,
type not in ('postcode', 'postal_code') as isaddress,
CASE WHEN rank_address = 0 THEN 100 CASE WHEN rank_address = 0 THEN 100
WHEN rank_address = 11 THEN 5 WHEN rank_address = 11 THEN 5
ELSE rank_address END as rank_address, ELSE rank_address END as rank_address,
0 as distance, country_code, postcode country_code
FROM placex FROM placex
WHERE place_id = for_place_id WHERE place_id = place.place_id
LOOP LOOP
--RAISE WARNING '%',location; --RAISE WARNING '%',location;
IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
searchcountrycode := location.country_code;
END IF;
IF location.rank_address < 4 THEN IF location.rank_address < 4 THEN
-- no country locations for ranks higher than country -- no country locations for ranks higher than country
searchcountrycode := NULL; place.country_code := NULL;
ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
place.country_code := location.country_code;
END IF; END IF;
countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
location.name, location.class, location.type, location.name, location.class, location.type,
location.place_type, location.place_type,
location.admin_level, true, location.isaddress, location.admin_level, true,
location.rank_address, location.distance)::addressline; location.type not in ('postcode', 'postal_code'),
RETURN NEXT countrylocation; location.rank_address, 0)::addressline;
current_rank_address := location.rank_address; current_rank_address := location.rank_address;
END LOOP; END LOOP;
@ -218,82 +215,86 @@ BEGIN
CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
distance, country_code, postcode distance, country_code, postcode
FROM place_addressline join placex on (address_place_id = placex.place_id) FROM place_addressline join placex on (address_place_id = placex.place_id)
WHERE place_addressline.place_id IN (for_place_id, in_place_id) WHERE place_addressline.place_id IN (place.place_id, in_place_id)
AND linked_place_id is null AND linked_place_id is null
AND (placex.country_code IS NULL OR searchcountrycode IS NULL AND (placex.country_code IS NULL OR place.country_code IS NULL
OR placex.country_code = searchcountrycode) OR placex.country_code = place.country_code)
ORDER BY rank_address desc, (place_addressline.place_id = in_place_id) desc, ORDER BY rank_address desc,
(place_addressline.place_id = in_place_id) desc,
(fromarea and place.centroid is not null and not isaddress
and (place.address is null or avals(name) && avals(place.address))
and ST_Contains(geometry, place.centroid)) desc,
isaddress desc, fromarea desc, isaddress desc, fromarea desc,
distance asc, rank_search desc distance asc, rank_search desc
LOOP LOOP
-- RAISE WARNING '%',location; -- RAISE WARNING '%',location;
IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN location_isaddress := location.rank_address != current_rank_address;
searchcountrycode := location.country_code;
IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
place.country_code := location.country_code;
END IF; END IF;
IF location.type in ('postcode', 'postal_code') IF location.type in ('postcode', 'postal_code')
AND searchpostcode is not null AND place.postcode is not null
THEN THEN
-- If the place had a postcode assigned, take this one only -- If the place had a postcode assigned, take this one only
-- into consideration when it is an area and the place does not have -- into consideration when it is an area and the place does not have
-- a postcode itself. -- a postcode itself.
IF location.fromarea AND not postcode_isexact AND location.isaddress THEN IF location.fromarea AND location.isaddress
searchpostcode := null; -- remove the less exact postcode AND (place.address is null or not place.address ? 'postcode')
THEN
place.postcode := null; -- remove the less exact postcode
ELSE ELSE
location.isaddress := false; location_isaddress := false;
END IF; END IF;
END IF; END IF;
countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
location.name, location.class, location.type, location.name, location.class, location.type,
location.place_type, location.place_type,
location.admin_level, location.fromarea, location.admin_level, location.fromarea,
location.isaddress and location.rank_address != current_rank_address, location_isaddress,
location.rank_address, location.rank_address,
location.distance)::addressline; location.distance)::addressline;
RETURN NEXT countrylocation;
IF location.isaddress THEN
current_rank_address := location.rank_address; current_rank_address := location.rank_address;
END IF;
END LOOP; END LOOP;
-- If no country was included yet, add the name information from country_name. -- If no country was included yet, add the name information from country_name.
IF current_rank_address > 4 THEN IF current_rank_address > 4 THEN
SELECT name FROM country_name FOR location IN
WHERE country_code = searchcountrycode LIMIT 1 INTO countryname; SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
LOOP
--RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname; --RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
IF countryname IS NOT NULL THEN RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
location := ROW(null, null, null, countryname, 'place', 'country', NULL,
null, true, true, 4, 0)::addressline; null, true, true, 4, 0)::addressline;
RETURN NEXT location; END LOOP;
END IF;
END IF; END IF;
-- Finally add some artificial rows. -- Finally add some artificial rows.
IF searchcountrycode IS NOT NULL THEN IF place.country_code IS NOT NULL THEN
location := ROW(null, null, null, hstore('ref', searchcountrycode), location := ROW(null, null, null, hstore('ref', place.country_code),
'place', 'country_code', null, null, true, false, 4, 0)::addressline; 'place', 'country_code', null, null, true, false, 4, 0)::addressline;
RETURN NEXT location; RETURN NEXT location;
END IF; END IF;
IF searchhousename IS NOT NULL THEN IF place.name IS NOT NULL THEN
location := ROW(in_place_id, null, null, searchhousename, searchclass, location := ROW(in_place_id, null, null, place.name, place.class,
searchtype, null, null, true, true, 29, 0)::addressline; place.type, null, null, true, true, 29, 0)::addressline;
RETURN NEXT location; RETURN NEXT location;
END IF; END IF;
IF searchhousenumber IS NOT NULL THEN IF place.housenumber IS NOT NULL THEN
location := ROW(null, null, null, hstore('ref', searchhousenumber), location := ROW(null, null, null, hstore('ref', place.housenumber),
'place', 'house_number', null, null, true, true, 28, 0)::addressline; 'place', 'house_number', null, null, true, true, 28, 0)::addressline;
RETURN NEXT location; RETURN NEXT location;
END IF; END IF;
IF search_unlisted_place is not null THEN IF place.address is not null and place.address ? '_unlisted_place' THEN
RETURN NEXT ROW(null, null, null, hstore('name', search_unlisted_place), RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
'place', 'locality', null, null, true, true, 25, 0)::addressline; 'place', 'locality', null, null, true, true, 25, 0)::addressline;
END IF; END IF;
IF searchpostcode IS NOT NULL THEN IF place.postcode is not null THEN
location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
'postcode', null, null, false, true, 5, 0)::addressline; 'postcode', null, null, false, true, 5, 0)::addressline;
RETURN NEXT location; RETURN NEXT location;
END IF; END IF;

View File

@ -5,11 +5,11 @@ Feature: Address computation
Scenario: place nodes are added to the address when they are close enough Scenario: place nodes are added to the address when they are close enough
Given the 0.002 grid Given the 0.002 grid
| 2 | | | | | | 1 | | 3 | | 2 | | | | | | 1 | | 3 |
And the named places And the places
| osm | class | type | geometry | | osm | class | type | name | geometry |
| N1 | place | square | 1 | | N1 | place | square | Square | 1 |
| N2 | place | hamlet | 2 | | N2 | place | hamlet | West Farm | 2 |
| N3 | place | hamlet | 3 | | N3 | place | hamlet | East Farm | 3 |
When importing When importing
Then place_addressline contains Then place_addressline contains
| object | address | fromarea | | object | address | fromarea |
@ -17,6 +17,10 @@ Feature: Address computation
Then place_addressline doesn't contain Then place_addressline doesn't contain
| object | address | | object | address |
| N1 | N2 | | N1 | N2 |
When searching for "Square"
Then results contain
| osm_type | osm_id | name |
| N | 1 | Square, East Farm |
Scenario: given two place nodes, the closer one wins for the address Scenario: given two place nodes, the closer one wins for the address
Given the grid Given the grid
@ -397,3 +401,35 @@ Feature: Address computation
Then results contain Then results contain
| osm_type | osm_id | name | | osm_type | osm_id | name |
| N | 1 | Bolder, Wonderway, Left | | N | 1 | Bolder, Wonderway, Left |
Scenario: POIs can correct address parts on the fly
Given the grid
| 1 | | | | 2 | | 5 |
| | | | 9 | | 8 | |
| 4 | | | | 3 | | 6 |
And the places
| osm | class | type | admin | name | geometry |
| R1 | boundary | administrative | 8 | Left | (1,2,3,4,1) |
| R2 | boundary | administrative | 8 | Right | (2,3,6,5,2) |
And the places
| osm | class | type | name | geometry |
| W1 | highway | primary | Wonderway | 2,3 |
| N1 | amenity | cafe | Bolder | 9 |
| N2 | amenity | cafe | Leftside | 8 |
When importing
Then place_addressline contains
| object | address | isaddress |
| W1 | R1 | False |
| W1 | R2 | True |
And place_addressline doesn't contain
| object | address |
| N1 | R1 |
| N2 | R2 |
When searching for "Bolder"
Then results contain
| osm_type | osm_id | name |
| N | 1 | Bolder, Wonderway, Left |
When searching for "Leftside"
Then results contain
| osm_type | osm_id | name |
| N | 2 | Leftside, Wonderway, Right |