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
22 -- Retrieve the data needed by the indexer for updating the place.
23 CREATE OR REPLACE FUNCTION placex_indexing_prepare(p placex)
24 RETURNS prepare_update_info
28 result prepare_update_info;
31 -- For POI nodes, check if the address should be derived from a surrounding
33 IF p.rank_search < 30 OR p.osm_type != 'N' THEN
34 result.address := p.address;
35 ELSEIF p.address is null THEN
36 -- The additional && condition works around the misguided query
37 -- planner of postgis 3.0.
38 SELECT placex.address || hstore('_inherited', '') INTO result.address
40 WHERE ST_Covers(geometry, p.centroid)
41 and geometry && p.centroid
42 and placex.address is not null
43 and (placex.address ? 'housenumber' or placex.address ? 'street' or placex.address ? 'place')
44 and rank_search = 30 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
47 result.address := p.address;
48 -- See if we can inherit addtional address tags from an interpolation.
49 -- These will become permanent.
51 SELECT (address - 'interpolation'::text - 'housenumber'::text) as address
52 FROM place, planet_osm_ways w
53 WHERE place.osm_type = 'W' and place.address ? 'interpolation'
54 and place.geometry && p.geometry
55 and place.osm_id = w.id
56 and p.osm_id = any(w.nodes)
58 result.address := location.address || result.address;
62 -- remove internal and derived names
63 result.address := result.address - '_unlisted_place'::TEXT;
64 SELECT hstore(array_agg(key), array_agg(value)) INTO result.name
65 FROM each(p.name) WHERE key not like '\_%';
67 result.class := p.class;
68 result.type := p.type;
69 result.country_code := p.country_code;
70 result.rank_address := p.rank_address;
72 -- Names of linked places need to be merged in, so search for a linkable
73 -- place already here.
74 SELECT * INTO location FROM find_linked_place(p);
76 IF location.place_id is not NULL THEN
77 result.linked_place_id := location.place_id;
79 IF location.name is not NULL THEN
80 {% if debug %}RAISE WARNING 'Names original: %, location: %', result.name, location.name;{% endif %}
81 -- Add all names from the place nodes that deviate from the name
82 -- in the relation with the prefix '_place_'. Deviation means that
83 -- either the value is different or a given key is missing completely
84 SELECT hstore(array_agg('_place_' || key), array_agg(value)) INTO extra_names
85 FROM each(location.name - result.name);
86 {% if debug %}RAISE WARNING 'Extra names: %', extra_names;{% endif %}
88 result.name := location.name || result.name || extra_names;
89 {% if debug %}RAISE WARNING 'Final names: %', result.name;{% endif %}
96 LANGUAGE plpgsql STABLE;
99 CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
108 SELECT members FROM planet_osm_rels
109 WHERE parts @> ARRAY[poi_osm_id]
110 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
111 and tags @> ARRAY['associatedStreet']
113 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
114 IF location.members[i+1] = 'street' THEN
116 SELECT place_id from placex
117 WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
119 and rank_search between 26 and 27
121 RETURN parent.place_id;
130 LANGUAGE plpgsql STABLE;
133 -- Find the parent road of a POI.
135 -- \returns Place ID of parent object or NULL if none
137 -- Copy data from linked items (POIs on ways, addr:street links, relations).
139 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
141 poi_partition SMALLINT,
144 is_place_addr BOOLEAN)
148 parent_place_id BIGINT DEFAULT NULL;
151 {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
153 -- Is this object part of an associatedStreet relation?
154 parent_place_id := find_associated_street(poi_osm_type, poi_osm_id);
156 IF parent_place_id is null THEN
157 parent_place_id := find_parent_for_address(token_info, poi_partition, bbox);
160 IF parent_place_id is null and poi_osm_type = 'N' THEN
162 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
163 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
164 FROM placex p, planet_osm_ways w
165 WHERE p.osm_type = 'W' and p.rank_search >= 26
166 and p.geometry && bbox
167 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
169 {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
171 -- Way IS a road then we are on it - that must be our road
172 IF location.rank_search < 28 THEN
173 {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
174 RETURN location.place_id;
177 parent_place_id := find_associated_street('W', location.osm_id);
181 IF parent_place_id is NULL THEN
182 IF is_place_addr THEN
183 -- The address is attached to a place we don't know.
184 -- Instead simply use the containing area with the largest rank.
186 SELECT place_id FROM placex
187 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
188 AND rank_address between 5 and 25
189 ORDER BY rank_address desc
191 RETURN location.place_id;
193 ELSEIF ST_Area(bbox) < 0.005 THEN
194 -- for smaller features get the nearest road
195 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
196 {% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
198 -- for larger features simply find the area with the largest rank that
199 -- contains the bbox, only use addressable features
201 SELECT place_id FROM placex
202 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
203 AND rank_address between 5 and 25
204 ORDER BY rank_address desc
206 RETURN location.place_id;
211 RETURN parent_place_id;
214 LANGUAGE plpgsql STABLE;
216 -- Try to find a linked place for the given object.
217 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
221 relation_members TEXT[];
223 linked_placex placex%ROWTYPE;
226 IF bnd.rank_search >= 26 or bnd.rank_address = 0
227 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
228 or bnd.type IN ('postcode', 'postal_code')
233 IF bnd.osm_type = 'R' THEN
234 -- see if we have any special relation members
235 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
236 {% if debug %}RAISE WARNING 'Got relation members';{% endif %}
238 -- Search for relation members with role 'lable'.
239 IF relation_members IS NOT NULL THEN
241 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
243 {% if debug %}RAISE WARNING 'Found label member %', rel_member.member;{% endif %}
247 WHERE osm_type = 'N' and osm_id = rel_member.member
250 {% if debug %}RAISE WARNING 'Linked label member';{% endif %}
251 RETURN linked_placex;
258 IF bnd.name ? 'name' THEN
259 bnd_name := lower(bnd.name->'name');
260 IF bnd_name = '' THEN
265 -- If extratags has a place tag, look for linked nodes by their place type.
266 -- Area and node still have to have the same name.
267 IF bnd.extratags ? 'place' and bnd_name is not null THEN
270 WHERE (position(lower(name->'name') in bnd_name) > 0
271 OR position(bnd_name in lower(name->'name')) > 0)
272 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
273 AND placex.osm_type = 'N'
274 AND placex.linked_place_id is null
275 AND placex.rank_search < 26 -- needed to select the right index
276 AND placex.type != 'postcode'
277 AND ST_Covers(bnd.geometry, placex.geometry)
279 {% if debug %}RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;{% endif %}
280 RETURN linked_placex;
284 IF bnd.extratags ? 'wikidata' THEN
287 WHERE placex.class = 'place' AND placex.osm_type = 'N'
288 AND placex.extratags ? 'wikidata' -- needed to select right index
289 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
290 AND placex.linked_place_id is null
291 AND placex.rank_search < 26
292 AND _st_covers(bnd.geometry, placex.geometry)
293 ORDER BY lower(name->'name') = bnd_name desc
295 {% if debug %}RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;{% endif %}
296 RETURN linked_placex;
300 -- Name searches can be done for ways as well as relations
301 IF bnd_name is not null THEN
302 {% if debug %}RAISE WARNING 'Looking for nodes with matching names';{% endif %}
304 SELECT placex.* from placex
305 WHERE lower(name->'name') = bnd_name
306 AND ((bnd.rank_address > 0
307 and bnd.rank_address = (compute_place_rank(placex.country_code,
309 placex.type, 15::SMALLINT,
310 false, placex.postcode)).address_rank)
311 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
312 AND placex.osm_type = 'N'
313 AND placex.class = 'place'
314 AND placex.linked_place_id is null
315 AND placex.rank_search < 26 -- needed to select the right index
316 AND placex.type != 'postcode'
317 AND ST_Covers(bnd.geometry, placex.geometry)
319 {% if debug %}RAISE WARNING 'Found matching place node %', linked_placex.osm_id;{% endif %}
320 RETURN linked_placex;
327 LANGUAGE plpgsql STABLE;
330 CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
331 in_partition SMALLINT,
332 parent_place_id BIGINT,
333 is_place_addr BOOLEAN,
337 OUT name_vector INTEGER[],
338 OUT nameaddress_vector INTEGER[])
341 parent_name_vector INTEGER[];
342 parent_address_vector INTEGER[];
343 addr_place_ids INTEGER[];
344 hnr_vector INTEGER[];
348 parent_address_place_ids BIGINT[];
350 nameaddress_vector := '{}'::INTEGER[];
352 SELECT s.name_vector, s.nameaddress_vector
353 INTO parent_name_vector, parent_address_vector
355 WHERE s.place_id = parent_place_id;
359 token_get_address_search_tokens(token_info, key) as search_tokens
360 FROM token_get_address_keys(token_info) as key,
361 LATERAL get_addr_tag_rank(key, country) as ranks
362 WHERE not token_get_address_search_tokens(token_info, key) <@ parent_address_vector
364 addr_place := get_address_place(in_partition, geometry,
365 addr_item.from_rank, addr_item.to_rank,
366 addr_item.extent, token_info, addr_item.key);
368 IF addr_place is null THEN
369 -- No place found in OSM that matches. Make it at least searchable.
370 nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
372 IF parent_address_place_ids is null THEN
373 SELECT array_agg(parent_place_id) INTO parent_address_place_ids
374 FROM place_addressline
375 WHERE place_id = parent_place_id;
378 -- If the parent already lists the place in place_address line, then we
379 -- are done. Otherwise, add its own place_address line.
380 IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
381 nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
383 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
384 isaddress, distance, cached_rank_address)
385 VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
386 true, addr_place.distance, addr_place.rank_address);
391 name_vector := token_get_name_search_tokens(token_info);
393 -- Check if the parent covers all address terms.
394 -- If not, create a search name entry with the house number as the name.
395 -- This is unusual for the search_name table but prevents that the place
396 -- is returned when we only search for the street/place.
398 hnr_vector := token_get_housenumber_search_tokens(token_info);
400 IF hnr_vector is not null and not nameaddress_vector <@ parent_address_vector THEN
401 name_vector := array_merge(name_vector, hnr_vector);
404 IF is_place_addr THEN
405 addr_place_ids := token_addr_place_search_tokens(token_info);
406 IF not addr_place_ids <@ parent_name_vector THEN
407 -- make sure addr:place terms are always searchable
408 nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
409 -- If there is a housenumber, also add the place name as a name,
410 -- so we can search it by the usual housenumber+place algorithms.
411 IF hnr_vector is not null THEN
412 name_vector := array_merge(name_vector, addr_place_ids);
417 -- Cheating here by not recomputing all terms but simply using the ones
418 -- from the parent object.
419 nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
420 nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
427 -- Insert address of a place into the place_addressline table.
429 -- \param obj_place_id Place_id of the place to compute the address for.
430 -- \param partition Partition number where the place is in.
431 -- \param maxrank Rank of the place. All address features must have
432 -- a search rank lower than the given rank.
433 -- \param address Address terms for the place.
434 -- \param geometry Geometry to which the address objects should be close.
436 -- \retval parent_place_id Place_id of the address object that is the direct
438 -- \retval postcode Postcode computed from the address. This is the
439 -- addr:postcode of one of the address objects. If
440 -- more than one of has a postcode, the highest ranking
441 -- one is used. May be NULL.
442 -- \retval nameaddress_vector Search terms for the address. This is the sum
443 -- of name terms of all address objects.
444 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
450 OUT parent_place_id BIGINT,
452 OUT nameaddress_vector INT[])
455 address_havelevel BOOLEAN[];
457 location_isaddress BOOLEAN;
458 current_boundary GEOMETRY := NULL;
459 current_node_area GEOMETRY := NULL;
461 parent_place_rank INT := 0;
462 addr_place_ids BIGINT[] := '{}'::int[];
463 new_address_vector INT[];
467 parent_place_id := 0;
468 nameaddress_vector := '{}'::int[];
470 address_havelevel := array_fill(false, ARRAY[maxrank]);
474 FROM (SELECT extra.*, key
475 FROM token_get_address_keys(token_info) as key,
476 LATERAL get_addr_tag_rank(key, country) as extra) x,
477 LATERAL get_address_place(partition, geometry, from_rank, to_rank,
478 extent, token_info, key) as apl
479 ORDER BY rank_address, distance, isguess desc
481 IF location.place_id is null THEN
482 {% if not db.reverse_only %}
483 nameaddress_vector := array_merge(nameaddress_vector,
484 token_get_address_search_tokens(token_info,
488 {% if not db.reverse_only %}
489 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
492 location_isaddress := not address_havelevel[location.rank_address];
493 IF not address_havelevel[location.rank_address] THEN
494 address_havelevel[location.rank_address] := true;
495 IF parent_place_rank < location.rank_address THEN
496 parent_place_id := location.place_id;
497 parent_place_rank := location.rank_address;
501 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
502 isaddress, distance, cached_rank_address)
503 VALUES (obj_place_id, location.place_id, not location.isguess,
504 true, location.distance, location.rank_address);
506 addr_place_ids := addr_place_ids || location.place_id;
511 SELECT * FROM getNearFeatures(partition, geometry, maxrank)
512 WHERE not addr_place_ids @> ARRAY[place_id]
513 ORDER BY rank_address, isguess asc,
515 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
516 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
517 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
520 -- Ignore all place nodes that do not fit in a lower level boundary.
521 CONTINUE WHEN location.isguess
522 and current_boundary is not NULL
523 and not ST_Contains(current_boundary, location.centroid);
525 -- If this is the first item in the rank, then assume it is the address.
526 location_isaddress := not address_havelevel[location.rank_address];
528 -- Further sanity checks to ensure that the address forms a sane hierarchy.
529 IF location_isaddress THEN
530 IF location.isguess and current_node_area is not NULL THEN
531 location_isaddress := ST_Contains(current_node_area, location.centroid);
533 IF not location.isguess and current_boundary is not NULL
534 and location.rank_address != 11 AND location.rank_address != 5 THEN
535 location_isaddress := ST_Contains(current_boundary, location.centroid);
539 IF location_isaddress THEN
540 address_havelevel[location.rank_address] := true;
541 parent_place_id := location.place_id;
543 -- Set postcode if we have one.
544 -- (Returned will be the highest ranking one.)
545 IF location.postcode is not NULL THEN
546 postcode = location.postcode;
549 -- Recompute the areas we need for hierarchy sanity checks.
550 IF location.rank_address != 11 AND location.rank_address != 5 THEN
551 IF location.isguess THEN
552 current_node_area := place_node_fuzzy_area(location.centroid,
553 location.rank_search);
555 current_node_area := NULL;
556 SELECT p.geometry FROM placex p
557 WHERE p.place_id = location.place_id INTO current_boundary;
562 -- Add it to the list of search terms
563 {% if not db.reverse_only %}
564 nameaddress_vector := array_merge(nameaddress_vector,
565 location.keywords::integer[]);
568 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
569 isaddress, distance, cached_rank_address)
570 VALUES (obj_place_id, location.place_id, not location.isguess,
571 location_isaddress, location.distance, location.rank_address);
578 CREATE OR REPLACE FUNCTION placex_insert()
585 country_code VARCHAR(2);
589 {% if debug %}RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
591 NEW.place_id := nextval('seq_place');
592 NEW.indexed_status := 1; --STATUS_NEW
594 NEW.centroid := ST_PointOnSurface(NEW.geometry);
595 NEW.country_code := lower(get_country_code(NEW.centroid));
597 NEW.partition := get_partition(NEW.country_code);
598 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.centroid);
600 IF NEW.osm_type = 'X' THEN
601 -- E'X'ternal records should already be in the right format so do nothing
603 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
605 IF NEW.class in ('place','boundary')
606 AND NEW.type in ('postcode','postal_code')
608 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
609 -- most likely just a part of a multipolygon postcode boundary, throw it away
613 NEW.name := hstore('ref', NEW.address->'postcode');
615 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
616 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
619 ELSEIF NEW.class = 'boundary' AND NOT is_area
622 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
623 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
628 SELECT * INTO NEW.rank_search, NEW.rank_address
629 FROM compute_place_rank(NEW.country_code,
630 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
631 NEW.class, NEW.type, NEW.admin_level,
632 (NEW.extratags->'capital') = 'yes',
633 NEW.address->'postcode');
635 -- a country code make no sense below rank 4 (country)
636 IF NEW.rank_search < 4 THEN
637 NEW.country_code := NULL;
642 {% if debug %}RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
644 {% if not disable_diff_updates %}
645 -- The following is not needed until doing diff updates, and slows the main index process down
647 IF NEW.rank_address > 0 THEN
648 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
649 -- Performance: We just can't handle re-indexing for country level changes
650 IF st_area(NEW.geometry) < 1 THEN
651 -- mark items within the geometry for re-indexing
652 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
654 UPDATE placex SET indexed_status = 2
655 WHERE ST_Intersects(NEW.geometry, placex.geometry)
656 and indexed_status = 0
657 and ((rank_address = 0 and rank_search > NEW.rank_address)
658 or rank_address > NEW.rank_address
659 or (class = 'place' and osm_type = 'N')
661 and (rank_search < 28
663 or (NEW.rank_address >= 16 and address ? 'place'));
666 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
667 diameter := update_place_diameter(NEW.rank_search);
669 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
670 IF NEW.rank_search >= 26 THEN
671 -- roads may cause reparenting for >27 rank places
672 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
673 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
674 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);
675 ELSEIF NEW.rank_search >= 16 THEN
676 -- up to rank 16, street-less addresses may need reparenting
677 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');
679 -- for all other places the search terms may change as well
680 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);
687 -- add to tables for special search
688 -- Note: won't work on initial import because the classtype tables
689 -- do not yet exist. It won't hurt either.
690 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
691 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
693 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
694 USING NEW.place_id, ST_Centroid(NEW.geometry);
697 {% endif %} -- not disable_diff_updates
705 CREATE OR REPLACE FUNCTION placex_update()
711 relation_members TEXT[];
714 parent_address_level SMALLINT;
715 place_address_level SMALLINT;
719 name_vector INTEGER[];
720 nameaddress_vector INTEGER[];
721 addr_nameaddress_vector INTEGER[];
725 linked_node_id BIGINT;
726 linked_importance FLOAT;
727 linked_wikipedia TEXT;
729 is_place_address BOOLEAN;
733 IF OLD.indexed_status = 100 THEN
734 {% if debug %}RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;{% endif %}
735 delete from placex where place_id = OLD.place_id;
739 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
743 {% if debug %}RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;{% endif %}
745 NEW.indexed_date = now();
747 {% if 'search_name' in db.tables %}
748 DELETE from search_name WHERE place_id = NEW.place_id;
750 result := deleteSearchName(NEW.partition, NEW.place_id);
751 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
752 result := deleteRoad(NEW.partition, NEW.place_id);
753 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
754 UPDATE placex set linked_place_id = null, indexed_status = 2
755 where linked_place_id = NEW.place_id;
756 -- update not necessary for osmline, cause linked_place_id does not exist
758 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
760 -- NEW.linked_place_id contains the precomputed linkee. Save this and restore
761 -- the previous link status.
762 linked_place := NEW.linked_place_id;
763 NEW.linked_place_id := OLD.linked_place_id;
765 IF NEW.linked_place_id is not null THEN
766 NEW.token_info := null;
767 {% if debug %}RAISE WARNING 'place already linked to %', OLD.linked_place_id;{% endif %}
771 -- Postcodes are just here to compute the centroids. They are not searchable
772 -- unless they are a boundary=postal_code.
773 -- There was an error in the style so that boundary=postal_code used to be
774 -- imported as place=postcode. That's why relations are allowed to pass here.
775 -- This can go away in a couple of versions.
776 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
777 NEW.token_info := null;
781 -- Compute a preliminary centroid.
782 NEW.centroid := ST_PointOnSurface(NEW.geometry);
784 -- recalculate country and partition
785 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
786 -- for countries, believe the mapped country code,
787 -- so that we remain in the right partition if the boundaries
789 NEW.country_code := lower(NEW.address->'country');
790 NEW.partition := get_partition(lower(NEW.country_code));
791 IF NEW.partition = 0 THEN
792 NEW.country_code := lower(get_country_code(NEW.centroid));
793 NEW.partition := get_partition(NEW.country_code);
796 IF NEW.rank_search >= 4 THEN
797 NEW.country_code := lower(get_country_code(NEW.centroid));
799 NEW.country_code := NULL;
801 NEW.partition := get_partition(NEW.country_code);
803 {% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
806 -- recompute the ranks, they might change when linking changes
807 SELECT * INTO NEW.rank_search, NEW.rank_address
808 FROM compute_place_rank(NEW.country_code,
809 CASE WHEN ST_GeometryType(NEW.geometry)
810 IN ('ST_Polygon','ST_MultiPolygon')
811 THEN 'A' ELSE NEW.osm_type END,
812 NEW.class, NEW.type, NEW.admin_level,
813 (NEW.extratags->'capital') = 'yes',
814 NEW.address->'postcode');
815 -- We must always increase the address level relative to the admin boundary.
816 IF NEW.class = 'boundary' and NEW.type = 'administrative'
817 and NEW.osm_type = 'R' and NEW.rank_address > 0
819 -- First, check that admin boundaries do not overtake each other rank-wise.
820 parent_address_level := 3;
823 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
824 and extratags->'wikidata' = NEW.extratags->'wikidata'
825 THEN ST_Equals(geometry, NEW.geometry)
826 ELSE false END) as is_same
828 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
829 and admin_level < NEW.admin_level and admin_level > 3
831 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
832 ORDER BY admin_level desc LIMIT 1
834 IF location.is_same THEN
835 -- Looks like the same boundary is replicated on multiple admin_levels.
836 -- Usual tagging in Poland. Remove our boundary from addresses.
837 NEW.rank_address := 0;
839 parent_address_level := location.rank_address;
840 IF location.rank_address >= NEW.rank_address THEN
841 IF location.rank_address >= 24 THEN
842 NEW.rank_address := 25;
844 NEW.rank_address := location.rank_address + 2;
850 IF NEW.rank_address > 9 THEN
851 -- Second check that the boundary is not completely contained in a
852 -- place area with a higher address rank
854 SELECT rank_address FROM placex
855 WHERE class = 'place' and rank_address < 24
856 and rank_address > NEW.rank_address
857 and geometry && NEW.geometry
858 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
859 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
860 ORDER BY rank_address desc LIMIT 1
862 NEW.rank_address := location.rank_address + 2;
865 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
866 and NEW.rank_address between 16 and 23
868 -- If a place node is contained in a admin boundary with the same address level
869 -- and has not been linked, then make the node a subpart by increasing the
870 -- address rank (city level and above).
872 SELECT rank_address FROM placex
873 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
874 and rank_address = NEW.rank_address
875 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
878 NEW.rank_address = NEW.rank_address + 2;
881 parent_address_level := 3;
884 NEW.housenumber := token_normalized_housenumber(NEW.token_info);
886 NEW.postcode := null;
888 -- waterway ways are linked when they are part of a relation and have the same class/type
889 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
890 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
892 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
893 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
894 {% if debug %}RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];{% endif %}
895 FOR linked_node_id IN SELECT place_id FROM placex
896 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
897 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
898 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
900 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
901 {% if 'search_name' in db.tables %}
902 DELETE FROM search_name WHERE place_id = linked_node_id;
908 {% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
911 NEW.importance := null;
912 SELECT wikipedia, importance
913 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
914 INTO NEW.wikipedia,NEW.importance;
916 {% if debug %}RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;{% endif %}
918 -- ---------------------------------------------------------------------------
919 -- For low level elements we inherit from our parent road
920 IF NEW.rank_search > 27 THEN
922 {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
923 NEW.parent_place_id := null;
924 is_place_address := coalesce(not NEW.address ? 'street' and NEW.address ? 'place', FALSE);
926 -- We have to find our parent road.
927 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
929 ST_Envelope(NEW.geometry),
933 -- If we found the road take a shortcut here.
934 -- Otherwise fall back to the full address getting method below.
935 IF NEW.parent_place_id is not null THEN
937 -- Get the details of the parent road
938 SELECT p.country_code, p.postcode, p.name FROM placex p
939 WHERE p.place_id = NEW.parent_place_id INTO location;
941 IF is_place_address THEN
942 -- Check if the addr:place tag is part of the parent name
943 SELECT count(*) INTO i
944 FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
946 NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
950 NEW.country_code := location.country_code;
951 {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
953 -- determine postcode
954 NEW.postcode := coalesce(token_normalized_postcode(NEW.address->'postcode'),
956 get_nearest_postcode(NEW.country_code, NEW.centroid));
958 IF NEW.name is not NULL THEN
959 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
962 {% if not db.reverse_only %}
963 IF NEW.name is not NULL OR NEW.address is not NULL THEN
964 SELECT * INTO name_vector, nameaddress_vector
965 FROM create_poi_search_terms(NEW.place_id,
966 NEW.partition, NEW.parent_place_id,
967 is_place_address, NEW.country_code,
968 NEW.token_info, NEW.centroid);
970 IF array_length(name_vector, 1) is not NULL THEN
971 INSERT INTO search_name (place_id, search_rank, address_rank,
972 importance, country_code, name_vector,
973 nameaddress_vector, centroid)
974 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
975 NEW.importance, NEW.country_code, name_vector,
976 nameaddress_vector, NEW.centroid);
977 {% if debug %}RAISE WARNING 'Place added to search table';{% endif %}
982 NEW.token_info := token_strip_info(NEW.token_info);
983 -- If the address was inherited from a surrounding building,
984 -- do not add it permanently to the table.
985 IF NEW.address ? '_inherited' THEN
986 IF NEW.address ? '_unlisted_place' THEN
987 NEW.address := hstore('_unlisted_place', NEW.address->'_unlisted_place');
998 -- ---------------------------------------------------------------------------
1000 {% if debug %}RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1001 IF linked_place is not null THEN
1002 SELECT * INTO location FROM placex WHERE place_id = linked_place;
1004 {% if debug %}RAISE WARNING 'Linked %', location;{% endif %}
1006 -- Use the linked point as the centre point of the geometry,
1007 -- but only if it is within the area of the boundary.
1008 geom := coalesce(location.centroid, ST_Centroid(location.geometry));
1009 IF geom is not NULL AND ST_Within(geom, NEW.geometry) THEN
1010 NEW.centroid := geom;
1013 {% if debug %}RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.rank_address;{% endif %}
1014 IF location.rank_address > parent_address_level
1015 and location.rank_address < 26
1017 NEW.rank_address := location.rank_address;
1020 -- merge in extra tags
1021 NEW.extratags := hstore('linked_' || location.class, location.type)
1022 || coalesce(location.extratags, ''::hstore)
1023 || coalesce(NEW.extratags, ''::hstore);
1025 -- mark the linked place (excludes from search results)
1026 UPDATE placex set linked_place_id = NEW.place_id
1027 WHERE place_id = location.place_id;
1028 -- ensure that those places are not found anymore
1029 {% if 'search_name' in db.tables %}
1030 DELETE FROM search_name WHERE place_id = location.place_id;
1032 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
1034 SELECT wikipedia, importance
1035 FROM compute_importance(location.extratags, NEW.country_code,
1036 'N', location.osm_id)
1037 INTO linked_wikipedia,linked_importance;
1039 -- Use the maximum importance if one could be computed from the linked object.
1040 IF linked_importance is not null AND
1041 (NEW.importance is null or NEW.importance < linked_importance)
1043 NEW.importance = linked_importance;
1046 -- No linked place? As a last resort check if the boundary is tagged with
1047 -- a place type and adapt the rank address.
1048 IF NEW.rank_address > 0 and NEW.extratags ? 'place' THEN
1049 SELECT address_rank INTO place_address_level
1050 FROM compute_place_rank(NEW.country_code, 'A', 'place',
1051 NEW.extratags->'place', 0::SMALLINT, False, null);
1052 IF place_address_level > parent_address_level and
1053 place_address_level < 26 THEN
1054 NEW.rank_address := place_address_level;
1059 IF NEW.admin_level = 2
1060 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
1061 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
1063 -- Update the list of country names.
1064 -- Only take the name from the largest area for the given country code
1065 -- in the hope that this is the authoritive one.
1066 -- Also replace any old names so that all mapping mistakes can
1067 -- be fixed through regular OSM updates.
1069 SELECT osm_id FROM placex
1070 WHERE rank_search = 4 and osm_type = 'R'
1071 and country_code = NEW.country_code
1072 ORDER BY ST_Area(geometry) desc
1075 IF location.osm_id = NEW.osm_id THEN
1076 {% if debug %}RAISE WARNING 'Updating names for country '%' with: %', NEW.country_code, NEW.name;{% endif %}
1077 UPDATE country_name SET derived_name = NEW.name WHERE country_code = NEW.country_code;
1082 -- For linear features we need the full geometry for determining the address
1083 -- because they may go through several administrative entities. Otherwise use
1084 -- the centroid for performance reasons.
1085 IF ST_GeometryType(NEW.geometry) in ('ST_LineString', 'ST_MultiLineString') THEN
1086 geom := NEW.geometry;
1088 geom := NEW.centroid;
1091 IF NEW.rank_address = 0 THEN
1092 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
1093 -- Rank 0 features may also span multiple administrative areas (e.g. lakes)
1094 -- so use the geometry here too. Just make sure the areas don't become too
1096 IF NEW.class = 'natural' or max_rank > 10 THEN
1097 geom := NEW.geometry;
1099 ELSEIF NEW.rank_address > 25 THEN
1102 max_rank := NEW.rank_address;
1105 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
1106 NEW.token_info, geom, NEW.country_code)
1107 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
1109 {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
1111 NEW.postcode := coalesce(token_normalized_postcode(NEW.address->'postcode'),
1114 -- if we have a name add this to the name search table
1115 IF NEW.name IS NOT NULL THEN
1116 -- Initialise the name vector using our name
1117 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1118 name_vector := token_get_name_search_tokens(NEW.token_info);
1120 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1121 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
1122 name_vector, NEW.rank_search, NEW.rank_address,
1123 NEW.postcode, NEW.geometry, NEW.centroid);
1124 {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
1127 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1128 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1129 {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
1132 IF NEW.rank_address between 16 and 27 THEN
1133 result := insertSearchName(NEW.partition, NEW.place_id,
1134 token_get_name_match_tokens(NEW.token_info),
1135 NEW.rank_search, NEW.rank_address, NEW.geometry);
1137 {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
1139 {% if not db.reverse_only %}
1140 INSERT INTO search_name (place_id, search_rank, address_rank,
1141 importance, country_code, name_vector,
1142 nameaddress_vector, centroid)
1143 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1144 NEW.importance, NEW.country_code, name_vector,
1145 nameaddress_vector, NEW.centroid);
1149 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1150 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1153 {% if debug %}RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;{% endif %}
1155 NEW.token_info := token_strip_info(NEW.token_info);
1162 CREATE OR REPLACE FUNCTION placex_delete()
1169 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1171 IF OLD.linked_place_id is null THEN
1172 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1173 {% if debug %}RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1174 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1175 {% if debug %}RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1177 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1180 IF OLD.rank_address < 30 THEN
1182 -- mark everything linked to this place for re-indexing
1183 {% if debug %}RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1184 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1185 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1187 {% if debug %}RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1188 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1190 {% if debug %}RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1191 b := deleteRoad(OLD.partition, OLD.place_id);
1193 {% if debug %}RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1194 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1195 {% if debug %}RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1196 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1197 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1201 {% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1203 IF OLD.rank_address < 26 THEN
1204 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1207 {% if debug %}RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1209 IF OLD.name is not null THEN
1210 {% if 'search_name' in db.tables %}
1211 DELETE from search_name WHERE place_id = OLD.place_id;
1213 b := deleteSearchName(OLD.partition, OLD.place_id);
1216 {% if debug %}RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1218 DELETE FROM place_addressline where place_id = OLD.place_id;
1220 {% if debug %}RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1222 -- remove from tables for special search
1223 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1224 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1226 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1229 {% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}