X-Git-Url: https://git.openstreetmap.org/nominatim.git/blobdiff_plain/9b7f0627eabba2aaeaf5d31b8a36a7dc2ff8d45a..0ef64258470a5665b20122a75cbac1bb8cc7121c:/sql/functions.sql diff --git a/sql/functions.sql b/sql/functions.sql index 024d1caa..908236b1 100644 --- a/sql/functions.sql +++ b/sql/functions.sql @@ -22,215 +22,6 @@ END; $$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text - AS '{modulepath}/nominatim.so', 'transliteration' -LANGUAGE c IMMUTABLE STRICT; - -CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text - AS '{modulepath}/nominatim.so', 'gettokenstring' -LANGUAGE c IMMUTABLE STRICT; - -CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT - AS $$ -DECLARE - o TEXT; -BEGIN - o := public.gettokenstring(public.transliteration(name)); - RETURN trim(substr(o,1,length(o))); -END; -$$ -LANGUAGE 'plpgsql' IMMUTABLE; - --- returns NULL if the word is too common -CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; - count INTEGER; -BEGIN - lookup_token := trim(lookup_word); - SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0); - ELSE - IF count > get_maxwordfreq() THEN - return_word_id := NULL; - END IF; - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - lookup_word TEXT; - return_word_id INTEGER; -BEGIN - lookup_word := upper(trim(postcode)); - lookup_token := ' ' || make_standard_name(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2)) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - nospace_lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0); --- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ',''); --- IF ' '||nospace_lookup_token != lookup_token THEN --- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null); --- END IF; - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE -BEGIN - RETURN getorcreate_name_id(lookup_word, ''); -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT) - RETURNS INTEGER[] - AS $$ -DECLARE - lookup_token TEXT; - return_word_ids INTEGER[]; -BEGIN - lookup_token := ' '||trim(lookup_word); - SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids; - RETURN return_word_ids; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[]) RETURNS INTEGER[] @@ -371,171 +162,6 @@ $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID - AS $$ -DECLARE - s TEXT; - w INTEGER; - words TEXT[]; - item RECORD; - j INTEGER; -BEGIN - FOR item IN SELECT (each(src)).* LOOP - - s := make_standard_name(item.value); - w := getorcreate_country(s, lookup_country_code); - - words := regexp_split_to_array(item.value, E'[,;()]'); - IF array_upper(words, 1) != 1 THEN - FOR j IN 1..array_upper(words, 1) LOOP - s := make_standard_name(words[j]); - IF s != '' THEN - w := getorcreate_country(s, lookup_country_code); - END IF; - END LOOP; - END IF; - END LOOP; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[] - AS $$ -DECLARE - result INTEGER[]; - s TEXT; - w INTEGER; - words TEXT[]; - item RECORD; - j INTEGER; -BEGIN - result := '{}'::INTEGER[]; - - FOR item IN SELECT (each(src)).* LOOP - - s := make_standard_name(item.value); - - w := getorcreate_name_id(s, item.value); - - IF not(ARRAY[w] <@ result) THEN - result := result || w; - END IF; - - w := getorcreate_word_id(s); - - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - - words := string_to_array(s, ' '); - IF array_upper(words, 1) IS NOT NULL THEN - FOR j IN 1..array_upper(words, 1) LOOP - IF (words[j] != '') THEN - w = getorcreate_word_id(words[j]); - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END LOOP; - END IF; - - words := regexp_split_to_array(item.value, E'[,;()]'); - IF array_upper(words, 1) != 1 THEN - FOR j IN 1..array_upper(words, 1) LOOP - s := make_standard_name(words[j]); - IF s != '' THEN - w := getorcreate_word_id(s); - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END LOOP; - END IF; - - s := regexp_replace(item.value, '市$', ''); - IF s != item.value THEN - s := make_standard_name(s); - IF s != '' THEN - w := getorcreate_name_id(s, item.value); - IF NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END IF; - - END LOOP; - - RETURN result; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[] - AS $$ -DECLARE - result INTEGER[]; - s TEXT; - w INTEGER; - words TEXT[]; - i INTEGER; - j INTEGER; -BEGIN - result := '{}'::INTEGER[]; - - s := make_standard_name(src); - w := getorcreate_name_id(s, src); - - IF NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - - w := getorcreate_word_id(s); - - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - - words := string_to_array(s, ' '); - IF array_upper(words, 1) IS NOT NULL THEN - FOR j IN 1..array_upper(words, 1) LOOP - IF (words[j] != '') THEN - w = getorcreate_word_id(words[j]); - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END LOOP; - END IF; - - words := regexp_split_to_array(src, E'[,;()]'); - IF array_upper(words, 1) != 1 THEN - FOR j IN 1..array_upper(words, 1) LOOP - s := make_standard_name(words[j]); - IF s != '' THEN - w := getorcreate_word_id(s); - IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END LOOP; - END IF; - - s := regexp_replace(src, '市$', ''); - IF s != src THEN - s := make_standard_name(s); - IF s != '' THEN - w := getorcreate_name_id(s, src); - IF NOT (ARRAY[w] <@ result) THEN - result := result || w; - END IF; - END IF; - END IF; - - RETURN result; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT AS $$ DECLARE @@ -547,7 +173,7 @@ BEGIN -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre); -- Try for a OSM polygon - FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1 + FOR nearcountry IN select country_code from location_area_country where country_code is not null and st_covers(geometry, place_centre) limit 1 LOOP RETURN nearcountry.country_code; END LOOP; @@ -561,14 +187,6 @@ BEGIN RETURN nearcountry.country_code; END LOOP; --- RAISE WARNING 'natural earth: %', ST_AsText(place_centre); - - -- Natural earth data - FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1 - LOOP - RETURN nearcountry.country_code; - END LOOP; - -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre); -- @@ -577,14 +195,6 @@ BEGIN RETURN nearcountry.country_code; END LOOP; --- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre); - - -- Natural earth data - FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1 - LOOP - RETURN nearcountry.country_code; - END LOOP; - RETURN NULL; END; $$ @@ -784,6 +394,28 @@ END; $$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION osmline_reinsert(node_id BIGINT, geom GEOMETRY) + RETURNS BOOLEAN + AS $$ +DECLARE + existingline RECORD; +BEGIN + SELECT w.id FROM planet_osm_ways w, location_property_osmline p + WHERE p.linegeo && geom and p.osm_id = w.id and p.indexed_status = 0 + and node_id = any(w.nodes) INTO existingline; + + IF existingline.id is not NULL THEN + DELETE FROM location_property_osmline WHERE osm_id = existingline.id; + INSERT INTO location_property_osmline (osm_id, address, linegeo) + SELECT osm_id, address, geometry FROM place + WHERE osm_type = 'W' and osm_id = existingline.id; + END IF; + + RETURN true; +END; +$$ +LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER AS $$ @@ -817,11 +449,12 @@ DECLARE i INTEGER; postcode TEXT; result BOOLEAN; + is_area BOOLEAN; country_code VARCHAR(2); default_language VARCHAR(10); diameter FLOAT; classtable TEXT; - line RECORD; + classtype TEXT; BEGIN --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; @@ -848,144 +481,70 @@ BEGIN IF NEW.osm_type = 'X' THEN -- E'X'ternal records should already be in the right format so do nothing ELSE - NEW.rank_search := 30; - NEW.rank_address := NEW.rank_search; + is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon'); - -- By doing in postgres we have the country available to us - currently only used for postcode - IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN + IF NEW.class in ('place','boundary') + AND NEW.type in ('postcode','postal_code') THEN - IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN - -- most likely just a part of a multipolygon postcode boundary, throw it away - RETURN NULL; - END IF; + IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN + -- most likely just a part of a multipolygon postcode boundary, throw it away + RETURN NULL; + END IF; - NEW.name := hstore('ref', NEW.address->'postcode'); + NEW.name := hstore('ref', NEW.address->'postcode'); - SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode') - INTO NEW.rank_search, NEW.rank_address; + SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode') + INTO NEW.rank_search, NEW.rank_address; - IF NOT ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon') THEN - NEW.rank_address := 0; - END IF; - - ELSEIF NEW.class = 'place' THEN - IF NEW.type in ('continent') THEN - NEW.rank_search := 2; - NEW.rank_address := NEW.rank_search; - NEW.country_code := NULL; - ELSEIF NEW.type in ('sea') THEN - NEW.rank_search := 2; - NEW.rank_address := 0; - NEW.country_code := NULL; - ELSEIF NEW.type in ('country') THEN - NEW.rank_search := 4; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('state') THEN - NEW.rank_search := 8; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('region') THEN - NEW.rank_search := 18; -- dropped from previous value of 10 - NEW.rank_address := 0; -- So badly miss-used that better to just drop it! - ELSEIF NEW.type in ('county') THEN - NEW.rank_search := 12; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('city') THEN - NEW.rank_search := 16; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('island') THEN - NEW.rank_search := 17; - NEW.rank_address := 0; - ELSEIF NEW.type in ('town') THEN - NEW.rank_search := 18; - NEW.rank_address := 16; - ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN - NEW.rank_search := 19; - NEW.rank_address := 16; - ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN - NEW.rank_search := 20; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN - NEW.rank_search := 20; - NEW.rank_address := 0; - -- Irish townlands, tagged as place=locality and locality=townland - IF (NEW.extratags -> 'locality') = 'townland' THEN - NEW.rank_address := 20; - END IF; - ELSEIF NEW.type in ('neighbourhood') THEN - NEW.rank_search := 22; - NEW.rank_address := 22; - ELSEIF NEW.type in ('house','building') THEN - NEW.rank_search := 30; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('houses') THEN - -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql - NEW.rank_search := 28; - NEW.rank_address := 0; + IF NOT is_area THEN + NEW.rank_address := 0; END IF; - - ELSEIF NEW.class = 'boundary' THEN - IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN --- RAISE WARNING 'invalid boundary %',NEW.osm_id; + ELSEIF NEW.class = 'boundary' AND NOT is_area THEN return NULL; - END IF; - NEW.rank_search := NEW.admin_level * 2; - IF NEW.type = 'administrative' THEN - NEW.rank_address := NEW.rank_search; + ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative' + AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN + return NULL; + ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN + return NULL; + ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN + NEW.rank_search = 30; + NEW.rank_address = 0; + ELSEIF NEW.class = 'landuse' AND NOT is_area THEN + NEW.rank_search = 30; + NEW.rank_address = 0; + ELSE + -- do table lookup stuff + IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN + classtype = NEW.type || NEW.admin_level::TEXT; ELSE - NEW.rank_address := 0; + classtype = NEW.type; END IF; - ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN - NEW.rank_search := 22; - IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN - NEW.rank_address := NEW.rank_search; - ELSE - NEW.rank_address := 0; + SELECT l.rank_search, l.rank_address FROM address_levels l + WHERE (l.country_code = NEW.country_code or l.country_code is NULL) + AND l.class = NEW.class AND (l.type = classtype or l.type is NULL) + ORDER BY l.country_code, l.class, l.type LIMIT 1 + INTO NEW.rank_search, NEW.rank_address; + + IF NEW.rank_search is NULL THEN + NEW.rank_search := 30; END IF; - ELSEIF NEW.class = 'leisure' and NEW.type in ('park') THEN - NEW.rank_search := 24; - NEW.rank_address := 0; - ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN - NEW.rank_search := 18; - NEW.rank_address := 0; - ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN - NEW.rank_search := 4; - NEW.rank_address := NEW.rank_search; - -- any feature more than 5 square miles is probably worth indexing - ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN - NEW.rank_search := 22; - NEW.rank_address := 0; - ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN - RETURN NULL; - ELSEIF NEW.class = 'waterway' THEN - IF NEW.osm_type = 'R' THEN - NEW.rank_search := 16; - ELSE - NEW.rank_search := 17; + + IF NEW.rank_address is NULL THEN + NEW.rank_address := 30; END IF; - NEW.rank_address := 0; - ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN - NEW.rank_search := 27; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN - NEW.rank_search := 26; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.class = 'mountain_pass' THEN - NEW.rank_search := 20; - NEW.rank_address := 0; END IF; - END IF; - - IF NEW.rank_search > 30 THEN - NEW.rank_search := 30; - END IF; + -- some postcorrections + IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN + -- Slightly promote waterway relations so that they are processed + -- before their members. + NEW.rank_search := NEW.rank_search - 1; + END IF; - IF NEW.rank_address > 30 THEN - NEW.rank_address := 30; - END IF; + IF (NEW.extratags -> 'capital') = 'yes' THEN + NEW.rank_search := NEW.rank_search - 1; + END IF; - IF (NEW.extratags -> 'capital') = 'yes' THEN - NEW.rank_search := NEW.rank_search - 1; END IF; -- a country code make no sense below rank 4 (country) @@ -993,16 +552,14 @@ BEGIN NEW.country_code := NULL; END IF; --- Block import below rank 22 --- IF NEW.rank_search > 22 THEN --- RETURN NULL; --- END IF; - --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down - IF NEW.rank_address > 0 THEN + IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN + -- might be part of an interpolation + result := osmline_reinsert(NEW.osm_id, NEW.geometry); + ELSEIF NEW.rank_address > 0 THEN IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN -- Performance: We just can't handle re-indexing for country level changes IF st_area(NEW.geometry) < 1 THEN @@ -1247,6 +804,7 @@ TRIGGER DECLARE place_centroid GEOMETRY; + near_centroid GEOMETRY; search_maxdistance FLOAT[]; search_mindistance FLOAT[]; @@ -1306,6 +864,9 @@ BEGIN NEW.indexed_date = now(); + IF NOT %REVERSE-ONLY% THEN + DELETE from search_name WHERE place_id = NEW.place_id; + END IF; result := deleteSearchName(NEW.partition, NEW.place_id); DELETE FROM place_addressline WHERE place_id = NEW.place_id; result := deleteRoad(NEW.partition, NEW.place_id); @@ -1320,6 +881,8 @@ BEGIN END IF; --DEBUG: RAISE WARNING 'Copy over address tags'; + -- housenumber is a computed field, so start with an empty value + NEW.housenumber := NULL; IF NEW.address is not NULL THEN IF NEW.address ? 'conscriptionnumber' THEN i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber')); @@ -1348,6 +911,8 @@ BEGIN -- Speed up searches - just use the centroid of the feature -- cheaper but less acurate place_centroid := ST_PointOnSurface(NEW.geometry); + -- For searching near features rather use the centroid + near_centroid := ST_Envelope(NEW.geometry); NEW.centroid := null; NEW.postcode := null; --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid); @@ -1393,10 +958,6 @@ BEGIN --DEBUG: RAISE WARNING 'Waterway processed'; END IF; - -- Adding ourselves to the list simplifies address calculations later - INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address) - VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address); - -- What level are we searching from search_maxrank := NEW.rank_search; @@ -1423,10 +984,9 @@ BEGIN END LOOP; NEW.importance := null; - select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance; - IF NEW.importance IS NULL THEN - select language||':'||title,importance from wikipedia_article where osm_type = NEW.osm_type and osm_id = NEW.osm_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance; - END IF; + SELECT wikipedia, importance + FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id) + INTO NEW.wikipedia,NEW.importance; --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance; @@ -1482,7 +1042,7 @@ BEGIN IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN address_street_word_ids := get_name_ids(make_standard_name(addr_street)); IF address_street_word_ids IS NOT NULL THEN - SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id; + SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id; END IF; END IF; --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id; @@ -1490,7 +1050,7 @@ BEGIN IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN address_street_word_ids := get_name_ids(make_standard_name(addr_place)); IF address_street_word_ids IS NOT NULL THEN - SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id; + SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id; END IF; END IF; --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id; @@ -1525,7 +1085,7 @@ BEGIN IF location.address ? 'street' THEN address_street_word_ids := get_name_ids(make_standard_name(location.address->'street')); IF address_street_word_ids IS NOT NULL THEN - SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id; + SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id; EXIT WHEN NEW.parent_place_id is not NULL; END IF; END IF; @@ -1534,7 +1094,7 @@ BEGIN IF location.address ? 'place' THEN address_street_word_ids := get_name_ids(make_standard_name(location.address->'place')); IF address_street_word_ids IS NOT NULL THEN - SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id; + SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id; EXIT WHEN NEW.parent_place_id is not NULL; END IF; END IF; @@ -1563,7 +1123,7 @@ BEGIN -- Still nothing, just use the nearest road IF NEW.parent_place_id IS NULL THEN - SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) INTO NEW.parent_place_id; + SELECT place_id FROM getNearestRoadFeature(NEW.partition, near_centroid) INTO NEW.parent_place_id; END IF; --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id; @@ -1572,8 +1132,9 @@ BEGIN IF NEW.parent_place_id IS NOT NULL THEN -- Get the details of the parent road - select s.country_code, s.name_vector, s.nameaddress_vector from search_name s - where s.place_id = NEW.parent_place_id INTO location; + SELECT p.country_code, p.postcode FROM placex p + WHERE p.place_id = NEW.parent_place_id INTO location; + NEW.country_code := location.country_code; --DEBUG: RAISE WARNING 'Got parent details from search name'; @@ -1582,10 +1143,10 @@ BEGIN IF NEW.address is not null AND NEW.address ? 'postcode' THEN NEW.postcode = upper(trim(NEW.address->'postcode')); ELSE - SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode; + NEW.postcode := location.postcode; END IF; IF NEW.postcode is null THEN - NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid); + NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry); END IF; END IF; @@ -1595,21 +1156,34 @@ BEGIN return NEW; END IF; - -- Merge address from parent - nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector); - nameaddress_vector := array_merge(nameaddress_vector, location.name_vector); - -- Performance, it would be more acurate to do all the rest of the import -- process but it takes too long -- Just be happy with inheriting from parent road only - IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry); --DEBUG: RAISE WARNING 'Place added to location table'; END IF; - result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry); - --DEBUG: RAISE WARNING 'Place added to search table'; + result := insertSearchName(NEW.partition, NEW.place_id, name_vector, + NEW.rank_search, NEW.rank_address, NEW.geometry); + + IF NOT %REVERSE-ONLY% THEN + -- Merge address from parent + SELECT s.name_vector, s.nameaddress_vector FROM search_name s + WHERE s.place_id = NEW.parent_place_id INTO location; + + nameaddress_vector := array_merge(nameaddress_vector, + location.nameaddress_vector); + nameaddress_vector := array_merge(nameaddress_vector, location.name_vector); + + INSERT INTO search_name (place_id, search_rank, address_rank, + importance, country_code, name_vector, + nameaddress_vector, centroid) + VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address, + NEW.importance, NEW.country_code, name_vector, + nameaddress_vector, place_centroid); + --DEBUG: RAISE WARNING 'Place added to search table'; + END IF; return NEW; END IF; @@ -1651,9 +1225,10 @@ BEGIN -- mark the linked place (excludes from search results) UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; - -- keep a note of the node id in case we need it for wikipedia in a bit - linked_node_id := linkedPlacex.osm_id; - select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance; + select wikipedia, importance + FROM compute_importance(linkedPlacex.extratags, NEW.country_code, + 'N', linkedPlacex.osm_id) + INTO linked_wikipedia,linked_importance; --DEBUG: RAISE WARNING 'Linked label member'; END LOOP; @@ -1690,9 +1265,10 @@ BEGIN -- mark the linked place (excludes from search results) UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; - -- keep a note of the node id in case we need it for wikipedia in a bit - linked_node_id := linkedPlacex.osm_id; - select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance; + select wikipedia, importance + FROM compute_importance(linkedPlacex.extratags, NEW.country_code, + 'N', linkedPlacex.osm_id) + INTO linked_wikipedia,linked_importance; --DEBUG: RAISE WARNING 'Linked admin_center'; END IF; @@ -1735,9 +1311,10 @@ BEGIN -- mark the linked place (excludes from search results) UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; - -- keep a note of the node id in case we need it for wikipedia in a bit - linked_node_id := linkedPlacex.osm_id; - select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance; + select wikipedia, importance + FROM compute_importance(linkedPlacex.extratags, NEW.country_code, + 'N', linkedPlacex.osm_id) + INTO linked_wikipedia,linked_importance; --DEBUG: RAISE WARNING 'Linked named place'; END LOOP; END IF; @@ -1765,13 +1342,6 @@ BEGIN (NEW.importance is null or NEW.importance < linked_importance) THEN NEW.importance = linked_importance; END IF; - - -- Still null? how about looking it up by the node id - IF NEW.importance IS NULL THEN - --DEBUG: RAISE WARNING 'Looking up importance by linked node id'; - select language||':'||title,importance from wikipedia_article where osm_type = 'N'::char(1) and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance; - END IF; - END IF; -- make sure all names are in the word table @@ -1795,9 +1365,11 @@ BEGIN IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN isin_tokens := isin_tokens || address_street_word_id; END IF; - address_street_word_id := get_word_id(make_standard_name(addr_item.value)); - IF address_street_word_id IS NOT NULL THEN - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + IF NOT %REVERSE-ONLY% THEN + address_street_word_id := get_word_id(make_standard_name(addr_item.value)); + IF address_street_word_id IS NOT NULL THEN + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + END IF; END IF; END IF; IF addr_item.key = 'is_in' THEN @@ -1811,16 +1383,20 @@ BEGIN END IF; -- merge word into address vector - address_street_word_id := get_word_id(make_standard_name(isin[i])); - IF address_street_word_id IS NOT NULL THEN - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + IF NOT %REVERSE-ONLY% THEN + address_street_word_id := get_word_id(make_standard_name(isin[i])); + IF address_street_word_id IS NOT NULL THEN + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + END IF; END IF; END LOOP; END IF; END IF; END LOOP; END IF; - nameaddress_vector := array_merge(nameaddress_vector, isin_tokens); + IF NOT %REVERSE-ONLY% THEN + nameaddress_vector := array_merge(nameaddress_vector, isin_tokens); + END IF; -- RAISE WARNING 'ISIN: %', isin_tokens; @@ -1869,7 +1445,7 @@ BEGIN -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress; -- Add it to the list of search terms - IF location.rank_search > 4 THEN + IF NOT %REVERSE-ONLY% THEN nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); END IF; INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address) @@ -1923,8 +1499,18 @@ BEGIN --DEBUG: RAISE WARNING 'insert into road location table (full)'; END IF; - result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry); - --DEBUG: RAISE WARNING 'added to serach name (full)'; + result := insertSearchName(NEW.partition, NEW.place_id, name_vector, + NEW.rank_search, NEW.rank_address, NEW.geometry); + --DEBUG: RAISE WARNING 'added to search name (full)'; + + IF NOT %REVERSE-ONLY% THEN + INSERT INTO search_name (place_id, search_rank, address_rank, + importance, country_code, name_vector, + nameaddress_vector, centroid) + VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address, + NEW.importance, NEW.country_code, name_vector, + nameaddress_vector, place_centroid); + END IF; END IF; @@ -1983,6 +1569,9 @@ BEGIN --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id; IF OLD.name is not null THEN + IF NOT %REVERSE-ONLY% THEN + DELETE from search_name WHERE place_id = OLD.place_id; + END IF; b := deleteSearchName(OLD.partition, OLD.place_id); END IF; @@ -2257,12 +1846,13 @@ BEGIN indexed_status = 2, geometry = NEW.geometry where place_id = existingplacex.place_id; - -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late) - IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN - -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting - update location_property_osmline p set indexed_status = 2 from planet_osm_ways w where p.linegeo && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes); + IF NEW.osm_type='N' + and (coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore) + or existing.geometry::text != NEW.geometry::text) + THEN + result:= osmline_reinsert(NEW.osm_id, NEW.geometry); END IF; -- linked places should get potential new naming and addresses @@ -2354,6 +1944,9 @@ create type addressline as ( distance FLOAT ); +-- Compute the list of address parts for the given place. +-- +-- If in_housenumber is greator or equal 0, look for an interpolation. CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline AS $$ DECLARE @@ -2368,53 +1961,72 @@ DECLARE searchhousename HSTORE; searchrankaddress INTEGER; searchpostcode TEXT; + postcode_isaddress BOOL; searchclass TEXT; searchtype TEXT; countryname HSTORE; - hadcountry BOOLEAN; BEGIN + -- The place ein 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. + + postcode_isaddress := true; + -- first query osmline (interpolation lines) - select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline - WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber - INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; - IF for_place_id IS NOT NULL THEN - searchhousenumber = in_housenumber::text; + IF in_housenumber >= 0 THEN + SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode, + null, 'place', 'house' + FROM location_property_osmline + WHERE place_id = in_place_id AND in_housenumber>=startnumber + AND in_housenumber <= endnumber + INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, + searchpostcode, searchhousename, searchclass, searchtype; END IF; --then query tiger data -- %NOTIGERDATA% IF 0 THEN - IF for_place_id IS NULL THEN - select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger - WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber - INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; - IF for_place_id IS NOT NULL THEN - searchhousenumber = in_housenumber::text; - END IF; + IF for_place_id IS NULL AND in_housenumber >= 0 THEN + SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null, + 'place', 'house' + FROM location_property_tiger + WHERE place_id = in_place_id AND in_housenumber >= startnumber + AND in_housenumber <= endnumber + INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, + searchpostcode, searchhousename, searchclass, searchtype; END IF; -- %NOTIGERDATA% END IF; -- %NOAUXDATA% IF 0 THEN IF for_place_id IS NULL THEN - select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux + SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house' + FROM location_property_aux WHERE place_id = in_place_id - INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, + searchpostcode, searchhousename, searchclass, searchtype; END IF; -- %NOAUXDATA% END IF; -- postcode table IF for_place_id IS NULL THEN - select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode' + SELECT parent_place_id, country_code, rank_search, postcode, 'place', 'postcode' FROM location_postcode WHERE place_id = in_place_id - INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype; + INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, + searchclass, searchtype; END IF; + -- POI objects in the placex table IF for_place_id IS NULL THEN - select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex - WHERE place_id = in_place_id and rank_search > 27 - INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + SELECT parent_place_id, country_code, housenumber, rank_search, postcode, + name, class, type + FROM placex + WHERE place_id = in_place_id and rank_search > 27 + INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, + searchpostcode, searchhousename, searchclass, searchtype; END IF; + -- If for_place_id 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 + -- place we should be using instead. IF for_place_id IS NULL THEN select coalesce(linked_place_id, place_id), country_code, housenumber, rank_search, postcode, null @@ -2424,103 +2036,105 @@ BEGIN --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode; - found := 1000; - hadcountry := false; - FOR location IN - select placex.place_id, osm_type, osm_id, name, - class, type, admin_level, true as isaddress, - CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, - 0 as distance, country_code, postcode - from placex - where place_id = for_place_id + found := 1000; -- the lowest rank_address included + + -- Return the record for the base entry. + FOR location IN + SELECT placex.place_id, osm_type, osm_id, name, + class, type, admin_level, + type not in ('postcode', 'postal_code') as isaddress, + CASE WHEN rank_address = 0 THEN 100 + WHEN rank_address = 11 THEN 5 + ELSE rank_address END as rank_address, + 0 as distance, country_code, postcode + FROM placex + WHERE place_id = for_place_id LOOP --RAISE WARNING '%',location; IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN searchcountrycode := location.country_code; END IF; - IF location.type in ('postcode', 'postal_code') THEN - location.isaddress := FALSE; - ELSEIF location.rank_address = 4 THEN - hadcountry := true; - END IF; - IF location.rank_address < 4 AND NOT hadcountry THEN - select name from country_name where country_code = searchcountrycode limit 1 INTO countryname; - IF countryname IS NOT NULL THEN - countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline; - RETURN NEXT countrylocation; - END IF; + IF location.rank_address < 4 THEN + -- no country locations for ranks higher than country + searchcountrycode := NULL; END IF; - countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class, - location.type, location.admin_level, true, location.isaddress, location.rank_address, - location.distance)::addressline; + countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, + location.name, location.class, location.type, + location.admin_level, true, location.isaddress, + location.rank_address, location.distance)::addressline; RETURN NEXT countrylocation; found := location.rank_address; END LOOP; - FOR location IN - select placex.place_id, osm_type, osm_id, name, - CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class, - CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type, - admin_level, fromarea, isaddress, - CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, - distance,country_code,postcode - from place_addressline join placex on (address_place_id = placex.place_id) - where place_addressline.place_id = for_place_id - and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress) - and address_place_id != for_place_id and linked_place_id is null - and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode) - order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc + FOR location IN + SELECT placex.place_id, osm_type, osm_id, name, + CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class, + CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type, + admin_level, fromarea, isaddress, + CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, + distance, country_code, postcode + FROM place_addressline join placex on (address_place_id = placex.place_id) + WHERE place_addressline.place_id = for_place_id + AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress) + AND linked_place_id is null + AND (placex.country_code IS NULL OR searchcountrycode IS NULL + OR placex.country_code = searchcountrycode) + ORDER BY rank_address desc, isaddress desc, fromarea desc, + distance asc, rank_search desc LOOP --RAISE WARNING '%',location; IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN searchcountrycode := location.country_code; END IF; IF location.type in ('postcode', 'postal_code') THEN - location.isaddress := FALSE; - END IF; - IF location.rank_address = 4 AND location.isaddress THEN - hadcountry := true; - END IF; - IF location.rank_address < 4 AND NOT hadcountry THEN - select name from country_name where country_code = searchcountrycode limit 1 INTO countryname; - IF countryname IS NOT NULL THEN - countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline; - RETURN NEXT countrylocation; + postcode_isaddress := false; + IF location.osm_type != 'R' THEN + location.isaddress := FALSE; END IF; END IF; - countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class, - location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address, + countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, + location.name, location.class, location.type, + location.admin_level, location.fromarea, + location.isaddress, location.rank_address, location.distance)::addressline; RETURN NEXT countrylocation; found := location.rank_address; END LOOP; + -- If no country was included yet, add the name information from country_name. IF found > 4 THEN - select name from country_name where country_code = searchcountrycode limit 1 INTO countryname; + SELECT name FROM country_name + WHERE country_code = searchcountrycode LIMIT 1 INTO countryname; --RAISE WARNING '% % %',found,searchcountrycode,countryname; IF countryname IS NOT NULL THEN - location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline; + location := ROW(null, null, null, countryname, 'place', 'country', + null, true, true, 4, 0)::addressline; RETURN NEXT location; END IF; END IF; + -- Finally add some artificial rows. IF searchcountrycode IS NOT NULL THEN - location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline; + location := ROW(null, null, null, hstore('ref', searchcountrycode), + 'place', 'country_code', null, true, false, 4, 0)::addressline; RETURN NEXT location; END IF; IF searchhousename IS NOT NULL THEN - location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline; + location := ROW(in_place_id, null, null, searchhousename, searchclass, + searchtype, null, true, true, 29, 0)::addressline; RETURN NEXT location; END IF; IF searchhousenumber IS NOT NULL THEN - location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline; + location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), + 'place', 'house_number', null, true, true, 28, 0)::addressline; RETURN NEXT location; END IF; IF searchpostcode IS NOT NULL THEN - location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline; + location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', + 'postcode', null, false, postcode_isaddress, 5, 0)::addressline; RETURN NEXT location; END IF; @@ -2530,96 +2144,6 @@ $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT - AS $$ -DECLARE -BEGIN - IF rank < 2 THEN - RETURN 'Continent'; - ELSEIF rank < 4 THEN - RETURN 'Sea'; - ELSEIF rank < 8 THEN - RETURN 'Country'; - ELSEIF rank < 12 THEN - RETURN 'State'; - ELSEIF rank < 16 THEN - RETURN 'County'; - ELSEIF rank = 16 THEN - RETURN 'City'; - ELSEIF rank = 17 THEN - RETURN 'Town / Island'; - ELSEIF rank = 18 THEN - RETURN 'Village / Hamlet'; - ELSEIF rank = 20 THEN - RETURN 'Suburb'; - ELSEIF rank = 21 THEN - RETURN 'Postcode Area'; - ELSEIF rank = 22 THEN - RETURN 'Croft / Farm / Locality / Islet'; - ELSEIF rank = 23 THEN - RETURN 'Postcode Area'; - ELSEIF rank = 25 THEN - RETURN 'Postcode Point'; - ELSEIF rank = 26 THEN - RETURN 'Street / Major Landmark'; - ELSEIF rank = 27 THEN - RETURN 'Minory Street / Path'; - ELSEIF rank = 28 THEN - RETURN 'House / Building'; - ELSE - RETURN 'Other: '||rank; - END IF; - -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT - AS $$ -DECLARE -BEGIN - IF rank = 0 THEN - RETURN 'None'; - ELSEIF rank < 2 THEN - RETURN 'Continent'; - ELSEIF rank < 4 THEN - RETURN 'Sea'; - ELSEIF rank = 5 THEN - RETURN 'Postcode'; - ELSEIF rank < 8 THEN - RETURN 'Country'; - ELSEIF rank < 12 THEN - RETURN 'State'; - ELSEIF rank < 16 THEN - RETURN 'County'; - ELSEIF rank = 16 THEN - RETURN 'City'; - ELSEIF rank = 17 THEN - RETURN 'Town / Village / Hamlet'; - ELSEIF rank = 20 THEN - RETURN 'Suburb'; - ELSEIF rank = 21 THEN - RETURN 'Postcode Area'; - ELSEIF rank = 22 THEN - RETURN 'Croft / Farm / Locality / Islet'; - ELSEIF rank = 23 THEN - RETURN 'Postcode Area'; - ELSEIF rank = 25 THEN - RETURN 'Postcode Point'; - ELSEIF rank = 26 THEN - RETURN 'Street / Major Landmark'; - ELSEIF rank = 27 THEN - RETURN 'Minory Street / Path'; - ELSEIF rank = 28 THEN - RETURN 'House / Building'; - ELSE - RETURN 'Other: '||rank; - END IF; - -END; -$$ -LANGUAGE plpgsql; - CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT, in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER AS $$ @@ -2724,7 +2248,7 @@ END; $$ LANGUAGE plpgsql IMMUTABLE; -DROP TYPE wikipedia_article_match CASCADE; +DROP TYPE IF EXISTS wikipedia_article_match CASCADE; create type wikipedia_article_match as ( language TEXT, title TEXT, @@ -2781,6 +2305,42 @@ END; $$ LANGUAGE plpgsql; +DROP TYPE IF EXISTS place_importance CASCADE; +create type place_importance as ( + importance FLOAT, + wikipedia TEXT +); + +CREATE OR REPLACE FUNCTION compute_importance(extratags HSTORE, country_code varchar(2), osm_type varchar(1), osm_id BIGINT) + RETURNS place_importance + AS $$ +DECLARE + match RECORD; + result place_importance; +BEGIN + FOR match IN SELECT * FROM get_wikipedia_match(extratags, country_code) + WHERE language is not NULL + LOOP + result.importance := match.importance; + result.wikipedia := match.language || ':' || match.title; + RETURN result; + END LOOP; + + IF extratags ? 'wikidata' THEN + FOR match IN SELECT * FROM wikipedia_article + WHERE wd_page_title = extratags->'wikidata' + ORDER BY language = 'en' DESC, langcount DESC LIMIT 1 LOOP + result.importance := match.importance; + result.wikipedia := match.language || ':' || match.title; + RETURN result; + END LOOP; + END IF; + + RETURN null; +END; +$$ +LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER) RETURNS SETOF GEOMETRY AS $$