1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2025 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 CREATE OR REPLACE FUNCTION place_insert()
15 existingplacex RECORD;
16 existingline BIGINT[];
20 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
23 -- Filter tuples with bad geometries.
24 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) THEN
25 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name,
26 country_code, updated, errormessage,
27 prevgeometry, newgeometry)
28 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
29 NEW.address->'country', now(), ST_IsValidReason(NEW.geometry),
32 RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
37 -- Remove the place from the list of places to be deleted
38 DELETE FROM place_to_be_deleted pdel
39 WHERE pdel.osm_type = NEW.osm_type and pdel.osm_id = NEW.osm_id
40 and pdel.class = NEW.class and pdel.type = NEW.type;
42 -- Have we already done this place?
43 SELECT * INTO existing
45 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
46 and class = NEW.class and type = NEW.type;
48 {% if debug %}RAISE WARNING 'Existing: %',existing.osm_id;{% endif %}
50 IF existing.osm_type IS NULL THEN
51 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
54 -- Remove any old logged data.
55 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
56 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
58 -- ---- Interpolation Lines
60 IF NEW.class='place' and NEW.type='houses'
61 and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString'
63 PERFORM reinsert_interpolation(NEW.osm_id, NEW.address, NEW.geometry);
65 -- Now invalidate all address nodes on the line.
66 -- They get their parent from the interpolation.
67 UPDATE placex p SET indexed_status = 2
68 FROM planet_osm_ways w
69 WHERE w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
71 -- If there is already an entry in place, just update that, if necessary.
72 IF existing.osm_type is not null THEN
73 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
74 OR existing.geometry::text != NEW.geometry::text
78 address = NEW.address,
79 extratags = NEW.extratags,
80 admin_level = NEW.admin_level,
81 geometry = NEW.geometry
82 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
83 and class = NEW.class and type = NEW.type;
92 -- ---- All other place types.
94 -- When an area is changed from large to small: log and discard change
95 IF existing.geometry is not null AND ST_IsValid(existing.geometry)
96 AND ST_Area(existing.geometry) > 0.02
97 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
98 AND ST_Area(NEW.geometry) < ST_Area(existing.geometry) * 0.5
100 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name,
101 country_code, updated, errormessage,
102 prevgeometry, newgeometry)
103 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
104 NEW.address->'country', now(),
105 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry),
106 existing.geometry, NEW.geometry);
111 -- If an address node is part of a interpolation line and changes or is
112 -- newly inserted (happens when the node already existed but now gets address
113 -- information), then mark the interpolation line for reparenting.
114 -- (Already here, because interpolation lines are reindexed before nodes,
115 -- so in the second call it would be too late.)
117 and coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
120 SELECT DISTINCT osm_id, address, geometry FROM place, planet_osm_ways w
121 WHERE NEW.geometry && place.geometry
122 and place.osm_type = 'W'
123 and place.address ? 'interpolation'
124 and exists (SELECT * FROM location_property_osmline
125 WHERE osm_id = place.osm_id
126 and indexed_status in (0, 2))
127 and w.id = place.osm_id and NEW.osm_id = any (w.nodes)
129 PERFORM reinsert_interpolation(interpol.osm_id, interpol.address,
134 -- Get the existing placex entry.
135 SELECT * INTO existingplacex
137 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
138 and class = NEW.class and type = NEW.type;
140 {% if debug %}RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;{% endif %}
142 -- To paraphrase: if there isn't an existing item, OR if the admin level has changed
143 IF existingplacex.osm_type IS NULL
144 or (existingplacex.class = 'boundary'
145 and ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15)
146 and existingplacex.type = 'administrative')
147 or existingplacex.type != NEW.type))
149 {% if config.get_bool('LIMIT_REINDEXING') %}
150 -- sanity check: ignore admin_level changes on places with too many active children
151 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
152 IF existingplacex.osm_type IS NOT NULL THEN
153 SELECT count(*) INTO i FROM
154 (SELECT 'a' FROM placex, place_addressline
155 WHERE address_place_id = existingplacex.place_id
156 and placex.place_id = place_addressline.place_id
157 and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub;
164 IF existingplacex.osm_type is not NULL THEN
165 -- Mark any existing place for delete in the placex table
166 UPDATE placex SET indexed_status = 100
167 WHERE placex.osm_type = NEW.osm_type and placex.osm_id = NEW.osm_id
168 and placex.class = NEW.class and placex.type = NEW.type;
171 -- Process it as a new insertion
172 INSERT INTO placex (osm_type, osm_id, class, type, name,
173 admin_level, address, extratags, geometry)
174 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
175 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
177 {% if debug %}RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;{% endif %}
179 IF existing.osm_type is not NULL THEN
180 -- If there is already an entry in place, just update that, if necessary.
181 IF coalesce(existing.name, ''::hstore) != coalesce(NEW.name, ''::hstore)
182 or coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
183 or coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore)
184 or coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
185 or existing.geometry::text != NEW.geometry::text
189 address = NEW.address,
190 extratags = NEW.extratags,
191 admin_level = NEW.admin_level,
192 geometry = NEW.geometry
193 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
194 and class = NEW.class and type = NEW.type;
203 -- Special case for polygon shape changes because they tend to be large
204 -- and we can be a bit clever about how we handle them
205 IF existing.geometry::text != NEW.geometry::text
206 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
207 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
210 IF ST_Area(NEW.geometry) < 0.000000001 AND ST_Area(existingplacex.geometry) < 1
212 -- re-index points that have moved in / out of the polygon.
213 -- Could be done as a single query but postgres gets the index usage wrong.
214 update placex set indexed_status = 2 where indexed_status = 0
215 AND ST_Intersects(NEW.geometry, placex.geometry)
216 AND NOT ST_Intersects(existingplacex.geometry, placex.geometry)
217 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
219 update placex set indexed_status = 2 where indexed_status = 0
220 AND ST_Intersects(existingplacex.geometry, placex.geometry)
221 AND NOT ST_Intersects(NEW.geometry, placex.geometry)
222 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
227 -- Has something relevant changed?
228 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
229 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
230 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
231 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
232 OR existing.geometry::text != NEW.geometry::text
236 address = NEW.address,
237 extratags = NEW.extratags,
238 admin_level = NEW.admin_level,
239 geometry = NEW.geometry
240 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
241 and class = NEW.class and type = NEW.type;
243 -- Boundaries must be areas.
244 IF NEW.class in ('boundary')
245 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon')
247 DELETE FROM placex where place_id = existingplacex.place_id;
251 -- Update the placex entry in-place.
254 address = NEW.address,
255 parent_place_id = null,
256 extratags = NEW.extratags,
257 admin_level = NEW.admin_level,
259 geometry = CASE WHEN existingplacex.rank_address = 0
260 THEN simplify_large_polygons(NEW.geometry)
261 ELSE NEW.geometry END
262 WHERE place_id = existingplacex.place_id;
264 -- Invalidate linked places: they potentially get a new name and addresses.
265 IF existingplacex.linked_place_id is not NULL THEN
268 extratags = p.extratags,
271 WHERE x.place_id = existingplacex.linked_place_id
272 and x.indexed_status = 0
273 and x.osm_type = p.osm_type
274 and x.osm_id = p.osm_id
275 and x.class = p.class;
278 -- Invalidate dependent objects effected by name changes
279 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
281 IF existingplacex.rank_address between 26 and 27 THEN
282 -- When streets change their name, this may have an effect on POI objects
283 -- with addr:street tags.
284 UPDATE placex SET indexed_status = 2
285 WHERE indexed_status = 0 and address ? 'street'
286 and parent_place_id = existingplacex.place_id;
287 UPDATE placex SET indexed_status = 2
288 WHERE indexed_status = 0 and rank_search = 30 and address ? 'street'
289 and ST_DWithin(NEW.geometry, geometry, 0.002);
290 ELSEIF existingplacex.rank_address between 16 and 25 THEN
291 -- When places change their name, this may have an effect on POI objects
292 -- with addr:place tags.
293 UPDATE placex SET indexed_status = 2
294 WHERE indexed_status = 0 and address ? 'place' and rank_search = 30
295 and parent_place_id = existingplacex.place_id;
296 -- No update of surrounding objects, potentially too expensive.
301 -- When an existing way is updated, recalculate entrances
302 IF existingplacex.osm_type = 'W' and (existingplacex.rank_search > 27 or existingplacex.class IN ('landuse', 'leisure')) THEN
303 PERFORM place_update_entrances(existingplacex.place_id, existingplacex.osm_id);
306 -- Abort the insertion (we modified the existing place instead)
311 CREATE OR REPLACE FUNCTION place_delete()
317 {% if debug %}RAISE WARNING 'Delete for % % %/%', OLD.osm_type, OLD.osm_id, OLD.class, OLD.type;{% endif %}
319 deferred := ST_IsValid(OLD.geometry) and ST_Area(OLD.geometry) > 2;
321 SELECT bool_or(not (rank_address = 0 or rank_address > 25)) INTO deferred
323 WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id
324 and class = OLD.class and type = OLD.type;
327 INSERT INTO place_to_be_deleted (osm_type, osm_id, class, type, deferred)
328 VALUES(OLD.osm_type, OLD.osm_id, OLD.class, OLD.type, deferred);