1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := public.gettokenstring(public.transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
259 CREATE OR REPLACE FUNCTION reverse_place_diameter(rank_search SMALLINT)
263 IF rank_search <= 4 THEN
265 ELSIF rank_search <= 8 THEN
267 ELSIF rank_search <= 12 THEN
269 ELSIF rank_search <= 17 THEN
271 ELSIF rank_search <= 18 THEN
273 ELSIF rank_search <= 19 THEN
280 LANGUAGE plpgsql IMMUTABLE;
282 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
283 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
290 postcode := upper(postcode);
292 IF country_code = 'gb' THEN
293 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
296 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
299 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
304 ELSEIF country_code = 'sg' THEN
305 IF postcode ~ '^([0-9]{6})$' THEN
310 ELSEIF country_code = 'de' THEN
311 IF postcode ~ '^([0-9]{5})$' THEN
317 -- Guess at the postcode format and coverage (!)
318 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
322 -- Does it look splitable into and area and local code?
323 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
325 IF part IS NOT NULL THEN
328 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
337 LANGUAGE plpgsql IMMUTABLE;
339 -- Find the nearest artificial postcode for the given geometry.
340 -- TODO For areas there should not be more than two inside the geometry.
341 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
347 -- If the geometry is an area then only one postcode must be within
348 -- that area, otherwise consider the area as not having a postcode.
349 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
350 SELECT min(postcode), count(*) FROM
351 (SELECT postcode FROM location_postcode
352 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
362 SELECT postcode FROM location_postcode
363 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
364 AND location_postcode.country_code = country
365 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
374 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
383 FOR item IN SELECT (each(src)).* LOOP
385 s := make_standard_name(item.value);
386 w := getorcreate_country(s, lookup_country_code);
388 words := regexp_split_to_array(item.value, E'[,;()]');
389 IF array_upper(words, 1) != 1 THEN
390 FOR j IN 1..array_upper(words, 1) LOOP
391 s := make_standard_name(words[j]);
393 w := getorcreate_country(s, lookup_country_code);
402 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
412 result := '{}'::INTEGER[];
414 FOR item IN SELECT (each(src)).* LOOP
416 s := make_standard_name(item.value);
418 w := getorcreate_name_id(s, item.value);
420 IF not(ARRAY[w] <@ result) THEN
421 result := result || w;
424 w := getorcreate_word_id(s);
426 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 words := string_to_array(s, ' ');
431 IF array_upper(words, 1) IS NOT NULL THEN
432 FOR j IN 1..array_upper(words, 1) LOOP
433 IF (words[j] != '') THEN
434 w = getorcreate_word_id(words[j]);
435 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
436 result := result || w;
442 words := regexp_split_to_array(item.value, E'[,;()]');
443 IF array_upper(words, 1) != 1 THEN
444 FOR j IN 1..array_upper(words, 1) LOOP
445 s := make_standard_name(words[j]);
447 w := getorcreate_word_id(s);
448 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
449 result := result || w;
455 s := regexp_replace(item.value, '市$', '');
456 IF s != item.value THEN
457 s := make_standard_name(s);
459 w := getorcreate_name_id(s, item.value);
460 IF NOT (ARRAY[w] <@ result) THEN
461 result := result || w;
471 LANGUAGE plpgsql IMMUTABLE;
473 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
483 result := '{}'::INTEGER[];
485 s := make_standard_name(src);
486 w := getorcreate_name_id(s, src);
488 IF NOT (ARRAY[w] <@ result) THEN
489 result := result || w;
492 w := getorcreate_word_id(s);
494 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
495 result := result || w;
498 words := string_to_array(s, ' ');
499 IF array_upper(words, 1) IS NOT NULL THEN
500 FOR j IN 1..array_upper(words, 1) LOOP
501 IF (words[j] != '') THEN
502 w = getorcreate_word_id(words[j]);
503 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
504 result := result || w;
510 words := regexp_split_to_array(src, E'[,;()]');
511 IF array_upper(words, 1) != 1 THEN
512 FOR j IN 1..array_upper(words, 1) LOOP
513 s := make_standard_name(words[j]);
515 w := getorcreate_word_id(s);
516 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
517 result := result || w;
523 s := regexp_replace(src, '市$', '');
525 s := make_standard_name(s);
527 w := getorcreate_name_id(s, src);
528 IF NOT (ARRAY[w] <@ result) THEN
529 result := result || w;
537 LANGUAGE plpgsql IMMUTABLE;
539 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
542 place_centre GEOMETRY;
545 place_centre := ST_PointOnSurface(place);
547 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
549 -- Try for a OSM polygon
550 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
552 RETURN nearcountry.country_code;
555 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
557 -- Try for OSM fallback data
558 -- The order is to deal with places like HongKong that are 'states' within another polygon
559 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
561 RETURN nearcountry.country_code;
564 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
567 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
569 RETURN nearcountry.country_code;
575 LANGUAGE plpgsql IMMUTABLE;
577 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
582 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
584 RETURN lower(nearcountry.country_default_language_code);
589 LANGUAGE plpgsql IMMUTABLE;
591 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
596 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
598 RETURN lower(nearcountry.country_default_language_codes);
603 LANGUAGE plpgsql IMMUTABLE;
605 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
610 FOR nearcountry IN select partition from country_name where country_code = in_country_code
612 RETURN nearcountry.partition;
617 LANGUAGE plpgsql IMMUTABLE;
619 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
623 DELETE FROM location_area where place_id = OLD_place_id;
624 -- TODO:location_area
630 CREATE OR REPLACE FUNCTION add_location(
632 country_code varchar(2),
636 rank_address INTEGER,
652 IF rank_search > 25 THEN
653 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
656 x := deleteLocationArea(partition, place_id, rank_search);
658 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
660 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
661 postcode := upper(trim (in_postcode));
664 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
665 centroid := ST_Centroid(geometry);
667 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
668 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
674 IF rank_address = 0 THEN
676 ELSEIF rank_search <= 14 THEN
678 ELSEIF rank_search <= 15 THEN
680 ELSEIF rank_search <= 16 THEN
682 ELSEIF rank_search <= 17 THEN
684 ELSEIF rank_search <= 21 THEN
686 ELSEIF rank_search = 25 THEN
690 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
692 secgeo := ST_Buffer(geometry, diameter);
693 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
703 -- find the parent road of the cut road parts
704 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
705 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
710 parent_place_id BIGINT;
711 address_street_word_ids INTEGER[];
717 addr_street = street;
720 IF addr_street is null and addr_place is null THEN
721 select nodes from planet_osm_ways where id = wayid INTO waynodes;
722 FOR location IN SELECT placex.address from placex
723 where osm_type = 'N' and osm_id = ANY(waynodes)
724 and placex.address is not null
725 and (placex.address ? 'street' or placex.address ? 'place')
726 and indexed_status < 100
728 addr_street = location.address->'street';
729 addr_place = location.address->'place';
733 IF addr_street IS NOT NULL THEN
734 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
735 IF address_street_word_ids IS NOT NULL THEN
736 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
737 parent_place_id := location.place_id;
742 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
743 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
744 IF address_street_word_ids IS NOT NULL THEN
745 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
746 parent_place_id := location.place_id;
751 IF parent_place_id is null THEN
752 FOR location IN SELECT place_id FROM placex
753 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
754 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
755 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
756 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
758 parent_place_id := location.place_id;
762 IF parent_place_id is null THEN
766 RETURN parent_place_id;
772 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
775 NEW.place_id := nextval('seq_place');
776 NEW.indexed_date := now();
778 IF NEW.indexed_status IS NULL THEN
779 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
780 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
781 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
785 NEW.indexed_status := 1; --STATUS_NEW
786 NEW.country_code := lower(get_country_code(NEW.linegeo));
788 NEW.partition := get_partition(NEW.country_code);
789 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
798 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
805 country_code VARCHAR(2);
806 default_language VARCHAR(10);
811 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
813 NEW.place_id := nextval('seq_place');
814 NEW.indexed_status := 1; --STATUS_NEW
816 NEW.country_code := lower(get_country_code(NEW.geometry));
818 NEW.partition := get_partition(NEW.country_code);
819 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
821 -- copy 'name' to or from the default language (if there is a default language)
822 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
823 default_language := get_country_language_code(NEW.country_code);
824 IF default_language IS NOT NULL THEN
825 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
826 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
827 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
828 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
833 IF NEW.osm_type = 'X' THEN
834 -- E'X'ternal records should already be in the right format so do nothing
836 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
838 IF NEW.class in ('place','boundary')
839 AND NEW.type in ('postcode','postal_code') THEN
841 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
842 -- most likely just a part of a multipolygon postcode boundary, throw it away
846 NEW.name := hstore('ref', NEW.address->'postcode');
848 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
849 INTO NEW.rank_search, NEW.rank_address;
852 NEW.rank_address := 0;
854 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
856 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
857 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
859 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
861 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
862 NEW.rank_search = 30;
863 NEW.rank_address = 0;
864 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
865 NEW.rank_search = 30;
866 NEW.rank_address = 0;
868 -- do table lookup stuff
869 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
870 classtype = NEW.type || NEW.admin_level::TEXT;
872 classtype = NEW.type;
874 SELECT l.rank_search, l.rank_address FROM address_levels l
875 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
876 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
877 ORDER BY l.country_code, l.class, l.type LIMIT 1
878 INTO NEW.rank_search, NEW.rank_address;
880 IF NEW.rank_search is NULL THEN
881 NEW.rank_search := 30;
884 IF NEW.rank_address is NULL THEN
885 NEW.rank_address := 30;
889 -- some postcorrections
890 IF NEW.class = 'place' THEN
891 IF NEW.type in ('continent', 'sea', 'country', 'state') AND NEW.osm_type = 'N' THEN
892 NEW.rank_address := 0;
894 ELSEIF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
895 -- Slightly promote waterway relations so that they are processed
896 -- before their members.
897 NEW.rank_search := NEW.rank_search - 1;
900 IF (NEW.extratags -> 'capital') = 'yes' THEN
901 NEW.rank_search := NEW.rank_search - 1;
906 -- a country code make no sense below rank 4 (country)
907 IF NEW.rank_search < 4 THEN
908 NEW.country_code := NULL;
911 -- Block import below rank 22
912 -- IF NEW.rank_search > 22 THEN
916 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
918 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
920 IF NEW.rank_address > 0 THEN
921 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
922 -- Performance: We just can't handle re-indexing for country level changes
923 IF st_area(NEW.geometry) < 1 THEN
924 -- mark items within the geometry for re-indexing
925 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
927 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
928 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
929 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'));
930 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
931 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'));
934 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
936 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
937 IF NEW.type='postcode' THEN
939 ELSEIF NEW.rank_search < 16 THEN
941 ELSEIF NEW.rank_search < 18 THEN
943 ELSEIF NEW.rank_search < 20 THEN
945 ELSEIF NEW.rank_search = 21 THEN
947 ELSEIF NEW.rank_search < 24 THEN
949 ELSEIF NEW.rank_search < 26 THEN
950 diameter := 0.002; -- 100 to 200 meters
951 ELSEIF NEW.rank_search < 28 THEN
952 diameter := 0.001; -- 50 to 100 meters
955 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
956 IF NEW.rank_search >= 26 THEN
957 -- roads may cause reparenting for >27 rank places
958 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
959 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
960 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
961 ELSEIF NEW.rank_search >= 16 THEN
962 -- up to rank 16, street-less addresses may need reparenting
963 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');
965 -- for all other places the search terms may change as well
966 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);
973 -- add to tables for special search
974 -- Note: won't work on initial import because the classtype tables
975 -- do not yet exist. It won't hurt either.
976 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
977 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
979 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
980 USING NEW.place_id, ST_Centroid(NEW.geometry);
989 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
993 place_centroid GEOMETRY;
1002 sectiongeo GEOMETRY;
1003 interpol_postcode TEXT;
1007 IF OLD.indexed_status = 100 THEN
1008 delete from location_property_osmline where place_id = OLD.place_id;
1012 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1016 NEW.interpolationtype = NEW.address->'interpolation';
1018 place_centroid := ST_PointOnSurface(NEW.linegeo);
1019 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1020 NEW.address->'place',
1021 NEW.partition, place_centroid, NEW.linegeo);
1023 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1024 interpol_postcode := NEW.address->'postcode';
1025 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1027 interpol_postcode := NULL;
1030 -- if the line was newly inserted, split the line as necessary
1031 IF OLD.indexed_status = 1 THEN
1032 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1034 IF array_upper(waynodes, 1) IS NULL THEN
1038 linegeo := NEW.linegeo;
1039 startnumber := NULL;
1041 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1043 select osm_id, address, geometry
1044 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1045 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1046 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1047 IF nextnode.osm_id IS NOT NULL THEN
1048 --RAISE NOTICE 'place_id is not null';
1049 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1050 -- Make sure that the point is actually on the line. That might
1051 -- be a bit paranoid but ensures that the algorithm still works
1052 -- should osm2pgsql attempt to repair geometries.
1053 splitline := split_line_on_node(linegeo, nextnode.geometry);
1054 sectiongeo := ST_GeometryN(splitline, 1);
1055 linegeo := ST_GeometryN(splitline, 2);
1057 sectiongeo = linegeo;
1059 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1061 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1062 AND startnumber != endnumber
1063 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1065 IF (startnumber > endnumber) THEN
1066 housenum := endnumber;
1067 endnumber := startnumber;
1068 startnumber := housenum;
1069 sectiongeo := ST_Reverse(sectiongeo);
1072 -- determine postcode
1073 postcode := coalesce(interpol_postcode,
1074 prevnode.address->'postcode',
1075 nextnode.address->'postcode',
1078 IF postcode is NULL THEN
1079 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1081 IF postcode is NULL THEN
1082 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1085 IF NEW.startnumber IS NULL THEN
1086 NEW.startnumber := startnumber;
1087 NEW.endnumber := endnumber;
1088 NEW.linegeo := sectiongeo;
1089 NEW.postcode := upper(trim(postcode));
1091 insert into location_property_osmline
1092 (linegeo, partition, osm_id, parent_place_id,
1093 startnumber, endnumber, interpolationtype,
1094 address, postcode, country_code,
1095 geometry_sector, indexed_status)
1096 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1097 startnumber, endnumber, NEW.interpolationtype,
1098 NEW.address, postcode,
1099 NEW.country_code, NEW.geometry_sector, 0);
1103 -- early break if we are out of line string,
1104 -- might happen when a line string loops back on itself
1105 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1109 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1110 prevnode := nextnode;
1115 -- marking descendants for reparenting is not needed, because there are
1116 -- actually no descendants for interpolation lines
1122 -- Trigger for updates of location_postcode
1124 -- Computes the parent object the postcode most likely refers to.
1125 -- This will be the place that determines the address displayed when
1126 -- searching for this postcode.
1127 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1134 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1138 NEW.indexed_date = now();
1140 partition := get_partition(NEW.country_code);
1142 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1143 INTO NEW.rank_search, NEW.rank_address;
1145 NEW.parent_place_id = 0;
1148 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1149 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1151 NEW.parent_place_id = location.place_id;
1159 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1164 place_centroid GEOMETRY;
1166 search_maxdistance FLOAT[];
1167 search_mindistance FLOAT[];
1168 address_havelevel BOOLEAN[];
1175 relation_members TEXT[];
1177 linkedplacex RECORD;
1179 search_diameter FLOAT;
1180 search_prevdiameter FLOAT;
1181 search_maxrank INTEGER;
1182 address_maxrank INTEGER;
1183 address_street_word_id INTEGER;
1184 address_street_word_ids INTEGER[];
1185 parent_place_id_rank BIGINT;
1193 location_rank_search INTEGER;
1194 location_distance FLOAT;
1195 location_parent GEOMETRY;
1196 location_isaddress BOOLEAN;
1197 location_keywords INTEGER[];
1199 default_language TEXT;
1200 name_vector INTEGER[];
1201 nameaddress_vector INTEGER[];
1203 linked_node_id BIGINT;
1204 linked_importance FLOAT;
1205 linked_wikipedia TEXT;
1210 IF OLD.indexed_status = 100 THEN
1211 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1212 delete from placex where place_id = OLD.place_id;
1216 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1220 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1222 NEW.indexed_date = now();
1224 IF NOT %REVERSE-ONLY% THEN
1225 DELETE from search_name WHERE place_id = NEW.place_id;
1227 result := deleteSearchName(NEW.partition, NEW.place_id);
1228 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1229 result := deleteRoad(NEW.partition, NEW.place_id);
1230 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1231 UPDATE placex set linked_place_id = null, indexed_status = 2
1232 where linked_place_id = NEW.place_id;
1233 -- update not necessary for osmline, cause linked_place_id does not exist
1235 IF NEW.linked_place_id is not null THEN
1236 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1240 --DEBUG: RAISE WARNING 'Copy over address tags';
1241 IF NEW.address is not NULL THEN
1242 IF NEW.address ? 'conscriptionnumber' THEN
1243 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1244 IF NEW.address ? 'streetnumber' THEN
1245 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1246 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1248 NEW.housenumber := NEW.address->'conscriptionnumber';
1250 ELSEIF NEW.address ? 'streetnumber' THEN
1251 NEW.housenumber := NEW.address->'streetnumber';
1252 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1253 ELSEIF NEW.address ? 'housenumber' THEN
1254 NEW.housenumber := NEW.address->'housenumber';
1255 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1258 addr_street := NEW.address->'street';
1259 addr_place := NEW.address->'place';
1261 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1262 i := getorcreate_postcode_id(NEW.address->'postcode');
1266 -- Speed up searches - just use the centroid of the feature
1267 -- cheaper but less acurate
1268 place_centroid := ST_PointOnSurface(NEW.geometry);
1269 NEW.centroid := null;
1270 NEW.postcode := null;
1271 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1273 -- recalculate country and partition
1274 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1275 -- for countries, believe the mapped country code,
1276 -- so that we remain in the right partition if the boundaries
1278 NEW.country_code := lower(NEW.address->'country');
1279 NEW.partition := get_partition(lower(NEW.country_code));
1280 IF NEW.partition = 0 THEN
1281 NEW.country_code := lower(get_country_code(place_centroid));
1282 NEW.partition := get_partition(NEW.country_code);
1285 IF NEW.rank_search >= 4 THEN
1286 NEW.country_code := lower(get_country_code(place_centroid));
1288 NEW.country_code := NULL;
1290 NEW.partition := get_partition(NEW.country_code);
1292 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1294 -- waterway ways are linked when they are part of a relation and have the same class/type
1295 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1296 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1298 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1299 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1300 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1301 FOR linked_node_id IN SELECT place_id FROM placex
1302 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1303 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1304 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1306 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1311 --DEBUG: RAISE WARNING 'Waterway processed';
1314 -- Adding ourselves to the list simplifies address calculations later
1315 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1316 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1318 -- What level are we searching from
1319 search_maxrank := NEW.rank_search;
1321 -- Thought this wasn't needed but when we add new languages to the country_name table
1322 -- we need to update the existing names
1323 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1324 default_language := get_country_language_code(NEW.country_code);
1325 IF default_language IS NOT NULL THEN
1326 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1327 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1328 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1329 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1333 --DEBUG: RAISE WARNING 'Local names updated';
1335 -- Initialise the name vector using our name
1336 name_vector := make_keywords(NEW.name);
1337 nameaddress_vector := '{}'::int[];
1340 address_havelevel[i] := false;
1343 NEW.importance := null;
1344 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1345 IF NEW.importance IS NULL THEN
1346 select language||':'||title,importance from wikipedia_article where osm_type = NEW.osm_type and osm_id = NEW.osm_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
1349 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1351 -- ---------------------------------------------------------------------------
1352 -- For low level elements we inherit from our parent road
1353 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1355 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1357 -- We won't get a better centroid, besides these places are too small to care
1358 NEW.centroid := place_centroid;
1360 NEW.parent_place_id := null;
1362 -- if we have a POI and there is no address information,
1363 -- see if we can get it from a surrounding building
1364 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1365 AND NEW.housenumber IS NULL THEN
1366 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1367 and address is not null
1368 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1369 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1372 NEW.housenumber := location.address->'housenumber';
1373 addr_street := location.address->'street';
1374 addr_place := location.address->'place';
1375 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1379 -- We have to find our parent road.
1380 -- Copy data from linked items (points on ways, addr:street links, relations)
1382 -- Is this object part of a relation?
1383 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1385 -- At the moment we only process one type of relation - associatedStreet
1386 IF relation.tags @> ARRAY['associatedStreet'] THEN
1387 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1388 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1389 --RAISE WARNING 'node in relation %',relation;
1390 SELECT place_id from placex where osm_type = 'W'
1391 and osm_id = substring(relation.members[i],2,200)::bigint
1392 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1397 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1399 -- Note that addr:street links can only be indexed once the street itself is indexed
1400 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1401 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1402 IF address_street_word_ids IS NOT NULL THEN
1403 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1406 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1408 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1409 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1410 IF address_street_word_ids IS NOT NULL THEN
1411 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1414 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1416 -- Is this node part of an interpolation?
1417 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1418 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1419 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1420 LIMIT 1 INTO NEW.parent_place_id;
1422 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1424 -- Is this node part of a way?
1425 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1428 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1429 WHERE p.osm_type = 'W' and p.rank_search >= 26 and p.geometry && NEW.geometry and w.id = p.osm_id and NEW.osm_id = any(w.nodes)
1431 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1433 -- Way IS a road then we are on it - that must be our road
1434 IF location.rank_search < 28 THEN
1435 --RAISE WARNING 'node in way that is a street %',location;
1436 NEW.parent_place_id := location.place_id;
1439 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1441 -- If the way mentions a street or place address, try that for parenting.
1442 IF location.address is not null THEN
1443 IF location.address ? 'street' THEN
1444 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1445 IF address_street_word_ids IS NOT NULL THEN
1446 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1447 EXIT WHEN NEW.parent_place_id is not NULL;
1450 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1452 IF location.address ? 'place' THEN
1453 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1454 IF address_street_word_ids IS NOT NULL THEN
1455 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1456 EXIT WHEN NEW.parent_place_id is not NULL;
1459 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1462 -- Is the WAY part of a relation
1463 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1465 -- At the moment we only process one type of relation - associatedStreet
1466 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1467 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1468 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1469 --RAISE WARNING 'node in way that is in a relation %',relation;
1470 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1471 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1476 EXIT WHEN NEW.parent_place_id is not null;
1477 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1482 -- Still nothing, just use the nearest road
1483 IF NEW.parent_place_id IS NULL THEN
1484 SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) INTO NEW.parent_place_id;
1486 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1489 -- If we didn't find any road fallback to standard method
1490 IF NEW.parent_place_id IS NOT NULL THEN
1492 -- Get the details of the parent road
1493 SELECT p.country_code, p.postcode FROM placex p
1494 WHERE p.place_id = NEW.parent_place_id INTO location;
1496 NEW.country_code := location.country_code;
1497 --DEBUG: RAISE WARNING 'Got parent details from search name';
1499 -- determine postcode
1500 IF NEW.rank_search > 4 THEN
1501 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1502 NEW.postcode = upper(trim(NEW.address->'postcode'));
1504 NEW.postcode := location.postcode;
1506 IF NEW.postcode is null THEN
1507 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1511 -- If there is no name it isn't searchable, don't bother to create a search record
1512 IF NEW.name is NULL THEN
1513 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1517 -- Performance, it would be more acurate to do all the rest of the import
1518 -- process but it takes too long
1519 -- Just be happy with inheriting from parent road only
1520 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1521 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);
1522 --DEBUG: RAISE WARNING 'Place added to location table';
1525 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1526 NEW.rank_search, NEW.rank_address, NEW.geometry);
1528 IF NOT %REVERSE-ONLY% THEN
1529 -- Merge address from parent
1530 SELECT s.name_vector, s.nameaddress_vector FROM search_name s
1531 WHERE s.place_id = NEW.parent_place_id INTO location;
1533 nameaddress_vector := array_merge(nameaddress_vector,
1534 location.nameaddress_vector);
1535 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1537 INSERT INTO search_name (place_id, search_rank, address_rank,
1538 importance, country_code, name_vector,
1539 nameaddress_vector, centroid)
1540 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1541 NEW.importance, NEW.country_code, name_vector,
1542 nameaddress_vector, place_centroid);
1543 --DEBUG: RAISE WARNING 'Place added to search table';
1551 -- ---------------------------------------------------------------------------
1553 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1555 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1557 -- see if we have any special relation members
1558 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1559 --DEBUG: RAISE WARNING 'Got relation members';
1561 IF relation_members IS NOT NULL THEN
1562 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1563 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1565 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1566 and osm_id = substring(relMember.member,2,10000)::bigint
1567 and class = 'place' order by rank_search desc limit 1 LOOP
1569 -- If we don't already have one use this as the centre point of the geometry
1570 IF NEW.centroid IS NULL THEN
1571 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1574 -- merge in the label name, re-init word vector
1575 IF NOT linkedPlacex.name IS NULL THEN
1576 NEW.name := linkedPlacex.name || NEW.name;
1577 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1580 -- merge in extra tags
1581 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1583 -- mark the linked place (excludes from search results)
1584 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1586 -- keep a note of the node id in case we need it for wikipedia in a bit
1587 linked_node_id := linkedPlacex.osm_id;
1588 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1589 --DEBUG: RAISE WARNING 'Linked label member';
1594 IF NEW.centroid IS NULL THEN
1596 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1597 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1599 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1600 and osm_id = substring(relMember.member,2,10000)::bigint
1601 and class = 'place' order by rank_search desc limit 1 LOOP
1603 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1604 -- But that can be fixed by explicitly setting the label in the data
1605 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1606 AND NEW.rank_address = linkedPlacex.rank_address THEN
1608 -- If we don't already have one use this as the centre point of the geometry
1609 IF NEW.centroid IS NULL THEN
1610 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1613 -- merge in the name, re-init word vector
1614 IF NOT linkedPlacex.name IS NULL THEN
1615 NEW.name := linkedPlacex.name || NEW.name;
1616 name_vector := make_keywords(NEW.name);
1619 -- merge in extra tags
1620 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1622 -- mark the linked place (excludes from search results)
1623 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1625 -- keep a note of the node id in case we need it for wikipedia in a bit
1626 linked_node_id := linkedPlacex.osm_id;
1627 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1628 --DEBUG: RAISE WARNING 'Linked admin_center';
1640 -- Name searches can be done for ways as well as relations
1641 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1643 -- not found one yet? how about doing a name search
1644 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1646 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1647 FOR linkedPlacex IN select placex.* from placex WHERE
1648 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1649 AND placex.rank_address = NEW.rank_address
1650 AND placex.place_id != NEW.place_id
1651 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1652 AND st_covers(NEW.geometry, placex.geometry)
1654 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1655 -- If we don't already have one use this as the centre point of the geometry
1656 IF NEW.centroid IS NULL THEN
1657 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1660 -- merge in the name, re-init word vector
1661 NEW.name := linkedPlacex.name || NEW.name;
1662 name_vector := make_keywords(NEW.name);
1664 -- merge in extra tags
1665 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1667 -- mark the linked place (excludes from search results)
1668 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1670 -- keep a note of the node id in case we need it for wikipedia in a bit
1671 linked_node_id := linkedPlacex.osm_id;
1672 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1673 --DEBUG: RAISE WARNING 'Linked named place';
1677 IF NEW.centroid IS NOT NULL THEN
1678 place_centroid := NEW.centroid;
1679 -- Place might have had only a name tag before but has now received translations
1680 -- from the linked place. Make sure a name tag for the default language exists in
1682 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1683 default_language := get_country_language_code(NEW.country_code);
1684 IF default_language IS NOT NULL THEN
1685 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1686 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1687 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1688 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1692 --DEBUG: RAISE WARNING 'Names updated from linked places';
1695 -- Use the maximum importance if a one could be computed from the linked object.
1696 IF linked_importance is not null AND
1697 (NEW.importance is null or NEW.importance < linked_importance) THEN
1698 NEW.importance = linked_importance;
1701 -- Still null? how about looking it up by the node id
1702 IF NEW.importance IS NULL THEN
1703 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1704 select language||':'||title,importance from wikipedia_article where osm_type = 'N'::char(1) and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
1709 -- make sure all names are in the word table
1710 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R' THEN
1711 perform create_country(NEW.name, lower(NEW.country_code));
1712 --DEBUG: RAISE WARNING 'Country names updated';
1715 NEW.parent_place_id = 0;
1716 parent_place_id_rank = 0;
1719 -- convert address store to array of tokenids
1720 --DEBUG: RAISE WARNING 'Starting address search';
1721 isin_tokens := '{}'::int[];
1722 IF NEW.address IS NOT NULL THEN
1723 FOR addr_item IN SELECT * FROM each(NEW.address)
1725 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1726 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1727 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1728 isin_tokens := isin_tokens || address_street_word_id;
1730 IF NOT %REVERSE-ONLY% THEN
1731 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1732 IF address_street_word_id IS NOT NULL THEN
1733 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1737 IF addr_item.key = 'is_in' THEN
1738 -- is_in items need splitting
1739 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1740 IF array_upper(isin, 1) IS NOT NULL THEN
1741 FOR i IN 1..array_upper(isin, 1) LOOP
1742 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1743 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1744 isin_tokens := isin_tokens || address_street_word_id;
1747 -- merge word into address vector
1748 IF NOT %REVERSE-ONLY% THEN
1749 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1750 IF address_street_word_id IS NOT NULL THEN
1751 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1759 IF NOT %REVERSE-ONLY% THEN
1760 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1763 -- RAISE WARNING 'ISIN: %', isin_tokens;
1765 -- Process area matches
1766 location_rank_search := 0;
1767 location_distance := 0;
1768 location_parent := NULL;
1769 -- added ourself as address already
1770 address_havelevel[NEW.rank_address] := true;
1771 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1773 SELECT * from getNearFeatures(NEW.partition,
1774 CASE WHEN NEW.rank_search >= 26
1775 AND NEW.rank_search < 30
1777 ELSE place_centroid END,
1778 search_maxrank, isin_tokens)
1780 IF location.rank_address != location_rank_search THEN
1781 location_rank_search := location.rank_address;
1782 IF location.isguess THEN
1783 location_distance := location.distance * 1.5;
1785 IF location.rank_address <= 12 THEN
1786 -- for county and above, if we have an area consider that exact
1787 -- (It would be nice to relax the constraint for places close to
1788 -- the boundary but we'd need the exact geometry for that. Too
1790 location_distance = 0;
1792 -- Below county level remain slightly fuzzy.
1793 location_distance := location.distance * 0.5;
1797 CONTINUE WHEN location.keywords <@ location_keywords;
1800 IF location.distance < location_distance OR NOT location.isguess THEN
1801 location_keywords := location.keywords;
1803 location_isaddress := NOT address_havelevel[location.rank_address];
1804 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1805 location_isaddress := ST_Contains(location_parent,location.centroid);
1808 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1809 -- Add it to the list of search terms
1810 IF NOT %REVERSE-ONLY% AND location.rank_search > 4 THEN
1811 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1813 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1814 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1816 IF location_isaddress THEN
1817 -- add postcode if we have one
1818 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1819 IF location.postcode is not null THEN
1820 NEW.postcode = location.postcode;
1823 address_havelevel[location.rank_address] := true;
1824 IF NOT location.isguess THEN
1825 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1828 IF location.rank_address > parent_place_id_rank THEN
1829 NEW.parent_place_id = location.place_id;
1830 parent_place_id_rank = location.rank_address;
1835 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1840 --DEBUG: RAISE WARNING 'address computed';
1842 IF NEW.address is not null AND NEW.address ? 'postcode'
1843 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1844 NEW.postcode := upper(trim(NEW.address->'postcode'));
1847 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1848 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1851 -- if we have a name add this to the name search table
1852 IF NEW.name IS NOT NULL THEN
1854 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1855 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);
1856 --DEBUG: RAISE WARNING 'added to location (full)';
1859 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1860 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1861 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1864 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1865 NEW.rank_search, NEW.rank_address, NEW.geometry);
1866 --DEBUG: RAISE WARNING 'added to search name (full)';
1868 IF NOT %REVERSE-ONLY% THEN
1869 INSERT INTO search_name (place_id, search_rank, address_rank,
1870 importance, country_code, name_vector,
1871 nameaddress_vector, centroid)
1872 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1873 NEW.importance, NEW.country_code, name_vector,
1874 nameaddress_vector, place_centroid);
1879 -- If we've not managed to pick up a better one - default centroid
1880 IF NEW.centroid IS NULL THEN
1881 NEW.centroid := place_centroid;
1884 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1891 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1897 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1899 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1900 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1901 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1902 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1904 IF OLD.rank_address < 30 THEN
1906 -- mark everything linked to this place for re-indexing
1907 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1908 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1909 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1911 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1912 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1914 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1915 b := deleteRoad(OLD.partition, OLD.place_id);
1917 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1918 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1919 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1920 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1921 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1925 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1927 IF OLD.rank_address < 26 THEN
1928 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1931 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1933 IF OLD.name is not null THEN
1934 IF NOT %REVERSE-ONLY% THEN
1935 DELETE from search_name WHERE place_id = OLD.place_id;
1937 b := deleteSearchName(OLD.partition, OLD.place_id);
1940 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1942 DELETE FROM place_addressline where place_id = OLD.place_id;
1944 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1946 -- remove from tables for special search
1947 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1948 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1950 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1953 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1961 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1967 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1969 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1970 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1971 SELECT bool_or(not (rank_address = 0 or rank_address > 26)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
1973 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1979 UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1981 -- interpolations are special
1982 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1983 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1992 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1997 existingplacex RECORD;
1998 existingline RECORD;
1999 existinggeometry GEOMETRY;
2000 existingplace_id BIGINT;
2005 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2006 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2007 -- filter wrong tupels
2008 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
2009 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2010 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2011 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2015 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2016 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2017 -- Have we already done this place?
2018 select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
2020 -- Get the existing place_id
2021 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2023 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2024 IF existing.osm_type IS NULL THEN
2025 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2028 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2029 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2031 -- update method for interpolation lines: delete all old interpolation lines with same osm_id (update on place) and insert the new one(s) (they can be split up, if they have > 2 nodes)
2032 IF existingline.osm_id IS NOT NULL THEN
2033 delete from location_property_osmline where osm_id = NEW.osm_id;
2036 -- for interpolations invalidate all nodes on the line
2037 update placex p set indexed_status = 2
2038 from planet_osm_ways w
2039 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2042 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2043 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2046 IF existing.osm_type IS NULL THEN
2050 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2051 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2052 OR existing.geometry::text != NEW.geometry::text
2057 address = NEW.address,
2058 extratags = NEW.extratags,
2059 admin_level = NEW.admin_level,
2060 geometry = NEW.geometry
2061 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2066 ELSE -- insert to placex
2068 -- Patch in additional country names
2069 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2070 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2071 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2072 IF existing.name IS NOT NULL THEN
2073 NEW.name = existing.name || NEW.name;
2077 -- Have we already done this place?
2078 select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
2080 -- Get the existing place_id
2081 select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex;
2083 -- Handle a place changing type by removing the old data
2084 -- My generated 'place' types are causing havok because they overlap with real keys
2085 -- TODO: move them to their own special purpose key/class to avoid collisions
2086 IF existing.osm_type IS NULL THEN
2087 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2090 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2091 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2094 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2095 AND st_area(existing.geometry) > 0.02
2096 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2097 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2099 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2100 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2101 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2105 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2106 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2108 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2109 IF existingplacex.osm_type IS NULL OR
2110 (existingplacex.class = 'boundary' AND
2111 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2112 (existingplacex.type != NEW.type)))
2115 IF existingplacex.osm_type IS NOT NULL THEN
2116 -- sanity check: ignore admin_level changes on places with too many active children
2117 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2118 --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i;
2119 --LIMIT INDEXING: IF i > 100000 THEN
2120 --LIMIT INDEXING: RETURN null;
2121 --LIMIT INDEXING: END IF;
2124 IF existing.osm_type IS NOT NULL THEN
2125 -- pathological case caused by the triggerless copy into place during initial import
2126 -- force delete even for large areas, it will be reinserted later
2127 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2128 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2131 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2132 insert into placex (osm_type, osm_id, class, type, name,
2133 admin_level, address, extratags, geometry)
2134 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2135 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2137 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2142 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2143 IF existing.geometry::text != NEW.geometry::text
2144 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2145 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2148 -- Get the version of the geometry actually used (in placex table)
2149 select geometry from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type into existinggeometry;
2151 -- Performance limit
2152 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2154 -- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong
2155 update placex set indexed_status = 2 where indexed_status = 0 and
2156 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2157 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2158 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2160 update placex set indexed_status = 2 where indexed_status = 0 and
2161 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2162 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2163 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2170 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2171 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2172 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2173 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2174 OR existing.geometry::text != NEW.geometry::text
2179 address = NEW.address,
2180 extratags = NEW.extratags,
2181 admin_level = NEW.admin_level,
2182 geometry = NEW.geometry
2183 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2186 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2187 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2188 -- postcode was deleted, no longer retain in placex
2189 DELETE FROM placex where place_id = existingplacex.place_id;
2193 NEW.name := hstore('ref', NEW.address->'postcode');
2196 IF NEW.class in ('boundary')
2197 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2198 DELETE FROM placex where place_id = existingplacex.place_id;
2204 address = NEW.address,
2205 parent_place_id = null,
2206 extratags = NEW.extratags,
2207 admin_level = NEW.admin_level,
2209 geometry = NEW.geometry
2210 where place_id = existingplacex.place_id;
2212 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2213 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2214 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2215 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2216 update location_property_osmline p set indexed_status = 2 from planet_osm_ways w where p.linegeo && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes);
2219 -- linked places should get potential new naming and addresses
2220 IF existingplacex.linked_place_id is not NULL THEN
2223 extratags = p.extratags,
2226 where x.place_id = existingplacex.linked_place_id
2227 and x.indexed_status = 0
2228 and x.osm_type = p.osm_type
2229 and x.osm_id = p.osm_id
2230 and x.class = p.class;
2235 -- Abort the add (we modified the existing place instead)
2240 $$ LANGUAGE plpgsql;
2243 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2248 IF name is null THEN
2252 FOR j IN 1..array_upper(languagepref,1) LOOP
2253 IF name ? languagepref[j] THEN
2254 result := trim(name->languagepref[j]);
2255 IF result != '' THEN
2261 -- anything will do as a fallback - just take the first name type thing there is
2262 RETURN trim((avals(name))[1]);
2265 LANGUAGE plpgsql IMMUTABLE;
2267 --housenumber only needed for tiger data
2268 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2280 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2281 currresult := trim(get_name_by_language(location.name, languagepref));
2282 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2283 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2284 prevresult := currresult;
2288 RETURN array_to_string(result,', ');
2293 DROP TYPE IF EXISTS addressline CASCADE;
2294 create type addressline as (
2301 admin_level INTEGER,
2304 rank_address INTEGER,
2308 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2311 for_place_id BIGINT;
2316 countrylocation RECORD;
2317 searchcountrycode varchar(2);
2318 searchhousenumber TEXT;
2319 searchhousename HSTORE;
2320 searchrankaddress INTEGER;
2321 searchpostcode TEXT;
2327 -- first query osmline (interpolation lines)
2328 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2329 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2330 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2331 IF for_place_id IS NOT NULL THEN
2332 searchhousenumber = in_housenumber::text;
2335 --then query tiger data
2336 -- %NOTIGERDATA% IF 0 THEN
2337 IF for_place_id IS NULL THEN
2338 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2339 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2340 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2341 IF for_place_id IS NOT NULL THEN
2342 searchhousenumber = in_housenumber::text;
2345 -- %NOTIGERDATA% END IF;
2347 -- %NOAUXDATA% IF 0 THEN
2348 IF for_place_id IS NULL THEN
2349 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2350 WHERE place_id = in_place_id
2351 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2353 -- %NOAUXDATA% END IF;
2356 IF for_place_id IS NULL THEN
2357 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2358 FROM location_postcode
2359 WHERE place_id = in_place_id
2360 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2363 IF for_place_id IS NULL THEN
2364 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2365 WHERE place_id = in_place_id and rank_search > 27
2366 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2369 IF for_place_id IS NULL THEN
2370 select coalesce(linked_place_id, place_id), country_code,
2371 housenumber, rank_search, postcode, null
2372 from placex where place_id = in_place_id
2373 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2376 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2379 hadcountry := false;
2381 select placex.place_id, osm_type, osm_id, name,
2382 class, type, admin_level, true as isaddress,
2383 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2384 0 as distance, country_code, postcode
2386 where place_id = for_place_id
2388 --RAISE WARNING '%',location;
2389 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2390 searchcountrycode := location.country_code;
2392 IF location.type in ('postcode', 'postal_code') THEN
2393 location.isaddress := FALSE;
2394 ELSEIF location.rank_address = 4 THEN
2397 IF location.rank_address < 4 AND NOT hadcountry THEN
2398 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2399 IF countryname IS NOT NULL THEN
2400 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2401 RETURN NEXT countrylocation;
2404 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2405 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2406 location.distance)::addressline;
2407 RETURN NEXT countrylocation;
2408 found := location.rank_address;
2412 select placex.place_id, osm_type, osm_id, name,
2413 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2414 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2415 admin_level, fromarea, isaddress,
2416 CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2417 distance,country_code,postcode
2418 from place_addressline join placex on (address_place_id = placex.place_id)
2419 where place_addressline.place_id = for_place_id
2420 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2421 and address_place_id != for_place_id and linked_place_id is null
2422 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2423 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2425 --RAISE WARNING '%',location;
2426 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2427 searchcountrycode := location.country_code;
2429 IF location.type in ('postcode', 'postal_code') THEN
2430 location.isaddress := FALSE;
2432 IF location.rank_address = 4 AND location.isaddress THEN
2435 IF location.rank_address < 4 AND NOT hadcountry THEN
2436 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2437 IF countryname IS NOT NULL THEN
2438 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2439 RETURN NEXT countrylocation;
2442 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2443 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2444 location.distance)::addressline;
2445 RETURN NEXT countrylocation;
2446 found := location.rank_address;
2450 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2451 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2452 IF countryname IS NOT NULL THEN
2453 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2454 RETURN NEXT location;
2458 IF searchcountrycode IS NOT NULL THEN
2459 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2460 RETURN NEXT location;
2463 IF searchhousename IS NOT NULL THEN
2464 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2465 RETURN NEXT location;
2468 IF searchhousenumber IS NOT NULL THEN
2469 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2470 RETURN NEXT location;
2473 IF searchpostcode IS NOT NULL THEN
2474 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2475 RETURN NEXT location;
2484 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2490 ELSEIF rank < 4 THEN
2492 ELSEIF rank < 8 THEN
2494 ELSEIF rank < 12 THEN
2496 ELSEIF rank < 16 THEN
2498 ELSEIF rank = 16 THEN
2500 ELSEIF rank = 17 THEN
2501 RETURN 'Town / Island';
2502 ELSEIF rank = 18 THEN
2503 RETURN 'Village / Hamlet';
2504 ELSEIF rank = 20 THEN
2506 ELSEIF rank = 21 THEN
2507 RETURN 'Postcode Area';
2508 ELSEIF rank = 22 THEN
2509 RETURN 'Croft / Farm / Locality / Islet';
2510 ELSEIF rank = 23 THEN
2511 RETURN 'Postcode Area';
2512 ELSEIF rank = 25 THEN
2513 RETURN 'Postcode Point';
2514 ELSEIF rank = 26 THEN
2515 RETURN 'Street / Major Landmark';
2516 ELSEIF rank = 27 THEN
2517 RETURN 'Minory Street / Path';
2518 ELSEIF rank = 28 THEN
2519 RETURN 'House / Building';
2521 RETURN 'Other: '||rank;
2528 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2534 ELSEIF rank < 2 THEN
2536 ELSEIF rank < 4 THEN
2538 ELSEIF rank = 5 THEN
2540 ELSEIF rank < 8 THEN
2542 ELSEIF rank < 12 THEN
2544 ELSEIF rank < 16 THEN
2546 ELSEIF rank = 16 THEN
2548 ELSEIF rank = 17 THEN
2549 RETURN 'Town / Village / Hamlet';
2550 ELSEIF rank = 20 THEN
2552 ELSEIF rank = 21 THEN
2553 RETURN 'Postcode Area';
2554 ELSEIF rank = 22 THEN
2555 RETURN 'Croft / Farm / Locality / Islet';
2556 ELSEIF rank = 23 THEN
2557 RETURN 'Postcode Area';
2558 ELSEIF rank = 25 THEN
2559 RETURN 'Postcode Point';
2560 ELSEIF rank = 26 THEN
2561 RETURN 'Street / Major Landmark';
2562 ELSEIF rank = 27 THEN
2563 RETURN 'Minory Street / Path';
2564 ELSEIF rank = 28 THEN
2565 RETURN 'House / Building';
2567 RETURN 'Other: '||rank;
2574 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2575 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2580 place_centroid GEOMETRY;
2581 out_partition INTEGER;
2582 out_parent_place_id BIGINT;
2584 address_street_word_id INTEGER;
2589 place_centroid := ST_Centroid(pointgeo);
2590 out_partition := get_partition(in_countrycode);
2591 out_parent_place_id := null;
2593 address_street_word_id := get_name_id(make_standard_name(in_street));
2594 IF address_street_word_id IS NOT NULL THEN
2595 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2596 out_parent_place_id := location.place_id;
2600 IF out_parent_place_id IS NULL THEN
2601 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2602 out_parent_place_id := location.place_id;
2606 out_postcode := in_postcode;
2607 IF out_postcode IS NULL THEN
2608 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2610 -- XXX look into postcode table
2613 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2614 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2615 newpoints := newpoints + 1;
2622 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2629 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2630 IF members[i+1] = member THEN
2631 result := result || members[i];
2640 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2646 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2647 IF members[i+1] = ANY(memberLabels) THEN
2648 RETURN NEXT members[i];
2657 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2658 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2660 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2661 SELECT CASE WHEN length(r.m[1]) = 1 THEN encode(convert_to(r.m[1], 'SQL_ASCII'), 'hex') ELSE substring(r.m[1] from 2 for 2) END
2662 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2663 ), '') AS bytea), 'UTF8');
2665 LANGUAGE SQL IMMUTABLE STRICT;
2667 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2671 RETURN decode_url_part(p);
2673 WHEN others THEN return null;
2676 LANGUAGE plpgsql IMMUTABLE;
2678 DROP TYPE wikipedia_article_match CASCADE;
2679 create type wikipedia_article_match as (
2685 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2691 wiki_article_title TEXT;
2692 wiki_article_language TEXT;
2693 result wikipedia_article_match;
2695 langs := ARRAY['english','country','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh'];
2697 WHILE langs[i] IS NOT NULL LOOP
2698 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2699 IF wiki_article is not null THEN
2700 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2701 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2702 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2703 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2704 wiki_article := replace(wiki_article,' ','_');
2705 IF strpos(wiki_article, ':') IN (3,4) THEN
2706 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2707 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2709 wiki_article_title := trim(wiki_article);
2710 wiki_article_language := CASE WHEN langs[i] = 'english' THEN 'en' WHEN langs[i] = 'country' THEN get_country_language_code(country_code) ELSE langs[i] END;
2713 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2714 from wikipedia_article
2715 where language = wiki_article_language and
2716 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2718 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2719 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2720 where wikipedia_redirect.language = wiki_article_language and
2721 (from_title = wiki_article_title OR from_title = catch_decode_url_part(wiki_article_title) OR from_title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2722 order by importance desc limit 1 INTO result;
2724 IF result.language is not null THEN
2735 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2736 RETURNS SETOF GEOMETRY
2750 remainingdepth INTEGER;
2755 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2757 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2758 RETURN NEXT geometry;
2762 remainingdepth := maxdepth - 1;
2763 area := ST_AREA(geometry);
2764 IF remainingdepth < 1 OR area < maxarea THEN
2765 RETURN NEXT geometry;
2769 xmin := st_xmin(geometry);
2770 xmax := st_xmax(geometry);
2771 ymin := st_ymin(geometry);
2772 ymax := st_ymax(geometry);
2773 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2775 -- if the geometry completely covers the box don't bother to slice any more
2776 IF ST_AREA(secbox) = area THEN
2777 RETURN NEXT geometry;
2781 xmid := (xmin+xmax)/2;
2782 ymid := (ymin+ymax)/2;
2785 FOR seg IN 1..4 LOOP
2788 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2791 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2794 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2797 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2800 IF st_intersects(geometry, secbox) THEN
2801 secgeo := st_intersection(geometry, secbox);
2802 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2803 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2804 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2806 RETURN NEXT geo.geom;
2818 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2819 RETURNS SETOF GEOMETRY
2824 -- 10000000000 is ~~ 1x1 degree
2825 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2826 RETURN NEXT geo.geom;
2834 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2838 osmtype character(1);
2842 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2843 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2844 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2845 -- force delete from place/placex by making it a very small geometry
2846 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2847 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2854 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2862 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2863 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2864 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2865 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2866 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2867 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2868 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
2869 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2870 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
2876 ELSEIF rank < 18 THEN
2878 ELSEIF rank < 20 THEN
2880 ELSEIF rank = 21 THEN
2882 ELSEIF rank < 24 THEN
2884 ELSEIF rank < 26 THEN
2885 diameter := 0.002; -- 100 to 200 meters
2886 ELSEIF rank < 28 THEN
2887 diameter := 0.001; -- 50 to 100 meters
2889 IF diameter > 0 THEN
2891 -- roads may cause reparenting for >27 rank places
2892 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2893 ELSEIF rank >= 16 THEN
2894 -- up to rank 16, street-less addresses may need reparenting
2895 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or address ? 'place');
2897 -- for all other places the search terms may change as well
2898 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null);