X-Git-Url: https://git.openstreetmap.org./nominatim.git/blobdiff_plain/bfe56e6a4575b9697dcfb496649889a57c681931..1e307392b2620267e1117efb413e69c4452c9cb5:/sql/functions.sql diff --git a/sql/functions.sql b/sql/functions.sql index 84dd62d5..c025f221 100644 --- a/sql/functions.sql +++ b/sql/functions.sql @@ -52,35 +52,14 @@ DECLARE NEWgeometry geometry; BEGIN -- RAISE WARNING '%',place; - NEWgeometry := place; - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - NEWgeometry := ST_buffer(NEWgeometry,0); - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - RETURN 0; - END IF; - END IF; - RETURN (partition*1000000) + (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer); -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER - AS $$ -DECLARE - NEWgeometry geometry; -BEGIN --- RAISE WARNING '%',osmid; - IF osmid = 61315 THEN - return null; - END IF; - NEWgeometry := place; - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - NEWgeometry := ST_buffer(NEWgeometry,0); - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - RETURN NULL; - END IF; - END IF; - RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer); + NEWgeometry := ST_PointOnSurface(place); +-- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN +-- NEWgeometry := ST_buffer(NEWgeometry,0); +-- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN +-- RETURN 0; +-- END IF; +-- END IF; + RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer); END; $$ LANGUAGE plpgsql IMMUTABLE; @@ -219,7 +198,7 @@ BEGIN SELECT min(word_id) FROM word WHERE word_token = lookup_token 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, null, null, lookup_class, lookup_type, null, 0, null, op); + INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null); END IF; RETURN return_word_id; END; @@ -302,7 +281,7 @@ BEGIN END IF; r := a; FOR i IN 1..array_upper(b, 1) LOOP - IF NOT (ARRAY[b[i]] && r) THEN + IF NOT (ARRAY[b[i]] <@ r) THEN r := r || b[i]; END IF; END LOOP; @@ -328,15 +307,18 @@ BEGIN s := make_standard_name(item.value); w := getorcreate_name_id(s, item.value); - result := result | w; + + IF 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 NOT (ARRAY[w] && result) THEN - result := result | w; + IF NOT (ARRAY[w] <@ result) THEN + result := result || w; END IF; END IF; END LOOP; @@ -348,8 +330,8 @@ BEGIN s := make_standard_name(words[j]); IF s != '' THEN w := getorcreate_word_id(s); - IF NOT (ARRAY[w] && result) THEN - result := result | w; + IF NOT (ARRAY[w] <@ result) THEN + result := result || w; END IF; END IF; END LOOP; @@ -360,8 +342,8 @@ BEGIN s := make_standard_name(s); IF s != '' THEN w := getorcreate_name_id(s, item.value); - IF NOT (ARRAY[w] && result) THEN - result := result | w; + IF NOT (ARRAY[w] <@ result) THEN + result := result || w; END IF; END IF; END IF; @@ -386,9 +368,9 @@ BEGIN result := '{}'::INTEGER[]; s := make_standard_name(src); - w := getorcreate_name_id(s); + w := getorcreate_name_id(s, src); - IF NOT (ARRAY[w] && result) THEN + IF NOT (ARRAY[w] <@ result) THEN result := result || w; END IF; @@ -397,13 +379,37 @@ BEGIN FOR j IN 1..array_upper(words, 1) LOOP IF (words[j] != '') THEN w = getorcreate_word_id(words[j]); - IF NOT (ARRAY[w] && result) THEN + IF 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 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; $$ @@ -440,54 +446,63 @@ DECLARE place_centre GEOMETRY; nearcountry RECORD; BEGIN - place_centre := ST_Centroid(place); + place_centre := ST_PointOnSurface(place); + +--DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre); ---RAISE WARNING 'start: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre); - -- Try for a OSM polygon first - FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_contains(geometry, place_centre) limit 1 + -- Try for OSM fallback data + -- The order is to deal with places like HongKong that are 'states' within another polygon + FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'osm fallback: %', ST_AsText(place_centre); - - -- Try for OSM fallback data - FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1 + -- 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 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'natural earth: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre); - -- Natural earth data (first fallback) - FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1 + -- 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; - -- Natural earth data (first fallback) - FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1 +--DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre); + + -- + FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'in country: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre); - -- WorldBoundaries data (second fallback - think there might be something broken in this data) - FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1 + -- 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; + -- WorldBoundaries data (second fallback - think there might be something broken in this data) +-- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1 +-- LOOP +-- RETURN nearcountry.country_code; +-- END LOOP; + --RAISE WARNING 'near country: %', ST_AsText(place_centre); -- Still not in a country - try nearest within ~12 miles of a country - FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5 - order by st_distance(geometry, place) limit 1 - LOOP - RETURN nearcountry.country_code; - END LOOP; +-- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5 +-- order by st_distance(geometry, place) limit 1 +-- LOOP +-- RETURN nearcountry.country_code; +-- END LOOP; RETURN NULL; END; @@ -537,7 +552,7 @@ END; $$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION delete_location(OLD_place_id INTEGER) RETURNS BOOLEAN +CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN AS $$ DECLARE BEGIN @@ -549,7 +564,7 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION add_location( - place_id INTEGER, + place_id BIGINT, country_code varchar(2), partition INTEGER, keywords INTEGER[], @@ -562,23 +577,19 @@ CREATE OR REPLACE FUNCTION add_location( DECLARE locationid INTEGER; isarea BOOLEAN; - xmin INTEGER; - ymin INTEGER; - xmax INTEGER; - ymax INTEGER; - lon INTEGER; - lat INTEGER; centroid GEOMETRY; - secgeo GEOMETRY; - secbox GEOMETRY; diameter FLOAT; x BOOLEAN; + splitGeom RECORD; + secgeo GEOMETRY; BEGIN - IF rank_search > 26 THEN - RAISE EXCEPTION 'Adding location with rank > 26 (% rank %)', place_id, rank_search; + IF rank_search > 25 THEN + RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search; END IF; +-- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search; + x := deleteLocationArea(partition, place_id); isarea := false; @@ -587,44 +598,31 @@ BEGIN isArea := true; centroid := ST_Centroid(geometry); - xmin := floor(st_xmin(geometry)); - xmax := ceil(st_xmax(geometry)); - ymin := floor(st_ymin(geometry)); - ymax := ceil(st_ymax(geometry)); - - IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN - x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry); - ELSE - FOR lon IN xmin..(xmax-1) LOOP - FOR lat IN ymin..(ymax-1) LOOP - secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326); - IF st_intersects(geometry, secbox) THEN - secgeo := st_intersection(geometry, secbox); - IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN - x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo); - END IF; - END IF; - END LOOP; - END LOOP; - END IF; + FOR secgeo IN select split_geometry(geometry) AS geom LOOP + x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo); + END LOOP; ELSEIF rank_search < 26 THEN diameter := 0.02; - IF rank_search = 14 THEN + IF rank_address = 0 THEN + diameter := 0.02; + ELSEIF rank_search <= 14 THEN + diameter := 1.2; + ELSEIF rank_search <= 15 THEN diameter := 1; - ELSEIF rank_search = 15 THEN + ELSEIF rank_search <= 16 THEN diameter := 0.5; - ELSEIF rank_search = 16 THEN - diameter := 0.15; - ELSEIF rank_search = 17 THEN + ELSEIF rank_search <= 17 THEN + diameter := 0.2; + ELSEIF rank_search <= 21 THEN diameter := 0.05; - ELSEIF rank_search = 21 THEN - diameter := 0.01; ELSEIF rank_search = 25 THEN diameter := 0.005; END IF; +-- RAISE WARNING 'adding % diameter %', place_id, diameter; + secgeo := ST_Buffer(geometry, diameter); x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo); @@ -647,7 +645,7 @@ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION update_location( partition INTEGER, - place_id INTEGER, + place_id BIGINT, place_country_code varchar(2), name hstore, rank_search INTEGER, @@ -660,12 +658,13 @@ DECLARE b BOOLEAN; BEGIN b := deleteLocationArea(partition, place_id); +-- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[]) +CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[]) RETURNS BOOLEAN AS $$ DECLARE @@ -682,9 +681,11 @@ BEGIN and search_name.place_id = place_addressline.place_id LOOP delete from search_name where place_id = childplace.place_id; - childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add)); - IF childplace.place_id = parent_place_id THEN - childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add)); + IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN + childplace.nameaddress_vector := childplace.nameaddress_vector || to_add; + END IF; + IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN + childplace.name_vector := childplace.name_vector || to_add; END IF; insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid) values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code, @@ -696,7 +697,7 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN +CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN AS $$ DECLARE newkeywords INTEGER[]; @@ -729,7 +730,7 @@ $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER +CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER AS $$ DECLARE @@ -745,7 +746,8 @@ DECLARE originalnumberrange INTEGER; housenum INTEGER; linegeo GEOMETRY; - search_place_id INTEGER; + search_place_id BIGINT; + defpostalcode TEXT; havefirstpoint BOOLEAN; linestr TEXT; @@ -753,6 +755,7 @@ BEGIN newpoints := 0; IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN + select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode; select nodes from planet_osm_ways where id = wayid INTO waynodes; --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes; IF array_upper(waynodes, 1) IS NOT NULL THEN @@ -778,7 +781,7 @@ BEGIN linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry); endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer; - IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN + IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber; @@ -819,9 +822,9 @@ BEGIN FOR housenum IN startnumber..endnumber BY stepsize LOOP -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit -- ideally postcodes should move up to the way - insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, + insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode, country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry) - values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, + values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode), prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float)); newpoints := newpoints + 1; --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum; @@ -860,19 +863,23 @@ DECLARE country_code VARCHAR(2); default_language VARCHAR(10); diameter FLOAT; + classtable TEXT; BEGIN --- RAISE WARNING '%',NEW.osm_id; + --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id; -- just block these IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN +-- RAISE WARNING 'bad highway %',NEW.osm_id; RETURN null; END IF; IF NEW.class in ('landuse','natural') and NEW.name is null THEN +-- RAISE WARNING 'empty landuse %',NEW.osm_id; RETURN null; END IF; IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems. + RAISE WARNING 'invalid geometry %',NEW.osm_id; RETURN NULL; -- Dead code @@ -887,21 +894,24 @@ BEGIN END IF; END IF; + --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; + NEW.place_id := nextval('seq_place'); NEW.indexed_status := 1; --STATUS_NEW - NEW.country_code := get_country_code(NEW.geometry, NEW.country_code); - NEW.partition := get_partition(NEW.geometry, NEW.country_code); + NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code)); + + NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code); NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry); -- copy 'name' to or from the default language (if there is a default language) - IF NEW.name is not null THEN - default_language := get_country_language_code(NEW.country_code); + IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN + default_language := get_country_language_code(NEW.calculated_country_code); IF default_language IS NOT NULL THEN IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name')); ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN - NEW.name := NEW.name || ('name' => (NEW.name -> 'name:'||default_language)); + NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language))); END IF; END IF; END IF; @@ -921,13 +931,63 @@ BEGIN NEW.rank_address := NEW.rank_search; -- By doing in postgres we have the country available to us - currently only used for postcode - IF NEW.class = 'place' THEN + IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN + + IF NEW.postcode IS NULL THEN + -- most likely just a part of a multipolygon postcode boundary, throw it away + RETURN NULL; + END IF; + + NEW.name := 'ref'=>NEW.postcode; + + IF NEW.calculated_country_code = 'gb' THEN + + IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN + NEW.rank_search := 25; + NEW.rank_address := 5; + ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN + NEW.rank_search := 23; + NEW.rank_address := 5; + ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN + NEW.rank_search := 21; + NEW.rank_address := 5; + END IF; + + ELSEIF NEW.calculated_country_code = 'de' THEN + + IF NEW.postcode ~ '^([0-9]{5})$' THEN + NEW.rank_search := 21; + NEW.rank_address := 11; + END IF; + + ELSE + -- Guess at the postcode format and coverage (!) + IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local + NEW.rank_search := 21; + NEW.rank_address := 11; + ELSE + -- Does it look splitable into and area and local code? + postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$'); + + IF postcode IS NOT NULL THEN + NEW.rank_search := 25; + NEW.rank_address := 11; + ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN + NEW.rank_search := 21; + NEW.rank_address := 11; + END IF; + END IF; + END IF; + + ELSEIF NEW.class = 'place' THEN IF NEW.type in ('continent') THEN NEW.rank_search := 2; NEW.rank_address := NEW.rank_search; + NEW.calculated_country_code := NULL; ELSEIF NEW.type in ('sea') THEN NEW.rank_search := 2; NEW.rank_address := 0; + NEW.calculated_country_code := NULL; ELSEIF NEW.type in ('country') THEN NEW.rank_search := 4; NEW.rank_address := NEW.rank_search; @@ -935,8 +995,8 @@ BEGIN NEW.rank_search := 8; NEW.rank_address := NEW.rank_search; ELSEIF NEW.type in ('region') THEN - NEW.rank_search := 10; - NEW.rank_address := NEW.rank_search; + 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; @@ -947,11 +1007,11 @@ BEGIN NEW.rank_search := 17; NEW.rank_address := 0; ELSEIF NEW.type in ('town') THEN - NEW.rank_search := 17; - NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN NEW.rank_search := 18; - NEW.rank_address := 17; + 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 ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN NEW.rank_search := 18; NEW.rank_address := 17; @@ -967,55 +1027,16 @@ BEGIN ELSEIF NEW.type in ('suburb','croft','subdivision') THEN NEW.rank_search := 20; NEW.rank_address := NEW.rank_search; - ELSEIF NEW.type in ('farm','locality','islet') THEN + ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','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 ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN NEW.rank_search := 22; NEW.rank_address := 22; - ELSEIF NEW.type in ('postcode') THEN - - NEW.name := 'ref'=>NEW.postcode; - - IF NEW.country_code = 'gb' THEN - - IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN - NEW.rank_search := 25; - NEW.rank_address := 5; - ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN - NEW.rank_search := 23; - NEW.rank_address := 5; - ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN - NEW.rank_search := 21; - NEW.rank_address := 5; - END IF; - - ELSEIF NEW.country_code = 'de' THEN - - IF NEW.postcode ~ '^([0-9]{5})$' THEN - NEW.rank_search := 21; - NEW.rank_address := 11; - END IF; - - ELSE - -- Guess at the postcode format and coverage (!) - IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local - NEW.rank_search := 21; - NEW.rank_address := 11; - ELSE - -- Does it look splitable into and area and local code? - postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$'); - - IF postcode IS NOT NULL THEN - NEW.rank_search := 25; - NEW.rank_address := 11; - ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN - NEW.rank_search := 21; - NEW.rank_address := 11; - END IF; - END IF; - END IF; - ELSEIF NEW.type in ('airport','street') THEN NEW.rank_search := 26; NEW.rank_address := NEW.rank_search; @@ -1031,6 +1052,10 @@ BEGIN 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; + return NULL; + END IF; NEW.rank_search := NEW.admin_level * 2; NEW.rank_address := NEW.rank_search; ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN @@ -1042,6 +1067,7 @@ BEGIN NEW.rank_address := NEW.rank_search; ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN +-- RAISE WARNING 'unnamed minor feature %',NEW.osm_id; RETURN NULL; ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN RETURN NULL; @@ -1075,31 +1101,42 @@ BEGIN NEW.rank_address := 30; 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) + IF NEW.rank_address < 4 THEN + NEW.calculated_country_code := NULL; + END IF; + -- Block import below rank 22 -- IF NEW.rank_search > 22 THEN -- RETURN NULL; -- END IF; - RETURN NEW; - -- The following is not needed until doing diff updates, and slows the main index process down + --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 (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 -- mark items within the geometry for re-indexing -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; --- work around bug in postgis - update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) - AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point'; - update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) - AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point'; + + -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547) + update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null); + update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null); END IF; ELSE -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :( diameter := 0; -- 16 = city, anything higher than city is effectively ignored (polygon required!) IF NEW.type='postcode' THEN - diameter := 0.001; + diameter := 0.05; ELSEIF NEW.rank_search < 16 THEN diameter := 0; ELSEIF NEW.rank_search < 18 THEN @@ -1117,11 +1154,22 @@ BEGIN END IF; IF diameter > 0 THEN -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter; - update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter); + update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null); END IF; END IF; + -- add to tables for special search + -- Note: won't work on initial import because the classtype tables + -- do not yet exist. It won't hurt either. + classtable := 'place_classtype_' || NEW.class || '_' || NEW.type; + SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result; + IF result THEN + EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)' + USING NEW.place_id, ST_Centroid(NEW.geometry); + END IF; + + -- IF NEW.rank_search < 26 THEN -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; -- END IF; @@ -1148,13 +1196,18 @@ DECLARE i INTEGER; iMax FLOAT; location RECORD; + way RECORD; relation RECORD; + relation_members TEXT[]; + relMember RECORD; + linkedplacex RECORD; search_diameter FLOAT; search_prevdiameter FLOAT; search_maxrank INTEGER; address_maxrank INTEGER; address_street_word_id INTEGER; - parent_place_id_count INTEGER; + parent_place_id_rank BIGINT; + isin TEXT[]; isin_tokens INT[]; @@ -1163,12 +1216,21 @@ DECLARE tagpairid INTEGER; + default_language TEXT; name_vector INTEGER[]; nameaddress_vector INTEGER[]; + linked_node_id BIGINT; + result BOOLEAN; BEGIN + IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN + RETURN NEW; + END IF; + + --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id; + --RAISE WARNING '%',NEW.place_id; --RAISE WARNING '%', NEW; @@ -1177,7 +1239,15 @@ BEGIN RETURN NEW; END IF; - IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN + -- deferred delete + IF OLD.indexed_status = 100 THEN + --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id; + delete from placex where place_id = OLD.place_id; + RETURN NULL; + END IF; + + IF OLD.indexed_status != 0 THEN + --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id; NEW.indexed_date = now(); @@ -1186,9 +1256,29 @@ BEGIN RETURN NEW; END IF; - result := deleteSearchName(NEW.partition, NEW.place_id); - DELETE FROM place_addressline WHERE place_id = NEW.place_id; - DELETE FROM place_boundingbox where place_id = NEW.place_id; + IF OLD.indexed_status > 0 THEN + result := deleteSearchName(NEW.partition, NEW.place_id); + DELETE FROM place_addressline WHERE place_id = NEW.place_id; + DELETE FROM place_boundingbox where place_id = NEW.place_id; + result := deleteRoad(NEW.partition, NEW.place_id); + result := deleteLocationArea(NEW.partition, NEW.place_id); + UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id; + END IF; + + -- Speed up searches - just use the centroid of the feature + -- cheaper but less acurate + place_centroid := ST_PointOnSurface(NEW.geometry); + NEW.centroid := null; + + -- reclaculate country and partition + IF NEW.rank_search >= 4 THEN + --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code)); + NEW.calculated_country_code := lower(get_country_code(place_centroid)); + ELSE + NEW.calculated_country_code := NULL; + END IF; + NEW.partition := get_partition(place_centroid, NEW.calculated_country_code); + NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid); -- Adding ourselves to the list simplifies address calculations later INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address); @@ -1196,9 +1286,18 @@ BEGIN -- What level are we searching from search_maxrank := NEW.rank_search; - -- Speed up searches - just use the centroid of the feature - -- cheaper but less acurate - place_centroid := ST_Centroid(NEW.geometry); + -- Thought this wasn't needed but when we add new languages to the country_name table + -- we need to update the existing names + IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN + default_language := get_country_language_code(NEW.calculated_country_code); + IF default_language IS NOT NULL THEN + IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN + NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name')); + ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN + NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language))); + END IF; + END IF; + END IF; -- Initialise the name vector using our name name_vector := make_keywords(NEW.name); @@ -1214,7 +1313,13 @@ BEGIN address_havelevel[i] := false; END LOOP; ---RAISE WARNING '% %', NEW.place_id, NEW.rank_search; + NEW.importance := null; + select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_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; + +--RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search; -- For low level elements we inherit from our parent road IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN @@ -1229,7 +1334,7 @@ BEGIN IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN -- Is this node part of a relation? - FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id] + FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id] LOOP -- At the moment we only process one type of relation - associatedStreet IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN @@ -1245,8 +1350,9 @@ BEGIN --RAISE WARNING 'x1'; -- Is this node part of a way? - FOR location IN select * from placex where osm_type = 'W' - and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer]) + FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP +--RAISE WARNING '%', way; + FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id LOOP --RAISE WARNING '%', location; -- Way IS a road then we are on it - that must be our road @@ -1256,19 +1362,21 @@ BEGIN END IF; -- Is the WAY part of a relation - FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id] - LOOP - -- At the moment we only process one type of relation - associatedStreet - IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN - FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP - IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN ---RAISE WARNING 'node in way that is in a relation %',relation; - SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer - and rank_search = 26 INTO NEW.parent_place_id; + IF NEW.parent_place_id IS NULL THEN + FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id] + LOOP + -- At the moment we only process one type of relation - associatedStreet + IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN + FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP + IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN + --RAISE WARNING 'node in way that is in a relation %',relation; + SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer + and rank_search = 26 INTO NEW.parent_place_id; + END IF; + END LOOP; END IF; END LOOP; - END IF; - END LOOP; + END IF; -- If the way contains an explicit name of a street copy it IF NEW.street IS NULL AND location.street IS NOT NULL THEN @@ -1292,6 +1400,7 @@ BEGIN END IF; END LOOP; + END LOOP; END IF; @@ -1299,7 +1408,7 @@ BEGIN IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN -- Is this way part of a relation? - FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id] + FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id] LOOP -- At the moment we only process one type of relation - associatedStreet IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN @@ -1314,56 +1423,43 @@ BEGIN END LOOP; END IF; ---RAISE WARNING 'x3'; +--RAISE WARNING 'x3 %',NEW.parent_place_id; IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN address_street_word_id := get_name_id(make_standard_name(NEW.street)); ---RAISE WARNING 'street: % %', NEW.street, address_street_word_id; IF address_street_word_id IS NOT NULL THEN FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP ---RAISE WARNING 'streetname found nearby %',location; NEW.parent_place_id := location.place_id; END LOOP; END IF; END IF; ---RAISE WARNING 'x4'; - +--RAISE WARNING 'x4 %',NEW.parent_place_id; -- Still nothing, just use the nearest road --- IF NEW.parent_place_id IS NULL THEN --- FOR location IN SELECT place_id FROM getNearRoads(NEW.partition, place_centroid) LOOP --- NEW.parent_place_id := location.place_id; --- END LOOP; --- END IF; - - search_diameter := 0.00005; - WHILE NEW.parent_place_id IS NULL AND search_diameter < 0.1 LOOP - FOR location IN SELECT place_id FROM placex - WHERE ST_DWithin(place_centroid, placex.geometry, search_diameter) and rank_search between 22 and 27 - ORDER BY ST_distance(NEW.geometry, placex.geometry) ASC limit 1 - LOOP + IF NEW.parent_place_id IS NULL THEN + FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP NEW.parent_place_id := location.place_id; END LOOP; - search_diameter := search_diameter * 2; - END LOOP; + END IF; +--return NEW; --RAISE WARNING 'x6 %',NEW.parent_place_id; -- If we didn't find any road fallback to standard method IF NEW.parent_place_id IS NOT NULL THEN -- Add the street to the address as zero distance to force to front of list - INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26); +-- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26); address_havelevel[26] := true; -- Import address details from parent, reclculating distance in process - INSERT INTO place_addressline select NEW.place_id, x.address_place_id, x.fromarea, x.isaddress, ST_distance(NEW.geometry, placex.geometry), placex.rank_address - from place_addressline as x join placex on (address_place_id = placex.place_id) - where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id; +-- INSERT INTO place_addressline select NEW.place_id, x.address_place_id, x.fromarea, x.isaddress, ST_distance(NEW.geometry, placex.geometry), placex.rank_address +-- from place_addressline as x join placex on (address_place_id = placex.place_id) +-- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id; -- Get the details of the parent road select * from search_name where place_id = NEW.parent_place_id INTO location; - NEW.country_code := location.country_code; + NEW.calculated_country_code := location.country_code; --RAISE WARNING '%', NEW.name; -- If there is no name it isn't searchable, don't bother to create a search record @@ -1373,20 +1469,136 @@ BEGIN -- Merge address from parent nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector); - +--return NEW; -- 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 - result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid); - --- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, 0, NEW.country_code, --- name_vector, nameaddress_vector, place_centroid); + + IF NEW.rank_search <= 25 THEN + result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); + END IF; + + result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); return NEW; END IF; END IF; ---RAISE WARNING ' INDEXING: %',NEW; +-- RAISE WARNING ' INDEXING Started:'; +-- RAISE WARNING ' INDEXING: %',NEW; + + IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN + + -- see if we have any special relation members + select members from planet_osm_rels where id = NEW.osm_id INTO relation_members; + +-- RAISE WARNING 'get_osm_rel_members, label'; + FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP + + select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1) + and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex; + + -- If we don't already have one use this as the centre point of the geometry + IF NEW.centroid IS NULL THEN + NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry)); + END IF; + + -- merge in the label name, re-init word vector + NEW.name := linkedPlacex.name || NEW.name; + name_vector := make_keywords(NEW.name); + + -- merge in extra tags + NEW.extratags := linkedPlacex.extratags || NEW.extratags; + + -- mark the linked place (excludes from search results) + UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; + + END LOOP; + + IF NEW.centroid IS NULL THEN + + FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP + + select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1) + and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex; + + -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york' + -- But that can be fixed by explicitly setting the label in the data + IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name') + AND NEW.rank_search = linkedPlacex.rank_search THEN + + + -- If we don't already have one use this as the centre point of the geometry + IF NEW.centroid IS NULL THEN + NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry)); + END IF; + + -- merge in the name, re-init word vector + NEW.name := linkedPlacex.name || NEW.name; + name_vector := make_keywords(NEW.name); + + -- merge in extra tags + NEW.extratags := linkedPlacex.extratags || NEW.extratags; + + -- 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; + END IF; + + END LOOP; + + END IF; + + -- not found one yet? how about doing a name search + IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN + + FOR linkedPlacex IN select placex.* from placex WHERE + make_standard_name(name->'name') = make_standard_name(NEW.name->'name') + AND placex.rank_search = NEW.rank_search + AND placex.place_id != NEW.place_id + AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26 + AND st_covers(NEW.geometry, placex.geometry) + LOOP + + -- If we don't already have one use this as the centre point of the geometry + IF NEW.centroid IS NULL THEN + NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry)); + END IF; + + -- merge in the name, re-init word vector + NEW.name := linkedPlacex.name || NEW.name; + name_vector := make_keywords(NEW.name); + + -- merge in extra tags + NEW.extratags := linkedPlacex.extratags || NEW.extratags; + + -- 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; + END LOOP; + END IF; + + IF NEW.centroid IS NOT NULL THEN + place_centroid := NEW.centroid; + END IF; + + -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance + IF NEW.importance is null THEN + select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance; + END IF; + -- Still null? how about looking it up by the node id + IF NEW.importance IS NULL THEN + 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; + + NEW.parent_place_id = 0; + parent_place_id_rank = 0; -- convert isin to array of tokenids isin_tokens := '{}'::int[]; @@ -1395,19 +1607,30 @@ BEGIN IF array_upper(isin, 1) IS NOT NULL THEN FOR i IN 1..array_upper(isin, 1) LOOP address_street_word_id := get_name_id(make_standard_name(isin[i])); - IF address_street_word_id IS NOT NULL THEN - isin_tokens := isin_tokens + address_street_word_id; + 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; + END LOOP; + END IF; + END IF; + IF NEW.postcode IS NOT NULL THEN + isin := regexp_split_to_array(NEW.postcode, E'[;,]'); + IF array_upper(isin, 1) IS NOT NULL THEN + FOR i IN 1..array_upper(isin, 1) LOOP + address_street_word_id := get_name_id(make_standard_name(isin[i])); + 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; END LOOP; END IF; - isin_tokens := uniq(sort(isin_tokens)); END IF; +-- RAISE WARNING 'ISIN: %', isin_tokens; -- Process area matches location_rank_search := 100; location_distance := 0; ---RAISE WARNING '%', NEW.partition; - FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP +-- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens; + FOR location IN SELECT distinct * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP --RAISE WARNING ' AREA: %',location; @@ -1416,40 +1639,91 @@ BEGIN location_distance := location.distance * 1.5; END IF; - IF location.distance < location_distance THEN + IF location.distance < location_distance OR NOT location.isguess THEN -- Add it to the list of search terms nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address); address_havelevel[location.rank_address] := true; - END IF; +--RAISE WARNING ' Terms: (%) %',location, nameaddress_vector; - END LOOP; + IF location.rank_address > parent_place_id_rank THEN + NEW.parent_place_id = location.place_id; + parent_place_id_rank = location.rank_address; + END IF; + + END IF; + + END LOOP; -- try using the isin value to find parent places IF array_upper(isin_tokens, 1) IS NOT NULL THEN FOR i IN 1..array_upper(isin_tokens, 1) LOOP +--RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i]; + + FOR location IN SELECT distinct * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP + +--RAISE WARNING ' ISIN: %',location; - FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address); address_havelevel[location.rank_address] := true; + + IF location.rank_address > parent_place_id_rank THEN + NEW.parent_place_id = location.place_id; + parent_place_id_rank = location.rank_address; + END IF; + END LOOP; END LOOP; END IF; + -- for long ways we should add search terms for the entire length + IF st_length(NEW.geometry) > 0.05 THEN + + location_rank_search := 100; + location_distance := 0; + + FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP + + IF location.rank_search < location_rank_search THEN + location_rank_search := location.rank_search; + location_distance := location.distance * 1.5; + END IF; + + IF location.distance < location_distance THEN + + -- Add it to the list of search terms + nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); + INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address); + + END IF; + + END LOOP; + + END IF; + -- if we have a name add this to the name search table IF NEW.name IS NOT NULL THEN - IF NEW.rank_search <= 26 THEN - result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); + IF NEW.rank_search <= 25 THEN + result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); + END IF; + + IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN + result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry); END IF; - result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid); + result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); + +-- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid); + END IF; --- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid); + -- If we've not managed to pick up a better one - default centroid + IF NEW.centroid IS NULL THEN + NEW.centroid := place_centroid; END IF; END IF; @@ -1463,17 +1737,60 @@ CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER AS $$ DECLARE b BOOLEAN; + classtable TEXT; BEGIN + RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id; + + update placex set linked_place_id = null where linked_place_id = OLD.place_id; + --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id; + update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id; + + IF OLD.rank_address < 30 THEN + + -- mark everything linked to this place for re-indexing + --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id; + UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id + and placex.place_id = place_addressline.place_id and indexed_status = 0; + + --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id; + DELETE FROM place_addressline where address_place_id = OLD.place_id; + + --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id; + b := deleteRoad(OLD.partition, OLD.place_id); + + --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id; + update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id; + + END IF; + + --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id; + + IF OLD.rank_address < 26 THEN + b := deleteLocationArea(OLD.partition, OLD.place_id); + END IF; - -- mark everything linked to this place for re-indexing - UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id - and placex.place_id = place_addressline.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id; + + IF OLD.name is not null THEN + b := deleteSearchName(OLD.partition, OLD.place_id); + END IF; + + --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id; - -- do the actual delete - b := deleteLocationArea(OLD.partition, OLD.place_id); - b := deleteSearchName(OLD.partition, OLD.place_id); DELETE FROM place_addressline where place_id = OLD.place_id; - DELETE FROM place_addressline where address_place_id = OLD.place_id; + + --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id; + + -- remove from tables for special search + classtable := 'place_classtype_' || OLD.class || '_' || OLD.type; + SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b; + IF b THEN + EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id; + END IF; + + --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id; RETURN OLD; @@ -1484,11 +1801,20 @@ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER AS $$ DECLARE - placeid INTEGER; + placeid BIGINT; BEGIN --- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type; - delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type; + --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type; + + -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through + IF st_area(OLD.geometry) > 2 THEN + insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type); + RETURN NULL; + END IF; + + -- mark for delete + UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type; + RETURN OLD; END; @@ -1502,15 +1828,17 @@ DECLARE existing RECORD; existingplacex RECORD; existinggeometry GEOMETRY; - existingplace_id INTEGER; + existingplace_id BIGINT; result BOOLEAN; + partition INTEGER; BEGIN - IF FALSE AND NEW.osm_type = 'R' THEN - RAISE WARNING '-----------------------------------------------------------------------------------'; - RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry); + --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------'; + --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry); + + IF FALSE and NEW.osm_type = 'R' THEN select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex; - RAISE WARNING '%', existingplacex; + --DEBUG: RAISE WARNING '%', existingplacex; END IF; -- Just block these - lots and pointless @@ -1522,14 +1850,15 @@ BEGIN END IF; IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN + INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, + now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry); -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; RETURN null; END IF; -- Patch in additional country names - -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2 - IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN - select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name; + IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN + select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name; END IF; -- Have we already done this place? @@ -1539,46 +1868,40 @@ BEGIN select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex; -- Handle a place changing type by removing the old data - -- My generated 'place' types are causing havok because they overlap with real tags - -- TODO: move them to their own special purpose tag to avoid collisions + -- My generated 'place' types are causing havok because they overlap with real keys + -- TODO: move them to their own special purpose key/class to avoid collisions IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses'); END IF; --- RAISE WARNING 'Existing: %',existing.place_id; - - -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry - IF existing.osm_type IS NULL - OR existingplacex.osm_type IS NULL - OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100) --- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') - OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT - (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon'))) - THEN - --- IF existing.osm_type IS NULL THEN --- RAISE WARNING 'no existing place'; --- END IF; --- IF existingplacex.osm_type IS NULL THEN --- RAISE WARNING 'no existing placex %', existingplacex; --- END IF; + --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id; + --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id; + + -- Log and discard + IF existing.geometry is not null AND st_isvalid(existing.geometry) + AND st_area(existing.geometry) > 0.02 + AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') + AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5 + THEN + INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(), + 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry); + RETURN null; + END IF; + DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id; + DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id; --- RAISE WARNING 'delete and replace'; + -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry + IF existingplacex.osm_type IS NULL THEN IF existing.osm_type IS NOT NULL THEN --- RAISE WARNING 'insert delete % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)),existing; - IF existing.rank_search < 26 THEN --- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; - END IF; - DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; - END IF; - --- RAISE WARNING 'delete and replace2'; + DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + END IF; -- No - process it as a new insertion (hopefully of low rank or it will be slow) - insert into placex values (NEW.place_id - ,NEW.osm_type + insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber, + street, isin, postcode, country_code, extratags, geometry) + values (NEW.osm_type ,NEW.osm_id ,NEW.class ,NEW.type @@ -1589,14 +1912,11 @@ BEGIN ,NEW.isin ,NEW.postcode ,NEW.country_code - ,NEW.parent_place_id - ,NEW.rank_address - ,NEW.rank_search - ,NEW.indexed + ,NEW.extratags ,NEW.geometry ); --- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; + --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name; RETURN NEW; END IF; @@ -1604,7 +1924,7 @@ BEGIN -- Various ways to do the update -- Debug, what's changed? - IF FALSE AND existing.rank_search < 26 THEN + IF FALSE THEN IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text; END IF; @@ -1626,38 +1946,34 @@ BEGIN END IF; -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them - IF existing.geometry != NEW.geometry + IF existing.geometry::text != NEW.geometry::text AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN --- IF existing.rank_search < 26 THEN --- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; --- END IF; - -- Get the version of the geometry actually used (in placex table) select geometry from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type into existinggeometry; -- Performance limit - IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN + IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN -- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong update placex set indexed_status = 2 where indexed_status = 0 and - (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) - AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) - AND rank_search > NEW.rank_search; + (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) + AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null); update placex set indexed_status = 2 where indexed_status = 0 and - (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) - AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) - AND rank_search > NEW.rank_search; + (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) + AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null); END IF; END IF; -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing - IF existingplacex.rank_search < 26 + IF FALSE AND existingplacex.rank_search < 26 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '') AND coalesce(existing.street, '') = coalesce(NEW.street, '') AND coalesce(existing.isin, '') = coalesce(NEW.isin, '') @@ -1666,15 +1982,12 @@ BEGIN AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN --- IF existing.rank_search < 26 THEN --- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; --- END IF; - IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN IF st_area(NEW.geometry) < 0.5 THEN UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id - and placex.place_id = place_addressline.place_id and indexed_status = 0; + and placex.place_id = place_addressline.place_id and indexed_status = 0 + and (rank_search < 28 or name is not null); END IF; END IF; @@ -1689,14 +2002,10 @@ BEGIN OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN --- IF existing.rank_search < 26 THEN --- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; --- END IF; - -- performance, can't take the load of re-indexing a whole country / huge area IF st_area(NEW.geometry) < 0.5 THEN - UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id - and placex.place_id = place_addressline.place_id and indexed_status = 0; +-- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id +-- and placex.place_id = place_addressline.place_id and indexed_status = 0; END IF; END IF; @@ -1704,12 +2013,14 @@ BEGIN END IF; IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') + OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '') OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') OR coalesce(existing.street, '') != coalesce(NEW.street, '') OR coalesce(existing.isin, '') != coalesce(NEW.isin, '') OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') - OR existing.geometry != NEW.geometry + OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15) + OR existing.geometry::text != NEW.geometry::text THEN update place set @@ -1719,7 +2030,7 @@ BEGIN isin = NEW.isin, postcode = NEW.postcode, country_code = NEW.country_code, - parent_place_id = null, + extratags = NEW.extratags, geometry = NEW.geometry where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; @@ -1731,12 +2042,11 @@ BEGIN postcode = NEW.postcode, country_code = NEW.country_code, parent_place_id = null, - indexed_status = 2, + extratags = NEW.extratags, + indexed_status = 2, geometry = NEW.geometry where place_id = existingplacex.place_id; - result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry); - END IF; -- Abort the add (we modified the existing place instead) @@ -1782,7 +2092,9 @@ BEGIN FOR location IN select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1 LOOP - searchnodes := searchnodes | location.nodes; + IF not (ARRAY[location.nodes] <@ searchnodes) THEN + searchnodes := searchnodes || location.nodes; + END IF; END LOOP; END LOOP; @@ -1791,7 +2103,7 @@ END; $$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT +CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT AS $$ DECLARE result TEXT[]; @@ -1816,7 +2128,7 @@ BEGIN IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN FOR j IN 1..array_upper(search, 1) LOOP FOR k IN 1..array_upper(location.name, 1) LOOP - IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result && ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN + IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN result[(100 - location.rank_address)] := trim(location.name[k].value); found := location.rank_address; END IF; @@ -1830,123 +2142,198 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT +CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT AS $$ DECLARE result TEXT[]; - search TEXT[]; - found INTEGER; + currresult TEXT; + prevresult TEXT; location RECORD; - searchcountrycode varchar(2); - searchhousenumber TEXT; - searchrankaddress INTEGER; BEGIN - found := 1000; - search := languagepref; result := '{}'; + prevresult := ''; - select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress; - - FOR location IN - select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address, - CASE WHEN type = 'postcode' THEN 'name' => postcode ELSE name END as name, - distance,length(name::text) as namelength - from place_addressline join placex on (address_place_id = placex.place_id) - where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id) - and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4) - order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc - LOOP - IF array_upper(search, 1) IS NOT NULL AND location.name IS NOT NULL THEN - FOR j IN 1..array_upper(search, 1) LOOP - IF (found > location.rank_address AND location.name ? search[j] AND location.name -> search[j] != '' - AND NOT result && ARRAY[location.name -> search[j]]) THEN - result[(100 - location.rank_address)] := trim(location.name -> search[j]); - found := location.rank_address; - END IF; - END LOOP; + FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP + currresult := trim(get_name_by_language(location.name, languagepref)); + IF currresult != prevresult AND currresult IS NOT NULL THEN + result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref)); + prevresult := currresult; END IF; END LOOP; - IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN - IF result[(100 - 28)] IS NOT NULL THEN - result[(100 - 29)] := result[(100 - 28)]; - END IF; - result[(100 - 28)] := searchhousenumber; - END IF; - - -- No country polygon - add it from the country_code - IF found > 4 THEN - select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code) - where place_id = for_place_id limit 1 INTO location; - IF location IS NOT NULL THEN - result[(100 - 4)] := trim(location.name); - END IF; - END IF; - RETURN array_to_string(result,', '); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT[] +DROP TYPE addressline CASCADE; +create type addressline as ( + place_id BIGINT, + osm_type CHAR(1), + osm_id INTEGER, + name HSTORE, + class TEXT, + type TEXT, + admin_level INTEGER, + fromarea BOOLEAN, + isaddress BOOLEAN, + rank_address INTEGER, + distance FLOAT +); + +CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline AS $$ DECLARE + for_place_id BIGINT; result TEXT[]; search TEXT[]; found INTEGER; location RECORD; + countrylocation RECORD; searchcountrycode varchar(2); searchhousenumber TEXT; + searchhousename HSTORE; + searchrankaddress INTEGER; + searchpostcode TEXT; + searchclass TEXT; + searchtype TEXT; + countryname HSTORE; + hadcountry BOOLEAN; BEGIN - found := 1000; - search := languagepref; - result := '{}'; + select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger + WHERE place_id = in_place_id + INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + + IF for_place_id IS NULL THEN + 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; + END IF; + + IF for_place_id IS NULL THEN + select parent_place_id, calculated_country_code, housenumber, rank_address, postcode, name, class, type from placex + WHERE place_id = in_place_id and rank_address = 30 + INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + END IF; - UPDATE placex set indexed_status = 0 where indexed_status > 0 and place_id = for_place_id; + IF for_place_id IS NULL THEN + for_place_id := in_place_id; + select calculated_country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id + INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename; + END IF; - select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber; +--RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode; + found := 1000; + hadcountry := false; FOR location IN - select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address, - name,distance,length(name::text) as namelength - from place_addressline join placex on (address_place_id = placex.place_id) - where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id) - and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4) - order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc + select placex.place_id, osm_type, osm_id, + CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name, + class, type, admin_level, true as fromarea, 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, calculated_country_code + from placex + where place_id = for_place_id LOOP - IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN - FOR j IN 1..array_upper(search, 1) LOOP - FOR k IN 1..array_upper(location.name, 1) LOOP - IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result && ARRAY[trim(location.name[k].value)] THEN - result[(100 - location.rank_address)] := trim(location.name[k].value); - found := location.rank_address; - END IF; - END LOOP; - END LOOP; +--RAISE WARNING '%',location; + IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN + searchcountrycode := location.calculated_country_code; + END IF; + IF searchpostcode IS NOT NULL and location.type = 'postcode' 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; + 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, + location.distance)::addressline; + RETURN NEXT countrylocation; + found := location.rank_address; END LOOP; - IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN - result[(100 - 28)] := searchhousenumber; - END IF; + FOR location IN + select placex.place_id, osm_type, osm_id, + CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name, + class, 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,calculated_country_code + 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 (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_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.calculated_country_code IS NOT NULL THEN + searchcountrycode := location.calculated_country_code; + END IF; + IF searchpostcode IS NOT NULL and location.type = 'postcode' 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; + 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, + location.distance)::addressline; + RETURN NEXT countrylocation; + found := location.rank_address; + END LOOP; - -- No country polygon - add it from the country_code IF found > 4 THEN - select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code) - where place_id = for_place_id limit 1 INTO location; - IF location IS NOT NULL THEN - result[(100 - 4)] := trim(location.name); + 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; + RETURN NEXT location; END IF; END IF; - RETURN result; + IF searchcountrycode IS NOT NULL THEN + location := ROW(null, null, null, '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, 'place', 'house_name', null, true, true, 29, 0)::addressline; + RETURN NEXT location; + END IF; + + IF searchhousenumber IS NOT NULL THEN + location := ROW(in_place_id, null, null, '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, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline; + RETURN NEXT location; + END IF; + + RETURN; END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox +CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox AS $$ DECLARE result place_boundingbox; @@ -1983,7 +2370,7 @@ $$ LANGUAGE plpgsql; -- don't do the operation if it would be slow -CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox +CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox AS $$ DECLARE result place_boundingbox; @@ -2022,32 +2409,7 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN - AS $$ -DECLARE - result place_boundingbox; - numfeatures integer; -BEGIN - update placex set - name = place.name, - housenumber = place.housenumber, - street = place.street, - isin = place.isin, - postcode = place.postcode, - country_code = place.country_code, - parent_place_id = null, - indexed_status = 1 - from place - where placex.place_id = search_place_id - and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id - and place.class = placex.class and place.type = placex.type; - update placex set indexed_status = 0 where place_id = search_place_id; - return true; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN +CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN AS $$ DECLARE result place_boundingbox; @@ -2060,12 +2422,12 @@ BEGIN isin = place.isin, postcode = place.postcode, country_code = place.country_code, - parent_place_id = null, - indexed_status = 2 + parent_place_id = null from place where placex.place_id = search_place_id and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id and place.class = placex.class and place.type = placex.type; + update placex set indexed_status = 2 where place_id = search_place_id; update placex set indexed_status = 0 where place_id = search_place_id; return true; END; @@ -2198,11 +2560,350 @@ END; $$ LANGUAGE plpgsql; -CREATE AGGREGATE array_agg(INT[]) -( - sfunc = array_cat, - stype = INT[], - initcond = '{}' +CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER, + in_endnumber INTEGER, interpolationtype TEXT, + in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER + AS $$ +DECLARE + + startnumber INTEGER; + endnumber INTEGER; + stepsize INTEGER; + housenum INTEGER; + newpoints INTEGER; + numberrange INTEGER; + rangestartnumber INTEGER; + place_centroid GEOMETRY; + out_partition INTEGER; + out_parent_place_id BIGINT; + location RECORD; + address_street_word_id INTEGER; + +BEGIN + + IF in_endnumber > in_startnumber THEN + startnumber = in_startnumber; + endnumber = in_endnumber; + ELSE + startnumber = in_endnumber; + endnumber = in_startnumber; + END IF; + + numberrange := endnumber - startnumber; + rangestartnumber := startnumber; + + IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN + startnumber := startnumber + 1; + stepsize := 2; + ELSE + IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN + stepsize := 2; + ELSE -- everything else assumed to be 'all' + stepsize := 1; + END IF; + END IF; + + -- Filter out really broken tiger data + IF numberrange > 0 AND (numberrange::float/stepsize::float > 500) + AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN + RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin, + ST_length(linegeo)/(numberrange::float/stepsize::float); + RETURN 0; + END IF; + + place_centroid := ST_Centroid(linegeo); + out_partition := get_partition(place_centroid, 'us'); + out_parent_place_id := null; + + address_street_word_id := get_name_id(make_standard_name(in_street)); + IF address_street_word_id IS NOT NULL THEN + FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP + out_parent_place_id := location.place_id; + END LOOP; + END IF; + + IF out_parent_place_id IS NULL THEN + FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP + out_parent_place_id := location.place_id; + END LOOP; + END IF; + + IF out_parent_place_id IS NULL THEN + FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP + out_parent_place_id := location.place_id; + END LOOP; + END IF; + + newpoints := 0; + FOR housenum IN startnumber..endnumber BY stepsize LOOP + insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid) + values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode, + ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float)); + newpoints := newpoints + 1; + END LOOP; + + RETURN newpoints; +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 $$ +DECLARE + + newpoints INTEGER; + place_centroid GEOMETRY; + out_partition INTEGER; + out_parent_place_id BIGINT; + location RECORD; + address_street_word_id INTEGER; + out_postcode TEXT; + +BEGIN + + place_centroid := ST_Centroid(pointgeo); + out_partition := get_partition(place_centroid, in_countrycode); + out_parent_place_id := null; + + address_street_word_id := get_name_id(make_standard_name(in_street)); + IF address_street_word_id IS NOT NULL THEN + FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP + out_parent_place_id := location.place_id; + END LOOP; + END IF; + + IF out_parent_place_id IS NULL THEN + FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP + out_parent_place_id := location.place_id; + END LOOP; + END IF; + + out_postcode := in_postcode; + IF out_postcode IS NULL THEN + SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode; + END IF; + IF out_postcode IS NULL THEN + out_postcode := getNearestPostcode(out_partition, place_centroid); + END IF; + + newpoints := 0; + insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid) + values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid); + newpoints := newpoints + 1; + + RETURN newpoints; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[] + AS $$ +DECLARE + result TEXT[]; + i INTEGER; +BEGIN + + FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP + IF members[i+1] = member THEN + result := result || members[i]; + END IF; + END LOOP; + + return result; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT + AS $$ +DECLARE + i INTEGER; +BEGIN + + FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP + IF members[i+1] = ANY(memberLabels) THEN + RETURN NEXT members[i]; + END IF; + END LOOP; + + RETURN; +END; +$$ +LANGUAGE plpgsql; + +-- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql +CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar + AS $$ +SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY( + SELECT CASE WHEN length(r.m[1]) = 1 THEN encode(convert_to(r.m[1], 'SQL_ASCII'), 'hex') ELSE substring(r.m[1] from 2 for 2) END + FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m) +), '') AS bytea), 'UTF8'); +$$ +LANGUAGE SQL IMMUTABLE STRICT; + +CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar + AS $$ +DECLARE +BEGIN + RETURN decode_url_part(p); +EXCEPTION + WHEN others THEN return null; +END; +$$ +LANGUAGE plpgsql IMMUTABLE; + +DROP TYPE wikipedia_article_match CASCADE; +create type wikipedia_article_match as ( + language TEXT, + title TEXT, + importance FLOAT ); +CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match + AS $$ +DECLARE + langs TEXT[]; + i INT; + wiki_article TEXT; + wiki_article_title TEXT; + wiki_article_language TEXT; + result wikipedia_article_match; +BEGIN + langs := ARRAY['english','country','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh']; + i := 1; + WHILE langs[i] IS NOT NULL LOOP + wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END); + IF wiki_article is not null THEN + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:'); + wiki_article := replace(wiki_article,' ','_'); + wiki_article_title := trim(split_part(wiki_article, ':', 2)); + IF wiki_article_title IS NULL OR wiki_article_title = '' THEN + wiki_article_title := trim(wiki_article); + wiki_article_language := CASE WHEN langs[i] = 'english' THEN 'en' WHEN langs[i] = 'country' THEN get_country_language_code(country_code) ELSE langs[i] END; + ELSE + wiki_article_language := lower(trim(split_part(wiki_article, ':', 1))); + END IF; + + select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance + from wikipedia_article + where language = wiki_article_language and + (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\','')) + UNION ALL + select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance + from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title) + where wikipedia_redirect.language = wiki_article_language and + (from_title = wiki_article_title OR from_title = catch_decode_url_part(wiki_article_title) OR from_title = replace(catch_decode_url_part(wiki_article_title),E'\\','')) + order by importance desc limit 1 INTO result; + + IF result.language is not null THEN + return result; + END IF; + END IF; + i := i + 1; + END LOOP; + RETURN NULL; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER) + RETURNS SETOF GEOMETRY + AS $$ +DECLARE + xmin FLOAT; + ymin FLOAT; + xmax FLOAT; + ymax FLOAT; + xmid FLOAT; + ymid FLOAT; + secgeo GEOMETRY; + secbox GEOMETRY; + seg INTEGER; + geo RECORD; + area FLOAT; + remainingdepth INTEGER; + added INTEGER; + +BEGIN + +-- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth; + + IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN + RETURN NEXT geometry; + RETURN; + END IF; + + remainingdepth := maxdepth - 1; + area := ST_AREA(geometry); + IF remainingdepth < 1 OR area < maxarea THEN + RETURN NEXT geometry; + RETURN; + END IF; + + xmin := st_xmin(geometry); + xmax := st_xmax(geometry); + ymin := st_ymin(geometry); + ymax := st_ymax(geometry); + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326); + + -- if the geometry completely covers the box don't bother to slice any more + IF ST_AREA(secbox) = area THEN + RETURN NEXT geometry; + RETURN; + END IF; + + xmid := (xmin+xmax)/2; + ymid := (ymin+ymax)/2; + + added := 0; + FOR seg IN 1..4 LOOP + IF seg = 1 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326); + END IF; + IF seg = 2 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326); + END IF; + IF seg = 3 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326); + END IF; + IF seg = 4 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326); + END IF; + + IF st_intersects(geometry, secbox) THEN + secgeo := st_intersection(geometry, secbox); + IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN + FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP + IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN + added := added + 1; + RETURN NEXT geo.geom; + END IF; + END LOOP; + END IF; + END IF; + END LOOP; + + RETURN; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY) + RETURNS SETOF GEOMETRY + AS $$ +DECLARE + geo RECORD; +BEGIN + -- 10000000000 is ~~ 1x1 degree + FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP + RETURN NEXT geo.geom; + END LOOP; + RETURN; +END; +$$ +LANGUAGE plpgsql;