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 SELECT hstore(array_agg('_place_' || key), array_agg(value)) INTO extra_names
92 FROM each(location.name - result.name);
93 {% if debug %}RAISE WARNING 'Extra names: %', extra_names;{% endif %}
95 IF extra_names is not null THEN
96 result.name := result.name || extra_names;
99 {% if debug %}RAISE WARNING 'Final names: %', result.name;{% endif %}
106 LANGUAGE plpgsql STABLE;
109 CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
123 SELECT members FROM planet_osm_rels
124 WHERE parts @> ARRAY[poi_osm_id]
125 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
126 and tags @> ARRAY['associatedStreet']
128 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
129 IF location.members[i+1] = 'street' THEN
131 SELECT place_id, geometry
133 WHERE osm_type = upper(substring(location.members[i], 1, 1))::char(1)
134 and osm_id = substring(location.members[i], 2)::bigint
136 and rank_search between 26 and 27
138 -- Find the closest 'street' member.
139 -- Avoid distance computation for the frequent case where there is
140 -- only one street member.
141 IF waygeom is null THEN
142 result := parent.place_id;
143 waygeom := parent.geometry;
145 distance := coalesce(distance, ST_Distance(waygeom, bbox));
146 new_distance := ST_Distance(parent.geometry, bbox);
147 IF new_distance < distance THEN
148 distance := new_distance;
149 result := parent.place_id;
150 waygeom := parent.geometry;
161 LANGUAGE plpgsql STABLE;
164 -- Find the parent road of a POI.
166 -- \returns Place ID of parent object or NULL if none
168 -- Copy data from linked items (POIs on ways, addr:street links, relations).
170 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
172 poi_partition SMALLINT,
175 is_place_addr BOOLEAN)
179 parent_place_id BIGINT DEFAULT NULL;
182 {% if debug %}RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;{% endif %}
184 -- Is this object part of an associatedStreet relation?
185 parent_place_id := find_associated_street(poi_osm_type, poi_osm_id, bbox);
187 IF parent_place_id is null THEN
188 parent_place_id := find_parent_for_address(token_info, poi_partition, bbox);
191 IF parent_place_id is null and poi_osm_type = 'N' THEN
193 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
194 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
195 FROM placex p, planet_osm_ways w
196 WHERE p.osm_type = 'W' and p.rank_search >= 26
197 and p.geometry && bbox
198 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
200 {% if debug %}RAISE WARNING 'Node is part of way % ', location.osm_id;{% endif %}
202 -- Way IS a road then we are on it - that must be our road
203 IF location.rank_search < 28 THEN
204 {% if debug %}RAISE WARNING 'node in way that is a street %',location;{% endif %}
205 RETURN location.place_id;
208 parent_place_id := find_associated_street('W', location.osm_id, bbox);
212 IF parent_place_id is NULL THEN
213 IF is_place_addr THEN
214 -- The address is attached to a place we don't know.
215 -- Instead simply use the containing area with the largest rank.
217 SELECT place_id FROM placex
218 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
219 AND rank_address between 5 and 25
220 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
221 ORDER BY rank_address desc
223 RETURN location.place_id;
225 ELSEIF ST_Area(bbox) < 0.005 THEN
226 -- for smaller features get the nearest road
227 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
228 {% if debug %}RAISE WARNING 'Checked for nearest way (%)', parent_place_id;{% endif %}
230 -- for larger features simply find the area with the largest rank that
231 -- contains the bbox, only use addressable features
233 SELECT place_id FROM placex
234 WHERE bbox && geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
235 AND rank_address between 5 and 25
236 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
237 ORDER BY rank_address desc
239 RETURN location.place_id;
244 RETURN parent_place_id;
247 LANGUAGE plpgsql STABLE;
249 -- Try to find a linked place for the given object.
250 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
254 relation_members TEXT[];
256 linked_placex placex%ROWTYPE;
259 IF bnd.rank_search >= 26 or bnd.rank_address = 0
260 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
261 or bnd.type IN ('postcode', 'postal_code')
266 IF bnd.osm_type = 'R' THEN
267 -- see if we have any special relation members
268 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
269 {% if debug %}RAISE WARNING 'Got relation members';{% endif %}
271 -- Search for relation members with role 'lable'.
272 IF relation_members IS NOT NULL THEN
274 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
276 {% if debug %}RAISE WARNING 'Found label member %', rel_member.member;{% endif %}
280 WHERE osm_type = 'N' and osm_id = rel_member.member
283 {% if debug %}RAISE WARNING 'Linked label member';{% endif %}
284 RETURN linked_placex;
291 IF bnd.name ? 'name' THEN
292 bnd_name := lower(bnd.name->'name');
293 IF bnd_name = '' THEN
298 -- If extratags has a place tag, look for linked nodes by their place type.
299 -- Area and node still have to have the same name.
300 IF bnd.extratags ? 'place' and bnd.extratags->'place' != 'postcode'
301 and bnd_name is not null
305 WHERE (position(lower(name->'name') in bnd_name) > 0
306 OR position(bnd_name in lower(name->'name')) > 0)
307 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
308 AND placex.osm_type = 'N'
309 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
310 AND placex.rank_search < 26 -- needed to select the right index
311 AND ST_Covers(bnd.geometry, placex.geometry)
313 {% if debug %}RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;{% endif %}
314 RETURN linked_placex;
318 IF bnd.extratags ? 'wikidata' THEN
321 WHERE placex.class = 'place' AND placex.osm_type = 'N'
322 AND placex.extratags ? 'wikidata' -- needed to select right index
323 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
324 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
325 AND placex.rank_search < 26
326 AND _st_covers(bnd.geometry, placex.geometry)
327 ORDER BY lower(name->'name') = bnd_name desc
329 {% if debug %}RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;{% endif %}
330 RETURN linked_placex;
334 -- Name searches can be done for ways as well as relations
335 IF bnd_name is not null THEN
336 {% if debug %}RAISE WARNING 'Looking for nodes with matching names';{% endif %}
338 SELECT placex.* from placex
339 WHERE lower(name->'name') = bnd_name
340 AND ((bnd.rank_address > 0
341 and bnd.rank_address = (compute_place_rank(placex.country_code,
343 placex.type, 15::SMALLINT,
344 false, placex.postcode)).address_rank)
345 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
346 AND placex.osm_type = 'N'
347 AND placex.class = 'place'
348 AND (placex.linked_place_id is null or placex.linked_place_id = bnd.place_id)
349 AND placex.rank_search < 26 -- needed to select the right index
350 AND placex.type != 'postcode'
351 AND ST_Covers(bnd.geometry, placex.geometry)
353 {% if debug %}RAISE WARNING 'Found matching place node %', linked_placex.osm_id;{% endif %}
354 RETURN linked_placex;
361 LANGUAGE plpgsql STABLE;
364 CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
365 in_partition SMALLINT,
366 parent_place_id BIGINT,
367 is_place_addr BOOLEAN,
371 OUT name_vector INTEGER[],
372 OUT nameaddress_vector INTEGER[])
375 parent_name_vector INTEGER[];
376 parent_address_vector INTEGER[];
377 addr_place_ids INTEGER[];
378 hnr_vector INTEGER[];
382 parent_address_place_ids BIGINT[];
384 nameaddress_vector := '{}'::INTEGER[];
386 SELECT s.name_vector, s.nameaddress_vector
387 INTO parent_name_vector, parent_address_vector
389 WHERE s.place_id = parent_place_id;
393 token_get_address_search_tokens(token_info, key) as search_tokens
394 FROM token_get_address_keys(token_info) as key,
395 LATERAL get_addr_tag_rank(key, country) as ranks
396 WHERE not token_get_address_search_tokens(token_info, key) <@ parent_address_vector
398 addr_place := get_address_place(in_partition, geometry,
399 addr_item.from_rank, addr_item.to_rank,
400 addr_item.extent, token_info, addr_item.key);
402 IF addr_place is null THEN
403 -- No place found in OSM that matches. Make it at least searchable.
404 nameaddress_vector := array_merge(nameaddress_vector, addr_item.search_tokens);
406 IF parent_address_place_ids is null THEN
407 SELECT array_agg(parent_place_id) INTO parent_address_place_ids
408 FROM place_addressline
409 WHERE place_id = parent_place_id;
412 -- If the parent already lists the place in place_address line, then we
413 -- are done. Otherwise, add its own place_address line.
414 IF not parent_address_place_ids @> ARRAY[addr_place.place_id] THEN
415 nameaddress_vector := array_merge(nameaddress_vector, addr_place.keywords);
417 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
418 isaddress, distance, cached_rank_address)
419 VALUES (obj_place_id, addr_place.place_id, not addr_place.isguess,
420 true, addr_place.distance, addr_place.rank_address);
425 name_vector := token_get_name_search_tokens(token_info);
427 -- Check if the parent covers all address terms.
428 -- If not, create a search name entry with the house number as the name.
429 -- This is unusual for the search_name table but prevents that the place
430 -- is returned when we only search for the street/place.
432 hnr_vector := token_get_housenumber_search_tokens(token_info);
434 IF hnr_vector is not null and not nameaddress_vector <@ parent_address_vector THEN
435 name_vector := array_merge(name_vector, hnr_vector);
438 IF is_place_addr THEN
439 addr_place_ids := token_addr_place_search_tokens(token_info);
440 IF not addr_place_ids <@ parent_name_vector THEN
441 -- make sure addr:place terms are always searchable
442 nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
443 -- If there is a housenumber, also add the place name as a name,
444 -- so we can search it by the usual housenumber+place algorithms.
445 IF hnr_vector is not null THEN
446 name_vector := array_merge(name_vector, addr_place_ids);
451 -- Cheating here by not recomputing all terms but simply using the ones
452 -- from the parent object.
453 nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
454 nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
461 -- Insert address of a place into the place_addressline table.
463 -- \param obj_place_id Place_id of the place to compute the address for.
464 -- \param partition Partition number where the place is in.
465 -- \param maxrank Rank of the place. All address features must have
466 -- a search rank lower than the given rank.
467 -- \param address Address terms for the place.
468 -- \param geometry Geometry to which the address objects should be close.
470 -- \retval parent_place_id Place_id of the address object that is the direct
472 -- \retval postcode Postcode computed from the address. This is the
473 -- addr:postcode of one of the address objects. If
474 -- more than one of has a postcode, the highest ranking
475 -- one is used. May be NULL.
476 -- \retval nameaddress_vector Search terms for the address. This is the sum
477 -- of name terms of all address objects.
478 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
485 OUT parent_place_id BIGINT,
487 OUT nameaddress_vector INT[])
490 address_havelevel BOOLEAN[];
492 location_isaddress BOOLEAN;
493 current_boundary GEOMETRY := NULL;
494 current_node_area GEOMETRY := NULL;
496 parent_place_rank INT := 0;
497 addr_place_ids BIGINT[] := '{}'::int[];
498 new_address_vector INT[];
502 parent_place_id := 0;
503 nameaddress_vector := '{}'::int[];
505 address_havelevel := array_fill(false, ARRAY[maxrank]);
509 FROM (SELECT extra.*, key
510 FROM token_get_address_keys(token_info) as key,
511 LATERAL get_addr_tag_rank(key, country) as extra) x,
512 LATERAL get_address_place(partition, geometry, from_rank, to_rank,
513 extent, token_info, key) as apl
514 ORDER BY rank_address, distance, isguess desc
516 IF location.place_id is null THEN
517 {% if not db.reverse_only %}
518 nameaddress_vector := array_merge(nameaddress_vector,
519 token_get_address_search_tokens(token_info,
523 {% if not db.reverse_only %}
524 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::INTEGER[]);
527 location_isaddress := not address_havelevel[location.rank_address];
528 IF not address_havelevel[location.rank_address] THEN
529 address_havelevel[location.rank_address] := true;
530 IF parent_place_rank < location.rank_address THEN
531 parent_place_id := location.place_id;
532 parent_place_rank := location.rank_address;
536 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
537 isaddress, distance, cached_rank_address)
538 VALUES (obj_place_id, location.place_id, not location.isguess,
539 true, location.distance, location.rank_address);
541 addr_place_ids := addr_place_ids || location.place_id;
546 SELECT * FROM getNearFeatures(partition, geometry, centroid, maxrank)
547 WHERE not addr_place_ids @> ARRAY[place_id]
548 ORDER BY rank_address, isguess asc,
550 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
551 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
552 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
555 -- Ignore all place nodes that do not fit in a lower level boundary.
556 CONTINUE WHEN location.isguess
557 and current_boundary is not NULL
558 and not ST_Contains(current_boundary, location.centroid);
560 -- If this is the first item in the rank, then assume it is the address.
561 location_isaddress := not address_havelevel[location.rank_address];
563 -- Further sanity checks to ensure that the address forms a sane hierarchy.
564 IF location_isaddress THEN
565 IF location.isguess and current_node_area is not NULL THEN
566 location_isaddress := ST_Contains(current_node_area, location.centroid);
568 IF not location.isguess and current_boundary is not NULL
569 and location.rank_address != 11 AND location.rank_address != 5 THEN
570 location_isaddress := ST_Contains(current_boundary, location.centroid);
574 IF location_isaddress THEN
575 address_havelevel[location.rank_address] := true;
576 parent_place_id := location.place_id;
578 -- Set postcode if we have one.
579 -- (Returned will be the highest ranking one.)
580 IF location.postcode is not NULL THEN
581 postcode = location.postcode;
584 -- Recompute the areas we need for hierarchy sanity checks.
585 IF location.rank_address != 11 AND location.rank_address != 5 THEN
586 IF location.isguess THEN
587 current_node_area := place_node_fuzzy_area(location.centroid,
588 location.rank_search);
590 current_node_area := NULL;
591 SELECT p.geometry FROM placex p
592 WHERE p.place_id = location.place_id INTO current_boundary;
597 -- Add it to the list of search terms
598 {% if not db.reverse_only %}
599 nameaddress_vector := array_merge(nameaddress_vector,
600 location.keywords::integer[]);
603 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
604 isaddress, distance, cached_rank_address)
605 VALUES (obj_place_id, location.place_id, not location.isguess,
606 location_isaddress, location.distance, location.rank_address);
613 CREATE OR REPLACE FUNCTION placex_insert()
620 country_code VARCHAR(2);
624 {% if debug %}RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
626 NEW.place_id := nextval('seq_place');
627 NEW.indexed_status := 1; --STATUS_NEW
629 NEW.centroid := ST_PointOnSurface(NEW.geometry);
630 NEW.country_code := lower(get_country_code(NEW.centroid));
632 NEW.partition := get_partition(NEW.country_code);
633 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.centroid);
635 IF NEW.osm_type = 'X' THEN
636 -- E'X'ternal records should already be in the right format so do nothing
638 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
640 IF NEW.class in ('place','boundary')
641 AND NEW.type in ('postcode','postal_code')
643 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
644 -- most likely just a part of a multipolygon postcode boundary, throw it away
648 NEW.name := hstore('ref', NEW.address->'postcode');
650 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
651 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
654 ELSEIF NEW.class = 'boundary' AND NOT is_area
657 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
658 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
663 SELECT * INTO NEW.rank_search, NEW.rank_address
664 FROM compute_place_rank(NEW.country_code,
665 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
666 NEW.class, NEW.type, NEW.admin_level,
667 (NEW.extratags->'capital') = 'yes',
668 NEW.address->'postcode');
670 -- a country code make no sense below rank 4 (country)
671 IF NEW.rank_search < 4 THEN
672 NEW.country_code := NULL;
677 {% if debug %}RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;{% endif %}
679 {% if not disable_diff_updates %}
680 -- The following is not needed until doing diff updates, and slows the main index process down
682 IF NEW.rank_address > 0 THEN
683 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
684 -- Performance: We just can't handle re-indexing for country level changes
685 IF st_area(NEW.geometry) < 1 THEN
686 -- mark items within the geometry for re-indexing
687 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
689 UPDATE placex SET indexed_status = 2
690 WHERE ST_Intersects(NEW.geometry, placex.geometry)
691 and indexed_status = 0
692 and ((rank_address = 0 and rank_search > NEW.rank_address)
693 or rank_address > NEW.rank_address
694 or (class = 'place' and osm_type = 'N')
696 and (rank_search < 28
698 or (NEW.rank_address >= 16 and address ? 'place'));
701 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
702 diameter := update_place_diameter(NEW.rank_search);
704 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
705 IF NEW.rank_search >= 26 THEN
706 -- roads may cause reparenting for >27 rank places
707 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
708 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
709 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);
710 ELSEIF NEW.rank_search >= 16 THEN
711 -- up to rank 16, street-less addresses may need reparenting
712 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');
714 -- for all other places the search terms may change as well
715 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);
722 -- add to tables for special search
723 -- Note: won't work on initial import because the classtype tables
724 -- do not yet exist. It won't hurt either.
725 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
726 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
728 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
729 USING NEW.place_id, ST_Centroid(NEW.geometry);
732 {% endif %} -- not disable_diff_updates
740 CREATE OR REPLACE FUNCTION placex_update()
746 relation_members TEXT[];
749 parent_address_level SMALLINT;
750 place_address_level SMALLINT;
754 name_vector INTEGER[];
755 nameaddress_vector INTEGER[];
756 addr_nameaddress_vector INTEGER[];
760 linked_node_id BIGINT;
761 linked_importance FLOAT;
762 linked_wikipedia TEXT;
764 is_place_address BOOLEAN;
768 IF OLD.indexed_status = 100 THEN
769 {% if debug %}RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;{% endif %}
770 delete from placex where place_id = OLD.place_id;
774 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
778 {% if debug %}RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;{% endif %}
780 NEW.indexed_date = now();
782 {% if 'search_name' in db.tables %}
783 DELETE from search_name WHERE place_id = NEW.place_id;
785 result := deleteSearchName(NEW.partition, NEW.place_id);
786 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
787 result := deleteRoad(NEW.partition, NEW.place_id);
788 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
790 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
792 -- NEW.linked_place_id contains the precomputed linkee. Save this and restore
793 -- the previous link status.
794 linked_place := NEW.linked_place_id;
795 NEW.linked_place_id := OLD.linked_place_id;
797 -- Remove linkage, if we have computed a different new linkee.
798 UPDATE placex SET linked_place_id = null, indexed_status = 2
799 WHERE linked_place_id = NEW.place_id
800 and (linked_place is null or linked_place_id != linked_place);
801 -- update not necessary for osmline, cause linked_place_id does not exist
803 -- Postcodes are just here to compute the centroids. They are not searchable
804 -- unless they are a boundary=postal_code.
805 -- There was an error in the style so that boundary=postal_code used to be
806 -- imported as place=postcode. That's why relations are allowed to pass here.
807 -- This can go away in a couple of versions.
808 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
809 NEW.token_info := null;
813 -- Compute a preliminary centroid.
814 NEW.centroid := ST_PointOnSurface(NEW.geometry);
816 -- recalculate country and partition
817 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
818 -- for countries, believe the mapped country code,
819 -- so that we remain in the right partition if the boundaries
821 NEW.country_code := lower(NEW.address->'country');
822 NEW.partition := get_partition(lower(NEW.country_code));
823 IF NEW.partition = 0 THEN
824 NEW.country_code := lower(get_country_code(NEW.centroid));
825 NEW.partition := get_partition(NEW.country_code);
828 IF NEW.rank_search >= 4 THEN
829 NEW.country_code := lower(get_country_code(NEW.centroid));
831 NEW.country_code := NULL;
833 NEW.partition := get_partition(NEW.country_code);
835 {% if debug %}RAISE WARNING 'Country updated: "%"', NEW.country_code;{% endif %}
838 -- recompute the ranks, they might change when linking changes
839 SELECT * INTO NEW.rank_search, NEW.rank_address
840 FROM compute_place_rank(NEW.country_code,
841 CASE WHEN ST_GeometryType(NEW.geometry)
842 IN ('ST_Polygon','ST_MultiPolygon')
843 THEN 'A' ELSE NEW.osm_type END,
844 NEW.class, NEW.type, NEW.admin_level,
845 (NEW.extratags->'capital') = 'yes',
846 NEW.address->'postcode');
848 -- Short-cut out for linked places. Note that this must happen after the
849 -- address rank has been recomputed. The linking might nullify a shift in
851 IF NEW.linked_place_id is not null THEN
852 NEW.token_info := null;
853 {% if debug %}RAISE WARNING 'place already linked to %', OLD.linked_place_id;{% endif %}
857 -- We must always increase the address level relative to the admin boundary.
858 IF NEW.class = 'boundary' and NEW.type = 'administrative'
859 and NEW.osm_type = 'R' and NEW.rank_address > 0
861 -- First, check that admin boundaries do not overtake each other rank-wise.
862 parent_address_level := 3;
865 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
866 and extratags->'wikidata' = NEW.extratags->'wikidata'
867 THEN ST_Equals(geometry, NEW.geometry)
868 ELSE false END) as is_same
870 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
871 and admin_level < NEW.admin_level and admin_level > 3
872 and rank_address between 1 and 25 -- for index selection
873 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- for index selection
874 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
875 ORDER BY admin_level desc LIMIT 1
877 IF location.is_same THEN
878 -- Looks like the same boundary is replicated on multiple admin_levels.
879 -- Usual tagging in Poland. Remove our boundary from addresses.
880 NEW.rank_address := 0;
882 parent_address_level := location.rank_address;
883 IF location.rank_address >= NEW.rank_address THEN
884 IF location.rank_address >= 24 THEN
885 NEW.rank_address := 25;
887 NEW.rank_address := location.rank_address + 2;
893 IF NEW.rank_address > 9 THEN
894 -- Second check that the boundary is not completely contained in a
895 -- place area with a equal or higher address rank.
899 LATERAL compute_place_rank(country_code, 'A', class, type,
900 admin_level, False, null) prank
901 WHERE class = 'place' and rank_address between 1 and 23
902 and prank.address_rank >= NEW.rank_address
903 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
904 and geometry && NEW.geometry
905 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
906 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
907 ORDER BY prank.address_rank desc LIMIT 1
909 NEW.rank_address := location.rank_address + 2;
912 ELSEIF NEW.class = 'place'
913 and ST_GeometryType(NEW.geometry) in ('ST_Polygon', 'ST_MultiPolygon')
914 and NEW.rank_address between 16 and 23
916 -- For place areas make sure they are not completely contained in an area
917 -- with a equal or higher address rank.
921 LATERAL compute_place_rank(country_code, 'A', class, type,
922 admin_level, False, null) prank
923 WHERE prank.address_rank < 24
924 and rank_address between 1 and 25 -- select right index
925 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
926 and prank.address_rank >= NEW.rank_address
927 and geometry && NEW.geometry
928 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
929 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
930 ORDER BY prank.address_rank desc LIMIT 1
932 NEW.rank_address := location.rank_address + 2;
934 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
935 and NEW.rank_address between 16 and 23
937 -- If a place node is contained in an admin or place boundary with the same
938 -- address level and has not been linked, then make the node a subpart
939 -- by increasing the address rank (city level and above).
943 LATERAL compute_place_rank(country_code, 'A', class, type,
944 admin_level, False, null) prank
946 and rank_address between 1 and 25 -- select right index
947 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') -- select right index
948 and ((class = 'place' and prank.address_rank = NEW.rank_address)
949 or (class = 'boundary' and rank_address = NEW.rank_address))
950 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
953 NEW.rank_address = NEW.rank_address + 2;
956 parent_address_level := 3;
959 NEW.housenumber := token_normalized_housenumber(NEW.token_info);
961 NEW.postcode := null;
963 -- waterway ways are linked when they are part of a relation and have the same class/type
964 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
965 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
967 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
968 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
969 {% if debug %}RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];{% endif %}
970 FOR linked_node_id IN SELECT place_id FROM placex
971 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
972 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
973 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
975 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
976 {% if 'search_name' in db.tables %}
977 DELETE FROM search_name WHERE place_id = linked_node_id;
983 {% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
986 NEW.importance := null;
987 SELECT wikipedia, importance
988 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.rank_search, NEW.centroid)
989 INTO NEW.wikipedia,NEW.importance;
991 {% if debug %}RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;{% endif %}
993 -- ---------------------------------------------------------------------------
994 -- For low level elements we inherit from our parent road
995 IF NEW.rank_search > 27 THEN
997 {% if debug %}RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;{% endif %}
998 NEW.parent_place_id := null;
999 is_place_address := coalesce(not NEW.address ? 'street' and NEW.address ? 'place', FALSE);
1001 -- We have to find our parent road.
1002 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
1004 ST_Envelope(NEW.geometry),
1008 -- If we found the road take a shortcut here.
1009 -- Otherwise fall back to the full address getting method below.
1010 IF NEW.parent_place_id is not null THEN
1012 -- Get the details of the parent road
1013 SELECT p.country_code, p.postcode, p.name FROM placex p
1014 WHERE p.place_id = NEW.parent_place_id INTO location;
1016 IF is_place_address THEN
1017 -- Check if the addr:place tag is part of the parent name
1018 SELECT count(*) INTO i
1019 FROM svals(location.name) AS pname WHERE pname = NEW.address->'place';
1021 NEW.address = NEW.address || hstore('_unlisted_place', NEW.address->'place');
1025 NEW.country_code := location.country_code;
1026 {% if debug %}RAISE WARNING 'Got parent details from search name';{% endif %}
1028 -- determine postcode
1029 NEW.postcode := coalesce(token_get_postcode(NEW.token_info),
1031 get_nearest_postcode(NEW.country_code, NEW.centroid));
1033 IF NEW.name is not NULL THEN
1034 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1037 {% if not db.reverse_only %}
1038 IF NEW.name is not NULL OR NEW.address is not NULL THEN
1039 SELECT * INTO name_vector, nameaddress_vector
1040 FROM create_poi_search_terms(NEW.place_id,
1041 NEW.partition, NEW.parent_place_id,
1042 is_place_address, NEW.country_code,
1043 NEW.token_info, NEW.centroid);
1045 IF array_length(name_vector, 1) is not NULL THEN
1046 INSERT INTO search_name (place_id, search_rank, address_rank,
1047 importance, country_code, name_vector,
1048 nameaddress_vector, centroid)
1049 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1050 NEW.importance, NEW.country_code, name_vector,
1051 nameaddress_vector, NEW.centroid);
1052 {% if debug %}RAISE WARNING 'Place added to search table';{% endif %}
1057 NEW.token_info := token_strip_info(NEW.token_info);
1064 -- ---------------------------------------------------------------------------
1066 {% if debug %}RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;{% endif %}
1067 IF linked_place is not null THEN
1068 -- Recompute the ranks here as the ones from the linked place might
1069 -- have been shifted to accommodate surrounding boundaries.
1070 SELECT place_id, osm_id, class, type, extratags, rank_search,
1072 (compute_place_rank(country_code, osm_type, class, type, admin_level,
1073 (extratags->'capital') = 'yes', null)).*
1075 FROM placex WHERE place_id = linked_place;
1077 {% if debug %}RAISE WARNING 'Linked %', location;{% endif %}
1079 -- Use the linked point as the centre point of the geometry,
1080 -- but only if it is within the area of the boundary.
1081 geom := coalesce(location.centroid, ST_Centroid(location.geometry));
1082 IF geom is not NULL AND ST_Within(geom, NEW.geometry) THEN
1083 NEW.centroid := geom;
1086 {% if debug %}RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.address_rank;{% endif %}
1087 IF location.address_rank > parent_address_level
1088 and location.address_rank < 26
1090 NEW.rank_address := location.address_rank;
1093 -- merge in extra tags
1094 NEW.extratags := hstore('linked_' || location.class, location.type)
1095 || coalesce(location.extratags, ''::hstore)
1096 || coalesce(NEW.extratags, ''::hstore);
1098 -- mark the linked place (excludes from search results)
1099 -- Force reindexing to remove any traces from the search indexes and
1100 -- reset the address rank if necessary.
1101 UPDATE placex set linked_place_id = NEW.place_id, indexed_status = 2
1102 WHERE place_id = location.place_id;
1103 -- ensure that those places are not found anymore
1104 {% if 'search_name' in db.tables %}
1105 DELETE FROM search_name WHERE place_id = location.place_id;
1107 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
1109 SELECT wikipedia, importance
1110 FROM compute_importance(location.extratags, NEW.country_code,
1111 location.rank_search, NEW.centroid)
1112 INTO linked_wikipedia,linked_importance;
1114 -- Use the maximum importance if one could be computed from the linked object.
1115 IF linked_importance is not null AND
1116 (NEW.importance is null or NEW.importance < linked_importance)
1118 NEW.importance = linked_importance;
1121 -- No linked place? As a last resort check if the boundary is tagged with
1122 -- a place type and adapt the rank address.
1123 IF NEW.rank_address > 0 and NEW.extratags ? 'place' THEN
1124 SELECT address_rank INTO place_address_level
1125 FROM compute_place_rank(NEW.country_code, 'A', 'place',
1126 NEW.extratags->'place', 0::SMALLINT, False, null);
1127 IF place_address_level > parent_address_level and
1128 place_address_level < 26 THEN
1129 NEW.rank_address := place_address_level;
1134 {% if not disable_diff_updates %}
1135 IF OLD.rank_address != NEW.rank_address THEN
1136 -- After a rank shift all addresses containing us must be updated.
1137 UPDATE placex p SET indexed_status = 2 FROM place_addressline pa
1138 WHERE pa.address_place_id = NEW.place_id and p.place_id = pa.place_id
1139 and p.indexed_status = 0 and p.rank_address between 4 and 25;
1143 IF NEW.admin_level = 2
1144 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
1145 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
1147 -- Update the list of country names.
1148 -- Only take the name from the largest area for the given country code
1149 -- in the hope that this is the authoritative one.
1150 -- Also replace any old names so that all mapping mistakes can
1151 -- be fixed through regular OSM updates.
1153 SELECT osm_id FROM placex
1154 WHERE rank_search = 4 and osm_type = 'R'
1155 and country_code = NEW.country_code
1156 ORDER BY ST_Area(geometry) desc
1159 IF location.osm_id = NEW.osm_id THEN
1160 {% if debug %}RAISE WARNING 'Updating names for country '%' with: %', NEW.country_code, NEW.name;{% endif %}
1161 UPDATE country_name SET derived_name = NEW.name WHERE country_code = NEW.country_code;
1166 -- For linear features we need the full geometry for determining the address
1167 -- because they may go through several administrative entities. Otherwise use
1168 -- the centroid for performance reasons.
1169 IF ST_GeometryType(NEW.geometry) in ('ST_LineString', 'ST_MultiLineString') THEN
1170 geom := NEW.geometry;
1172 geom := NEW.centroid;
1175 IF NEW.rank_address = 0 THEN
1176 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
1177 -- Rank 0 features may also span multiple administrative areas (e.g. lakes)
1178 -- so use the geometry here too. Just make sure the areas don't become too
1180 IF NEW.class = 'natural' or max_rank > 10 THEN
1181 geom := NEW.geometry;
1183 ELSEIF NEW.rank_address > 25 THEN
1186 max_rank := NEW.rank_address;
1189 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
1190 NEW.token_info, geom, NEW.centroid,
1192 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
1194 {% if debug %}RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;{% endif %}
1196 NEW.postcode := coalesce(token_get_postcode(NEW.token_info), NEW.postcode);
1198 -- if we have a name add this to the name search table
1199 IF NEW.name IS NOT NULL THEN
1200 -- Initialise the name vector using our name
1201 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
1202 name_vector := token_get_name_search_tokens(NEW.token_info);
1204 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1205 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
1206 name_vector, NEW.rank_search, NEW.rank_address,
1207 NEW.postcode, NEW.geometry, NEW.centroid);
1208 {% if debug %}RAISE WARNING 'added to location (full)';{% endif %}
1211 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1212 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1213 {% if debug %}RAISE WARNING 'insert into road location table (full)';{% endif %}
1216 IF NEW.rank_address between 16 and 27 THEN
1217 result := insertSearchName(NEW.partition, NEW.place_id,
1218 token_get_name_match_tokens(NEW.token_info),
1219 NEW.rank_search, NEW.rank_address, NEW.geometry);
1221 {% if debug %}RAISE WARNING 'added to search name (full)';{% endif %}
1223 {% if not db.reverse_only %}
1224 INSERT INTO search_name (place_id, search_rank, address_rank,
1225 importance, country_code, name_vector,
1226 nameaddress_vector, centroid)
1227 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1228 NEW.importance, NEW.country_code, name_vector,
1229 nameaddress_vector, NEW.centroid);
1233 IF NEW.postcode is null AND NEW.rank_search > 8
1234 AND (NEW.rank_address > 0
1235 OR ST_GeometryType(NEW.geometry) not in ('ST_LineString','ST_MultiLineString')
1236 OR ST_Length(NEW.geometry) < 0.02)
1238 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1241 {% if debug %}RAISE WARNING 'place update % % finished.', NEW.osm_type, NEW.osm_id;{% endif %}
1243 NEW.token_info := token_strip_info(NEW.token_info);
1250 CREATE OR REPLACE FUNCTION placex_delete()
1257 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1259 IF OLD.linked_place_id is null THEN
1260 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1261 {% if debug %}RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1262 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1263 {% if debug %}RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1265 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1268 IF OLD.rank_address < 30 THEN
1270 -- mark everything linked to this place for re-indexing
1271 {% if debug %}RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1272 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1273 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1275 {% if debug %}RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1276 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1278 {% if debug %}RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1279 b := deleteRoad(OLD.partition, OLD.place_id);
1281 {% if debug %}RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1282 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1283 {% if debug %}RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1284 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1285 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1289 {% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1291 IF OLD.rank_address < 26 THEN
1292 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1295 {% if debug %}RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1297 IF OLD.name is not null THEN
1298 {% if 'search_name' in db.tables %}
1299 DELETE from search_name WHERE place_id = OLD.place_id;
1301 b := deleteSearchName(OLD.partition, OLD.place_id);
1304 {% if debug %}RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1306 DELETE FROM place_addressline where place_id = OLD.place_id;
1308 {% if debug %}RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;{% endif %}
1310 -- remove from tables for special search
1311 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1312 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1314 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1317 {% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}