1 -- Assorted helper functions for the triggers.
3 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry)
9 -- RAISE WARNING '%',place;
10 NEWgeometry := ST_PointOnSurface(place);
11 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
14 LANGUAGE plpgsql IMMUTABLE;
17 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
24 IF array_upper(a, 1) IS NULL THEN
27 IF array_upper(b, 1) IS NULL THEN
31 FOR i IN 1..array_upper(b, 1) LOOP
32 IF NOT (ARRAY[b[i]] <@ r) THEN
39 LANGUAGE plpgsql IMMUTABLE;
42 CREATE OR REPLACE FUNCTION reverse_place_diameter(rank_search SMALLINT)
46 IF rank_search <= 4 THEN
48 ELSIF rank_search <= 8 THEN
50 ELSIF rank_search <= 12 THEN
52 ELSIF rank_search <= 17 THEN
54 ELSIF rank_search <= 18 THEN
56 ELSIF rank_search <= 19 THEN
63 LANGUAGE plpgsql IMMUTABLE;
66 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
67 OUT rank_search SMALLINT,
68 OUT rank_address SMALLINT)
75 postcode := upper(postcode);
77 IF country_code = 'gb' THEN
78 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
81 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
84 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
89 ELSEIF country_code = 'sg' THEN
90 IF postcode ~ '^([0-9]{6})$' THEN
95 ELSEIF country_code = 'de' THEN
96 IF postcode ~ '^([0-9]{5})$' THEN
102 -- Guess at the postcode format and coverage (!)
103 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
107 -- Does it look splitable into and area and local code?
108 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
110 IF part IS NOT NULL THEN
113 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
122 LANGUAGE plpgsql IMMUTABLE;
125 -- Find the nearest artificial postcode for the given geometry.
126 -- TODO For areas there should not be more than two inside the geometry.
127 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY)
134 -- If the geometry is an area then only one postcode must be within
135 -- that area, otherwise consider the area as not having a postcode.
136 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
137 SELECT min(postcode), count(*) FROM
138 (SELECT postcode FROM location_postcode
139 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
149 SELECT postcode FROM location_postcode
150 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
151 AND location_postcode.country_code = country
152 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
158 LANGUAGE plpgsql STABLE;
161 CREATE OR REPLACE FUNCTION get_country_code(place geometry)
165 place_centre GEOMETRY;
168 place_centre := ST_PointOnSurface(place);
170 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
172 -- Try for a OSM polygon
174 SELECT country_code from location_area_country
175 WHERE country_code is not null and st_covers(geometry, place_centre) limit 1
177 RETURN nearcountry.country_code;
180 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
182 -- Try for OSM fallback data
183 -- The order is to deal with places like HongKong that are 'states' within another polygon
185 SELECT country_code from country_osm_grid
186 WHERE st_covers(geometry, place_centre) order by area asc limit 1
188 RETURN nearcountry.country_code;
191 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
195 SELECT country_code from country_osm_grid
196 WHERE st_dwithin(geometry, place_centre, 0.5)
197 ORDER BY st_distance(geometry, place_centre) asc, area asc limit 1
199 RETURN nearcountry.country_code;
205 LANGUAGE plpgsql STABLE;
208 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2))
215 SELECT distinct country_default_language_code from country_name
216 WHERE country_code = search_country_code limit 1
218 RETURN lower(nearcountry.country_default_language_code);
223 LANGUAGE plpgsql STABLE;
226 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2))
233 SELECT country_default_language_codes from country_name
234 WHERE country_code = search_country_code limit 1
236 RETURN lower(nearcountry.country_default_language_codes);
241 LANGUAGE plpgsql STABLE;
244 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10))
251 SELECT partition from country_name where country_code = in_country_code
253 RETURN nearcountry.partition;
258 LANGUAGE plpgsql STABLE;
261 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT)
266 DELETE FROM location_area where place_id = OLD_place_id;
267 -- TODO:location_area
274 CREATE OR REPLACE FUNCTION add_location(place_id BIGINT, country_code varchar(2),
275 partition INTEGER, keywords INTEGER[],
276 rank_search INTEGER, rank_address INTEGER,
277 in_postcode TEXT, geometry GEOMETRY)
290 IF rank_search > 25 THEN
291 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
294 x := deleteLocationArea(partition, place_id, rank_search);
296 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
298 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
299 postcode := upper(trim (in_postcode));
302 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
303 centroid := ST_Centroid(geometry);
305 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
306 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
312 IF rank_address = 0 THEN
314 ELSEIF rank_search <= 14 THEN
316 ELSEIF rank_search <= 15 THEN
318 ELSEIF rank_search <= 16 THEN
320 ELSEIF rank_search <= 17 THEN
322 ELSEIF rank_search <= 21 THEN
324 ELSEIF rank_search = 25 THEN
328 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
330 secgeo := ST_Buffer(geometry, diameter);
331 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
341 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT)
349 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
350 IF members[i+1] = member THEN
351 result := result || members[i];
358 LANGUAGE plpgsql IMMUTABLE;
361 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[])
368 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
369 IF members[i+1] = ANY(memberLabels) THEN
370 RETURN NEXT members[i];
377 LANGUAGE plpgsql IMMUTABLE;
380 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT,
382 RETURNS SETOF GEOMETRY
396 remainingdepth INTEGER;
400 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
402 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
403 RETURN NEXT geometry;
407 remainingdepth := maxdepth - 1;
408 area := ST_AREA(geometry);
409 IF remainingdepth < 1 OR area < maxarea THEN
410 RETURN NEXT geometry;
414 xmin := st_xmin(geometry);
415 xmax := st_xmax(geometry);
416 ymin := st_ymin(geometry);
417 ymax := st_ymax(geometry);
418 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
420 -- if the geometry completely covers the box don't bother to slice any more
421 IF ST_AREA(secbox) = area THEN
422 RETURN NEXT geometry;
426 xmid := (xmin+xmax)/2;
427 ymid := (ymin+ymax)/2;
433 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
436 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
439 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
442 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
445 IF st_intersects(geometry, secbox) THEN
446 secgeo := st_intersection(geometry, secbox);
447 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
448 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
449 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
451 RETURN NEXT geo.geom;
461 LANGUAGE plpgsql IMMUTABLE;
464 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
465 RETURNS SETOF GEOMETRY
470 -- 10000000000 is ~~ 1x1 degree
471 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
472 RETURN NEXT geo.geom;
477 LANGUAGE plpgsql IMMUTABLE;
480 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT)
485 osmtype character(1);
489 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
490 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
491 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
492 -- force delete from place/placex by making it a very small geometry
493 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
494 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
502 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT)
511 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
512 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
513 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
514 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
515 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
516 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
517 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
518 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
519 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
525 ELSEIF rank < 18 THEN
527 ELSEIF rank < 20 THEN
529 ELSEIF rank = 21 THEN
531 ELSEIF rank < 24 THEN
533 ELSEIF rank < 26 THEN
534 diameter := 0.002; -- 100 to 200 meters
535 ELSEIF rank < 28 THEN
536 diameter := 0.001; -- 50 to 100 meters
540 -- roads may cause reparenting for >27 rank places
541 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
542 ELSEIF rank >= 16 THEN
543 -- up to rank 16, street-less addresses may need reparenting
544 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or address ? 'place');
546 -- for all other places the search terms may change as well
547 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null);