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_place_for_poi(poi_osm_type CHAR(1),
51 poi_partition SMALLINT,
52 near_centroid GEOMETRY,
59 parent_place_id BIGINT DEFAULT NULL;
64 --DEBUG: RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;
66 -- Is this object part of an associatedStreet relation?
68 SELECT members FROM planet_osm_rels
69 WHERE parts @> ARRAY[poi_osm_id]
70 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
71 and tags @> ARRAY['associatedStreet']
73 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
74 IF location.members[i+1] = 'street' THEN
75 --DEBUG: RAISE WARNING 'node in relation %',relation;
77 SELECT place_id from placex
78 WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
80 and rank_search between 26 and 27
82 RETURN parent.place_id;
88 -- Check for addr:street attributes
89 -- Note that addr:street links can only be indexed, once the street itself is indexed
90 word_ids := word_ids_from_name(addr_street);
91 IF word_ids is not null THEN
93 FROM getNearestNamedRoadFeature(poi_partition, near_centroid, word_ids)
95 IF parent_place_id is not null THEN
96 --DEBUG: RAISE WARNING 'Get parent form addr:street: %', parent.place_id;
97 RETURN parent_place_id;
101 -- Check for addr:place attributes.
102 word_ids := word_ids_from_name(addr_place);
103 IF word_ids is not null THEN
105 FROM getNearestNamedPlaceFeature(poi_partition, near_centroid, word_ids)
106 INTO parent_place_id;
107 IF parent_place_id is not null THEN
108 --DEBUG: RAISE WARNING 'Get parent form addr:place: %', parent.place_id;
109 RETURN parent_place_id;
113 IF poi_osm_type = 'N' THEN
114 -- Is this node part of an interpolation?
116 SELECT q.parent_place_id
117 FROM location_property_osmline q, planet_osm_ways x
118 WHERE q.linegeo && near_centroid and x.id = q.osm_id
119 and poi_osm_id = any(x.nodes)
122 --DEBUG: RAISE WARNING 'Get parent from interpolation: %', parent.parent_place_id;
123 RETURN parent.parent_place_id;
126 -- Is this node part of any other way?
128 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
129 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
130 FROM placex p, planet_osm_ways w
131 WHERE p.osm_type = 'W' and p.rank_search >= 26
132 and p.geometry && near_centroid
133 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
135 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
137 -- Way IS a road then we are on it - that must be our road
138 IF location.rank_search < 28 THEN
139 --DEBUG: RAISE WARNING 'node in way that is a street %',location;
140 return location.place_id;
143 SELECT find_parent_place_for_poi('W', location.osm_id, poi_partition,
145 location.address->'street',
146 location.address->'place',
148 INTO parent_place_id;
149 IF parent_place_id is not null THEN
150 RETURN parent_place_id;
155 -- Still nothing, just use the nearest road
157 SELECT place_id FROM getNearestRoadFeature(poi_partition, near_centroid) INTO parent_place_id;
158 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
161 RETURN parent_place_id;
164 LANGUAGE plpgsql STABLE;
166 -- Try to find a linked place for the given object.
167 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
171 relation_members TEXT[];
173 linked_placex placex%ROWTYPE;
176 IF bnd.rank_search >= 26 or bnd.rank_address = 0
177 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
182 IF bnd.osm_type = 'R' THEN
183 -- see if we have any special relation members
184 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
185 --DEBUG: RAISE WARNING 'Got relation members';
187 -- Search for relation members with role 'lable'.
188 IF relation_members IS NOT NULL THEN
190 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
192 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
196 WHERE osm_type = 'N' and osm_id = rel_member.member
199 --DEBUG: RAISE WARNING 'Linked label member';
200 RETURN linked_placex;
207 IF bnd.name ? 'name' THEN
208 bnd_name := make_standard_name(bnd.name->'name');
209 IF bnd_name = '' THEN
214 -- Search for relation members with role admin_center.
215 IF bnd.osm_type = 'R' and bnd_name is not null
216 and relation_members is not null THEN
218 SELECT get_rel_node_members(relation_members,
219 ARRAY['admin_center','admin_centre']) as member
221 --DEBUG: RAISE WARNING 'Found admin_center member %', rel_member.member;
224 WHERE osm_type = 'N' and osm_id = rel_member.member
227 -- For an admin centre we also want a name match - still not perfect,
228 -- for example 'new york, new york'
229 -- But that can be fixed by explicitly setting the label in the data
230 IF bnd_name = make_standard_name(linked_placex.name->'name')
231 AND bnd.rank_address = linked_placex.rank_address
233 RETURN linked_placex;
235 --DEBUG: RAISE WARNING 'Linked admin_center';
240 -- Name searches can be done for ways as well as relations
241 IF bnd.osm_type in ('W','R') and bnd_name is not null THEN
242 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
244 SELECT placex.* from placex
245 WHERE make_standard_name(name->'name') = bnd_name
246 AND placex.rank_address = bnd.rank_address
247 AND placex.osm_type = 'N'
248 AND st_covers(geometry, placex.geometry)
250 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
251 RETURN linked_placex;
260 CREATE OR REPLACE FUNCTION placex_insert()
268 country_code VARCHAR(2);
273 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
275 NEW.place_id := nextval('seq_place');
276 NEW.indexed_status := 1; --STATUS_NEW
278 NEW.country_code := lower(get_country_code(NEW.geometry));
280 NEW.partition := get_partition(NEW.country_code);
281 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
283 IF NEW.osm_type = 'X' THEN
284 -- E'X'ternal records should already be in the right format so do nothing
286 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
288 IF NEW.class in ('place','boundary')
289 AND NEW.type in ('postcode','postal_code') THEN
291 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
292 -- most likely just a part of a multipolygon postcode boundary, throw it away
296 NEW.name := hstore('ref', NEW.address->'postcode');
298 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
299 INTO NEW.rank_search, NEW.rank_address;
302 NEW.rank_address := 0;
304 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
306 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
307 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
309 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
310 NEW.rank_search = 30;
311 NEW.rank_address = 0;
312 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
313 NEW.rank_search = 30;
314 NEW.rank_address = 0;
316 -- do table lookup stuff
317 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
318 classtype = NEW.type || NEW.admin_level::TEXT;
320 classtype = NEW.type;
322 SELECT l.rank_search, l.rank_address FROM address_levels l
323 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
324 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
325 ORDER BY l.country_code, l.class, l.type LIMIT 1
326 INTO NEW.rank_search, NEW.rank_address;
328 IF NEW.rank_search is NULL THEN
329 NEW.rank_search := 30;
332 IF NEW.rank_address is NULL THEN
333 NEW.rank_address := 30;
337 -- some postcorrections
338 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
339 -- Slightly promote waterway relations so that they are processed
340 -- before their members.
341 NEW.rank_search := NEW.rank_search - 1;
344 IF (NEW.extratags -> 'capital') = 'yes' THEN
345 NEW.rank_search := NEW.rank_search - 1;
350 -- a country code make no sense below rank 4 (country)
351 IF NEW.rank_search < 4 THEN
352 NEW.country_code := NULL;
355 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
357 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
359 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
360 -- might be part of an interpolation
361 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
362 ELSEIF NEW.rank_address > 0 THEN
363 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
364 -- Performance: We just can't handle re-indexing for country level changes
365 IF st_area(NEW.geometry) < 1 THEN
366 -- mark items within the geometry for re-indexing
367 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
369 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
370 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
371 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'));
372 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
373 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'));
376 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
378 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
379 IF NEW.type='postcode' THEN
381 ELSEIF NEW.rank_search < 16 THEN
383 ELSEIF NEW.rank_search < 18 THEN
385 ELSEIF NEW.rank_search < 20 THEN
387 ELSEIF NEW.rank_search = 21 THEN
389 ELSEIF NEW.rank_search < 24 THEN
391 ELSEIF NEW.rank_search < 26 THEN
392 diameter := 0.002; -- 100 to 200 meters
393 ELSEIF NEW.rank_search < 28 THEN
394 diameter := 0.001; -- 50 to 100 meters
397 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
398 IF NEW.rank_search >= 26 THEN
399 -- roads may cause reparenting for >27 rank places
400 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
401 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
402 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
403 ELSEIF NEW.rank_search >= 16 THEN
404 -- up to rank 16, street-less addresses may need reparenting
405 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');
407 -- for all other places the search terms may change as well
408 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);
415 -- add to tables for special search
416 -- Note: won't work on initial import because the classtype tables
417 -- do not yet exist. It won't hurt either.
418 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
419 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
421 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
422 USING NEW.place_id, ST_Centroid(NEW.geometry);
432 CREATE OR REPLACE FUNCTION placex_update()
437 near_centroid GEOMETRY;
439 search_maxdistance FLOAT[];
440 search_mindistance FLOAT[];
441 address_havelevel BOOLEAN[];
448 relation_members TEXT[];
450 search_diameter FLOAT;
451 search_prevdiameter FLOAT;
452 search_maxrank INTEGER;
453 address_maxrank INTEGER;
454 address_street_word_id INTEGER;
455 address_street_word_ids INTEGER[];
456 parent_place_id_rank BIGINT;
464 location_rank_search INTEGER;
465 location_distance FLOAT;
466 location_parent GEOMETRY;
467 location_isaddress BOOLEAN;
468 location_keywords INTEGER[];
470 name_vector INTEGER[];
471 nameaddress_vector INTEGER[];
473 linked_node_id BIGINT;
474 linked_importance FLOAT;
475 linked_wikipedia TEXT;
480 IF OLD.indexed_status = 100 THEN
481 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
482 delete from placex where place_id = OLD.place_id;
486 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
490 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
492 NEW.indexed_date = now();
494 IF NOT %REVERSE-ONLY% THEN
495 DELETE from search_name WHERE place_id = NEW.place_id;
497 result := deleteSearchName(NEW.partition, NEW.place_id);
498 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
499 result := deleteRoad(NEW.partition, NEW.place_id);
500 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
501 UPDATE placex set linked_place_id = null, indexed_status = 2
502 where linked_place_id = NEW.place_id;
503 -- update not necessary for osmline, cause linked_place_id does not exist
505 IF NEW.linked_place_id is not null THEN
506 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
510 --DEBUG: RAISE WARNING 'Copy over address tags';
511 -- housenumber is a computed field, so start with an empty value
512 NEW.housenumber := NULL;
513 IF NEW.address is not NULL THEN
514 IF NEW.address ? 'conscriptionnumber' THEN
515 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
516 IF NEW.address ? 'streetnumber' THEN
517 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
518 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
520 NEW.housenumber := NEW.address->'conscriptionnumber';
522 ELSEIF NEW.address ? 'streetnumber' THEN
523 NEW.housenumber := NEW.address->'streetnumber';
524 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
525 ELSEIF NEW.address ? 'housenumber' THEN
526 NEW.housenumber := NEW.address->'housenumber';
527 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
530 addr_street := NEW.address->'street';
531 addr_place := NEW.address->'place';
533 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
534 i := getorcreate_postcode_id(NEW.address->'postcode');
538 -- Speed up searches - just use the centroid of the feature
539 -- cheaper but less acurate
540 NEW.centroid := ST_PointOnSurface(NEW.geometry);
541 -- For searching near features rather use the centroid
542 near_centroid := ST_Envelope(NEW.geometry);
543 NEW.postcode := null;
544 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
546 -- recalculate country and partition
547 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
548 -- for countries, believe the mapped country code,
549 -- so that we remain in the right partition if the boundaries
551 NEW.country_code := lower(NEW.address->'country');
552 NEW.partition := get_partition(lower(NEW.country_code));
553 IF NEW.partition = 0 THEN
554 NEW.country_code := lower(get_country_code(NEW.centroid));
555 NEW.partition := get_partition(NEW.country_code);
558 IF NEW.rank_search >= 4 THEN
559 NEW.country_code := lower(get_country_code(NEW.centroid));
561 NEW.country_code := NULL;
563 NEW.partition := get_partition(NEW.country_code);
565 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
567 -- waterway ways are linked when they are part of a relation and have the same class/type
568 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
569 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
571 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
572 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
573 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
574 FOR linked_node_id IN SELECT place_id FROM placex
575 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
576 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
577 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
579 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
584 --DEBUG: RAISE WARNING 'Waterway processed';
587 NEW.importance := null;
588 SELECT wikipedia, importance
589 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
590 INTO NEW.wikipedia,NEW.importance;
592 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
594 -- ---------------------------------------------------------------------------
595 -- For low level elements we inherit from our parent road
596 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
598 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
599 NEW.parent_place_id := null;
601 -- if we have a POI and there is no address information,
602 -- see if we can get it from a surrounding building
603 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
604 AND NEW.housenumber IS NULL THEN
606 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
607 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
608 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
611 NEW.housenumber := location.address->'housenumber';
612 addr_street := location.address->'street';
613 addr_place := location.address->'place';
614 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
618 -- We have to find our parent road.
619 NEW.parent_place_id := find_parent_place_for_poi(NEW.osm_type, NEW.osm_id,
621 near_centroid, addr_street,
624 -- If we found the road take a shortcut here.
625 -- Otherwise fall back to the full address getting method below.
626 IF NEW.parent_place_id is not null THEN
628 -- Get the details of the parent road
629 SELECT p.country_code, p.postcode FROM placex p
630 WHERE p.place_id = NEW.parent_place_id INTO location;
632 NEW.country_code := location.country_code;
633 --DEBUG: RAISE WARNING 'Got parent details from search name';
635 -- determine postcode
636 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
637 NEW.postcode = upper(trim(NEW.address->'postcode'));
639 NEW.postcode := location.postcode;
641 IF NEW.postcode is null THEN
642 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
645 -- If there is no name it isn't searchable, don't bother to create a search record
646 IF NEW.name is NULL THEN
647 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
651 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
652 name_vector := make_keywords(NEW.name);
654 -- Performance, it would be more acurate to do all the rest of the import
655 -- process but it takes too long
656 -- Just be happy with inheriting from parent road only
657 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
658 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);
659 --DEBUG: RAISE WARNING 'Place added to location table';
662 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
663 NEW.rank_search, NEW.rank_address, NEW.geometry);
665 IF NOT %REVERSE-ONLY% THEN
666 -- Merge address from parent
667 SELECT array_merge(s.name_vector, s.nameaddress_vector)
668 INTO nameaddress_vector
670 WHERE s.place_id = NEW.parent_place_id;
672 INSERT INTO search_name (place_id, search_rank, address_rank,
673 importance, country_code, name_vector,
674 nameaddress_vector, centroid)
675 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
676 NEW.importance, NEW.country_code, name_vector,
677 nameaddress_vector, NEW.centroid);
678 --DEBUG: RAISE WARNING 'Place added to search table';
686 -- ---------------------------------------------------------------------------
688 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
689 SELECT * INTO location FROM find_linked_place(NEW);
690 IF location.place_id is not null THEN
691 --DEBUG: RAISE WARNING 'Linked %', location;
693 -- Use this as the centre point of the geometry
694 NEW.centroid := coalesce(location.centroid,
695 ST_Centroid(location.geometry));
697 -- merge in the label name
698 IF NOT location.name IS NULL THEN
699 NEW.name := location.name || NEW.name;
702 -- merge in extra tags
703 NEW.extratags := hstore(location.class, location.type)
704 || coalesce(location.extratags, ''::hstore)
705 || coalesce(NEW.extratags, ''::hstore);
707 -- mark the linked place (excludes from search results)
708 UPDATE placex set linked_place_id = NEW.place_id
709 WHERE place_id = location.place_id;
711 SELECT wikipedia, importance
712 FROM compute_importance(location.extratags, NEW.country_code,
713 'N', location.osm_id)
714 INTO linked_wikipedia,linked_importance;
716 -- Use the maximum importance if one could be computed from the linked object.
717 IF linked_importance is not null AND
718 (NEW.importance is null or NEW.importance < linked_importance)
720 NEW.importance = linked_importance;
724 -- What level are we searching from
725 search_maxrank := NEW.rank_search;
727 -- Initialise the name vector using our name
728 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
729 name_vector := make_keywords(NEW.name);
730 nameaddress_vector := '{}'::int[];
732 -- make sure all names are in the word table
733 IF NEW.admin_level = 2
734 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
735 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
737 PERFORM create_country(NEW.name, lower(NEW.country_code));
738 --DEBUG: RAISE WARNING 'Country names updated';
742 address_havelevel[i] := false;
745 NEW.parent_place_id = 0;
746 parent_place_id_rank = 0;
749 -- convert address store to array of tokenids
750 --DEBUG: RAISE WARNING 'Starting address search';
751 isin_tokens := '{}'::int[];
752 IF NEW.address IS NOT NULL THEN
753 FOR addr_item IN SELECT * FROM each(NEW.address)
755 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
756 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
757 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
758 isin_tokens := isin_tokens || address_street_word_id;
760 IF NOT %REVERSE-ONLY% THEN
761 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
762 IF address_street_word_id IS NOT NULL THEN
763 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
767 IF addr_item.key = 'is_in' THEN
768 -- is_in items need splitting
769 isin := regexp_split_to_array(addr_item.value, E'[;,]');
770 IF array_upper(isin, 1) IS NOT NULL THEN
771 FOR i IN 1..array_upper(isin, 1) LOOP
772 address_street_word_id := get_name_id(make_standard_name(isin[i]));
773 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
774 isin_tokens := isin_tokens || address_street_word_id;
777 -- merge word into address vector
778 IF NOT %REVERSE-ONLY% THEN
779 address_street_word_id := get_word_id(make_standard_name(isin[i]));
780 IF address_street_word_id IS NOT NULL THEN
781 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
789 IF NOT %REVERSE-ONLY% THEN
790 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
793 -- RAISE WARNING 'ISIN: %', isin_tokens;
795 -- Process area matches
796 location_rank_search := 0;
797 location_distance := 0;
798 location_parent := NULL;
799 -- added ourself as address already
800 address_havelevel[NEW.rank_address] := true;
801 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, NEW.centroid, search_maxrank, isin_tokens;
803 SELECT * from getNearFeatures(NEW.partition,
804 CASE WHEN NEW.rank_search >= 26
805 AND NEW.rank_search < 30
807 ELSE NEW.centroid END,
808 search_maxrank, isin_tokens)
810 IF location.rank_address != location_rank_search THEN
811 location_rank_search := location.rank_address;
812 IF location.isguess THEN
813 location_distance := location.distance * 1.5;
815 IF location.rank_address <= 12 THEN
816 -- for county and above, if we have an area consider that exact
817 -- (It would be nice to relax the constraint for places close to
818 -- the boundary but we'd need the exact geometry for that. Too
820 location_distance = 0;
822 -- Below county level remain slightly fuzzy.
823 location_distance := location.distance * 0.5;
827 CONTINUE WHEN location.keywords <@ location_keywords;
830 IF location.distance < location_distance OR NOT location.isguess THEN
831 location_keywords := location.keywords;
833 location_isaddress := NOT address_havelevel[location.rank_address];
834 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
835 location_isaddress := ST_Contains(location_parent,location.centroid);
838 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
839 -- Add it to the list of search terms
840 IF NOT %REVERSE-ONLY% THEN
841 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
843 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
844 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
846 IF location_isaddress THEN
847 -- add postcode if we have one
848 -- (If multiple postcodes are available, we end up with the highest ranking one.)
849 IF location.postcode is not null THEN
850 NEW.postcode = location.postcode;
853 address_havelevel[location.rank_address] := true;
854 IF NOT location.isguess THEN
855 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
858 IF location.rank_address > parent_place_id_rank THEN
859 NEW.parent_place_id = location.place_id;
860 parent_place_id_rank = location.rank_address;
865 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
870 --DEBUG: RAISE WARNING 'address computed';
872 IF NEW.address is not null AND NEW.address ? 'postcode'
873 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
874 NEW.postcode := upper(trim(NEW.address->'postcode'));
877 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
878 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
881 -- if we have a name add this to the name search table
882 IF NEW.name IS NOT NULL THEN
884 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
885 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);
886 --DEBUG: RAISE WARNING 'added to location (full)';
889 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
890 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
891 --DEBUG: RAISE WARNING 'insert into road location table (full)';
894 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
895 NEW.rank_search, NEW.rank_address, NEW.geometry);
896 --DEBUG: RAISE WARNING 'added to search name (full)';
898 IF NOT %REVERSE-ONLY% THEN
899 INSERT INTO search_name (place_id, search_rank, address_rank,
900 importance, country_code, name_vector,
901 nameaddress_vector, centroid)
902 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
903 NEW.importance, NEW.country_code, name_vector,
904 nameaddress_vector, NEW.centroid);
909 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
917 CREATE OR REPLACE FUNCTION placex_delete()
924 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
926 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
927 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
928 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
929 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
931 IF OLD.rank_address < 30 THEN
933 -- mark everything linked to this place for re-indexing
934 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
935 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
936 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
938 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
939 DELETE FROM place_addressline where address_place_id = OLD.place_id;
941 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
942 b := deleteRoad(OLD.partition, OLD.place_id);
944 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
945 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
946 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
947 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
948 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
952 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
954 IF OLD.rank_address < 26 THEN
955 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
958 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
960 IF OLD.name is not null THEN
961 IF NOT %REVERSE-ONLY% THEN
962 DELETE from search_name WHERE place_id = OLD.place_id;
964 b := deleteSearchName(OLD.partition, OLD.place_id);
967 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
969 DELETE FROM place_addressline where place_id = OLD.place_id;
971 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
973 -- remove from tables for special search
974 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
975 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
977 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
980 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;