1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2026 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- Trigger functions for the placex table.
10 -- Information returned by update preparation.
11 DROP TYPE IF EXISTS prepare_update_info CASCADE;
12 CREATE TYPE prepare_update_info AS (
15 rank_address SMALLINT,
19 linked_place_id BIGINT,
24 -- Retrieve the data needed by the indexer for updating the place.
25 CREATE OR REPLACE FUNCTION placex_indexing_prepare(p placex)
26 RETURNS prepare_update_info
30 result prepare_update_info;
32 default_language VARCHAR(10);
34 IF not p.address ? '_inherited' THEN
35 result.address := p.address;
38 -- For POI nodes, check if the address should be derived from a surrounding
40 IF p.rank_search = 30 AND p.osm_type = 'N' THEN
41 IF p.address is null THEN
42 -- The additional && condition works around the misguided query
43 -- planner of postgis 3.0.
44 SELECT placex.address || hstore('_inherited', '') INTO result.address
46 WHERE ST_Covers(geometry, p.centroid)
47 and geometry && p.centroid
48 and placex.address is not null
49 and (placex.address ? 'housenumber' or placex.address ? 'street' or placex.address ? 'place')
50 and rank_search = 30 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
53 -- See if we can inherit additional address tags from an interpolation.
54 -- These will become permanent.
56 SELECT (address - 'interpolation'::text - 'housenumber'::text) as address
57 FROM place, planet_osm_ways w
58 WHERE place.osm_type = 'W' and place.address ? 'interpolation'
59 and place.geometry && p.geometry
60 and place.osm_id = w.id
61 and p.osm_id = any(w.nodes)
63 result.address := location.address || result.address;
68 -- remove internal and derived names
69 result.address := result.address - '_unlisted_place'::TEXT;
70 SELECT hstore(array_agg(key), array_agg(value)) INTO result.name
71 FROM each(p.name) WHERE key not like '\_%';
73 result.class := p.class;
74 result.type := p.type;
75 result.country_code := p.country_code;
76 result.rank_address := p.rank_address;
77 result.centroid_x := ST_X(p.centroid);
78 result.centroid_y := ST_Y(p.centroid);
80 -- Names of linked places need to be merged in, so search for a linkable
81 -- place already here.
82 SELECT * INTO location FROM find_linked_place(p);
84 IF location.place_id is not NULL THEN
85 result.linked_place_id := location.place_id;
87 IF location.name is not NULL THEN
88 {% if debug %}RAISE WARNING 'Names original: %, location: %', result.name, location.name;{% endif %}
90 -- Add the linked-place (e.g. city) name as a searchable placename in the default language (if any)
91 default_language := get_country_language_code(location.country_code);
92 IF default_language is not NULL AND location.name ? 'name' AND NOT location.name ? ('name:' || default_language) THEN
93 location.name := location.name || hstore('name:' || default_language, location.name->'name');
96 -- Add all names from the place nodes that deviate from the name
97 -- in the relation with the prefix '_place_'. Deviation means that
98 -- either the value is different or a given key is missing completely
99 IF result.name is null THEN
100 SELECT hstore(array_agg('_place_' || key), array_agg(value))
102 FROM each(location.name);
104 SELECT hstore(array_agg('_place_' || key), array_agg(value)) INTO extra_names
105 FROM each(location.name - result.name);
106 {% if debug %}RAISE WARNING 'Extra names: %', extra_names;{% endif %}
108 IF extra_names is not null THEN
109 result.name := result.name || extra_names;
113 {% if debug %}RAISE WARNING 'Final names: %', result.name;{% endif %}
120 LANGUAGE plpgsql STABLE PARALLEL SAFE;
123 CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
137 {% if db.middle_db_format == '1' %}
139 SELECT members FROM planet_osm_rels
140 WHERE parts @> ARRAY[poi_osm_id]
141 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
142 and tags @> ARRAY['associatedStreet']
144 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
145 IF location.members[i+1] = 'street' THEN
147 SELECT place_id, geometry
149 WHERE osm_type = upper(substring(location.members[i], 1, 1))::char(1)
150 and osm_id = substring(location.members[i], 2)::bigint
152 and rank_search between 26 and 27
154 -- Find the closest 'street' member.
155 -- Avoid distance computation for the frequent case where there is
156 -- only one street member.
157 IF waygeom is null THEN
158 result := parent.place_id;
159 waygeom := parent.geometry;
161 distance := coalesce(distance, ST_Distance(waygeom, bbox));
162 new_distance := ST_Distance(parent.geometry, bbox);
163 IF new_distance < distance THEN
164 distance := new_distance;
165 result := parent.place_id;
166 waygeom := parent.geometry;
176 SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(members)
177 WHERE planet_osm_member_ids(members, poi_osm_type::char(1)) && ARRAY[poi_osm_id]
178 and tags->>'type' = 'associatedStreet'
179 and value->>'role' = 'street'
182 SELECT place_id, geometry
184 WHERE osm_type = (member->>'type')::char(1)
185 and osm_id = (member->>'ref')::bigint
187 and rank_search between 26 and 27
189 -- Find the closest 'street' member.
190 -- Avoid distance computation for the frequent case where there is
191 -- only one street member.
192 IF waygeom is null THEN
193 result := parent.place_id;
194 waygeom := parent.geometry;
196 distance := coalesce(distance, ST_Distance(waygeom, bbox));
197 new_distance := ST_Distance(parent.geometry, bbox);
198 IF new_distance < distance THEN
199 distance := new_distance;
200 result := parent.place_id;
201 waygeom := parent.geometry;
211 LANGUAGE plpgsql STABLE PARALLEL SAFE;
214 -- Find the parent road of a POI.
216 -- \returns Place ID of parent object or NULL if none
218 -- Copy data from linked items (POIs on ways, addr:street links, relations).
220 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
222 poi_partition SMALLINT,
225 is_place_addr BOOLEAN)
229 parent_place_id BIGINT DEFAULT NULL;
232 {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
234 -- Is this object part of an associatedStreet relation?
235 parent_place_id := find_associated_street(poi_osm_type, poi_osm_id, bbox);
237 IF parent_place_id is null THEN
238 parent_place_id := find_parent_for_address(token_info, poi_partition, bbox);
241 IF parent_place_id is null and poi_osm_type = 'N' THEN
243 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
244 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
245 FROM placex p, planet_osm_ways w
246 WHERE p.osm_type = 'W' and p.rank_search >= 26
247 and p.geometry && bbox
248 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
250 {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
252 -- Way IS a road then we are on it - that must be our road
253 IF location.rank_search < 28 THEN
254 {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
255 RETURN location.place_id;
258 parent_place_id := find_associated_street('W', location.osm_id, bbox);
262 IF parent_place_id is NULL THEN
263 IF is_place_addr THEN
264 -- The address is attached to a place we don't know.
265 -- Instead simply use the containing area with the largest rank.
267 SELECT place_id FROM placex
268 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
269 AND rank_address between 5 and 25
270 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
271 ORDER BY rank_address desc
273 RETURN location.place_id;
275 ELSEIF ST_Area(bbox) < 0.005 THEN
276 -- for smaller features get the nearest road
277 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
278 {% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
280 -- for larger features simply find the area with the largest rank that
281 -- contains the bbox, only use addressable features
283 SELECT place_id FROM placex
284 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
285 AND rank_address between 5 and 25
286 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
287 ORDER BY rank_address desc
289 RETURN location.place_id;
294 RETURN parent_place_id;
297 LANGUAGE plpgsql STABLE PARALLEL SAFE;
299 -- Try to find a linked place for the given object.
300 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
304 {% if db.middle_db_format == '1' %}
305 relation_members TEXT[];
307 relation_members JSONB;
310 linked_placex placex%ROWTYPE;
313 IF bnd.rank_search >= 26 or bnd.rank_address = 0
314 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
319 IF bnd.osm_type = 'R' THEN
320 -- see if we have any special relation members
321 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
322 {% if debug %}RAISE WARNING 'Got relation members';{% endif %}
324 -- Search for relation members with role 'lable'.
325 IF relation_members IS NOT NULL THEN
327 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
329 {% if debug %}RAISE WARNING 'Found label member %', rel_member.member;{% endif %}
333 WHERE osm_type = 'N' and osm_id = rel_member.member
336 {% if debug %}RAISE WARNING 'Linked label member';{% endif %}
337 RETURN linked_placex;
344 IF bnd.name ? 'name' THEN
345 bnd_name := lower(bnd.name->'name');
346 IF bnd_name = '' THEN
351 IF bnd.extratags ? 'wikidata' THEN
354 WHERE placex.class = 'place' AND placex.osm_type = 'N'
355 AND placex.extratags ? 'wikidata' -- needed to select right index
356 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
357 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
358 AND placex.rank_search < 26
359 AND _st_covers(bnd.geometry, placex.geometry)
360 ORDER BY lower(name->'name') = bnd_name desc
362 {% if debug %}RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;{% endif %}
363 RETURN linked_placex;
367 -- If extratags has a place tag, look for linked nodes by their place type.
368 -- Area and node still have to have the same name.
369 IF bnd.extratags ? 'place' and bnd_name is not null
373 WHERE (position(lower(name->'name') in bnd_name) > 0
374 OR position(bnd_name in lower(name->'name')) > 0)
375 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
376 AND placex.osm_type = 'N'
377 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
378 AND placex.rank_search < 26 -- needed to select the right index
379 AND ST_Covers(bnd.geometry, placex.geometry)
381 {% if debug %}RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;{% endif %}
382 RETURN linked_placex;
386 -- Name searches can be done for ways as well as relations
387 IF bnd_name is not null THEN
388 {% if debug %}RAISE WARNING 'Looking for nodes with matching names';{% endif %}
390 SELECT placex.* from placex
391 WHERE lower(name->'name') = bnd_name
392 AND ((bnd.rank_address > 0
393 and bnd.rank_address = (compute_place_rank(placex.country_code,
395 placex.type, 15::SMALLINT,
396 false, placex.postcode)).address_rank)
397 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
398 AND placex.osm_type = 'N'
399 AND placex.class = 'place'
400 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
401 AND placex.rank_search < 26 -- needed to select the right index
402 AND ST_Covers(bnd.geometry, placex.geometry)
404 {% if debug %}RAISE WARNING 'Found matching place node %', linked_placex.osm_id;{% endif %}
405 RETURN linked_placex;
412 LANGUAGE plpgsql STABLE PARALLEL SAFE;
415 CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
416 in_partition SMALLINT,
417 parent_place_id BIGINT,
418 is_place_addr BOOLEAN,
422 OUT name_vector INTEGER[],
423 OUT nameaddress_vector INTEGER[])
426 parent_name_vector INTEGER[];
427 parent_address_vector INTEGER[];
428 addr_place_ids INTEGER[];
429 hnr_vector INTEGER[];
433 parent_address_place_ids BIGINT[];
435 nameaddress_vector := '{}'::INTEGER[];
437 SELECT s.name_vector, s.nameaddress_vector
438 INTO parent_name_vector, parent_address_vector
440 WHERE s.place_id = parent_place_id;
444 token_get_address_search_tokens(token_info, key) as search_tokens
445 FROM token_get_address_keys(token_info) as key,
446 LATERAL get_addr_tag_rank(key, country) as ranks
447 WHERE not token_get_address_search_tokens(token_info, key) <@ parent_address_vector
449 addr_place := get_address_place(in_partition, geometry,
450 addr_item.from_rank, addr_item.to_rank,
451 addr_item.extent, token_info, addr_item.key);
453 IF addr_place is null THEN
454 -- No place found in OSM that matches. Make it at least searchable.
455 nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
457 IF parent_address_place_ids is null THEN
458 SELECT array_agg(parent_place_id) INTO parent_address_place_ids
459 FROM place_addressline
460 WHERE place_id = parent_place_id;
463 -- If the parent already lists the place in place_address line, then we
464 -- are done. Otherwise, add its own place_address line.
465 IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
466 nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
468 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
469 isaddress, distance, cached_rank_address)
470 VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
471 true, addr_place.distance, addr_place.rank_address);
476 name_vector := COALESCE(token_get_name_search_tokens(token_info), '{}'::INTEGER[]);
478 -- Check if the parent covers all address terms.
479 -- If not, create a search name entry with the house number as the name.
480 -- This is unusual for the search_name table but prevents that the place
481 -- is returned when we only search for the street/place.
483 hnr_vector := token_get_housenumber_search_tokens(token_info);
485 IF hnr_vector is not null and not nameaddress_vector <@ parent_address_vector THEN
486 name_vector := array_merge(name_vector, hnr_vector);
489 -- Cheating here by not recomputing all terms but simply using the ones
490 -- from the parent object.
491 nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
492 nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
494 -- make sure addr:place terms are always searchable
495 IF is_place_addr THEN
496 addr_place_ids := token_addr_place_search_tokens(token_info);
497 IF hnr_vector is not null AND not addr_place_ids <@ parent_name_vector
499 name_vector := array_merge(name_vector, hnr_vector);
501 nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
508 -- Insert address of a place into the place_addressline table.
510 -- \param obj_place_id Place_id of the place to compute the address for.
511 -- \param partition Partition number where the place is in.
512 -- \param maxrank Rank of the place. All address features must have
513 -- a search rank lower than the given rank.
514 -- \param address Address terms for the place.
515 -- \param geometry Geometry to which the address objects should be close.
517 -- \retval parent_place_id Place_id of the address object that is the direct
519 -- \retval postcode Postcode computed from the address. This is the
520 -- addr:postcode of one of the address objects. If
521 -- more than one of has a postcode, the highest ranking
522 -- one is used. May be NULL.
523 -- \retval nameaddress_vector Search terms for the address. This is the sum
524 -- of name terms of all address objects.
525 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
532 OUT parent_place_id BIGINT,
534 OUT nameaddress_vector INT[])
537 address_havelevel BOOLEAN[];
538 place_min_distance FLOAT[];
540 location_isaddress BOOLEAN;
541 current_boundary GEOMETRY := NULL;
542 current_node_area GEOMETRY := NULL;
544 parent_place_rank INT := 0;
545 addr_place_ids BIGINT[] := '{}'::int[];
546 new_address_vector INT[];
550 parent_place_id := 0;
551 nameaddress_vector := '{}'::int[];
553 address_havelevel := array_fill(false, ARRAY[maxrank]);
554 place_min_distance := array_fill(1.0, ARRAY[maxrank]);
558 FROM (SELECT extra.*, key
559 FROM token_get_address_keys(token_info) as key,
560 LATERAL get_addr_tag_rank(key, country) as extra) x,
561 LATERAL get_address_place(partition, geometry, from_rank, to_rank,
562 extent, token_info, key) as apl
563 ORDER BY rank_address, distance, isguess desc
565 IF location.place_id is null THEN
566 {% if not db.reverse_only %}
567 nameaddress_vector := array_merge(nameaddress_vector,
568 token_get_address_search_tokens(token_info,
572 {% if not db.reverse_only %}
573 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
576 location_isaddress := not address_havelevel[location.rank_address];
577 IF not address_havelevel[location.rank_address] THEN
578 address_havelevel[location.rank_address] := true;
579 IF parent_place_rank < location.rank_address THEN
580 parent_place_id := location.place_id;
581 parent_place_rank := location.rank_address;
585 IF location.isguess and location.distance < place_min_distance[location.rank_address] THEN
586 place_min_distance[location.rank_address] := location.distance;
589 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
590 isaddress, distance, cached_rank_address)
591 VALUES (obj_place_id, location.place_id, not location.isguess,
592 true, location.distance, location.rank_address);
594 addr_place_ids := addr_place_ids || location.place_id;
599 SELECT * FROM getNearFeatures(partition, geometry, centroid, maxrank)
600 WHERE not addr_place_ids @> ARRAY[place_id]
601 ORDER BY rank_address, isguess asc,
603 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
604 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
605 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
608 -- Ignore all place nodes that do not fit in a lower level boundary.
609 CONTINUE WHEN location.isguess
610 and current_boundary is not NULL
611 and not ST_Contains(current_boundary, location.centroid);
613 -- If this is the first item in the rank, then assume it is the address.
614 location_isaddress := not address_havelevel[location.rank_address];
616 -- Ignore guessed places when they are too far away compared to similar closer ones.
617 IF location.isguess THEN
618 CONTINUE WHEN not location_isaddress
619 AND location.distance > 2 * place_min_distance[location.rank_address];
621 IF location.distance < place_min_distance[location.rank_address] THEN
622 place_min_distance[location.rank_address] := location.distance;
626 -- Further sanity checks to ensure that the address forms a sane hierarchy.
627 IF location_isaddress THEN
628 IF location.isguess and current_node_area is not NULL THEN
629 location_isaddress := ST_Contains(current_node_area, location.centroid);
631 IF not location.isguess and current_boundary is not NULL
632 and location.rank_address != 11 AND location.rank_address != 5 THEN
633 location_isaddress := ST_Contains(current_boundary, location.centroid);
637 IF location_isaddress THEN
638 address_havelevel[location.rank_address] := true;
639 parent_place_id := location.place_id;
641 -- Set postcode if we have one.
642 -- (Returned will be the highest ranking one.)
643 IF location.postcode is not NULL THEN
644 postcode = location.postcode;
647 -- Recompute the areas we need for hierarchy sanity checks.
648 IF location.rank_address != 11 AND location.rank_address != 5 THEN
649 IF location.isguess THEN
650 current_node_area := place_node_fuzzy_area(location.centroid,
651 location.rank_search);
653 current_node_area := NULL;
654 SELECT p.geometry FROM placex p
655 WHERE p.place_id = location.place_id INTO current_boundary;
660 -- Add it to the list of search terms
661 {% if not db.reverse_only %}
662 IF location.rank_address != 11 AND location.rank_address != 5 THEN
663 nameaddress_vector := array_merge(nameaddress_vector,
664 location.keywords::integer[]);
668 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
669 isaddress, distance, cached_rank_address)
670 VALUES (obj_place_id, location.place_id, not location.isguess,
671 location_isaddress, location.distance, location.rank_address);
678 CREATE OR REPLACE FUNCTION placex_insert()
685 country_code VARCHAR(2);
689 {% if debug %}RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
691 NEW.place_id := nextval('seq_place');
692 NEW.indexed_status := 1; --STATUS_NEW
694 NEW.centroid := get_center_point(NEW.geometry);
695 NEW.country_code := lower(get_country_code(NEW.centroid));
697 NEW.partition := get_partition(NEW.country_code);
698 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.centroid);
700 IF NEW.osm_type = 'X' THEN
701 -- E'X'ternal records should already be in the right format so do nothing
703 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
705 IF NEW.class = 'highway' AND is_area AND NEW.name is null
706 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
709 ELSEIF NEW.class = 'boundary' AND NOT is_area
712 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
713 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
718 SELECT * INTO NEW.rank_search, NEW.rank_address
719 FROM compute_place_rank(NEW.country_code,
720 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
721 NEW.class, NEW.type, NEW.admin_level,
722 (NEW.extratags->'capital') = 'yes',
723 NEW.address->'postcode');
725 -- a country code make no sense below rank 4 (country)
726 IF NEW.rank_search < 4 THEN
727 NEW.country_code := NULL;
730 -- Simplify polygons with a very large memory footprint when they
731 -- do not take part in address computation.
732 IF NEW.rank_address = 0 THEN
733 NEW.geometry := simplify_large_polygons(NEW.geometry);
738 {% if debug %}RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
740 {% if not disable_diff_updates %}
741 -- The following is not needed until doing diff updates, and slows the main index process down
743 IF NEW.rank_address between 2 and 27 THEN
744 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
745 -- Performance: We just can't handle re-indexing for country level changes
746 IF (NEW.rank_address < 26 and st_area(NEW.geometry) <= 2)
747 OR (NEW.rank_address >= 26 and st_area(NEW.geometry) < 0.01)
749 -- mark items within the geometry for re-indexing
750 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
752 UPDATE placex SET indexed_status = 2
753 WHERE ST_Intersects(NEW.geometry, placex.geometry)
754 and indexed_status = 0
755 and ((rank_address = 0 and rank_search > NEW.rank_address)
756 or rank_address > NEW.rank_address
757 or (class = 'place' and osm_type = 'N')
759 and (rank_search < 28
761 or (NEW.rank_address >= 16 and address ? 'place'));
763 ELSEIF ST_GeometryType(NEW.geometry) not in ('ST_LineString', 'ST_MultiLineString')
764 OR ST_Length(NEW.geometry) < 0.5
766 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
767 diameter := update_place_diameter(NEW.rank_address);
769 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
770 IF NEW.rank_search >= 26 THEN
771 -- roads may cause reparenting for >27 rank places
772 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
773 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
774 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and startnumber is not null and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
775 ELSEIF NEW.rank_search >= 16 THEN
776 -- up to rank 16, street-less addresses may need reparenting
777 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or address ? 'place');
779 -- for all other places the search terms may change as well
780 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null);
787 -- add to tables for special search
788 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
789 SELECT count(*) INTO result
791 WHERE classtable NOT SIMILAR TO '%\W%'
792 AND tablename = classtable and schemaname = current_schema();
794 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
795 USING NEW.place_id, NEW.centroid;
798 {% endif %} -- not disable_diff_updates
806 CREATE OR REPLACE FUNCTION placex_update()
812 {% if db.middle_db_format == '1' %}
813 relation_members TEXT[];
815 relation_member JSONB;
819 parent_address_level SMALLINT;
820 place_address_level SMALLINT;
824 name_vector INTEGER[];
825 nameaddress_vector INTEGER[];
826 addr_nameaddress_vector INTEGER[];
830 linked_node_id BIGINT;
831 linked_importance FLOAT;
832 linked_wikipedia TEXT;
834 is_place_address BOOLEAN;
838 IF OLD.indexed_status = 100 THEN
839 {% if debug %}RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;{% endif %}
840 delete from placex where place_id = OLD.place_id;
844 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
848 {% if debug %}RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;{% endif %}
850 NEW.indexed_date = now();
852 IF OLD.indexed_status > 1 THEN
853 {% if 'search_name' in db.tables %}
854 DELETE from search_name WHERE place_id = NEW.place_id;
856 result := deleteSearchName(NEW.partition, NEW.place_id);
857 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
858 result := deleteRoad(NEW.partition, NEW.place_id);
859 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
862 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
863 IF NEW.extratags = ''::hstore THEN
864 NEW.extratags := NULL;
867 -- NEW.linked_place_id contains the precomputed linkee. Save this and restore
868 -- the previous link status.
869 linked_place := NEW.linked_place_id;
870 NEW.linked_place_id := OLD.linked_place_id;
872 -- Remove linkage, if we have computed a different new linkee.
873 IF OLD.indexed_status > 1 THEN
875 SET linked_place_id = null,
876 indexed_status = CASE WHEN indexed_status = 0 THEN 2 ELSE indexed_status END
877 WHERE linked_place_id = NEW.place_id
878 and (linked_place is null or place_id != linked_place);
881 -- Compute a preliminary centroid.
882 NEW.centroid := get_center_point(NEW.geometry);
884 -- Record the entrance node locations
885 IF NEW.osm_type = 'W' and (NEW.rank_search > 27 or NEW.class IN ('landuse', 'leisure')) THEN
886 PERFORM place_update_entrances(NEW.place_id, NEW.osm_id);
889 -- recalculate country and partition
890 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
891 -- for countries, believe the mapped country code,
892 -- so that we remain in the right partition if the boundaries
894 NEW.country_code := lower(NEW.address->'country');
895 NEW.partition := get_partition(lower(NEW.country_code));
896 IF NEW.partition = 0 THEN
897 NEW.country_code := lower(get_country_code(NEW.centroid));
898 NEW.partition := get_partition(NEW.country_code);
901 IF NEW.rank_search >= 4 THEN
902 NEW.country_code := lower(get_country_code(NEW.centroid));
904 NEW.country_code := NULL;
906 NEW.partition := get_partition(NEW.country_code);
908 {% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
911 -- recompute the ranks, they might change when linking changes
912 SELECT * INTO NEW.rank_search, NEW.rank_address
913 FROM compute_place_rank(NEW.country_code,
914 CASE WHEN ST_GeometryType(NEW.geometry)
915 IN ('ST_Polygon','ST_MultiPolygon')
916 THEN 'A' ELSE NEW.osm_type END,
917 NEW.class, NEW.type, NEW.admin_level,
918 (NEW.extratags->'capital') = 'yes',
919 NEW.address->'postcode');
921 -- Short-cut out for linked places. Note that this must happen after the
922 -- address rank has been recomputed. The linking might nullify a shift in
924 IF NEW.linked_place_id is not null THEN
925 NEW.token_info := null;
926 {% if debug %}RAISE WARNING 'place already linked to %', OLD.linked_place_id;{% endif %}
930 -- We must always increase the address level relative to the admin boundary.
931 IF NEW.class = 'boundary' and NEW.type = 'administrative'
932 and NEW.osm_type = 'R' and NEW.rank_address > 0
934 -- First, check that admin boundaries do not overtake each other rank-wise.
935 parent_address_level := 3;
938 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
939 and extratags->'wikidata' = NEW.extratags->'wikidata'
940 THEN ST_Equals(geometry, NEW.geometry)
941 ELSE false END) as is_same
943 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
944 and admin_level < NEW.admin_level and admin_level > 3
945 and rank_address between 1 and 25 -- for index selection
946 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- for index selection
947 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
948 ORDER BY admin_level desc LIMIT 1
950 IF location.is_same THEN
951 -- Looks like the same boundary is replicated on multiple admin_levels.
952 -- Usual tagging in Poland. Remove our boundary from addresses.
953 NEW.rank_address := 0;
955 parent_address_level := location.rank_address;
956 IF location.rank_address >= NEW.rank_address THEN
957 IF location.rank_address >= 24 THEN
958 NEW.rank_address := 25;
960 NEW.rank_address := location.rank_address + 2;
966 IF NEW.rank_address > 9 THEN
967 -- Second check that the boundary is not completely contained in a
968 -- place area with a equal or higher address rank.
972 LATERAL compute_place_rank(country_code, 'A', class, type,
973 admin_level, False, null) prank
974 WHERE class = 'place' and rank_address between 1 and 23
975 and prank.address_rank >= NEW.rank_address
976 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
977 and ST_Contains(geometry, NEW.geometry)
978 and not ST_Equals(geometry, NEW.geometry)
979 ORDER BY prank.address_rank desc LIMIT 1
981 NEW.rank_address := location.rank_address + 2;
984 ELSEIF NEW.class = 'place'
985 and ST_GeometryType(NEW.geometry) in ('ST_Polygon', 'ST_MultiPolygon')
986 and NEW.rank_address between 16 and 23
988 -- For place areas make sure they are not completely contained in an area
989 -- with a equal or higher address rank.
993 LATERAL compute_place_rank(country_code, 'A', class, type,
994 admin_level, False, null) prank
995 WHERE prank.address_rank < 24
996 and rank_address between 1 and 25 -- select right index
997 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
998 and prank.address_rank >= NEW.rank_address
999 and ST_Contains(geometry, NEW.geometry)
1000 and not ST_Equals(geometry, NEW.geometry)
1001 ORDER BY prank.address_rank desc LIMIT 1
1003 NEW.rank_address := location.rank_address + 2;
1005 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
1006 and NEW.rank_address between 16 and 23
1008 -- If a place node is contained in an admin or place boundary with the same
1009 -- address level and has not been linked, then make the node a subpart
1010 -- by increasing the address rank (city level and above).
1014 LATERAL compute_place_rank(country_code, 'A', class, type,
1015 admin_level, False, null) prank
1016 WHERE osm_type = 'R'
1017 and rank_address between 1 and 25 -- select right index
1018 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
1019 and ((class = 'place' and prank.address_rank = NEW.rank_address)
1020 or (class = 'boundary' and rank_address = NEW.rank_address))
1021 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
1024 NEW.rank_address = NEW.rank_address + 2;
1027 parent_address_level := 3;
1030 NEW.housenumber := token_normalized_housenumber(NEW.token_info);
1032 NEW.postcode := null;
1034 -- waterway ways are linked when they are part of a relation and have the same class/type
1035 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1036 {% if db.middle_db_format == '1' %}
1037 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1039 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1040 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1041 {% if debug %}RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];{% endif %}
1042 FOR linked_node_id IN SELECT place_id FROM placex
1043 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1044 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1045 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1047 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1048 {% if 'search_name' in db.tables %}
1049 IF OLD.indexed_status > 1 THEN
1050 DELETE FROM search_name WHERE place_id = linked_node_id;
1058 FOR relation_member IN
1059 SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(r.members)
1060 WHERE r.id = NEW.osm_id
1062 IF relation_member->>'role' IN ('', 'main_stream', 'side_stream')
1063 and relation_member->>'type' = 'W'
1065 {% if debug %}RAISE WARNING 'waterway parent %, child %', NEW.osm_id, relation_member;{% endif %}
1066 FOR linked_node_id IN
1067 SELECT place_id FROM placex
1068 WHERE osm_type = 'W' and osm_id = (relation_member->>'ref')::bigint
1069 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1070 and (relation_member->>'role' != 'side_stream' or NEW.name->'name' = name->'name')
1072 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1073 {% if 'search_name' in db.tables %}
1074 DELETE FROM search_name WHERE place_id = linked_node_id;
1080 {% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
1083 NEW.importance := null;
1084 SELECT wikipedia, importance
1085 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.rank_search, NEW.centroid)
1086 INTO NEW.wikipedia,NEW.importance;
1088 {% if debug %}RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;{% endif %}
1090 -- ---------------------------------------------------------------------------
1091 -- For low level elements we inherit from our parent road
1092 IF NEW.rank_search > 27 THEN
1094 {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1095 NEW.parent_place_id := null;
1096 is_place_address := not token_is_street_address(NEW.token_info);
1098 -- We have to find our parent road.
1099 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
1101 ST_Envelope(NEW.geometry),
1105 -- If we found the road take a shortcut here.
1106 -- Otherwise fall back to the full address getting method below.
1107 IF NEW.parent_place_id is not null THEN
1109 -- Get the details of the parent road
1110 SELECT p.country_code, p.postcode, p.name FROM placex p
1111 WHERE p.place_id = NEW.parent_place_id INTO location;
1113 IF is_place_address and NEW.address ? 'place' THEN
1114 -- Check if the addr:place tag is part of the parent name
1115 SELECT count(*) INTO i
1116 FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
1118 NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
1122 NEW.country_code := location.country_code;
1123 {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
1125 -- determine postcode
1126 NEW.postcode := coalesce(token_get_postcode(NEW.token_info),
1128 get_nearest_postcode(NEW.country_code, NEW.centroid));
1130 IF NEW.name is not NULL THEN
1131 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1134 {% if not db.reverse_only %}
1135 IF NEW.name is not NULL OR NEW.address is not NULL THEN
1136 SELECT * INTO name_vector, nameaddress_vector
1137 FROM create_poi_search_terms(NEW.place_id,
1138 NEW.partition, NEW.parent_place_id,
1139 is_place_address, NEW.country_code,
1140 NEW.token_info, NEW.centroid);
1142 IF array_length(name_vector, 1) is not NULL THEN
1143 INSERT INTO search_name (place_id, search_rank, address_rank,
1144 importance, country_code, name_vector,
1145 nameaddress_vector, centroid)
1146 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1147 NEW.importance, NEW.country_code, name_vector,
1148 nameaddress_vector, NEW.centroid);
1149 {% if debug %}RAISE WARNING 'Place added to search table';{% endif %}
1154 NEW.token_info := token_strip_info(NEW.token_info);
1161 -- ---------------------------------------------------------------------------
1163 {% if debug %}RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1164 IF linked_place is not null THEN
1165 -- Recompute the ranks here as the ones from the linked place might
1166 -- have been shifted to accommodate surrounding boundaries.
1167 SELECT place_id, osm_id, class, type, extratags, rank_search,
1169 (compute_place_rank(country_code, osm_type, class, type, admin_level,
1170 (extratags->'capital') = 'yes', null)).*
1172 FROM placex WHERE place_id = linked_place;
1174 {% if debug %}RAISE WARNING 'Linked %', location;{% endif %}
1176 -- Use the linked point as the centre point of the geometry,
1177 -- but only if it is within the area of the boundary.
1178 geom := coalesce(location.centroid, ST_Centroid(location.geometry));
1179 IF geom is not NULL AND ST_Within(geom, NEW.geometry) THEN
1180 NEW.centroid := geom;
1183 {% if debug %}RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.address_rank;{% endif %}
1184 IF location.address_rank > parent_address_level
1185 and location.address_rank < 26
1187 NEW.rank_address := location.address_rank;
1190 -- merge in extra tags
1191 NEW.extratags := hstore('linked_' || location.class, location.type)
1192 || coalesce(location.extratags, ''::hstore)
1193 || coalesce(NEW.extratags, ''::hstore);
1195 -- mark the linked place (excludes from search results)
1196 -- Force reindexing to remove any traces from the search indexes and
1197 -- reset the address rank if necessary.
1198 UPDATE placex set linked_place_id = NEW.place_id, indexed_status = 2
1199 WHERE place_id = location.place_id;
1201 SELECT wikipedia, importance
1202 FROM compute_importance(location.extratags, NEW.country_code,
1203 location.rank_search, NEW.centroid)
1204 INTO linked_wikipedia,linked_importance;
1206 -- Use the maximum importance if one could be computed from the linked object.
1207 IF linked_importance is not null AND
1208 (NEW.importance is null or NEW.importance < linked_importance)
1210 NEW.importance := linked_importance;
1213 -- No linked place? As a last resort check if the boundary is tagged with
1214 -- a place type and adapt the rank address.
1215 IF NEW.rank_address between 4 and 25 and NEW.extratags ? 'place' THEN
1216 SELECT address_rank INTO place_address_level
1217 FROM compute_place_rank(NEW.country_code, 'A', 'place',
1218 NEW.extratags->'place', 0::SMALLINT, False, null);
1219 IF place_address_level > parent_address_level and
1220 place_address_level < 26 THEN
1221 NEW.rank_address := place_address_level;
1226 {% if not disable_diff_updates %}
1227 IF OLD.rank_address != NEW.rank_address THEN
1228 -- After a rank shift all addresses containing us must be updated.
1229 UPDATE placex p SET indexed_status = 2 FROM place_addressline pa
1230 WHERE pa.address_place_id = NEW.place_id and p.place_id = pa.place_id
1231 and p.indexed_status = 0 and p.rank_address between 4 and 25;
1235 IF NEW.admin_level = 2
1236 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
1237 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
1239 -- Update the list of country names.
1240 -- Only take the name from the largest area for the given country code
1241 -- in the hope that this is the authoritative one.
1242 -- Also replace any old names so that all mapping mistakes can
1243 -- be fixed through regular OSM updates.
1245 SELECT osm_id FROM placex
1246 WHERE rank_search = 4 and osm_type = 'R'
1247 and country_code = NEW.country_code
1248 ORDER BY ST_Area(geometry) desc
1251 IF location.osm_id = NEW.osm_id THEN
1252 {% if debug %}RAISE WARNING 'Updating names for country ''%'' with: %', NEW.country_code, NEW.name;{% endif %}
1253 UPDATE country_name SET derived_name = NEW.name WHERE country_code = NEW.country_code;
1258 -- For linear features we need the full geometry for determining the address
1259 -- because they may go through several administrative entities. Otherwise use
1260 -- the centroid for performance reasons.
1261 IF ST_GeometryType(NEW.geometry) in ('ST_LineString', 'ST_MultiLineString') THEN
1262 geom := NEW.geometry;
1264 geom := NEW.centroid;
1267 IF NEW.rank_address = 0 THEN
1268 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
1269 -- Rank 0 features may also span multiple administrative areas (e.g. lakes)
1270 -- so use the geometry here too. Just make sure the areas don't become too
1272 IF NEW.class = 'natural' or max_rank > 10 THEN
1273 geom := NEW.geometry;
1275 ELSEIF NEW.rank_address > 25 THEN
1278 max_rank := NEW.rank_address;
1281 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
1282 NEW.token_info, geom, NEW.centroid,
1284 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
1286 {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
1288 NEW.postcode := coalesce(token_get_postcode(NEW.token_info), NEW.postcode);
1290 -- if we have a name add this to the name search table
1291 name_vector := token_get_name_search_tokens(NEW.token_info);
1292 IF array_length(name_vector, 1) is not NULL THEN
1293 -- Initialise the name vector using our name
1294 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1296 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1297 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
1298 name_vector, NEW.rank_search, NEW.rank_address,
1299 NEW.postcode, NEW.geometry, NEW.centroid);
1300 {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
1303 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1304 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1305 {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
1308 IF NEW.rank_address between 16 and 27 THEN
1309 result := insertSearchName(NEW.partition, NEW.place_id,
1310 token_get_name_match_tokens(NEW.token_info),
1311 NEW.rank_search, NEW.rank_address, NEW.geometry);
1313 {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
1315 {% if not db.reverse_only %}
1316 INSERT INTO search_name (place_id, search_rank, address_rank,
1317 importance, country_code, name_vector,
1318 nameaddress_vector, centroid)
1319 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1320 NEW.importance, NEW.country_code, name_vector,
1321 nameaddress_vector, NEW.centroid);
1325 IF NEW.postcode is null AND NEW.rank_search > 8
1326 AND (NEW.rank_address > 0
1327 OR ST_GeometryType(NEW.geometry) not in ('ST_LineString','ST_MultiLineString')
1328 OR ST_Length(NEW.geometry) < 0.02)
1330 NEW.postcode := get_nearest_postcode(NEW.country_code,
1331 CASE WHEN NEW.rank_address > 25
1332 THEN NEW.centroid ELSE NEW.geometry END);
1335 {% if debug %}RAISE WARNING 'place update % % finished.', NEW.osm_type, NEW.osm_id;{% endif %}
1337 NEW.token_info := token_strip_info(NEW.token_info);
1344 CREATE OR REPLACE FUNCTION placex_delete()
1352 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1354 IF OLD.linked_place_id is null THEN
1356 SET linked_place_id = NULL,
1357 indexed_status = CASE WHEN indexed_status = 0 THEN 2 ELSE indexed_status END
1358 WHERE linked_place_id = OLD.place_id;
1360 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1363 IF OLD.rank_address < 30 THEN
1365 -- mark everything linked to this place for re-indexing
1366 {% if debug %}RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1367 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1368 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1370 {% if debug %}RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1371 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1373 {% if debug %}RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1374 b := deleteRoad(OLD.partition, OLD.place_id);
1376 {% if debug %}RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1377 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1378 {% if debug %}RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1379 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1380 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1382 UPDATE location_postcodes SET indexed_status = 2 WHERE parent_place_id = OLD.place_id;
1385 {% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1387 IF OLD.rank_address < 26 THEN
1388 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1391 {% if debug %}RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1393 IF OLD.name is not null THEN
1394 {% if 'search_name' in db.tables %}
1395 DELETE from search_name WHERE place_id = OLD.place_id;
1397 b := deleteSearchName(OLD.partition, OLD.place_id);
1400 {% if debug %}RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1402 DELETE FROM place_addressline where place_id = OLD.place_id;
1404 {% if debug %}RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1406 -- remove from tables for special search
1407 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1408 SELECT count(*) INTO result
1410 WHERE classtable NOT SIMILAR TO '%\W%'
1411 AND tablename = classtable and schemaname = current_schema();
1414 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1417 {% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}