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')
145 IF bnd.osm_type = 'R' THEN
146 -- see if we have any special relation members
147 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
148 --DEBUG: RAISE WARNING 'Got relation members';
150 -- Search for relation members with role 'lable'.
151 IF relation_members IS NOT NULL THEN
153 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
155 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
159 WHERE osm_type = 'N' and osm_id = rel_member.member
162 --DEBUG: RAISE WARNING 'Linked label member';
163 RETURN linked_placex;
170 IF bnd.name ? 'name' THEN
171 bnd_name := make_standard_name(bnd.name->'name');
172 IF bnd_name = '' THEN
177 -- If extratags has a place tag, look for linked nodes by their place type.
178 -- Area and node still have to have the same name.
179 IF bnd.extratags ? 'place' and bnd_name is not null THEN
182 WHERE make_standard_name(name->'name') = bnd_name
183 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
184 AND placex.osm_type = 'N'
185 AND placex.rank_search < 26 -- needed to select the right index
186 AND _st_covers(bnd.geometry, placex.geometry)
188 --DEBUG: RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;
189 RETURN linked_placex;
193 IF bnd.extratags ? 'wikidata' THEN
196 WHERE placex.class = 'place' AND placex.osm_type = 'N'
197 AND placex.extratags ? 'wikidata' -- needed to select right index
198 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
199 AND placex.rank_search < 26
200 AND _st_covers(bnd.geometry, placex.geometry)
201 ORDER BY make_standard_name(name->'name') = bnd_name desc
203 --DEBUG: RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;
204 RETURN linked_placex;
208 -- Name searches can be done for ways as well as relations
209 IF bnd_name is not null THEN
210 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
212 SELECT placex.* from placex
213 WHERE make_standard_name(name->'name') = bnd_name
214 AND ((bnd.rank_address > 0
215 and bnd.rank_address = (compute_place_rank(placex.country_code,
217 placex.type, 15::SMALLINT,
218 false, placex.postcode)).address_rank)
219 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
220 AND placex.osm_type = 'N'
221 AND placex.rank_search < 26 -- needed to select the right index
222 AND _st_covers(bnd.geometry, placex.geometry)
224 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
225 RETURN linked_placex;
232 LANGUAGE plpgsql STABLE;
235 -- Insert address of a place into the place_addressline table.
237 -- \param obj_place_id Place_id of the place to compute the address for.
238 -- \param partition Partition number where the place is in.
239 -- \param maxrank Rank of the place. All address features must have
240 -- a search rank lower than the given rank.
241 -- \param address Address terms for the place.
242 -- \param geometry Geometry to which the address objects should be close.
244 -- \retval parent_place_id Place_id of the address object that is the direct
246 -- \retval postcode Postcode computed from the address. This is the
247 -- addr:postcode of one of the address objects. If
248 -- more than one of has a postcode, the highest ranking
249 -- one is used. May be NULL.
250 -- \retval nameaddress_vector Search terms for the address. This is the sum
251 -- of name terms of all address objects.
252 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
257 OUT parent_place_id BIGINT,
259 OUT nameaddress_vector INT[])
262 address_havelevel BOOLEAN[];
264 location_isaddress BOOLEAN;
265 current_boundary GEOMETRY := NULL;
266 current_node_area GEOMETRY := NULL;
273 parent_place_id := 0;
274 nameaddress_vector := '{}'::int[];
275 isin_tokens := '{}'::int[];
277 ---- convert address store to array of tokenids
278 IF address IS NOT NULL THEN
279 FOR addr_item IN SELECT * FROM each(address)
281 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
282 'district', 'region', 'county', 'municipality',
283 'hamlet', 'village', 'subdistrict', 'town',
284 'neighbourhood', 'quarter', 'parish')
286 isin_tokens := array_merge(isin_tokens,
287 word_ids_from_name(addr_item.value));
288 IF NOT %REVERSE-ONLY% THEN
289 nameaddress_vector := array_merge(nameaddress_vector,
290 addr_ids_from_name(addr_item.value));
295 IF NOT %REVERSE-ONLY% THEN
296 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
299 ---- now compute the address terms
300 FOR i IN 1..maxrank LOOP
301 address_havelevel[i] := false;
305 SELECT * FROM getNearFeatures(partition, geometry, maxrank)
306 ORDER BY rank_address, isin_tokens && keywords desc, isguess asc,
308 CASE WHEN rank_address = 16 AND rank_search = 15 THEN 0.2
309 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25
310 WHEN rank_address = 16 AND rank_search = 18 THEN 0.5
313 -- Ignore all place nodes that do not fit in a lower level boundary.
314 CONTINUE WHEN location.isguess
315 and current_boundary is not NULL
316 and not ST_Contains(current_boundary, location.centroid);
318 -- If this is the first item in the rank, then assume it is the address.
319 location_isaddress := not address_havelevel[location.rank_address];
321 -- Further sanity checks to ensure that the address forms a sane hierarchy.
322 IF location_isaddress THEN
323 IF location.isguess and current_node_area is not NULL THEN
324 location_isaddress := ST_Contains(current_node_area, location.centroid);
326 IF not location.isguess and current_boundary is not NULL
327 and location.rank_address != 11 AND location.rank_address != 5 THEN
328 location_isaddress := ST_Contains(current_boundary, location.centroid);
332 IF location_isaddress THEN
333 address_havelevel[location.rank_address] := true;
334 parent_place_id := location.place_id;
336 -- Set postcode if we have one.
337 -- (Returned will be the highest ranking one.)
338 IF location.postcode is not NULL THEN
339 postcode = location.postcode;
342 -- Recompute the areas we need for hierarchy sanity checks.
343 IF location.rank_address != 11 AND location.rank_address != 5 THEN
344 IF location.isguess THEN
345 current_node_area := place_node_fuzzy_area(location.centroid,
346 location.rank_search);
348 current_node_area := NULL;
349 SELECT p.geometry FROM placex p
350 WHERE p.place_id = location.place_id INTO current_boundary;
355 -- Add it to the list of search terms
356 IF NOT %REVERSE-ONLY% THEN
357 nameaddress_vector := array_merge(nameaddress_vector,
358 location.keywords::integer[]);
361 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
362 isaddress, distance, cached_rank_address)
363 VALUES (obj_place_id, location.place_id, not location.isguess,
364 location_isaddress, location.distance, location.rank_address);
371 CREATE OR REPLACE FUNCTION placex_insert()
378 country_code VARCHAR(2);
382 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
384 NEW.place_id := nextval('seq_place');
385 NEW.indexed_status := 1; --STATUS_NEW
387 NEW.country_code := lower(get_country_code(NEW.geometry));
389 NEW.partition := get_partition(NEW.country_code);
390 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
392 IF NEW.osm_type = 'X' THEN
393 -- E'X'ternal records should already be in the right format so do nothing
395 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
397 IF NEW.class in ('place','boundary')
398 AND NEW.type in ('postcode','postal_code')
400 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
401 -- most likely just a part of a multipolygon postcode boundary, throw it away
405 NEW.name := hstore('ref', NEW.address->'postcode');
407 ELSEIF NEW.class = 'highway' AND is_area AND NEW.name is null
408 AND NEW.extratags ? 'area' AND NEW.extratags->'area' = 'yes'
411 ELSEIF NEW.class = 'boundary' AND NOT is_area
414 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
415 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
420 SELECT * INTO NEW.rank_search, NEW.rank_address
421 FROM compute_place_rank(NEW.country_code,
422 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
423 NEW.class, NEW.type, NEW.admin_level,
424 (NEW.extratags->'capital') = 'yes',
425 NEW.address->'postcode');
427 -- a country code make no sense below rank 4 (country)
428 IF NEW.rank_search < 4 THEN
429 NEW.country_code := NULL;
434 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
436 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
438 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
439 -- might be part of an interpolation
440 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
441 ELSEIF NEW.rank_address > 0 THEN
442 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
443 -- Performance: We just can't handle re-indexing for country level changes
444 IF st_area(NEW.geometry) < 1 THEN
445 -- mark items within the geometry for re-indexing
446 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
448 UPDATE placex SET indexed_status = 2
449 WHERE ST_Intersects(NEW.geometry, placex.geometry)
450 and indexed_status = 0
451 and ((rank_address = 0 and rank_search > NEW.rank_address)
452 or rank_address > NEW.rank_address
453 or (class = 'place' and osm_type = 'N')
455 and (rank_search < 28
457 or (NEW.rank_address >= 16 and address ? 'place'));
460 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
461 diameter := update_place_diameter(NEW.rank_search);
463 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
464 IF NEW.rank_search >= 26 THEN
465 -- roads may cause reparenting for >27 rank places
466 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
467 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
468 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
469 ELSEIF NEW.rank_search >= 16 THEN
470 -- up to rank 16, street-less addresses may need reparenting
471 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');
473 -- for all other places the search terms may change as well
474 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);
481 -- add to tables for special search
482 -- Note: won't work on initial import because the classtype tables
483 -- do not yet exist. It won't hurt either.
484 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
485 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
487 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
488 USING NEW.place_id, ST_Centroid(NEW.geometry);
497 CREATE OR REPLACE FUNCTION get_parent_address_level(geom GEOMETRY, in_level SMALLINT)
501 address_rank SMALLINT;
503 IF in_level <= 3 or in_level > 15 THEN
506 SELECT rank_address INTO address_rank
508 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
509 and admin_level < in_level
510 and geometry ~ geom and _ST_Covers(geometry, geom)
511 ORDER BY admin_level desc LIMIT 1;
514 IF address_rank is NULL or address_rank <= 3 THEN
524 CREATE OR REPLACE FUNCTION placex_update()
530 relation_members TEXT[];
533 parent_address_level SMALLINT;
534 place_address_level SMALLINT;
539 name_vector INTEGER[];
540 nameaddress_vector INTEGER[];
541 addr_nameaddress_vector INTEGER[];
543 inherited_address HSTORE;
545 linked_node_id BIGINT;
546 linked_importance FLOAT;
547 linked_wikipedia TEXT;
552 IF OLD.indexed_status = 100 THEN
553 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
554 delete from placex where place_id = OLD.place_id;
558 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
562 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
564 NEW.indexed_date = now();
566 IF NOT %REVERSE-ONLY% THEN
567 DELETE from search_name WHERE place_id = NEW.place_id;
569 result := deleteSearchName(NEW.partition, NEW.place_id);
570 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
571 result := deleteRoad(NEW.partition, NEW.place_id);
572 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
573 UPDATE placex set linked_place_id = null, indexed_status = 2
574 where linked_place_id = NEW.place_id;
575 -- update not necessary for osmline, cause linked_place_id does not exist
577 NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
578 NEW.address := NEW.address - '_unlisted_place'::TEXT;
580 IF NEW.linked_place_id is not null THEN
581 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
585 -- Postcodes are just here to compute the centroids. They are not searchable
586 -- unless they are a boundary=postal_code.
587 -- There was an error in the style so that boundary=postal_code used to be
588 -- imported as place=postcode. That's why relations are allowed to pass here.
589 -- This can go away in a couple of versions.
590 IF NEW.class = 'place' and NEW.type = 'postcode' and NEW.osm_type != 'R' THEN
594 -- Speed up searches - just use the centroid of the feature
595 -- cheaper but less acurate
596 NEW.centroid := ST_PointOnSurface(NEW.geometry);
597 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
599 -- recompute the ranks, they might change when linking changes
600 SELECT * INTO NEW.rank_search, NEW.rank_address
601 FROM compute_place_rank(NEW.country_code,
602 CASE WHEN ST_GeometryType(NEW.geometry)
603 IN ('ST_Polygon','ST_MultiPolygon')
604 THEN 'A' ELSE NEW.osm_type END,
605 NEW.class, NEW.type, NEW.admin_level,
606 (NEW.extratags->'capital') = 'yes',
607 NEW.address->'postcode');
608 -- We must always increase the address level relative to the admin boundary.
609 IF NEW.class = 'boundary' and NEW.type = 'administrative'
610 and NEW.osm_type = 'R' and NEW.rank_address > 0
612 -- First, check that admin boundaries do not overtake each other rank-wise.
613 parent_address_level := get_parent_address_level(NEW.centroid, NEW.admin_level);
614 IF parent_address_level >= NEW.rank_address THEN
615 IF parent_address_level >= 24 THEN
616 NEW.rank_address := 25;
618 NEW.rank_address := parent_address_level + 2;
621 -- Second check that the boundary is not completely contained in a
622 -- place area with a higher address rank
624 SELECT rank_address FROM placex
625 WHERE class = 'place' and rank_address < 24
626 and rank_address > NEW.rank_address
627 and geometry && NEW.geometry
628 and ST_Relate(geometry, NEW.geometry, 'T*T***FF*') -- contains but not equal
629 ORDER BY rank_address desc LIMIT 1
631 NEW.rank_address := location.rank_address + 2;
633 ELSEIF NEW.class = 'place' and NEW.osm_type = 'N'
634 and NEW.rank_address between 16 and 23
636 -- If a place node is contained in a admin boundary with the same address level
637 -- and has not been linked, then make the node a subpart by increasing the
638 -- address rank (city level and above).
640 SELECT rank_address FROM placex
641 WHERE osm_type = 'R' and class = 'boundary' and type = 'administrative'
642 and rank_address = NEW.rank_address
643 and geometry && NEW.centroid and _ST_Covers(geometry, NEW.centroid)
646 NEW.rank_address = NEW.rank_address + 2;
649 parent_address_level := 3;
652 --DEBUG: RAISE WARNING 'Copy over address tags';
653 -- housenumber is a computed field, so start with an empty value
654 NEW.housenumber := NULL;
655 IF NEW.address is not NULL THEN
656 IF NEW.address ? 'conscriptionnumber' THEN
657 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
658 IF NEW.address ? 'streetnumber' THEN
659 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
660 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
662 NEW.housenumber := NEW.address->'conscriptionnumber';
664 ELSEIF NEW.address ? 'streetnumber' THEN
665 NEW.housenumber := NEW.address->'streetnumber';
666 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
667 ELSEIF NEW.address ? 'housenumber' THEN
668 NEW.housenumber := NEW.address->'housenumber';
669 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
672 addr_street := NEW.address->'street';
673 addr_place := NEW.address->'place';
675 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(:|,|;)%' THEN
676 i := getorcreate_postcode_id(NEW.address->'postcode');
680 NEW.postcode := null;
682 -- recalculate country and partition
683 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
684 -- for countries, believe the mapped country code,
685 -- so that we remain in the right partition if the boundaries
687 NEW.country_code := lower(NEW.address->'country');
688 NEW.partition := get_partition(lower(NEW.country_code));
689 IF NEW.partition = 0 THEN
690 NEW.country_code := lower(get_country_code(NEW.centroid));
691 NEW.partition := get_partition(NEW.country_code);
694 IF NEW.rank_search >= 4 THEN
695 NEW.country_code := lower(get_country_code(NEW.centroid));
697 NEW.country_code := NULL;
699 NEW.partition := get_partition(NEW.country_code);
701 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
703 -- waterway ways are linked when they are part of a relation and have the same class/type
704 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
705 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
707 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
708 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
709 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
710 FOR linked_node_id IN SELECT place_id FROM placex
711 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
712 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
713 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
715 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
716 IF NOT %REVERSE-ONLY% THEN
717 DELETE FROM search_name WHERE place_id = linked_node_id;
723 --DEBUG: RAISE WARNING 'Waterway processed';
726 NEW.importance := null;
727 SELECT wikipedia, importance
728 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
729 INTO NEW.wikipedia,NEW.importance;
731 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
733 -- ---------------------------------------------------------------------------
734 -- For low level elements we inherit from our parent road
735 IF NEW.rank_search > 27 THEN
737 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
738 NEW.parent_place_id := null;
740 -- if we have a POI and there is no address information,
741 -- see if we can get it from a surrounding building
742 inherited_address := ''::HSTORE;
743 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
744 AND NEW.housenumber IS NULL THEN
746 -- The additional && condition works around the misguided query
747 -- planner of postgis 3.0.
748 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
749 and geometry && NEW.centroid
750 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
751 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
754 NEW.housenumber := location.address->'housenumber';
755 addr_street := location.address->'street';
756 addr_place := location.address->'place';
757 inherited_address := location.address;
761 -- We have to find our parent road.
762 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
764 ST_Envelope(NEW.geometry),
765 addr_street, addr_place);
767 -- If we found the road take a shortcut here.
768 -- Otherwise fall back to the full address getting method below.
769 IF NEW.parent_place_id is not null THEN
771 -- Get the details of the parent road
772 SELECT p.country_code, p.postcode, p.name FROM placex p
773 WHERE p.place_id = NEW.parent_place_id INTO location;
775 IF addr_street is null and addr_place is not null THEN
776 -- Check if the addr:place tag is part of the parent name
777 SELECT count(*) INTO i
778 FROM svals(location.name) AS pname WHERE pname = addr_place;
780 NEW.address = NEW.address || hstore('_unlisted_place', addr_place);
784 NEW.country_code := location.country_code;
785 --DEBUG: RAISE WARNING 'Got parent details from search name';
787 -- determine postcode
788 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
789 NEW.postcode = upper(trim(NEW.address->'postcode'));
791 NEW.postcode := location.postcode;
793 IF NEW.postcode is null THEN
794 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
797 IF NEW.name is not NULL THEN
798 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
799 name_vector := make_keywords(NEW.name);
801 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
802 result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
803 name_vector, NEW.rank_search, NEW.rank_address,
804 upper(trim(NEW.address->'postcode')), NEW.geometry,
806 --DEBUG: RAISE WARNING 'Place added to location table';
811 IF NOT %REVERSE-ONLY% THEN
812 SELECT * INTO name_vector, nameaddress_vector
813 FROM create_poi_search_terms(NEW.parent_place_id,
814 inherited_address || NEW.address,
815 NEW.housenumber, name_vector);
817 IF array_length(name_vector, 1) is not NULL THEN
818 INSERT INTO search_name (place_id, search_rank, address_rank,
819 importance, country_code, name_vector,
820 nameaddress_vector, centroid)
821 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
822 NEW.importance, NEW.country_code, name_vector,
823 nameaddress_vector, NEW.centroid);
824 --DEBUG: RAISE WARNING 'Place added to search table';
833 -- ---------------------------------------------------------------------------
835 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
836 SELECT * INTO location FROM find_linked_place(NEW);
837 IF location.place_id is not null THEN
838 --DEBUG: RAISE WARNING 'Linked %', location;
840 -- Use the linked point as the centre point of the geometry,
841 -- but only if it is within the area of the boundary.
842 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
843 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
844 NEW.centroid := centroid;
847 --DEBUG: RAISE WARNING 'parent address: % rank address: %', parent_address_level, location.rank_address;
848 IF location.rank_address > parent_address_level
849 and location.rank_address < 26
851 NEW.rank_address := location.rank_address;
854 -- merge in the label name
855 IF NOT location.name IS NULL THEN
856 NEW.name := location.name || NEW.name;
859 -- merge in extra tags
860 NEW.extratags := hstore('linked_' || location.class, location.type)
861 || coalesce(location.extratags, ''::hstore)
862 || coalesce(NEW.extratags, ''::hstore);
864 -- mark the linked place (excludes from search results)
865 UPDATE placex set linked_place_id = NEW.place_id
866 WHERE place_id = location.place_id;
867 -- ensure that those places are not found anymore
868 IF NOT %REVERSE-ONLY% THEN
869 DELETE FROM search_name WHERE place_id = location.place_id;
871 PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
873 SELECT wikipedia, importance
874 FROM compute_importance(location.extratags, NEW.country_code,
875 'N', location.osm_id)
876 INTO linked_wikipedia,linked_importance;
878 -- Use the maximum importance if one could be computed from the linked object.
879 IF linked_importance is not null AND
880 (NEW.importance is null or NEW.importance < linked_importance)
882 NEW.importance = linked_importance;
885 -- No linked place? As a last resort check if the boundary is tagged with
886 -- a place type and adapt the rank address.
887 IF NEW.rank_address > 0 and NEW.extratags ? 'place' THEN
888 SELECT address_rank INTO place_address_level
889 FROM compute_place_rank(NEW.country_code, 'A', 'place',
890 NEW.extratags->'place', 0::SMALLINT, False, null);
891 IF place_address_level > parent_address_level and
892 place_address_level < 26 THEN
893 NEW.rank_address := place_address_level;
898 -- Initialise the name vector using our name
899 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
900 name_vector := make_keywords(NEW.name);
902 -- make sure all names are in the word table
903 IF NEW.admin_level = 2
904 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
905 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
907 PERFORM create_country(NEW.name, lower(NEW.country_code));
908 --DEBUG: RAISE WARNING 'Country names updated';
911 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
912 CASE WHEN NEW.rank_address = 0 THEN NEW.rank_search
913 WHEN NEW.rank_address > 25 THEN 25::smallint
914 ELSE NEW.rank_address END,
916 CASE WHEN NEW.rank_search >= 26
917 AND NEW.rank_search < 30
918 THEN NEW.geometry ELSE NEW.centroid END)
919 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
921 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
923 IF NEW.address is not null AND NEW.address ? 'postcode'
924 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
925 NEW.postcode := upper(trim(NEW.address->'postcode'));
928 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
929 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
932 -- if we have a name add this to the name search table
933 IF NEW.name IS NOT NULL THEN
935 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
936 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);
937 --DEBUG: RAISE WARNING 'added to location (full)';
940 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
941 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
942 --DEBUG: RAISE WARNING 'insert into road location table (full)';
945 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
946 NEW.rank_search, NEW.rank_address, NEW.geometry);
947 --DEBUG: RAISE WARNING 'added to search name (full)';
949 IF NOT %REVERSE-ONLY% THEN
950 INSERT INTO search_name (place_id, search_rank, address_rank,
951 importance, country_code, name_vector,
952 nameaddress_vector, centroid)
953 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
954 NEW.importance, NEW.country_code, name_vector,
955 nameaddress_vector, NEW.centroid);
960 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
968 CREATE OR REPLACE FUNCTION placex_delete()
975 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
977 IF OLD.linked_place_id is null THEN
978 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
979 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
980 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
981 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
983 update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
986 IF OLD.rank_address < 30 THEN
988 -- mark everything linked to this place for re-indexing
989 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
990 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
991 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
993 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
994 DELETE FROM place_addressline where address_place_id = OLD.place_id;
996 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
997 b := deleteRoad(OLD.partition, OLD.place_id);
999 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1000 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1001 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1002 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1003 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1007 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1009 IF OLD.rank_address < 26 THEN
1010 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1013 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1015 IF OLD.name is not null THEN
1016 IF NOT %REVERSE-ONLY% THEN
1017 DELETE from search_name WHERE place_id = OLD.place_id;
1019 b := deleteSearchName(OLD.partition, OLD.place_id);
1022 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1024 DELETE FROM place_addressline where place_id = OLD.place_id;
1026 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1028 -- remove from tables for special search
1029 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1030 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1032 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1035 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;