X-Git-Url: https://git.openstreetmap.org./nominatim.git/blobdiff_plain/b9a3e52a67fe664ded2ef56b5ef8638aec351258..d396505786ce3be105249c740e0d3365beb4ef10:/sql/functions.sql diff --git a/sql/functions.sql b/sql/functions.sql index ec25c7fa..25769785 100644 --- a/sql/functions.sql +++ b/sql/functions.sql @@ -52,35 +52,14 @@ DECLARE NEWgeometry geometry; BEGIN -- RAISE WARNING '%',place; - NEWgeometry := place; - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - NEWgeometry := ST_buffer(NEWgeometry,0); - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - RETURN 0; - END IF; - END IF; - RETURN (partition*1000000) + (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer); -END; -$$ -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER - AS $$ -DECLARE - NEWgeometry geometry; -BEGIN --- RAISE WARNING '%',osmid; - IF osmid = 61315 THEN - return null; - END IF; - NEWgeometry := place; - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - NEWgeometry := ST_buffer(NEWgeometry,0); - IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN - RETURN NULL; - END IF; - END IF; - RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer); + NEWgeometry := ST_PointOnSurface(place); +-- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN +-- NEWgeometry := ST_buffer(NEWgeometry,0); +-- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN +-- RETURN 0; +-- END IF; +-- END IF; + RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer); END; $$ LANGUAGE plpgsql IMMUTABLE; @@ -389,7 +368,7 @@ BEGIN result := '{}'::INTEGER[]; s := make_standard_name(src); - w := getorcreate_name_id(s); + w := getorcreate_name_id(s, src); IF NOT (ARRAY[w] <@ result) THEN result := result || w; @@ -407,6 +386,30 @@ BEGIN END LOOP; END IF; + words := regexp_split_to_array(src, E'[,;()]'); + IF array_upper(words, 1) != 1 THEN + FOR j IN 1..array_upper(words, 1) LOOP + s := make_standard_name(words[j]); + IF s != '' THEN + w := getorcreate_word_id(s); + IF NOT (ARRAY[w] <@ result) THEN + result := result || w; + END IF; + END IF; + END LOOP; + END IF; + + s := regexp_replace(src, '市$', ''); + IF s != src THEN + s := make_standard_name(s); + IF s != '' THEN + w := getorcreate_name_id(s, src); + IF NOT (ARRAY[w] <@ result) THEN + result := result || w; + END IF; + END IF; + END IF; + RETURN result; END; $$ @@ -443,54 +446,63 @@ DECLARE place_centre GEOMETRY; nearcountry RECORD; BEGIN - place_centre := ST_Centroid(place); + place_centre := ST_PointOnSurface(place); ---RAISE WARNING 'start: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre); - -- Try for a OSM polygon first - FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_contains(geometry, place_centre) limit 1 +--DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre); + + -- Try for OSM fallback data + -- The order is to deal with places like HongKong that are 'states' within another polygon + FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'osm fallback: %', ST_AsText(place_centre); - - -- Try for OSM fallback data - FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1 + -- Try for a OSM polygon + FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'natural earth: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre); - -- Natural earth data (first fallback) - FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1 + -- Natural earth data + FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1 LOOP RETURN nearcountry.country_code; END LOOP; - -- Natural earth data (first fallback) - FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1 +--DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre); + + -- + FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1 LOOP RETURN nearcountry.country_code; END LOOP; ---RAISE WARNING 'in country: %', ST_AsText(place_centre); +--DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre); - -- WorldBoundaries data (second fallback - think there might be something broken in this data) - FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1 + -- Natural earth data + FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1 LOOP RETURN nearcountry.country_code; END LOOP; + -- WorldBoundaries data (second fallback - think there might be something broken in this data) +-- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1 +-- LOOP +-- RETURN nearcountry.country_code; +-- END LOOP; + --RAISE WARNING 'near country: %', ST_AsText(place_centre); -- Still not in a country - try nearest within ~12 miles of a country - FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5 - order by st_distance(geometry, place) limit 1 - LOOP - RETURN nearcountry.country_code; - END LOOP; +-- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5 +-- order by st_distance(geometry, place) limit 1 +-- LOOP +-- RETURN nearcountry.country_code; +-- END LOOP; RETURN NULL; END; @@ -565,17 +577,11 @@ CREATE OR REPLACE FUNCTION add_location( DECLARE locationid INTEGER; isarea BOOLEAN; - xmin INTEGER; - ymin INTEGER; - xmax INTEGER; - ymax INTEGER; - lon INTEGER; - lat INTEGER; centroid GEOMETRY; - secgeo GEOMETRY; - secbox GEOMETRY; diameter FLOAT; x BOOLEAN; + splitGeom RECORD; + secgeo GEOMETRY; BEGIN IF rank_search > 25 THEN @@ -592,27 +598,9 @@ BEGIN isArea := true; centroid := ST_Centroid(geometry); - xmin := floor(st_xmin(geometry)); - xmax := ceil(st_xmax(geometry)); - ymin := floor(st_ymin(geometry)); - ymax := ceil(st_ymax(geometry)); - - IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN - x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry); - ELSE --- RAISE WARNING 'Spliting geometry: % to %, % to %', xmin, xmax, ymin, ymax; - FOR lon IN xmin..(xmax-1) LOOP - FOR lat IN ymin..(ymax-1) LOOP - secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326); - IF st_intersects(geometry, secbox) THEN - secgeo := st_intersection(geometry, secbox); - IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN - x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo); - END IF; - END IF; - END LOOP; - END LOOP; - END IF; + FOR secgeo IN select split_geometry(geometry) AS geom LOOP + x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo); + END LOOP; ELSEIF rank_search < 26 THEN @@ -781,6 +769,13 @@ BEGIN -- null record of right type select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER 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; @@ -877,7 +872,7 @@ DECLARE diameter FLOAT; classtable TEXT; BEGIN --- RAISE WARNING '%',NEW.osm_id; + --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id; -- just block these IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN @@ -891,7 +886,7 @@ BEGIN 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; + RAISE WARNING 'invalid geometry %',NEW.osm_id; RETURN NULL; -- Dead code @@ -901,26 +896,24 @@ BEGIN 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; + 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; + NEW.place_id := nextval('seq_place'); NEW.indexed_status := 1; --STATUS_NEW - IF NEW.rank_search >= 4 THEN - NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code)); - ELSE - NEW.country_code := NULL; - END IF; + NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code)); - NEW.partition := get_partition(NEW.geometry, NEW.country_code); + NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code); NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry); -- copy 'name' to or from the default language (if there is a default language) IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN - default_language := get_country_language_code(NEW.country_code); + default_language := get_country_language_code(NEW.calculated_country_code); IF default_language IS NOT NULL THEN IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name')); @@ -954,7 +947,7 @@ BEGIN NEW.name := 'ref'=>NEW.postcode; - IF NEW.country_code = 'gb' THEN + IF NEW.calculated_country_code = 'gb' THEN IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN NEW.rank_search := 25; @@ -967,7 +960,7 @@ BEGIN NEW.rank_address := 5; END IF; - ELSEIF NEW.country_code = 'de' THEN + ELSEIF NEW.calculated_country_code = 'de' THEN IF NEW.postcode ~ '^([0-9]{5})$' THEN NEW.rank_search := 21; @@ -997,9 +990,11 @@ BEGIN IF NEW.type in ('continent') THEN NEW.rank_search := 2; NEW.rank_address := NEW.rank_search; + NEW.calculated_country_code := NULL; ELSEIF NEW.type in ('sea') THEN NEW.rank_search := 2; NEW.rank_address := 0; + NEW.calculated_country_code := NULL; ELSEIF NEW.type in ('country') THEN NEW.rank_search := 4; NEW.rank_address := NEW.rank_search; @@ -1114,7 +1109,12 @@ BEGIN END IF; IF (NEW.extratags -> 'capital') = 'yes' THEN - NEW.rank_search := NEW.rank_search -1; + NEW.rank_search := NEW.rank_search - 1; + END IF; + + -- a country code make no sense below rank 4 (country) + IF NEW.rank_address < 4 THEN + NEW.calculated_country_code := NULL; END IF; -- Block import below rank 22 @@ -1122,7 +1122,9 @@ BEGIN -- RETURN NULL; -- END IF; - RETURN NEW; -- The following is not needed until doing diff updates, and slows the main index process down + --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; + + RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN -- Performance: We just can't handle re-indexing for country level changes @@ -1131,9 +1133,9 @@ BEGIN -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547) - update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null); - update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null); END IF; ELSE @@ -1218,6 +1220,8 @@ DECLARE location_rank_search INTEGER; location_distance FLOAT; + location_parent GEOMETRY; + location_isaddress BOOLEAN; tagpairid INTEGER; @@ -1230,6 +1234,12 @@ DECLARE result BOOLEAN; BEGIN + IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN + RETURN NEW; + END IF; + + --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id; + --RAISE WARNING '%',NEW.place_id; --RAISE WARNING '%', NEW; @@ -1240,11 +1250,13 @@ BEGIN -- deferred delete IF OLD.indexed_status = 100 THEN + --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id; delete from placex where place_id = OLD.place_id; RETURN NULL; END IF; - IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN + IF OLD.indexed_status != 0 THEN + --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id; NEW.indexed_date = now(); @@ -1253,7 +1265,7 @@ BEGIN RETURN NEW; END IF; - IF OLD.indexed_status > 1 THEN + IF OLD.indexed_status > 0 THEN result := deleteSearchName(NEW.partition, NEW.place_id); DELETE FROM place_addressline WHERE place_id = NEW.place_id; DELETE FROM place_boundingbox where place_id = NEW.place_id; @@ -1262,15 +1274,20 @@ BEGIN UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id; END IF; - -- reclaculate country and partition (should probably have a country_code and calculated_country_code as seperate fields) + -- 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 - SELECT country_code from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO NEW.country_code; - NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code)); + --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.country_code := NULL; + NEW.calculated_country_code := NULL; END IF; - NEW.partition := get_partition(NEW.geometry, NEW.country_code); - NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry); + NEW.partition := get_partition(place_centroid, NEW.calculated_country_code); + NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid); -- Adding ourselves to the list simplifies address calculations later INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address); @@ -1278,15 +1295,10 @@ BEGIN -- What level are we searching from search_maxrank := NEW.rank_search; - -- Speed up searches - just use the centroid of the feature - -- cheaper but less acurate - place_centroid := ST_Centroid(NEW.geometry); - NEW.centroid := null; - -- 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.country_code); + default_language := get_country_language_code(NEW.calculated_country_code); IF default_language IS NOT NULL THEN IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name')); @@ -1311,12 +1323,12 @@ BEGIN END LOOP; NEW.importance := null; - select language||':'||title,importance from get_wikipedia_match(NEW.extratags) INTO NEW.wikipedia,NEW.importance; + 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 '% %', NEW.place_id, NEW.rank_search; +--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 @@ -1456,7 +1468,7 @@ BEGIN -- Get the details of the parent road select * from search_name where place_id = NEW.parent_place_id INTO location; - NEW.country_code := location.country_code; + NEW.calculated_country_code := location.country_code; --RAISE WARNING '%', NEW.name; -- If there is no name it isn't searchable, don't bother to create a search record @@ -1471,16 +1483,17 @@ BEGIN -- Just be happy with inheriting from parent road only IF NEW.rank_search <= 25 THEN - result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); + 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.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); + result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); 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 @@ -1488,10 +1501,11 @@ BEGIN -- see if we have any special relation members select members from planet_osm_rels where id = NEW.osm_id INTO relation_members; +-- RAISE WARNING 'get_osm_rel_members, label'; FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP - select * from placex where osm_type = upper(substring(relMember.member,1,1)) - and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex; + select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1) + and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex; -- If we don't already have one use this as the centre point of the geometry IF NEW.centroid IS NULL THEN @@ -1514,14 +1528,15 @@ BEGIN FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP - select * from placex where osm_type = upper(substring(relMember.member,1,1)) - and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex; + select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1) + and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex; -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york' -- But that can be fixed by explicitly setting the label in the data IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name') AND NEW.rank_search = linkedPlacex.rank_search THEN + -- If we don't already have one use this as the centre point of the geometry IF NEW.centroid IS NULL THEN NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry)); @@ -1552,8 +1567,8 @@ BEGIN make_standard_name(name->'name') = make_standard_name(NEW.name->'name') AND placex.rank_search = NEW.rank_search AND placex.place_id != NEW.place_id - AND placex.osm_type = 'N' AND placex.rank_search < 26 - AND st_contains(NEW.geometry, placex.geometry) + AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26 + AND st_covers(NEW.geometry, placex.geometry) LOOP -- If we don't already have one use this as the centre point of the geometry @@ -1582,11 +1597,11 @@ BEGIN -- 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) INTO NEW.wikipedia,NEW.importance; + 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' and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance; + 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; @@ -1618,27 +1633,40 @@ BEGIN END LOOP; END IF; END IF; ---RAISE WARNING 'ISIN: %', isin_tokens; +-- RAISE WARNING 'ISIN: %', isin_tokens; -- Process area matches - location_rank_search := 100; + location_rank_search := 0; location_distance := 0; ---RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens; + location_parent := NULL; + -- 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_search < location_rank_search THEN - location_rank_search := location.rank_search; + IF location.rank_address != location_rank_search THEN + location_rank_search := location.rank_address; 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); + END IF; + + -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress; -- Add it to the list of search terms nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]); - INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address); - address_havelevel[location.rank_address] := true; + INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address); + + 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; + END IF; --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector; @@ -1677,13 +1705,13 @@ BEGIN -- for long ways we should add search terms for the entire length IF st_length(NEW.geometry) > 0.05 THEN - location_rank_search := 100; + location_rank_search := 0; location_distance := 0; FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP - IF location.rank_search < location_rank_search THEN - location_rank_search := location.rank_search; + IF location.rank_address != location_rank_search THEN + location_rank_search := location.rank_address; location_distance := location.distance * 1.5; END IF; @@ -1703,16 +1731,16 @@ BEGIN IF NEW.name IS NOT NULL THEN IF NEW.rank_search <= 25 THEN - result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry); + 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.country_code, NEW.geometry); + result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry); END IF; - result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); + result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid); --- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid); +-- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid); END IF; -- If we've not managed to pick up a better one - default centroid @@ -1733,34 +1761,50 @@ DECLARE b BOOLEAN; classtable TEXT; BEGIN + -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id; update placex set linked_place_id = null where linked_place_id = OLD.place_id; + --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id; update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id; IF OLD.rank_address < 30 THEN -- mark everything linked to this place for re-indexing + --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id; UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id; DELETE FROM place_addressline where address_place_id = OLD.place_id; + --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id; b := deleteRoad(OLD.partition, OLD.place_id); + --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id; update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0; + --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id; END IF; + --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id; + IF OLD.rank_address < 26 THEN b := deleteLocationArea(OLD.partition, OLD.place_id); END IF; + --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id; + IF OLD.name is not null THEN b := deleteSearchName(OLD.partition, OLD.place_id); END IF; + --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id; + DELETE FROM place_addressline where place_id = OLD.place_id; + --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id; + -- remove from tables for special search classtable := 'place_classtype_' || OLD.class || '_' || OLD.type; SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b; @@ -1768,6 +1812,8 @@ BEGIN EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id; END IF; + --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id; + RETURN OLD; END; @@ -1780,10 +1826,10 @@ DECLARE placeid BIGINT; BEGIN --- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type; + --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type; - -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through - IF st_area(OLD.geometry) > 2 THEN + -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through + IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type); RETURN NULL; END IF; @@ -1791,7 +1837,6 @@ 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; --- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type; RETURN OLD; END; @@ -1810,11 +1855,12 @@ DECLARE partition INTEGER; 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 - RAISE WARNING '-----------------------------------------------------------------------------------'; - RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry); select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex; - RAISE WARNING '%', existingplacex; + --DEBUG: RAISE WARNING '%', existingplacex; END IF; -- Just block these - lots and pointless @@ -1834,7 +1880,7 @@ BEGIN -- Patch in additional country names IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN - select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name; + select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name; END IF; -- Have we already done this place? @@ -1850,7 +1896,8 @@ BEGIN DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses'); END IF; --- RAISE WARNING 'Existing: %',existing.place_id; + --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) @@ -1867,29 +1914,11 @@ BEGIN 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, OR if it is a major change in geometry - IF existing.osm_type IS NULL - OR existingplacex.osm_type IS NULL - OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100) - OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') - OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT - (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon'))) - THEN - --- IF existing.osm_type IS NULL THEN --- RAISE WARNING 'no existing place'; --- END IF; --- IF existingplacex.osm_type IS NULL THEN --- RAISE WARNING 'no existing placex %', existingplacex; --- END IF; - --- RAISE WARNING 'delete and replace'; + IF existingplacex.osm_type IS NULL THEN IF existing.osm_type IS NOT NULL THEN --- RAISE WARNING 'insert delete % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)),existing; - DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; - END IF; - --- RAISE WARNING 'delete and replace2'; + DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type; + END IF; -- No - process it as a new insertion (hopefully of low rank or it will be slow) insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber, @@ -1909,7 +1938,7 @@ BEGIN ,NEW.geometry ); --- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type; + --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name; RETURN NEW; END IF; @@ -1952,13 +1981,13 @@ BEGIN -- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong update placex set indexed_status = 2 where indexed_status = 0 and - (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) - AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) + (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null); update placex set indexed_status = 2 where indexed_status = 0 and - (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry)) - AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry)) + (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; @@ -2012,6 +2041,7 @@ BEGIN 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 @@ -2039,10 +2069,6 @@ BEGIN geometry = NEW.geometry where place_id = existingplacex.place_id; --- now done as part of insert --- partition := get_partition(NEW.geometry, existingplacex.country_code); --- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry); - END IF; -- Abort the add (we modified the existing place instead) @@ -2209,14 +2235,14 @@ BEGIN END IF; IF for_place_id IS NULL THEN - select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex + select parent_place_id, calculated_country_code, housenumber, rank_address, postcode, name, class, type from placex WHERE place_id = in_place_id and rank_address = 30 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype; END IF; IF for_place_id IS NULL THEN for_place_id := in_place_id; - select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id + select calculated_country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename; END IF; @@ -2229,13 +2255,13 @@ BEGIN CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name, class, type, admin_level, true as fromarea, true as isaddress, CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, - 0 as distance, country_code + 0 as distance, calculated_country_code from placex where place_id = for_place_id LOOP --RAISE WARNING '%',location; - IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN - searchcountrycode := location.country_code; + IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN + searchcountrycode := location.calculated_country_code; END IF; IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN location.isaddress := FALSE; @@ -2262,17 +2288,17 @@ BEGIN CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name, class, type, admin_level, fromarea, isaddress, CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address, - distance,country_code + distance,calculated_country_code from place_addressline join placex on (address_place_id = placex.place_id) where place_addressline.place_id = for_place_id and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress) and address_place_id != for_place_id - and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4) + and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode) order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc LOOP --RAISE WARNING '%',location; - IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN - searchcountrycode := location.country_code; + IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN + searchcountrycode := location.calculated_country_code; END IF; IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN location.isaddress := FALSE; @@ -2756,7 +2782,7 @@ create type wikipedia_article_match as ( importance FLOAT ); -CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE) RETURNS wikipedia_article_match +CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match AS $$ DECLARE langs TEXT[]; @@ -2766,18 +2792,22 @@ DECLARE wiki_article_language TEXT; result wikipedia_article_match; BEGIN - langs := ARRAY['','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh']; + langs := ARRAY['english','country','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh']; i := 1; WHILE langs[i] IS NOT NULL LOOP - wiki_article := extratags->(case when langs[i] = '' THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END); + wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END); IF wiki_article is not null THEN - wiki_article := replace(regexp_replace(wiki_article,E'(.*?)([a-z]+).wikipedia.org/wiki/',E'\\2:'),' ','_'); - wiki_article_title := split_part(wiki_article, ':', 2); + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:'); + wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:'); + wiki_article := replace(wiki_article,' ','_'); + wiki_article_title := trim(split_part(wiki_article, ':', 2)); IF wiki_article_title IS NULL OR wiki_article_title = '' THEN - wiki_article_title := wiki_article; - wiki_article_language := CASE WHEN langs[i] = '' THEN 'en' ELSE langs[i] END; + 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(split_part(wiki_article, ':', 1)); + wiki_article_language := lower(trim(split_part(wiki_article, ':', 1))); END IF; select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance @@ -2801,3 +2831,101 @@ BEGIN END; $$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER) + RETURNS SETOF GEOMETRY + AS $$ +DECLARE + xmin FLOAT; + ymin FLOAT; + xmax FLOAT; + ymax FLOAT; + xmid FLOAT; + ymid FLOAT; + secgeo GEOMETRY; + secbox GEOMETRY; + seg INTEGER; + geo RECORD; + area FLOAT; + remainingdepth INTEGER; + added INTEGER; + +BEGIN + +-- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth; + + IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN + RETURN NEXT geometry; + RETURN; + END IF; + + remainingdepth := maxdepth - 1; + area := ST_AREA(geometry); + IF remainingdepth < 1 OR area < maxarea THEN + RETURN NEXT geometry; + RETURN; + END IF; + + xmin := st_xmin(geometry); + xmax := st_xmax(geometry); + ymin := st_ymin(geometry); + ymax := st_ymax(geometry); + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326); + + -- if the geometry completely covers the box don't bother to slice any more + IF ST_AREA(secbox) = area THEN + RETURN NEXT geometry; + RETURN; + END IF; + + xmid := (xmin+xmax)/2; + ymid := (ymin+ymax)/2; + + added := 0; + FOR seg IN 1..4 LOOP + + IF seg = 1 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326); + END IF; + IF seg = 2 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326); + END IF; + IF seg = 3 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326); + END IF; + IF seg = 4 THEN + secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326); + END IF; + + IF st_intersects(geometry, secbox) THEN + secgeo := st_intersection(geometry, secbox); + IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN + FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP + IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN + added := added + 1; + RETURN NEXT geo.geom; + END IF; + END LOOP; + END IF; + END IF; + END LOOP; + + RETURN; +END; +$$ +LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY) + RETURNS SETOF GEOMETRY + AS $$ +DECLARE + geo RECORD; +BEGIN + -- 10000000000 is ~~ 1x1 degree + FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP + RETURN NEXT geo.geom; + END LOOP; + RETURN; +END; +$$ +LANGUAGE plpgsql;