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 -- Name searches can be done for ways as well as relations
224 IF bnd_name is not null THEN
225 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
227 SELECT placex.* from placex
228 WHERE make_standard_name(name->'name') = bnd_name
229 AND ((bnd.rank_address > 0 and placex.rank_address = bnd.rank_address)
230 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
231 AND placex.osm_type = 'N'
232 AND placex.rank_search < 26 -- needed to select the right index
233 AND _st_covers(bnd.geometry, placex.geometry)
235 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
236 RETURN linked_placex;
243 LANGUAGE plpgsql STABLE;
246 -- Insert address of a place into the place_addressline table.
248 -- \param obj_place_id Place_id of the place to compute the address for.
249 -- \param partition Partition number where the place is in.
250 -- \param maxrank Rank of the place. All address features must have
251 -- a search rank lower than the given rank.
252 -- \param address Address terms for the place.
253 -- \param geoemtry Geometry to which the address objects should be close.
255 -- \retval parent_place_id Place_id of the address object that is the direct
257 -- \retval postcode Postcode computed from the address. This is the
258 -- addr:postcode of one of the address objects. If
259 -- more than one of has a postcode, the highest ranking
260 -- one is used. May be NULL.
261 -- \retval nameaddress_vector Search terms for the address. This is the sum
262 -- of name terms of all address objects.
263 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
268 OUT parent_place_id BIGINT,
270 OUT nameaddress_vector INT[])
273 current_rank_address INTEGER := 0;
274 location_distance FLOAT := 0;
275 location_parent GEOMETRY := NULL;
276 parent_place_id_rank SMALLINT := 0;
278 location_isaddress BOOLEAN;
280 address_havelevel BOOLEAN[];
281 location_keywords INT[];
289 parent_place_id := 0;
290 nameaddress_vector := '{}'::int[];
291 isin_tokens := '{}'::int[];
293 ---- convert address store to array of tokenids
294 IF address IS NOT NULL THEN
295 FOR addr_item IN SELECT * FROM each(address)
297 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
298 'district', 'region', 'county', 'municipality',
299 'hamlet', 'village', 'subdistrict', 'town',
300 'neighbourhood', 'quarter', 'parish')
302 isin_tokens := array_merge(isin_tokens,
303 word_ids_from_name(addr_item.value));
304 IF NOT %REVERSE-ONLY% THEN
305 nameaddress_vector := array_merge(nameaddress_vector,
306 addr_ids_from_name(addr_item.value));
311 IF address ? 'is_in' THEN
312 -- is_in items need splitting
313 isin := regexp_split_to_array(address->'is_in', E'[;,]');
314 IF array_upper(isin, 1) IS NOT NULL THEN
315 FOR i IN 1..array_upper(isin, 1) LOOP
316 isin_tokens := array_merge(isin_tokens,
317 word_ids_from_name(isin[i]));
319 -- merge word into address vector
320 IF NOT %REVERSE-ONLY% THEN
321 nameaddress_vector := array_merge(nameaddress_vector,
322 addr_ids_from_name(isin[i]));
328 IF NOT %REVERSE-ONLY% THEN
329 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
332 ---- now compute the address terms
334 address_havelevel[i] := false;
338 SELECT * FROM getNearFeatures(partition, geometry, maxrank, isin_tokens)
340 IF location.rank_address != current_rank_address THEN
341 current_rank_address := location.rank_address;
342 IF location.isguess THEN
343 location_distance := location.distance * 1.5;
345 IF location.rank_address <= 12 THEN
346 -- for county and above, if we have an area consider that exact
347 -- (It would be nice to relax the constraint for places close to
348 -- the boundary but we'd need the exact geometry for that. Too
350 location_distance = 0;
352 -- Below county level remain slightly fuzzy.
353 location_distance := location.distance * 0.5;
357 CONTINUE WHEN location.keywords <@ location_keywords;
360 IF location.distance < location_distance OR NOT location.isguess THEN
361 location_keywords := location.keywords;
363 location_isaddress := NOT address_havelevel[location.rank_address];
364 --DEBUG: RAISE WARNING 'should be address: %, is guess: %, rank: %', location_isaddress, location.isguess, location.rank_address;
365 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
366 location_isaddress := ST_Contains(location_parent, location.centroid);
369 --DEBUG: RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
370 -- Add it to the list of search terms
371 IF NOT %REVERSE-ONLY% THEN
372 nameaddress_vector := array_merge(nameaddress_vector,
373 location.keywords::integer[]);
376 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
377 isaddress, distance, cached_rank_address)
378 VALUES (obj_place_id, location.place_id, true,
379 location_isaddress, location.distance, location.rank_address);
381 IF location_isaddress THEN
382 -- add postcode if we have one
383 -- (If multiple postcodes are available, we end up with the highest ranking one.)
384 IF location.postcode is not null THEN
385 postcode = location.postcode;
388 address_havelevel[location.rank_address] := true;
389 -- add a hack against postcode ranks
390 IF NOT location.isguess
391 AND location.rank_address != 11 AND location.rank_address != 5
393 SELECT p.geometry FROM placex p
394 WHERE p.place_id = location.place_id INTO location_parent;
397 IF location.rank_address > parent_place_id_rank THEN
398 parent_place_id = location.place_id;
399 parent_place_id_rank = location.rank_address;
410 CREATE OR REPLACE FUNCTION placex_insert()
417 country_code VARCHAR(2);
422 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
424 NEW.place_id := nextval('seq_place');
425 NEW.indexed_status := 1; --STATUS_NEW
427 NEW.country_code := lower(get_country_code(NEW.geometry));
429 NEW.partition := get_partition(NEW.country_code);
430 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
432 IF NEW.osm_type = 'X' THEN
433 -- E'X'ternal records should already be in the right format so do nothing
435 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
437 IF NEW.class in ('place','boundary')
438 AND NEW.type in ('postcode','postal_code') THEN
440 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
441 -- most likely just a part of a multipolygon postcode boundary, throw it away
445 NEW.name := hstore('ref', NEW.address->'postcode');
447 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
448 INTO NEW.rank_search, NEW.rank_address;
451 NEW.rank_address := 0;
453 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
455 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
456 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
458 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
459 NEW.rank_search = 30;
460 NEW.rank_address = 0;
461 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
462 NEW.rank_search = 30;
463 NEW.rank_address = 0;
465 -- do table lookup stuff
466 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
467 classtype = NEW.type || NEW.admin_level::TEXT;
469 classtype = NEW.type;
471 SELECT l.rank_search, l.rank_address FROM address_levels l
472 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
473 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
474 ORDER BY l.country_code, l.class, l.type LIMIT 1
475 INTO NEW.rank_search, NEW.rank_address;
477 IF NEW.rank_search is NULL THEN
478 NEW.rank_search := 30;
481 IF NEW.rank_address is NULL THEN
482 NEW.rank_address := 30;
486 -- some postcorrections
487 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
488 -- Slightly promote waterway relations so that they are processed
489 -- before their members.
490 NEW.rank_search := NEW.rank_search - 1;
493 IF (NEW.extratags -> 'capital') = 'yes' THEN
494 NEW.rank_search := NEW.rank_search - 1;
499 -- a country code make no sense below rank 4 (country)
500 IF NEW.rank_search < 4 THEN
501 NEW.country_code := NULL;
504 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
506 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
508 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
509 -- might be part of an interpolation
510 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
511 ELSEIF NEW.rank_address > 0 THEN
512 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
513 -- Performance: We just can't handle re-indexing for country level changes
514 IF st_area(NEW.geometry) < 1 THEN
515 -- mark items within the geometry for re-indexing
516 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
518 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
519 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
520 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'));
521 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
522 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'));
525 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
527 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
528 IF NEW.type='postcode' THEN
530 ELSEIF NEW.rank_search < 16 THEN
532 ELSEIF NEW.rank_search < 18 THEN
534 ELSEIF NEW.rank_search < 20 THEN
536 ELSEIF NEW.rank_search = 21 THEN
538 ELSEIF NEW.rank_search < 24 THEN
540 ELSEIF NEW.rank_search < 26 THEN
541 diameter := 0.002; -- 100 to 200 meters
542 ELSEIF NEW.rank_search < 28 THEN
543 diameter := 0.001; -- 50 to 100 meters
546 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
547 IF NEW.rank_search >= 26 THEN
548 -- roads may cause reparenting for >27 rank places
549 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
550 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
551 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
552 ELSEIF NEW.rank_search >= 16 THEN
553 -- up to rank 16, street-less addresses may need reparenting
554 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');
556 -- for all other places the search terms may change as well
557 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);
564 -- add to tables for special search
565 -- Note: won't work on initial import because the classtype tables
566 -- do not yet exist. It won't hurt either.
567 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
568 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
570 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
571 USING NEW.place_id, ST_Centroid(NEW.geometry);
581 CREATE OR REPLACE FUNCTION placex_update()
587 relation_members TEXT[];
594 name_vector INTEGER[];
595 nameaddress_vector INTEGER[];
597 linked_node_id BIGINT;
598 linked_importance FLOAT;
599 linked_wikipedia TEXT;
604 IF OLD.indexed_status = 100 THEN
605 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
606 delete from placex where place_id = OLD.place_id;
610 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
614 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
616 NEW.indexed_date = now();
618 IF NOT %REVERSE-ONLY% THEN
619 DELETE from search_name WHERE place_id = NEW.place_id;
621 result := deleteSearchName(NEW.partition, NEW.place_id);
622 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
623 result := deleteRoad(NEW.partition, NEW.place_id);
624 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
625 UPDATE placex set linked_place_id = null, indexed_status = 2
626 where linked_place_id = NEW.place_id;
627 -- update not necessary for osmline, cause linked_place_id does not exist
629 IF NEW.linked_place_id is not null THEN
630 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
634 --DEBUG: RAISE WARNING 'Copy over address tags';
635 -- housenumber is a computed field, so start with an empty value
636 NEW.housenumber := NULL;
637 IF NEW.address is not NULL THEN
638 IF NEW.address ? 'conscriptionnumber' THEN
639 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
640 IF NEW.address ? 'streetnumber' THEN
641 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
642 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
644 NEW.housenumber := NEW.address->'conscriptionnumber';
646 ELSEIF NEW.address ? 'streetnumber' THEN
647 NEW.housenumber := NEW.address->'streetnumber';
648 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
649 ELSEIF NEW.address ? 'housenumber' THEN
650 NEW.housenumber := NEW.address->'housenumber';
651 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
654 addr_street := NEW.address->'street';
655 addr_place := NEW.address->'place';
657 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
658 i := getorcreate_postcode_id(NEW.address->'postcode');
662 -- Speed up searches - just use the centroid of the feature
663 -- cheaper but less acurate
664 NEW.centroid := ST_PointOnSurface(NEW.geometry);
665 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
667 NEW.postcode := null;
669 -- recalculate country and partition
670 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
671 -- for countries, believe the mapped country code,
672 -- so that we remain in the right partition if the boundaries
674 NEW.country_code := lower(NEW.address->'country');
675 NEW.partition := get_partition(lower(NEW.country_code));
676 IF NEW.partition = 0 THEN
677 NEW.country_code := lower(get_country_code(NEW.centroid));
678 NEW.partition := get_partition(NEW.country_code);
681 IF NEW.rank_search >= 4 THEN
682 NEW.country_code := lower(get_country_code(NEW.centroid));
684 NEW.country_code := NULL;
686 NEW.partition := get_partition(NEW.country_code);
688 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
690 -- waterway ways are linked when they are part of a relation and have the same class/type
691 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
692 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
694 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
695 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
696 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
697 FOR linked_node_id IN SELECT place_id FROM placex
698 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
699 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
700 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
702 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
703 DELETE FROM search_name WHERE place_id = linked_node_id;
708 --DEBUG: RAISE WARNING 'Waterway processed';
711 NEW.importance := null;
712 SELECT wikipedia, importance
713 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
714 INTO NEW.wikipedia,NEW.importance;
716 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
718 -- ---------------------------------------------------------------------------
719 -- For low level elements we inherit from our parent road
720 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
722 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
723 NEW.parent_place_id := null;
725 -- if we have a POI and there is no address information,
726 -- see if we can get it from a surrounding building
727 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
728 AND NEW.housenumber IS NULL THEN
730 -- The additional && condition works around the misguided query
731 -- planner of postgis 3.0.
732 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
733 and geometry && NEW.centroid
734 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
735 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
738 NEW.housenumber := location.address->'housenumber';
739 addr_street := location.address->'street';
740 addr_place := location.address->'place';
741 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
745 -- We have to find our parent road.
746 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
748 ST_Envelope(NEW.geometry),
749 addr_street, addr_place);
751 -- If we found the road take a shortcut here.
752 -- Otherwise fall back to the full address getting method below.
753 IF NEW.parent_place_id is not null THEN
755 -- Get the details of the parent road
756 SELECT p.country_code, p.postcode FROM placex p
757 WHERE p.place_id = NEW.parent_place_id INTO location;
759 NEW.country_code := location.country_code;
760 --DEBUG: RAISE WARNING 'Got parent details from search name';
762 -- determine postcode
763 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
764 NEW.postcode = upper(trim(NEW.address->'postcode'));
766 NEW.postcode := location.postcode;
768 IF NEW.postcode is null THEN
769 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
772 -- If there is no name it isn't searchable, don't bother to create a search record
773 IF NEW.name is NULL THEN
774 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
778 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
779 name_vector := make_keywords(NEW.name);
781 -- Performance, it would be more acurate to do all the rest of the import
782 -- process but it takes too long
783 -- Just be happy with inheriting from parent road only
784 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
785 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);
786 --DEBUG: RAISE WARNING 'Place added to location table';
789 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
790 NEW.rank_search, NEW.rank_address, NEW.geometry);
792 IF NOT %REVERSE-ONLY% THEN
793 -- Merge address from parent
794 SELECT array_merge(s.name_vector, s.nameaddress_vector)
795 INTO nameaddress_vector
797 WHERE s.place_id = NEW.parent_place_id;
799 INSERT INTO search_name (place_id, search_rank, address_rank,
800 importance, country_code, name_vector,
801 nameaddress_vector, centroid)
802 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
803 NEW.importance, NEW.country_code, name_vector,
804 nameaddress_vector, NEW.centroid);
805 --DEBUG: RAISE WARNING 'Place added to search table';
813 -- ---------------------------------------------------------------------------
815 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
816 SELECT * INTO location FROM find_linked_place(NEW);
817 IF location.place_id is not null THEN
818 --DEBUG: RAISE WARNING 'Linked %', location;
820 -- Use the linked point as the centre point of the geometry,
821 -- but only if it is within the area of the boundary.
822 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
823 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
824 NEW.centroid := centroid;
827 -- Use the address rank of the linked place, if it has one
828 IF location.rank_address between 5 and 25 THEN
829 NEW.rank_address := location.rank_address;
832 -- merge in the label name
833 IF NOT location.name IS NULL THEN
834 NEW.name := location.name || NEW.name;
837 -- merge in extra tags
838 NEW.extratags := hstore('linked_' || location.class, location.type)
839 || coalesce(location.extratags, ''::hstore)
840 || coalesce(NEW.extratags, ''::hstore);
842 -- mark the linked place (excludes from search results)
843 UPDATE placex set linked_place_id = NEW.place_id
844 WHERE place_id = location.place_id;
845 -- ensure that those places are not found anymore
846 DELETE FROM search_name WHERE place_id = location.place_id;
848 SELECT wikipedia, importance
849 FROM compute_importance(location.extratags, NEW.country_code,
850 'N', location.osm_id)
851 INTO linked_wikipedia,linked_importance;
853 -- Use the maximum importance if one could be computed from the linked object.
854 IF linked_importance is not null AND
855 (NEW.importance is null or NEW.importance < linked_importance)
857 NEW.importance = linked_importance;
861 -- Initialise the name vector using our name
862 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
863 name_vector := make_keywords(NEW.name);
865 -- make sure all names are in the word table
866 IF NEW.admin_level = 2
867 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
868 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
870 PERFORM create_country(NEW.name, lower(NEW.country_code));
871 --DEBUG: RAISE WARNING 'Country names updated';
874 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
875 NEW.rank_search, NEW.address,
876 CASE WHEN NEW.rank_search >= 26
877 AND NEW.rank_search < 30
878 THEN NEW.geometry ELSE NEW.centroid END)
879 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
881 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
883 IF NEW.address is not null AND NEW.address ? 'postcode'
884 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
885 NEW.postcode := upper(trim(NEW.address->'postcode'));
888 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
889 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
892 -- if we have a name add this to the name search table
893 IF NEW.name IS NOT NULL THEN
895 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
896 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);
897 --DEBUG: RAISE WARNING 'added to location (full)';
900 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
901 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
902 --DEBUG: RAISE WARNING 'insert into road location table (full)';
905 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
906 NEW.rank_search, NEW.rank_address, NEW.geometry);
907 --DEBUG: RAISE WARNING 'added to search name (full)';
909 IF NOT %REVERSE-ONLY% THEN
910 INSERT INTO search_name (place_id, search_rank, address_rank,
911 importance, country_code, name_vector,
912 nameaddress_vector, centroid)
913 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
914 NEW.importance, NEW.country_code, name_vector,
915 nameaddress_vector, NEW.centroid);
920 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
928 CREATE OR REPLACE FUNCTION placex_delete()
935 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
937 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
938 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
939 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
940 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
942 IF OLD.rank_address < 30 THEN
944 -- mark everything linked to this place for re-indexing
945 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
946 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
947 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
949 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
950 DELETE FROM place_addressline where address_place_id = OLD.place_id;
952 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
953 b := deleteRoad(OLD.partition, OLD.place_id);
955 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
956 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
957 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
958 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
959 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
963 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
965 IF OLD.rank_address < 26 THEN
966 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
969 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
971 IF OLD.name is not null THEN
972 IF NOT %REVERSE-ONLY% THEN
973 DELETE from search_name WHERE place_id = OLD.place_id;
975 b := deleteSearchName(OLD.partition, OLD.place_id);
978 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
980 DELETE FROM place_addressline where place_id = OLD.place_id;
982 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
984 -- remove from tables for special search
985 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
986 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
988 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
991 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;