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;
255 CREATE OR REPLACE FUNCTION placex_insert()
263 country_code VARCHAR(2);
268 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
270 NEW.place_id := nextval('seq_place');
271 NEW.indexed_status := 1; --STATUS_NEW
273 NEW.country_code := lower(get_country_code(NEW.geometry));
275 NEW.partition := get_partition(NEW.country_code);
276 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
278 IF NEW.osm_type = 'X' THEN
279 -- E'X'ternal records should already be in the right format so do nothing
281 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
283 IF NEW.class in ('place','boundary')
284 AND NEW.type in ('postcode','postal_code') THEN
286 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
287 -- most likely just a part of a multipolygon postcode boundary, throw it away
291 NEW.name := hstore('ref', NEW.address->'postcode');
293 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
294 INTO NEW.rank_search, NEW.rank_address;
297 NEW.rank_address := 0;
299 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
301 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
302 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
304 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
305 NEW.rank_search = 30;
306 NEW.rank_address = 0;
307 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
308 NEW.rank_search = 30;
309 NEW.rank_address = 0;
311 -- do table lookup stuff
312 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
313 classtype = NEW.type || NEW.admin_level::TEXT;
315 classtype = NEW.type;
317 SELECT l.rank_search, l.rank_address FROM address_levels l
318 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
319 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
320 ORDER BY l.country_code, l.class, l.type LIMIT 1
321 INTO NEW.rank_search, NEW.rank_address;
323 IF NEW.rank_search is NULL THEN
324 NEW.rank_search := 30;
327 IF NEW.rank_address is NULL THEN
328 NEW.rank_address := 30;
332 -- some postcorrections
333 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
334 -- Slightly promote waterway relations so that they are processed
335 -- before their members.
336 NEW.rank_search := NEW.rank_search - 1;
339 IF (NEW.extratags -> 'capital') = 'yes' THEN
340 NEW.rank_search := NEW.rank_search - 1;
345 -- a country code make no sense below rank 4 (country)
346 IF NEW.rank_search < 4 THEN
347 NEW.country_code := NULL;
350 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
352 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
354 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
355 -- might be part of an interpolation
356 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
357 ELSEIF NEW.rank_address > 0 THEN
358 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
359 -- Performance: We just can't handle re-indexing for country level changes
360 IF st_area(NEW.geometry) < 1 THEN
361 -- mark items within the geometry for re-indexing
362 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
364 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
365 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
366 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'));
367 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
368 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'));
371 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
373 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
374 IF NEW.type='postcode' THEN
376 ELSEIF NEW.rank_search < 16 THEN
378 ELSEIF NEW.rank_search < 18 THEN
380 ELSEIF NEW.rank_search < 20 THEN
382 ELSEIF NEW.rank_search = 21 THEN
384 ELSEIF NEW.rank_search < 24 THEN
386 ELSEIF NEW.rank_search < 26 THEN
387 diameter := 0.002; -- 100 to 200 meters
388 ELSEIF NEW.rank_search < 28 THEN
389 diameter := 0.001; -- 50 to 100 meters
392 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
393 IF NEW.rank_search >= 26 THEN
394 -- roads may cause reparenting for >27 rank places
395 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
396 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
397 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
398 ELSEIF NEW.rank_search >= 16 THEN
399 -- up to rank 16, street-less addresses may need reparenting
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) and (rank_search < 28 or name is not null or address ? 'place');
402 -- for all other places the search terms may change as well
403 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);
410 -- add to tables for special search
411 -- Note: won't work on initial import because the classtype tables
412 -- do not yet exist. It won't hurt either.
413 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
414 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
416 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
417 USING NEW.place_id, ST_Centroid(NEW.geometry);
427 CREATE OR REPLACE FUNCTION placex_update()
431 search_maxdistance FLOAT[];
432 search_mindistance FLOAT[];
433 address_havelevel BOOLEAN[];
437 relation_members TEXT[];
439 search_diameter FLOAT;
440 search_prevdiameter FLOAT;
441 search_maxrank INTEGER;
442 address_maxrank INTEGER;
443 address_street_word_ids INTEGER[];
444 parent_place_id_rank BIGINT;
452 location_rank_search INTEGER;
453 location_distance FLOAT;
454 location_parent GEOMETRY;
455 location_isaddress BOOLEAN;
456 location_keywords INTEGER[];
458 name_vector INTEGER[];
459 nameaddress_vector INTEGER[];
461 linked_node_id BIGINT;
462 linked_importance FLOAT;
463 linked_wikipedia TEXT;
468 IF OLD.indexed_status = 100 THEN
469 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
470 delete from placex where place_id = OLD.place_id;
474 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
478 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
480 NEW.indexed_date = now();
482 IF NOT %REVERSE-ONLY% THEN
483 DELETE from search_name WHERE place_id = NEW.place_id;
485 result := deleteSearchName(NEW.partition, NEW.place_id);
486 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
487 result := deleteRoad(NEW.partition, NEW.place_id);
488 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
489 UPDATE placex set linked_place_id = null, indexed_status = 2
490 where linked_place_id = NEW.place_id;
491 -- update not necessary for osmline, cause linked_place_id does not exist
493 IF NEW.linked_place_id is not null THEN
494 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
498 --DEBUG: RAISE WARNING 'Copy over address tags';
499 -- housenumber is a computed field, so start with an empty value
500 NEW.housenumber := NULL;
501 IF NEW.address is not NULL THEN
502 IF NEW.address ? 'conscriptionnumber' THEN
503 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
504 IF NEW.address ? 'streetnumber' THEN
505 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
506 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
508 NEW.housenumber := NEW.address->'conscriptionnumber';
510 ELSEIF NEW.address ? 'streetnumber' THEN
511 NEW.housenumber := NEW.address->'streetnumber';
512 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
513 ELSEIF NEW.address ? 'housenumber' THEN
514 NEW.housenumber := NEW.address->'housenumber';
515 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
518 addr_street := NEW.address->'street';
519 addr_place := NEW.address->'place';
521 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
522 i := getorcreate_postcode_id(NEW.address->'postcode');
526 -- Speed up searches - just use the centroid of the feature
527 -- cheaper but less acurate
528 NEW.centroid := ST_PointOnSurface(NEW.geometry);
529 -- For searching near features rather use the centroid
530 NEW.postcode := null;
531 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
533 -- recalculate country and partition
534 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
535 -- for countries, believe the mapped country code,
536 -- so that we remain in the right partition if the boundaries
538 NEW.country_code := lower(NEW.address->'country');
539 NEW.partition := get_partition(lower(NEW.country_code));
540 IF NEW.partition = 0 THEN
541 NEW.country_code := lower(get_country_code(NEW.centroid));
542 NEW.partition := get_partition(NEW.country_code);
545 IF NEW.rank_search >= 4 THEN
546 NEW.country_code := lower(get_country_code(NEW.centroid));
548 NEW.country_code := NULL;
550 NEW.partition := get_partition(NEW.country_code);
552 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
554 -- waterway ways are linked when they are part of a relation and have the same class/type
555 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
556 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
558 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
559 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
560 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
561 FOR linked_node_id IN SELECT place_id FROM placex
562 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
563 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
564 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
566 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
571 --DEBUG: RAISE WARNING 'Waterway processed';
574 NEW.importance := null;
575 SELECT wikipedia, importance
576 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
577 INTO NEW.wikipedia,NEW.importance;
579 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
581 -- ---------------------------------------------------------------------------
582 -- For low level elements we inherit from our parent road
583 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
585 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
586 NEW.parent_place_id := null;
588 -- if we have a POI and there is no address information,
589 -- see if we can get it from a surrounding building
590 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
591 AND NEW.housenumber IS NULL THEN
593 -- The additional && condition works around the misguided query
594 -- planner of postgis 3.0.
595 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
596 and geometry && NEW.centroid
597 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
598 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
601 NEW.housenumber := location.address->'housenumber';
602 addr_street := location.address->'street';
603 addr_place := location.address->'place';
604 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
608 -- We have to find our parent road.
609 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
611 ST_Envelope(NEW.geometry),
612 addr_street, addr_place);
614 -- If we found the road take a shortcut here.
615 -- Otherwise fall back to the full address getting method below.
616 IF NEW.parent_place_id is not null THEN
618 -- Get the details of the parent road
619 SELECT p.country_code, p.postcode FROM placex p
620 WHERE p.place_id = NEW.parent_place_id INTO location;
622 NEW.country_code := location.country_code;
623 --DEBUG: RAISE WARNING 'Got parent details from search name';
625 -- determine postcode
626 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
627 NEW.postcode = upper(trim(NEW.address->'postcode'));
629 NEW.postcode := location.postcode;
631 IF NEW.postcode is null THEN
632 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
635 -- If there is no name it isn't searchable, don't bother to create a search record
636 IF NEW.name is NULL THEN
637 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
641 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
642 name_vector := make_keywords(NEW.name);
644 -- Performance, it would be more acurate to do all the rest of the import
645 -- process but it takes too long
646 -- Just be happy with inheriting from parent road only
647 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
648 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);
649 --DEBUG: RAISE WARNING 'Place added to location table';
652 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
653 NEW.rank_search, NEW.rank_address, NEW.geometry);
655 IF NOT %REVERSE-ONLY% THEN
656 -- Merge address from parent
657 SELECT array_merge(s.name_vector, s.nameaddress_vector)
658 INTO nameaddress_vector
660 WHERE s.place_id = NEW.parent_place_id;
662 INSERT INTO search_name (place_id, search_rank, address_rank,
663 importance, country_code, name_vector,
664 nameaddress_vector, centroid)
665 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
666 NEW.importance, NEW.country_code, name_vector,
667 nameaddress_vector, NEW.centroid);
668 --DEBUG: RAISE WARNING 'Place added to search table';
676 -- ---------------------------------------------------------------------------
678 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
679 SELECT * INTO location FROM find_linked_place(NEW);
680 IF location.place_id is not null THEN
681 --DEBUG: RAISE WARNING 'Linked %', location;
683 -- Use this as the centre point of the geometry
684 NEW.centroid := coalesce(location.centroid,
685 ST_Centroid(location.geometry));
687 -- merge in the label name
688 IF NOT location.name IS NULL THEN
689 NEW.name := location.name || NEW.name;
692 -- merge in extra tags
693 NEW.extratags := hstore(location.class, location.type)
694 || coalesce(location.extratags, ''::hstore)
695 || coalesce(NEW.extratags, ''::hstore);
697 -- mark the linked place (excludes from search results)
698 UPDATE placex set linked_place_id = NEW.place_id
699 WHERE place_id = location.place_id;
701 SELECT wikipedia, importance
702 FROM compute_importance(location.extratags, NEW.country_code,
703 'N', location.osm_id)
704 INTO linked_wikipedia,linked_importance;
706 -- Use the maximum importance if one could be computed from the linked object.
707 IF linked_importance is not null AND
708 (NEW.importance is null or NEW.importance < linked_importance)
710 NEW.importance = linked_importance;
714 -- What level are we searching from
715 search_maxrank := NEW.rank_search;
717 -- Initialise the name vector using our name
718 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
719 name_vector := make_keywords(NEW.name);
720 nameaddress_vector := '{}'::int[];
722 -- make sure all names are in the word table
723 IF NEW.admin_level = 2
724 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
725 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
727 PERFORM create_country(NEW.name, lower(NEW.country_code));
728 --DEBUG: RAISE WARNING 'Country names updated';
732 address_havelevel[i] := false;
735 NEW.parent_place_id = 0;
736 parent_place_id_rank = 0;
739 -- convert address store to array of tokenids
740 --DEBUG: RAISE WARNING 'Starting address search';
741 isin_tokens := '{}'::int[];
742 IF NEW.address IS NOT NULL THEN
743 FOR addr_item IN SELECT * FROM each(NEW.address)
745 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
746 'district', 'region', 'county', 'municipality',
747 'hamlet', 'village', 'subdistrict', 'town',
748 'neighbourhood', 'quarter', 'parish')
750 address_street_word_ids := word_ids_from_name(addr_item.value);
751 IF address_street_word_ids is not null THEN
752 isin_tokens := array_merge(isin_tokens, address_street_word_ids);
754 IF NOT %REVERSE-ONLY% THEN
755 address_street_word_ids := addr_ids_from_name(addr_item.value);
756 IF address_street_word_ids is not null THEN
757 nameaddress_vector := array_merge(nameaddress_vector,
758 address_street_word_ids);
762 IF addr_item.key = 'is_in' THEN
763 -- is_in items need splitting
764 isin := regexp_split_to_array(addr_item.value, E'[;,]');
765 IF array_upper(isin, 1) IS NOT NULL THEN
766 FOR i IN 1..array_upper(isin, 1) LOOP
767 address_street_word_ids := word_ids_from_name(isin[i]);
768 IF address_street_word_ids is not null THEN
769 isin_tokens := array_merge(isin_tokens, address_street_word_ids);
772 -- merge word into address vector
773 IF NOT %REVERSE-ONLY% THEN
774 address_street_word_ids := addr_ids_from_name(isin[i]);
775 IF address_street_word_ids is not null THEN
776 nameaddress_vector := array_merge(nameaddress_vector,
777 address_street_word_ids);
785 IF NOT %REVERSE-ONLY% THEN
786 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
789 -- RAISE WARNING 'ISIN: %', isin_tokens;
791 -- Process area matches
792 location_rank_search := 0;
793 location_distance := 0;
794 location_parent := NULL;
795 -- added ourself as address already
796 address_havelevel[NEW.rank_address] := true;
797 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, NEW.centroid, search_maxrank, isin_tokens;
799 SELECT * from getNearFeatures(NEW.partition,
800 CASE WHEN NEW.rank_search >= 26
801 AND NEW.rank_search < 30
803 ELSE NEW.centroid END,
804 search_maxrank, isin_tokens)
806 IF location.rank_address != location_rank_search THEN
807 location_rank_search := location.rank_address;
808 IF location.isguess THEN
809 location_distance := location.distance * 1.5;
811 IF location.rank_address <= 12 THEN
812 -- for county and above, if we have an area consider that exact
813 -- (It would be nice to relax the constraint for places close to
814 -- the boundary but we'd need the exact geometry for that. Too
816 location_distance = 0;
818 -- Below county level remain slightly fuzzy.
819 location_distance := location.distance * 0.5;
823 CONTINUE WHEN location.keywords <@ location_keywords;
826 IF location.distance < location_distance OR NOT location.isguess THEN
827 location_keywords := location.keywords;
829 location_isaddress := NOT address_havelevel[location.rank_address];
830 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
831 location_isaddress := ST_Contains(location_parent,location.centroid);
834 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
835 -- Add it to the list of search terms
836 IF NOT %REVERSE-ONLY% THEN
837 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
839 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
840 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
842 IF location_isaddress THEN
843 -- add postcode if we have one
844 -- (If multiple postcodes are available, we end up with the highest ranking one.)
845 IF location.postcode is not null THEN
846 NEW.postcode = location.postcode;
849 address_havelevel[location.rank_address] := true;
850 IF NOT location.isguess THEN
851 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
854 IF location.rank_address > parent_place_id_rank THEN
855 NEW.parent_place_id = location.place_id;
856 parent_place_id_rank = location.rank_address;
861 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
866 --DEBUG: RAISE WARNING 'address computed';
868 IF NEW.address is not null AND NEW.address ? 'postcode'
869 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
870 NEW.postcode := upper(trim(NEW.address->'postcode'));
873 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
874 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
877 -- if we have a name add this to the name search table
878 IF NEW.name IS NOT NULL THEN
880 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
881 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);
882 --DEBUG: RAISE WARNING 'added to location (full)';
885 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
886 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
887 --DEBUG: RAISE WARNING 'insert into road location table (full)';
890 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
891 NEW.rank_search, NEW.rank_address, NEW.geometry);
892 --DEBUG: RAISE WARNING 'added to search name (full)';
894 IF NOT %REVERSE-ONLY% THEN
895 INSERT INTO search_name (place_id, search_rank, address_rank,
896 importance, country_code, name_vector,
897 nameaddress_vector, centroid)
898 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
899 NEW.importance, NEW.country_code, name_vector,
900 nameaddress_vector, NEW.centroid);
905 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
913 CREATE OR REPLACE FUNCTION placex_delete()
920 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
922 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
923 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
924 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
925 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
927 IF OLD.rank_address < 30 THEN
929 -- mark everything linked to this place for re-indexing
930 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
931 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
932 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
934 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
935 DELETE FROM place_addressline where address_place_id = OLD.place_id;
937 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
938 b := deleteRoad(OLD.partition, OLD.place_id);
940 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
941 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
942 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
943 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
944 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
948 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
950 IF OLD.rank_address < 26 THEN
951 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
954 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
956 IF OLD.name is not null THEN
957 IF NOT %REVERSE-ONLY% THEN
958 DELETE from search_name WHERE place_id = OLD.place_id;
960 b := deleteSearchName(OLD.partition, OLD.place_id);
963 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
965 DELETE FROM place_addressline where place_id = OLD.place_id;
967 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
969 -- remove from tables for special search
970 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
971 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
973 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
976 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;