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 := gettokenstring(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;
260 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
261 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
269 IF country_code = 'gb' THEN
270 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
273 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
276 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
281 ELSEIF country_code = 'sg' THEN
282 IF postcode ~ '^([0-9]{6})$' THEN
287 ELSEIF country_code = 'de' THEN
288 IF postcode ~ '^([0-9]{5})$' THEN
294 -- Guess at the postcode format and coverage (!)
295 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
299 -- Does it look splitable into and area and local code?
300 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
302 IF part IS NOT NULL THEN
305 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
314 LANGUAGE plpgsql IMMUTABLE;
316 -- Find the nearest artificial postcode for the given geometry.
317 -- TODO For areas there should not be more than two inside the geometry.
318 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
324 SELECT postcode FROM location_postcode
325 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
326 AND location_postcode.country_code = country
327 ORDER BY ST_Distance(geom, location_postcode.geometry)
330 RETURN item.postcode;
339 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
348 FOR item IN SELECT (each(src)).* LOOP
350 s := make_standard_name(item.value);
351 w := getorcreate_country(s, lookup_country_code);
353 words := regexp_split_to_array(item.value, E'[,;()]');
354 IF array_upper(words, 1) != 1 THEN
355 FOR j IN 1..array_upper(words, 1) LOOP
356 s := make_standard_name(words[j]);
358 w := getorcreate_country(s, lookup_country_code);
367 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
377 result := '{}'::INTEGER[];
379 FOR item IN SELECT (each(src)).* LOOP
381 s := make_standard_name(item.value);
383 w := getorcreate_name_id(s, item.value);
385 IF not(ARRAY[w] <@ result) THEN
386 result := result || w;
389 w := getorcreate_word_id(s);
391 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
392 result := result || w;
395 words := string_to_array(s, ' ');
396 IF array_upper(words, 1) IS NOT NULL THEN
397 FOR j IN 1..array_upper(words, 1) LOOP
398 IF (words[j] != '') THEN
399 w = getorcreate_word_id(words[j]);
400 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
401 result := result || w;
407 words := regexp_split_to_array(item.value, E'[,;()]');
408 IF array_upper(words, 1) != 1 THEN
409 FOR j IN 1..array_upper(words, 1) LOOP
410 s := make_standard_name(words[j]);
412 w := getorcreate_word_id(s);
413 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
414 result := result || w;
420 s := regexp_replace(item.value, '市$', '');
421 IF s != item.value THEN
422 s := make_standard_name(s);
424 w := getorcreate_name_id(s, item.value);
425 IF NOT (ARRAY[w] <@ result) THEN
426 result := result || w;
436 LANGUAGE plpgsql IMMUTABLE;
438 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
448 result := '{}'::INTEGER[];
450 s := make_standard_name(src);
451 w := getorcreate_name_id(s, src);
453 IF NOT (ARRAY[w] <@ result) THEN
454 result := result || w;
457 w := getorcreate_word_id(s);
459 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
460 result := result || w;
463 words := string_to_array(s, ' ');
464 IF array_upper(words, 1) IS NOT NULL THEN
465 FOR j IN 1..array_upper(words, 1) LOOP
466 IF (words[j] != '') THEN
467 w = getorcreate_word_id(words[j]);
468 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
469 result := result || w;
475 words := regexp_split_to_array(src, E'[,;()]');
476 IF array_upper(words, 1) != 1 THEN
477 FOR j IN 1..array_upper(words, 1) LOOP
478 s := make_standard_name(words[j]);
480 w := getorcreate_word_id(s);
481 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
482 result := result || w;
488 s := regexp_replace(src, '市$', '');
490 s := make_standard_name(s);
492 w := getorcreate_name_id(s, src);
493 IF NOT (ARRAY[w] <@ result) THEN
494 result := result || w;
502 LANGUAGE plpgsql IMMUTABLE;
504 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
507 place_centre GEOMETRY;
510 place_centre := ST_PointOnSurface(place);
512 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
514 -- Try for a OSM polygon
515 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
517 RETURN nearcountry.country_code;
520 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
522 -- Try for OSM fallback data
523 -- The order is to deal with places like HongKong that are 'states' within another polygon
524 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
526 RETURN nearcountry.country_code;
529 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
531 -- Natural earth data
532 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
534 RETURN nearcountry.country_code;
537 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
540 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
542 RETURN nearcountry.country_code;
545 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
547 -- Natural earth data
548 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
550 RETURN nearcountry.country_code;
556 LANGUAGE plpgsql IMMUTABLE;
558 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
563 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
565 RETURN lower(nearcountry.country_default_language_code);
570 LANGUAGE plpgsql IMMUTABLE;
572 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
577 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
579 RETURN lower(nearcountry.country_default_language_codes);
584 LANGUAGE plpgsql IMMUTABLE;
586 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
591 FOR nearcountry IN select partition from country_name where country_code = in_country_code
593 RETURN nearcountry.partition;
598 LANGUAGE plpgsql IMMUTABLE;
600 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
604 DELETE FROM location_area where place_id = OLD_place_id;
605 -- TODO:location_area
611 CREATE OR REPLACE FUNCTION add_location(
613 country_code varchar(2),
617 rank_address INTEGER,
633 IF rank_search > 25 THEN
634 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
637 x := deleteLocationArea(partition, place_id, rank_search);
639 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
641 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
642 postcode := upper(trim (in_postcode));
645 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
646 centroid := ST_Centroid(geometry);
648 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
649 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
655 IF rank_address = 0 THEN
657 ELSEIF rank_search <= 14 THEN
659 ELSEIF rank_search <= 15 THEN
661 ELSEIF rank_search <= 16 THEN
663 ELSEIF rank_search <= 17 THEN
665 ELSEIF rank_search <= 21 THEN
667 ELSEIF rank_search = 25 THEN
671 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
673 secgeo := ST_Buffer(geometry, diameter);
674 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
684 -- find the parent road of the cut road parts
685 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
686 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
691 parent_place_id BIGINT;
692 address_street_word_ids INTEGER[];
698 addr_street = street;
701 IF addr_street is null and addr_place is null THEN
702 select nodes from planet_osm_ways where id = wayid INTO waynodes;
703 FOR location IN SELECT placex.address from placex
704 where osm_type = 'N' and osm_id = ANY(waynodes)
705 and placex.address is not null
706 and (placex.address ? 'street' or placex.address ? 'place')
707 and indexed_status < 100
709 addr_street = location.address->'street';
710 addr_place = location.address->'place';
714 IF addr_street IS NOT NULL THEN
715 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
716 IF address_street_word_ids IS NOT NULL THEN
717 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
718 parent_place_id := location.place_id;
723 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
724 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
725 IF address_street_word_ids IS NOT NULL THEN
726 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
727 parent_place_id := location.place_id;
732 IF parent_place_id is null THEN
733 FOR location IN SELECT place_id FROM placex
734 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
735 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
736 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
737 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
739 parent_place_id := location.place_id;
743 IF parent_place_id is null THEN
747 RETURN parent_place_id;
753 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
756 NEW.place_id := nextval('seq_place');
757 NEW.indexed_date := now();
759 IF NEW.indexed_status IS NULL THEN
760 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
761 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
762 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
766 NEW.indexed_status := 1; --STATUS_NEW
767 NEW.country_code := lower(get_country_code(NEW.linegeo));
769 NEW.partition := get_partition(NEW.country_code);
770 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
779 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
785 country_code VARCHAR(2);
786 default_language VARCHAR(10);
791 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
793 NEW.place_id := nextval('seq_place');
794 NEW.indexed_status := 1; --STATUS_NEW
796 NEW.country_code := lower(get_country_code(NEW.geometry));
798 NEW.partition := get_partition(NEW.country_code);
799 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
801 -- copy 'name' to or from the default language (if there is a default language)
802 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
803 default_language := get_country_language_code(NEW.country_code);
804 IF default_language IS NOT NULL THEN
805 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
806 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
807 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
808 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
813 IF NEW.osm_type = 'X' THEN
814 -- E'X'ternal records should already be in the right format so do nothing
816 NEW.rank_search := 30;
817 NEW.rank_address := NEW.rank_search;
819 -- By doing in postgres we have the country available to us - currently only used for postcode
820 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
822 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
823 -- most likely just a part of a multipolygon postcode boundary, throw it away
827 NEW.name := hstore('ref', NEW.postcode);
829 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
830 INTO NEW.rank_search, NEW.rank_address;
832 ELSEIF NEW.class = 'place' THEN
833 IF NEW.type in ('continent') THEN
834 NEW.rank_search := 2;
835 NEW.rank_address := NEW.rank_search;
836 NEW.country_code := NULL;
837 ELSEIF NEW.type in ('sea') THEN
838 NEW.rank_search := 2;
839 NEW.rank_address := 0;
840 NEW.country_code := NULL;
841 ELSEIF NEW.type in ('country') THEN
842 NEW.rank_search := 4;
843 NEW.rank_address := NEW.rank_search;
844 ELSEIF NEW.type in ('state') THEN
845 NEW.rank_search := 8;
846 NEW.rank_address := NEW.rank_search;
847 ELSEIF NEW.type in ('region') THEN
848 NEW.rank_search := 18; -- dropped from previous value of 10
849 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
850 ELSEIF NEW.type in ('county') THEN
851 NEW.rank_search := 12;
852 NEW.rank_address := NEW.rank_search;
853 ELSEIF NEW.type in ('city') THEN
854 NEW.rank_search := 16;
855 NEW.rank_address := NEW.rank_search;
856 ELSEIF NEW.type in ('island') THEN
857 NEW.rank_search := 17;
858 NEW.rank_address := 0;
859 ELSEIF NEW.type in ('town') THEN
860 NEW.rank_search := 18;
861 NEW.rank_address := 16;
862 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
863 NEW.rank_search := 19;
864 NEW.rank_address := 16;
865 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
866 NEW.rank_search := 20;
867 NEW.rank_address := NEW.rank_search;
868 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
869 NEW.rank_search := 20;
870 NEW.rank_address := 0;
871 -- Irish townlands, tagged as place=locality and locality=townland
872 IF (NEW.extratags -> 'locality') = 'townland' THEN
873 NEW.rank_address := 20;
875 ELSEIF NEW.type in ('neighbourhood') THEN
876 NEW.rank_search := 22;
877 NEW.rank_address := 22;
878 ELSEIF NEW.type in ('house','building') THEN
879 NEW.rank_search := 30;
880 NEW.rank_address := NEW.rank_search;
881 ELSEIF NEW.type in ('houses') THEN
882 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
883 NEW.rank_search := 28;
884 NEW.rank_address := 0;
887 ELSEIF NEW.class = 'boundary' THEN
888 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
889 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
892 NEW.rank_search := NEW.admin_level * 2;
893 IF NEW.type = 'administrative' THEN
894 NEW.rank_address := NEW.rank_search;
896 NEW.rank_address := 0;
898 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
899 NEW.rank_search := 22;
900 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
901 NEW.rank_address := NEW.rank_search;
903 NEW.rank_address := 0;
905 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
906 NEW.rank_search := 18;
907 NEW.rank_address := 0;
908 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
909 NEW.rank_search := 4;
910 NEW.rank_address := NEW.rank_search;
911 -- any feature more than 5 square miles is probably worth indexing
912 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
913 NEW.rank_search := 22;
914 NEW.rank_address := 0;
915 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
917 ELSEIF NEW.class = 'waterway' THEN
918 IF NEW.osm_type = 'R' THEN
919 NEW.rank_search := 16;
921 NEW.rank_search := 17;
923 NEW.rank_address := 0;
924 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
925 NEW.rank_search := 27;
926 NEW.rank_address := NEW.rank_search;
927 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
928 NEW.rank_search := 26;
929 NEW.rank_address := NEW.rank_search;
930 ELSEIF NEW.class = 'mountain_pass' THEN
931 NEW.rank_search := 20;
932 NEW.rank_address := 0;
937 IF NEW.rank_search > 30 THEN
938 NEW.rank_search := 30;
941 IF NEW.rank_address > 30 THEN
942 NEW.rank_address := 30;
945 IF (NEW.extratags -> 'capital') = 'yes' THEN
946 NEW.rank_search := NEW.rank_search - 1;
949 -- a country code make no sense below rank 4 (country)
950 IF NEW.rank_search < 4 THEN
951 NEW.country_code := NULL;
954 -- Block import below rank 22
955 -- IF NEW.rank_search > 22 THEN
959 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
961 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
963 IF NEW.rank_address > 0 THEN
964 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
965 -- Performance: We just can't handle re-indexing for country level changes
966 IF st_area(NEW.geometry) < 1 THEN
967 -- mark items within the geometry for re-indexing
968 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
970 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
971 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
972 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'));
973 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
974 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'));
977 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
979 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
980 IF NEW.type='postcode' THEN
982 ELSEIF NEW.rank_search < 16 THEN
984 ELSEIF NEW.rank_search < 18 THEN
986 ELSEIF NEW.rank_search < 20 THEN
988 ELSEIF NEW.rank_search = 21 THEN
990 ELSEIF NEW.rank_search < 24 THEN
992 ELSEIF NEW.rank_search < 26 THEN
993 diameter := 0.002; -- 100 to 200 meters
994 ELSEIF NEW.rank_search < 28 THEN
995 diameter := 0.001; -- 50 to 100 meters
998 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
999 IF NEW.rank_search >= 26 THEN
1000 -- roads may cause reparenting for >27 rank places
1001 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1002 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1003 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1004 ELSEIF NEW.rank_search >= 16 THEN
1005 -- up to rank 16, street-less addresses may need reparenting
1006 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');
1008 -- for all other places the search terms may change as well
1009 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);
1016 -- add to tables for special search
1017 -- Note: won't work on initial import because the classtype tables
1018 -- do not yet exist. It won't hurt either.
1019 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1020 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1022 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1023 USING NEW.place_id, ST_Centroid(NEW.geometry);
1032 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1036 place_centroid GEOMETRY;
1040 startnumber INTEGER;
1045 sectiongeo GEOMETRY;
1050 IF OLD.indexed_status = 100 THEN
1051 delete from location_property_osmline where place_id = OLD.place_id;
1055 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1059 NEW.interpolationtype = NEW.address->'interpolation';
1061 place_centroid := ST_PointOnSurface(NEW.linegeo);
1062 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1063 NEW.address->'place',
1064 NEW.partition, place_centroid, NEW.linegeo);
1067 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1068 NEW.postcode = NEW.address->'postcode';
1071 -- if the line was newly inserted, split the line as necessary
1072 IF OLD.indexed_status = 1 THEN
1073 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1075 IF array_upper(waynodes, 1) IS NULL THEN
1079 linegeo := NEW.linegeo;
1080 startnumber := NULL;
1081 postcode := NEW.postcode;
1083 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1085 select osm_id, address, geometry
1086 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1087 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1088 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1089 IF nextnode.osm_id IS NOT NULL THEN
1090 --RAISE NOTICE 'place_id is not null';
1091 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1092 -- Make sure that the point is actually on the line. That might
1093 -- be a bit paranoid but ensures that the algorithm still works
1094 -- should osm2pgsql attempt to repair geometries.
1095 splitline := split_line_on_node(linegeo, nextnode.geometry);
1096 sectiongeo := ST_GeometryN(splitline, 1);
1097 linegeo := ST_GeometryN(splitline, 2);
1099 sectiongeo = linegeo;
1101 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1103 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1104 AND startnumber != endnumber
1105 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1107 IF (startnumber > endnumber) THEN
1108 housenum := endnumber;
1109 endnumber := startnumber;
1110 startnumber := housenum;
1111 sectiongeo := ST_Reverse(sectiongeo);
1114 seg_postcode := coalesce(postcode,
1115 prevnode.address->'postcode',
1116 nextnode.address->'postcode');
1118 IF NEW.startnumber IS NULL THEN
1119 NEW.startnumber := startnumber;
1120 NEW.endnumber := endnumber;
1121 NEW.linegeo := sectiongeo;
1122 NEW.postcode := seg_postcode;
1124 insert into location_property_osmline
1125 (linegeo, partition, osm_id, parent_place_id,
1126 startnumber, endnumber, interpolationtype,
1127 address, postcode, country_code,
1128 geometry_sector, indexed_status)
1129 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1130 startnumber, endnumber, NEW.interpolationtype,
1131 NEW.address, seg_postcode,
1132 NEW.country_code, NEW.geometry_sector, 0);
1136 -- early break if we are out of line string,
1137 -- might happen when a line string loops back on itself
1138 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1142 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1143 prevnode := nextnode;
1148 -- marking descendants for reparenting is not needed, because there are
1149 -- actually no descendants for interpolation lines
1155 -- Trigger for updates of location_postcode
1157 -- Computes the parent object the postcode most likely refers to.
1158 -- This will be the place that determines the address displayed when
1159 -- searching for this postcode.
1160 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1167 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1171 NEW.indexed_date = now();
1173 partition := get_partition(NEW.country_code);
1175 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1176 INTO NEW.rank_search, NEW.rank_address;
1178 NEW.parent_place_id = 0;
1181 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1182 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1184 NEW.parent_place_id = location.place_id;
1192 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1197 place_centroid GEOMETRY;
1199 search_maxdistance FLOAT[];
1200 search_mindistance FLOAT[];
1201 address_havelevel BOOLEAN[];
1208 relation_members TEXT[];
1210 linkedplacex RECORD;
1211 search_diameter FLOAT;
1212 search_prevdiameter FLOAT;
1213 search_maxrank INTEGER;
1214 address_maxrank INTEGER;
1215 address_street_word_id INTEGER;
1216 address_street_word_ids INTEGER[];
1217 parent_place_id_rank BIGINT;
1225 location_rank_search INTEGER;
1226 location_distance FLOAT;
1227 location_parent GEOMETRY;
1228 location_isaddress BOOLEAN;
1229 location_keywords INTEGER[];
1231 default_language TEXT;
1232 name_vector INTEGER[];
1233 nameaddress_vector INTEGER[];
1235 linked_node_id BIGINT;
1236 linked_importance FLOAT;
1237 linked_wikipedia TEXT;
1242 IF OLD.indexed_status = 100 THEN
1243 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1244 delete from placex where place_id = OLD.place_id;
1248 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1252 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1254 NEW.indexed_date = now();
1256 result := deleteSearchName(NEW.partition, NEW.place_id);
1257 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1258 result := deleteRoad(NEW.partition, NEW.place_id);
1259 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1260 UPDATE placex set linked_place_id = null, indexed_status = 2
1261 where linked_place_id = NEW.place_id;
1262 -- update not necessary for osmline, cause linked_place_id does not exist
1264 IF NEW.linked_place_id is not null THEN
1265 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1269 --DEBUG: RAISE WARNING 'Copy over address tags';
1270 IF NEW.address is not NULL THEN
1271 IF NEW.address ? 'conscriptionnumber' THEN
1272 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1273 IF NEW.address ? 'streetnumber' THEN
1274 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1275 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1277 NEW.housenumber := NEW.address->'conscriptionnumber';
1279 ELSEIF NEW.address ? 'streetnumber' THEN
1280 NEW.housenumber := NEW.address->'streetnumber';
1281 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1282 ELSEIF NEW.address ? 'housenumber' THEN
1283 NEW.housenumber := NEW.address->'housenumber';
1284 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1287 addr_street = NEW.address->'street';
1288 addr_place = NEW.address->'place';
1290 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1291 i := getorcreate_postcode_id(NEW.address->'postcode');
1295 -- Speed up searches - just use the centroid of the feature
1296 -- cheaper but less acurate
1297 place_centroid := ST_PointOnSurface(NEW.geometry);
1298 NEW.centroid := null;
1299 NEW.postcode := null;
1300 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1302 -- recalculate country and partition
1303 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1304 -- for countries, believe the mapped country code,
1305 -- so that we remain in the right partition if the boundaries
1307 NEW.country_code := lower(NEW.address->'country');
1308 NEW.partition := get_partition(lower(NEW.country_code));
1309 IF NEW.partition = 0 THEN
1310 NEW.country_code := lower(get_country_code(place_centroid));
1311 NEW.partition := get_partition(NEW.country_code);
1314 IF NEW.rank_search >= 4 THEN
1315 NEW.country_code := lower(get_country_code(place_centroid));
1317 NEW.country_code := NULL;
1319 NEW.partition := get_partition(NEW.country_code);
1321 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1323 -- waterway ways are linked when they are part of a relation and have the same class/type
1324 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1325 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1327 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1328 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1329 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1330 FOR linked_node_id IN SELECT place_id FROM placex
1331 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1332 and class = NEW.class and type = NEW.type
1333 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1335 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1340 --DEBUG: RAISE WARNING 'Waterway processed';
1343 -- Adding ourselves to the list simplifies address calculations later
1344 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1345 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1347 -- What level are we searching from
1348 search_maxrank := NEW.rank_search;
1350 -- Thought this wasn't needed but when we add new languages to the country_name table
1351 -- we need to update the existing names
1352 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1353 default_language := get_country_language_code(NEW.country_code);
1354 IF default_language IS NOT NULL THEN
1355 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1356 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1357 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1358 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1362 --DEBUG: RAISE WARNING 'Local names updated';
1364 -- Initialise the name vector using our name
1365 name_vector := make_keywords(NEW.name);
1366 nameaddress_vector := '{}'::int[];
1369 address_havelevel[i] := false;
1372 NEW.importance := null;
1373 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1374 IF NEW.importance IS NULL THEN
1375 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;
1378 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1380 -- ---------------------------------------------------------------------------
1381 -- For low level elements we inherit from our parent road
1382 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1384 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1386 -- We won't get a better centroid, besides these places are too small to care
1387 NEW.centroid := place_centroid;
1389 NEW.parent_place_id := null;
1391 -- if we have a POI and there is no address information,
1392 -- see if we can get it from a surrounding building
1393 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1394 AND NEW.housenumber IS NULL THEN
1395 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1396 and address is not null
1397 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1398 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1401 NEW.housenumber := location.address->'housenumber';
1402 addr_street := location.address->'street';
1403 addr_place := location.address->'place';
1404 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1408 -- We have to find our parent road.
1409 -- Copy data from linked items (points on ways, addr:street links, relations)
1411 -- Is this object part of a relation?
1412 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1414 -- At the moment we only process one type of relation - associatedStreet
1415 IF relation.tags @> ARRAY['associatedStreet'] THEN
1416 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1417 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1418 --RAISE WARNING 'node in relation %',relation;
1419 SELECT place_id from placex where osm_type = 'W'
1420 and osm_id = substring(relation.members[i],2,200)::bigint
1421 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1426 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1428 -- Note that addr:street links can only be indexed once the street itself is indexed
1429 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1430 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1431 IF address_street_word_ids IS NOT NULL THEN
1432 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1433 NEW.parent_place_id := location.place_id;
1437 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1439 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1440 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1441 IF address_street_word_ids IS NOT NULL THEN
1442 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1443 NEW.parent_place_id := location.place_id;
1447 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1449 -- Is this node part of an interpolation?
1450 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1452 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1453 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1456 NEW.parent_place_id := location.parent_place_id;
1459 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1461 -- Is this node part of a way?
1462 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1464 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.address from placex p, planet_osm_ways w
1465 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)
1467 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1469 -- Way IS a road then we are on it - that must be our road
1470 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1471 --RAISE WARNING 'node in way that is a street %',location;
1472 NEW.parent_place_id := location.place_id;
1474 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1476 -- If the way mentions a street or place address, try that for parenting.
1477 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1478 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1479 IF address_street_word_ids IS NOT NULL THEN
1480 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1481 NEW.parent_place_id := linkedplacex.place_id;
1485 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1487 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1488 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1489 IF address_street_word_ids IS NOT NULL THEN
1490 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1491 NEW.parent_place_id := linkedplacex.place_id;
1495 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1497 -- Is the WAY part of a relation
1498 IF NEW.parent_place_id IS NULL THEN
1499 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1501 -- At the moment we only process one type of relation - associatedStreet
1502 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1503 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1504 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1505 --RAISE WARNING 'node in way that is in a relation %',relation;
1506 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1507 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1513 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1519 -- Still nothing, just use the nearest road
1520 IF NEW.parent_place_id IS NULL THEN
1521 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1522 NEW.parent_place_id := location.place_id;
1525 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1528 -- If we didn't find any road fallback to standard method
1529 IF NEW.parent_place_id IS NOT NULL THEN
1531 -- Get the details of the parent road
1532 select * from search_name where place_id = NEW.parent_place_id INTO location;
1533 NEW.country_code := location.country_code;
1534 --DEBUG: RAISE WARNING 'Got parent details from search name';
1536 -- determine postcode
1537 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1538 NEW.postcode = NEW.address->'postcode';
1540 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1542 IF NEW.postcode is null THEN
1543 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1546 -- Merge the postcode into the parent's address if necessary
1547 IF NEW.postcode IS NOT NULL THEN
1548 --DEBUG: RAISE WARNING 'Merging postcode into parent';
1549 isin_tokens := '{}'::int[];
1550 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1551 IF address_street_word_id is not null
1552 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1553 isin_tokens := isin_tokens || address_street_word_id;
1555 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1556 IF address_street_word_id is not null
1557 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1558 isin_tokens := isin_tokens || address_street_word_id;
1560 IF isin_tokens != '{}'::int[] THEN
1562 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1563 WHERE place_id = NEW.parent_place_id;
1567 -- If there is no name it isn't searchable, don't bother to create a search record
1568 IF NEW.name is NULL THEN
1569 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1573 -- Merge address from parent
1574 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1575 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1577 -- Performance, it would be more acurate to do all the rest of the import
1578 -- process but it takes too long
1579 -- Just be happy with inheriting from parent road only
1581 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1582 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1583 --DEBUG: RAISE WARNING 'Place added to location table';
1586 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1587 --DEBUG: RAISE WARNING 'Place added to search table';
1594 -- ---------------------------------------------------------------------------
1596 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1598 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1600 -- see if we have any special relation members
1601 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1602 --DEBUG: RAISE WARNING 'Got relation members';
1604 IF relation_members IS NOT NULL THEN
1605 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1606 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1608 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1609 and osm_id = substring(relMember.member,2,10000)::bigint
1610 and class = 'place' order by rank_search desc limit 1 LOOP
1612 -- If we don't already have one use this as the centre point of the geometry
1613 IF NEW.centroid IS NULL THEN
1614 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1617 -- merge in the label name, re-init word vector
1618 IF NOT linkedPlacex.name IS NULL THEN
1619 NEW.name := linkedPlacex.name || NEW.name;
1620 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1623 -- merge in extra tags
1624 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1626 -- mark the linked place (excludes from search results)
1627 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1629 -- keep a note of the node id in case we need it for wikipedia in a bit
1630 linked_node_id := linkedPlacex.osm_id;
1631 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1632 --DEBUG: RAISE WARNING 'Linked label member';
1637 IF NEW.centroid IS NULL THEN
1639 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1640 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1642 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1643 and osm_id = substring(relMember.member,2,10000)::bigint
1644 and class = 'place' order by rank_search desc limit 1 LOOP
1646 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1647 -- But that can be fixed by explicitly setting the label in the data
1648 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1649 AND NEW.rank_address = linkedPlacex.rank_address THEN
1651 -- If we don't already have one use this as the centre point of the geometry
1652 IF NEW.centroid IS NULL THEN
1653 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1656 -- merge in the name, re-init word vector
1657 IF NOT linkedPlacex.name IS NULL THEN
1658 NEW.name := linkedPlacex.name || NEW.name;
1659 name_vector := make_keywords(NEW.name);
1662 -- merge in extra tags
1663 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1665 -- mark the linked place (excludes from search results)
1666 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1668 -- keep a note of the node id in case we need it for wikipedia in a bit
1669 linked_node_id := linkedPlacex.osm_id;
1670 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1671 --DEBUG: RAISE WARNING 'Linked admin_center';
1683 -- Name searches can be done for ways as well as relations
1684 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1686 -- not found one yet? how about doing a name search
1687 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1689 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1690 FOR linkedPlacex IN select placex.* from placex WHERE
1691 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1692 AND placex.rank_address = NEW.rank_address
1693 AND placex.place_id != NEW.place_id
1694 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1695 AND st_covers(NEW.geometry, placex.geometry)
1697 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1698 -- If we don't already have one use this as the centre point of the geometry
1699 IF NEW.centroid IS NULL THEN
1700 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1703 -- merge in the name, re-init word vector
1704 NEW.name := linkedPlacex.name || NEW.name;
1705 name_vector := make_keywords(NEW.name);
1707 -- merge in extra tags
1708 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1710 -- mark the linked place (excludes from search results)
1711 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1713 -- keep a note of the node id in case we need it for wikipedia in a bit
1714 linked_node_id := linkedPlacex.osm_id;
1715 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1716 --DEBUG: RAISE WARNING 'Linked named place';
1720 IF NEW.centroid IS NOT NULL THEN
1721 place_centroid := NEW.centroid;
1722 -- Place might have had only a name tag before but has now received translations
1723 -- from the linked place. Make sure a name tag for the default language exists in
1725 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1726 default_language := get_country_language_code(NEW.country_code);
1727 IF default_language IS NOT NULL THEN
1728 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1729 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1730 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1731 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1735 --DEBUG: RAISE WARNING 'Names updated from linked places';
1738 -- Use the maximum importance if a one could be computed from the linked object.
1739 IF linked_importance is not null AND
1740 (NEW.importance is null or NEW.importance < linked_importance) THEN
1741 NEW.importance = linked_importance;
1744 -- Still null? how about looking it up by the node id
1745 IF NEW.importance IS NULL THEN
1746 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1747 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;
1752 -- make sure all names are in the word table
1753 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1754 perform create_country(NEW.name, lower(NEW.country_code));
1755 --DEBUG: RAISE WARNING 'Country names updated';
1758 NEW.parent_place_id = 0;
1759 parent_place_id_rank = 0;
1762 -- convert isin to array of tokenids
1763 --DEBUG: RAISE WARNING 'Starting address search';
1764 isin_tokens := '{}'::int[];
1765 IF NEW.address IS NOT NULL THEN
1766 isin := avals(NEW.address);
1767 IF array_upper(isin, 1) IS NOT NULL THEN
1768 FOR i IN 1..array_upper(isin, 1) LOOP
1769 -- TODO further split terms with comma and semicolon
1770 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1771 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1772 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1773 isin_tokens := isin_tokens || address_street_word_id;
1776 -- merge word into address vector
1777 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1778 IF address_street_word_id IS NOT NULL THEN
1779 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1785 -- %NOTIGERDATA% IF 0 THEN
1786 -- for the USA we have an additional address table. Merge in zip codes from there too
1787 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1788 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1789 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1790 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1791 isin_tokens := isin_tokens || address_street_word_id;
1793 -- also merge in the single word version
1794 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1795 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1798 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1799 -- %NOTIGERDATA% END IF;
1801 -- RAISE WARNING 'ISIN: %', isin_tokens;
1803 -- Process area matches
1804 location_rank_search := 0;
1805 location_distance := 0;
1806 location_parent := NULL;
1807 -- added ourself as address already
1808 address_havelevel[NEW.rank_address] := true;
1809 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1811 SELECT * from getNearFeatures(NEW.partition,
1812 CASE WHEN NEW.rank_search >= 26
1813 AND NEW.rank_search < 30
1815 ELSE place_centroid END,
1816 search_maxrank, isin_tokens)
1818 IF location.rank_address != location_rank_search THEN
1819 location_rank_search := location.rank_address;
1820 IF location.isguess THEN
1821 location_distance := location.distance * 1.5;
1823 IF location.rank_address <= 12 THEN
1824 -- for county and above, if we have an area consider that exact
1825 -- (It would be nice to relax the constraint for places close to
1826 -- the boundary but we'd need the exact geometry for that. Too
1828 location_distance = 0;
1830 -- Below county level remain slightly fuzzy.
1831 location_distance := location.distance * 0.5;
1835 CONTINUE WHEN location.keywords <@ location_keywords;
1838 IF location.distance < location_distance OR NOT location.isguess THEN
1839 location_keywords := location.keywords;
1841 location_isaddress := NOT address_havelevel[location.rank_address];
1842 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1843 location_isaddress := ST_Contains(location_parent,location.centroid);
1846 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1847 -- Add it to the list of search terms
1848 IF location.rank_search > 4 THEN
1849 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1851 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1852 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1854 IF location_isaddress THEN
1855 -- add postcode if we have one
1856 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1857 IF location.postcode is not null THEN
1858 NEW.postcode = location.postcode;
1861 address_havelevel[location.rank_address] := true;
1862 IF NOT location.isguess THEN
1863 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1866 IF location.rank_address > parent_place_id_rank THEN
1867 NEW.parent_place_id = location.place_id;
1868 parent_place_id_rank = location.rank_address;
1873 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1878 --DEBUG: RAISE WARNING 'address computed';
1880 -- try using the isin value to find parent places
1881 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1882 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1883 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1884 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1886 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1888 --RAISE WARNING ' ISIN: %',location;
1890 IF location.rank_search > 4 THEN
1891 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1892 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1893 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1894 IF NEW.postcode is null AND location.postcode is not null
1895 AND NOT address_havelevel[location.rank_address] THEN
1896 NEW.postcode := location.postcode;
1899 address_havelevel[location.rank_address] := true;
1901 IF location.rank_address > parent_place_id_rank THEN
1902 NEW.parent_place_id = location.place_id;
1903 parent_place_id_rank = location.rank_address;
1912 --DEBUG: RAISE WARNING 'isin tokens processed';
1914 -- for long ways we should add search terms for the entire length
1915 IF st_length(NEW.geometry) > 0.05 THEN
1917 location_rank_search := 0;
1918 location_distance := 0;
1920 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1922 IF location.rank_address != location_rank_search THEN
1923 location_rank_search := location.rank_address;
1924 location_distance := location.distance * 1.5;
1927 IF location.rank_search > 4 AND location.distance < location_distance THEN
1929 -- Add it to the list of search terms
1930 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1931 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1932 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1939 --DEBUG: RAISE WARNING 'search terms for long ways added';
1941 IF NEW.address is not null AND NEW.address ? 'postcode'
1942 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1943 NEW.postcode := NEW.address->'postcode';
1946 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1947 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1950 -- if we have a name add this to the name search table
1951 IF NEW.name IS NOT NULL THEN
1953 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1954 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1955 --DEBUG: RAISE WARNING 'added to location (full)';
1958 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1959 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1960 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1963 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1964 --DEBUG: RAISE WARNING 'added to serach name (full)';
1968 -- If we've not managed to pick up a better one - default centroid
1969 IF NEW.centroid IS NULL THEN
1970 NEW.centroid := place_centroid;
1973 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1980 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1986 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1988 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1989 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1990 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1991 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1993 IF OLD.rank_address < 30 THEN
1995 -- mark everything linked to this place for re-indexing
1996 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1997 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1998 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
2000 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
2001 DELETE FROM place_addressline where address_place_id = OLD.place_id;
2003 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
2004 b := deleteRoad(OLD.partition, OLD.place_id);
2006 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
2007 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
2008 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
2009 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
2010 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
2014 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2016 IF OLD.rank_address < 26 THEN
2017 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2020 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2022 IF OLD.name is not null THEN
2023 b := deleteSearchName(OLD.partition, OLD.place_id);
2026 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2028 DELETE FROM place_addressline where place_id = OLD.place_id;
2030 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2032 -- remove from tables for special search
2033 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2034 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2036 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2039 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2047 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2053 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2055 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2056 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2057 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;
2059 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2065 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;
2067 -- interpolations are special
2068 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2069 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2078 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2083 existingplacex RECORD;
2084 existingline RECORD;
2085 existinggeometry GEOMETRY;
2086 existingplace_id BIGINT;
2091 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2092 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2093 -- filter wrong tupels
2094 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
2095 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2096 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2097 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2101 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2102 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2103 -- Have we already done this place?
2104 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;
2106 -- Get the existing place_id
2107 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2109 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2110 IF existing.osm_type IS NULL THEN
2111 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2114 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2115 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2117 -- 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)
2118 IF existingline.osm_id IS NOT NULL THEN
2119 delete from location_property_osmline where osm_id = NEW.osm_id;
2122 -- for interpolations invalidate all nodes on the line
2123 update placex p set indexed_status = 2
2124 from planet_osm_ways w
2125 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2128 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2129 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2132 IF existing.osm_type IS NULL THEN
2136 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2137 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2138 OR existing.geometry::text != NEW.geometry::text
2143 address = NEW.address,
2144 extratags = NEW.extratags,
2145 admin_level = NEW.admin_level,
2146 geometry = NEW.geometry
2147 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2152 ELSE -- insert to placex
2154 -- Patch in additional country names
2155 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2156 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2157 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2158 IF existing.name IS NOT NULL THEN
2159 NEW.name = existing.name || NEW.name;
2163 -- Have we already done this place?
2164 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;
2166 -- Get the existing place_id
2167 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;
2169 -- Handle a place changing type by removing the old data
2170 -- My generated 'place' types are causing havok because they overlap with real keys
2171 -- TODO: move them to their own special purpose key/class to avoid collisions
2172 IF existing.osm_type IS NULL THEN
2173 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2176 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2177 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2180 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2181 AND st_area(existing.geometry) > 0.02
2182 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2183 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2185 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2186 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2187 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2191 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2192 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2194 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2195 IF existingplacex.osm_type IS NULL OR
2196 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2199 IF existingplacex.osm_type IS NOT NULL THEN
2200 -- sanity check: ignore admin_level changes on places with too many active children
2201 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2202 --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;
2203 --LIMIT INDEXING: IF i > 100000 THEN
2204 --LIMIT INDEXING: RETURN null;
2205 --LIMIT INDEXING: END IF;
2208 IF existing.osm_type IS NOT NULL THEN
2209 -- pathological case caused by the triggerless copy into place during initial import
2210 -- force delete even for large areas, it will be reinserted later
2211 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;
2212 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2215 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2216 insert into placex (osm_type, osm_id, class, type, name,
2217 admin_level, address, extratags, geometry)
2218 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2219 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2221 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2226 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2227 IF existing.geometry::text != NEW.geometry::text
2228 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2229 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2232 -- Get the version of the geometry actually used (in placex table)
2233 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;
2235 -- Performance limit
2236 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2238 -- 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
2239 update placex set indexed_status = 2 where indexed_status = 0 and
2240 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2241 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2242 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2244 update placex set indexed_status = 2 where indexed_status = 0 and
2245 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2246 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2247 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2254 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2255 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2256 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2257 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2258 OR existing.geometry::text != NEW.geometry::text
2263 address = NEW.address,
2264 extratags = NEW.extratags,
2265 admin_level = NEW.admin_level,
2266 geometry = NEW.geometry
2267 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2270 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2271 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2272 -- postcode was deleted, no longer retain in placex
2273 DELETE FROM placex where place_id = existingplacex.place_id;
2277 NEW.name := hstore('ref', NEW.address->'postcode');
2280 IF NEW.class in ('boundary')
2281 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2282 DELETE FROM placex where place_id = existingplacex.place_id;
2288 address = NEW.address,
2289 parent_place_id = null,
2290 extratags = NEW.extratags,
2291 admin_level = NEW.admin_level,
2293 geometry = NEW.geometry
2294 where place_id = existingplacex.place_id;
2296 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2297 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2298 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2299 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2300 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);
2303 -- linked places should get potential new naming and addresses
2304 IF existingplacex.linked_place_id is not NULL THEN
2307 extratags = p.extratags,
2310 where x.place_id = existingplacex.linked_place_id
2311 and x.indexed_status = 0
2312 and x.osm_type = p.osm_type
2313 and x.osm_id = p.osm_id
2314 and x.class = p.class;
2319 -- Abort the add (we modified the existing place instead)
2324 $$ LANGUAGE plpgsql;
2327 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2332 IF name is null THEN
2336 FOR j IN 1..array_upper(languagepref,1) LOOP
2337 IF name ? languagepref[j] THEN
2338 result := trim(name->languagepref[j]);
2339 IF result != '' THEN
2345 -- anything will do as a fallback - just take the first name type thing there is
2346 RETURN trim((avals(name))[1]);
2349 LANGUAGE plpgsql IMMUTABLE;
2351 --housenumber only needed for tiger data
2352 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2364 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2365 currresult := trim(get_name_by_language(location.name, languagepref));
2366 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2367 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2368 prevresult := currresult;
2372 RETURN array_to_string(result,', ');
2377 DROP TYPE IF EXISTS addressline CASCADE;
2378 create type addressline as (
2385 admin_level INTEGER,
2388 rank_address INTEGER,
2392 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2395 for_place_id BIGINT;
2400 countrylocation RECORD;
2401 searchcountrycode varchar(2);
2402 searchhousenumber TEXT;
2403 searchhousename HSTORE;
2404 searchrankaddress INTEGER;
2405 searchpostcode TEXT;
2411 -- first query osmline (interpolation lines)
2412 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2413 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2414 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2415 IF for_place_id IS NOT NULL THEN
2416 searchhousenumber = in_housenumber::text;
2419 --then query tiger data
2420 -- %NOTIGERDATA% IF 0 THEN
2421 IF for_place_id IS NULL THEN
2422 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2423 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2424 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2425 IF for_place_id IS NOT NULL THEN
2426 searchhousenumber = in_housenumber::text;
2429 -- %NOTIGERDATA% END IF;
2431 -- %NOAUXDATA% IF 0 THEN
2432 IF for_place_id IS NULL THEN
2433 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2434 WHERE place_id = in_place_id
2435 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2437 -- %NOAUXDATA% END IF;
2440 IF for_place_id IS NULL THEN
2441 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2442 FROM location_postcode
2443 WHERE place_id = in_place_id
2444 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2447 IF for_place_id IS NULL THEN
2448 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2449 WHERE place_id = in_place_id and rank_search > 27
2450 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2453 IF for_place_id IS NULL THEN
2454 select coalesce(linked_place_id, place_id), country_code,
2455 housenumber, rank_search, postcode, null
2456 from placex where place_id = in_place_id
2457 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2460 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2463 hadcountry := false;
2465 select placex.place_id, osm_type, osm_id, name,
2466 class, type, admin_level, true as isaddress,
2467 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2468 0 as distance, country_code, postcode
2470 where place_id = for_place_id
2472 --RAISE WARNING '%',location;
2473 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2474 searchcountrycode := location.country_code;
2476 IF location.type in ('postcode', 'postal_code') THEN
2477 location.isaddress := FALSE;
2478 ELSEIF location.rank_address = 4 THEN
2481 IF location.rank_address < 4 AND NOT hadcountry THEN
2482 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2483 IF countryname IS NOT NULL THEN
2484 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2485 RETURN NEXT countrylocation;
2488 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2489 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2490 location.distance)::addressline;
2491 RETURN NEXT countrylocation;
2492 found := location.rank_address;
2496 select placex.place_id, osm_type, osm_id, name,
2497 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2498 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2499 admin_level, fromarea, isaddress,
2500 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,
2501 distance,country_code,postcode
2502 from place_addressline join placex on (address_place_id = placex.place_id)
2503 where place_addressline.place_id = for_place_id
2504 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2505 and address_place_id != for_place_id
2506 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2507 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2509 --RAISE WARNING '%',location;
2510 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2511 searchcountrycode := location.country_code;
2513 IF location.type in ('postcode', 'postal_code') THEN
2514 location.isaddress := FALSE;
2516 IF location.rank_address = 4 AND location.isaddress THEN
2519 IF location.rank_address < 4 AND NOT hadcountry THEN
2520 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2521 IF countryname IS NOT NULL THEN
2522 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2523 RETURN NEXT countrylocation;
2526 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2527 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2528 location.distance)::addressline;
2529 RETURN NEXT countrylocation;
2530 found := location.rank_address;
2534 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2535 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2536 IF countryname IS NOT NULL THEN
2537 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2538 RETURN NEXT location;
2542 IF searchcountrycode IS NOT NULL THEN
2543 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2544 RETURN NEXT location;
2547 IF searchhousename IS NOT NULL THEN
2548 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2549 RETURN NEXT location;
2552 IF searchhousenumber IS NOT NULL THEN
2553 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2554 RETURN NEXT location;
2557 IF searchpostcode IS NOT NULL THEN
2558 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2559 RETURN NEXT location;
2568 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2574 ELSEIF rank < 4 THEN
2576 ELSEIF rank < 8 THEN
2578 ELSEIF rank < 12 THEN
2580 ELSEIF rank < 16 THEN
2582 ELSEIF rank = 16 THEN
2584 ELSEIF rank = 17 THEN
2585 RETURN 'Town / Island';
2586 ELSEIF rank = 18 THEN
2587 RETURN 'Village / Hamlet';
2588 ELSEIF rank = 20 THEN
2590 ELSEIF rank = 21 THEN
2591 RETURN 'Postcode Area';
2592 ELSEIF rank = 22 THEN
2593 RETURN 'Croft / Farm / Locality / Islet';
2594 ELSEIF rank = 23 THEN
2595 RETURN 'Postcode Area';
2596 ELSEIF rank = 25 THEN
2597 RETURN 'Postcode Point';
2598 ELSEIF rank = 26 THEN
2599 RETURN 'Street / Major Landmark';
2600 ELSEIF rank = 27 THEN
2601 RETURN 'Minory Street / Path';
2602 ELSEIF rank = 28 THEN
2603 RETURN 'House / Building';
2605 RETURN 'Other: '||rank;
2612 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2618 ELSEIF rank < 2 THEN
2620 ELSEIF rank < 4 THEN
2622 ELSEIF rank = 5 THEN
2624 ELSEIF rank < 8 THEN
2626 ELSEIF rank < 12 THEN
2628 ELSEIF rank < 16 THEN
2630 ELSEIF rank = 16 THEN
2632 ELSEIF rank = 17 THEN
2633 RETURN 'Town / Village / Hamlet';
2634 ELSEIF rank = 20 THEN
2636 ELSEIF rank = 21 THEN
2637 RETURN 'Postcode Area';
2638 ELSEIF rank = 22 THEN
2639 RETURN 'Croft / Farm / Locality / Islet';
2640 ELSEIF rank = 23 THEN
2641 RETURN 'Postcode Area';
2642 ELSEIF rank = 25 THEN
2643 RETURN 'Postcode Point';
2644 ELSEIF rank = 26 THEN
2645 RETURN 'Street / Major Landmark';
2646 ELSEIF rank = 27 THEN
2647 RETURN 'Minory Street / Path';
2648 ELSEIF rank = 28 THEN
2649 RETURN 'House / Building';
2651 RETURN 'Other: '||rank;
2658 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2659 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2664 place_centroid GEOMETRY;
2665 out_partition INTEGER;
2666 out_parent_place_id BIGINT;
2668 address_street_word_id INTEGER;
2673 place_centroid := ST_Centroid(pointgeo);
2674 out_partition := get_partition(in_countrycode);
2675 out_parent_place_id := null;
2677 address_street_word_id := get_name_id(make_standard_name(in_street));
2678 IF address_street_word_id IS NOT NULL THEN
2679 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2680 out_parent_place_id := location.place_id;
2684 IF out_parent_place_id IS NULL THEN
2685 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2686 out_parent_place_id := location.place_id;
2690 out_postcode := in_postcode;
2691 IF out_postcode IS NULL THEN
2692 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2694 -- XXX look into postcode table
2697 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2698 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2699 newpoints := newpoints + 1;
2706 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2713 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2714 IF members[i+1] = member THEN
2715 result := result || members[i];
2724 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2730 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2731 IF members[i+1] = ANY(memberLabels) THEN
2732 RETURN NEXT members[i];
2741 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2742 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2744 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2745 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
2746 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2747 ), '') AS bytea), 'UTF8');
2749 LANGUAGE SQL IMMUTABLE STRICT;
2751 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2755 RETURN decode_url_part(p);
2757 WHEN others THEN return null;
2760 LANGUAGE plpgsql IMMUTABLE;
2762 DROP TYPE wikipedia_article_match CASCADE;
2763 create type wikipedia_article_match as (
2769 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2775 wiki_article_title TEXT;
2776 wiki_article_language TEXT;
2777 result wikipedia_article_match;
2779 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'];
2781 WHILE langs[i] IS NOT NULL LOOP
2782 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2783 IF wiki_article is not null THEN
2784 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2785 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2786 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2787 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2788 wiki_article := replace(wiki_article,' ','_');
2789 IF strpos(wiki_article, ':') IN (3,4) THEN
2790 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2791 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2793 wiki_article_title := trim(wiki_article);
2794 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;
2797 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2798 from wikipedia_article
2799 where language = wiki_article_language and
2800 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2802 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2803 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2804 where wikipedia_redirect.language = wiki_article_language and
2805 (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'\\',''))
2806 order by importance desc limit 1 INTO result;
2808 IF result.language is not null THEN
2819 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2820 RETURNS SETOF GEOMETRY
2834 remainingdepth INTEGER;
2839 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2841 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2842 RETURN NEXT geometry;
2846 remainingdepth := maxdepth - 1;
2847 area := ST_AREA(geometry);
2848 IF remainingdepth < 1 OR area < maxarea THEN
2849 RETURN NEXT geometry;
2853 xmin := st_xmin(geometry);
2854 xmax := st_xmax(geometry);
2855 ymin := st_ymin(geometry);
2856 ymax := st_ymax(geometry);
2857 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2859 -- if the geometry completely covers the box don't bother to slice any more
2860 IF ST_AREA(secbox) = area THEN
2861 RETURN NEXT geometry;
2865 xmid := (xmin+xmax)/2;
2866 ymid := (ymin+ymax)/2;
2869 FOR seg IN 1..4 LOOP
2872 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2875 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2878 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2881 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2884 IF st_intersects(geometry, secbox) THEN
2885 secgeo := st_intersection(geometry, secbox);
2886 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2887 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2888 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2890 RETURN NEXT geo.geom;
2902 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2903 RETURNS SETOF GEOMETRY
2908 -- 10000000000 is ~~ 1x1 degree
2909 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2910 RETURN NEXT geo.geom;
2918 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2922 osmtype character(1);
2926 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2927 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2928 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2929 -- force delete from place/placex by making it a very small geometry
2930 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;
2931 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2938 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2946 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2947 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2948 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2949 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2950 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2951 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2952 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'));
2953 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2954 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'));
2960 ELSEIF rank < 18 THEN
2962 ELSEIF rank < 20 THEN
2964 ELSEIF rank = 21 THEN
2966 ELSEIF rank < 24 THEN
2968 ELSEIF rank < 26 THEN
2969 diameter := 0.002; -- 100 to 200 meters
2970 ELSEIF rank < 28 THEN
2971 diameter := 0.001; -- 50 to 100 meters
2973 IF diameter > 0 THEN
2975 -- roads may cause reparenting for >27 rank places
2976 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2977 ELSEIF rank >= 16 THEN
2978 -- up to rank 16, street-less addresses may need reparenting
2979 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');
2981 -- for all other places the search terms may change as well
2982 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);