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;
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,
88 poi_partition, near_centroid);
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 && near_centroid 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 && near_centroid
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_place_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;
135 -- Still nothing, just use the nearest road
137 SELECT place_id FROM getNearestRoadFeature(poi_partition, near_centroid) INTO parent_place_id;
138 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
141 RETURN parent_place_id;
144 LANGUAGE plpgsql STABLE;
146 -- Try to find a linked place for the given object.
147 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
151 relation_members TEXT[];
153 linked_placex placex%ROWTYPE;
156 IF bnd.rank_search >= 26 or bnd.rank_address = 0
157 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
162 IF bnd.osm_type = 'R' THEN
163 -- see if we have any special relation members
164 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
165 --DEBUG: RAISE WARNING 'Got relation members';
167 -- Search for relation members with role 'lable'.
168 IF relation_members IS NOT NULL THEN
170 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
172 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
176 WHERE osm_type = 'N' and osm_id = rel_member.member
179 --DEBUG: RAISE WARNING 'Linked label member';
180 RETURN linked_placex;
187 IF bnd.name ? 'name' THEN
188 bnd_name := make_standard_name(bnd.name->'name');
189 IF bnd_name = '' THEN
194 -- Search for relation members with role admin_center.
195 IF bnd.osm_type = 'R' and bnd_name is not null
196 and relation_members is not null THEN
198 SELECT get_rel_node_members(relation_members,
199 ARRAY['admin_center','admin_centre']) as member
201 --DEBUG: RAISE WARNING 'Found admin_center member %', rel_member.member;
204 WHERE osm_type = 'N' and osm_id = rel_member.member
207 -- For an admin centre we also want a name match - still not perfect,
208 -- for example 'new york, new york'
209 -- But that can be fixed by explicitly setting the label in the data
210 IF bnd_name = make_standard_name(linked_placex.name->'name')
211 AND bnd.rank_address = linked_placex.rank_address
213 RETURN linked_placex;
215 --DEBUG: RAISE WARNING 'Linked admin_center';
220 -- Name searches can be done for ways as well as relations
221 IF bnd.osm_type in ('W','R') and bnd_name is not null THEN
222 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
224 SELECT placex.* from placex
225 WHERE make_standard_name(name->'name') = bnd_name
226 AND placex.rank_address = bnd.rank_address
227 AND placex.osm_type = 'N'
228 AND placex.rank_search < 26 -- needed to select the right index
229 AND st_covers(geometry, placex.geometry)
231 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
232 RETURN linked_placex;
239 LANGUAGE plpgsql STABLE;
241 CREATE OR REPLACE FUNCTION placex_insert()
249 country_code VARCHAR(2);
254 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
256 NEW.place_id := nextval('seq_place');
257 NEW.indexed_status := 1; --STATUS_NEW
259 NEW.country_code := lower(get_country_code(NEW.geometry));
261 NEW.partition := get_partition(NEW.country_code);
262 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
264 IF NEW.osm_type = 'X' THEN
265 -- E'X'ternal records should already be in the right format so do nothing
267 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
269 IF NEW.class in ('place','boundary')
270 AND NEW.type in ('postcode','postal_code') THEN
272 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
273 -- most likely just a part of a multipolygon postcode boundary, throw it away
277 NEW.name := hstore('ref', NEW.address->'postcode');
279 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
280 INTO NEW.rank_search, NEW.rank_address;
283 NEW.rank_address := 0;
285 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
287 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
288 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
290 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
291 NEW.rank_search = 30;
292 NEW.rank_address = 0;
293 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
294 NEW.rank_search = 30;
295 NEW.rank_address = 0;
297 -- do table lookup stuff
298 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
299 classtype = NEW.type || NEW.admin_level::TEXT;
301 classtype = NEW.type;
303 SELECT l.rank_search, l.rank_address FROM address_levels l
304 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
305 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
306 ORDER BY l.country_code, l.class, l.type LIMIT 1
307 INTO NEW.rank_search, NEW.rank_address;
309 IF NEW.rank_search is NULL THEN
310 NEW.rank_search := 30;
313 IF NEW.rank_address is NULL THEN
314 NEW.rank_address := 30;
318 -- some postcorrections
319 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
320 -- Slightly promote waterway relations so that they are processed
321 -- before their members.
322 NEW.rank_search := NEW.rank_search - 1;
325 IF (NEW.extratags -> 'capital') = 'yes' THEN
326 NEW.rank_search := NEW.rank_search - 1;
331 -- a country code make no sense below rank 4 (country)
332 IF NEW.rank_search < 4 THEN
333 NEW.country_code := NULL;
336 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
338 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
340 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
341 -- might be part of an interpolation
342 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
343 ELSEIF NEW.rank_address > 0 THEN
344 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
345 -- Performance: We just can't handle re-indexing for country level changes
346 IF st_area(NEW.geometry) < 1 THEN
347 -- mark items within the geometry for re-indexing
348 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
350 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
351 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
352 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'));
353 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
354 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'));
357 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
359 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
360 IF NEW.type='postcode' THEN
362 ELSEIF NEW.rank_search < 16 THEN
364 ELSEIF NEW.rank_search < 18 THEN
366 ELSEIF NEW.rank_search < 20 THEN
368 ELSEIF NEW.rank_search = 21 THEN
370 ELSEIF NEW.rank_search < 24 THEN
372 ELSEIF NEW.rank_search < 26 THEN
373 diameter := 0.002; -- 100 to 200 meters
374 ELSEIF NEW.rank_search < 28 THEN
375 diameter := 0.001; -- 50 to 100 meters
378 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
379 IF NEW.rank_search >= 26 THEN
380 -- roads may cause reparenting for >27 rank places
381 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
382 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
383 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
384 ELSEIF NEW.rank_search >= 16 THEN
385 -- up to rank 16, street-less addresses may need reparenting
386 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');
388 -- for all other places the search terms may change as well
389 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);
396 -- add to tables for special search
397 -- Note: won't work on initial import because the classtype tables
398 -- do not yet exist. It won't hurt either.
399 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
400 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
402 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
403 USING NEW.place_id, ST_Centroid(NEW.geometry);
413 CREATE OR REPLACE FUNCTION placex_update()
417 near_centroid GEOMETRY;
419 search_maxdistance FLOAT[];
420 search_mindistance FLOAT[];
421 address_havelevel BOOLEAN[];
425 relation_members TEXT[];
427 search_diameter FLOAT;
428 search_prevdiameter FLOAT;
429 search_maxrank INTEGER;
430 address_maxrank INTEGER;
431 address_street_word_ids INTEGER[];
432 parent_place_id_rank BIGINT;
440 location_rank_search INTEGER;
441 location_distance FLOAT;
442 location_parent GEOMETRY;
443 location_isaddress BOOLEAN;
444 location_keywords INTEGER[];
446 name_vector INTEGER[];
447 nameaddress_vector INTEGER[];
449 linked_node_id BIGINT;
450 linked_importance FLOAT;
451 linked_wikipedia TEXT;
456 IF OLD.indexed_status = 100 THEN
457 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
458 delete from placex where place_id = OLD.place_id;
462 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
466 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
468 NEW.indexed_date = now();
470 IF NOT %REVERSE-ONLY% THEN
471 DELETE from search_name WHERE place_id = NEW.place_id;
473 result := deleteSearchName(NEW.partition, NEW.place_id);
474 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
475 result := deleteRoad(NEW.partition, NEW.place_id);
476 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
477 UPDATE placex set linked_place_id = null, indexed_status = 2
478 where linked_place_id = NEW.place_id;
479 -- update not necessary for osmline, cause linked_place_id does not exist
481 IF NEW.linked_place_id is not null THEN
482 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
486 --DEBUG: RAISE WARNING 'Copy over address tags';
487 -- housenumber is a computed field, so start with an empty value
488 NEW.housenumber := NULL;
489 IF NEW.address is not NULL THEN
490 IF NEW.address ? 'conscriptionnumber' THEN
491 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
492 IF NEW.address ? 'streetnumber' THEN
493 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
494 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
496 NEW.housenumber := NEW.address->'conscriptionnumber';
498 ELSEIF NEW.address ? 'streetnumber' THEN
499 NEW.housenumber := NEW.address->'streetnumber';
500 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
501 ELSEIF NEW.address ? 'housenumber' THEN
502 NEW.housenumber := NEW.address->'housenumber';
503 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
506 addr_street := NEW.address->'street';
507 addr_place := NEW.address->'place';
509 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
510 i := getorcreate_postcode_id(NEW.address->'postcode');
514 -- Speed up searches - just use the centroid of the feature
515 -- cheaper but less acurate
516 NEW.centroid := ST_PointOnSurface(NEW.geometry);
517 -- For searching near features rather use the centroid
518 near_centroid := ST_Envelope(NEW.geometry);
519 NEW.postcode := null;
520 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
522 -- recalculate country and partition
523 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
524 -- for countries, believe the mapped country code,
525 -- so that we remain in the right partition if the boundaries
527 NEW.country_code := lower(NEW.address->'country');
528 NEW.partition := get_partition(lower(NEW.country_code));
529 IF NEW.partition = 0 THEN
530 NEW.country_code := lower(get_country_code(NEW.centroid));
531 NEW.partition := get_partition(NEW.country_code);
534 IF NEW.rank_search >= 4 THEN
535 NEW.country_code := lower(get_country_code(NEW.centroid));
537 NEW.country_code := NULL;
539 NEW.partition := get_partition(NEW.country_code);
541 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
543 -- waterway ways are linked when they are part of a relation and have the same class/type
544 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
545 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
547 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
548 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
549 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
550 FOR linked_node_id IN SELECT place_id FROM placex
551 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
552 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
553 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
555 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
560 --DEBUG: RAISE WARNING 'Waterway processed';
563 NEW.importance := null;
564 SELECT wikipedia, importance
565 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
566 INTO NEW.wikipedia,NEW.importance;
568 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
570 -- ---------------------------------------------------------------------------
571 -- For low level elements we inherit from our parent road
572 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
574 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
575 NEW.parent_place_id := null;
577 -- if we have a POI and there is no address information,
578 -- see if we can get it from a surrounding building
579 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
580 AND NEW.housenumber IS NULL THEN
582 -- The additional && condition works around the misguided query
583 -- planner of postgis 3.0.
584 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
585 and geometry && NEW.centroid
586 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
587 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
590 NEW.housenumber := location.address->'housenumber';
591 addr_street := location.address->'street';
592 addr_place := location.address->'place';
593 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
597 -- We have to find our parent road.
598 NEW.parent_place_id := find_parent_place_for_poi(NEW.osm_type, NEW.osm_id,
600 near_centroid, addr_street,
603 -- If we found the road take a shortcut here.
604 -- Otherwise fall back to the full address getting method below.
605 IF NEW.parent_place_id is not null THEN
607 -- Get the details of the parent road
608 SELECT p.country_code, p.postcode FROM placex p
609 WHERE p.place_id = NEW.parent_place_id INTO location;
611 NEW.country_code := location.country_code;
612 --DEBUG: RAISE WARNING 'Got parent details from search name';
614 -- determine postcode
615 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
616 NEW.postcode = upper(trim(NEW.address->'postcode'));
618 NEW.postcode := location.postcode;
620 IF NEW.postcode is null THEN
621 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
624 -- If there is no name it isn't searchable, don't bother to create a search record
625 IF NEW.name is NULL THEN
626 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
630 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
631 name_vector := make_keywords(NEW.name);
633 -- Performance, it would be more acurate to do all the rest of the import
634 -- process but it takes too long
635 -- Just be happy with inheriting from parent road only
636 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
637 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);
638 --DEBUG: RAISE WARNING 'Place added to location table';
641 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
642 NEW.rank_search, NEW.rank_address, NEW.geometry);
644 IF NOT %REVERSE-ONLY% THEN
645 -- Merge address from parent
646 SELECT array_merge(s.name_vector, s.nameaddress_vector)
647 INTO nameaddress_vector
649 WHERE s.place_id = NEW.parent_place_id;
651 INSERT INTO search_name (place_id, search_rank, address_rank,
652 importance, country_code, name_vector,
653 nameaddress_vector, centroid)
654 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
655 NEW.importance, NEW.country_code, name_vector,
656 nameaddress_vector, NEW.centroid);
657 --DEBUG: RAISE WARNING 'Place added to search table';
665 -- ---------------------------------------------------------------------------
667 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
668 SELECT * INTO location FROM find_linked_place(NEW);
669 IF location.place_id is not null THEN
670 --DEBUG: RAISE WARNING 'Linked %', location;
672 -- Use this as the centre point of the geometry
673 NEW.centroid := coalesce(location.centroid,
674 ST_Centroid(location.geometry));
676 -- merge in the label name
677 IF NOT location.name IS NULL THEN
678 NEW.name := location.name || NEW.name;
681 -- merge in extra tags
682 NEW.extratags := hstore(location.class, location.type)
683 || coalesce(location.extratags, ''::hstore)
684 || coalesce(NEW.extratags, ''::hstore);
686 -- mark the linked place (excludes from search results)
687 UPDATE placex set linked_place_id = NEW.place_id
688 WHERE place_id = location.place_id;
690 SELECT wikipedia, importance
691 FROM compute_importance(location.extratags, NEW.country_code,
692 'N', location.osm_id)
693 INTO linked_wikipedia,linked_importance;
695 -- Use the maximum importance if one could be computed from the linked object.
696 IF linked_importance is not null AND
697 (NEW.importance is null or NEW.importance < linked_importance)
699 NEW.importance = linked_importance;
703 -- What level are we searching from
704 search_maxrank := NEW.rank_search;
706 -- Initialise the name vector using our name
707 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
708 name_vector := make_keywords(NEW.name);
709 nameaddress_vector := '{}'::int[];
711 -- make sure all names are in the word table
712 IF NEW.admin_level = 2
713 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
714 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
716 PERFORM create_country(NEW.name, lower(NEW.country_code));
717 --DEBUG: RAISE WARNING 'Country names updated';
721 address_havelevel[i] := false;
724 NEW.parent_place_id = 0;
725 parent_place_id_rank = 0;
728 -- convert address store to array of tokenids
729 --DEBUG: RAISE WARNING 'Starting address search';
730 isin_tokens := '{}'::int[];
731 IF NEW.address IS NOT NULL THEN
732 FOR addr_item IN SELECT * FROM each(NEW.address)
734 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
735 'district', 'region', 'county', 'municipality',
736 'hamlet', 'village', 'subdistrict', 'town',
737 'neighbourhood', 'quarter', 'parish')
739 address_street_word_ids := word_ids_from_name(addr_item.value);
740 IF address_street_word_ids is not null THEN
741 isin_tokens := array_merge(isin_tokens, address_street_word_ids);
743 IF NOT %REVERSE-ONLY% THEN
744 address_street_word_ids := addr_ids_from_name(addr_item.value);
745 IF address_street_word_ids is not null THEN
746 nameaddress_vector := array_merge(nameaddress_vector,
747 address_street_word_ids);
751 IF addr_item.key = 'is_in' THEN
752 -- is_in items need splitting
753 isin := regexp_split_to_array(addr_item.value, E'[;,]');
754 IF array_upper(isin, 1) IS NOT NULL THEN
755 FOR i IN 1..array_upper(isin, 1) LOOP
756 address_street_word_ids := word_ids_from_name(isin[i]);
757 IF address_street_word_ids is not null THEN
758 isin_tokens := array_merge(isin_tokens, address_street_word_ids);
761 -- merge word into address vector
762 IF NOT %REVERSE-ONLY% THEN
763 address_street_word_ids := addr_ids_from_name(isin[i]);
764 IF address_street_word_ids is not null THEN
765 nameaddress_vector := array_merge(nameaddress_vector,
766 address_street_word_ids);
774 IF NOT %REVERSE-ONLY% THEN
775 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
778 -- RAISE WARNING 'ISIN: %', isin_tokens;
780 -- Process area matches
781 location_rank_search := 0;
782 location_distance := 0;
783 location_parent := NULL;
784 -- added ourself as address already
785 address_havelevel[NEW.rank_address] := true;
786 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, NEW.centroid, search_maxrank, isin_tokens;
788 SELECT * from getNearFeatures(NEW.partition,
789 CASE WHEN NEW.rank_search >= 26
790 AND NEW.rank_search < 30
792 ELSE NEW.centroid END,
793 search_maxrank, isin_tokens)
795 IF location.rank_address != location_rank_search THEN
796 location_rank_search := location.rank_address;
797 IF location.isguess THEN
798 location_distance := location.distance * 1.5;
800 IF location.rank_address <= 12 THEN
801 -- for county and above, if we have an area consider that exact
802 -- (It would be nice to relax the constraint for places close to
803 -- the boundary but we'd need the exact geometry for that. Too
805 location_distance = 0;
807 -- Below county level remain slightly fuzzy.
808 location_distance := location.distance * 0.5;
812 CONTINUE WHEN location.keywords <@ location_keywords;
815 IF location.distance < location_distance OR NOT location.isguess THEN
816 location_keywords := location.keywords;
818 location_isaddress := NOT address_havelevel[location.rank_address];
819 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
820 location_isaddress := ST_Contains(location_parent,location.centroid);
823 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
824 -- Add it to the list of search terms
825 IF NOT %REVERSE-ONLY% THEN
826 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
828 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
829 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
831 IF location_isaddress THEN
832 -- add postcode if we have one
833 -- (If multiple postcodes are available, we end up with the highest ranking one.)
834 IF location.postcode is not null THEN
835 NEW.postcode = location.postcode;
838 address_havelevel[location.rank_address] := true;
839 IF NOT location.isguess THEN
840 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
843 IF location.rank_address > parent_place_id_rank THEN
844 NEW.parent_place_id = location.place_id;
845 parent_place_id_rank = location.rank_address;
850 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
855 --DEBUG: RAISE WARNING 'address computed';
857 IF NEW.address is not null AND NEW.address ? 'postcode'
858 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
859 NEW.postcode := upper(trim(NEW.address->'postcode'));
862 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
863 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
866 -- if we have a name add this to the name search table
867 IF NEW.name IS NOT NULL THEN
869 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
870 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);
871 --DEBUG: RAISE WARNING 'added to location (full)';
874 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
875 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
876 --DEBUG: RAISE WARNING 'insert into road location table (full)';
879 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
880 NEW.rank_search, NEW.rank_address, NEW.geometry);
881 --DEBUG: RAISE WARNING 'added to search name (full)';
883 IF NOT %REVERSE-ONLY% THEN
884 INSERT INTO search_name (place_id, search_rank, address_rank,
885 importance, country_code, name_vector,
886 nameaddress_vector, centroid)
887 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
888 NEW.importance, NEW.country_code, name_vector,
889 nameaddress_vector, NEW.centroid);
894 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
902 CREATE OR REPLACE FUNCTION placex_delete()
909 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
911 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
912 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
913 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
914 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
916 IF OLD.rank_address < 30 THEN
918 -- mark everything linked to this place for re-indexing
919 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
920 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
921 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
923 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
924 DELETE FROM place_addressline where address_place_id = OLD.place_id;
926 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
927 b := deleteRoad(OLD.partition, OLD.place_id);
929 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
930 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
931 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
932 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
933 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
937 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
939 IF OLD.rank_address < 26 THEN
940 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
943 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
945 IF OLD.name is not null THEN
946 IF NOT %REVERSE-ONLY% THEN
947 DELETE from search_name WHERE place_id = OLD.place_id;
949 b := deleteSearchName(OLD.partition, OLD.place_id);
952 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
954 DELETE FROM place_addressline where place_id = OLD.place_id;
956 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
958 -- remove from tables for special search
959 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
960 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
962 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
965 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;