1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2024 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;
33 IF not p.address ? '_inherited' THEN
34 result.address := p.address;
37 -- For POI nodes, check if the address should be derived from a surrounding
39 IF p.rank_search = 30 AND p.osm_type = 'N' THEN
40 IF p.address is null THEN
41 -- The additional && condition works around the misguided query
42 -- planner of postgis 3.0.
43 SELECT placex.address || hstore('_inherited', '') INTO result.address
45 WHERE ST_Covers(geometry, p.centroid)
46 and geometry && p.centroid
47 and placex.address is not null
48 and (placex.address ? 'housenumber' or placex.address ? 'street' or placex.address ? 'place')
49 and rank_search = 30 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
52 -- See if we can inherit additional address tags from an interpolation.
53 -- These will become permanent.
55 SELECT (address - 'interpolation'::text - 'housenumber'::text) as address
56 FROM place, planet_osm_ways w
57 WHERE place.osm_type = 'W' and place.address ? 'interpolation'
58 and place.geometry && p.geometry
59 and place.osm_id = w.id
60 and p.osm_id = any(w.nodes)
62 result.address := location.address || result.address;
67 -- remove internal and derived names
68 result.address := result.address - '_unlisted_place'::TEXT;
69 SELECT hstore(array_agg(key), array_agg(value)) INTO result.name
70 FROM each(p.name) WHERE key not like '\_%';
72 result.class := p.class;
73 result.type := p.type;
74 result.country_code := p.country_code;
75 result.rank_address := p.rank_address;
76 result.centroid_x := ST_X(p.centroid);
77 result.centroid_y := ST_Y(p.centroid);
79 -- Names of linked places need to be merged in, so search for a linkable
80 -- place already here.
81 SELECT * INTO location FROM find_linked_place(p);
83 IF location.place_id is not NULL THEN
84 result.linked_place_id := location.place_id;
86 IF location.name is not NULL THEN
87 {% if debug %}RAISE WARNING 'Names original: %, location: %', result.name, location.name;{% endif %}
88 -- Add all names from the place nodes that deviate from the name
89 -- in the relation with the prefix '_place_'. Deviation means that
90 -- either the value is different or a given key is missing completely
91 IF result.name is null THEN
92 SELECT hstore(array_agg('_place_' || key), array_agg(value))
94 FROM each(location.name);
96 SELECT hstore(array_agg('_place_' || key), array_agg(value)) INTO extra_names
97 FROM each(location.name - result.name);
98 {% if debug %}RAISE WARNING 'Extra names: %', extra_names;{% endif %}
100 IF extra_names is not null THEN
101 result.name := result.name || extra_names;
105 {% if debug %}RAISE WARNING 'Final names: %', result.name;{% endif %}
112 LANGUAGE plpgsql STABLE;
115 CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
129 {% if db.middle_db_format == '1' %}
131 SELECT members FROM planet_osm_rels
132 WHERE parts @> ARRAY[poi_osm_id]
133 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
134 and tags @> ARRAY['associatedStreet']
136 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
137 IF location.members[i+1] = 'street' THEN
139 SELECT place_id, geometry
141 WHERE osm_type = upper(substring(location.members[i], 1, 1))::char(1)
142 and osm_id = substring(location.members[i], 2)::bigint
144 and rank_search between 26 and 27
146 -- Find the closest 'street' member.
147 -- Avoid distance computation for the frequent case where there is
148 -- only one street member.
149 IF waygeom is null THEN
150 result := parent.place_id;
151 waygeom := parent.geometry;
153 distance := coalesce(distance, ST_Distance(waygeom, bbox));
154 new_distance := ST_Distance(parent.geometry, bbox);
155 IF new_distance < distance THEN
156 distance := new_distance;
157 result := parent.place_id;
158 waygeom := parent.geometry;
168 SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(members)
169 WHERE planet_osm_member_ids(members, poi_osm_type::char(1)) && ARRAY[poi_osm_id]
170 and tags->>'type' = 'associatedStreet'
171 and value->>'role' = 'street'
174 SELECT place_id, geometry
176 WHERE osm_type = (member->>'type')::char(1)
177 and osm_id = (member->>'ref')::bigint
179 and rank_search between 26 and 27
181 -- Find the closest 'street' member.
182 -- Avoid distance computation for the frequent case where there is
183 -- only one street member.
184 IF waygeom is null THEN
185 result := parent.place_id;
186 waygeom := parent.geometry;
188 distance := coalesce(distance, ST_Distance(waygeom, bbox));
189 new_distance := ST_Distance(parent.geometry, bbox);
190 IF new_distance < distance THEN
191 distance := new_distance;
192 result := parent.place_id;
193 waygeom := parent.geometry;
203 LANGUAGE plpgsql STABLE;
206 -- Find the parent road of a POI.
208 -- \returns Place ID of parent object or NULL if none
210 -- Copy data from linked items (POIs on ways, addr:street links, relations).
212 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
214 poi_partition SMALLINT,
217 is_place_addr BOOLEAN)
221 parent_place_id BIGINT DEFAULT NULL;
224 {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
226 -- Is this object part of an associatedStreet relation?
227 parent_place_id := find_associated_street(poi_osm_type, poi_osm_id, bbox);
229 IF parent_place_id is null THEN
230 parent_place_id := find_parent_for_address(token_info, poi_partition, bbox);
233 IF parent_place_id is null and poi_osm_type = 'N' THEN
235 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
236 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
237 FROM placex p, planet_osm_ways w
238 WHERE p.osm_type = 'W' and p.rank_search >= 26
239 and p.geometry && bbox
240 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
242 {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
244 -- Way IS a road then we are on it - that must be our road
245 IF location.rank_search < 28 THEN
246 {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
247 RETURN location.place_id;
250 parent_place_id := find_associated_street('W', location.osm_id, bbox);
254 IF parent_place_id is NULL THEN
255 IF is_place_addr THEN
256 -- The address is attached to a place we don't know.
257 -- Instead simply use the containing area with the largest rank.
259 SELECT place_id FROM placex
260 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
261 AND rank_address between 5 and 25
262 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
263 ORDER BY rank_address desc
265 RETURN location.place_id;
267 ELSEIF ST_Area(bbox) < 0.005 THEN
268 -- for smaller features get the nearest road
269 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
270 {% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
272 -- for larger features simply find the area with the largest rank that
273 -- contains the bbox, only use addressable features
275 SELECT place_id FROM placex
276 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
277 AND rank_address between 5 and 25
278 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
279 ORDER BY rank_address desc
281 RETURN location.place_id;
286 RETURN parent_place_id;
289 LANGUAGE plpgsql STABLE;
291 -- Try to find a linked place for the given object.
292 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
296 {% if db.middle_db_format == '1' %}
297 relation_members TEXT[];
299 relation_members JSONB;
302 linked_placex placex%ROWTYPE;
305 IF bnd.rank_search >= 26 or bnd.rank_address = 0
306 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
307 or bnd.type IN ('postcode', 'postal_code')
312 IF bnd.osm_type = 'R' THEN
313 -- see if we have any special relation members
314 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
315 {% if debug %}RAISE WARNING 'Got relation members';{% endif %}
317 -- Search for relation members with role 'lable'.
318 IF relation_members IS NOT NULL THEN
320 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
322 {% if debug %}RAISE WARNING 'Found label member %', rel_member.member;{% endif %}
326 WHERE osm_type = 'N' and osm_id = rel_member.member
329 {% if debug %}RAISE WARNING 'Linked label member';{% endif %}
330 RETURN linked_placex;
337 IF bnd.name ? 'name' THEN
338 bnd_name := lower(bnd.name->'name');
339 IF bnd_name = '' THEN
344 -- If extratags has a place tag, look for linked nodes by their place type.
345 -- Area and node still have to have the same name.
346 IF bnd.extratags ? 'place' and bnd.extratags->'place' != 'postcode'
347 and bnd_name is not null
351 WHERE (position(lower(name->'name') in bnd_name) > 0
352 OR position(bnd_name in lower(name->'name')) > 0)
353 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
354 AND placex.osm_type = 'N'
355 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
356 AND placex.rank_search < 26 -- needed to select the right index
357 AND ST_Covers(bnd.geometry, placex.geometry)
359 {% if debug %}RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;{% endif %}
360 RETURN linked_placex;
364 IF bnd.extratags ? 'wikidata' THEN
367 WHERE placex.class = 'place' AND placex.osm_type = 'N'
368 AND placex.extratags ? 'wikidata' -- needed to select right index
369 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
370 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
371 AND placex.rank_search < 26
372 AND _st_covers(bnd.geometry, placex.geometry)
373 ORDER BY lower(name->'name') = bnd_name desc
375 {% if debug %}RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;{% endif %}
376 RETURN linked_placex;
380 -- Name searches can be done for ways as well as relations
381 IF bnd_name is not null THEN
382 {% if debug %}RAISE WARNING 'Looking for nodes with matching names';{% endif %}
384 SELECT placex.* from placex
385 WHERE lower(name->'name') = bnd_name
386 AND ((bnd.rank_address > 0
387 and bnd.rank_address = (compute_place_rank(placex.country_code,
389 placex.type, 15::SMALLINT,
390 false, placex.postcode)).address_rank)
391 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
392 AND placex.osm_type = 'N'
393 AND placex.class = 'place'
394 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
395 AND placex.rank_search < 26 -- needed to select the right index
396 AND placex.type != 'postcode'
397 AND ST_Covers(bnd.geometry, placex.geometry)
399 {% if debug %}RAISE WARNING 'Found matching place node %', linked_placex.osm_id;{% endif %}
400 RETURN linked_placex;
407 LANGUAGE plpgsql STABLE;
410 CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
411 in_partition SMALLINT,
412 parent_place_id BIGINT,
413 is_place_addr BOOLEAN,
417 OUT name_vector INTEGER[],
418 OUT nameaddress_vector INTEGER[])
421 parent_name_vector INTEGER[];
422 parent_address_vector INTEGER[];
423 addr_place_ids INTEGER[];
424 hnr_vector INTEGER[];
428 parent_address_place_ids BIGINT[];
430 nameaddress_vector := '{}'::INTEGER[];
432 SELECT s.name_vector, s.nameaddress_vector
433 INTO parent_name_vector, parent_address_vector
435 WHERE s.place_id = parent_place_id;
439 token_get_address_search_tokens(token_info, key) as search_tokens
440 FROM token_get_address_keys(token_info) as key,
441 LATERAL get_addr_tag_rank(key, country) as ranks
442 WHERE not token_get_address_search_tokens(token_info, key) <@ parent_address_vector
444 addr_place := get_address_place(in_partition, geometry,
445 addr_item.from_rank, addr_item.to_rank,
446 addr_item.extent, token_info, addr_item.key);
448 IF addr_place is null THEN
449 -- No place found in OSM that matches. Make it at least searchable.
450 nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
452 IF parent_address_place_ids is null THEN
453 SELECT array_agg(parent_place_id) INTO parent_address_place_ids
454 FROM place_addressline
455 WHERE place_id = parent_place_id;
458 -- If the parent already lists the place in place_address line, then we
459 -- are done. Otherwise, add its own place_address line.
460 IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
461 nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
463 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
464 isaddress, distance, cached_rank_address)
465 VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
466 true, addr_place.distance, addr_place.rank_address);
471 name_vector := token_get_name_search_tokens(token_info);
473 -- Check if the parent covers all address terms.
474 -- If not, create a search name entry with the house number as the name.
475 -- This is unusual for the search_name table but prevents that the place
476 -- is returned when we only search for the street/place.
478 hnr_vector := token_get_housenumber_search_tokens(token_info);
480 IF hnr_vector is not null and not nameaddress_vector <@ parent_address_vector THEN
481 name_vector := array_merge(name_vector, hnr_vector);
484 IF is_place_addr THEN
485 addr_place_ids := token_addr_place_search_tokens(token_info);
486 IF not addr_place_ids <@ parent_name_vector THEN
487 -- make sure addr:place terms are always searchable
488 nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
489 -- If there is a housenumber, also add the place name as a name,
490 -- so we can search it by the usual housenumber+place algorithms.
491 IF hnr_vector is not null THEN
492 name_vector := array_merge(name_vector, addr_place_ids);
497 -- Cheating here by not recomputing all terms but simply using the ones
498 -- from the parent object.
499 nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
500 nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
507 -- Insert address of a place into the place_addressline table.
509 -- \param obj_place_id Place_id of the place to compute the address for.
510 -- \param partition Partition number where the place is in.
511 -- \param maxrank Rank of the place. All address features must have
512 -- a search rank lower than the given rank.
513 -- \param address Address terms for the place.
514 -- \param geometry Geometry to which the address objects should be close.
516 -- \retval parent_place_id Place_id of the address object that is the direct
518 -- \retval postcode Postcode computed from the address. This is the
519 -- addr:postcode of one of the address objects. If
520 -- more than one of has a postcode, the highest ranking
521 -- one is used. May be NULL.
522 -- \retval nameaddress_vector Search terms for the address. This is the sum
523 -- of name terms of all address objects.
524 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
531 OUT parent_place_id BIGINT,
533 OUT nameaddress_vector INT[])
536 address_havelevel BOOLEAN[];
538 location_isaddress BOOLEAN;
539 current_boundary GEOMETRY := NULL;
540 current_node_area GEOMETRY := NULL;
542 parent_place_rank INT := 0;
543 addr_place_ids BIGINT[] := '{}'::int[];
544 new_address_vector INT[];
548 parent_place_id := 0;
549 nameaddress_vector := '{}'::int[];
551 address_havelevel := array_fill(false, ARRAY[maxrank]);
555 FROM (SELECT extra.*, key
556 FROM token_get_address_keys(token_info) as key,
557 LATERAL get_addr_tag_rank(key, country) as extra) x,
558 LATERAL get_address_place(partition, geometry, from_rank, to_rank,
559 extent, token_info, key) as apl
560 ORDER BY rank_address, distance, isguess desc
562 IF location.place_id is null THEN
563 {% if not db.reverse_only %}
564 nameaddress_vector := array_merge(nameaddress_vector,
565 token_get_address_search_tokens(token_info,
569 {% if not db.reverse_only %}
570 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
573 location_isaddress := not address_havelevel[location.rank_address];
574 IF not address_havelevel[location.rank_address] THEN
575 address_havelevel[location.rank_address] := true;
576 IF parent_place_rank < location.rank_address THEN
577 parent_place_id := location.place_id;
578 parent_place_rank := location.rank_address;
582 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
583 isaddress, distance, cached_rank_address)
584 VALUES (obj_place_id, location.place_id, not location.isguess,
585 true, location.distance, location.rank_address);
587 addr_place_ids := addr_place_ids || location.place_id;
592 SELECT * FROM getNearFeatures(partition, geometry, centroid, maxrank)
593 WHERE not addr_place_ids @> ARRAY[place_id]
594 ORDER BY rank_address, isguess asc,
596 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
597 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
598 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
601 -- Ignore all place nodes that do not fit in a lower level boundary.
602 CONTINUE WHEN location.isguess
603 and current_boundary is not NULL
604 and not ST_Contains(current_boundary, location.centroid);
606 -- If this is the first item in the rank, then assume it is the address.
607 location_isaddress := not address_havelevel[location.rank_address];
609 -- Further sanity checks to ensure that the address forms a sane hierarchy.
610 IF location_isaddress THEN
611 IF location.isguess and current_node_area is not NULL THEN
612 location_isaddress := ST_Contains(current_node_area, location.centroid);
614 IF not location.isguess and current_boundary is not NULL
615 and location.rank_address != 11 AND location.rank_address != 5 THEN
616 location_isaddress := ST_Contains(current_boundary, location.centroid);
620 IF location_isaddress THEN
621 address_havelevel[location.rank_address] := true;
622 parent_place_id := location.place_id;
624 -- Set postcode if we have one.
625 -- (Returned will be the highest ranking one.)
626 IF location.postcode is not NULL THEN
627 postcode = location.postcode;
630 -- Recompute the areas we need for hierarchy sanity checks.
631 IF location.rank_address != 11 AND location.rank_address != 5 THEN
632 IF location.isguess THEN
633 current_node_area := place_node_fuzzy_area(location.centroid,
634 location.rank_search);
636 current_node_area := NULL;
637 SELECT p.geometry FROM placex p
638 WHERE p.place_id = location.place_id INTO current_boundary;
643 -- Add it to the list of search terms
644 {% if not db.reverse_only %}
645 nameaddress_vector := array_merge(nameaddress_vector,
646 location.keywords::integer[]);
649 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
650 isaddress, distance, cached_rank_address)
651 VALUES (obj_place_id, location.place_id, not location.isguess,
652 location_isaddress, location.distance, location.rank_address);
659 CREATE OR REPLACE FUNCTION placex_insert()
666 country_code VARCHAR(2);
670 {% if debug %}RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
672 NEW.place_id := nextval('seq_place');
673 NEW.indexed_status := 1; --STATUS_NEW
675 NEW.centroid := ST_PointOnSurface(NEW.geometry);
676 NEW.country_code := lower(get_country_code(NEW.centroid));
678 NEW.partition := get_partition(NEW.country_code);
679 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.centroid);
681 IF NEW.osm_type = 'X' THEN
682 -- E'X'ternal records should already be in the right format so do nothing
684 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
686 IF NEW.class in ('place','boundary')
687 AND NEW.type in ('postcode','postal_code')
689 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
690 -- most likely just a part of a multipolygon postcode boundary, throw it away
694 NEW.name := hstore('ref', NEW.address->'postcode');
696 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
697 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
700 ELSEIF NEW.class = 'boundary' AND NOT is_area
703 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
704 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
709 SELECT * INTO NEW.rank_search, NEW.rank_address
710 FROM compute_place_rank(NEW.country_code,
711 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
712 NEW.class, NEW.type, NEW.admin_level,
713 (NEW.extratags->'capital') = 'yes',
714 NEW.address->'postcode');
716 -- a country code make no sense below rank 4 (country)
717 IF NEW.rank_search < 4 THEN
718 NEW.country_code := NULL;
723 {% if debug %}RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
725 {% if not disable_diff_updates %}
726 -- The following is not needed until doing diff updates, and slows the main index process down
728 IF NEW.rank_address > 0 THEN
729 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
730 -- Performance: We just can't handle re-indexing for country level changes
731 IF st_area(NEW.geometry) < 1 THEN
732 -- mark items within the geometry for re-indexing
733 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
735 UPDATE placex SET indexed_status = 2
736 WHERE ST_Intersects(NEW.geometry, placex.geometry)
737 and indexed_status = 0
738 and ((rank_address = 0 and rank_search > NEW.rank_address)
739 or rank_address > NEW.rank_address
740 or (class = 'place' and osm_type = 'N')
742 and (rank_search < 28
744 or (NEW.rank_address >= 16 and address ? 'place'));
747 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
748 diameter := update_place_diameter(NEW.rank_search);
750 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
751 IF NEW.rank_search >= 26 THEN
752 -- roads may cause reparenting for >27 rank places
753 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
754 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
755 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);
756 ELSEIF NEW.rank_search >= 16 THEN
757 -- up to rank 16, street-less addresses may need reparenting
758 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');
760 -- for all other places the search terms may change as well
761 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);
768 -- add to tables for special search
769 -- Note: won't work on initial import because the classtype tables
770 -- do not yet exist. It won't hurt either.
771 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
772 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
774 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
775 USING NEW.place_id, ST_Centroid(NEW.geometry);
778 {% endif %} -- not disable_diff_updates
786 CREATE OR REPLACE FUNCTION placex_update()
792 {% if db.middle_db_format == '1' %}
793 relation_members TEXT[];
795 relation_member JSONB;
799 parent_address_level SMALLINT;
800 place_address_level SMALLINT;
804 name_vector INTEGER[];
805 nameaddress_vector INTEGER[];
806 addr_nameaddress_vector INTEGER[];
810 linked_node_id BIGINT;
811 linked_importance FLOAT;
812 linked_wikipedia TEXT;
814 is_place_address BOOLEAN;
818 IF OLD.indexed_status = 100 THEN
819 {% if debug %}RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;{% endif %}
820 delete from placex where place_id = OLD.place_id;
824 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
828 {% if debug %}RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;{% endif %}
830 NEW.indexed_date = now();
832 {% if 'search_name' in db.tables %}
833 DELETE from search_name WHERE place_id = NEW.place_id;
835 result := deleteSearchName(NEW.partition, NEW.place_id);
836 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
837 result := deleteRoad(NEW.partition, NEW.place_id);
838 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
840 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
841 IF NEW.extratags = ''::hstore THEN
842 NEW.extratags := NULL;
845 -- NEW.linked_place_id contains the precomputed linkee. Save this and restore
846 -- the previous link status.
847 linked_place := NEW.linked_place_id;
848 NEW.linked_place_id := OLD.linked_place_id;
850 -- Remove linkage, if we have computed a different new linkee.
851 UPDATE placex SET linked_place_id = null, indexed_status = 2
852 WHERE linked_place_id = NEW.place_id
853 and (linked_place is null or linked_place_id != linked_place);
854 -- update not necessary for osmline, cause linked_place_id does not exist
856 -- Postcodes are just here to compute the centroids. They are not searchable
857 -- unless they are a boundary=postal_code.
858 -- There was an error in the style so that boundary=postal_code used to be
859 -- imported as place=postcode. That's why relations are allowed to pass here.
860 -- This can go away in a couple of versions.
861 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
862 NEW.token_info := null;
866 -- Compute a preliminary centroid.
867 NEW.centroid := ST_PointOnSurface(NEW.geometry);
869 -- recalculate country and partition
870 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
871 -- for countries, believe the mapped country code,
872 -- so that we remain in the right partition if the boundaries
874 NEW.country_code := lower(NEW.address->'country');
875 NEW.partition := get_partition(lower(NEW.country_code));
876 IF NEW.partition = 0 THEN
877 NEW.country_code := lower(get_country_code(NEW.centroid));
878 NEW.partition := get_partition(NEW.country_code);
881 IF NEW.rank_search >= 4 THEN
882 NEW.country_code := lower(get_country_code(NEW.centroid));
884 NEW.country_code := NULL;
886 NEW.partition := get_partition(NEW.country_code);
888 {% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
891 -- recompute the ranks, they might change when linking changes
892 SELECT * INTO NEW.rank_search, NEW.rank_address
893 FROM compute_place_rank(NEW.country_code,
894 CASE WHEN ST_GeometryType(NEW.geometry)
895 IN ('ST_Polygon','ST_MultiPolygon')
896 THEN 'A' ELSE NEW.osm_type END,
897 NEW.class, NEW.type, NEW.admin_level,
898 (NEW.extratags->'capital') = 'yes',
899 NEW.address->'postcode');
901 -- Short-cut out for linked places. Note that this must happen after the
902 -- address rank has been recomputed. The linking might nullify a shift in
904 IF NEW.linked_place_id is not null THEN
905 NEW.token_info := null;
906 {% if debug %}RAISE WARNING 'place already linked to %', OLD.linked_place_id;{% endif %}
910 -- We must always increase the address level relative to the admin boundary.
911 IF NEW.class = 'boundary' and NEW.type = 'administrative'
912 and NEW.osm_type = 'R' and NEW.rank_address > 0
914 -- First, check that admin boundaries do not overtake each other rank-wise.
915 parent_address_level := 3;
918 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
919 and extratags->'wikidata' = NEW.extratags->'wikidata'
920 THEN ST_Equals(geometry, NEW.geometry)
921 ELSE false END) as is_same
923 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
924 and admin_level < NEW.admin_level and admin_level > 3
925 and rank_address between 1 and 25 -- for index selection
926 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- for index selection
927 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
928 ORDER BY admin_level desc LIMIT 1
930 IF location.is_same THEN
931 -- Looks like the same boundary is replicated on multiple admin_levels.
932 -- Usual tagging in Poland. Remove our boundary from addresses.
933 NEW.rank_address := 0;
935 parent_address_level := location.rank_address;
936 IF location.rank_address >= NEW.rank_address THEN
937 IF location.rank_address >= 24 THEN
938 NEW.rank_address := 25;
940 NEW.rank_address := location.rank_address + 2;
946 IF NEW.rank_address > 9 THEN
947 -- Second check that the boundary is not completely contained in a
948 -- place area with a equal or higher address rank.
952 LATERAL compute_place_rank(country_code, 'A', class, type,
953 admin_level, False, null) prank
954 WHERE class = 'place' and rank_address between 1 and 23
955 and prank.address_rank >= NEW.rank_address
956 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
957 and geometry && NEW.geometry
958 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
959 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
960 ORDER BY prank.address_rank desc LIMIT 1
962 NEW.rank_address := location.rank_address + 2;
965 ELSEIF NEW.class = 'place'
966 and ST_GeometryType(NEW.geometry) in ('ST_Polygon', 'ST_MultiPolygon')
967 and NEW.rank_address between 16 and 23
969 -- For place areas make sure they are not completely contained in an area
970 -- with a equal or higher address rank.
974 LATERAL compute_place_rank(country_code, 'A', class, type,
975 admin_level, False, null) prank
976 WHERE prank.address_rank < 24
977 and rank_address between 1 and 25 -- select right index
978 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
979 and prank.address_rank >= NEW.rank_address
980 and geometry && NEW.geometry
981 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
982 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
983 ORDER BY prank.address_rank desc LIMIT 1
985 NEW.rank_address := location.rank_address + 2;
987 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
988 and NEW.rank_address between 16 and 23
990 -- If a place node is contained in an admin or place boundary with the same
991 -- address level and has not been linked, then make the node a subpart
992 -- by increasing the address rank (city level and above).
996 LATERAL compute_place_rank(country_code, 'A', class, type,
997 admin_level, False, null) prank
999 and rank_address between 1 and 25 -- select right index
1000 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
1001 and ((class = 'place' and prank.address_rank = NEW.rank_address)
1002 or (class = 'boundary' and rank_address = NEW.rank_address))
1003 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
1006 NEW.rank_address = NEW.rank_address + 2;
1009 parent_address_level := 3;
1012 NEW.housenumber := token_normalized_housenumber(NEW.token_info);
1014 NEW.postcode := null;
1016 -- waterway ways are linked when they are part of a relation and have the same class/type
1017 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1018 {% if db.middle_db_format == '1' %}
1019 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1021 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1022 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1023 {% if debug %}RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];{% endif %}
1024 FOR linked_node_id IN SELECT place_id FROM placex
1025 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1026 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1027 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1029 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1030 {% if 'search_name' in db.tables %}
1031 DELETE FROM search_name WHERE place_id = linked_node_id;
1038 FOR relation_member IN
1039 SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(r.members)
1040 WHERE r.id = NEW.osm_id
1042 IF relation_member->>'role' IN ('', 'main_stream', 'side_stream')
1043 and relation_member->>'type' = 'W'
1045 {% if debug %}RAISE WARNING 'waterway parent %, child %', NEW.osm_id, relation_member;{% endif %}
1046 FOR linked_node_id IN
1047 SELECT place_id FROM placex
1048 WHERE osm_type = 'W' and osm_id = (relation_member->>'ref')::bigint
1049 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1050 and (relation_member->>'role' != 'side_stream' or NEW.name->'name' = name->'name')
1052 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1053 {% if 'search_name' in db.tables %}
1054 DELETE FROM search_name WHERE place_id = linked_node_id;
1060 {% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
1063 NEW.importance := null;
1064 SELECT wikipedia, importance
1065 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.rank_search, NEW.centroid)
1066 INTO NEW.wikipedia,NEW.importance;
1068 {% if debug %}RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;{% endif %}
1070 -- ---------------------------------------------------------------------------
1071 -- For low level elements we inherit from our parent road
1072 IF NEW.rank_search > 27 THEN
1074 {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1075 NEW.parent_place_id := null;
1076 is_place_address := not token_is_street_address(NEW.token_info);
1078 -- We have to find our parent road.
1079 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
1081 ST_Envelope(NEW.geometry),
1085 -- If we found the road take a shortcut here.
1086 -- Otherwise fall back to the full address getting method below.
1087 IF NEW.parent_place_id is not null THEN
1089 -- Get the details of the parent road
1090 SELECT p.country_code, p.postcode, p.name FROM placex p
1091 WHERE p.place_id = NEW.parent_place_id INTO location;
1093 IF is_place_address and NEW.address ? 'place' THEN
1094 -- Check if the addr:place tag is part of the parent name
1095 SELECT count(*) INTO i
1096 FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
1098 NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
1102 NEW.country_code := location.country_code;
1103 {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
1105 -- determine postcode
1106 NEW.postcode := coalesce(token_get_postcode(NEW.token_info),
1108 get_nearest_postcode(NEW.country_code, NEW.centroid));
1110 IF NEW.name is not NULL THEN
1111 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1114 {% if not db.reverse_only %}
1115 IF NEW.name is not NULL OR NEW.address is not NULL THEN
1116 SELECT * INTO name_vector, nameaddress_vector
1117 FROM create_poi_search_terms(NEW.place_id,
1118 NEW.partition, NEW.parent_place_id,
1119 is_place_address, NEW.country_code,
1120 NEW.token_info, NEW.centroid);
1122 IF array_length(name_vector, 1) is not NULL THEN
1123 INSERT INTO search_name (place_id, search_rank, address_rank,
1124 importance, country_code, name_vector,
1125 nameaddress_vector, centroid)
1126 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1127 NEW.importance, NEW.country_code, name_vector,
1128 nameaddress_vector, NEW.centroid);
1129 {% if debug %}RAISE WARNING 'Place added to search table';{% endif %}
1134 NEW.token_info := token_strip_info(NEW.token_info);
1141 -- ---------------------------------------------------------------------------
1143 {% if debug %}RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1144 IF linked_place is not null THEN
1145 -- Recompute the ranks here as the ones from the linked place might
1146 -- have been shifted to accommodate surrounding boundaries.
1147 SELECT place_id, osm_id, class, type, extratags, rank_search,
1149 (compute_place_rank(country_code, osm_type, class, type, admin_level,
1150 (extratags->'capital') = 'yes', null)).*
1152 FROM placex WHERE place_id = linked_place;
1154 {% if debug %}RAISE WARNING 'Linked %', location;{% endif %}
1156 -- Use the linked point as the centre point of the geometry,
1157 -- but only if it is within the area of the boundary.
1158 geom := coalesce(location.centroid, ST_Centroid(location.geometry));
1159 IF geom is not NULL AND ST_Within(geom, NEW.geometry) THEN
1160 NEW.centroid := geom;
1163 {% if debug %}RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.address_rank;{% endif %}
1164 IF location.address_rank > parent_address_level
1165 and location.address_rank < 26
1167 NEW.rank_address := location.address_rank;
1170 -- merge in extra tags
1171 NEW.extratags := hstore('linked_' || location.class, location.type)
1172 || coalesce(location.extratags, ''::hstore)
1173 || coalesce(NEW.extratags, ''::hstore);
1175 -- mark the linked place (excludes from search results)
1176 -- Force reindexing to remove any traces from the search indexes and
1177 -- reset the address rank if necessary.
1178 UPDATE placex set linked_place_id = NEW.place_id, indexed_status = 2
1179 WHERE place_id = location.place_id;
1180 -- ensure that those places are not found anymore
1181 {% if 'search_name' in db.tables %}
1182 DELETE FROM search_name WHERE place_id = location.place_id;
1184 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
1186 SELECT wikipedia, importance
1187 FROM compute_importance(location.extratags, NEW.country_code,
1188 location.rank_search, NEW.centroid)
1189 INTO linked_wikipedia,linked_importance;
1191 -- Use the maximum importance if one could be computed from the linked object.
1192 IF linked_importance is not null AND
1193 (NEW.importance is null or NEW.importance < linked_importance)
1195 NEW.importance = linked_importance;
1198 -- No linked place? As a last resort check if the boundary is tagged with
1199 -- a place type and adapt the rank address.
1200 IF NEW.rank_address between 4 and 25 and NEW.extratags ? 'place' THEN
1201 SELECT address_rank INTO place_address_level
1202 FROM compute_place_rank(NEW.country_code, 'A', 'place',
1203 NEW.extratags->'place', 0::SMALLINT, False, null);
1204 IF place_address_level > parent_address_level and
1205 place_address_level < 26 THEN
1206 NEW.rank_address := place_address_level;
1211 {% if not disable_diff_updates %}
1212 IF OLD.rank_address != NEW.rank_address THEN
1213 -- After a rank shift all addresses containing us must be updated.
1214 UPDATE placex p SET indexed_status = 2 FROM place_addressline pa
1215 WHERE pa.address_place_id = NEW.place_id and p.place_id = pa.place_id
1216 and p.indexed_status = 0 and p.rank_address between 4 and 25;
1220 IF NEW.admin_level = 2
1221 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
1222 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
1224 -- Update the list of country names.
1225 -- Only take the name from the largest area for the given country code
1226 -- in the hope that this is the authoritative one.
1227 -- Also replace any old names so that all mapping mistakes can
1228 -- be fixed through regular OSM updates.
1230 SELECT osm_id FROM placex
1231 WHERE rank_search = 4 and osm_type = 'R'
1232 and country_code = NEW.country_code
1233 ORDER BY ST_Area(geometry) desc
1236 IF location.osm_id = NEW.osm_id THEN
1237 {% if debug %}RAISE WARNING 'Updating names for country '%' with: %', NEW.country_code, NEW.name;{% endif %}
1238 UPDATE country_name SET derived_name = NEW.name WHERE country_code = NEW.country_code;
1243 -- For linear features we need the full geometry for determining the address
1244 -- because they may go through several administrative entities. Otherwise use
1245 -- the centroid for performance reasons.
1246 IF ST_GeometryType(NEW.geometry) in ('ST_LineString', 'ST_MultiLineString') THEN
1247 geom := NEW.geometry;
1249 geom := NEW.centroid;
1252 IF NEW.rank_address = 0 THEN
1253 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
1254 -- Rank 0 features may also span multiple administrative areas (e.g. lakes)
1255 -- so use the geometry here too. Just make sure the areas don't become too
1257 IF NEW.class = 'natural' or max_rank > 10 THEN
1258 geom := NEW.geometry;
1260 ELSEIF NEW.rank_address > 25 THEN
1263 max_rank := NEW.rank_address;
1266 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
1267 NEW.token_info, geom, NEW.centroid,
1269 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
1271 {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
1273 NEW.postcode := coalesce(token_get_postcode(NEW.token_info), NEW.postcode);
1275 -- if we have a name add this to the name search table
1276 IF NEW.name IS NOT NULL THEN
1277 -- Initialise the name vector using our name
1278 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1279 name_vector := token_get_name_search_tokens(NEW.token_info);
1281 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1282 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
1283 name_vector, NEW.rank_search, NEW.rank_address,
1284 NEW.postcode, NEW.geometry, NEW.centroid);
1285 {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
1288 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1289 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1290 {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
1293 IF NEW.rank_address between 16 and 27 THEN
1294 result := insertSearchName(NEW.partition, NEW.place_id,
1295 token_get_name_match_tokens(NEW.token_info),
1296 NEW.rank_search, NEW.rank_address, NEW.geometry);
1298 {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
1300 {% if not db.reverse_only %}
1301 INSERT INTO search_name (place_id, search_rank, address_rank,
1302 importance, country_code, name_vector,
1303 nameaddress_vector, centroid)
1304 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1305 NEW.importance, NEW.country_code, name_vector,
1306 nameaddress_vector, NEW.centroid);
1310 IF NEW.postcode is null AND NEW.rank_search > 8
1311 AND (NEW.rank_address > 0
1312 OR ST_GeometryType(NEW.geometry) not in ('ST_LineString','ST_MultiLineString')
1313 OR ST_Length(NEW.geometry) < 0.02)
1315 NEW.postcode := get_nearest_postcode(NEW.country_code,
1316 CASE WHEN NEW.rank_address > 25
1317 THEN NEW.centroid ELSE NEW.geometry END);
1320 {% if debug %}RAISE WARNING 'place update % % finished.', NEW.osm_type, NEW.osm_id;{% endif %}
1322 NEW.token_info := token_strip_info(NEW.token_info);
1329 CREATE OR REPLACE FUNCTION placex_delete()
1336 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1338 IF OLD.linked_place_id is null THEN
1339 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1340 {% if debug %}RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1341 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1342 {% if debug %}RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1344 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1347 IF OLD.rank_address < 30 THEN
1349 -- mark everything linked to this place for re-indexing
1350 {% if debug %}RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1351 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1352 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1354 {% if debug %}RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1355 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1357 {% if debug %}RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1358 b := deleteRoad(OLD.partition, OLD.place_id);
1360 {% if debug %}RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1361 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1362 {% if debug %}RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1363 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1364 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1368 {% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1370 IF OLD.rank_address < 26 THEN
1371 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1374 {% if debug %}RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1376 IF OLD.name is not null THEN
1377 {% if 'search_name' in db.tables %}
1378 DELETE from search_name WHERE place_id = OLD.place_id;
1380 b := deleteSearchName(OLD.partition, OLD.place_id);
1383 {% if debug %}RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1385 DELETE FROM place_addressline where place_id = OLD.place_id;
1387 {% if debug %}RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1389 -- remove from tables for special search
1390 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1391 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1393 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1396 {% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}