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 geometry_sector(partition INTEGER, place geometry)
16 -- RAISE WARNING '%',place;
17 NEWgeometry := ST_PointOnSurface(place);
18 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
21 LANGUAGE plpgsql IMMUTABLE;
24 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
31 IF array_upper(a, 1) IS NULL THEN
34 IF array_upper(b, 1) IS NULL THEN
38 FOR i IN 1..array_upper(b, 1) LOOP
39 IF NOT (ARRAY[b[i]] <@ r) THEN
46 LANGUAGE plpgsql IMMUTABLE;
48 -- Return the node members with a given label from a relation member list
51 -- \param members Member list in osm2pgsql middle format.
52 -- \param memberLabels Array of labels to accept.
54 -- \returns Set of OSM ids of nodes that are found.
56 CREATE OR REPLACE FUNCTION get_rel_node_members(members TEXT[],
63 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
64 IF members[i+1] = ANY(memberLabels)
65 AND upper(substring(members[i], 1, 1))::char(1) = 'N'
67 RETURN NEXT substring(members[i], 2)::bigint;
74 LANGUAGE plpgsql IMMUTABLE;
76 -- Copy 'name' to or from the default language.
78 -- \param country_code Country code of the object being named.
79 -- \param[inout] name List of names of the object.
81 -- If the country named by country_code has a single default language,
82 -- then a `name` tag is copied to `name:<country_code>` if this tag does
83 -- not yet exist and vice versa.
84 CREATE OR REPLACE FUNCTION add_default_place_name(country_code VARCHAR(2),
88 default_language VARCHAR(10);
90 IF name is not null AND array_upper(akeys(name),1) > 1 THEN
91 default_language := get_country_language_code(country_code);
92 IF default_language IS NOT NULL THEN
93 IF name ? 'name' AND NOT name ? ('name:'||default_language) THEN
94 name := name || hstore(('name:'||default_language), (name -> 'name'));
95 ELSEIF name ? ('name:'||default_language) AND NOT name ? 'name' THEN
96 name := name || hstore('name', (name -> ('name:'||default_language)));
102 LANGUAGE plpgsql IMMUTABLE;
105 -- Find the nearest artificial postcode for the given geometry.
106 -- TODO For areas there should not be more than two inside the geometry.
107 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY)
114 -- If the geometry is an area then only one postcode must be within
115 -- that area, otherwise consider the area as not having a postcode.
116 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
117 SELECT min(postcode), count(*) FROM
118 (SELECT postcode FROM location_postcode
119 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
129 SELECT postcode FROM location_postcode
130 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
131 AND location_postcode.country_code = country
132 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
138 LANGUAGE plpgsql STABLE;
141 CREATE OR REPLACE FUNCTION get_country_code(place geometry)
145 place_centre GEOMETRY;
148 place_centre := ST_PointOnSurface(place);
150 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
152 -- Try for a OSM polygon
154 SELECT country_code from location_area_country
155 WHERE country_code is not null and st_covers(geometry, place_centre) limit 1
157 RETURN nearcountry.country_code;
160 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
162 -- Try for OSM fallback data
163 -- The order is to deal with places like HongKong that are 'states' within another polygon
165 SELECT country_code from country_osm_grid
166 WHERE st_covers(geometry, place_centre) order by area asc limit 1
168 RETURN nearcountry.country_code;
171 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
175 SELECT country_code from country_osm_grid
176 WHERE st_dwithin(geometry, place_centre, 0.5)
177 ORDER BY st_distance(geometry, place_centre) asc, area asc limit 1
179 RETURN nearcountry.country_code;
185 LANGUAGE plpgsql STABLE;
188 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2))
195 SELECT distinct country_default_language_code from country_name
196 WHERE country_code = search_country_code limit 1
198 RETURN lower(nearcountry.country_default_language_code);
203 LANGUAGE plpgsql STABLE;
206 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10))
213 SELECT partition from country_name where country_code = in_country_code
215 RETURN nearcountry.partition;
220 LANGUAGE plpgsql STABLE;
223 -- Find the parent of an address with addr:street/addr:place tag.
225 -- \param token_info Naming info with the address information.
226 -- \param partition Partition where to search the parent.
227 -- \param centroid Location of the address.
229 -- \return Place ID of the parent if one was found, NULL otherwise.
230 CREATE OR REPLACE FUNCTION find_parent_for_address(token_info JSONB,
236 parent_place_id BIGINT;
238 -- Check for addr:street attributes
239 parent_place_id := getNearestNamedRoadPlaceId(partition, centroid, token_info);
240 IF parent_place_id is not null THEN
241 {% if debug %}RAISE WARNING 'Get parent from addr:street: %', parent_place_id;{% endif %}
242 RETURN parent_place_id;
245 -- Check for addr:place attributes.
246 parent_place_id := getNearestNamedPlacePlaceId(partition, centroid, token_info);
247 {% if debug %}RAISE WARNING 'Get parent from addr:place: %', parent_place_id;{% endif %}
248 RETURN parent_place_id;
251 LANGUAGE plpgsql STABLE;
254 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT)
259 DELETE FROM location_area where place_id = OLD_place_id;
260 -- TODO:location_area
266 -- Create a bounding box with an extent computed from the radius (in meters)
267 -- which in turn is derived from the given search rank.
268 CREATE OR REPLACE FUNCTION place_node_fuzzy_area(geom GEOMETRY, rank_search INTEGER)
274 IF rank_search <= 16 THEN -- city
276 ELSIF rank_search <= 18 THEN -- town
278 ELSIF rank_search <= 19 THEN -- village
280 ELSIF rank_search <= 20 THEN -- hamlet
284 RETURN ST_Envelope(ST_Collect(
285 ST_Project(geom, radius, 0.785398)::geometry,
286 ST_Project(geom, radius, 3.9269908)::geometry));
289 LANGUAGE plpgsql IMMUTABLE;
292 CREATE OR REPLACE FUNCTION add_location(place_id BIGINT, country_code varchar(2),
293 partition INTEGER, keywords INTEGER[],
294 rank_search INTEGER, rank_address INTEGER,
295 in_postcode TEXT, geometry GEOMETRY,
304 PERFORM deleteLocationArea(partition, place_id, rank_search);
306 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
308 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
309 postcode := upper(trim (in_postcode));
312 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
313 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
314 PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
317 ELSEIF ST_GeometryType(geometry) = 'ST_Point' THEN
318 secgeo := place_node_fuzzy_area(geometry, rank_search);
319 PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, centroid, secgeo);
329 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT,
331 RETURNS SETOF GEOMETRY
345 remainingdepth INTEGER;
349 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
351 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
352 RETURN NEXT geometry;
356 remainingdepth := maxdepth - 1;
357 area := ST_AREA(geometry);
358 IF remainingdepth < 1 OR area < maxarea THEN
359 RETURN NEXT geometry;
363 xmin := st_xmin(geometry);
364 xmax := st_xmax(geometry);
365 ymin := st_ymin(geometry);
366 ymax := st_ymax(geometry);
367 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
369 -- if the geometry completely covers the box don't bother to slice any more
370 IF ST_AREA(secbox) = area THEN
371 RETURN NEXT geometry;
375 xmid := (xmin+xmax)/2;
376 ymid := (ymin+ymax)/2;
382 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
385 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
388 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
391 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
394 IF st_intersects(geometry, secbox) THEN
395 secgeo := st_intersection(geometry, secbox);
396 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
397 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
398 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
400 RETURN NEXT geo.geom;
410 LANGUAGE plpgsql IMMUTABLE;
413 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
414 RETURNS SETOF GEOMETRY
419 -- 10000000000 is ~~ 1x1 degree
420 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
421 RETURN NEXT geo.geom;
426 LANGUAGE plpgsql IMMUTABLE;
429 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT)
434 osmtype character(1);
438 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
439 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
440 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
441 -- force delete from place/placex by making it a very small geometry
442 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;
443 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
451 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT)
460 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
462 SELECT geometry, rank_address INTO placegeom, rank
463 FROM placex WHERE place_id = placeid;
465 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
466 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon')
469 FOR geom IN SELECT split_geometry(placegeom) LOOP
470 UPDATE placex SET indexed_status = 2
471 WHERE ST_Intersects(geom, placex.geometry)
472 and indexed_status = 0
473 and ((rank_address = 0 and rank_search > rank) or rank_address > rank)
474 and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
477 diameter := update_place_diameter(rank);
480 -- roads may cause reparenting for >27 rank places
481 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
482 ELSEIF rank >= 16 THEN
483 -- up to rank 16, street-less addresses may need reparenting
484 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');
486 -- for all other places the search terms may change as well
487 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);