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 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 -- Have we already done this place?
38 SELECT * INTO existing
40 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
41 and class = NEW.class and type = NEW.type;
43 {% if debug %}RAISE WARNING 'Existing: %',existing.osm_id;{% endif %}
45 -- Handle a place changing type by removing the old data.
46 -- (This trigger is executed BEFORE INSERT of the NEW tuple.)
47 IF existing.osm_type IS NULL THEN
48 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
51 -- Remove any old logged data.
52 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
53 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
55 -- ---- Interpolation Lines
57 IF NEW.class='place' and NEW.type='houses'
58 and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString'
60 PERFORM reinsert_interpolation(NEW.osm_id, NEW.address, NEW.geometry);
62 -- Now invalidate all address nodes on the line.
63 -- They get their parent from the interpolation.
64 UPDATE placex p SET indexed_status = 2
65 FROM planet_osm_ways w
66 WHERE w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
68 -- If there is already an entry in place, just update that, if necessary.
69 IF existing.osm_type is not null THEN
70 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
71 OR existing.geometry::text != NEW.geometry::text
75 address = NEW.address,
76 extratags = NEW.extratags,
77 admin_level = NEW.admin_level,
78 geometry = NEW.geometry
79 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
80 and class = NEW.class and type = NEW.type;
89 -- ---- Postcode points.
91 IF NEW.class = 'place' AND NEW.type = 'postcode' THEN
92 -- Pure postcodes are never queried from placex so we don't add them.
93 -- location_postcodes is filled from the place table directly.
95 -- Remove any old placex entry.
96 DELETE FROM placex WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id;
98 IF existing.osm_type IS NOT NULL THEN
99 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
100 OR existing.geometry::text != NEW.geometry::text
104 address = NEW.address,
105 extratags = NEW.extratags,
106 admin_level = NEW.admin_level,
107 geometry = NEW.geometry
108 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
109 and class = NEW.class and type = NEW.type;
118 -- ---- All other place types.
120 -- When an area is changed from large to small: log and discard change
121 IF existing.geometry is not null AND ST_IsValid(existing.geometry)
122 AND ST_Area(existing.geometry) > 0.02
123 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
124 AND ST_Area(NEW.geometry) < ST_Area(existing.geometry) * 0.5
126 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name,
127 country_code, updated, errormessage,
128 prevgeometry, newgeometry)
129 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
130 NEW.address->'country', now(),
131 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry),
132 existing.geometry, NEW.geometry);
137 -- If an address node is part of a interpolation line and changes or is
138 -- newly inserted (happens when the node already existed but now gets address
139 -- information), then mark the interpolation line for reparenting.
140 -- (Already here, because interpolation lines are reindexed before nodes,
141 -- so in the second call it would be too late.)
143 and coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
146 SELECT DISTINCT osm_id, address, geometry FROM place, planet_osm_ways w
147 WHERE NEW.geometry && place.geometry
148 and place.osm_type = 'W'
149 and place.address ? 'interpolation'
150 and exists (SELECT * FROM location_property_osmline
151 WHERE osm_id = place.osm_id
152 and indexed_status in (0, 2))
153 and w.id = place.osm_id and NEW.osm_id = any (w.nodes)
155 PERFORM reinsert_interpolation(interpol.osm_id, interpol.address,
160 -- Get the existing placex entry.
161 SELECT * INTO existingplacex
163 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
164 and class = NEW.class and type = NEW.type;
166 {% if debug %}RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;{% endif %}
168 -- To paraphrase: if there isn't an existing item, OR if the admin level has changed
169 IF existingplacex.osm_type IS NULL
170 or (existingplacex.class = 'boundary'
171 and ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15)
172 and existingplacex.type = 'administrative')
173 or existingplacex.type != NEW.type))
175 {% if config.get_bool('LIMIT_REINDEXING') %}
176 -- sanity check: ignore admin_level changes on places with too many active children
177 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
178 IF existingplacex.osm_type IS NOT NULL THEN
179 SELECT count(*) INTO i FROM
180 (SELECT 'a' FROM placex, place_addressline
181 WHERE address_place_id = existingplacex.place_id
182 and placex.place_id = place_addressline.place_id
183 and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub;
190 IF existing.osm_type IS NOT NULL THEN
191 -- Pathological case caused by the triggerless copy into place during initial import
192 -- force delete even for large areas, it will be reinserted later
193 UPDATE place SET geometry = ST_SetSRID(ST_Point(0,0), 4326)
194 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
195 and class = NEW.class and type = NEW.type;
197 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
198 and class = NEW.class and type = NEW.type;
201 -- Process it as a new insertion
202 INSERT INTO placex (osm_type, osm_id, class, type, name,
203 admin_level, address, extratags, geometry)
204 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
205 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
207 {% if debug %}RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;{% endif %}
212 -- Special case for polygon shape changes because they tend to be large
213 -- and we can be a bit clever about how we handle them
214 IF existing.geometry::text != NEW.geometry::text
215 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
216 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
219 IF ST_Area(NEW.geometry) < 0.000000001 AND ST_Area(existingplacex.geometry) < 1
221 -- re-index points that have moved in / out of the polygon.
222 -- Could be done as a single query but postgres gets the index usage wrong.
223 update placex set indexed_status = 2 where indexed_status = 0
224 AND ST_Intersects(NEW.geometry, placex.geometry)
225 AND NOT ST_Intersects(existingplacex.geometry, placex.geometry)
226 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
228 update placex set indexed_status = 2 where indexed_status = 0
229 AND ST_Intersects(existingplacex.geometry, placex.geometry)
230 AND NOT ST_Intersects(NEW.geometry, placex.geometry)
231 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
236 -- Has something relevant changed?
237 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
238 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
239 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
240 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
241 OR existing.geometry::text != NEW.geometry::text
245 address = NEW.address,
246 extratags = NEW.extratags,
247 admin_level = NEW.admin_level,
248 geometry = NEW.geometry
249 WHERE osm_type = NEW.osm_type and osm_id = NEW.osm_id
250 and class = NEW.class and type = NEW.type;
252 -- Postcode areas are only kept, when there is an actual postcode assigned.
253 IF NEW.class = 'boundary' AND NEW.type = 'postal_code' THEN
254 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
255 -- postcode was deleted, no longer retain in placex
256 DELETE FROM placex where place_id = existingplacex.place_id;
260 NEW.name := hstore('ref', NEW.address->'postcode');
263 -- Boundaries must be areas.
264 IF NEW.class in ('boundary')
265 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon')
267 DELETE FROM placex where place_id = existingplacex.place_id;
271 -- Update the placex entry in-place.
274 address = NEW.address,
275 parent_place_id = null,
276 extratags = NEW.extratags,
277 admin_level = NEW.admin_level,
279 geometry = NEW.geometry
280 WHERE place_id = existingplacex.place_id;
282 -- Invalidate linked places: they potentially get a new name and addresses.
283 IF existingplacex.linked_place_id is not NULL THEN
286 extratags = p.extratags,
289 WHERE x.place_id = existingplacex.linked_place_id
290 and x.indexed_status = 0
291 and x.osm_type = p.osm_type
292 and x.osm_id = p.osm_id
293 and x.class = p.class;
296 -- Invalidate dependent objects effected by name changes
297 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
299 IF existingplacex.rank_address between 26 and 27 THEN
300 -- When streets change their name, this may have an effect on POI objects
301 -- with addr:street tags.
302 UPDATE placex SET indexed_status = 2
303 WHERE indexed_status = 0 and address ? 'street'
304 and parent_place_id = existingplacex.place_id;
305 UPDATE placex SET indexed_status = 2
306 WHERE indexed_status = 0 and rank_search = 30 and address ? 'street'
307 and ST_DWithin(NEW.geometry, geometry, 0.002);
308 ELSEIF existingplacex.rank_address between 16 and 25 THEN
309 -- When places change their name, this may have an effect on POI objects
310 -- with addr:place tags.
311 UPDATE placex SET indexed_status = 2
312 WHERE indexed_status = 0 and address ? 'place' and rank_search = 30
313 and parent_place_id = existingplacex.place_id;
314 -- No update of surrounding objects, potentially too expensive.
319 -- Abort the insertion (we modified the existing place instead)
325 CREATE OR REPLACE FUNCTION place_delete()
332 {% if debug %}RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;{% endif %}
334 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
335 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
336 SELECT bool_or(not (rank_address = 0 or rank_address > 25)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
338 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
344 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;
346 -- interpolations are special
347 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
348 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)