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 -- Search for relation members with role admin_center.
224 IF bnd.osm_type = 'R' and bnd_name is not null
225 and relation_members is not null
228 SELECT get_rel_node_members(relation_members,
229 ARRAY['admin_center','admin_centre']) as member
231 --DEBUG: RAISE WARNING 'Found admin_center member %', rel_member.member;
234 WHERE osm_type = 'N' and osm_id = rel_member.member
237 -- For an admin centre we also want a name match - still not perfect,
238 -- for example 'new york, new york'
239 -- But that can be fixed by explicitly setting the label in the data
240 IF bnd_name = make_standard_name(linked_placex.name->'name')
241 AND bnd.rank_address = linked_placex.rank_address
243 RETURN linked_placex;
245 --DEBUG: RAISE WARNING 'Linked admin_center';
250 -- Name searches can be done for ways as well as relations
251 IF bnd_name is not null THEN
252 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
254 SELECT placex.* from placex
255 WHERE make_standard_name(name->'name') = bnd_name
256 AND ((bnd.rank_address > 0 and placex.rank_address = bnd.rank_address)
257 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
258 AND placex.osm_type = 'N'
259 AND placex.rank_search < 26 -- needed to select the right index
260 AND _st_covers(bnd.geometry, placex.geometry)
262 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
263 RETURN linked_placex;
270 LANGUAGE plpgsql STABLE;
273 -- Insert address of a place into the place_addressline table.
275 -- \param obj_place_id Place_id of the place to compute the address for.
276 -- \param partition Partition number where the place is in.
277 -- \param maxrank Rank of the place. All address features must have
278 -- a search rank lower than the given rank.
279 -- \param address Address terms for the place.
280 -- \param geoemtry Geometry to which the address objects should be close.
282 -- \retval parent_place_id Place_id of the address object that is the direct
284 -- \retval postcode Postcode computed from the address. This is the
285 -- addr:postcode of one of the address objects. If
286 -- more than one of has a postcode, the highest ranking
287 -- one is used. May be NULL.
288 -- \retval nameaddress_vector Search terms for the address. This is the sum
289 -- of name terms of all address objects.
290 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
295 OUT parent_place_id BIGINT,
297 OUT nameaddress_vector INT[])
300 current_rank_address INTEGER := 0;
301 location_distance FLOAT := 0;
302 location_parent GEOMETRY := NULL;
303 parent_place_id_rank SMALLINT := 0;
305 location_isaddress BOOLEAN;
307 address_havelevel BOOLEAN[];
308 location_keywords INT[];
316 parent_place_id := 0;
317 nameaddress_vector := '{}'::int[];
318 isin_tokens := '{}'::int[];
320 ---- convert address store to array of tokenids
321 IF address IS NOT NULL THEN
322 FOR addr_item IN SELECT * FROM each(address)
324 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
325 'district', 'region', 'county', 'municipality',
326 'hamlet', 'village', 'subdistrict', 'town',
327 'neighbourhood', 'quarter', 'parish')
329 isin_tokens := array_merge(isin_tokens,
330 word_ids_from_name(addr_item.value));
331 IF NOT %REVERSE-ONLY% THEN
332 nameaddress_vector := array_merge(nameaddress_vector,
333 addr_ids_from_name(addr_item.value));
338 IF address ? 'is_in' THEN
339 -- is_in items need splitting
340 isin := regexp_split_to_array(address->'is_in', E'[;,]');
341 IF array_upper(isin, 1) IS NOT NULL THEN
342 FOR i IN 1..array_upper(isin, 1) LOOP
343 isin_tokens := array_merge(isin_tokens,
344 word_ids_from_name(isin[i]));
346 -- merge word into address vector
347 IF NOT %REVERSE-ONLY% THEN
348 nameaddress_vector := array_merge(nameaddress_vector,
349 addr_ids_from_name(isin[i]));
355 IF NOT %REVERSE-ONLY% THEN
356 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
359 ---- now compute the address terms
361 address_havelevel[i] := false;
365 SELECT * FROM getNearFeatures(partition, geometry, maxrank, isin_tokens)
367 IF location.rank_address != current_rank_address THEN
368 current_rank_address := location.rank_address;
369 IF location.isguess THEN
370 location_distance := location.distance * 1.5;
372 IF location.rank_address <= 12 THEN
373 -- for county and above, if we have an area consider that exact
374 -- (It would be nice to relax the constraint for places close to
375 -- the boundary but we'd need the exact geometry for that. Too
377 location_distance = 0;
379 -- Below county level remain slightly fuzzy.
380 location_distance := location.distance * 0.5;
384 CONTINUE WHEN location.keywords <@ location_keywords;
387 IF location.distance < location_distance OR NOT location.isguess THEN
388 location_keywords := location.keywords;
390 location_isaddress := NOT address_havelevel[location.rank_address];
391 --DEBUG: RAISE WARNING 'should be address: %, is guess: %, rank: %', location_isaddress, location.isguess, location.rank_address;
392 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
393 location_isaddress := ST_Contains(location_parent, location.centroid);
396 --DEBUG: RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
397 -- Add it to the list of search terms
398 IF NOT %REVERSE-ONLY% THEN
399 nameaddress_vector := array_merge(nameaddress_vector,
400 location.keywords::integer[]);
403 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
404 isaddress, distance, cached_rank_address)
405 VALUES (obj_place_id, location.place_id, true,
406 location_isaddress, location.distance, location.rank_address);
408 IF location_isaddress THEN
409 -- add postcode if we have one
410 -- (If multiple postcodes are available, we end up with the highest ranking one.)
411 IF location.postcode is not null THEN
412 postcode = location.postcode;
415 address_havelevel[location.rank_address] := true;
416 -- add a hack against postcode ranks
417 IF NOT location.isguess
418 AND location.rank_address != 11 AND location.rank_address != 5
420 SELECT p.geometry FROM placex p
421 WHERE p.place_id = location.place_id INTO location_parent;
424 IF location.rank_address > parent_place_id_rank THEN
425 parent_place_id = location.place_id;
426 parent_place_id_rank = location.rank_address;
437 CREATE OR REPLACE FUNCTION placex_insert()
444 country_code VARCHAR(2);
449 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
451 NEW.place_id := nextval('seq_place');
452 NEW.indexed_status := 1; --STATUS_NEW
454 NEW.country_code := lower(get_country_code(NEW.geometry));
456 NEW.partition := get_partition(NEW.country_code);
457 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
459 IF NEW.osm_type = 'X' THEN
460 -- E'X'ternal records should already be in the right format so do nothing
462 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
464 IF NEW.class in ('place','boundary')
465 AND NEW.type in ('postcode','postal_code') THEN
467 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
468 -- most likely just a part of a multipolygon postcode boundary, throw it away
472 NEW.name := hstore('ref', NEW.address->'postcode');
474 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
475 INTO NEW.rank_search, NEW.rank_address;
478 NEW.rank_address := 0;
480 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
482 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
483 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
485 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
486 NEW.rank_search = 30;
487 NEW.rank_address = 0;
488 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
489 NEW.rank_search = 30;
490 NEW.rank_address = 0;
492 -- do table lookup stuff
493 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
494 classtype = NEW.type || NEW.admin_level::TEXT;
496 classtype = NEW.type;
498 SELECT l.rank_search, l.rank_address FROM address_levels l
499 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
500 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
501 ORDER BY l.country_code, l.class, l.type LIMIT 1
502 INTO NEW.rank_search, NEW.rank_address;
504 IF NEW.rank_search is NULL THEN
505 NEW.rank_search := 30;
508 IF NEW.rank_address is NULL THEN
509 NEW.rank_address := 30;
513 -- some postcorrections
514 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
515 -- Slightly promote waterway relations so that they are processed
516 -- before their members.
517 NEW.rank_search := NEW.rank_search - 1;
520 IF (NEW.extratags -> 'capital') = 'yes' THEN
521 NEW.rank_search := NEW.rank_search - 1;
526 -- a country code make no sense below rank 4 (country)
527 IF NEW.rank_search < 4 THEN
528 NEW.country_code := NULL;
531 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
533 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
535 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
536 -- might be part of an interpolation
537 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
538 ELSEIF NEW.rank_address > 0 THEN
539 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
540 -- Performance: We just can't handle re-indexing for country level changes
541 IF st_area(NEW.geometry) < 1 THEN
542 -- mark items within the geometry for re-indexing
543 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
545 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
546 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
547 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'));
548 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
549 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'));
552 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
554 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
555 IF NEW.type='postcode' THEN
557 ELSEIF NEW.rank_search < 16 THEN
559 ELSEIF NEW.rank_search < 18 THEN
561 ELSEIF NEW.rank_search < 20 THEN
563 ELSEIF NEW.rank_search = 21 THEN
565 ELSEIF NEW.rank_search < 24 THEN
567 ELSEIF NEW.rank_search < 26 THEN
568 diameter := 0.002; -- 100 to 200 meters
569 ELSEIF NEW.rank_search < 28 THEN
570 diameter := 0.001; -- 50 to 100 meters
573 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
574 IF NEW.rank_search >= 26 THEN
575 -- roads may cause reparenting for >27 rank places
576 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
577 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
578 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
579 ELSEIF NEW.rank_search >= 16 THEN
580 -- up to rank 16, street-less addresses may need reparenting
581 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');
583 -- for all other places the search terms may change as well
584 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);
591 -- add to tables for special search
592 -- Note: won't work on initial import because the classtype tables
593 -- do not yet exist. It won't hurt either.
594 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
595 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
597 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
598 USING NEW.place_id, ST_Centroid(NEW.geometry);
608 CREATE OR REPLACE FUNCTION placex_update()
614 relation_members TEXT[];
621 name_vector INTEGER[];
622 nameaddress_vector INTEGER[];
624 linked_node_id BIGINT;
625 linked_importance FLOAT;
626 linked_wikipedia TEXT;
631 IF OLD.indexed_status = 100 THEN
632 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
633 delete from placex where place_id = OLD.place_id;
637 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
641 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
643 NEW.indexed_date = now();
645 IF NOT %REVERSE-ONLY% THEN
646 DELETE from search_name WHERE place_id = NEW.place_id;
648 result := deleteSearchName(NEW.partition, NEW.place_id);
649 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
650 result := deleteRoad(NEW.partition, NEW.place_id);
651 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
652 UPDATE placex set linked_place_id = null, indexed_status = 2
653 where linked_place_id = NEW.place_id;
654 -- update not necessary for osmline, cause linked_place_id does not exist
656 IF NEW.linked_place_id is not null THEN
657 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
661 --DEBUG: RAISE WARNING 'Copy over address tags';
662 -- housenumber is a computed field, so start with an empty value
663 NEW.housenumber := NULL;
664 IF NEW.address is not NULL THEN
665 IF NEW.address ? 'conscriptionnumber' THEN
666 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
667 IF NEW.address ? 'streetnumber' THEN
668 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
669 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
671 NEW.housenumber := NEW.address->'conscriptionnumber';
673 ELSEIF NEW.address ? 'streetnumber' THEN
674 NEW.housenumber := NEW.address->'streetnumber';
675 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
676 ELSEIF NEW.address ? 'housenumber' THEN
677 NEW.housenumber := NEW.address->'housenumber';
678 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
681 addr_street := NEW.address->'street';
682 addr_place := NEW.address->'place';
684 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
685 i := getorcreate_postcode_id(NEW.address->'postcode');
689 -- Speed up searches - just use the centroid of the feature
690 -- cheaper but less acurate
691 NEW.centroid := ST_PointOnSurface(NEW.geometry);
692 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
694 NEW.postcode := null;
696 -- recalculate country and partition
697 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
698 -- for countries, believe the mapped country code,
699 -- so that we remain in the right partition if the boundaries
701 NEW.country_code := lower(NEW.address->'country');
702 NEW.partition := get_partition(lower(NEW.country_code));
703 IF NEW.partition = 0 THEN
704 NEW.country_code := lower(get_country_code(NEW.centroid));
705 NEW.partition := get_partition(NEW.country_code);
708 IF NEW.rank_search >= 4 THEN
709 NEW.country_code := lower(get_country_code(NEW.centroid));
711 NEW.country_code := NULL;
713 NEW.partition := get_partition(NEW.country_code);
715 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
717 -- waterway ways are linked when they are part of a relation and have the same class/type
718 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
719 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
721 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
722 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
723 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
724 FOR linked_node_id IN SELECT place_id FROM placex
725 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
726 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
727 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
729 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
730 DELETE FROM search_name WHERE place_id = linked_node_id;
735 --DEBUG: RAISE WARNING 'Waterway processed';
738 NEW.importance := null;
739 SELECT wikipedia, importance
740 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
741 INTO NEW.wikipedia,NEW.importance;
743 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
745 -- ---------------------------------------------------------------------------
746 -- For low level elements we inherit from our parent road
747 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
749 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
750 NEW.parent_place_id := null;
752 -- if we have a POI and there is no address information,
753 -- see if we can get it from a surrounding building
754 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
755 AND NEW.housenumber IS NULL THEN
757 -- The additional && condition works around the misguided query
758 -- planner of postgis 3.0.
759 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
760 and geometry && NEW.centroid
761 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
762 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
765 NEW.housenumber := location.address->'housenumber';
766 addr_street := location.address->'street';
767 addr_place := location.address->'place';
768 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
772 -- We have to find our parent road.
773 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
775 ST_Envelope(NEW.geometry),
776 addr_street, addr_place);
778 -- If we found the road take a shortcut here.
779 -- Otherwise fall back to the full address getting method below.
780 IF NEW.parent_place_id is not null THEN
782 -- Get the details of the parent road
783 SELECT p.country_code, p.postcode FROM placex p
784 WHERE p.place_id = NEW.parent_place_id INTO location;
786 NEW.country_code := location.country_code;
787 --DEBUG: RAISE WARNING 'Got parent details from search name';
789 -- determine postcode
790 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
791 NEW.postcode = upper(trim(NEW.address->'postcode'));
793 NEW.postcode := location.postcode;
795 IF NEW.postcode is null THEN
796 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
799 -- If there is no name it isn't searchable, don't bother to create a search record
800 IF NEW.name is NULL THEN
801 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
805 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
806 name_vector := make_keywords(NEW.name);
808 -- Performance, it would be more acurate to do all the rest of the import
809 -- process but it takes too long
810 -- Just be happy with inheriting from parent road only
811 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
812 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);
813 --DEBUG: RAISE WARNING 'Place added to location table';
816 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
817 NEW.rank_search, NEW.rank_address, NEW.geometry);
819 IF NOT %REVERSE-ONLY% THEN
820 -- Merge address from parent
821 SELECT array_merge(s.name_vector, s.nameaddress_vector)
822 INTO nameaddress_vector
824 WHERE s.place_id = NEW.parent_place_id;
826 INSERT INTO search_name (place_id, search_rank, address_rank,
827 importance, country_code, name_vector,
828 nameaddress_vector, centroid)
829 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
830 NEW.importance, NEW.country_code, name_vector,
831 nameaddress_vector, NEW.centroid);
832 --DEBUG: RAISE WARNING 'Place added to search table';
840 -- ---------------------------------------------------------------------------
842 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
843 SELECT * INTO location FROM find_linked_place(NEW);
844 IF location.place_id is not null THEN
845 --DEBUG: RAISE WARNING 'Linked %', location;
847 -- Use the linked point as the centre point of the geometry,
848 -- but only if it is within the area of the boundary.
849 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
850 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
851 NEW.centroid := centroid;
854 -- Use the address rank of the linked place, if it has one
855 IF location.rank_address between 5 and 25 THEN
856 NEW.rank_address := location.rank_address;
859 -- merge in the label name
860 IF NOT location.name IS NULL THEN
861 NEW.name := location.name || NEW.name;
864 -- merge in extra tags
865 NEW.extratags := hstore('linked_' || location.class, location.type)
866 || coalesce(location.extratags, ''::hstore)
867 || coalesce(NEW.extratags, ''::hstore);
869 -- mark the linked place (excludes from search results)
870 UPDATE placex set linked_place_id = NEW.place_id
871 WHERE place_id = location.place_id;
872 -- ensure that those places are not found anymore
873 DELETE FROM search_name WHERE place_id = location.place_id;
875 SELECT wikipedia, importance
876 FROM compute_importance(location.extratags, NEW.country_code,
877 'N', location.osm_id)
878 INTO linked_wikipedia,linked_importance;
880 -- Use the maximum importance if one could be computed from the linked object.
881 IF linked_importance is not null AND
882 (NEW.importance is null or NEW.importance < linked_importance)
884 NEW.importance = linked_importance;
888 -- Initialise the name vector using our name
889 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
890 name_vector := make_keywords(NEW.name);
892 -- make sure all names are in the word table
893 IF NEW.admin_level = 2
894 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
895 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
897 PERFORM create_country(NEW.name, lower(NEW.country_code));
898 --DEBUG: RAISE WARNING 'Country names updated';
901 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
902 NEW.rank_search, NEW.address,
903 CASE WHEN NEW.rank_search >= 26
904 AND NEW.rank_search < 30
905 THEN NEW.geometry ELSE NEW.centroid END)
906 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
908 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
910 IF NEW.address is not null AND NEW.address ? 'postcode'
911 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
912 NEW.postcode := upper(trim(NEW.address->'postcode'));
915 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
916 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
919 -- if we have a name add this to the name search table
920 IF NEW.name IS NOT NULL THEN
922 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
923 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);
924 --DEBUG: RAISE WARNING 'added to location (full)';
927 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
928 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
929 --DEBUG: RAISE WARNING 'insert into road location table (full)';
932 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
933 NEW.rank_search, NEW.rank_address, NEW.geometry);
934 --DEBUG: RAISE WARNING 'added to search name (full)';
936 IF NOT %REVERSE-ONLY% THEN
937 INSERT INTO search_name (place_id, search_rank, address_rank,
938 importance, country_code, name_vector,
939 nameaddress_vector, centroid)
940 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
941 NEW.importance, NEW.country_code, name_vector,
942 nameaddress_vector, NEW.centroid);
947 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
955 CREATE OR REPLACE FUNCTION placex_delete()
962 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
964 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
965 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
966 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
967 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
969 IF OLD.rank_address < 30 THEN
971 -- mark everything linked to this place for re-indexing
972 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
973 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
974 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
976 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
977 DELETE FROM place_addressline where address_place_id = OLD.place_id;
979 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
980 b := deleteRoad(OLD.partition, OLD.place_id);
982 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
983 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
984 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
985 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
986 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
990 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
992 IF OLD.rank_address < 26 THEN
993 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
996 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
998 IF OLD.name is not null THEN
999 IF NOT %REVERSE-ONLY% THEN
1000 DELETE from search_name WHERE place_id = OLD.place_id;
1002 b := deleteSearchName(OLD.partition, OLD.place_id);
1005 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1007 DELETE FROM place_addressline where place_id = OLD.place_id;
1009 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1011 -- remove from tables for special search
1012 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1013 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1015 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1018 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;