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 place_id FROM getNearestRoadFeature(poi_partition, bbox)
139 INTO parent_place_id;
140 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
142 -- for larger features simply find the area with the largest rank that
145 SELECT place_id FROM placex
146 WHERE bbox @ geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
147 AND rank_search between 5 and 25
148 ORDER BY rank_search desc
150 RETURN location.place_id;
155 RETURN parent_place_id;
158 LANGUAGE plpgsql STABLE;
160 -- Try to find a linked place for the given object.
161 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
165 relation_members TEXT[];
167 linked_placex placex%ROWTYPE;
170 IF bnd.rank_search >= 26 or bnd.rank_address = 0
171 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
176 IF bnd.osm_type = 'R' THEN
177 -- see if we have any special relation members
178 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
179 --DEBUG: RAISE WARNING 'Got relation members';
181 -- Search for relation members with role 'lable'.
182 IF relation_members IS NOT NULL THEN
184 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
186 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
190 WHERE osm_type = 'N' and osm_id = rel_member.member
193 --DEBUG: RAISE WARNING 'Linked label member';
194 RETURN linked_placex;
201 IF bnd.name ? 'name' THEN
202 bnd_name := make_standard_name(bnd.name->'name');
203 IF bnd_name = '' THEN
208 -- Search for relation members with role admin_center.
209 IF bnd.osm_type = 'R' and bnd_name is not null
210 and relation_members is not null THEN
212 SELECT get_rel_node_members(relation_members,
213 ARRAY['admin_center','admin_centre']) as member
215 --DEBUG: RAISE WARNING 'Found admin_center member %', rel_member.member;
218 WHERE osm_type = 'N' and osm_id = rel_member.member
221 -- For an admin centre we also want a name match - still not perfect,
222 -- for example 'new york, new york'
223 -- But that can be fixed by explicitly setting the label in the data
224 IF bnd_name = make_standard_name(linked_placex.name->'name')
225 AND bnd.rank_address = linked_placex.rank_address
227 RETURN linked_placex;
229 --DEBUG: RAISE WARNING 'Linked admin_center';
234 -- Name searches can be done for ways as well as relations
235 IF bnd.osm_type in ('W','R') and bnd_name is not null THEN
236 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
238 SELECT placex.* from placex
239 WHERE make_standard_name(name->'name') = bnd_name
240 AND placex.rank_address = bnd.rank_address
241 AND placex.osm_type = 'N'
242 AND placex.rank_search < 26 -- needed to select the right index
243 AND _st_covers(bnd.geometry, placex.geometry)
245 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
246 RETURN linked_placex;
253 LANGUAGE plpgsql STABLE;
256 -- Insert address of a place into the place_addressline table.
258 -- \param obj_place_id Place_id of the place to compute the address for.
259 -- \param partition Partition number where the place is in.
260 -- \param maxrank Rank of the place. All address features must have
261 -- a search rank lower than the given rank.
262 -- \param address Address terms for the place.
263 -- \param geoemtry Geometry to which the address objects should be close.
265 -- \retval parent_place_id Place_id of the address object that is the direct
267 -- \retval postcode Postcode computed from the address. This is the
268 -- addr:postcode of one of the address objects. If
269 -- more than one of has a postcode, the highest ranking
270 -- one is used. May be NULL.
271 -- \retval nameaddress_vector Search terms for the address. This is the sum
272 -- of name terms of all address objects.
273 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
278 OUT parent_place_id BIGINT,
280 OUT nameaddress_vector INT[])
283 current_rank_address INTEGER := 0;
284 location_distance FLOAT := 0;
285 location_parent GEOMETRY := NULL;
286 parent_place_id_rank SMALLINT := 0;
288 location_isaddress BOOLEAN;
290 address_havelevel BOOLEAN[];
291 location_keywords INT[];
299 parent_place_id := 0;
300 nameaddress_vector := '{}'::int[];
301 isin_tokens := '{}'::int[];
303 ---- convert address store to array of tokenids
304 IF address IS NOT NULL THEN
305 FOR addr_item IN SELECT * FROM each(address)
307 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
308 'district', 'region', 'county', 'municipality',
309 'hamlet', 'village', 'subdistrict', 'town',
310 'neighbourhood', 'quarter', 'parish')
312 isin_tokens := array_merge(isin_tokens,
313 word_ids_from_name(addr_item.value));
314 IF NOT %REVERSE-ONLY% THEN
315 nameaddress_vector := array_merge(nameaddress_vector,
316 addr_ids_from_name(addr_item.value));
321 IF address ? 'is_in' THEN
322 -- is_in items need splitting
323 isin := regexp_split_to_array(address->'is_in', E'[;,]');
324 IF array_upper(isin, 1) IS NOT NULL THEN
325 FOR i IN 1..array_upper(isin, 1) LOOP
326 isin_tokens := array_merge(isin_tokens,
327 word_ids_from_name(isin[i]));
329 -- merge word into address vector
330 IF NOT %REVERSE-ONLY% THEN
331 nameaddress_vector := array_merge(nameaddress_vector,
332 addr_ids_from_name(isin[i]));
338 IF NOT %REVERSE-ONLY% THEN
339 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
342 ---- now compute the address terms
344 address_havelevel[i] := false;
348 SELECT * FROM getNearFeatures(partition, geometry, maxrank, isin_tokens)
350 IF location.rank_address != current_rank_address THEN
351 current_rank_address := location.rank_address;
352 IF location.isguess THEN
353 location_distance := location.distance * 1.5;
355 IF location.rank_address <= 12 THEN
356 -- for county and above, if we have an area consider that exact
357 -- (It would be nice to relax the constraint for places close to
358 -- the boundary but we'd need the exact geometry for that. Too
360 location_distance = 0;
362 -- Below county level remain slightly fuzzy.
363 location_distance := location.distance * 0.5;
367 CONTINUE WHEN location.keywords <@ location_keywords;
370 IF location.distance < location_distance OR NOT location.isguess THEN
371 location_keywords := location.keywords;
373 location_isaddress := NOT address_havelevel[location.rank_address];
374 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
375 location_isaddress := ST_Contains(location_parent, location.centroid);
378 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
379 -- Add it to the list of search terms
380 IF NOT %REVERSE-ONLY% THEN
381 nameaddress_vector := array_merge(nameaddress_vector,
382 location.keywords::integer[]);
385 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
386 isaddress, distance, cached_rank_address)
387 VALUES (obj_place_id, location.place_id, true,
388 location_isaddress, location.distance, location.rank_address);
390 IF location_isaddress THEN
391 -- add postcode if we have one
392 -- (If multiple postcodes are available, we end up with the highest ranking one.)
393 IF location.postcode is not null THEN
394 postcode = location.postcode;
397 address_havelevel[location.rank_address] := true;
398 IF NOT location.isguess THEN
399 SELECT placex.geometry FROM placex
400 WHERE obj_place_id = location.place_id INTO location_parent;
403 IF location.rank_address > parent_place_id_rank THEN
404 parent_place_id = location.place_id;
405 parent_place_id_rank = location.rank_address;
408 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
417 CREATE OR REPLACE FUNCTION placex_insert()
424 country_code VARCHAR(2);
429 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
431 NEW.place_id := nextval('seq_place');
432 NEW.indexed_status := 1; --STATUS_NEW
434 NEW.country_code := lower(get_country_code(NEW.geometry));
436 NEW.partition := get_partition(NEW.country_code);
437 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
439 IF NEW.osm_type = 'X' THEN
440 -- E'X'ternal records should already be in the right format so do nothing
442 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
444 IF NEW.class in ('place','boundary')
445 AND NEW.type in ('postcode','postal_code') THEN
447 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
448 -- most likely just a part of a multipolygon postcode boundary, throw it away
452 NEW.name := hstore('ref', NEW.address->'postcode');
454 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
455 INTO NEW.rank_search, NEW.rank_address;
458 NEW.rank_address := 0;
460 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
462 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
463 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
465 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
466 NEW.rank_search = 30;
467 NEW.rank_address = 0;
468 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
469 NEW.rank_search = 30;
470 NEW.rank_address = 0;
472 -- do table lookup stuff
473 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
474 classtype = NEW.type || NEW.admin_level::TEXT;
476 classtype = NEW.type;
478 SELECT l.rank_search, l.rank_address FROM address_levels l
479 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
480 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
481 ORDER BY l.country_code, l.class, l.type LIMIT 1
482 INTO NEW.rank_search, NEW.rank_address;
484 IF NEW.rank_search is NULL THEN
485 NEW.rank_search := 30;
488 IF NEW.rank_address is NULL THEN
489 NEW.rank_address := 30;
493 -- some postcorrections
494 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
495 -- Slightly promote waterway relations so that they are processed
496 -- before their members.
497 NEW.rank_search := NEW.rank_search - 1;
500 IF (NEW.extratags -> 'capital') = 'yes' THEN
501 NEW.rank_search := NEW.rank_search - 1;
506 -- a country code make no sense below rank 4 (country)
507 IF NEW.rank_search < 4 THEN
508 NEW.country_code := NULL;
511 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
513 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
515 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
516 -- might be part of an interpolation
517 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
518 ELSEIF NEW.rank_address > 0 THEN
519 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
520 -- Performance: We just can't handle re-indexing for country level changes
521 IF st_area(NEW.geometry) < 1 THEN
522 -- mark items within the geometry for re-indexing
523 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
525 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
526 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
527 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'));
528 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
529 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'));
532 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
534 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
535 IF NEW.type='postcode' THEN
537 ELSEIF NEW.rank_search < 16 THEN
539 ELSEIF NEW.rank_search < 18 THEN
541 ELSEIF NEW.rank_search < 20 THEN
543 ELSEIF NEW.rank_search = 21 THEN
545 ELSEIF NEW.rank_search < 24 THEN
547 ELSEIF NEW.rank_search < 26 THEN
548 diameter := 0.002; -- 100 to 200 meters
549 ELSEIF NEW.rank_search < 28 THEN
550 diameter := 0.001; -- 50 to 100 meters
553 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
554 IF NEW.rank_search >= 26 THEN
555 -- roads may cause reparenting for >27 rank places
556 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
557 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
558 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
559 ELSEIF NEW.rank_search >= 16 THEN
560 -- up to rank 16, street-less addresses may need reparenting
561 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');
563 -- for all other places the search terms may change as well
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) and (rank_search < 28 or name is not null);
571 -- add to tables for special search
572 -- Note: won't work on initial import because the classtype tables
573 -- do not yet exist. It won't hurt either.
574 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
575 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
577 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
578 USING NEW.place_id, ST_Centroid(NEW.geometry);
588 CREATE OR REPLACE FUNCTION placex_update()
594 relation_members TEXT[];
599 name_vector INTEGER[];
600 nameaddress_vector INTEGER[];
602 linked_node_id BIGINT;
603 linked_importance FLOAT;
604 linked_wikipedia TEXT;
609 IF OLD.indexed_status = 100 THEN
610 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
611 delete from placex where place_id = OLD.place_id;
615 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
619 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
621 NEW.indexed_date = now();
623 IF NOT %REVERSE-ONLY% THEN
624 DELETE from search_name WHERE place_id = NEW.place_id;
626 result := deleteSearchName(NEW.partition, NEW.place_id);
627 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
628 result := deleteRoad(NEW.partition, NEW.place_id);
629 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
630 UPDATE placex set linked_place_id = null, indexed_status = 2
631 where linked_place_id = NEW.place_id;
632 -- update not necessary for osmline, cause linked_place_id does not exist
634 IF NEW.linked_place_id is not null THEN
635 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
639 --DEBUG: RAISE WARNING 'Copy over address tags';
640 -- housenumber is a computed field, so start with an empty value
641 NEW.housenumber := NULL;
642 IF NEW.address is not NULL THEN
643 IF NEW.address ? 'conscriptionnumber' THEN
644 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
645 IF NEW.address ? 'streetnumber' THEN
646 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
647 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
649 NEW.housenumber := NEW.address->'conscriptionnumber';
651 ELSEIF NEW.address ? 'streetnumber' THEN
652 NEW.housenumber := NEW.address->'streetnumber';
653 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
654 ELSEIF NEW.address ? 'housenumber' THEN
655 NEW.housenumber := NEW.address->'housenumber';
656 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
659 addr_street := NEW.address->'street';
660 addr_place := NEW.address->'place';
662 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
663 i := getorcreate_postcode_id(NEW.address->'postcode');
667 -- Speed up searches - just use the centroid of the feature
668 -- cheaper but less acurate
669 NEW.centroid := ST_PointOnSurface(NEW.geometry);
670 -- For searching near features rather use the centroid
671 NEW.postcode := null;
672 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
674 -- recalculate country and partition
675 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
676 -- for countries, believe the mapped country code,
677 -- so that we remain in the right partition if the boundaries
679 NEW.country_code := lower(NEW.address->'country');
680 NEW.partition := get_partition(lower(NEW.country_code));
681 IF NEW.partition = 0 THEN
682 NEW.country_code := lower(get_country_code(NEW.centroid));
683 NEW.partition := get_partition(NEW.country_code);
686 IF NEW.rank_search >= 4 THEN
687 NEW.country_code := lower(get_country_code(NEW.centroid));
689 NEW.country_code := NULL;
691 NEW.partition := get_partition(NEW.country_code);
693 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
695 -- waterway ways are linked when they are part of a relation and have the same class/type
696 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
697 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
699 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
700 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
701 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
702 FOR linked_node_id IN SELECT place_id FROM placex
703 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
704 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
705 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
707 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
712 --DEBUG: RAISE WARNING 'Waterway processed';
715 NEW.importance := null;
716 SELECT wikipedia, importance
717 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
718 INTO NEW.wikipedia,NEW.importance;
720 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
722 -- ---------------------------------------------------------------------------
723 -- For low level elements we inherit from our parent road
724 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
726 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
727 NEW.parent_place_id := null;
729 -- if we have a POI and there is no address information,
730 -- see if we can get it from a surrounding building
731 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
732 AND NEW.housenumber IS NULL THEN
734 -- The additional && condition works around the misguided query
735 -- planner of postgis 3.0.
736 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
737 and geometry && NEW.centroid
738 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
739 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
742 NEW.housenumber := location.address->'housenumber';
743 addr_street := location.address->'street';
744 addr_place := location.address->'place';
745 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
749 -- We have to find our parent road.
750 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
752 ST_Envelope(NEW.geometry),
753 addr_street, addr_place);
755 -- If we found the road take a shortcut here.
756 -- Otherwise fall back to the full address getting method below.
757 IF NEW.parent_place_id is not null THEN
759 -- Get the details of the parent road
760 SELECT p.country_code, p.postcode FROM placex p
761 WHERE p.place_id = NEW.parent_place_id INTO location;
763 NEW.country_code := location.country_code;
764 --DEBUG: RAISE WARNING 'Got parent details from search name';
766 -- determine postcode
767 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
768 NEW.postcode = upper(trim(NEW.address->'postcode'));
770 NEW.postcode := location.postcode;
772 IF NEW.postcode is null THEN
773 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
776 -- If there is no name it isn't searchable, don't bother to create a search record
777 IF NEW.name is NULL THEN
778 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
782 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
783 name_vector := make_keywords(NEW.name);
785 -- Performance, it would be more acurate to do all the rest of the import
786 -- process but it takes too long
787 -- Just be happy with inheriting from parent road only
788 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
789 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);
790 --DEBUG: RAISE WARNING 'Place added to location table';
793 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
794 NEW.rank_search, NEW.rank_address, NEW.geometry);
796 IF NOT %REVERSE-ONLY% THEN
797 -- Merge address from parent
798 SELECT array_merge(s.name_vector, s.nameaddress_vector)
799 INTO nameaddress_vector
801 WHERE s.place_id = NEW.parent_place_id;
803 INSERT INTO search_name (place_id, search_rank, address_rank,
804 importance, country_code, name_vector,
805 nameaddress_vector, centroid)
806 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
807 NEW.importance, NEW.country_code, name_vector,
808 nameaddress_vector, NEW.centroid);
809 --DEBUG: RAISE WARNING 'Place added to search table';
817 -- ---------------------------------------------------------------------------
819 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
820 SELECT * INTO location FROM find_linked_place(NEW);
821 IF location.place_id is not null THEN
822 --DEBUG: RAISE WARNING 'Linked %', location;
824 -- Use this as the centre point of the geometry
825 NEW.centroid := coalesce(location.centroid,
826 ST_Centroid(location.geometry));
828 -- merge in the label name
829 IF NOT location.name IS NULL THEN
830 NEW.name := location.name || NEW.name;
833 -- merge in extra tags
834 NEW.extratags := hstore(location.class, location.type)
835 || coalesce(location.extratags, ''::hstore)
836 || coalesce(NEW.extratags, ''::hstore);
838 -- mark the linked place (excludes from search results)
839 UPDATE placex set linked_place_id = NEW.place_id
840 WHERE place_id = location.place_id;
842 SELECT wikipedia, importance
843 FROM compute_importance(location.extratags, NEW.country_code,
844 'N', location.osm_id)
845 INTO linked_wikipedia,linked_importance;
847 -- Use the maximum importance if one could be computed from the linked object.
848 IF linked_importance is not null AND
849 (NEW.importance is null or NEW.importance < linked_importance)
851 NEW.importance = linked_importance;
855 -- Initialise the name vector using our name
856 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
857 name_vector := make_keywords(NEW.name);
859 -- make sure all names are in the word table
860 IF NEW.admin_level = 2
861 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
862 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
864 PERFORM create_country(NEW.name, lower(NEW.country_code));
865 --DEBUG: RAISE WARNING 'Country names updated';
868 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
869 NEW.rank_search, NEW.address,
870 CASE WHEN NEW.rank_search >= 26
871 AND NEW.rank_search < 30
872 THEN NEW.geometry ELSE NEW.centroid END)
873 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
875 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
877 IF NEW.address is not null AND NEW.address ? 'postcode'
878 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
879 NEW.postcode := upper(trim(NEW.address->'postcode'));
882 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
883 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
886 -- if we have a name add this to the name search table
887 IF NEW.name IS NOT NULL THEN
889 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
890 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);
891 --DEBUG: RAISE WARNING 'added to location (full)';
894 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
895 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
896 --DEBUG: RAISE WARNING 'insert into road location table (full)';
899 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
900 NEW.rank_search, NEW.rank_address, NEW.geometry);
901 --DEBUG: RAISE WARNING 'added to search name (full)';
903 IF NOT %REVERSE-ONLY% THEN
904 INSERT INTO search_name (place_id, search_rank, address_rank,
905 importance, country_code, name_vector,
906 nameaddress_vector, centroid)
907 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
908 NEW.importance, NEW.country_code, name_vector,
909 nameaddress_vector, NEW.centroid);
914 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
922 CREATE OR REPLACE FUNCTION placex_delete()
929 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
931 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
932 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
933 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
934 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
936 IF OLD.rank_address < 30 THEN
938 -- mark everything linked to this place for re-indexing
939 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
940 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
941 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
943 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
944 DELETE FROM place_addressline where address_place_id = OLD.place_id;
946 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
947 b := deleteRoad(OLD.partition, OLD.place_id);
949 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
950 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
951 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
952 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
953 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
957 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
959 IF OLD.rank_address < 26 THEN
960 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
963 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
965 IF OLD.name is not null THEN
966 IF NOT %REVERSE-ONLY% THEN
967 DELETE from search_name WHERE place_id = OLD.place_id;
969 b := deleteSearchName(OLD.partition, OLD.place_id);
972 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
974 DELETE FROM place_addressline where place_id = OLD.place_id;
976 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
978 -- remove from tables for special search
979 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
980 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
982 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
985 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;