1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2022 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- Assorted helper functions for the triggers.
10 CREATE OR REPLACE FUNCTION get_center_point(place GEOMETRY)
16 geom_type := ST_GeometryType(place);
17 IF geom_type = ' ST_Point' THEN
20 IF geom_type = 'ST_LineString' THEN
21 RETURN ST_LineInterpolatePoint(place, 0.5);
24 RETURN ST_PointOnSurface(place);
27 LANGUAGE plpgsql IMMUTABLE;
30 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place GEOMETRY)
34 RETURN (partition*1000000) + (500-ST_X(place)::INTEGER)*1000 + (500-ST_Y(place)::INTEGER);
37 LANGUAGE plpgsql IMMUTABLE;
41 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
48 IF array_upper(a, 1) IS NULL THEN
51 IF array_upper(b, 1) IS NULL THEN
55 FOR i IN 1..array_upper(b, 1) LOOP
56 IF NOT (ARRAY[b[i]] <@ r) THEN
63 LANGUAGE plpgsql IMMUTABLE;
65 -- Return the node members with a given label from a relation member list
68 -- \param members Member list in osm2pgsql middle format.
69 -- \param memberLabels Array of labels to accept.
71 -- \returns Set of OSM ids of nodes that are found.
73 CREATE OR REPLACE FUNCTION get_rel_node_members(members TEXT[],
80 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
81 IF members[i+1] = ANY(memberLabels)
82 AND upper(substring(members[i], 1, 1))::char(1) = 'N'
84 RETURN NEXT substring(members[i], 2)::bigint;
91 LANGUAGE plpgsql IMMUTABLE;
94 CREATE OR REPLACE FUNCTION get_rel_node_members(members JSONB, memberLabels TEXT[])
100 FOR member IN SELECT * FROM jsonb_array_elements(members)
102 IF member->>'type' = 'N' and member->>'role' = ANY(memberLabels) THEN
103 RETURN NEXT (member->>'ref')::bigint;
110 LANGUAGE plpgsql IMMUTABLE;
113 -- Copy 'name' to or from the default language.
115 -- \param country_code Country code of the object being named.
116 -- \param[inout] name List of names of the object.
118 -- If the country named by country_code has a single default language,
119 -- then a `name` tag is copied to `name:<country_code>` if this tag does
120 -- not yet exist and vice versa.
121 CREATE OR REPLACE FUNCTION add_default_place_name(country_code VARCHAR(2),
125 default_language VARCHAR(10);
127 IF name is not null AND array_upper(akeys(name),1) > 1 THEN
128 default_language := get_country_language_code(country_code);
129 IF default_language IS NOT NULL THEN
130 IF name ? 'name' AND NOT name ? ('name:'||default_language) THEN
131 name := name || hstore(('name:'||default_language), (name -> 'name'));
132 ELSEIF name ? ('name:'||default_language) AND NOT name ? 'name' THEN
133 name := name || hstore('name', (name -> ('name:'||default_language)));
139 LANGUAGE plpgsql IMMUTABLE;
142 -- Find the nearest artificial postcode for the given geometry.
143 -- TODO For areas there should not be more than two inside the geometry.
144 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY)
151 -- If the geometry is an area then only one postcode must be within
152 -- that area, otherwise consider the area as not having a postcode.
153 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
154 SELECT min(postcode), count(*) FROM
155 (SELECT postcode FROM location_postcode
156 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
166 SELECT postcode FROM location_postcode
167 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
168 AND location_postcode.country_code = country
169 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
175 LANGUAGE plpgsql STABLE;
178 CREATE OR REPLACE FUNCTION get_country_code(place geometry)
185 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place);
187 -- Try for a OSM polygon
188 SELECT array_agg(country_code) FROM location_area_country
189 WHERE country_code is not null and st_covers(geometry, place)
192 IF array_length(countries, 1) = 1 THEN
196 IF array_length(countries, 1) > 1 THEN
197 -- more than one country found, confirm against the fallback data what to choose
199 SELECT country_code FROM country_osm_grid
200 WHERE ST_Covers(geometry, place) AND country_code = ANY(countries)
203 RETURN nearcountry.country_code;
205 -- Still nothing? Choose the country code with the smallest partition number.
206 -- And failing that, just go by the alphabet.
209 (SELECT partition FROM country_name WHERE country_code = cc) as partition
210 FROM unnest(countries) cc
211 ORDER BY partition, cc
213 RETURN nearcountry.cc;
216 -- Should never be reached.
220 -- RAISE WARNING 'osm fallback: %', ST_AsText(place);
222 -- Try for OSM fallback data
223 -- The order is to deal with places like HongKong that are 'states' within another polygon
225 SELECT country_code from country_osm_grid
226 WHERE st_covers(geometry, place) order by area asc limit 1
228 RETURN nearcountry.country_code;
231 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place);
236 LANGUAGE plpgsql STABLE;
239 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2))
246 SELECT distinct country_default_language_code from country_name
247 WHERE country_code = search_country_code limit 1
249 RETURN lower(nearcountry.country_default_language_code);
254 LANGUAGE plpgsql STABLE;
257 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10))
264 SELECT partition from country_name where country_code = in_country_code
266 RETURN nearcountry.partition;
271 LANGUAGE plpgsql STABLE;
274 -- Find the parent of an address with addr:street/addr:place tag.
276 -- \param token_info Naming info with the address information.
277 -- \param partition Partition where to search the parent.
278 -- \param centroid Location of the address.
280 -- \return Place ID of the parent if one was found, NULL otherwise.
281 CREATE OR REPLACE FUNCTION find_parent_for_address(token_info JSONB,
287 parent_place_id BIGINT;
289 -- Check for addr:street attributes
290 parent_place_id := getNearestNamedRoadPlaceId(partition, centroid, token_info);
291 IF parent_place_id is not null THEN
292 {% if debug %}RAISE WARNING 'Get parent from addr:street: %', parent_place_id;{% endif %}
293 RETURN parent_place_id;
296 -- Check for addr:place attributes.
297 parent_place_id := getNearestNamedPlacePlaceId(partition, centroid, token_info);
298 {% if debug %}RAISE WARNING 'Get parent from addr:place: %', parent_place_id;{% endif %}
299 RETURN parent_place_id;
302 LANGUAGE plpgsql STABLE;
305 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT)
310 DELETE FROM location_area where place_id = OLD_place_id;
311 -- TODO:location_area
317 -- Create a bounding box with an extent computed from the radius (in meters)
318 -- which in turn is derived from the given search rank.
319 CREATE OR REPLACE FUNCTION place_node_fuzzy_area(geom GEOMETRY, rank_search INTEGER)
325 IF rank_search <= 16 THEN -- city
327 ELSIF rank_search <= 18 THEN -- town
329 ELSIF rank_search <= 19 THEN -- village
331 ELSIF rank_search <= 20 THEN -- hamlet
335 RETURN ST_Envelope(ST_Collect(
336 ST_Project(geom::geography, radius, 0.785398)::geometry,
337 ST_Project(geom::geography, radius, 3.9269908)::geometry));
340 LANGUAGE plpgsql IMMUTABLE;
343 CREATE OR REPLACE FUNCTION add_location(place_id BIGINT, country_code varchar(2),
344 partition INTEGER, keywords INTEGER[],
345 rank_search INTEGER, rank_address INTEGER,
346 in_postcode TEXT, geometry GEOMETRY,
355 PERFORM deleteLocationArea(partition, place_id, rank_search);
357 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
359 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
360 postcode := upper(trim (in_postcode));
363 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
364 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
365 PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
368 ELSEIF ST_GeometryType(geometry) = 'ST_Point' THEN
369 secgeo := place_node_fuzzy_area(geometry, rank_search);
370 PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, centroid, secgeo);
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;
479 CREATE OR REPLACE FUNCTION simplify_large_polygons(geometry GEOMETRY)
483 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
484 and ST_MemSize(geometry) > 3000000
486 geometry := ST_SimplifyPreserveTopology(geometry, 0.0001);
491 LANGUAGE plpgsql IMMUTABLE;
494 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT)
499 osmtype character(1);
503 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
504 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
505 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
506 -- force delete by directly entering it into the to-be-deleted table
507 INSERT INTO place_to_be_deleted (osm_type, osm_id, class, type, deferred)
508 VALUES(osmtype, osmid, pclass, ptype, false);
509 PERFORM flush_deleted_places();
517 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT)
526 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
528 SELECT geometry, rank_address INTO placegeom, rank
529 FROM placex WHERE place_id = placeid;
531 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
532 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon')
535 FOR geom IN SELECT split_geometry(placegeom) LOOP
536 UPDATE placex SET indexed_status = 2
537 WHERE ST_Intersects(geom, placex.geometry)
538 and indexed_status = 0
539 and ((rank_address = 0 and rank_search > rank) or rank_address > rank)
540 and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
543 diameter := update_place_diameter(rank);
546 -- roads may cause reparenting for >27 rank places
547 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
548 ELSEIF rank >= 16 THEN
549 -- up to rank 16, street-less addresses may need reparenting
550 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');
552 -- for all other places the search terms may change as well
553 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);
565 CREATE OR REPLACE FUNCTION flush_deleted_places()
569 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
570 INSERT INTO import_polygon_delete (osm_type, osm_id, class, type)
571 SELECT osm_type, osm_id, class, type FROM place_to_be_deleted WHERE deferred;
573 -- delete from place table
574 ALTER TABLE place DISABLE TRIGGER place_before_delete;
575 DELETE FROM place USING place_to_be_deleted
576 WHERE place.osm_type = place_to_be_deleted.osm_type
577 and place.osm_id = place_to_be_deleted.osm_id
578 and place.class = place_to_be_deleted.class
579 and place.type = place_to_be_deleted.type
581 ALTER TABLE place ENABLE TRIGGER place_before_delete;
583 -- Mark for delete in the placex table
584 UPDATE placex SET indexed_status = 100 FROM place_to_be_deleted
585 WHERE placex.osm_type = 'N' and place_to_be_deleted.osm_type = 'N'
586 and placex.osm_id = place_to_be_deleted.osm_id
587 and placex.class = place_to_be_deleted.class
588 and placex.type = place_to_be_deleted.type
590 UPDATE placex SET indexed_status = 100 FROM place_to_be_deleted
591 WHERE placex.osm_type = 'W' and place_to_be_deleted.osm_type = 'W'
592 and placex.osm_id = place_to_be_deleted.osm_id
593 and placex.class = place_to_be_deleted.class
594 and placex.type = place_to_be_deleted.type
596 UPDATE placex SET indexed_status = 100 FROM place_to_be_deleted
597 WHERE placex.osm_type = 'R' and place_to_be_deleted.osm_type = 'R'
598 and placex.osm_id = place_to_be_deleted.osm_id
599 and placex.class = place_to_be_deleted.class
600 and placex.type = place_to_be_deleted.type
603 -- Mark for delete in interpolations
604 UPDATE location_property_osmline SET indexed_status = 100 FROM place_to_be_deleted
605 WHERE place_to_be_deleted.osm_type = 'W'
606 and place_to_be_deleted.class = 'place'
607 and place_to_be_deleted.type = 'houses'
608 and location_property_osmline.osm_id = place_to_be_deleted.osm_id
612 TRUNCATE TABLE place_to_be_deleted;