X-Git-Url: https://git.openstreetmap.org./nominatim.git/blobdiff_plain/2643225b72fe2d32ced5191511a059e88badac79..b03be15442502aa2e52bacff70fb983cf4397d70:/sql/functions.sql diff --git a/sql/functions.sql b/sql/functions.sql index 5c4cea05..80763eaa 100644 --- a/sql/functions.sql +++ b/sql/functions.sql @@ -1,49 +1,14 @@ ---DROP TRIGGER IF EXISTS place_before_insert on placex; ---DROP TRIGGER IF EXISTS place_before_update on placex; ---CREATE TYPE addresscalculationtype AS ( --- word text, --- score integer ---); - -CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT +-- Splits the line at the given point and returns the two parts +-- in a multilinestring. +CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY) +RETURNS GEOMETRY AS $$ -DECLARE -BEGIN - RETURN c||'|'||t; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN - AS $$ -DECLARE - NEWgeometry geometry; BEGIN - 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 - RETURN true; - END IF; - RETURN false; + RETURN ST_Split(ST_Snap(line, point, 0.0005), point); END; $$ -LANGUAGE plpgsql IMMUTABLE; +LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry - AS $$ -DECLARE - NEWgeometry geometry; -BEGIN - NEWgeometry := place; - IF 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_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - RETURN ST_SetSRID(ST_Point(0,0),4326); - END IF; - END IF; - RETURN NEWgeometry; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER AS $$ @@ -52,12 +17,6 @@ DECLARE BEGIN -- RAISE WARNING '%',place; 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; $$ @@ -160,38 +119,6 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := lookup_class||'='||lookup_type; - SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id; - IF return_word_id IS NULL THEN - return_word_id := nextval('seq_word'); - INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0); - END IF; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text) - RETURNS INTEGER - AS $$ -DECLARE - lookup_token TEXT; - return_word_id INTEGER; -BEGIN - lookup_token := lookup_class||'='||lookup_type; - SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id; - RETURN return_word_id; -END; -$$ -LANGUAGE plpgsql; - CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text) RETURNS INTEGER AS $$ @@ -474,31 +401,6 @@ END; $$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer - AS $$ -DECLARE - idxword integer; - idxscores integer; - result integer; -BEGIN - IF (wordscores is null OR words is null) THEN - RETURN 0; - END IF; - - result := 0; - FOR idxword in 1 .. array_upper(words, 1) LOOP - FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP - IF wordscores[idxscores].word = words[idxword] THEN - result := result + wordscores[idxscores].score; - END IF; - END LOOP; - END LOOP; - - RETURN result; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT AS $$ DECLARE @@ -548,21 +450,6 @@ BEGIN 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; - RETURN NULL; END; $$ @@ -660,7 +547,7 @@ BEGIN x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo); END LOOP; - ELSEIF rank_search < 26 THEN + ELSE diameter := 0.02; IF rank_address = 0 THEN @@ -684,16 +571,6 @@ BEGIN secgeo := ST_Buffer(geometry, diameter); x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo); - ELSE - - -- ~ 20meters - secgeo := ST_Buffer(geometry, 0.0002); - x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo); - - -- ~ 100meters - secgeo := ST_Buffer(geometry, 0.001); - x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo); - END IF; RETURN true; @@ -701,97 +578,82 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION update_location( - partition INTEGER, - place_id BIGINT, - place_country_code varchar(2), - name hstore, - rank_search INTEGER, - rank_address INTEGER, - geometry GEOMETRY - ) - RETURNS BOOLEAN - AS $$ -DECLARE - b BOOLEAN; -BEGIN - b := deleteLocationArea(partition, place_id, rank_search); --- 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 BIGINT, to_add INTEGER[]) - RETURNS BOOLEAN - AS $$ +-- find the parent road of the cut road parts +CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT, + partition INTEGER, centroid GEOMETRY, geom GEOMETRY) +RETURNS BIGINT AS $$ DECLARE - childplace RECORD; + addr_street TEXT; + addr_place TEXT; + parent_place_id BIGINT; + address_street_word_ids INTEGER[]; + + waynodes BIGINT[]; + + location RECORD; BEGIN + addr_street = street; + addr_place = place; - IF #to_add = 0 THEN - RETURN true; + IF addr_street is null and addr_place is null THEN + select nodes from planet_osm_ways where id = wayid INTO waynodes; + FOR location IN SELECT placex.street, placex.addr_place from placex + where osm_type = 'N' and osm_id = ANY(waynodes) + and (placex.street is not null or placex.addr_place is not null) + and indexed_status < 100 + limit 1 LOOP + addr_street = location.street; + addr_place = location.addr_place; + END LOOP; END IF; - -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't) - FOR childplace IN select * from search_name,place_addressline - where address_place_id = parent_place_id - and search_name.place_id = place_addressline.place_id - LOOP - delete from search_name where place_id = childplace.place_id; - 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; + IF addr_street IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(addr_street)); + IF address_street_word_ids IS NOT NULL THEN + FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP + parent_place_id := location.place_id; + END LOOP; 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, - childplace.name_vector, childplace.nameaddress_vector, childplace.centroid); - END LOOP; - - RETURN true; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN - AS $$ -DECLARE - newkeywords INTEGER[]; - addedkeywords INTEGER[]; - removedkeywords INTEGER[]; -BEGIN - - -- what has changed? - newkeywords := make_keywords(name); - select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]), - coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point - where place_id = OLD_place_id into addedkeywords, removedkeywords; + END IF; --- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords; + IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(addr_place)); + IF address_street_word_ids IS NOT NULL THEN + FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP + parent_place_id := location.place_id; + END LOOP; + END IF; + END IF; - IF #removedkeywords > 0 THEN - -- abort due to tokens removed - RETURN false; + IF parent_place_id is null THEN + FOR location IN SELECT place_id FROM placex + WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26 + ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+ + ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+ + ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1 + LOOP + parent_place_id := location.place_id; + END LOOP; END IF; - - IF #addedkeywords > 0 THEN - -- short circuit - no changes - RETURN true; + + IF parent_place_id is null THEN + RETURN 0; END IF; - UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id; - RETURN search_name_add_words(OLD_place_id, addedkeywords); + RETURN parent_place_id; END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER - AS $$ +CREATE OR REPLACE FUNCTION insert_osmline(wayid BIGINT, interpolationtype TEXT, + street TEXT, addr_place TEXT, + defpostalcode TEXT, country_code TEXT, + geom GEOMETRY) +RETURNS INTEGER AS $$ DECLARE - + newpoints INTEGER; waynodes BIGINT[]; nodeid BIGINT; @@ -799,130 +661,101 @@ DECLARE nextnode RECORD; startnumber INTEGER; endnumber INTEGER; - stepsize INTEGER; - orginalstartnumber INTEGER; - originalnumberrange INTEGER; housenum INTEGER; linegeo GEOMETRY; - search_place_id BIGINT; - defpostalcode TEXT; + splitline GEOMETRY; + sectiongeo GEOMETRY; + pointgeo GEOMETRY; + place_centroid GEOMETRY; + calculated_country_code VARCHAR(2); + partition INTEGER; + geometry_sector INTEGER; - havefirstpoint BOOLEAN; - linestr TEXT; 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 - - havefirstpoint := false; - - FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP - - -- If there is a place of a type other than place/house, use that because - -- it is guaranteed to be the original node. For place/house types use the - -- one with the smallest id because the original node was created first. - -- Ignore all nodes marked for deletion. (Might happen when the type changes.) - select place_id from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and indexed_status < 100 order by (type = 'house'),place_id limit 1 INTO search_place_id; - IF search_place_id IS NULL THEN - -- if no such node exists, create a record of the right type - select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and type = 'house' limit 1 INTO nextnode; - select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry; - IF nextnode.geometry IS NULL THEN - -- we don't have any information about this point, most likely - -- because an excerpt was updated and the node never imported - -- because the interpolation is outside the region of the excerpt. - -- Give up. - RETURN newpoints; - END IF; - ELSE - select * from placex where place_id = search_place_id INTO nextnode; - END IF; + place_centroid := ST_PointOnSurface(geom); + calculated_country_code := lower(get_country_code(place_centroid)); + partition := get_partition(calculated_country_code); + geometry_sector := geometry_sector(partition, place_centroid); ---RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry); - - IF havefirstpoint THEN + IF interpolationtype != 'odd' AND interpolationtype != 'even' AND interpolationtype!='all' THEN + -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported + RETURN 0; + END IF; - -- add point to the line string - linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry); - endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer; + select nodes from planet_osm_ways where id = wayid INTO waynodes; - IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN + IF array_upper(waynodes, 1) IS NULL THEN + RETURN 0; + END IF; ---RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber; + linegeo := geom; + startnumber := NULL; + + FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP + + -- If there is a place of a type other than place/house, use that because + -- it is guaranteed to be the original node. For place/house types use the + -- one with the smallest id because the original node was created first. + -- Ignore all nodes marked for deletion. (Might happen when the type changes.) + select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT + and indexed_status < 100 and housenumber is not NULL + order by (type = 'address'),place_id limit 1 INTO nextnode; + --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id; + IF nextnode.place_id IS NOT NULL THEN + --RAISE NOTICE 'place_id is not null'; + IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN + -- Make sure that the point is actually on the line. That might + -- be a bit paranoid but ensures that the algorithm still works + -- should osm2pgsql attempt to repair geometries. + splitline := split_line_on_node(linegeo, nextnode.geometry); + sectiongeo := ST_GeometryN(splitline, 1); + linegeo := ST_GeometryN(splitline, 2); + ELSE + sectiongeo = linegeo; + END IF; + endnumber := substring(nextnode.housenumber,'[0-9]+')::integer; - IF startnumber != endnumber THEN + IF startnumber IS NOT NULL AND endnumber IS NOT NULL + AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber + AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN - linestr := linestr || ')'; ---RAISE WARNING 'linestr %',linestr; - linegeo := ST_GeomFromText(linestr,4326); - linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry); - IF (startnumber > endnumber) THEN - housenum := endnumber; - endnumber := startnumber; - startnumber := housenum; - linegeo := ST_Reverse(linegeo); - END IF; - orginalstartnumber := startnumber; - originalnumberrange := endnumber - startnumber; - --- Too much broken data worldwide for this test to be worth using --- IF originalnumberrange > 500 THEN --- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode; --- END IF; - - 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 - startnumber := startnumber + 2; - stepsize := 2; - ELSE -- everything else assumed to be 'all' - startnumber := startnumber + 1; - stepsize := 1; - END IF; - END IF; - endnumber := endnumber - 1; - delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id; - 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, addr_place, isin, postcode, - country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry) - values ('N',prevnode.osm_id, 'place', 'house', prevnode.admin_level, housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode), - prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_LineInterpolatePoint(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float)); - newpoints := newpoints + 1; ---RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum; - END LOOP; - END IF; - havefirstpoint := false; - END IF; + IF (startnumber > endnumber) THEN + housenum := endnumber; + endnumber := startnumber; + startnumber := housenum; + sectiongeo := ST_Reverse(sectiongeo); END IF; + + -- a correction for odd/even is NOT necessary anymore (e.g. if interpolationtype=even, but start/endnumber != even) + -- see PlaceLookup.php + + -- keep for compatibility with previous versions + delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id + and place_id != prevnode.place_id and class = 'place' + and type = 'house'; + insert into location_property_osmline + values (sectiongeo, nextval('seq_place'), partition, wayid, NULL, startnumber, endnumber, interpolationtype, prevnode.admin_level, + street, coalesce(prevnode.postcode, defpostalcode), + calculated_country_code, geometry_sector, 2, now()); + END IF; - IF NOT havefirstpoint THEN - startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer; - IF startnumber IS NOT NULL AND startnumber > 0 THEN - havefirstpoint := true; - linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry); - prevnode := nextnode; - END IF; ---RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber; - END IF; - END LOOP; - END IF; - END IF; + -- early break if we are out of line string, + -- might happen when a line string loops back on itself + IF ST_GeometryType(linegeo) != 'ST_LineString' THEN + RETURN 0; + END IF; ---RAISE WARNING 'interpolation points % ',newpoints; + startnumber := substring(nextnode.housenumber,'[0-9]+')::integer; + prevnode := nextnode; + END IF; + END LOOP; - RETURN newpoints; + RETURN 1; END; $$ LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER AS $$ DECLARE @@ -933,30 +766,19 @@ DECLARE default_language VARCHAR(10); diameter FLOAT; classtable TEXT; + line RECORD; BEGIN --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id; - -- just block these - IF NEW.class in ('landuse','natural') and NEW.name is null THEN --- RAISE WARNING 'empty landuse %',NEW.osm_id; - RETURN null; + -- ignore interpolated addresses, not necessary anymore, cause interpolated addresses are now in location_property_osmline + IF NEW.class = 'place' and NEW.type = 'address' THEN + RETURN NEW; 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 - IF NEW.osm_type = 'R' THEN - -- invalid multipolygons can crash postgis, don't even bother to try! - RETURN NULL; - END IF; - NEW.geometry := ST_buffer(NEW.geometry,0); - 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 - RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id; - RETURN NULL; - END IF; END IF; --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; @@ -1018,6 +840,13 @@ BEGIN NEW.rank_address := 5; END IF; + ELSEIF NEW.calculated_country_code = 'sg' THEN + + IF NEW.postcode ~ '^([0-9]{6})$' THEN + NEW.rank_search := 25; + NEW.rank_address := 11; + END IF; + ELSEIF NEW.calculated_country_code = 'de' THEN IF NEW.postcode ~ '^([0-9]{5})$' THEN @@ -1095,8 +924,6 @@ BEGIN NEW.rank_address := NEW.rank_search; ELSEIF NEW.type in ('houses') THEN -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql - -- insert new point into place for each derived building - --i := create_interpolation(NEW.osm_id, NEW.housenumber); NEW.rank_search := 28; NEW.rank_address := 0; END IF; @@ -1114,27 +941,23 @@ BEGIN END IF; ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN NEW.rank_search := 22; - NEW.rank_address := NEW.rank_search; + IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN + NEW.rank_address := NEW.rank_search; + ELSE + NEW.rank_address := 0; + END IF; ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN NEW.rank_search := 18; NEW.rank_address := 0; ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN NEW.rank_search := 4; NEW.rank_address := NEW.rank_search; - ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN - RETURN NULL; -- any feature more than 5 square miles is probably worth indexing ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN NEW.rank_search := 22; - NEW.rank_address := 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; + NEW.rank_address := 0; ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN RETURN NULL; - ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN - RETURN NULL; ELSEIF NEW.class = 'waterway' THEN IF NEW.osm_type = 'R' THEN NEW.rank_search := 16; @@ -1179,7 +1002,7 @@ BEGIN --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 + RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down IF NEW.rank_address > 0 THEN IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN @@ -1220,6 +1043,8 @@ BEGIN IF NEW.rank_search >= 26 THEN -- roads may cause reparenting for >27 rank places update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter); + -- reparenting also for OSM Interpolation Lines (and for Tiger?) + update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter); ELSEIF NEW.rank_search >= 16 THEN -- up to rank 16, street-less addresses may need reparenting 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 or addr_place is not null); @@ -1231,6 +1056,7 @@ BEGIN 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. @@ -1241,18 +1067,44 @@ BEGIN 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; - RETURN NEW; END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION placex_update() RETURNS +CREATE OR REPLACE FUNCTION osmline_update() RETURNS +TRIGGER + AS $$ +DECLARE + place_centroid GEOMETRY; +BEGIN + -- deferred delete + IF OLD.indexed_status = 100 THEN + delete from location_property_osmline where place_id = OLD.place_id; + RETURN NULL; + END IF; + + IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN + RETURN NEW; + END IF; + + IF OLD.indexed_status = 2 and NEW.indexed_status=0 THEN + -- do the reparenting: (finally here, so that ALL places in placex, that are needed for reparenting, are up to date) + -- (the osm interpolationline in location_property_osmline was marked for reparenting in placex_insert/placex_delete with index_status = 2 + -- => index.c: sets index_status back to 0 + -- => triggers this function) + place_centroid := ST_PointOnSurface(NEW.linegeo); + -- mark descendants for reparenting + UPDATE placex SET indexed_status = 2 WHERE parent_place_id = OLD.place_id; + NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.street, null, NEW.partition, place_centroid, NEW.linegeo); -- addr_place (3rd param) is not necessarily needed + return NEW; + END IF; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION placex_update() RETURNS TRIGGER AS $$ DECLARE @@ -1262,8 +1114,6 @@ DECLARE search_maxdistance FLOAT[]; search_mindistance FLOAT[]; address_havelevel BOOLEAN[]; --- search_scores wordscore[]; --- search_scores_pos INTEGER; i INTEGER; iMax FLOAT; @@ -1288,8 +1138,7 @@ DECLARE location_distance FLOAT; location_parent GEOMETRY; location_isaddress BOOLEAN; - - tagpairid INTEGER; + location_keywords INTEGER[]; default_language TEXT; name_vector INTEGER[]; @@ -1299,7 +1148,6 @@ DECLARE result BOOLEAN; BEGIN - -- deferred delete IF OLD.indexed_status = 100 THEN --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id; @@ -1308,6 +1156,19 @@ BEGIN END IF; IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN + + -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting + -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late) + -- needed for test case features/db/import: Scenario: addr:street added to housenumbers + IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN + -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting + update location_property_osmline p set indexed_status = 2 from planet_osm_ways w where p.linegeo && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes); + END IF; + RETURN NEW; + END IF; + + -- ignore interpolated addresses + IF NEW.class = 'place' and NEW.type = 'address' THEN RETURN NEW; END IF; @@ -1321,628 +1182,637 @@ BEGIN RETURN NEW; END IF; - -- TODO: this test is now redundant? - IF OLD.indexed_status != 0 THEN - - NEW.indexed_date = now(); + NEW.indexed_date = now(); - 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, NEW.rank_search); - UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id; + result := deleteSearchName(NEW.partition, NEW.place_id); + DELETE FROM place_addressline WHERE place_id = NEW.place_id; + result := deleteRoad(NEW.partition, NEW.place_id); + result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search); + UPDATE placex set linked_place_id = null, indexed_status = 2 + where linked_place_id = NEW.place_id; + -- update not necessary for osmline, cause linked_place_id does not exist - IF NEW.linked_place_id is not null THEN - RETURN NEW; - END IF; + IF NEW.linked_place_id is not null THEN + RETURN NEW; + END IF; - IF NEW.class = 'place' AND NEW.type = 'houses' THEN - i := create_interpolation(NEW.osm_id, NEW.housenumber); - RETURN NEW; - 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; - -- 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 - -- for countries, believe the mapped country code, - -- so that we remain in the right partition if the boundaries - -- suddenly expand. - NEW.partition := get_partition(lower(NEW.country_code)); - IF NEW.partition = 0 THEN - NEW.calculated_country_code := lower(get_country_code(place_centroid)); - NEW.partition := get_partition(NEW.calculated_country_code); - ELSE - NEW.calculated_country_code := lower(NEW.country_code); - END IF; - ELSE - 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; + -- recalculate country and partition + IF NEW.rank_search = 4 THEN + -- for countries, believe the mapped country code, + -- so that we remain in the right partition if the boundaries + -- suddenly expand. + NEW.partition := get_partition(lower(NEW.country_code)); + IF NEW.partition = 0 THEN + NEW.calculated_country_code := lower(get_country_code(place_centroid)); NEW.partition := get_partition(NEW.calculated_country_code); + ELSE + NEW.calculated_country_code := lower(NEW.country_code); END IF; - NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid); - - -- waterway ways are linked when they are part of a relation and have the same class/type - IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN - FOR relation IN select * from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[] - LOOP - FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP - IF relation.members[i+1] in ('', 'main_stream') AND substring(relation.members[i],1,1) = 'w' THEN - --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.parts[i]; - FOR location IN SELECT * FROM placex WHERE osm_type = 'W' and osm_id = substring(relation.members[i],2,200)::bigint and class = NEW.class and type = NEW.type - LOOP - UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = location.place_id; - END LOOP; - END IF; - END LOOP; - END LOOP; - END IF; + ELSE + 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(NEW.calculated_country_code); + END IF; + + -- waterway ways are linked when they are part of a relation and have the same class/type + IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN + FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[] + LOOP + FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP + IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN + --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i]; + FOR linked_node_id IN SELECT place_id FROM placex + WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint + and class = NEW.class and type = NEW.type + and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name') + LOOP + UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id; + END LOOP; + END IF; + END LOOP; + END LOOP; + END IF; - -- 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); + -- 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); - -- What level are we searching from - search_maxrank := NEW.rank_search; + -- What level are we searching from + search_maxrank := NEW.rank_search; - -- 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 || hstore(('name:'||default_language), (NEW.name -> 'name')); - ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN - NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language))); - END IF; + -- 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 || hstore(('name:'||default_language), (NEW.name -> 'name')); + ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN + NEW.name := NEW.name || hstore('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); - nameaddress_vector := '{}'::int[]; - - -- some tag combinations add a special id for search - tagpairid := get_tagpair(NEW.class,NEW.type); - IF tagpairid IS NOT NULL THEN - name_vector := name_vector + tagpairid; - END IF; + -- Initialise the name vector using our name + name_vector := make_keywords(NEW.name); + nameaddress_vector := '{}'::int[]; - FOR i IN 1..28 LOOP - address_havelevel[i] := false; - END LOOP; + FOR i IN 1..28 LOOP + address_havelevel[i] := false; + END LOOP; - 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; + 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 + -- 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 --RAISE WARNING 'finding street for %', NEW; - -- We won't get a better centroid, besides these places are too small to care - NEW.centroid := place_centroid; - - NEW.parent_place_id := null; - - -- to do that we have to find our parent road - -- Copy data from linked items (points on ways, addr:street links, relations) - -- Note that addr:street links can only be indexed once the street itself is indexed - IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN + -- We won't get a better centroid, besides these places are too small to care + NEW.centroid := place_centroid; + + NEW.parent_place_id := null; + + -- if we have a POI and there is no address information, + -- see if we can get it from a surrounding building + IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL + AND NEW.housenumber IS NULL THEN + FOR location IN select * from placex where ST_Covers(geometry, place_centroid) + and (housenumber is not null or street is not null or addr_place is not null) + and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') + limit 1 + LOOP + NEW.housenumber := location.housenumber; + NEW.street := location.street; + NEW.addr_place := location.addr_place; + END LOOP; + END IF; - -- if there is no address information, see if we can get it from a surrounding building - IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN - FOR location IN select * from placex where ST_Covers(geometry, place_centroid) and rank_search > 28 and (housenumber is not null or street is not null or addr_place is not null) AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') - LOOP - NEW.housenumber := location.housenumber; - NEW.street := location.street; - NEW.addr_place := location.addr_place; - END LOOP; - END IF; + -- We have to find our parent road. + -- Copy data from linked items (points on ways, addr:street links, relations) - -- Is this node part of a relation? - 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 - 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 + -- Is this object part of a relation? + FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id] + LOOP + -- At the moment we only process one type of relation - associatedStreet + IF relation.tags @> ARRAY['associatedStreet'] 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 relation %',relation; - SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint - and rank_search = 26 and name is not null INTO NEW.parent_place_id; - END IF; - END LOOP; + SELECT place_id from placex where osm_type = 'W' + and osm_id = substring(relation.members[i],2,200)::bigint + and rank_search = 26 and name is not null INTO NEW.parent_place_id; END IF; - END LOOP; + END LOOP; + END IF; + END LOOP; ---RAISE WARNING 'x1'; - -- Is this node part of a way? - 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 - IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN ---RAISE WARNING 'node in way that is a street %',location; - NEW.parent_place_id := location.place_id; - END IF; - - -- Is the WAY part of a relation - 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)::bigint - and rank_search = 26 and name is not null INTO NEW.parent_place_id; - END IF; - END LOOP; - END IF; - END LOOP; - END IF; - - -- If the way contains an explicit name of a street copy it - -- Slightly less strict then above because data is copied from any object. - IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN ---RAISE WARNING 'node in way that has a streetname %',location; - NEW.street := location.street; - NEW.addr_place := location.addr_place; - END IF; - - -- If this way is a street interpolation line then it is probably as good as we are going to get - IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND NEW.addr_place IS NULL AND location.class = 'place' and location.type='houses' THEN - -- Try and find a way that is close roughly parellel to this line - FOR relation IN SELECT place_id FROM placex - WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26 - and st_geometrytype(location.geometry) in ('ST_LineString') - ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+ - ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+ - ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1 - LOOP ---RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation; - NEW.parent_place_id := relation.place_id; - END LOOP; - END IF; + -- Note that addr:street links can only be indexed once the street itself is indexed + IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(NEW.street)); + IF address_street_word_ids IS NOT NULL THEN + FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP + NEW.parent_place_id := location.place_id; END LOOP; + END IF; + END IF; + + IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place)); + IF address_street_word_ids IS NOT NULL THEN + FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP + NEW.parent_place_id := location.place_id; END LOOP; - END IF; + END IF; ---RAISE WARNING 'x2'; - - 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] 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 - 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 '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)::bigint - and rank_search = 26 and name is not null INTO NEW.parent_place_id; + IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN + +--RAISE WARNING 'x1'; + -- Is this node part of a way? search for the way in placex AND location_property_osmline (for interpolation lines) + FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.class, p.type, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w + where p.osm_type = 'W' and p.rank_search >= 26 and p.geometry && NEW.geometry and w.id = p.osm_id and NEW.osm_id = any(w.nodes) + UNION + select q.place_id, q.osm_id, q.parent_place_id, 'place' as class, 'houses' as type, 30 as rank_search, null as street, + null as addr_place from location_property_osmline q, planet_osm_ways x + where q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes) + LOOP + +--RAISE WARNING '%', location; + -- Way IS a road then we are on it - that must be our road + IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN +--RAISE WARNING 'node in way that is a street %',location; + NEW.parent_place_id := location.place_id; + END IF; + + -- If this way is a street interpolation line then it is probably as good as we are going to get + IF NEW.parent_place_id IS NULL AND location.class = 'place' and location.type='houses' THEN + NEW.parent_place_id := location.parent_place_id; + END IF; + + -- Is the WAY part of a relation + 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)::bigint + and rank_search = 26 and name is not null INTO NEW.parent_place_id; + END IF; + END LOOP; END IF; END LOOP; - END IF; - END LOOP; - END IF; - ---RAISE WARNING 'x3 %',NEW.parent_place_id; + END IF; - IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN - address_street_word_ids := get_name_ids(make_standard_name(NEW.street)); - IF address_street_word_ids IS NOT NULL THEN - FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP - NEW.parent_place_id := location.place_id; - END LOOP; + -- If the way mentions a street or place address, try that for parenting. + IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(location.street)); + IF address_street_word_ids IS NOT NULL THEN + FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP + NEW.parent_place_id := linkedplacex.place_id; + END LOOP; + END IF; END IF; - END IF; - IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN - address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place)); - IF address_street_word_ids IS NOT NULL THEN - FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP - NEW.parent_place_id := location.place_id; - END LOOP; + IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN + address_street_word_ids := get_name_ids(make_standard_name(location.addr_place)); + IF address_street_word_ids IS NOT NULL THEN + FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP + NEW.parent_place_id := linkedplacex.place_id; + END LOOP; + END IF; END IF; - END IF; + + END LOOP; + + END IF; --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 getNearestRoadFeature(NEW.partition, place_centroid) LOOP - NEW.parent_place_id := location.place_id; - END LOOP; - END IF; + -- Still nothing, just use the nearest road + 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; + 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 + -- 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); - address_havelevel[26] := true; + -- Get the details of the parent road + select * from search_name where place_id = NEW.parent_place_id INTO location; + NEW.calculated_country_code := location.country_code; - -- 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; - - -- Get the details of the parent road - select * from search_name where place_id = NEW.parent_place_id INTO location; - 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 - IF NEW.name is NULL THEN - return NEW; + -- Merge the postcode into the parent's address if necessary XXXX + IF NEW.postcode IS NOT NULL THEN + isin_tokens := '{}'::int[]; + address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode)); + IF address_street_word_id is not null + and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN + isin_tokens := isin_tokens || address_street_word_id; END IF; + address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode)); + IF address_street_word_id is not null + and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN + isin_tokens := isin_tokens || address_street_word_id; + END IF; + IF isin_tokens != '{}'::int[] THEN + UPDATE search_name + SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens + WHERE place_id = NEW.parent_place_id; + END IF; + END IF; - -- Merge address from parent - nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector); - nameaddress_vector := array_merge(nameaddress_vector, location.name_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 +--RAISE WARNING '%', NEW.name; + -- If there is no name it isn't searchable, don't bother to create a search record + IF NEW.name is NULL THEN + return NEW; + END IF; - 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; + -- Merge address from parent + nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector); + nameaddress_vector := array_merge(nameaddress_vector, location.name_vector); - 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, NEW.geometry); + -- 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 - return NEW; + IF NEW.rank_search <= 25 and NEW.rank_address > 0 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, NEW.geometry); + + return NEW; END IF; + END IF; + -- RAISE WARNING ' INDEXING Started:'; -- RAISE WARNING ' INDEXING: %',NEW; - IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN + 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; + -- 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'; - IF relation_members IS NOT NULL THEN - FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP + IF relation_members IS NOT NULL THEN + FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP - FOR linkedPlacex IN 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 LOOP + FOR linkedPlacex IN 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 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 label name, re-init word vector - IF NOT linkedPlacex.name IS NULL THEN - NEW.name := linkedPlacex.name || NEW.name; - name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name)); - END IF; + -- 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 extra tags - NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); + -- merge in the label name, re-init word vector + IF NOT linkedPlacex.name IS NULL THEN + NEW.name := linkedPlacex.name || NEW.name; + name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name)); + END IF; - -- mark the linked place (excludes from search results) - UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; + -- merge in extra tags + NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); - -- 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; + -- 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; - IF NEW.centroid IS NULL THEN + END LOOP; - FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP + IF NEW.centroid IS NULL THEN - FOR linkedPlacex IN 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 LOOP + FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP - -- 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_address = linkedPlacex.rank_address THEN + FOR linkedPlacex IN 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 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; + -- 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_address = linkedPlacex.rank_address THEN - -- merge in the name, re-init word vector - IF NOT linkedPlacex.name IS NULL THEN - NEW.name := linkedPlacex.name || NEW.name; - name_vector := make_keywords(NEW.name); - END IF; + -- 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 extra tags - NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); + -- merge in the name, re-init word vector + IF NOT linkedPlacex.name IS NULL THEN + NEW.name := linkedPlacex.name || NEW.name; + name_vector := make_keywords(NEW.name); + END IF; - -- mark the linked place (excludes from search results) - UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; + -- merge in extra tags + NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); - -- 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; + -- 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; + -- 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; - END IF; + END LOOP; + END IF; END IF; - -- Name searches can be done for ways as well as relations - IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN + 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 + -- Name searches can be done for ways as well as relations + IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN - FOR linkedPlacex IN select placex.* from placex WHERE - make_standard_name(name->'name') = make_standard_name(NEW.name->'name') - AND placex.rank_address = NEW.rank_address - 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 + -- 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 - -- 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; + FOR linkedPlacex IN select placex.* from placex WHERE + make_standard_name(name->'name') = make_standard_name(NEW.name->'name') + AND placex.rank_address = NEW.rank_address + 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 - -- merge in the name, re-init word vector - NEW.name := linkedPlacex.name || NEW.name; - name_vector := make_keywords(NEW.name); + -- 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 extra tags - NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); + -- merge in the name, re-init word vector + NEW.name := linkedPlacex.name || NEW.name; + name_vector := make_keywords(NEW.name); - -- mark the linked place (excludes from search results) - UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; + -- merge in extra tags + NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore); - -- 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; + -- mark the linked place (excludes from search results) + UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id; - IF NEW.centroid IS NOT NULL THEN - place_centroid := NEW.centroid; - -- Place might have had only a name tag before but has now received translations - -- from the linked place. Make sure a name tag for the default language exists in - -- this case. - 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 || hstore(('name:'||default_language), (NEW.name -> 'name')); - ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN - NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language))); - END IF; + -- 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; + -- Place might have had only a name tag before but has now received translations + -- from the linked place. Make sure a name tag for the default language exists in + -- this case. + 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 || hstore(('name:'||default_language), (NEW.name -> 'name')); + ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN + NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language))); END IF; END IF; 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; - -- make sure all names are in the word table - IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN - perform create_country(NEW.name, lower(NEW.country_code)); + -- 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; - NEW.parent_place_id = 0; - parent_place_id_rank = 0; + END IF; - -- convert isin to array of tokenids - isin_tokens := '{}'::int[]; - IF NEW.isin IS NOT NULL THEN - isin := regexp_split_to_array(NEW.isin, 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 - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); - isin_tokens := isin_tokens || address_street_word_id; - END IF; + -- make sure all names are in the word table + IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN + perform create_country(NEW.name, lower(NEW.country_code)); + END IF; - -- merge word into address vector - address_street_word_id := get_word_id(make_standard_name(isin[i])); - IF address_street_word_id IS NOT NULL THEN - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); - 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 - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); - isin_tokens := isin_tokens || address_street_word_id; - END IF; + NEW.parent_place_id = 0; + parent_place_id_rank = 0; - -- merge into address vector - address_street_word_id := get_word_id(make_standard_name(isin[i])); - IF address_street_word_id IS NOT NULL THEN - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); - END IF; - END LOOP; - END IF; - END IF; - -- for the USA we have an additional address table. Merge in zip codes from there too - IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN - FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP - address_street_word_id := get_name_id(make_standard_name(location.postcode)); - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); - isin_tokens := isin_tokens || address_street_word_id; + -- convert isin to array of tokenids + isin_tokens := '{}'::int[]; + IF NEW.isin IS NOT NULL THEN + isin := regexp_split_to_array(NEW.isin, 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 + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + isin_tokens := isin_tokens || address_street_word_id; + END IF; - -- also merge in the single word version - address_street_word_id := get_word_id(make_standard_name(location.postcode)); - nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + -- merge word into address vector + address_street_word_id := get_word_id(make_standard_name(isin[i])); + IF address_street_word_id IS NOT NULL THEN + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + 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 + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + isin_tokens := isin_tokens || address_street_word_id; + END IF; + + -- merge into address vector + address_street_word_id := get_word_id(make_standard_name(isin[i])); + IF address_street_word_id IS NOT NULL THEN + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + END IF; + END LOOP; + END IF; + END IF; + + -- %NOTIGERDATA% IF 0 THEN + -- for the USA we have an additional address table. Merge in zip codes from there too + IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN + FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP + address_street_word_id := get_name_id(make_standard_name(location.postcode)); + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + isin_tokens := isin_tokens || address_street_word_id; + + -- also merge in the single word version + address_street_word_id := get_word_id(make_standard_name(location.postcode)); + nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]); + END LOOP; + END IF; + -- %NOTIGERDATA% END IF; -- RAISE WARNING 'ISIN: %', isin_tokens; - -- Process area matches - location_rank_search := 0; - location_distance := 0; - location_parent := NULL; - -- added ourself as address already - address_havelevel[NEW.rank_address] := true; - -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens; - FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP + -- Process area matches + location_rank_search := 0; + location_distance := 0; + location_parent := NULL; + -- added ourself as address already + address_havelevel[NEW.rank_address] := true; + -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens; + FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP --RAISE WARNING ' AREA: %',location; - IF location.rank_address != location_rank_search THEN - location_rank_search := location.rank_address; + IF location.rank_address != location_rank_search THEN + location_rank_search := location.rank_address; + IF location.isguess THEN location_distance := location.distance * 1.5; - END IF; - - IF location.distance < location_distance OR NOT location.isguess THEN - - location_isaddress := NOT address_havelevel[location.rank_address]; - IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN - location_isaddress := ST_Contains(location_parent,location.centroid); + ELSE + IF location.rank_address <= 12 THEN + -- for county and above, if we have an area consider that exact + -- (It would be nice to relax the constraint for places close to + -- the boundary but we'd need the exact geometry for that. Too + -- expensive.) + location_distance = 0; + ELSE + -- Below county level remain slightly fuzzy. + location_distance := location.distance * 0.5; END IF; + END IF; + ELSE + CONTINUE WHEN location.keywords <@ location_keywords; + END IF; - -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress; - -- Add it to the list of search terms - IF location.rank_search > 4 THEN - nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); - END IF; - INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address); + IF location.distance < location_distance OR NOT location.isguess THEN + location_keywords := location.keywords; - IF location_isaddress THEN + location_isaddress := NOT address_havelevel[location.rank_address]; + IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN + location_isaddress := ST_Contains(location_parent,location.centroid); + END IF; - address_havelevel[location.rank_address] := true; - IF NOT location.isguess THEN - SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent; - END IF; + -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress; + -- Add it to the list of search terms + IF location.rank_search > 4 THEN + nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); + END IF; + INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address); - 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; + IF location_isaddress THEN + address_havelevel[location.rank_address] := true; + IF NOT location.isguess THEN + SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent; END IF; ---RAISE WARNING ' Terms: (%) %',location, nameaddress_vector; + 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]; - IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN - - FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP +--RAISE WARNING ' Terms: (%) %',location, nameaddress_vector; - --RAISE WARNING ' ISIN: %',location; + END IF; - IF location.rank_search > 4 THEN - 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; + 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]; + IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN - END IF; + FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP - END LOOP; - END IF; +--RAISE WARNING ' ISIN: %',location; - -- for long ways we should add search terms for the entire length - IF st_length(NEW.geometry) > 0.05 THEN + IF location.rank_search > 4 THEN + 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; - location_rank_search := 0; - location_distance := 0; + 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; - FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP + END IF; - IF location.rank_address != location_rank_search THEN - location_rank_search := location.rank_address; - location_distance := location.distance * 1.5; - END IF; + END LOOP; + END IF; - IF location.rank_search > 4 AND location.distance < location_distance THEN + -- for long ways we should add search terms for the entire length + IF st_length(NEW.geometry) > 0.05 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); + location_rank_search := 0; + location_distance := 0; - END IF; + FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP - END LOOP; + IF location.rank_address != location_rank_search THEN + location_rank_search := location.rank_address; + location_distance := location.distance * 1.5; + END IF; - END IF; + IF location.rank_search > 4 AND location.distance < location_distance THEN - -- if we have a name add this to the name search table - IF NEW.name IS NOT NULL 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); - 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; + END LOOP; - 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, NEW.geometry); + 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 <= 25 and NEW.rank_address > 0 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 we've not managed to pick up a better one - default centroid - IF NEW.centroid IS NULL THEN - NEW.centroid := place_centroid; + 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.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry); + END IF; + -- 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; + RETURN NEW; END; $$ @@ -1977,6 +1847,8 @@ BEGIN --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; + -- reparenting also for OSM Interpolation Lines (and for Tiger?) + update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id; END IF; @@ -2033,6 +1905,11 @@ BEGIN -- 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; + -- interpolations are special + IF OLD.class = 'place' and OLD.type = 'houses' THEN + UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id) + END IF; + RETURN OLD; END; @@ -2045,6 +1922,7 @@ DECLARE i INTEGER; existing RECORD; existingplacex RECORD; + existingline RECORD; existinggeometry GEOMETRY; existingplace_id BIGINT; result BOOLEAN; @@ -2053,309 +1931,305 @@ BEGIN --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; - --DEBUG: RAISE WARNING '%', existingplacex; - END IF; - - -- Just block these - lots and pointless - IF NEW.class in ('landuse','natural') and NEW.name is null THEN - -- if the name tag was removed, older versions might still be lurking in the place table - DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; - RETURN null; - END IF; - + RAISE WARNING 'X3366 - place_isnert'; + -- filter wrong tupels 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 - 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; + + -- decide, whether its an osm interpolation line => insert_osmline, or else just insert into placex + IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN + -- Have we already done this place? + select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing; - -- Have we already done this place? - select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing; - - -- Get the existing place_id - 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 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; - - --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; - - -- To paraphrase, if there isn't an existing item, OR if the admin level has changed - IF existingplacex.osm_type IS NULL OR - (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative') - THEN - - IF existingplacex.osm_type IS NOT NULL THEN - -- sanity check: ignore admin_level changes on places with too many active children - -- or we end up reindexing entire countries because somebody accidentally deleted admin_level - --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i; - --LIMIT INDEXING: IF i > 100000 THEN - --LIMIT INDEXING: RETURN null; - --LIMIT INDEXING: END IF; - END IF; - - IF existing.osm_type IS NOT NULL THEN - -- pathological case caused by the triggerless copy into place during initial import - -- force delete even for large areas, it will be reinserted later - UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; - 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 (osm_type, osm_id, class, type, name, admin_level, housenumber, - street, addr_place, isin, postcode, country_code, extratags, geometry) - values (NEW.osm_type - ,NEW.osm_id - ,NEW.class - ,NEW.type - ,NEW.name - ,NEW.admin_level - ,NEW.housenumber - ,NEW.street - ,NEW.addr_place - ,NEW.isin - ,NEW.postcode - ,NEW.country_code - ,NEW.extratags - ,NEW.geometry - ); - - --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name; - - RETURN NEW; - END IF; - - -- Various ways to do the update - - -- Debug, what's changed? - 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; - IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN - RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber; - END IF; - IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN - RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street; + -- Get the existing place_id + select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline; + + -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel) + -- 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 THEN + DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class; END IF; - IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN - RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place; + + 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; + + -- To paraphrase, if there isn't an existing item + IF existingline.osm_id IS NULL THEN + IF existing.osm_type IS NOT NULL THEN + -- pathological case caused by the triggerless copy into place during initial import + -- force delete even for large areas, it will be reinserted later + UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + 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; + -- insert new line into location_property_osmline, use function insert_osmline + i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry); + RETURN NEW; END IF; - IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN - RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin; + 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.addr_place, '') != coalesce(NEW.addr_place, '') + OR coalesce(existing.isin, '') != coalesce(NEW.isin, '') + OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') + OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') + OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15) + OR existing.geometry::text != NEW.geometry::text + THEN + + update place set + name = NEW.name, + housenumber = NEW.housenumber, + street = NEW.street, + addr_place = NEW.addr_place, + isin = NEW.isin, + postcode = NEW.postcode, + country_code = NEW.country_code, + extratags = NEW.extratags, + admin_level = NEW.admin_level, + geometry = NEW.geometry + where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + + -- update method for interpolation lines: delete all old interpolation lines with same osm_id (update on place) and insert the new one(s) (they can be split up, if they have > 2 nodes) + delete from location_property_osmline where osm_id = NEW.osm_id; + i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry); END IF; - IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN - RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode; + + -- for interpolations invalidate all nodes on the line + update placex p set indexed_status = 2 from planet_osm_ways w where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes); + RAISE WARNING 'X3399 - updated nodes of interpolation line'; + RETURN NULL; + + ELSE -- insert to placex + + 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; + --DEBUG: RAISE WARNING '%', existingplacex; END IF; - IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN - RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code; + -- Patch in additional country names + 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; - 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::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 - - -- 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; + + -- Have we already done this place? + select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing; - -- Performance limit - IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN + -- Get the existing place_id + 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; - -- 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_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); + -- Handle a place changing type by removing the old data + -- 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 THEN + DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class; + END IF; - update placex set indexed_status = 2 where indexed_status = 0 and - (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); + --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; - 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; - -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing - IF FALSE AND existingplacex.rank_search < 26 - AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '') - AND coalesce(existing.street, '') = coalesce(NEW.street, '') - AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '') - AND coalesce(existing.isin, '') = coalesce(NEW.isin, '') - AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '') - AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '') - AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') - THEN + -- To paraphrase, if there isn't an existing item, OR if the admin level has changed + IF existingplacex.osm_type IS NULL OR + (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative') + THEN - IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN + IF existingplacex.osm_type IS NOT NULL THEN + -- sanity check: ignore admin_level changes on places with too many active children + -- or we end up reindexing entire countries because somebody accidentally deleted admin_level + --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i; + --LIMIT INDEXING: IF i > 100000 THEN + --LIMIT INDEXING: RETURN null; + --LIMIT INDEXING: END IF; + END IF; - 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 (rank_search < 28 or name is not null); + IF existing.osm_type IS NOT NULL THEN + -- pathological case caused by the triggerless copy into place during initial import + -- force delete even for large areas, it will be reinserted later + UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + 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 (osm_type, osm_id, class, type, name, admin_level, housenumber, + street, addr_place, isin, postcode, country_code, extratags, geometry) + values (NEW.osm_type + ,NEW.osm_id + ,NEW.class + ,NEW.type + ,NEW.name + ,NEW.admin_level + ,NEW.housenumber + ,NEW.street + ,NEW.addr_place + ,NEW.isin + ,NEW.postcode + ,NEW.country_code + ,NEW.extratags + ,NEW.geometry + ); + + --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name; + + RETURN NEW; END IF; - - ELSE - -- Anything else has changed - reindex the lot - IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') - OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') - OR coalesce(existing.street, '') != coalesce(NEW.street, '') - OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') - OR coalesce(existing.isin, '') != coalesce(NEW.isin, '') - OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') - OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN - - -- 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; - END IF; + -- Various ways to do the update + -- Debug, what's changed? + 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; + IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN + RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber; + END IF; + IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN + RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street; + END IF; + IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN + RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place; + END IF; + IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN + RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin; + END IF; + IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN + RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode; + END IF; + IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN + RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code; + END IF; END IF; - 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::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 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.addr_place, '') != coalesce(NEW.addr_place, '') - OR coalesce(existing.isin, '') != coalesce(NEW.isin, '') - OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') - OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') - OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15) - OR existing.geometry::text != NEW.geometry::text - THEN + -- 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; - update place set - name = NEW.name, - housenumber = NEW.housenumber, - street = NEW.street, - addr_place = NEW.addr_place, - isin = NEW.isin, - postcode = NEW.postcode, - country_code = NEW.country_code, - extratags = NEW.extratags, - admin_level = NEW.admin_level, - geometry = NEW.geometry - where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + -- Performance limit + IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN - IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN - IF NEW.postcode IS NULL THEN - -- postcode was deleted, no longer retain in placex - DELETE FROM placex where place_id = existingplacex.place_id; - RETURN NULL; - END IF; + -- 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_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_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; - NEW.name := hstore('ref', NEW.postcode); END IF; - update placex set - name = NEW.name, - housenumber = NEW.housenumber, - street = NEW.street, - addr_place = NEW.addr_place, - isin = NEW.isin, - postcode = NEW.postcode, - country_code = NEW.country_code, - parent_place_id = null, - extratags = NEW.extratags, - admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END, - indexed_status = 2, - geometry = NEW.geometry - where place_id = existingplacex.place_id; - 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.addr_place, '') != coalesce(NEW.addr_place, '') + OR coalesce(existing.isin, '') != coalesce(NEW.isin, '') + OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') + OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') + OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15) + OR existing.geometry::text != NEW.geometry::text + THEN + + update place set + name = NEW.name, + housenumber = NEW.housenumber, + street = NEW.street, + addr_place = NEW.addr_place, + isin = NEW.isin, + postcode = NEW.postcode, + country_code = NEW.country_code, + extratags = NEW.extratags, + admin_level = NEW.admin_level, + geometry = NEW.geometry + where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + + IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN + IF NEW.postcode IS NULL THEN + -- postcode was deleted, no longer retain in placex + DELETE FROM placex where place_id = existingplacex.place_id; + RETURN NULL; + END IF; - -- Abort the add (we modified the existing place instead) - RETURN NULL; + NEW.name := hstore('ref', NEW.postcode); + END IF; + + update placex set + name = NEW.name, + housenumber = NEW.housenumber, + street = NEW.street, + addr_place = NEW.addr_place, + isin = NEW.isin, + postcode = NEW.postcode, + country_code = NEW.country_code, + parent_place_id = null, + extratags = NEW.extratags, + admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END, + indexed_status = 2, + geometry = NEW.geometry + where place_id = existingplacex.place_id; + + END IF; + + -- Abort the add (we modified the existing place instead) + RETURN NULL; + END IF; END; $$ LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT AS $$ DECLARE - search TEXT[]; - found BOOLEAN; + result TEXT; BEGIN - IF name is null THEN RETURN null; END IF; - search := languagepref; - - FOR j IN 1..array_upper(search, 1) LOOP - IF name ? search[j] AND trim(name->search[j]) != '' THEN - return trim(name->search[j]); + FOR j IN 1..array_upper(languagepref,1) LOOP + IF name ? languagepref[j] THEN + result := trim(name->languagepref[j]); + IF result != '' THEN + return result; + END IF; END IF; END LOOP; -- anything will do as a fallback - just take the first name type thing there is - search := avals(name); - RETURN search[1]; + RETURN trim((avals(name))[1]); END; $$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways - AS $$ -DECLARE - searchnodes INTEGER[]; - location RECORD; - j INTEGER; -BEGIN - - searchnodes := '{}'; - FOR j IN 1..array_upper(way_ids, 1) LOOP - FOR location IN - select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1 - LOOP - IF not (ARRAY[location.nodes] <@ searchnodes) THEN - searchnodes := searchnodes || location.nodes; - END IF; - END LOOP; - END LOOP; - - RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids; -END; -$$ -LANGUAGE plpgsql IMMUTABLE; CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT AS $$ @@ -2396,7 +2270,8 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT +--housenumber only needed for tiger data +CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT AS $$ DECLARE result TEXT[]; @@ -2408,7 +2283,7 @@ BEGIN result := '{}'; prevresult := ''; - FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP + FOR location IN select * from get_addressdata(for_place_id, housenumber) 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 AND result[(100 - location.rank_address)] IS NULL THEN result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref)); @@ -2436,7 +2311,7 @@ create type addressline as ( distance FLOAT ); -CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline +CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline AS $$ DECLARE for_place_id BIGINT; @@ -2455,16 +2330,33 @@ DECLARE countryname HSTORE; hadcountry BOOLEAN; BEGIN + -- first query osmline (interpolation lines) + select parent_place_id, calculated_country_code, 30, postcode, null, 'place', 'house' from location_property_osmline + WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber + INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + IF for_place_id IS NOT NULL THEN + searchhousenumber = in_housenumber::text; + END IF; - 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; + --then query tiger data + -- %NOTIGERDATA% IF 0 THEN + IF for_place_id IS NULL THEN + select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger + WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber + INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; + IF for_place_id IS NOT NULL THEN + searchhousenumber = in_housenumber::text; + END IF; + END IF; + -- %NOTIGERDATA% END IF; + -- %NOAUXDATA% IF 0 THEN IF for_place_id IS NULL THEN select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux WHERE place_id = in_place_id INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; END IF; + -- %NOAUXDATA% END IF; IF for_place_id IS NULL THEN select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex @@ -2473,9 +2365,10 @@ BEGIN END IF; IF for_place_id IS NULL THEN - for_place_id := in_place_id; - select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id - INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename; + select coalesce(linked_place_id, place_id), calculated_country_code, + housenumber, rank_search, postcode, null + from placex where place_id = in_place_id + INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename; END IF; --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode; @@ -2595,86 +2488,10 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox - AS $$ -DECLARE - result place_boundingbox; - numfeatures integer; -BEGIN - select * from place_boundingbox into result where place_id = search_place_id; - IF result.place_id IS NULL THEN --- remove isaddress = true because if there is a matching polygon it always wins - select count(*) from place_addressline where address_place_id = search_place_id into numfeatures; - insert into place_boundingbox select place_id, - ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)), - ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)), - numfeatures, ST_Area(geometry), - geometry as area from location_area where place_id = search_place_id; - select * from place_boundingbox into result where place_id = search_place_id; - END IF; - IF result.place_id IS NULL THEN --- TODO 0.0001 - insert into place_boundingbox select address_place_id, - min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon, - min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat, - count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area, - ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary - from (select * from place_addressline where address_place_id = search_place_id order by cached_rank_address limit 4000) as place_addressline join placex using (place_id) - where address_place_id = search_place_id --- and (isaddress = true OR place_id = search_place_id) - and (st_length(geometry) < 0.01 or place_id = search_place_id) - group by address_place_id limit 1; - select * from place_boundingbox into result where place_id = search_place_id; - END IF; - return result; -END; -$$ -LANGUAGE plpgsql; - --- don't do the operation if it would be slow -CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox - AS $$ -DECLARE - result place_boundingbox; - numfeatures integer; - rank integer; -BEGIN - select * from place_boundingbox into result where place_id = search_place_id; - IF result IS NULL AND rank > 14 THEN - select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures; - insert into place_boundingbox select place_id, - ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)), - ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)), - numfeatures, ST_Area(geometry), - geometry as area from location_area where place_id = search_place_id; - select * from place_boundingbox into result where place_id = search_place_id; - END IF; - IF result IS NULL THEN - select rank_search from placex where place_id = search_place_id into rank; - IF rank > 20 THEN --- TODO 0.0001 - insert into place_boundingbox select address_place_id, - min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon, - min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat, - count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area, - ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary - from place_addressline join placex using (place_id) - where address_place_id = search_place_id - and (isaddress = true OR place_id = search_place_id) - and (st_length(geometry) < 0.01 or place_id = search_place_id) - group by address_place_id limit 1; - select * from place_boundingbox into result where place_id = search_place_id; - END IF; - END IF; - return result; -END; -$$ -LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN AS $$ DECLARE - result place_boundingbox; numfeatures integer; BEGIN update placex set @@ -2787,42 +2604,6 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT - AS $$ -DECLARE - trigramtoken TEXT; - result TEXT; -BEGIN - - trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g'); - SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result; - - return result; -END; -$$ -LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[] - AS $$ -DECLARE - trigramtoken TEXT; - result TEXT[]; - r RECORD; -BEGIN - - trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g'); - - FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word - WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4 - LOOP - result[coalesce(array_upper(result,1)+1,1)] := r.word; - END LOOP; - - return result; -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 $$ @@ -2954,14 +2735,14 @@ BEGIN 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 := 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 + IF strpos(wiki_article, ':') IN (3,4) THEN + wiki_article_language := lower(trim(split_part(wiki_article, ':', 1))); + wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1)); + ELSE 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