1 -- Trigger functions for the placex table.
3 CREATE OR REPLACE FUNCTION get_rel_node_members(members TEXT[], memberLabels TEXT[])
9 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
10 IF members[i+1] = ANY(memberLabels)
11 AND upper(substring(members[i], 1, 1))::char(1) = 'N'
13 RETURN NEXT substring(members[i], 2)::bigint;
20 LANGUAGE plpgsql IMMUTABLE;
22 -- copy 'name' to or from the default language (if there is a default language)
23 CREATE OR REPLACE FUNCTION add_default_place_name(country_code VARCHAR(2),
27 default_language VARCHAR(10);
29 IF name is not null AND array_upper(akeys(name),1) > 1 THEN
30 default_language := get_country_language_code(country_code);
31 IF default_language IS NOT NULL THEN
32 IF name ? 'name' AND NOT name ? ('name:'||default_language) THEN
33 name := name || hstore(('name:'||default_language), (name -> 'name'));
34 ELSEIF name ? ('name:'||default_language) AND NOT name ? 'name' THEN
35 name := name || hstore('name', (name -> ('name:'||default_language)));
41 LANGUAGE plpgsql IMMUTABLE;
43 -- Find the parent road of a POI.
45 -- \returns Place ID of parent object or NULL if none
47 -- Copy data from linked items (POIs on ways, addr:street links, relations).
49 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
51 poi_partition SMALLINT,
59 parent_place_id BIGINT DEFAULT NULL;
63 --DEBUG: RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;
65 -- Is this object part of an associatedStreet relation?
67 SELECT members FROM planet_osm_rels
68 WHERE parts @> ARRAY[poi_osm_id]
69 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
70 and tags @> ARRAY['associatedStreet']
72 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
73 IF location.members[i+1] = 'street' THEN
74 --DEBUG: RAISE WARNING 'node in relation %',relation;
76 SELECT place_id from placex
77 WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
79 and rank_search between 26 and 27
81 RETURN parent.place_id;
87 parent_place_id := find_parent_for_address(addr_street, addr_place,
89 IF parent_place_id is not null THEN
90 RETURN parent_place_id;
93 IF poi_osm_type = 'N' THEN
94 -- Is this node part of an interpolation?
96 SELECT q.parent_place_id
97 FROM location_property_osmline q, planet_osm_ways x
98 WHERE q.linegeo && bbox and x.id = q.osm_id
99 and poi_osm_id = any(x.nodes)
102 --DEBUG: RAISE WARNING 'Get parent from interpolation: %', parent.parent_place_id;
103 RETURN parent.parent_place_id;
106 -- Is this node part of any other way?
108 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
109 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
110 FROM placex p, planet_osm_ways w
111 WHERE p.osm_type = 'W' and p.rank_search >= 26
112 and p.geometry && bbox
113 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
115 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
117 -- Way IS a road then we are on it - that must be our road
118 IF location.rank_search < 28 THEN
119 --DEBUG: RAISE WARNING 'node in way that is a street %',location;
120 return location.place_id;
123 SELECT find_parent_for_poi('W', location.osm_id, poi_partition,
125 location.address->'street',
126 location.address->'place',
128 INTO parent_place_id;
129 IF parent_place_id is not null THEN
130 RETURN parent_place_id;
136 IF ST_Area(bbox) < 0.01 THEN
137 -- for smaller features get the nearest road
138 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
139 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
141 -- for larger features simply find the area with the largest rank that
144 SELECT place_id FROM placex
145 WHERE bbox @ geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
146 AND rank_search between 5 and 25
147 ORDER BY rank_search desc
149 RETURN location.place_id;
154 RETURN parent_place_id;
157 LANGUAGE plpgsql STABLE;
159 -- Try to find a linked place for the given object.
160 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
164 relation_members TEXT[];
166 linked_placex placex%ROWTYPE;
169 IF bnd.rank_search >= 26 or bnd.rank_address = 0
170 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
175 IF bnd.osm_type = 'R' THEN
176 -- see if we have any special relation members
177 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
178 --DEBUG: RAISE WARNING 'Got relation members';
180 -- Search for relation members with role 'lable'.
181 IF relation_members IS NOT NULL THEN
183 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
185 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
189 WHERE osm_type = 'N' and osm_id = rel_member.member
192 --DEBUG: RAISE WARNING 'Linked label member';
193 RETURN linked_placex;
200 IF bnd.name ? 'name' THEN
201 bnd_name := make_standard_name(bnd.name->'name');
202 IF bnd_name = '' THEN
207 -- If extratags has a place tag, look for linked nodes by their place type.
208 -- Area and node still have to have the same name.
209 IF bnd.extratags ? 'place' and bnd_name is not null THEN
212 WHERE make_standard_name(name->'name') = bnd_name
213 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
214 AND placex.osm_type = 'N'
215 AND placex.rank_search < 26 -- needed to select the right index
216 AND _st_covers(bnd.geometry, placex.geometry)
218 --DEBUG: RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;
219 RETURN linked_placex;
223 IF bnd.extratags ? 'wikidata' THEN
226 WHERE placex.class = 'place' AND placex.osm_type = 'N'
227 AND placex.extratags ? 'wikidata' -- needed to select right index
228 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
229 AND placex.rank_search < 26
230 AND _st_covers(bnd.geometry, placex.geometry)
231 ORDER BY make_standard_name(name->'name') = bnd_name desc
233 --DEBUG: RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;
234 RETURN linked_placex;
238 -- Name searches can be done for ways as well as relations
239 IF bnd_name is not null THEN
240 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
242 SELECT placex.* from placex
243 WHERE make_standard_name(name->'name') = bnd_name
244 AND ((bnd.rank_address > 0 and placex.rank_address = bnd.rank_address)
245 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
246 AND placex.osm_type = 'N'
247 AND placex.rank_search < 26 -- needed to select the right index
248 AND _st_covers(bnd.geometry, placex.geometry)
250 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
251 RETURN linked_placex;
258 LANGUAGE plpgsql STABLE;
261 -- Insert address of a place into the place_addressline table.
263 -- \param obj_place_id Place_id of the place to compute the address for.
264 -- \param partition Partition number where the place is in.
265 -- \param maxrank Rank of the place. All address features must have
266 -- a search rank lower than the given rank.
267 -- \param address Address terms for the place.
268 -- \param geoemtry Geometry to which the address objects should be close.
270 -- \retval parent_place_id Place_id of the address object that is the direct
272 -- \retval postcode Postcode computed from the address. This is the
273 -- addr:postcode of one of the address objects. If
274 -- more than one of has a postcode, the highest ranking
275 -- one is used. May be NULL.
276 -- \retval nameaddress_vector Search terms for the address. This is the sum
277 -- of name terms of all address objects.
278 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
283 OUT parent_place_id BIGINT,
285 OUT nameaddress_vector INT[])
288 current_rank_address INTEGER := 0;
289 location_distance FLOAT := 0;
290 location_parent GEOMETRY := NULL;
291 parent_place_id_rank SMALLINT := 0;
293 location_isaddress BOOLEAN;
295 address_havelevel BOOLEAN[];
296 location_keywords INT[];
304 parent_place_id := 0;
305 nameaddress_vector := '{}'::int[];
306 isin_tokens := '{}'::int[];
308 ---- convert address store to array of tokenids
309 IF address IS NOT NULL THEN
310 FOR addr_item IN SELECT * FROM each(address)
312 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
313 'district', 'region', 'county', 'municipality',
314 'hamlet', 'village', 'subdistrict', 'town',
315 'neighbourhood', 'quarter', 'parish')
317 isin_tokens := array_merge(isin_tokens,
318 word_ids_from_name(addr_item.value));
319 IF NOT %REVERSE-ONLY% THEN
320 nameaddress_vector := array_merge(nameaddress_vector,
321 addr_ids_from_name(addr_item.value));
326 IF address ? 'is_in' THEN
327 -- is_in items need splitting
328 isin := regexp_split_to_array(address->'is_in', E'[;,]');
329 IF array_upper(isin, 1) IS NOT NULL THEN
330 FOR i IN 1..array_upper(isin, 1) LOOP
331 isin_tokens := array_merge(isin_tokens,
332 word_ids_from_name(isin[i]));
334 -- merge word into address vector
335 IF NOT %REVERSE-ONLY% THEN
336 nameaddress_vector := array_merge(nameaddress_vector,
337 addr_ids_from_name(isin[i]));
343 IF NOT %REVERSE-ONLY% THEN
344 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
347 ---- now compute the address terms
349 address_havelevel[i] := false;
353 SELECT * FROM getNearFeatures(partition, geometry, maxrank, isin_tokens)
355 IF location.rank_address != current_rank_address THEN
356 current_rank_address := location.rank_address;
357 IF location.isguess THEN
358 location_distance := location.distance * 1.5;
360 IF location.rank_address <= 12 THEN
361 -- for county and above, if we have an area consider that exact
362 -- (It would be nice to relax the constraint for places close to
363 -- the boundary but we'd need the exact geometry for that. Too
365 location_distance = 0;
367 -- Below county level remain slightly fuzzy.
368 location_distance := location.distance * 0.5;
372 CONTINUE WHEN location.keywords <@ location_keywords;
375 IF location.distance < location_distance OR NOT location.isguess THEN
376 location_keywords := location.keywords;
378 location_isaddress := NOT address_havelevel[location.rank_address];
379 --DEBUG: RAISE WARNING 'should be address: %, is guess: %, rank: %', location_isaddress, location.isguess, location.rank_address;
380 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
381 location_isaddress := ST_Contains(location_parent, location.centroid);
384 --DEBUG: RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
385 -- Add it to the list of search terms
386 IF NOT %REVERSE-ONLY% THEN
387 nameaddress_vector := array_merge(nameaddress_vector,
388 location.keywords::integer[]);
391 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
392 isaddress, distance, cached_rank_address)
393 VALUES (obj_place_id, location.place_id, true,
394 location_isaddress, location.distance, location.rank_address);
396 IF location_isaddress THEN
397 -- add postcode if we have one
398 -- (If multiple postcodes are available, we end up with the highest ranking one.)
399 IF location.postcode is not null THEN
400 postcode = location.postcode;
403 address_havelevel[location.rank_address] := true;
404 -- add a hack against postcode ranks
405 IF NOT location.isguess
406 AND location.rank_address != 11 AND location.rank_address != 5
408 SELECT p.geometry FROM placex p
409 WHERE p.place_id = location.place_id INTO location_parent;
412 IF location.rank_address > parent_place_id_rank THEN
413 parent_place_id = location.place_id;
414 parent_place_id_rank = location.rank_address;
425 CREATE OR REPLACE FUNCTION placex_insert()
432 country_code VARCHAR(2);
437 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
439 NEW.place_id := nextval('seq_place');
440 NEW.indexed_status := 1; --STATUS_NEW
442 NEW.country_code := lower(get_country_code(NEW.geometry));
444 NEW.partition := get_partition(NEW.country_code);
445 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
447 IF NEW.osm_type = 'X' THEN
448 -- E'X'ternal records should already be in the right format so do nothing
450 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
452 IF NEW.class in ('place','boundary')
453 AND NEW.type in ('postcode','postal_code') THEN
455 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
456 -- most likely just a part of a multipolygon postcode boundary, throw it away
460 NEW.name := hstore('ref', NEW.address->'postcode');
462 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
463 INTO NEW.rank_search, NEW.rank_address;
466 NEW.rank_address := 0;
468 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
470 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
471 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
473 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
474 NEW.rank_search = 30;
475 NEW.rank_address = 0;
476 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
477 NEW.rank_search = 30;
478 NEW.rank_address = 0;
480 -- do table lookup stuff
481 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
482 classtype = NEW.type || NEW.admin_level::TEXT;
484 classtype = NEW.type;
486 SELECT l.rank_search, l.rank_address FROM address_levels l
487 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
488 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
489 ORDER BY l.country_code, l.class, l.type LIMIT 1
490 INTO NEW.rank_search, NEW.rank_address;
492 IF NEW.rank_search is NULL THEN
493 NEW.rank_search := 30;
496 IF NEW.rank_address is NULL THEN
497 NEW.rank_address := 30;
501 -- some postcorrections
502 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
503 -- Slightly promote waterway relations so that they are processed
504 -- before their members.
505 NEW.rank_search := NEW.rank_search - 1;
508 IF (NEW.extratags -> 'capital') = 'yes' THEN
509 NEW.rank_search := NEW.rank_search - 1;
514 -- a country code make no sense below rank 4 (country)
515 IF NEW.rank_search < 4 THEN
516 NEW.country_code := NULL;
519 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
521 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
523 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
524 -- might be part of an interpolation
525 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
526 ELSEIF NEW.rank_address > 0 THEN
527 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
528 -- Performance: We just can't handle re-indexing for country level changes
529 IF st_area(NEW.geometry) < 1 THEN
530 -- mark items within the geometry for re-indexing
531 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
533 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
534 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
535 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
536 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
537 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
540 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
542 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
543 IF NEW.type='postcode' THEN
545 ELSEIF NEW.rank_search < 16 THEN
547 ELSEIF NEW.rank_search < 18 THEN
549 ELSEIF NEW.rank_search < 20 THEN
551 ELSEIF NEW.rank_search = 21 THEN
553 ELSEIF NEW.rank_search < 24 THEN
555 ELSEIF NEW.rank_search < 26 THEN
556 diameter := 0.002; -- 100 to 200 meters
557 ELSEIF NEW.rank_search < 28 THEN
558 diameter := 0.001; -- 50 to 100 meters
561 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
562 IF NEW.rank_search >= 26 THEN
563 -- roads may cause reparenting for >27 rank places
564 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
565 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
566 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
567 ELSEIF NEW.rank_search >= 16 THEN
568 -- up to rank 16, street-less addresses may need reparenting
569 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');
571 -- for all other places the search terms may change as well
572 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);
579 -- add to tables for special search
580 -- Note: won't work on initial import because the classtype tables
581 -- do not yet exist. It won't hurt either.
582 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
583 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
585 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
586 USING NEW.place_id, ST_Centroid(NEW.geometry);
596 CREATE OR REPLACE FUNCTION placex_update()
602 relation_members TEXT[];
609 name_vector INTEGER[];
610 nameaddress_vector INTEGER[];
612 linked_node_id BIGINT;
613 linked_importance FLOAT;
614 linked_wikipedia TEXT;
619 IF OLD.indexed_status = 100 THEN
620 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
621 delete from placex where place_id = OLD.place_id;
625 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
629 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
631 NEW.indexed_date = now();
633 IF NOT %REVERSE-ONLY% THEN
634 DELETE from search_name WHERE place_id = NEW.place_id;
636 result := deleteSearchName(NEW.partition, NEW.place_id);
637 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
638 result := deleteRoad(NEW.partition, NEW.place_id);
639 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
640 UPDATE placex set linked_place_id = null, indexed_status = 2
641 where linked_place_id = NEW.place_id;
642 -- update not necessary for osmline, cause linked_place_id does not exist
644 IF NEW.linked_place_id is not null THEN
645 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
649 --DEBUG: RAISE WARNING 'Copy over address tags';
650 -- housenumber is a computed field, so start with an empty value
651 NEW.housenumber := NULL;
652 IF NEW.address is not NULL THEN
653 IF NEW.address ? 'conscriptionnumber' THEN
654 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
655 IF NEW.address ? 'streetnumber' THEN
656 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
657 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
659 NEW.housenumber := NEW.address->'conscriptionnumber';
661 ELSEIF NEW.address ? 'streetnumber' THEN
662 NEW.housenumber := NEW.address->'streetnumber';
663 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
664 ELSEIF NEW.address ? 'housenumber' THEN
665 NEW.housenumber := NEW.address->'housenumber';
666 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
669 addr_street := NEW.address->'street';
670 addr_place := NEW.address->'place';
672 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
673 i := getorcreate_postcode_id(NEW.address->'postcode');
677 -- Speed up searches - just use the centroid of the feature
678 -- cheaper but less acurate
679 NEW.centroid := ST_PointOnSurface(NEW.geometry);
680 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
682 NEW.postcode := null;
684 -- recalculate country and partition
685 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
686 -- for countries, believe the mapped country code,
687 -- so that we remain in the right partition if the boundaries
689 NEW.country_code := lower(NEW.address->'country');
690 NEW.partition := get_partition(lower(NEW.country_code));
691 IF NEW.partition = 0 THEN
692 NEW.country_code := lower(get_country_code(NEW.centroid));
693 NEW.partition := get_partition(NEW.country_code);
696 IF NEW.rank_search >= 4 THEN
697 NEW.country_code := lower(get_country_code(NEW.centroid));
699 NEW.country_code := NULL;
701 NEW.partition := get_partition(NEW.country_code);
703 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
705 -- waterway ways are linked when they are part of a relation and have the same class/type
706 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
707 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
709 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
710 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
711 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
712 FOR linked_node_id IN SELECT place_id FROM placex
713 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
714 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
715 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
717 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
718 IF NOT %REVERSE-ONLY% THEN
719 DELETE FROM search_name WHERE place_id = linked_node_id;
725 --DEBUG: RAISE WARNING 'Waterway processed';
728 NEW.importance := null;
729 SELECT wikipedia, importance
730 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
731 INTO NEW.wikipedia,NEW.importance;
733 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
735 -- ---------------------------------------------------------------------------
736 -- For low level elements we inherit from our parent road
737 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
739 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
740 NEW.parent_place_id := null;
742 -- if we have a POI and there is no address information,
743 -- see if we can get it from a surrounding building
744 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
745 AND NEW.housenumber IS NULL THEN
747 -- The additional && condition works around the misguided query
748 -- planner of postgis 3.0.
749 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
750 and geometry && NEW.centroid
751 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
752 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
755 NEW.housenumber := location.address->'housenumber';
756 addr_street := location.address->'street';
757 addr_place := location.address->'place';
758 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
762 -- We have to find our parent road.
763 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
765 ST_Envelope(NEW.geometry),
766 addr_street, addr_place);
768 -- If we found the road take a shortcut here.
769 -- Otherwise fall back to the full address getting method below.
770 IF NEW.parent_place_id is not null THEN
772 -- Get the details of the parent road
773 SELECT p.country_code, p.postcode FROM placex p
774 WHERE p.place_id = NEW.parent_place_id INTO location;
776 NEW.country_code := location.country_code;
777 --DEBUG: RAISE WARNING 'Got parent details from search name';
779 -- determine postcode
780 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
781 NEW.postcode = upper(trim(NEW.address->'postcode'));
783 NEW.postcode := location.postcode;
785 IF NEW.postcode is null THEN
786 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
789 -- If there is no name it isn't searchable, don't bother to create a search record
790 IF NEW.name is NULL THEN
791 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
795 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
796 name_vector := make_keywords(NEW.name);
798 -- Performance, it would be more acurate to do all the rest of the import
799 -- process but it takes too long
800 -- Just be happy with inheriting from parent road only
801 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
802 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);
803 --DEBUG: RAISE WARNING 'Place added to location table';
806 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
807 NEW.rank_search, NEW.rank_address, NEW.geometry);
809 IF NOT %REVERSE-ONLY% THEN
810 -- Merge address from parent
811 SELECT array_merge(s.name_vector, s.nameaddress_vector)
812 INTO nameaddress_vector
814 WHERE s.place_id = NEW.parent_place_id;
816 INSERT INTO search_name (place_id, search_rank, address_rank,
817 importance, country_code, name_vector,
818 nameaddress_vector, centroid)
819 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
820 NEW.importance, NEW.country_code, name_vector,
821 nameaddress_vector, NEW.centroid);
822 --DEBUG: RAISE WARNING 'Place added to search table';
830 -- ---------------------------------------------------------------------------
832 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
833 SELECT * INTO location FROM find_linked_place(NEW);
834 IF location.place_id is not null THEN
835 --DEBUG: RAISE WARNING 'Linked %', location;
837 -- Use the linked point as the centre point of the geometry,
838 -- but only if it is within the area of the boundary.
839 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
840 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
841 NEW.centroid := centroid;
844 -- Use the address rank of the linked place, if it has one
845 IF location.rank_address between 5 and 25 THEN
846 NEW.rank_address := location.rank_address;
849 -- merge in the label name
850 IF NOT location.name IS NULL THEN
851 NEW.name := location.name || NEW.name;
854 -- merge in extra tags
855 NEW.extratags := hstore('linked_' || location.class, location.type)
856 || coalesce(location.extratags, ''::hstore)
857 || coalesce(NEW.extratags, ''::hstore);
859 -- mark the linked place (excludes from search results)
860 UPDATE placex set linked_place_id = NEW.place_id
861 WHERE place_id = location.place_id;
862 -- ensure that those places are not found anymore
863 IF NOT %REVERSE-ONLY% THEN
864 DELETE FROM search_name WHERE place_id = location.place_id;
867 SELECT wikipedia, importance
868 FROM compute_importance(location.extratags, NEW.country_code,
869 'N', location.osm_id)
870 INTO linked_wikipedia,linked_importance;
872 -- Use the maximum importance if one could be computed from the linked object.
873 IF linked_importance is not null AND
874 (NEW.importance is null or NEW.importance < linked_importance)
876 NEW.importance = linked_importance;
880 -- Initialise the name vector using our name
881 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
882 name_vector := make_keywords(NEW.name);
884 -- make sure all names are in the word table
885 IF NEW.admin_level = 2
886 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
887 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
889 PERFORM create_country(NEW.name, lower(NEW.country_code));
890 --DEBUG: RAISE WARNING 'Country names updated';
893 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
894 NEW.rank_search, NEW.address,
895 CASE WHEN NEW.rank_search >= 26
896 AND NEW.rank_search < 30
897 THEN NEW.geometry ELSE NEW.centroid END)
898 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
900 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
902 IF NEW.address is not null AND NEW.address ? 'postcode'
903 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
904 NEW.postcode := upper(trim(NEW.address->'postcode'));
907 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
908 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
911 -- if we have a name add this to the name search table
912 IF NEW.name IS NOT NULL THEN
914 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
915 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);
916 --DEBUG: RAISE WARNING 'added to location (full)';
919 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
920 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
921 --DEBUG: RAISE WARNING 'insert into road location table (full)';
924 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
925 NEW.rank_search, NEW.rank_address, NEW.geometry);
926 --DEBUG: RAISE WARNING 'added to search name (full)';
928 IF NOT %REVERSE-ONLY% THEN
929 INSERT INTO search_name (place_id, search_rank, address_rank,
930 importance, country_code, name_vector,
931 nameaddress_vector, centroid)
932 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
933 NEW.importance, NEW.country_code, name_vector,
934 nameaddress_vector, NEW.centroid);
939 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
947 CREATE OR REPLACE FUNCTION placex_delete()
954 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
956 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
957 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
958 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
959 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
961 IF OLD.rank_address < 30 THEN
963 -- mark everything linked to this place for re-indexing
964 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
965 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
966 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
968 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
969 DELETE FROM place_addressline where address_place_id = OLD.place_id;
971 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
972 b := deleteRoad(OLD.partition, OLD.place_id);
974 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
975 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
976 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
977 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
978 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
982 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
984 IF OLD.rank_address < 26 THEN
985 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
988 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
990 IF OLD.name is not null THEN
991 IF NOT %REVERSE-ONLY% THEN
992 DELETE from search_name WHERE place_id = OLD.place_id;
994 b := deleteSearchName(OLD.partition, OLD.place_id);
997 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
999 DELETE FROM place_addressline where place_id = OLD.place_id;
1001 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1003 -- remove from tables for special search
1004 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1005 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1007 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1010 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;