1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2022 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 -- 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 SELECT members FROM planet_osm_rels
130 WHERE parts @> ARRAY[poi_osm_id]
131 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
132 and tags @> ARRAY['associatedStreet']
134 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
135 IF location.members[i+1] = 'street' THEN
137 SELECT place_id, geometry
139 WHERE osm_type = upper(substring(location.members[i], 1, 1))::char(1)
140 and osm_id = substring(location.members[i], 2)::bigint
142 and rank_search between 26 and 27
144 -- Find the closest 'street' member.
145 -- Avoid distance computation for the frequent case where there is
146 -- only one street member.
147 IF waygeom is null THEN
148 result := parent.place_id;
149 waygeom := parent.geometry;
151 distance := coalesce(distance, ST_Distance(waygeom, bbox));
152 new_distance := ST_Distance(parent.geometry, bbox);
153 IF new_distance < distance THEN
154 distance := new_distance;
155 result := parent.place_id;
156 waygeom := parent.geometry;
167 LANGUAGE plpgsql STABLE;
170 -- Find the parent road of a POI.
172 -- \returns Place ID of parent object or NULL if none
174 -- Copy data from linked items (POIs on ways, addr:street links, relations).
176 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
178 poi_partition SMALLINT,
181 is_place_addr BOOLEAN)
185 parent_place_id BIGINT DEFAULT NULL;
188 {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
190 -- Is this object part of an associatedStreet relation?
191 parent_place_id := find_associated_street(poi_osm_type, poi_osm_id, bbox);
193 IF parent_place_id is null THEN
194 parent_place_id := find_parent_for_address(token_info, poi_partition, bbox);
197 IF parent_place_id is null and poi_osm_type = 'N' THEN
199 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
200 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
201 FROM placex p, planet_osm_ways w
202 WHERE p.osm_type = 'W' and p.rank_search >= 26
203 and p.geometry && bbox
204 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
206 {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
208 -- Way IS a road then we are on it - that must be our road
209 IF location.rank_search < 28 THEN
210 {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
211 RETURN location.place_id;
214 parent_place_id := find_associated_street('W', location.osm_id, bbox);
218 IF parent_place_id is NULL THEN
219 IF is_place_addr THEN
220 -- The address is attached to a place we don't know.
221 -- Instead simply use the containing area with the largest rank.
223 SELECT place_id FROM placex
224 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
225 AND rank_address between 5 and 25
226 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
227 ORDER BY rank_address desc
229 RETURN location.place_id;
231 ELSEIF ST_Area(bbox) < 0.005 THEN
232 -- for smaller features get the nearest road
233 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
234 {% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
236 -- for larger features simply find the area with the largest rank that
237 -- contains the bbox, only use addressable features
239 SELECT place_id FROM placex
240 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
241 AND rank_address between 5 and 25
242 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
243 ORDER BY rank_address desc
245 RETURN location.place_id;
250 RETURN parent_place_id;
253 LANGUAGE plpgsql STABLE;
255 -- Try to find a linked place for the given object.
256 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
260 relation_members TEXT[];
262 linked_placex placex%ROWTYPE;
265 IF bnd.rank_search >= 26 or bnd.rank_address = 0
266 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
267 or bnd.type IN ('postcode', 'postal_code')
272 IF bnd.osm_type = 'R' THEN
273 -- see if we have any special relation members
274 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
275 {% if debug %}RAISE WARNING 'Got relation members';{% endif %}
277 -- Search for relation members with role 'lable'.
278 IF relation_members IS NOT NULL THEN
280 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
282 {% if debug %}RAISE WARNING 'Found label member %', rel_member.member;{% endif %}
286 WHERE osm_type = 'N' and osm_id = rel_member.member
289 {% if debug %}RAISE WARNING 'Linked label member';{% endif %}
290 RETURN linked_placex;
297 IF bnd.name ? 'name' THEN
298 bnd_name := lower(bnd.name->'name');
299 IF bnd_name = '' THEN
304 -- If extratags has a place tag, look for linked nodes by their place type.
305 -- Area and node still have to have the same name.
306 IF bnd.extratags ? 'place' and bnd.extratags->'place' != 'postcode'
307 and bnd_name is not null
311 WHERE (position(lower(name->'name') in bnd_name) > 0
312 OR position(bnd_name in lower(name->'name')) > 0)
313 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
314 AND placex.osm_type = 'N'
315 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
316 AND placex.rank_search < 26 -- needed to select the right index
317 AND ST_Covers(bnd.geometry, placex.geometry)
319 {% if debug %}RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;{% endif %}
320 RETURN linked_placex;
324 IF bnd.extratags ? 'wikidata' THEN
327 WHERE placex.class = 'place' AND placex.osm_type = 'N'
328 AND placex.extratags ? 'wikidata' -- needed to select right index
329 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
330 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
331 AND placex.rank_search < 26
332 AND _st_covers(bnd.geometry, placex.geometry)
333 ORDER BY lower(name->'name') = bnd_name desc
335 {% if debug %}RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;{% endif %}
336 RETURN linked_placex;
340 -- Name searches can be done for ways as well as relations
341 IF bnd_name is not null THEN
342 {% if debug %}RAISE WARNING 'Looking for nodes with matching names';{% endif %}
344 SELECT placex.* from placex
345 WHERE lower(name->'name') = bnd_name
346 AND ((bnd.rank_address > 0
347 and bnd.rank_address = (compute_place_rank(placex.country_code,
349 placex.type, 15::SMALLINT,
350 false, placex.postcode)).address_rank)
351 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
352 AND placex.osm_type = 'N'
353 AND placex.class = 'place'
354 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
355 AND placex.rank_search < 26 -- needed to select the right index
356 AND placex.type != 'postcode'
357 AND ST_Covers(bnd.geometry, placex.geometry)
359 {% if debug %}RAISE WARNING 'Found matching place node %', linked_placex.osm_id;{% endif %}
360 RETURN linked_placex;
367 LANGUAGE plpgsql STABLE;
370 CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
371 in_partition SMALLINT,
372 parent_place_id BIGINT,
373 is_place_addr BOOLEAN,
377 OUT name_vector INTEGER[],
378 OUT nameaddress_vector INTEGER[])
381 parent_name_vector INTEGER[];
382 parent_address_vector INTEGER[];
383 addr_place_ids INTEGER[];
384 hnr_vector INTEGER[];
388 parent_address_place_ids BIGINT[];
390 nameaddress_vector := '{}'::INTEGER[];
392 SELECT s.name_vector, s.nameaddress_vector
393 INTO parent_name_vector, parent_address_vector
395 WHERE s.place_id = parent_place_id;
399 token_get_address_search_tokens(token_info, key) as search_tokens
400 FROM token_get_address_keys(token_info) as key,
401 LATERAL get_addr_tag_rank(key, country) as ranks
402 WHERE not token_get_address_search_tokens(token_info, key) <@ parent_address_vector
404 addr_place := get_address_place(in_partition, geometry,
405 addr_item.from_rank, addr_item.to_rank,
406 addr_item.extent, token_info, addr_item.key);
408 IF addr_place is null THEN
409 -- No place found in OSM that matches. Make it at least searchable.
410 nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
412 IF parent_address_place_ids is null THEN
413 SELECT array_agg(parent_place_id) INTO parent_address_place_ids
414 FROM place_addressline
415 WHERE place_id = parent_place_id;
418 -- If the parent already lists the place in place_address line, then we
419 -- are done. Otherwise, add its own place_address line.
420 IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
421 nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
423 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
424 isaddress, distance, cached_rank_address)
425 VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
426 true, addr_place.distance, addr_place.rank_address);
431 name_vector := token_get_name_search_tokens(token_info);
433 -- Check if the parent covers all address terms.
434 -- If not, create a search name entry with the house number as the name.
435 -- This is unusual for the search_name table but prevents that the place
436 -- is returned when we only search for the street/place.
438 hnr_vector := token_get_housenumber_search_tokens(token_info);
440 IF hnr_vector is not null and not nameaddress_vector <@ parent_address_vector THEN
441 name_vector := array_merge(name_vector, hnr_vector);
444 IF is_place_addr THEN
445 addr_place_ids := token_addr_place_search_tokens(token_info);
446 IF not addr_place_ids <@ parent_name_vector THEN
447 -- make sure addr:place terms are always searchable
448 nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
449 -- If there is a housenumber, also add the place name as a name,
450 -- so we can search it by the usual housenumber+place algorithms.
451 IF hnr_vector is not null THEN
452 name_vector := array_merge(name_vector, addr_place_ids);
457 -- Cheating here by not recomputing all terms but simply using the ones
458 -- from the parent object.
459 nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
460 nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
467 -- Insert address of a place into the place_addressline table.
469 -- \param obj_place_id Place_id of the place to compute the address for.
470 -- \param partition Partition number where the place is in.
471 -- \param maxrank Rank of the place. All address features must have
472 -- a search rank lower than the given rank.
473 -- \param address Address terms for the place.
474 -- \param geometry Geometry to which the address objects should be close.
476 -- \retval parent_place_id Place_id of the address object that is the direct
478 -- \retval postcode Postcode computed from the address. This is the
479 -- addr:postcode of one of the address objects. If
480 -- more than one of has a postcode, the highest ranking
481 -- one is used. May be NULL.
482 -- \retval nameaddress_vector Search terms for the address. This is the sum
483 -- of name terms of all address objects.
484 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
491 OUT parent_place_id BIGINT,
493 OUT nameaddress_vector INT[])
496 address_havelevel BOOLEAN[];
498 location_isaddress BOOLEAN;
499 current_boundary GEOMETRY := NULL;
500 current_node_area GEOMETRY := NULL;
502 parent_place_rank INT := 0;
503 addr_place_ids BIGINT[] := '{}'::int[];
504 new_address_vector INT[];
508 parent_place_id := 0;
509 nameaddress_vector := '{}'::int[];
511 address_havelevel := array_fill(false, ARRAY[maxrank]);
515 FROM (SELECT extra.*, key
516 FROM token_get_address_keys(token_info) as key,
517 LATERAL get_addr_tag_rank(key, country) as extra) x,
518 LATERAL get_address_place(partition, geometry, from_rank, to_rank,
519 extent, token_info, key) as apl
520 ORDER BY rank_address, distance, isguess desc
522 IF location.place_id is null THEN
523 {% if not db.reverse_only %}
524 nameaddress_vector := array_merge(nameaddress_vector,
525 token_get_address_search_tokens(token_info,
529 {% if not db.reverse_only %}
530 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
533 location_isaddress := not address_havelevel[location.rank_address];
534 IF not address_havelevel[location.rank_address] THEN
535 address_havelevel[location.rank_address] := true;
536 IF parent_place_rank < location.rank_address THEN
537 parent_place_id := location.place_id;
538 parent_place_rank := location.rank_address;
542 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
543 isaddress, distance, cached_rank_address)
544 VALUES (obj_place_id, location.place_id, not location.isguess,
545 true, location.distance, location.rank_address);
547 addr_place_ids := addr_place_ids || location.place_id;
552 SELECT * FROM getNearFeatures(partition, geometry, centroid, maxrank)
553 WHERE not addr_place_ids @> ARRAY[place_id]
554 ORDER BY rank_address, isguess asc,
556 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
557 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
558 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
561 -- Ignore all place nodes that do not fit in a lower level boundary.
562 CONTINUE WHEN location.isguess
563 and current_boundary is not NULL
564 and not ST_Contains(current_boundary, location.centroid);
566 -- If this is the first item in the rank, then assume it is the address.
567 location_isaddress := not address_havelevel[location.rank_address];
569 -- Further sanity checks to ensure that the address forms a sane hierarchy.
570 IF location_isaddress THEN
571 IF location.isguess and current_node_area is not NULL THEN
572 location_isaddress := ST_Contains(current_node_area, location.centroid);
574 IF not location.isguess and current_boundary is not NULL
575 and location.rank_address != 11 AND location.rank_address != 5 THEN
576 location_isaddress := ST_Contains(current_boundary, location.centroid);
580 IF location_isaddress THEN
581 address_havelevel[location.rank_address] := true;
582 parent_place_id := location.place_id;
584 -- Set postcode if we have one.
585 -- (Returned will be the highest ranking one.)
586 IF location.postcode is not NULL THEN
587 postcode = location.postcode;
590 -- Recompute the areas we need for hierarchy sanity checks.
591 IF location.rank_address != 11 AND location.rank_address != 5 THEN
592 IF location.isguess THEN
593 current_node_area := place_node_fuzzy_area(location.centroid,
594 location.rank_search);
596 current_node_area := NULL;
597 SELECT p.geometry FROM placex p
598 WHERE p.place_id = location.place_id INTO current_boundary;
603 -- Add it to the list of search terms
604 {% if not db.reverse_only %}
605 nameaddress_vector := array_merge(nameaddress_vector,
606 location.keywords::integer[]);
609 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
610 isaddress, distance, cached_rank_address)
611 VALUES (obj_place_id, location.place_id, not location.isguess,
612 location_isaddress, location.distance, location.rank_address);
619 CREATE OR REPLACE FUNCTION placex_insert()
626 country_code VARCHAR(2);
630 {% if debug %}RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
632 NEW.place_id := nextval('seq_place');
633 NEW.indexed_status := 1; --STATUS_NEW
635 NEW.centroid := ST_PointOnSurface(NEW.geometry);
636 NEW.country_code := lower(get_country_code(NEW.centroid));
638 NEW.partition := get_partition(NEW.country_code);
639 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.centroid);
641 IF NEW.osm_type = 'X' THEN
642 -- E'X'ternal records should already be in the right format so do nothing
644 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
646 IF NEW.class in ('place','boundary')
647 AND NEW.type in ('postcode','postal_code')
649 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
650 -- most likely just a part of a multipolygon postcode boundary, throw it away
654 NEW.name := hstore('ref', NEW.address->'postcode');
656 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
657 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
660 ELSEIF NEW.class = 'boundary' AND NOT is_area
663 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
664 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
669 SELECT * INTO NEW.rank_search, NEW.rank_address
670 FROM compute_place_rank(NEW.country_code,
671 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
672 NEW.class, NEW.type, NEW.admin_level,
673 (NEW.extratags->'capital') = 'yes',
674 NEW.address->'postcode');
676 -- a country code make no sense below rank 4 (country)
677 IF NEW.rank_search < 4 THEN
678 NEW.country_code := NULL;
683 {% if debug %}RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
685 {% if not disable_diff_updates %}
686 -- The following is not needed until doing diff updates, and slows the main index process down
688 IF NEW.rank_address > 0 THEN
689 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
690 -- Performance: We just can't handle re-indexing for country level changes
691 IF st_area(NEW.geometry) < 1 THEN
692 -- mark items within the geometry for re-indexing
693 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
695 UPDATE placex SET indexed_status = 2
696 WHERE ST_Intersects(NEW.geometry, placex.geometry)
697 and indexed_status = 0
698 and ((rank_address = 0 and rank_search > NEW.rank_address)
699 or rank_address > NEW.rank_address
700 or (class = 'place' and osm_type = 'N')
702 and (rank_search < 28
704 or (NEW.rank_address >= 16 and address ? 'place'));
707 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
708 diameter := update_place_diameter(NEW.rank_search);
710 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
711 IF NEW.rank_search >= 26 THEN
712 -- roads may cause reparenting for >27 rank places
713 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
714 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
715 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);
716 ELSEIF NEW.rank_search >= 16 THEN
717 -- up to rank 16, street-less addresses may need reparenting
718 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');
720 -- for all other places the search terms may change as well
721 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);
728 -- add to tables for special search
729 -- Note: won't work on initial import because the classtype tables
730 -- do not yet exist. It won't hurt either.
731 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
732 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
734 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
735 USING NEW.place_id, ST_Centroid(NEW.geometry);
738 {% endif %} -- not disable_diff_updates
746 CREATE OR REPLACE FUNCTION placex_update()
752 relation_members TEXT[];
755 parent_address_level SMALLINT;
756 place_address_level SMALLINT;
760 name_vector INTEGER[];
761 nameaddress_vector INTEGER[];
762 addr_nameaddress_vector INTEGER[];
766 linked_node_id BIGINT;
767 linked_importance FLOAT;
768 linked_wikipedia TEXT;
770 is_place_address BOOLEAN;
774 IF OLD.indexed_status = 100 THEN
775 {% if debug %}RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;{% endif %}
776 delete from placex where place_id = OLD.place_id;
780 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
784 {% if debug %}RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;{% endif %}
786 NEW.indexed_date = now();
788 {% if 'search_name' in db.tables %}
789 DELETE from search_name WHERE place_id = NEW.place_id;
791 result := deleteSearchName(NEW.partition, NEW.place_id);
792 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
793 result := deleteRoad(NEW.partition, NEW.place_id);
794 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
796 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
798 -- NEW.linked_place_id contains the precomputed linkee. Save this and restore
799 -- the previous link status.
800 linked_place := NEW.linked_place_id;
801 NEW.linked_place_id := OLD.linked_place_id;
803 -- Remove linkage, if we have computed a different new linkee.
804 UPDATE placex SET linked_place_id = null, indexed_status = 2
805 WHERE linked_place_id = NEW.place_id
806 and (linked_place is null or linked_place_id != linked_place);
807 -- update not necessary for osmline, cause linked_place_id does not exist
809 -- Postcodes are just here to compute the centroids. They are not searchable
810 -- unless they are a boundary=postal_code.
811 -- There was an error in the style so that boundary=postal_code used to be
812 -- imported as place=postcode. That's why relations are allowed to pass here.
813 -- This can go away in a couple of versions.
814 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
815 NEW.token_info := null;
819 -- Compute a preliminary centroid.
820 NEW.centroid := ST_PointOnSurface(NEW.geometry);
822 -- recalculate country and partition
823 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
824 -- for countries, believe the mapped country code,
825 -- so that we remain in the right partition if the boundaries
827 NEW.country_code := lower(NEW.address->'country');
828 NEW.partition := get_partition(lower(NEW.country_code));
829 IF NEW.partition = 0 THEN
830 NEW.country_code := lower(get_country_code(NEW.centroid));
831 NEW.partition := get_partition(NEW.country_code);
834 IF NEW.rank_search >= 4 THEN
835 NEW.country_code := lower(get_country_code(NEW.centroid));
837 NEW.country_code := NULL;
839 NEW.partition := get_partition(NEW.country_code);
841 {% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
844 -- recompute the ranks, they might change when linking changes
845 SELECT * INTO NEW.rank_search, NEW.rank_address
846 FROM compute_place_rank(NEW.country_code,
847 CASE WHEN ST_GeometryType(NEW.geometry)
848 IN ('ST_Polygon','ST_MultiPolygon')
849 THEN 'A' ELSE NEW.osm_type END,
850 NEW.class, NEW.type, NEW.admin_level,
851 (NEW.extratags->'capital') = 'yes',
852 NEW.address->'postcode');
854 -- Short-cut out for linked places. Note that this must happen after the
855 -- address rank has been recomputed. The linking might nullify a shift in
857 IF NEW.linked_place_id is not null THEN
858 NEW.token_info := null;
859 {% if debug %}RAISE WARNING 'place already linked to %', OLD.linked_place_id;{% endif %}
863 -- We must always increase the address level relative to the admin boundary.
864 IF NEW.class = 'boundary' and NEW.type = 'administrative'
865 and NEW.osm_type = 'R' and NEW.rank_address > 0
867 -- First, check that admin boundaries do not overtake each other rank-wise.
868 parent_address_level := 3;
871 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
872 and extratags->'wikidata' = NEW.extratags->'wikidata'
873 THEN ST_Equals(geometry, NEW.geometry)
874 ELSE false END) as is_same
876 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
877 and admin_level < NEW.admin_level and admin_level > 3
878 and rank_address between 1 and 25 -- for index selection
879 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- for index selection
880 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
881 ORDER BY admin_level desc LIMIT 1
883 IF location.is_same THEN
884 -- Looks like the same boundary is replicated on multiple admin_levels.
885 -- Usual tagging in Poland. Remove our boundary from addresses.
886 NEW.rank_address := 0;
888 parent_address_level := location.rank_address;
889 IF location.rank_address >= NEW.rank_address THEN
890 IF location.rank_address >= 24 THEN
891 NEW.rank_address := 25;
893 NEW.rank_address := location.rank_address + 2;
899 IF NEW.rank_address > 9 THEN
900 -- Second check that the boundary is not completely contained in a
901 -- place area with a equal or higher address rank.
905 LATERAL compute_place_rank(country_code, 'A', class, type,
906 admin_level, False, null) prank
907 WHERE class = 'place' and rank_address between 1 and 23
908 and prank.address_rank >= NEW.rank_address
909 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
910 and geometry && NEW.geometry
911 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
912 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
913 ORDER BY prank.address_rank desc LIMIT 1
915 NEW.rank_address := location.rank_address + 2;
918 ELSEIF NEW.class = 'place'
919 and ST_GeometryType(NEW.geometry) in ('ST_Polygon', 'ST_MultiPolygon')
920 and NEW.rank_address between 16 and 23
922 -- For place areas make sure they are not completely contained in an area
923 -- with a equal or higher address rank.
927 LATERAL compute_place_rank(country_code, 'A', class, type,
928 admin_level, False, null) prank
929 WHERE prank.address_rank < 24
930 and rank_address between 1 and 25 -- select right index
931 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
932 and prank.address_rank >= NEW.rank_address
933 and geometry && NEW.geometry
934 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
935 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
936 ORDER BY prank.address_rank desc LIMIT 1
938 NEW.rank_address := location.rank_address + 2;
940 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
941 and NEW.rank_address between 16 and 23
943 -- If a place node is contained in an admin or place boundary with the same
944 -- address level and has not been linked, then make the node a subpart
945 -- by increasing the address rank (city level and above).
949 LATERAL compute_place_rank(country_code, 'A', class, type,
950 admin_level, False, null) prank
952 and rank_address between 1 and 25 -- select right index
953 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
954 and ((class = 'place' and prank.address_rank = NEW.rank_address)
955 or (class = 'boundary' and rank_address = NEW.rank_address))
956 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
959 NEW.rank_address = NEW.rank_address + 2;
962 parent_address_level := 3;
965 NEW.housenumber := token_normalized_housenumber(NEW.token_info);
967 NEW.postcode := null;
969 -- waterway ways are linked when they are part of a relation and have the same class/type
970 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
971 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
973 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
974 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
975 {% if debug %}RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];{% endif %}
976 FOR linked_node_id IN SELECT place_id FROM placex
977 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
978 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
979 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
981 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
982 {% if 'search_name' in db.tables %}
983 DELETE FROM search_name WHERE place_id = linked_node_id;
989 {% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
992 NEW.importance := null;
993 SELECT wikipedia, importance
994 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.rank_search, NEW.centroid)
995 INTO NEW.wikipedia,NEW.importance;
997 {% if debug %}RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;{% endif %}
999 -- ---------------------------------------------------------------------------
1000 -- For low level elements we inherit from our parent road
1001 IF NEW.rank_search > 27 THEN
1003 {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1004 NEW.parent_place_id := null;
1005 is_place_address := not token_is_street_address(NEW.token_info);
1007 -- We have to find our parent road.
1008 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
1010 ST_Envelope(NEW.geometry),
1014 -- If we found the road take a shortcut here.
1015 -- Otherwise fall back to the full address getting method below.
1016 IF NEW.parent_place_id is not null THEN
1018 -- Get the details of the parent road
1019 SELECT p.country_code, p.postcode, p.name FROM placex p
1020 WHERE p.place_id = NEW.parent_place_id INTO location;
1022 IF is_place_address and NEW.address ? 'place' THEN
1023 -- Check if the addr:place tag is part of the parent name
1024 SELECT count(*) INTO i
1025 FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
1027 NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
1031 NEW.country_code := location.country_code;
1032 {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
1034 -- determine postcode
1035 NEW.postcode := coalesce(token_get_postcode(NEW.token_info),
1037 get_nearest_postcode(NEW.country_code, NEW.centroid));
1039 IF NEW.name is not NULL THEN
1040 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1043 {% if not db.reverse_only %}
1044 IF NEW.name is not NULL OR NEW.address is not NULL THEN
1045 SELECT * INTO name_vector, nameaddress_vector
1046 FROM create_poi_search_terms(NEW.place_id,
1047 NEW.partition, NEW.parent_place_id,
1048 is_place_address, NEW.country_code,
1049 NEW.token_info, NEW.centroid);
1051 IF array_length(name_vector, 1) is not NULL THEN
1052 INSERT INTO search_name (place_id, search_rank, address_rank,
1053 importance, country_code, name_vector,
1054 nameaddress_vector, centroid)
1055 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1056 NEW.importance, NEW.country_code, name_vector,
1057 nameaddress_vector, NEW.centroid);
1058 {% if debug %}RAISE WARNING 'Place added to search table';{% endif %}
1063 NEW.token_info := token_strip_info(NEW.token_info);
1070 -- ---------------------------------------------------------------------------
1072 {% if debug %}RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1073 IF linked_place is not null THEN
1074 -- Recompute the ranks here as the ones from the linked place might
1075 -- have been shifted to accommodate surrounding boundaries.
1076 SELECT place_id, osm_id, class, type, extratags, rank_search,
1078 (compute_place_rank(country_code, osm_type, class, type, admin_level,
1079 (extratags->'capital') = 'yes', null)).*
1081 FROM placex WHERE place_id = linked_place;
1083 {% if debug %}RAISE WARNING 'Linked %', location;{% endif %}
1085 -- Use the linked point as the centre point of the geometry,
1086 -- but only if it is within the area of the boundary.
1087 geom := coalesce(location.centroid, ST_Centroid(location.geometry));
1088 IF geom is not NULL AND ST_Within(geom, NEW.geometry) THEN
1089 NEW.centroid := geom;
1092 {% if debug %}RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.address_rank;{% endif %}
1093 IF location.address_rank > parent_address_level
1094 and location.address_rank < 26
1096 NEW.rank_address := location.address_rank;
1099 -- merge in extra tags
1100 NEW.extratags := hstore('linked_' || location.class, location.type)
1101 || coalesce(location.extratags, ''::hstore)
1102 || coalesce(NEW.extratags, ''::hstore);
1104 -- mark the linked place (excludes from search results)
1105 -- Force reindexing to remove any traces from the search indexes and
1106 -- reset the address rank if necessary.
1107 UPDATE placex set linked_place_id = NEW.place_id, indexed_status = 2
1108 WHERE place_id = location.place_id;
1109 -- ensure that those places are not found anymore
1110 {% if 'search_name' in db.tables %}
1111 DELETE FROM search_name WHERE place_id = location.place_id;
1113 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
1115 SELECT wikipedia, importance
1116 FROM compute_importance(location.extratags, NEW.country_code,
1117 location.rank_search, NEW.centroid)
1118 INTO linked_wikipedia,linked_importance;
1120 -- Use the maximum importance if one could be computed from the linked object.
1121 IF linked_importance is not null AND
1122 (NEW.importance is null or NEW.importance < linked_importance)
1124 NEW.importance = linked_importance;
1127 -- No linked place? As a last resort check if the boundary is tagged with
1128 -- a place type and adapt the rank address.
1129 IF NEW.rank_address between 4 and 25 and NEW.extratags ? 'place' THEN
1130 SELECT address_rank INTO place_address_level
1131 FROM compute_place_rank(NEW.country_code, 'A', 'place',
1132 NEW.extratags->'place', 0::SMALLINT, False, null);
1133 IF place_address_level > parent_address_level and
1134 place_address_level < 26 THEN
1135 NEW.rank_address := place_address_level;
1140 {% if not disable_diff_updates %}
1141 IF OLD.rank_address != NEW.rank_address THEN
1142 -- After a rank shift all addresses containing us must be updated.
1143 UPDATE placex p SET indexed_status = 2 FROM place_addressline pa
1144 WHERE pa.address_place_id = NEW.place_id and p.place_id = pa.place_id
1145 and p.indexed_status = 0 and p.rank_address between 4 and 25;
1149 IF NEW.admin_level = 2
1150 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
1151 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
1153 -- Update the list of country names.
1154 -- Only take the name from the largest area for the given country code
1155 -- in the hope that this is the authoritative one.
1156 -- Also replace any old names so that all mapping mistakes can
1157 -- be fixed through regular OSM updates.
1159 SELECT osm_id FROM placex
1160 WHERE rank_search = 4 and osm_type = 'R'
1161 and country_code = NEW.country_code
1162 ORDER BY ST_Area(geometry) desc
1165 IF location.osm_id = NEW.osm_id THEN
1166 {% if debug %}RAISE WARNING 'Updating names for country '%' with: %', NEW.country_code, NEW.name;{% endif %}
1167 UPDATE country_name SET derived_name = NEW.name WHERE country_code = NEW.country_code;
1172 -- For linear features we need the full geometry for determining the address
1173 -- because they may go through several administrative entities. Otherwise use
1174 -- the centroid for performance reasons.
1175 IF ST_GeometryType(NEW.geometry) in ('ST_LineString', 'ST_MultiLineString') THEN
1176 geom := NEW.geometry;
1178 geom := NEW.centroid;
1181 IF NEW.rank_address = 0 THEN
1182 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
1183 -- Rank 0 features may also span multiple administrative areas (e.g. lakes)
1184 -- so use the geometry here too. Just make sure the areas don't become too
1186 IF NEW.class = 'natural' or max_rank > 10 THEN
1187 geom := NEW.geometry;
1189 ELSEIF NEW.rank_address > 25 THEN
1192 max_rank := NEW.rank_address;
1195 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
1196 NEW.token_info, geom, NEW.centroid,
1198 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
1200 {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
1202 NEW.postcode := coalesce(token_get_postcode(NEW.token_info), NEW.postcode);
1204 -- if we have a name add this to the name search table
1205 IF NEW.name IS NOT NULL THEN
1206 -- Initialise the name vector using our name
1207 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1208 name_vector := token_get_name_search_tokens(NEW.token_info);
1210 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1211 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
1212 name_vector, NEW.rank_search, NEW.rank_address,
1213 NEW.postcode, NEW.geometry, NEW.centroid);
1214 {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
1217 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1218 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1219 {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
1222 IF NEW.rank_address between 16 and 27 THEN
1223 result := insertSearchName(NEW.partition, NEW.place_id,
1224 token_get_name_match_tokens(NEW.token_info),
1225 NEW.rank_search, NEW.rank_address, NEW.geometry);
1227 {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
1229 {% if not db.reverse_only %}
1230 INSERT INTO search_name (place_id, search_rank, address_rank,
1231 importance, country_code, name_vector,
1232 nameaddress_vector, centroid)
1233 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1234 NEW.importance, NEW.country_code, name_vector,
1235 nameaddress_vector, NEW.centroid);
1239 IF NEW.postcode is null AND NEW.rank_search > 8
1240 AND (NEW.rank_address > 0
1241 OR ST_GeometryType(NEW.geometry) not in ('ST_LineString','ST_MultiLineString')
1242 OR ST_Length(NEW.geometry) < 0.02)
1244 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1247 {% if debug %}RAISE WARNING 'place update % % finished.', NEW.osm_type, NEW.osm_id;{% endif %}
1249 NEW.token_info := token_strip_info(NEW.token_info);
1256 CREATE OR REPLACE FUNCTION placex_delete()
1263 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1265 IF OLD.linked_place_id is null THEN
1266 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1267 {% if debug %}RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1268 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1269 {% if debug %}RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1271 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1274 IF OLD.rank_address < 30 THEN
1276 -- mark everything linked to this place for re-indexing
1277 {% if debug %}RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1278 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1279 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1281 {% if debug %}RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1282 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1284 {% if debug %}RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1285 b := deleteRoad(OLD.partition, OLD.place_id);
1287 {% if debug %}RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1288 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1289 {% if debug %}RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1290 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1291 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1295 {% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1297 IF OLD.rank_address < 26 THEN
1298 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1301 {% if debug %}RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1303 IF OLD.name is not null THEN
1304 {% if 'search_name' in db.tables %}
1305 DELETE from search_name WHERE place_id = OLD.place_id;
1307 b := deleteSearchName(OLD.partition, OLD.place_id);
1310 {% if debug %}RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1312 DELETE FROM place_addressline where place_id = OLD.place_id;
1314 {% if debug %}RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1316 -- remove from tables for special search
1317 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1318 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1320 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1323 {% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}