1 -- Trigger functions for the placex table.
3 -- Find the parent road of a POI.
5 -- \returns Place ID of parent object or NULL if none
7 -- Copy data from linked items (POIs on ways, addr:street links, relations).
9 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
11 poi_partition SMALLINT,
19 parent_place_id BIGINT DEFAULT NULL;
23 --DEBUG: RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;
25 -- Is this object part of an associatedStreet relation?
27 SELECT members FROM planet_osm_rels
28 WHERE parts @> ARRAY[poi_osm_id]
29 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
30 and tags @> ARRAY['associatedStreet']
32 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
33 IF location.members[i+1] = 'street' THEN
35 SELECT place_id from placex
36 WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
38 and rank_search between 26 and 27
40 RETURN parent.place_id;
46 parent_place_id := find_parent_for_address(addr_street, addr_place,
48 IF parent_place_id is not null THEN
49 RETURN parent_place_id;
52 IF poi_osm_type = 'N' THEN
53 -- Is this node part of an interpolation?
55 SELECT q.parent_place_id
56 FROM location_property_osmline q, planet_osm_ways x
57 WHERE q.linegeo && bbox and x.id = q.osm_id
58 and poi_osm_id = any(x.nodes)
61 --DEBUG: RAISE WARNING 'Get parent from interpolation: %', parent.parent_place_id;
62 RETURN parent.parent_place_id;
65 -- Is this node part of any other way?
67 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
68 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
69 FROM placex p, planet_osm_ways w
70 WHERE p.osm_type = 'W' and p.rank_search >= 26
71 and p.geometry && bbox
72 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
74 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
76 -- Way IS a road then we are on it - that must be our road
77 IF location.rank_search < 28 THEN
78 --DEBUG: RAISE WARNING 'node in way that is a street %',location;
79 return location.place_id;
82 SELECT find_parent_for_poi('W', location.osm_id, poi_partition,
84 location.address->'street',
85 location.address->'place',
88 IF parent_place_id is not null THEN
89 RETURN parent_place_id;
95 IF addr_street is null and addr_place is not null THEN
96 -- The address is attached to a place we don't know.
97 -- Instead simply use the containing area with the largest rank.
99 SELECT place_id FROM placex
100 WHERE bbox @ geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
101 AND rank_address between 5 and 25
102 ORDER BY rank_address desc
104 RETURN location.place_id;
106 ELSEIF ST_Area(bbox) < 0.005 THEN
107 -- for smaller features get the nearest road
108 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
109 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
111 -- for larger features simply find the area with the largest rank that
112 -- contains the bbox, only use addressable features
114 SELECT place_id FROM placex
115 WHERE bbox @ geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
116 AND rank_address between 5 and 25
117 ORDER BY rank_address desc
119 RETURN location.place_id;
124 RETURN parent_place_id;
127 LANGUAGE plpgsql STABLE;
129 -- Try to find a linked place for the given object.
130 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
134 relation_members TEXT[];
136 linked_placex placex%ROWTYPE;
139 IF bnd.rank_search >= 26 or bnd.rank_address = 0
140 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
141 or bnd.type IN ('postcode', 'postal_code')
146 IF bnd.osm_type = 'R' THEN
147 -- see if we have any special relation members
148 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
149 --DEBUG: RAISE WARNING 'Got relation members';
151 -- Search for relation members with role 'lable'.
152 IF relation_members IS NOT NULL THEN
154 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
156 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
160 WHERE osm_type = 'N' and osm_id = rel_member.member
163 --DEBUG: RAISE WARNING 'Linked label member';
164 RETURN linked_placex;
171 IF bnd.name ? 'name' THEN
172 bnd_name := make_standard_name(bnd.name->'name');
173 IF bnd_name = '' THEN
178 -- If extratags has a place tag, look for linked nodes by their place type.
179 -- Area and node still have to have the same name.
180 IF bnd.extratags ? 'place' and bnd_name is not null THEN
183 WHERE make_standard_name(name->'name') = bnd_name
184 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
185 AND placex.osm_type = 'N'
186 AND placex.rank_search < 26 -- needed to select the right index
187 AND _st_covers(bnd.geometry, placex.geometry)
189 --DEBUG: RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;
190 RETURN linked_placex;
194 IF bnd.extratags ? 'wikidata' THEN
197 WHERE placex.class = 'place' AND placex.osm_type = 'N'
198 AND placex.extratags ? 'wikidata' -- needed to select right index
199 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
200 AND placex.rank_search < 26
201 AND _st_covers(bnd.geometry, placex.geometry)
202 ORDER BY make_standard_name(name->'name') = bnd_name desc
204 --DEBUG: RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;
205 RETURN linked_placex;
209 -- Name searches can be done for ways as well as relations
210 IF bnd_name is not null THEN
211 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
213 SELECT placex.* from placex
214 WHERE make_standard_name(name->'name') = bnd_name
215 AND ((bnd.rank_address > 0
216 and bnd.rank_address = (compute_place_rank(placex.country_code,
218 placex.type, 15::SMALLINT,
219 false, placex.postcode)).address_rank)
220 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
221 AND placex.osm_type = 'N'
222 AND placex.rank_search < 26 -- needed to select the right index
223 AND _st_covers(bnd.geometry, placex.geometry)
225 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
226 RETURN linked_placex;
233 LANGUAGE plpgsql STABLE;
236 -- Insert address of a place into the place_addressline table.
238 -- \param obj_place_id Place_id of the place to compute the address for.
239 -- \param partition Partition number where the place is in.
240 -- \param maxrank Rank of the place. All address features must have
241 -- a search rank lower than the given rank.
242 -- \param address Address terms for the place.
243 -- \param geometry Geometry to which the address objects should be close.
245 -- \retval parent_place_id Place_id of the address object that is the direct
247 -- \retval postcode Postcode computed from the address. This is the
248 -- addr:postcode of one of the address objects. If
249 -- more than one of has a postcode, the highest ranking
250 -- one is used. May be NULL.
251 -- \retval nameaddress_vector Search terms for the address. This is the sum
252 -- of name terms of all address objects.
253 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
259 OUT parent_place_id BIGINT,
261 OUT nameaddress_vector INT[])
264 address_havelevel BOOLEAN[];
266 location_isaddress BOOLEAN;
267 current_boundary GEOMETRY := NULL;
268 current_node_area GEOMETRY := NULL;
270 parent_place_rank INT := 0;
271 addr_place_ids BIGINT[];
275 parent_place_id := 0;
276 nameaddress_vector := '{}'::int[];
278 address_havelevel := array_fill(false, ARRAY[maxrank]);
281 SELECT * FROM get_places_for_addr_tags(partition, geometry,
283 ORDER BY rank_address, distance, isguess desc
285 IF NOT %REVERSE-ONLY% THEN
286 nameaddress_vector := array_merge(nameaddress_vector,
287 location.keywords::int[]);
290 IF location.place_id is not null THEN
291 location_isaddress := not address_havelevel[location.rank_address];
292 IF not address_havelevel[location.rank_address] THEN
293 address_havelevel[location.rank_address] := true;
294 IF parent_place_rank < location.rank_address THEN
295 parent_place_id := location.place_id;
296 parent_place_rank := location.rank_address;
300 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
301 isaddress, distance, cached_rank_address)
302 VALUES (obj_place_id, location.place_id, not location.isguess,
303 true, location.distance, location.rank_address);
305 addr_place_ids := array_append(addr_place_ids, location.place_id);
310 SELECT * FROM getNearFeatures(partition, geometry, maxrank)
311 WHERE addr_place_ids is null or not addr_place_ids @> ARRAY[place_id]
312 ORDER BY rank_address, isguess asc,
314 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
315 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
316 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
319 -- Ignore all place nodes that do not fit in a lower level boundary.
320 CONTINUE WHEN location.isguess
321 and current_boundary is not NULL
322 and not ST_Contains(current_boundary, location.centroid);
324 -- If this is the first item in the rank, then assume it is the address.
325 location_isaddress := not address_havelevel[location.rank_address];
327 -- Further sanity checks to ensure that the address forms a sane hierarchy.
328 IF location_isaddress THEN
329 IF location.isguess and current_node_area is not NULL THEN
330 location_isaddress := ST_Contains(current_node_area, location.centroid);
332 IF not location.isguess and current_boundary is not NULL
333 and location.rank_address != 11 AND location.rank_address != 5 THEN
334 location_isaddress := ST_Contains(current_boundary, location.centroid);
338 IF location_isaddress THEN
339 address_havelevel[location.rank_address] := true;
340 parent_place_id := location.place_id;
342 -- Set postcode if we have one.
343 -- (Returned will be the highest ranking one.)
344 IF location.postcode is not NULL THEN
345 postcode = location.postcode;
348 -- Recompute the areas we need for hierarchy sanity checks.
349 IF location.rank_address != 11 AND location.rank_address != 5 THEN
350 IF location.isguess THEN
351 current_node_area := place_node_fuzzy_area(location.centroid,
352 location.rank_search);
354 current_node_area := NULL;
355 SELECT p.geometry FROM placex p
356 WHERE p.place_id = location.place_id INTO current_boundary;
361 -- Add it to the list of search terms
362 IF NOT %REVERSE-ONLY% THEN
363 nameaddress_vector := array_merge(nameaddress_vector,
364 location.keywords::integer[]);
367 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
368 isaddress, distance, cached_rank_address)
369 VALUES (obj_place_id, location.place_id, not location.isguess,
370 location_isaddress, location.distance, location.rank_address);
377 CREATE OR REPLACE FUNCTION placex_insert()
384 country_code VARCHAR(2);
388 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
390 NEW.place_id := nextval('seq_place');
391 NEW.indexed_status := 1; --STATUS_NEW
393 NEW.country_code := lower(get_country_code(NEW.geometry));
395 NEW.partition := get_partition(NEW.country_code);
396 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
398 IF NEW.osm_type = 'X' THEN
399 -- E'X'ternal records should already be in the right format so do nothing
401 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
403 IF NEW.class in ('place','boundary')
404 AND NEW.type in ('postcode','postal_code')
406 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
407 -- most likely just a part of a multipolygon postcode boundary, throw it away
411 NEW.name := hstore('ref', NEW.address->'postcode');
413 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
414 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
417 ELSEIF NEW.class = 'boundary' AND NOT is_area
420 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
421 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
426 SELECT * INTO NEW.rank_search, NEW.rank_address
427 FROM compute_place_rank(NEW.country_code,
428 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
429 NEW.class, NEW.type, NEW.admin_level,
430 (NEW.extratags->'capital') = 'yes',
431 NEW.address->'postcode');
433 -- a country code make no sense below rank 4 (country)
434 IF NEW.rank_search < 4 THEN
435 NEW.country_code := NULL;
440 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
442 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
444 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
445 -- might be part of an interpolation
446 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
447 ELSEIF NEW.rank_address > 0 THEN
448 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
449 -- Performance: We just can't handle re-indexing for country level changes
450 IF st_area(NEW.geometry) < 1 THEN
451 -- mark items within the geometry for re-indexing
452 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
454 UPDATE placex SET indexed_status = 2
455 WHERE ST_Intersects(NEW.geometry, placex.geometry)
456 and indexed_status = 0
457 and ((rank_address = 0 and rank_search > NEW.rank_address)
458 or rank_address > NEW.rank_address
459 or (class = 'place' and osm_type = 'N')
461 and (rank_search < 28
463 or (NEW.rank_address >= 16 and address ? 'place'));
466 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
467 diameter := update_place_diameter(NEW.rank_search);
469 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
470 IF NEW.rank_search >= 26 THEN
471 -- roads may cause reparenting for >27 rank places
472 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
473 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
474 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
475 ELSEIF NEW.rank_search >= 16 THEN
476 -- up to rank 16, street-less addresses may need reparenting
477 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');
479 -- for all other places the search terms may change as well
480 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);
487 -- add to tables for special search
488 -- Note: won't work on initial import because the classtype tables
489 -- do not yet exist. It won't hurt either.
490 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
491 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
493 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
494 USING NEW.place_id, ST_Centroid(NEW.geometry);
503 CREATE OR REPLACE FUNCTION placex_update()
509 relation_members TEXT[];
512 parent_address_level SMALLINT;
513 place_address_level SMALLINT;
520 name_vector INTEGER[];
521 nameaddress_vector INTEGER[];
522 addr_nameaddress_vector INTEGER[];
524 inherited_address HSTORE;
526 linked_node_id BIGINT;
527 linked_importance FLOAT;
528 linked_wikipedia TEXT;
533 IF OLD.indexed_status = 100 THEN
534 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
535 delete from placex where place_id = OLD.place_id;
539 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
543 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
545 NEW.indexed_date = now();
547 IF NOT %REVERSE-ONLY% THEN
548 DELETE from search_name WHERE place_id = NEW.place_id;
550 result := deleteSearchName(NEW.partition, NEW.place_id);
551 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
552 result := deleteRoad(NEW.partition, NEW.place_id);
553 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
554 UPDATE placex set linked_place_id = null, indexed_status = 2
555 where linked_place_id = NEW.place_id;
556 -- update not necessary for osmline, cause linked_place_id does not exist
558 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
559 NEW.address := NEW.address - '_unlisted_place'::TEXT;
561 IF NEW.linked_place_id is not null THEN
562 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
566 -- Postcodes are just here to compute the centroids. They are not searchable
567 -- unless they are a boundary=postal_code.
568 -- There was an error in the style so that boundary=postal_code used to be
569 -- imported as place=postcode. That's why relations are allowed to pass here.
570 -- This can go away in a couple of versions.
571 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
575 -- Speed up searches - just use the centroid of the feature
576 -- cheaper but less acurate
577 NEW.centroid := ST_PointOnSurface(NEW.geometry);
578 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
580 -- recompute the ranks, they might change when linking changes
581 SELECT * INTO NEW.rank_search, NEW.rank_address
582 FROM compute_place_rank(NEW.country_code,
583 CASE WHEN ST_GeometryType(NEW.geometry)
584 IN ('ST_Polygon','ST_MultiPolygon')
585 THEN 'A' ELSE NEW.osm_type END,
586 NEW.class, NEW.type, NEW.admin_level,
587 (NEW.extratags->'capital') = 'yes',
588 NEW.address->'postcode');
589 -- We must always increase the address level relative to the admin boundary.
590 IF NEW.class = 'boundary' and NEW.type = 'administrative'
591 and NEW.osm_type = 'R' and NEW.rank_address > 0
593 -- First, check that admin boundaries do not overtake each other rank-wise.
594 parent_address_level := 3;
597 (CASE WHEN extratags ? 'wikidata' and NEW.extratags ? 'wikidata'
598 and extratags->'wikidata' = NEW.extratags->'wikidata'
599 THEN ST_Equals(geometry, NEW.geometry)
600 ELSE false END) as is_same
602 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
603 and admin_level < NEW.admin_level and admin_level > 3
605 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
606 ORDER BY admin_level desc LIMIT 1
608 IF location.is_same THEN
609 -- Looks like the same boundary is replicated on multiple admin_levels.
610 -- Usual tagging in Poland. Remove our boundary from addresses.
611 NEW.rank_address := 0;
613 parent_address_level := location.rank_address;
614 IF location.rank_address >= NEW.rank_address THEN
615 IF location.rank_address >= 24 THEN
616 NEW.rank_address := 25;
618 NEW.rank_address := location.rank_address + 2;
624 IF NEW.rank_address > 9 THEN
625 -- Second check that the boundary is not completely contained in a
626 -- place area with a higher address rank
628 SELECT rank_address FROM placex
629 WHERE class = 'place' and rank_address < 24
630 and rank_address > NEW.rank_address
631 and geometry && NEW.geometry
632 and geometry ~ NEW.geometry -- needed because ST_Relate does not do bbox cover test
633 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
634 ORDER BY rank_address desc LIMIT 1
636 NEW.rank_address := location.rank_address + 2;
639 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
640 and NEW.rank_address between 16 and 23
642 -- If a place node is contained in a admin boundary with the same address level
643 -- and has not been linked, then make the node a subpart by increasing the
644 -- address rank (city level and above).
646 SELECT rank_address FROM placex
647 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
648 and rank_address = NEW.rank_address
649 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
652 NEW.rank_address = NEW.rank_address + 2;
655 parent_address_level := 3;
658 --DEBUG: RAISE WARNING 'Copy over address tags';
659 -- housenumber is a computed field, so start with an empty value
660 NEW.housenumber := NULL;
661 IF NEW.address is not NULL THEN
662 IF NEW.address ? 'conscriptionnumber' THEN
663 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
664 IF NEW.address ? 'streetnumber' THEN
665 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
666 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
668 NEW.housenumber := NEW.address->'conscriptionnumber';
670 ELSEIF NEW.address ? 'streetnumber' THEN
671 NEW.housenumber := NEW.address->'streetnumber';
672 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
673 ELSEIF NEW.address ? 'housenumber' THEN
674 NEW.housenumber := NEW.address->'housenumber';
675 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
678 addr_street := NEW.address->'street';
679 addr_place := NEW.address->'place';
681 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(:|,|;)%' THEN
682 i := getorcreate_postcode_id(NEW.address->'postcode');
686 NEW.postcode := null;
688 -- recalculate country and partition
689 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
690 -- for countries, believe the mapped country code,
691 -- so that we remain in the right partition if the boundaries
693 NEW.country_code := lower(NEW.address->'country');
694 NEW.partition := get_partition(lower(NEW.country_code));
695 IF NEW.partition = 0 THEN
696 NEW.country_code := lower(get_country_code(NEW.centroid));
697 NEW.partition := get_partition(NEW.country_code);
700 IF NEW.rank_search >= 4 THEN
701 NEW.country_code := lower(get_country_code(NEW.centroid));
703 NEW.country_code := NULL;
705 NEW.partition := get_partition(NEW.country_code);
707 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
709 -- waterway ways are linked when they are part of a relation and have the same class/type
710 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
711 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
713 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
714 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
715 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
716 FOR linked_node_id IN SELECT place_id FROM placex
717 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
718 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
719 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
721 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
722 IF NOT %REVERSE-ONLY% THEN
723 DELETE FROM search_name WHERE place_id = linked_node_id;
729 --DEBUG: RAISE WARNING 'Waterway processed';
732 NEW.importance := null;
733 SELECT wikipedia, importance
734 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
735 INTO NEW.wikipedia,NEW.importance;
737 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
739 -- ---------------------------------------------------------------------------
740 -- For low level elements we inherit from our parent road
741 IF NEW.rank_search > 27 THEN
743 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
744 NEW.parent_place_id := null;
746 -- if we have a POI and there is no address information,
747 -- see if we can get it from a surrounding building
748 inherited_address := ''::HSTORE;
749 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
750 AND NEW.housenumber IS NULL THEN
752 -- The additional && condition works around the misguided query
753 -- planner of postgis 3.0.
754 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
755 and geometry && NEW.centroid
756 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
757 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
760 NEW.housenumber := location.address->'housenumber';
761 addr_street := location.address->'street';
762 addr_place := location.address->'place';
763 inherited_address := location.address;
767 -- We have to find our parent road.
768 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
770 ST_Envelope(NEW.geometry),
771 addr_street, addr_place);
773 -- If we found the road take a shortcut here.
774 -- Otherwise fall back to the full address getting method below.
775 IF NEW.parent_place_id is not null THEN
777 -- Get the details of the parent road
778 SELECT p.country_code, p.postcode, p.name FROM placex p
779 WHERE p.place_id = NEW.parent_place_id INTO location;
781 IF addr_street is null and addr_place is not null THEN
782 -- Check if the addr:place tag is part of the parent name
783 SELECT count(*) INTO i
784 FROM svals(location.name) AS pname WHERE pname = addr_place;
786 NEW.address = NEW.address || hstore('_unlisted_place', addr_place);
790 NEW.country_code := location.country_code;
791 --DEBUG: RAISE WARNING 'Got parent details from search name';
793 -- determine postcode
794 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
795 NEW.postcode = upper(trim(NEW.address->'postcode'));
797 NEW.postcode := location.postcode;
799 IF NEW.postcode is null THEN
800 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
803 IF NEW.name is not NULL THEN
804 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
805 name_vector := make_keywords(NEW.name);
807 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
808 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
809 name_vector, NEW.rank_search, NEW.rank_address,
810 upper(trim(NEW.address->'postcode')), NEW.geometry,
812 --DEBUG: RAISE WARNING 'Place added to location table';
817 IF array_length(name_vector, 1) is not NULL
818 OR inherited_address is not NULL OR NEW.address is not NULL
820 SELECT * INTO name_vector, nameaddress_vector
821 FROM create_poi_search_terms(NEW.place_id,
822 NEW.partition, NEW.parent_place_id,
823 inherited_address || NEW.address,
824 NEW.country_code, NEW.housenumber,
825 name_vector, NEW.centroid);
827 IF not %REVERSE-ONLY% AND array_length(name_vector, 1) is not NULL THEN
828 INSERT INTO search_name (place_id, search_rank, address_rank,
829 importance, country_code, name_vector,
830 nameaddress_vector, centroid)
831 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
832 NEW.importance, NEW.country_code, name_vector,
833 nameaddress_vector, NEW.centroid);
834 --DEBUG: RAISE WARNING 'Place added to search table';
843 -- ---------------------------------------------------------------------------
845 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
846 SELECT * INTO location FROM find_linked_place(NEW);
847 IF location.place_id is not null THEN
848 --DEBUG: RAISE WARNING 'Linked %', location;
850 -- Use the linked point as the centre point of the geometry,
851 -- but only if it is within the area of the boundary.
852 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
853 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
854 NEW.centroid := centroid;
857 --DEBUG: RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.rank_address;
858 IF location.rank_address > parent_address_level
859 and location.rank_address < 26
861 NEW.rank_address := location.rank_address;
864 -- merge in the label name
865 IF NOT location.name IS NULL THEN
866 NEW.name := location.name || NEW.name;
869 -- merge in extra tags
870 NEW.extratags := hstore('linked_' || location.class, location.type)
871 || coalesce(location.extratags, ''::hstore)
872 || coalesce(NEW.extratags, ''::hstore);
874 -- mark the linked place (excludes from search results)
875 UPDATE placex set linked_place_id = NEW.place_id
876 WHERE place_id = location.place_id;
877 -- ensure that those places are not found anymore
878 IF NOT %REVERSE-ONLY% THEN
879 DELETE FROM search_name WHERE place_id = location.place_id;
881 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
883 SELECT wikipedia, importance
884 FROM compute_importance(location.extratags, NEW.country_code,
885 'N', location.osm_id)
886 INTO linked_wikipedia,linked_importance;
888 -- Use the maximum importance if one could be computed from the linked object.
889 IF linked_importance is not null AND
890 (NEW.importance is null or NEW.importance < linked_importance)
892 NEW.importance = linked_importance;
895 -- No linked place? As a last resort check if the boundary is tagged with
896 -- a place type and adapt the rank address.
897 IF NEW.rank_address > 0 and NEW.extratags ? 'place' THEN
898 SELECT address_rank INTO place_address_level
899 FROM compute_place_rank(NEW.country_code, 'A', 'place',
900 NEW.extratags->'place', 0::SMALLINT, False, null);
901 IF place_address_level > parent_address_level and
902 place_address_level < 26 THEN
903 NEW.rank_address := place_address_level;
908 -- Initialise the name vector using our name
909 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
910 name_vector := make_keywords(NEW.name);
912 -- make sure all names are in the word table
913 IF NEW.admin_level = 2
914 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
915 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
917 PERFORM create_country(NEW.name, lower(NEW.country_code));
918 --DEBUG: RAISE WARNING 'Country names updated';
921 IF NEW.rank_address = 0 THEN
922 max_rank := geometry_to_rank(NEW.rank_search, NEW.geometry, NEW.country_code);
923 ELSEIF NEW.rank_address > 25 THEN
926 max_rank = NEW.rank_address;
929 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition, max_rank,
931 CASE WHEN (NEW.rank_address = 0 or
932 NEW.rank_search between 26 and 29)
933 THEN NEW.geometry ELSE NEW.centroid END,
935 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
937 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
939 IF NEW.address is not null AND NEW.address ? 'postcode'
940 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
941 NEW.postcode := upper(trim(NEW.address->'postcode'));
944 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
945 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
948 -- if we have a name add this to the name search table
949 IF NEW.name IS NOT NULL THEN
951 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
952 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry, NEW.centroid);
953 --DEBUG: RAISE WARNING 'added to location (full)';
956 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
957 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
958 --DEBUG: RAISE WARNING 'insert into road location table (full)';
961 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
962 NEW.rank_search, NEW.rank_address, NEW.geometry);
963 --DEBUG: RAISE WARNING 'added to search name (full)';
965 IF NOT %REVERSE-ONLY% THEN
966 INSERT INTO search_name (place_id, search_rank, address_rank,
967 importance, country_code, name_vector,
968 nameaddress_vector, centroid)
969 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
970 NEW.importance, NEW.country_code, name_vector,
971 nameaddress_vector, NEW.centroid);
976 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
984 CREATE OR REPLACE FUNCTION placex_delete()
991 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
993 IF OLD.linked_place_id is null THEN
994 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
995 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
996 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
997 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
999 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
1002 IF OLD.rank_address < 30 THEN
1004 -- mark everything linked to this place for re-indexing
1005 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1006 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1007 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1009 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1010 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1012 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1013 b := deleteRoad(OLD.partition, OLD.place_id);
1015 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1016 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1017 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1018 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1019 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1023 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1025 IF OLD.rank_address < 26 THEN
1026 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1029 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1031 IF OLD.name is not null THEN
1032 IF NOT %REVERSE-ONLY% THEN
1033 DELETE from search_name WHERE place_id = OLD.place_id;
1035 b := deleteSearchName(OLD.partition, OLD.place_id);
1038 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1040 DELETE FROM place_addressline where place_id = OLD.place_id;
1042 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1044 -- remove from tables for special search
1045 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1046 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1048 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1051 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;