use address tokens in SQL

This commit is contained in:
Sarah Hoffmann
2021-04-25 23:42:56 +02:00
parent 9e92759ac7
commit d75a235c1f
5 changed files with 279 additions and 271 deletions

View File

@@ -43,8 +43,8 @@ LANGUAGE plpgsql STABLE;
-- find the parent road of the cut road parts -- find the parent road of the cut road parts
CREATE OR REPLACE FUNCTION get_interpolation_parent(street TEXT, CREATE OR REPLACE FUNCTION get_interpolation_parent(street INTEGER[], place INTEGER[],
place TEXT, partition SMALLINT, partition SMALLINT,
centroid GEOMETRY, geom GEOMETRY) centroid GEOMETRY, geom GEOMETRY)
RETURNS BIGINT RETURNS BIGINT
AS $$ AS $$
@@ -155,16 +155,13 @@ BEGIN
NEW.interpolationtype = NEW.address->'interpolation'; NEW.interpolationtype = NEW.address->'interpolation';
place_centroid := ST_PointOnSurface(NEW.linegeo); place_centroid := ST_PointOnSurface(NEW.linegeo);
NEW.parent_place_id = get_interpolation_parent(NEW.address->'street', NEW.parent_place_id = get_interpolation_parent(token_addr_street_match_tokens(NEW.token_info),
NEW.address->'place', token_addr_place_match_tokens(NEW.token_info),
NEW.partition, place_centroid, NEW.linegeo); NEW.partition, place_centroid, NEW.linegeo);
IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN interpol_postcode := token_normalized_postcode(NEW.address->'postcode');
interpol_postcode := NEW.address->'postcode';
ELSE
interpol_postcode := NULL;
END IF;
NEW.token_info := token_strip_info(NEW.token_info);
IF NEW.address ? '_inherited' THEN IF NEW.address ? '_inherited' THEN
NEW.address := hstore('interpolation', NEW.interpolationtype); NEW.address := hstore('interpolation', NEW.interpolationtype);
END IF; END IF;
@@ -213,12 +210,13 @@ BEGIN
-- determine postcode -- determine postcode
postcode := coalesce(interpol_postcode, postcode := coalesce(interpol_postcode,
prevnode.address->'postcode', token_normalized_postcode(prevnode.address->'postcode'),
nextnode.address->'postcode', token_normalized_postcode(nextnode.address->'postcode'),
postcode); postcode);
IF postcode is NULL THEN IF postcode is NULL THEN
SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode; SELECT token_normalized_postcode(placex.postcode)
FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
END IF; END IF;
IF postcode is NULL THEN IF postcode is NULL THEN
postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry); postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
@@ -228,7 +226,7 @@ BEGIN
NEW.startnumber := startnumber; NEW.startnumber := startnumber;
NEW.endnumber := endnumber; NEW.endnumber := endnumber;
NEW.linegeo := sectiongeo; NEW.linegeo := sectiongeo;
NEW.postcode := upper(trim(postcode)); NEW.postcode := postcode;
ELSE ELSE
insert into location_property_osmline insert into location_property_osmline
(linegeo, partition, osm_id, parent_place_id, (linegeo, partition, osm_id, parent_place_id,

View File

@@ -63,54 +63,36 @@ END
$$ $$
LANGUAGE plpgsql STABLE; LANGUAGE plpgsql STABLE;
CREATE OR REPLACE FUNCTION get_places_for_addr_tags(in_partition SMALLINT,
feature GEOMETRY, CREATE OR REPLACE FUNCTION get_address_place(in_partition SMALLINT, feature GEOMETRY,
address HSTORE, country TEXT) from_rank SMALLINT, to_rank SMALLINT,
RETURNS SETOF nearfeaturecentr extent FLOAT, tokens INT[])
RETURNS nearfeaturecentr
AS $$ AS $$
DECLARE DECLARE
r nearfeaturecentr%rowtype; r nearfeaturecentr%rowtype;
item RECORD;
BEGIN BEGIN
FOR item IN
SELECT (get_addr_tag_rank(key, country)).*, key, name FROM
(SELECT skeys(address) as key, svals(address) as name) x
LOOP
IF item.from_rank is null THEN
CONTINUE;
END IF;
{% for partition in db.partitions %} {% for partition in db.partitions %}
IF in_partition = {{ partition }} THEN IF in_partition = {{ partition }} THEN
SELECT place_id, keywords, rank_address, rank_search, SELECT place_id, keywords, rank_address, rank_search,
min(ST_Distance(feature, centroid)) as distance, min(ST_Distance(feature, centroid)) as distance,
isguess, postcode, centroid INTO r isguess, postcode, centroid INTO r
FROM location_area_large_{{ partition }} FROM location_area_large_{{ partition }}
WHERE geometry && ST_Expand(feature, item.extent) WHERE geometry && ST_Expand(feature, extent)
AND rank_address between item.from_rank and item.to_rank AND rank_address between from_rank and to_rank
AND word_ids_from_name(item.name) && keywords AND tokens && keywords
GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
ORDER BY bool_or(ST_Intersects(geometry, feature)), distance LIMIT 1; ORDER BY bool_or(ST_Intersects(geometry, feature)), distance LIMIT 1;
IF r.place_id is null THEN RETURN r;
-- If we cannot find a place for the term, just return the END IF;
-- search term for the given name. That ensures that the address
-- element can still be searched for, even though it will not be
-- displayed.
RETURN NEXT ROW(null, addr_ids_from_name(item.name), null, null,
null, null, null, null)::nearfeaturecentr;
ELSE
RETURN NEXT r;
END IF;
CONTINUE;
END IF;
{% endfor %} {% endfor %}
RAISE EXCEPTION 'Unknown partition %', in_partition; RAISE EXCEPTION 'Unknown partition %', in_partition;
END LOOP;
END; END;
$$ $$
LANGUAGE plpgsql STABLE; LANGUAGE plpgsql STABLE;
create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$ create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$
DECLARE DECLARE
BEGIN BEGIN

View File

@@ -47,6 +47,40 @@ $$
LANGUAGE plpgsql STABLE; LANGUAGE plpgsql STABLE;
CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
poi_osm_id BIGINT)
RETURNS BIGINT
AS $$
DECLARE
location RECORD;
parent RECORD;
BEGIN
FOR location IN
SELECT members FROM planet_osm_rels
WHERE parts @> ARRAY[poi_osm_id]
and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
and tags @> ARRAY['associatedStreet']
LOOP
FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
IF location.members[i+1] = 'street' THEN
FOR parent IN
SELECT place_id from placex
WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
and name is not null
and rank_search between 26 and 27
LOOP
RETURN parent.place_id;
END LOOP;
END IF;
END LOOP;
END LOOP;
RETURN NULL;
END;
$$
LANGUAGE plpgsql STABLE;
-- Find the parent road of a POI. -- Find the parent road of a POI.
-- --
-- \returns Place ID of parent object or NULL if none -- \returns Place ID of parent object or NULL if none
@@ -57,118 +91,89 @@ CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
poi_osm_id BIGINT, poi_osm_id BIGINT,
poi_partition SMALLINT, poi_partition SMALLINT,
bbox GEOMETRY, bbox GEOMETRY,
addr_street TEXT, addr_street INTEGER[],
addr_place TEXT, addr_place INTEGER[],
fallback BOOL = true) is_place_addr BOOLEAN)
RETURNS BIGINT RETURNS BIGINT
AS $$ AS $$
DECLARE DECLARE
parent_place_id BIGINT DEFAULT NULL; parent_place_id BIGINT DEFAULT NULL;
location RECORD; location RECORD;
parent RECORD;
BEGIN BEGIN
{% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %} {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
-- Is this object part of an associatedStreet relation? -- Is this object part of an associatedStreet relation?
FOR location IN parent_place_id := find_associated_street(poi_osm_type, poi_osm_id);
SELECT members FROM planet_osm_rels
WHERE parts @> ARRAY[poi_osm_id]
and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
and tags @> ARRAY['associatedStreet']
LOOP
FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
IF location.members[i+1] = 'street' THEN
FOR parent IN
SELECT place_id from placex
WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
and name is not null
and rank_search between 26 and 27
LOOP
RETURN parent.place_id;
END LOOP;
END IF;
END LOOP;
END LOOP;
IF parent_place_id is null THEN
parent_place_id := find_parent_for_address(addr_street, addr_place, parent_place_id := find_parent_for_address(addr_street, addr_place,
poi_partition, bbox); poi_partition, bbox);
IF parent_place_id is not null THEN END IF;
RETURN parent_place_id;
END IF;
IF poi_osm_type = 'N' THEN IF parent_place_id is null and poi_osm_type = 'N' THEN
-- Is this node part of an interpolation? -- Is this node part of an interpolation?
FOR parent IN FOR location IN
SELECT q.parent_place_id SELECT q.parent_place_id
FROM location_property_osmline q, planet_osm_ways x FROM location_property_osmline q, planet_osm_ways x
WHERE q.linegeo && bbox and x.id = q.osm_id WHERE q.linegeo && bbox and x.id = q.osm_id
and poi_osm_id = any(x.nodes) and poi_osm_id = any(x.nodes)
LIMIT 1 LIMIT 1
LOOP LOOP
{% if debug %}RAISE WARNING 'Get parent from interpolation: %', parent.parent_place_id;{% endif %} {% if debug %}RAISE WARNING 'Get parent from interpolation: %', location.parent_place_id;{% endif %}
RETURN parent.parent_place_id; RETURN location.parent_place_id;
END LOOP; END LOOP;
-- Is this node part of any other way? FOR location IN
FOR location IN SELECT p.place_id, p.osm_id, p.rank_search, p.address,
SELECT p.place_id, p.osm_id, p.rank_search, p.address, coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid FROM placex p, planet_osm_ways w
FROM placex p, planet_osm_ways w WHERE p.osm_type = 'W' and p.rank_search >= 26
WHERE p.osm_type = 'W' and p.rank_search >= 26 and p.geometry && bbox
and p.geometry && bbox and w.id = p.osm_id and poi_osm_id = any(w.nodes)
and w.id = p.osm_id and poi_osm_id = any(w.nodes) LOOP
LOOP {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
{% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
-- Way IS a road then we are on it - that must be our road -- Way IS a road then we are on it - that must be our road
IF location.rank_search < 28 THEN IF location.rank_search < 28 THEN
{% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %} {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
return location.place_id; RETURN location.place_id;
END IF;
SELECT find_parent_for_poi('W', location.osm_id, poi_partition,
location.centroid,
location.address->'street',
location.address->'place',
false)
INTO parent_place_id;
IF parent_place_id is not null THEN
RETURN parent_place_id;
END IF;
END LOOP;
END IF;
IF fallback THEN
IF addr_street is null and addr_place is not null THEN
-- The address is attached to a place we don't know.
-- Instead simply use the containing area with the largest rank.
FOR location IN
SELECT place_id FROM placex
WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
AND rank_address between 5 and 25
ORDER BY rank_address desc
LOOP
RETURN location.place_id;
END LOOP;
ELSEIF ST_Area(bbox) < 0.005 THEN
-- for smaller features get the nearest road
SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
{% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
ELSE
-- for larger features simply find the area with the largest rank that
-- contains the bbox, only use addressable features
FOR location IN
SELECT place_id FROM placex
WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
AND rank_address between 5 and 25
ORDER BY rank_address desc
LOOP
RETURN location.place_id;
END LOOP;
END IF; END IF;
END IF;
RETURN parent_place_id; parent_place_id := find_associated_street('W', location.osm_id);
END LOOP;
END IF;
IF parent_place_id is NULL THEN
IF is_place_addr THEN
-- The address is attached to a place we don't know.
-- Instead simply use the containing area with the largest rank.
FOR location IN
SELECT place_id FROM placex
WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
AND rank_address between 5 and 25
ORDER BY rank_address desc
LOOP
RETURN location.place_id;
END LOOP;
ELSEIF ST_Area(bbox) < 0.005 THEN
-- for smaller features get the nearest road
SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
{% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
ELSE
-- for larger features simply find the area with the largest rank that
-- contains the bbox, only use addressable features
FOR location IN
SELECT place_id FROM placex
WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
AND rank_address between 5 and 25
ORDER BY rank_address desc
LOOP
RETURN location.place_id;
END LOOP;
END IF;
END IF;
RETURN parent_place_id;
END; END;
$$ $$
LANGUAGE plpgsql STABLE; LANGUAGE plpgsql STABLE;
@@ -290,7 +295,7 @@ LANGUAGE plpgsql STABLE;
CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT, CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
in_partition SMALLINT, in_partition SMALLINT,
parent_place_id BIGINT, parent_place_id BIGINT,
address HSTORE, is_place_addr BOOLEAN,
country TEXT, country TEXT,
token_info JSONB, token_info JSONB,
geometry GEOMETRY, geometry GEOMETRY,
@@ -304,8 +309,8 @@ DECLARE
hnr_vector INTEGER[]; hnr_vector INTEGER[];
addr_item RECORD; addr_item RECORD;
addr_place RECORD;
parent_address_place_ids BIGINT[]; parent_address_place_ids BIGINT[];
filtered_address HSTORE;
BEGIN BEGIN
nameaddress_vector := '{}'::INTEGER[]; nameaddress_vector := '{}'::INTEGER[];
@@ -314,42 +319,37 @@ BEGIN
FROM search_name s FROM search_name s
WHERE s.place_id = parent_place_id; WHERE s.place_id = parent_place_id;
-- Find all address tags that don't appear in the parent search names. FOR addr_item IN
SELECT hstore(array_agg(ARRAY[k, v])) INTO filtered_address SELECT (get_addr_tag_rank(key, country)).*, match_tokens, search_tokens
FROM (SELECT skeys(address) as k, svals(address) as v) a FROM token_get_address_tokens(token_info)
WHERE not addr_ids_from_name(v) && parent_address_vector WHERE not search_tokens <@ parent_address_vector
AND k not in ('country', 'street', 'place', 'postcode', LOOP
'housenumber', 'streetnumber', 'conscriptionnumber'); addr_place := get_address_place(in_partition, geometry,
addr_item.from_rank, addr_item.to_rank,
addr_item.extent, addr_item.match_tokens);
-- Compute all search terms from the addr: tags. IF addr_place is null THEN
IF filtered_address IS NOT NULL THEN -- No place found in OSM that matches. Make it at least searchable.
FOR addr_item IN nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
SELECT * FROM ELSE
get_places_for_addr_tags(in_partition, geometry, filtered_address, country) IF parent_address_place_ids is null THEN
LOOP SELECT array_agg(parent_place_id) INTO parent_address_place_ids
IF addr_item.place_id is null THEN FROM place_addressline
nameaddress_vector := array_merge(nameaddress_vector, WHERE place_id = parent_place_id;
addr_item.keywords); END IF;
CONTINUE;
END IF;
IF parent_address_place_ids is null THEN -- If the parent already lists the place in place_address line, then we
SELECT array_agg(parent_place_id) INTO parent_address_place_ids -- are done. Otherwise, add its own place_address line.
FROM place_addressline IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
WHERE place_id = parent_place_id; nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
END IF;
IF not parent_address_place_ids @> ARRAY[addr_item.place_id] THEN INSERT INTO place_addressline (place_id, address_place_id, fromarea,
nameaddress_vector := array_merge(nameaddress_vector, isaddress, distance, cached_rank_address)
addr_item.keywords); VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
true, addr_place.distance, addr_place.rank_address);
INSERT INTO place_addressline (place_id, address_place_id, fromarea, END IF;
isaddress, distance, cached_rank_address) END IF;
VALUES (obj_place_id, addr_item.place_id, not addr_item.isguess, END LOOP;
true, addr_item.distance, addr_item.rank_address);
END IF;
END LOOP;
END IF;
name_vector := token_get_name_search_tokens(token_info); name_vector := token_get_name_search_tokens(token_info);
@@ -364,16 +364,15 @@ BEGIN
name_vector := array_merge(name_vector, hnr_vector); name_vector := array_merge(name_vector, hnr_vector);
END IF; END IF;
IF not address ? 'street' and address ? 'place' THEN IF is_place_addr THEN
addr_place_ids := addr_ids_from_name(address->'place'); addr_place_ids := token_addr_place_search_tokens(token_info);
IF not addr_place_ids <@ parent_name_vector THEN IF not addr_place_ids <@ parent_name_vector THEN
-- make sure addr:place terms are always searchable -- make sure addr:place terms are always searchable
nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids); nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
-- If there is a housenumber, also add the place name as a name, -- If there is a housenumber, also add the place name as a name,
-- so we can search it by the usual housenumber+place algorithms. -- so we can search it by the usual housenumber+place algorithms.
IF hnr_vector is not null THEN IF hnr_vector is not null THEN
name_vector := array_merge(name_vector, name_vector := array_merge(name_vector, addr_place_ids);
ARRAY[getorcreate_name_id(make_standard_name(address->'place'))]);
END IF; END IF;
END IF; END IF;
END IF; END IF;
@@ -408,7 +407,7 @@ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT, CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
partition SMALLINT, partition SMALLINT,
maxrank SMALLINT, maxrank SMALLINT,
address HSTORE, token_info JSONB,
geometry GEOMETRY, geometry GEOMETRY,
country TEXT, country TEXT,
OUT parent_place_id BIGINT, OUT parent_place_id BIGINT,
@@ -423,7 +422,8 @@ DECLARE
current_node_area GEOMETRY := NULL; current_node_area GEOMETRY := NULL;
parent_place_rank INT := 0; parent_place_rank INT := 0;
addr_place_ids BIGINT[]; addr_place_ids BIGINT[] := '{}'::int[];
new_address_vector INT[];
location RECORD; location RECORD;
BEGIN BEGIN
@@ -433,16 +433,21 @@ BEGIN
address_havelevel := array_fill(false, ARRAY[maxrank]); address_havelevel := array_fill(false, ARRAY[maxrank]);
FOR location IN FOR location IN
SELECT * FROM get_places_for_addr_tags(partition, geometry, SELECT (get_address_place(partition, geometry, from_rank, to_rank,
address, country) extent, match_tokens)).*, search_tokens
ORDER BY rank_address, distance, isguess desc FROM (SELECT (get_addr_tag_rank(key, country)).*, match_tokens, search_tokens
FROM token_get_address_tokens(token_info)) x
ORDER BY rank_address, distance, isguess desc
LOOP LOOP
{% if not db.reverse_only %} IF location.place_id is null THEN
nameaddress_vector := array_merge(nameaddress_vector, {% if not db.reverse_only %}
location.keywords::int[]); nameaddress_vector := array_merge(nameaddress_vector, location.search_tokens);
{% endif %} {% endif %}
ELSE
{% if not db.reverse_only %}
nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
{% endif %}
IF location.place_id is not null THEN
location_isaddress := not address_havelevel[location.rank_address]; location_isaddress := not address_havelevel[location.rank_address];
IF not address_havelevel[location.rank_address] THEN IF not address_havelevel[location.rank_address] THEN
address_havelevel[location.rank_address] := true; address_havelevel[location.rank_address] := true;
@@ -457,13 +462,13 @@ BEGIN
VALUES (obj_place_id, location.place_id, not location.isguess, VALUES (obj_place_id, location.place_id, not location.isguess,
true, location.distance, location.rank_address); true, location.distance, location.rank_address);
addr_place_ids := array_append(addr_place_ids, location.place_id); addr_place_ids := addr_place_ids || location.place_id;
END IF; END IF;
END LOOP; END LOOP;
FOR location IN FOR location IN
SELECT * FROM getNearFeatures(partition, geometry, maxrank) SELECT * FROM getNearFeatures(partition, geometry, maxrank)
WHERE addr_place_ids is null or not addr_place_ids @> ARRAY[place_id] WHERE not addr_place_ids @> ARRAY[place_id]
ORDER BY rank_address, isguess asc, ORDER BY rank_address, isguess asc,
distance * distance *
CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
@@ -671,8 +676,8 @@ DECLARE
parent_address_level SMALLINT; parent_address_level SMALLINT;
place_address_level SMALLINT; place_address_level SMALLINT;
addr_street TEXT; addr_street INTEGER[];
addr_place TEXT; addr_place INTEGER[];
max_rank SMALLINT; max_rank SMALLINT;
@@ -684,6 +689,7 @@ DECLARE
linked_importance FLOAT; linked_importance FLOAT;
linked_wikipedia TEXT; linked_wikipedia TEXT;
is_place_address BOOLEAN;
result BOOLEAN; result BOOLEAN;
BEGIN BEGIN
-- deferred delete -- deferred delete
@@ -715,6 +721,7 @@ BEGIN
NEW.extratags := NEW.extratags - 'linked_place'::TEXT; NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
IF NEW.linked_place_id is not null THEN IF NEW.linked_place_id is not null THEN
NEW.token_info := null;
{% if debug %}RAISE WARNING 'place already linked to %', NEW.linked_place_id;{% endif %} {% if debug %}RAISE WARNING 'place already linked to %', NEW.linked_place_id;{% endif %}
RETURN NEW; RETURN NEW;
END IF; END IF;
@@ -725,13 +732,34 @@ BEGIN
-- imported as place=postcode. That's why relations are allowed to pass here. -- imported as place=postcode. That's why relations are allowed to pass here.
-- This can go away in a couple of versions. -- This can go away in a couple of versions.
IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
NEW.token_info := null;
RETURN NEW; RETURN NEW;
END IF; END IF;
-- Speed up searches - just use the centroid of the feature -- Compute a preliminary centroid.
-- cheaper but less acurate
NEW.centroid := ST_PointOnSurface(NEW.geometry); NEW.centroid := ST_PointOnSurface(NEW.geometry);
{% if debug %}RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);{% endif %}
-- recalculate country and partition
IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
-- for countries, believe the mapped country code,
-- so that we remain in the right partition if the boundaries
-- suddenly expand.
NEW.country_code := lower(NEW.address->'country');
NEW.partition := get_partition(lower(NEW.country_code));
IF NEW.partition = 0 THEN
NEW.country_code := lower(get_country_code(NEW.centroid));
NEW.partition := get_partition(NEW.country_code);
END IF;
ELSE
IF NEW.rank_search >= 4 THEN
NEW.country_code := lower(get_country_code(NEW.centroid));
ELSE
NEW.country_code := NULL;
END IF;
NEW.partition := get_partition(NEW.country_code);
END IF;
{% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
-- recompute the ranks, they might change when linking changes -- recompute the ranks, they might change when linking changes
SELECT * INTO NEW.rank_search, NEW.rank_address SELECT * INTO NEW.rank_search, NEW.rank_address
@@ -811,37 +839,12 @@ BEGIN
parent_address_level := 3; parent_address_level := 3;
END IF; END IF;
{% if debug %}RAISE WARNING 'Copy over address tags';{% endif %}
-- housenumber is a computed field, so start with an empty value
NEW.housenumber := token_normalized_housenumber(NEW.token_info); NEW.housenumber := token_normalized_housenumber(NEW.token_info);
IF NEW.address is not NULL THEN addr_street := token_addr_street_match_tokens(NEW.token_info);
addr_street := NEW.address->'street'; addr_place := token_addr_place_match_tokens(NEW.token_info);
addr_place := NEW.address->'place';
END IF;
NEW.postcode := null; NEW.postcode := null;
-- recalculate country and partition
IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
-- for countries, believe the mapped country code,
-- so that we remain in the right partition if the boundaries
-- suddenly expand.
NEW.country_code := lower(NEW.address->'country');
NEW.partition := get_partition(lower(NEW.country_code));
IF NEW.partition = 0 THEN
NEW.country_code := lower(get_country_code(NEW.centroid));
NEW.partition := get_partition(NEW.country_code);
END IF;
ELSE
IF NEW.rank_search >= 4 THEN
NEW.country_code := lower(get_country_code(NEW.centroid));
ELSE
NEW.country_code := NULL;
END IF;
NEW.partition := get_partition(NEW.country_code);
END IF;
{% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
-- waterway ways are linked when they are part of a relation and have the same class/type -- waterway ways are linked when they are part of a relation and have the same class/type
IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[] FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
@@ -878,12 +881,14 @@ BEGIN
{% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %} {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
NEW.parent_place_id := null; NEW.parent_place_id := null;
is_place_address := coalesce(not NEW.address ? 'street' and NEW.address ? 'place', FALSE);
-- We have to find our parent road. -- We have to find our parent road.
NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id, NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
NEW.partition, NEW.partition,
ST_Envelope(NEW.geometry), ST_Envelope(NEW.geometry),
addr_street, addr_place); addr_street, addr_place,
is_place_address);
-- If we found the road take a shortcut here. -- If we found the road take a shortcut here.
-- Otherwise fall back to the full address getting method below. -- Otherwise fall back to the full address getting method below.
@@ -893,12 +898,12 @@ BEGIN
SELECT p.country_code, p.postcode, p.name FROM placex p SELECT p.country_code, p.postcode, p.name FROM placex p
WHERE p.place_id = NEW.parent_place_id INTO location; WHERE p.place_id = NEW.parent_place_id INTO location;
IF addr_street is null and addr_place is not null THEN IF is_place_address THEN
-- Check if the addr:place tag is part of the parent name -- Check if the addr:place tag is part of the parent name
SELECT count(*) INTO i SELECT count(*) INTO i
FROM svals(location.name) AS pname WHERE pname = addr_place; FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
IF i = 0 THEN IF i = 0 THEN
NEW.address = NEW.address || hstore('_unlisted_place', addr_place); NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
END IF; END IF;
END IF; END IF;
@@ -906,14 +911,9 @@ BEGIN
{% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %} {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
-- determine postcode -- determine postcode
IF NEW.address is not null AND NEW.address ? 'postcode' THEN NEW.postcode := coalesce(token_normalized_postcode(NEW.address->'postcode'),
NEW.postcode = upper(trim(NEW.address->'postcode')); location.postcode,
ELSE get_nearest_postcode(NEW.country_code, NEW.geometry));
NEW.postcode := location.postcode;
END IF;
IF NEW.postcode is null THEN
NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
END IF;
IF NEW.name is not NULL THEN IF NEW.name is not NULL THEN
NEW.name := add_default_place_name(NEW.country_code, NEW.name); NEW.name := add_default_place_name(NEW.country_code, NEW.name);
@@ -924,7 +924,7 @@ BEGIN
SELECT * INTO name_vector, nameaddress_vector SELECT * INTO name_vector, nameaddress_vector
FROM create_poi_search_terms(NEW.place_id, FROM create_poi_search_terms(NEW.place_id,
NEW.partition, NEW.parent_place_id, NEW.partition, NEW.parent_place_id,
NEW.address, NEW.country_code, is_place_address, NEW.country_code,
NEW.token_info, NEW.centroid); NEW.token_info, NEW.centroid);
IF array_length(name_vector, 1) is not NULL THEN IF array_length(name_vector, 1) is not NULL THEN
@@ -1020,7 +1020,6 @@ BEGIN
END IF; END IF;
END IF; END IF;
-- make sure all names are in the word table
IF NEW.admin_level = 2 IF NEW.admin_level = 2
AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.class = 'boundary' AND NEW.type = 'administrative'
AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R' AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
@@ -1058,23 +1057,17 @@ BEGIN
ELSEIF NEW.rank_address > 25 THEN ELSEIF NEW.rank_address > 25 THEN
max_rank := 25; max_rank := 25;
ELSE ELSE
max_rank = NEW.rank_address; max_rank := NEW.rank_address;
END IF; END IF;
SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank, SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
NEW.address, geom, NEW.country_code) NEW.token_info, geom, NEW.country_code)
INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector; INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
{% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %} {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
IF NEW.address is not null AND NEW.address ? 'postcode' NEW.postcode := coalesce(token_normalized_postcode(NEW.address->'postcode'),
AND NEW.address->'postcode' not similar to '%(,|;)%' THEN NEW.postcode);
NEW.postcode := upper(trim(NEW.address->'postcode'));
END IF;
IF NEW.postcode is null AND NEW.rank_search > 8 THEN
NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
END IF;
-- if we have a name add this to the name search table -- if we have a name add this to the name search table
IF NEW.name IS NOT NULL THEN IF NEW.name IS NOT NULL THEN
@@ -1085,7 +1078,7 @@ BEGIN
IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
result := add_location(NEW.place_id, NEW.country_code, NEW.partition, result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
name_vector, NEW.rank_search, NEW.rank_address, name_vector, NEW.rank_search, NEW.rank_address,
upper(trim(NEW.address->'postcode')), NEW.geometry, NEW.centroid); NEW.postcode, NEW.geometry, NEW.centroid);
{% if debug %}RAISE WARNING 'added to location (full)';{% endif %} {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
END IF; END IF;
@@ -1094,9 +1087,11 @@ BEGIN
{% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %} {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
END IF; END IF;
result := insertSearchName(NEW.partition, NEW.place_id, IF NEW.rank_address between 16 and 27 THEN
token_get_name_match_tokens(NEW.token_info), result := insertSearchName(NEW.partition, NEW.place_id,
NEW.rank_search, NEW.rank_address, NEW.geometry); token_get_name_match_tokens(NEW.token_info),
NEW.rank_search, NEW.rank_address, NEW.geometry);
END IF;
{% if debug %}RAISE WARNING 'added to search name (full)';{% endif %} {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
{% if not db.reverse_only %} {% if not db.reverse_only %}
@@ -1107,7 +1102,10 @@ BEGIN
NEW.importance, NEW.country_code, name_vector, NEW.importance, NEW.country_code, name_vector,
nameaddress_vector, NEW.centroid); nameaddress_vector, NEW.centroid);
{% endif %} {% endif %}
END IF;
IF NEW.postcode is null AND NEW.rank_search > 8 THEN
NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
END IF; END IF;
{% if debug %}RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;{% endif %} {% if debug %}RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;{% endif %}

View File

@@ -221,37 +221,30 @@ LANGUAGE plpgsql STABLE;
-- \param centroid Location of the address. -- \param centroid Location of the address.
-- --
-- \return Place ID of the parent if one was found, NULL otherwise. -- \return Place ID of the parent if one was found, NULL otherwise.
CREATE OR REPLACE FUNCTION find_parent_for_address(street TEXT, place TEXT, CREATE OR REPLACE FUNCTION find_parent_for_address(street INTEGER[], place INTEGER[],
partition SMALLINT, partition SMALLINT,
centroid GEOMETRY) centroid GEOMETRY)
RETURNS BIGINT RETURNS BIGINT
AS $$ AS $$
DECLARE DECLARE
parent_place_id BIGINT; parent_place_id BIGINT;
word_ids INTEGER[];
BEGIN BEGIN
IF street is not null THEN IF street is not null THEN
-- Check for addr:street attributes -- Check for addr:street attributes
-- Note that addr:street links can only be indexed, once the street itself is indexed -- Note that addr:street links can only be indexed, once the street itself is indexed
word_ids := word_ids_from_name(street); parent_place_id := getNearestNamedRoadPlaceId(partition, centroid, street);
IF word_ids is not null THEN IF parent_place_id is not null THEN
parent_place_id := getNearestNamedRoadPlaceId(partition, centroid, word_ids); {% if debug %}RAISE WARNING 'Get parent form addr:street: %', parent_place_id;{% endif %}
IF parent_place_id is not null THEN RETURN parent_place_id;
{% if debug %}RAISE WARNING 'Get parent form addr:street: %', parent_place_id;{% endif %}
RETURN parent_place_id;
END IF;
END IF; END IF;
END IF; END IF;
-- Check for addr:place attributes. -- Check for addr:place attributes.
IF place is not null THEN IF place is not null THEN
word_ids := word_ids_from_name(place); parent_place_id := getNearestNamedPlacePlaceId(partition, centroid, place);
IF word_ids is not null THEN IF parent_place_id is not null THEN
parent_place_id := getNearestNamedPlacePlaceId(partition, centroid, word_ids); {% if debug %}RAISE WARNING 'Get parent form addr:place: %', parent_place_id;{% endif %}
IF parent_place_id is not null THEN RETURN parent_place_id;
{% if debug %}RAISE WARNING 'Get parent form addr:place: %', parent_place_id;{% endif %}
RETURN parent_place_id;
END IF;
END IF; END IF;
END IF; END IF;

View File

@@ -34,6 +34,43 @@ AS $$
$$ LANGUAGE SQL IMMUTABLE STRICT; $$ LANGUAGE SQL IMMUTABLE STRICT;
CREATE OR REPLACE FUNCTION token_addr_street_match_tokens(info JSONB)
RETURNS INTEGER[]
AS $$
SELECT (info->>'street_match')::INTEGER[]
$$ LANGUAGE SQL IMMUTABLE STRICT;
CREATE OR REPLACE FUNCTION token_addr_place_match_tokens(info JSONB)
RETURNS INTEGER[]
AS $$
SELECT (info->>'place_match')::INTEGER[]
$$ LANGUAGE SQL IMMUTABLE STRICT;
CREATE OR REPLACE FUNCTION token_addr_place_search_tokens(info JSONB)
RETURNS INTEGER[]
AS $$
SELECT (info->>'place_search')::INTEGER[]
$$ LANGUAGE SQL IMMUTABLE STRICT;
DROP TYPE IF EXISTS token_addresstoken CASCADE;
CREATE TYPE token_addresstoken AS (
key TEXT,
match_tokens INT[],
search_tokens INT[]
);
CREATE OR REPLACE FUNCTION token_get_address_tokens(info JSONB)
RETURNS SETOF token_addresstoken
AS $$
SELECT key, (value->>1)::int[] as match_tokens,
(value->>0)::int[] as search_tokens
FROM jsonb_each(info->'addr');
$$ LANGUAGE SQL IMMUTABLE STRICT;
CREATE OR REPLACE FUNCTION token_normalized_postcode(postcode TEXT) CREATE OR REPLACE FUNCTION token_normalized_postcode(postcode TEXT)
RETURNS TEXT RETURNS TEXT
AS $$ AS $$