1 -- Trigger functions for the placex table.
3 -- Find the parent road of a POI.
5 -- \returns Place ID of parent object or NULL if none
7 -- Copy data from linked items (POIs on ways, addr:street links, relations).
9 CREATE OR REPLACE FUNCTION find_parent_for_poi(poi_osm_type CHAR(1),
11 poi_partition SMALLINT,
19 parent_place_id BIGINT DEFAULT NULL;
23 --DEBUG: RAISE WARNING 'finding street for % %', poi_osm_type, poi_osm_id;
25 -- Is this object part of an associatedStreet relation?
27 SELECT members FROM planet_osm_rels
28 WHERE parts @> ARRAY[poi_osm_id]
29 and members @> ARRAY[lower(poi_osm_type) || poi_osm_id]
30 and tags @> ARRAY['associatedStreet']
32 FOR i IN 1..array_upper(location.members, 1) BY 2 LOOP
33 IF location.members[i+1] = 'street' THEN
34 --DEBUG: RAISE WARNING 'node in relation %',relation;
36 SELECT place_id from placex
37 WHERE osm_type = 'W' and osm_id = substring(location.members[i],2)::bigint
39 and rank_search between 26 and 27
41 RETURN parent.place_id;
47 parent_place_id := find_parent_for_address(addr_street, addr_place,
49 IF parent_place_id is not null THEN
50 RETURN parent_place_id;
53 IF poi_osm_type = 'N' THEN
54 -- Is this node part of an interpolation?
56 SELECT q.parent_place_id
57 FROM location_property_osmline q, planet_osm_ways x
58 WHERE q.linegeo && bbox and x.id = q.osm_id
59 and poi_osm_id = any(x.nodes)
62 --DEBUG: RAISE WARNING 'Get parent from interpolation: %', parent.parent_place_id;
63 RETURN parent.parent_place_id;
66 -- Is this node part of any other way?
68 SELECT p.place_id, p.osm_id, p.rank_search, p.address,
69 coalesce(p.centroid, ST_Centroid(p.geometry)) as centroid
70 FROM placex p, planet_osm_ways w
71 WHERE p.osm_type = 'W' and p.rank_search >= 26
72 and p.geometry && bbox
73 and w.id = p.osm_id and poi_osm_id = any(w.nodes)
75 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
77 -- Way IS a road then we are on it - that must be our road
78 IF location.rank_search < 28 THEN
79 --DEBUG: RAISE WARNING 'node in way that is a street %',location;
80 return location.place_id;
83 SELECT find_parent_for_poi('W', location.osm_id, poi_partition,
85 location.address->'street',
86 location.address->'place',
89 IF parent_place_id is not null THEN
90 RETURN parent_place_id;
96 IF ST_Area(bbox) < 0.01 THEN
97 -- for smaller features get the nearest road
98 SELECT getNearestRoadPlaceId(poi_partition, bbox) INTO parent_place_id;
99 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', parent_place_id;
101 -- for larger features simply find the area with the largest rank that
104 SELECT place_id FROM placex
105 WHERE bbox @ geometry AND _ST_Covers(geometry, ST_Centroid(bbox))
106 AND rank_search between 5 and 25
107 ORDER BY rank_search desc
109 RETURN location.place_id;
114 RETURN parent_place_id;
117 LANGUAGE plpgsql STABLE;
119 -- Try to find a linked place for the given object.
120 CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
124 relation_members TEXT[];
126 linked_placex placex%ROWTYPE;
129 IF bnd.rank_search >= 26 or bnd.rank_address = 0
130 or ST_GeometryType(bnd.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon')
135 IF bnd.osm_type = 'R' THEN
136 -- see if we have any special relation members
137 SELECT members FROM planet_osm_rels WHERE id = bnd.osm_id INTO relation_members;
138 --DEBUG: RAISE WARNING 'Got relation members';
140 -- Search for relation members with role 'lable'.
141 IF relation_members IS NOT NULL THEN
143 SELECT get_rel_node_members(relation_members, ARRAY['label']) as member
145 --DEBUG: RAISE WARNING 'Found label member %', rel_member.member;
149 WHERE osm_type = 'N' and osm_id = rel_member.member
152 --DEBUG: RAISE WARNING 'Linked label member';
153 RETURN linked_placex;
160 IF bnd.name ? 'name' THEN
161 bnd_name := make_standard_name(bnd.name->'name');
162 IF bnd_name = '' THEN
167 -- If extratags has a place tag, look for linked nodes by their place type.
168 -- Area and node still have to have the same name.
169 IF bnd.extratags ? 'place' and bnd_name is not null THEN
172 WHERE make_standard_name(name->'name') = bnd_name
173 AND placex.class = 'place' AND placex.type = bnd.extratags->'place'
174 AND placex.osm_type = 'N'
175 AND placex.rank_search < 26 -- needed to select the right index
176 AND _st_covers(bnd.geometry, placex.geometry)
178 --DEBUG: RAISE WARNING 'Found type-matching place node %', linked_placex.osm_id;
179 RETURN linked_placex;
183 IF bnd.extratags ? 'wikidata' THEN
186 WHERE placex.class = 'place' AND placex.osm_type = 'N'
187 AND placex.extratags ? 'wikidata' -- needed to select right index
188 AND placex.extratags->'wikidata' = bnd.extratags->'wikidata'
189 AND placex.rank_search < 26
190 AND _st_covers(bnd.geometry, placex.geometry)
191 ORDER BY make_standard_name(name->'name') = bnd_name desc
193 --DEBUG: RAISE WARNING 'Found wikidata-matching place node %', linked_placex.osm_id;
194 RETURN linked_placex;
198 -- Name searches can be done for ways as well as relations
199 IF bnd_name is not null THEN
200 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
202 SELECT placex.* from placex
203 WHERE make_standard_name(name->'name') = bnd_name
204 AND ((bnd.rank_address > 0 and placex.rank_address = bnd.rank_address)
205 OR (bnd.rank_address = 0 and placex.rank_search = bnd.rank_search))
206 AND placex.osm_type = 'N'
207 AND placex.rank_search < 26 -- needed to select the right index
208 AND _st_covers(bnd.geometry, placex.geometry)
210 --DEBUG: RAISE WARNING 'Found matching place node %', linked_placex.osm_id;
211 RETURN linked_placex;
218 LANGUAGE plpgsql STABLE;
221 -- Insert address of a place into the place_addressline table.
223 -- \param obj_place_id Place_id of the place to compute the address for.
224 -- \param partition Partition number where the place is in.
225 -- \param maxrank Rank of the place. All address features must have
226 -- a search rank lower than the given rank.
227 -- \param address Address terms for the place.
228 -- \param geoemtry Geometry to which the address objects should be close.
230 -- \retval parent_place_id Place_id of the address object that is the direct
232 -- \retval postcode Postcode computed from the address. This is the
233 -- addr:postcode of one of the address objects. If
234 -- more than one of has a postcode, the highest ranking
235 -- one is used. May be NULL.
236 -- \retval nameaddress_vector Search terms for the address. This is the sum
237 -- of name terms of all address objects.
238 CREATE OR REPLACE FUNCTION insert_addresslines(obj_place_id BIGINT,
243 OUT parent_place_id BIGINT,
245 OUT nameaddress_vector INT[])
248 current_rank_address INTEGER := 0;
249 location_distance FLOAT := 0;
250 location_parent GEOMETRY := NULL;
251 parent_place_id_rank SMALLINT := 0;
253 location_isaddress BOOLEAN;
255 address_havelevel BOOLEAN[];
256 location_keywords INT[];
264 parent_place_id := 0;
265 nameaddress_vector := '{}'::int[];
266 isin_tokens := '{}'::int[];
268 ---- convert address store to array of tokenids
269 IF address IS NOT NULL THEN
270 FOR addr_item IN SELECT * FROM each(address)
272 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province',
273 'district', 'region', 'county', 'municipality',
274 'hamlet', 'village', 'subdistrict', 'town',
275 'neighbourhood', 'quarter', 'parish')
277 isin_tokens := array_merge(isin_tokens,
278 word_ids_from_name(addr_item.value));
279 IF NOT %REVERSE-ONLY% THEN
280 nameaddress_vector := array_merge(nameaddress_vector,
281 addr_ids_from_name(addr_item.value));
286 IF address ? 'is_in' THEN
287 -- is_in items need splitting
288 isin := regexp_split_to_array(address->'is_in', E'[;,]');
289 IF array_upper(isin, 1) IS NOT NULL THEN
290 FOR i IN 1..array_upper(isin, 1) LOOP
291 isin_tokens := array_merge(isin_tokens,
292 word_ids_from_name(isin[i]));
294 -- merge word into address vector
295 IF NOT %REVERSE-ONLY% THEN
296 nameaddress_vector := array_merge(nameaddress_vector,
297 addr_ids_from_name(isin[i]));
303 IF NOT %REVERSE-ONLY% THEN
304 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
307 ---- now compute the address terms
309 address_havelevel[i] := false;
313 SELECT * FROM getNearFeatures(partition, geometry, maxrank, isin_tokens)
315 IF location.rank_address != current_rank_address THEN
316 current_rank_address := location.rank_address;
317 IF location.isguess THEN
318 location_distance := location.distance * 1.5;
320 IF location.rank_address <= 12 THEN
321 -- for county and above, if we have an area consider that exact
322 -- (It would be nice to relax the constraint for places close to
323 -- the boundary but we'd need the exact geometry for that. Too
325 location_distance = 0;
327 -- Below county level remain slightly fuzzy.
328 location_distance := location.distance * 0.5;
332 CONTINUE WHEN location.keywords <@ location_keywords;
335 IF location.distance < location_distance OR NOT location.isguess THEN
336 location_keywords := location.keywords;
338 location_isaddress := NOT address_havelevel[location.rank_address];
339 --DEBUG: RAISE WARNING 'should be address: %, is guess: %, rank: %', location_isaddress, location.isguess, location.rank_address;
340 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
341 location_isaddress := ST_Contains(location_parent, location.centroid);
344 --DEBUG: RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
345 -- Add it to the list of search terms
346 IF NOT %REVERSE-ONLY% THEN
347 nameaddress_vector := array_merge(nameaddress_vector,
348 location.keywords::integer[]);
351 INSERT INTO place_addressline (place_id, address_place_id, fromarea,
352 isaddress, distance, cached_rank_address)
353 VALUES (obj_place_id, location.place_id, true,
354 location_isaddress, location.distance, location.rank_address);
356 IF location_isaddress THEN
357 -- add postcode if we have one
358 -- (If multiple postcodes are available, we end up with the highest ranking one.)
359 IF location.postcode is not null THEN
360 postcode = location.postcode;
363 address_havelevel[location.rank_address] := true;
364 -- add a hack against postcode ranks
365 IF NOT location.isguess
366 AND location.rank_address != 11 AND location.rank_address != 5
368 SELECT p.geometry FROM placex p
369 WHERE p.place_id = location.place_id INTO location_parent;
372 IF location.rank_address > parent_place_id_rank THEN
373 parent_place_id = location.place_id;
374 parent_place_id_rank = location.rank_address;
385 CREATE OR REPLACE FUNCTION placex_insert()
392 country_code VARCHAR(2);
396 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
398 NEW.place_id := nextval('seq_place');
399 NEW.indexed_status := 1; --STATUS_NEW
401 NEW.country_code := lower(get_country_code(NEW.geometry));
403 NEW.partition := get_partition(NEW.country_code);
404 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
406 IF NEW.osm_type = 'X' THEN
407 -- E'X'ternal records should already be in the right format so do nothing
409 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
411 IF NEW.class in ('place','boundary')
412 AND NEW.type in ('postcode','postal_code')
414 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
415 -- most likely just a part of a multipolygon postcode boundary, throw it away
419 NEW.name := hstore('ref', NEW.address->'postcode');
421 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
423 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
424 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W'
429 SELECT * INTO NEW.rank_search, NEW.rank_address
430 FROM compute_place_rank(NEW.country_code,
431 CASE WHEN is_area THEN 'A' ELSE NEW.osm_type END,
432 NEW.class, NEW.type, NEW.admin_level,
433 (NEW.extratags->'capital') = 'yes',
434 NEW.address->'postcode');
436 -- a country code make no sense below rank 4 (country)
437 IF NEW.rank_search < 4 THEN
438 NEW.country_code := NULL;
443 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
445 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
447 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
448 -- might be part of an interpolation
449 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
450 ELSEIF NEW.rank_address > 0 THEN
451 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
452 -- Performance: We just can't handle re-indexing for country level changes
453 IF st_area(NEW.geometry) < 1 THEN
454 -- mark items within the geometry for re-indexing
455 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
457 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
458 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
459 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'));
460 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
461 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'));
464 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
465 diameter := update_place_diameter(NEW.rank_search);
467 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
468 IF NEW.rank_search >= 26 THEN
469 -- roads may cause reparenting for >27 rank places
470 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
471 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
472 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
473 ELSEIF NEW.rank_search >= 16 THEN
474 -- up to rank 16, street-less addresses may need reparenting
475 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');
477 -- for all other places the search terms may change as well
478 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);
485 -- add to tables for special search
486 -- Note: won't work on initial import because the classtype tables
487 -- do not yet exist. It won't hurt either.
488 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
489 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
491 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
492 USING NEW.place_id, ST_Centroid(NEW.geometry);
502 CREATE OR REPLACE FUNCTION placex_update()
508 relation_members TEXT[];
515 name_vector INTEGER[];
516 nameaddress_vector INTEGER[];
518 linked_node_id BIGINT;
519 linked_importance FLOAT;
520 linked_wikipedia TEXT;
525 IF OLD.indexed_status = 100 THEN
526 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
527 delete from placex where place_id = OLD.place_id;
531 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
535 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
537 NEW.indexed_date = now();
539 IF NOT %REVERSE-ONLY% THEN
540 DELETE from search_name WHERE place_id = NEW.place_id;
542 result := deleteSearchName(NEW.partition, NEW.place_id);
543 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
544 result := deleteRoad(NEW.partition, NEW.place_id);
545 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
546 UPDATE placex set linked_place_id = null, indexed_status = 2
547 where linked_place_id = NEW.place_id;
548 -- update not necessary for osmline, cause linked_place_id does not exist
550 IF NEW.linked_place_id is not null THEN
551 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
555 -- recompute the ranks, they might change when linking changes
556 SELECT * INTO NEW.rank_search, NEW.rank_address
557 FROM compute_place_rank(NEW.country_code,
558 CASE WHEN ST_GeometryType(NEW.geometry)
559 IN ('ST_Polygon','ST_MultiPolygon')
560 THEN 'A' ELSE NEW.osm_type END,
561 NEW.class, NEW.type, NEW.admin_level,
562 (NEW.extratags->'capital') = 'yes',
563 NEW.address->'postcode');
566 --DEBUG: RAISE WARNING 'Copy over address tags';
567 -- housenumber is a computed field, so start with an empty value
568 NEW.housenumber := NULL;
569 IF NEW.address is not NULL THEN
570 IF NEW.address ? 'conscriptionnumber' THEN
571 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
572 IF NEW.address ? 'streetnumber' THEN
573 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
574 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
576 NEW.housenumber := NEW.address->'conscriptionnumber';
578 ELSEIF NEW.address ? 'streetnumber' THEN
579 NEW.housenumber := NEW.address->'streetnumber';
580 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
581 ELSEIF NEW.address ? 'housenumber' THEN
582 NEW.housenumber := NEW.address->'housenumber';
583 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
586 addr_street := NEW.address->'street';
587 addr_place := NEW.address->'place';
589 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
590 i := getorcreate_postcode_id(NEW.address->'postcode');
594 -- Speed up searches - just use the centroid of the feature
595 -- cheaper but less acurate
596 NEW.centroid := ST_PointOnSurface(NEW.geometry);
597 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(NEW.centroid);
599 NEW.postcode := null;
601 -- recalculate country and partition
602 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
603 -- for countries, believe the mapped country code,
604 -- so that we remain in the right partition if the boundaries
606 NEW.country_code := lower(NEW.address->'country');
607 NEW.partition := get_partition(lower(NEW.country_code));
608 IF NEW.partition = 0 THEN
609 NEW.country_code := lower(get_country_code(NEW.centroid));
610 NEW.partition := get_partition(NEW.country_code);
613 IF NEW.rank_search >= 4 THEN
614 NEW.country_code := lower(get_country_code(NEW.centroid));
616 NEW.country_code := NULL;
618 NEW.partition := get_partition(NEW.country_code);
620 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
622 -- waterway ways are linked when they are part of a relation and have the same class/type
623 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
624 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
626 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
627 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
628 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
629 FOR linked_node_id IN SELECT place_id FROM placex
630 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
631 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
632 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
634 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
635 IF NOT %REVERSE-ONLY% THEN
636 DELETE FROM search_name WHERE place_id = linked_node_id;
642 --DEBUG: RAISE WARNING 'Waterway processed';
645 NEW.importance := null;
646 SELECT wikipedia, importance
647 FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
648 INTO NEW.wikipedia,NEW.importance;
650 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
652 -- ---------------------------------------------------------------------------
653 -- For low level elements we inherit from our parent road
654 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
656 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
657 NEW.parent_place_id := null;
659 -- if we have a POI and there is no address information,
660 -- see if we can get it from a surrounding building
661 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
662 AND NEW.housenumber IS NULL THEN
664 -- The additional && condition works around the misguided query
665 -- planner of postgis 3.0.
666 SELECT address from placex where ST_Covers(geometry, NEW.centroid)
667 and geometry && NEW.centroid
668 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
669 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
672 NEW.housenumber := location.address->'housenumber';
673 addr_street := location.address->'street';
674 addr_place := location.address->'place';
675 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
679 -- We have to find our parent road.
680 NEW.parent_place_id := find_parent_for_poi(NEW.osm_type, NEW.osm_id,
682 ST_Envelope(NEW.geometry),
683 addr_street, addr_place);
685 -- If we found the road take a shortcut here.
686 -- Otherwise fall back to the full address getting method below.
687 IF NEW.parent_place_id is not null THEN
689 -- Get the details of the parent road
690 SELECT p.country_code, p.postcode FROM placex p
691 WHERE p.place_id = NEW.parent_place_id INTO location;
693 NEW.country_code := location.country_code;
694 --DEBUG: RAISE WARNING 'Got parent details from search name';
696 -- determine postcode
697 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
698 NEW.postcode = upper(trim(NEW.address->'postcode'));
700 NEW.postcode := location.postcode;
702 IF NEW.postcode is null THEN
703 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
706 -- If there is no name it isn't searchable, don't bother to create a search record
707 IF NEW.name is NULL THEN
708 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
712 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
713 name_vector := make_keywords(NEW.name);
715 -- Performance, it would be more acurate to do all the rest of the import
716 -- process but it takes too long
717 -- Just be happy with inheriting from parent road only
718 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
719 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);
720 --DEBUG: RAISE WARNING 'Place added to location table';
723 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
724 NEW.rank_search, NEW.rank_address, NEW.geometry);
726 IF NOT %REVERSE-ONLY% THEN
727 -- Merge address from parent
728 SELECT array_merge(s.name_vector, s.nameaddress_vector)
729 INTO nameaddress_vector
731 WHERE s.place_id = NEW.parent_place_id;
733 INSERT INTO search_name (place_id, search_rank, address_rank,
734 importance, country_code, name_vector,
735 nameaddress_vector, centroid)
736 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
737 NEW.importance, NEW.country_code, name_vector,
738 nameaddress_vector, NEW.centroid);
739 --DEBUG: RAISE WARNING 'Place added to search table';
747 -- ---------------------------------------------------------------------------
749 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
750 SELECT * INTO location FROM find_linked_place(NEW);
751 IF location.place_id is not null THEN
752 --DEBUG: RAISE WARNING 'Linked %', location;
754 -- Use the linked point as the centre point of the geometry,
755 -- but only if it is within the area of the boundary.
756 centroid := coalesce(location.centroid, ST_Centroid(location.geometry));
757 IF centroid is not NULL AND ST_Within(centroid, NEW.geometry) THEN
758 NEW.centroid := centroid;
761 -- Use the address rank of the linked place, if it has one
762 IF location.rank_address between 5 and 25 THEN
763 NEW.rank_address := location.rank_address;
766 -- merge in the label name
767 IF NOT location.name IS NULL THEN
768 NEW.name := location.name || NEW.name;
771 -- merge in extra tags
772 NEW.extratags := hstore('linked_' || location.class, location.type)
773 || coalesce(location.extratags, ''::hstore)
774 || coalesce(NEW.extratags, ''::hstore);
776 -- mark the linked place (excludes from search results)
777 UPDATE placex set linked_place_id = NEW.place_id
778 WHERE place_id = location.place_id;
779 -- ensure that those places are not found anymore
780 IF NOT %REVERSE-ONLY% THEN
781 DELETE FROM search_name WHERE place_id = location.place_id;
784 SELECT wikipedia, importance
785 FROM compute_importance(location.extratags, NEW.country_code,
786 'N', location.osm_id)
787 INTO linked_wikipedia,linked_importance;
789 -- Use the maximum importance if one could be computed from the linked object.
790 IF linked_importance is not null AND
791 (NEW.importance is null or NEW.importance < linked_importance)
793 NEW.importance = linked_importance;
797 -- Initialise the name vector using our name
798 NEW.name := add_default_place_name(NEW.country_code, NEW.name);
799 name_vector := make_keywords(NEW.name);
801 -- make sure all names are in the word table
802 IF NEW.admin_level = 2
803 AND NEW.class = 'boundary' AND NEW.type = 'administrative'
804 AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R'
806 PERFORM create_country(NEW.name, lower(NEW.country_code));
807 --DEBUG: RAISE WARNING 'Country names updated';
810 SELECT * FROM insert_addresslines(NEW.place_id, NEW.partition,
811 NEW.rank_search, NEW.address,
812 CASE WHEN NEW.rank_search >= 26
813 AND NEW.rank_search < 30
814 THEN NEW.geometry ELSE NEW.centroid END)
815 INTO NEW.parent_place_id, NEW.postcode, nameaddress_vector;
817 --DEBUG: RAISE WARNING 'RETURN insert_addresslines: %, %, %', NEW.parent_place_id, NEW.postcode, nameaddress_vector;
819 IF NEW.address is not null AND NEW.address ? 'postcode'
820 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
821 NEW.postcode := upper(trim(NEW.address->'postcode'));
824 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
825 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
828 -- if we have a name add this to the name search table
829 IF NEW.name IS NOT NULL THEN
831 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
832 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);
833 --DEBUG: RAISE WARNING 'added to location (full)';
836 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
837 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
838 --DEBUG: RAISE WARNING 'insert into road location table (full)';
841 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
842 NEW.rank_search, NEW.rank_address, NEW.geometry);
843 --DEBUG: RAISE WARNING 'added to search name (full)';
845 IF NOT %REVERSE-ONLY% THEN
846 INSERT INTO search_name (place_id, search_rank, address_rank,
847 importance, country_code, name_vector,
848 nameaddress_vector, centroid)
849 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
850 NEW.importance, NEW.country_code, name_vector,
851 nameaddress_vector, NEW.centroid);
856 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
864 CREATE OR REPLACE FUNCTION placex_delete()
871 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
873 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
874 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
875 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
876 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
878 IF OLD.rank_address < 30 THEN
880 -- mark everything linked to this place for re-indexing
881 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
882 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
883 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
885 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
886 DELETE FROM place_addressline where address_place_id = OLD.place_id;
888 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
889 b := deleteRoad(OLD.partition, OLD.place_id);
891 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
892 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
893 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
894 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
895 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
899 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
901 IF OLD.rank_address < 26 THEN
902 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
905 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
907 IF OLD.name is not null THEN
908 IF NOT %REVERSE-ONLY% THEN
909 DELETE from search_name WHERE place_id = OLD.place_id;
911 b := deleteSearchName(OLD.partition, OLD.place_id);
914 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
916 DELETE FROM place_addressline where place_id = OLD.place_id;
918 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
920 -- remove from tables for special search
921 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
922 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
924 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
927 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;